Re: How to keep at-most N rows per group? periodic DELETEs or constraints or..?

From: Erik Jones <erik(at)myemma(dot)com>
To: Jamie Tufnell <diesql(at)googlemail(dot)com>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: How to keep at-most N rows per group? periodic DELETEs or constraints or..?
Date: 2008-01-08 16:30:28
Message-ID: D71EBDA2-B18D-4722-B291-B4A7E2C49D09@myemma.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql


On Jan 8, 2008, at 8:24 AM, Jamie Tufnell wrote:

> Hi,
>
> I have a table that stores per-user histories of recently viewed items
> and I'd like to limit the amount of history items to <= 50 per user.
> I'm considering doing this with a query run from cron every so often
> but I'm not happy with what I've come up with so far, and since it's a
> quite active table I thought I'd ask here to see if there's a more
> efficient way.
>
> Right now the table structure is as follows...
>
> user_item_history: id (PK), user_id (FK), item_id (FK), timestamp
>
> For user_ids that have more than 50 rows, I want to keep the most
> recent 50 and delete the rest.

Create an row trigger that fires after insert containing something
along the lines of :

DELETE FROM user_item_history
WHERE id IN (SELECT id
FROM user_item_history
WHERE user_id=NEW.user_id
ORDER BY timestamp DESC
OFFSET 50);

Erik Jones

DBA | Emma®
erik(at)myemma(dot)com
800.595.4401 or 615.292.5888
615.292.0777 (fax)

Emma helps organizations everywhere communicate & market in style.
Visit us online at http://www.myemma.com

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Jamie Tufnell 2008-01-08 16:31:08 Re: How to keep at-most N rows per group? periodic DELETEs or constraints or..?
Previous Message codeWarrior 2008-01-08 15:45:02 Re: How to keep at-most N rows per group? periodic DELETEs or constraints or..?