Re: best way to auto-update a field when row is updated

From: Scott Marlowe <smarlowe(at)g2switchworks(dot)com>
To: Henry Ortega <juandelacruz(at)gmail(dot)com>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: best way to auto-update a field when row is updated
Date: 2005-03-10 20:35:48
Message-ID: 1110486947.28555.3.camel@state.g2switchworks.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

On Thu, 2005-03-10 at 14:09, Henry Ortega wrote:
> I have the following table
>
> FIELD_A | FIELD_B | TSTAMP
> --------------------------------------------------------------------------------------------------------
> x y 2005-03-10
> 14:56:47.456431
>
> TSTAMP = not null default now()
>
> What's the best way to always auto-update TSTAMP to it's
> default value whenever the row gets updated?
> (e.g. update TABLENAME set FIELD_A='zzz' where FIELD_A='x';
> should automatically set TSTAMP to now)

Here's a simple trigger to do that for ya.

-- FUNCTION --

CREATE FUNCTION modtime () RETURNS opaque AS '
BEGIN
new.lm :=''now'';
RETURN new;
END;
' LANGUAGE 'plpgsql';

-- TABLE --

CREATE TABLE dtest (
id int primary key,
fluff text,
lm timestamp without time zone
);

--TRIGGER --

CREATE TRIGGER dtest
BEFORE UPDATE or INSERT ON dtest FOR EACH ROW EXECUTE PROCEDURE
modtime(lm);

-- SQL TESTS --

INSERT INTO dtest (id, fluff) VALUES (1,'this is a test');
INSERT INTO dtest (id, fluff) VALUES (2,'this is another test');
SELECT * FROM dtest;
1 | this is a test | 2003-04-02 10:33:12.577089
2 | this is another test | 2003-04-02 10:33:18.591148
UPDATE dtest SET id=3 WHERE id=1;
3 | this is a test | 2003-04-02 10:34:52.219963 [1]
UPDATE dtest SET fluff='now is the time' WHERE id=2;
SELECT * FROM dtest WHERE id=2;
2 | now is the time | 2003-04-02 10:38:06.259443 [2]
UPDATE dtest SET lm='2003-04-02 08:30:00' WHERE id=3;
SELECT * FROM dtest WHERE id=3;
3 | this is a test | 2003-04-02 10:36:15.45687 [3]

[1] The timestamp has changed for this record when we changed the id field.
[2] The timestamp also changes for the fluff field.
[3] We tried to set lm, but the trigger on that field in dtest intercepted the change and forced it

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Juris Zeltins 2005-03-11 10:54:52 pl/pgsql problem with return types
Previous Message Larry Rosenman 2005-03-10 20:21:33 Re: best way to auto-update a field when row is updated