Re: Triggers using PL/pgSQL

From: "Aaron Bono" <postgresql(at)aranya(dot)com>
To: "Thusitha Kodikara" <kthusi(at)yahoo(dot)com>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: Triggers using PL/pgSQL
Date: 2006-07-31 04:52:41
Message-ID: bf05e51c0607302152k2801caflc9040d99af7b2816@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-php pgsql-sql

On 7/30/06, Thusitha Kodikara <kthusi(at)yahoo(dot)com> wrote:
>
> Hello,
>
> I am interested in developing some triggers to keep track of records that
> are changed (possibly the changes of one or more specific columns). In
> addition to keeping the new values, I also need to keep the old values (may
> be on a separate table).
>
> Though I have done similar things in other RDBMs using SQL, I find doing
> this in Postgres, a little bit complicated - may be because it needs to be
> done through a separate procedural language and through a separate function.
> The Postgres documentation also didn't provide much help ( the examples in
> C). I was mainly looking for example showing how to refer 'OLD' and 'NEW'
> rows using PL/pgSQL.
>
> Can someone please direct me to some such examples?
>

How about this:

CREATE TABLE my_table (
my_table_id BIGSERIAL NOT NULL,
my_value VARCHAR(100) NOT NULL,
CONSTRAINT my_table_pkey PRIMARY KEY (my_table_id)
);

CREATE TABLE my_table_history (
my_table_id BIGINT NOT NULL,
my_value VARCHAR(100) NOT NULL,
create_dt TIMESTAMP NOT NULL,
CONSTRAINT my_table_history_pkey PRIMARY KEY (my_table_id, create_dt)
);

CREATE OR REPLACE FUNCTION my_table_history_fn () RETURNS SETOF opaque AS
'
BEGIN
-- if a trigger insert or update operation occurs
IF TG_OP = ''INSERT'' OR TG_OP = ''UPDATE'' THEN
execute
''INSERT INTO my_table_history ( '' ||
'' my_table_id, '' ||
'' my_value, '' ||
'' create_dt '' ||
'') VALUES ( '' ||
'' '''''' || NEW.my_table_id || '''''', '' ||
'' '''''' || NEW.my_value || '''''', '' ||
'' now() '' ||
'');''
;
RETURN NEW;
END IF;
END;
'
LANGUAGE 'plpgsql' VOLATILE CALLED ON NULL INPUT SECURITY INVOKER;

CREATE TRIGGER my_table_history_tr BEFORE UPDATE OR INSERT
ON my_table FOR EACH ROW
EXECUTE PROCEDURE my_table_history_fn();

I tried it out and it works in version 8.1.

==================================================================
Aaron Bono
Aranya Software Technologies, Inc.
http://www.aranya.com
==================================================================

In response to

Responses

Browse pgsql-php by date

  From Date Subject
Next Message Thusitha Kodikara 2006-07-31 05:30:57 Re: Triggers using PL/pgSQL
Previous Message Thusitha Kodikara 2006-07-31 04:16:44 Triggers using PL/pgSQL

Browse pgsql-sql by date

  From Date Subject
Next Message Thusitha Kodikara 2006-07-31 05:30:57 Re: Triggers using PL/pgSQL
Previous Message Thusitha Kodikara 2006-07-31 04:16:44 Triggers using PL/pgSQL