Re: [Trigger] Help needed with NEW.* and TG_TABLE_NAME

From: Torsten Zühlsdorff <foo(at)meisterderspiele(dot)de>
To: pgsql-sql(at)postgresql(dot)org
Subject: Re: [Trigger] Help needed with NEW.* and TG_TABLE_NAME
Date: 2010-05-17 08:57:08
Message-ID: hsr0d5$g8m$1@news.eternal-september.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

Jasen Betts schrieb:

> On 2010-05-11, Torsten Zühlsdorff <foo(at)meisterderspiele(dot)de> wrote:
>> Hello,
>>
>> i have a problem with a trigger written in pl/pgsql.
>>
>> It looks like this:
>>
>> CREATE OR REPLACE FUNCTION versionize()
>> RETURNS TRIGGER
>> AS $$
>> BEGIN
>>
>> NEW.revision := addContentRevision (OLD.content_id, OLD.revision);
>>
>> /* not working line, just a stub:
>> EXECUTE 'INSERT INTO ' || TG_TABLE_NAME || ' SELECT $1 ' USING NEW;
>> */
>>
>> RETURN NULL;
>>
>> END;
>> $$ LANGUAGE 'plpgsql' VOLATILE;
>>
>> The function should be used at different tables and is invoked before
>> UPDATEs. Everything what happens is the function call of
>> addContentRevision. After this call all data (with the updated revision
>> column) should be stored in the table as a new row.
>
> What many people have missed is that you want to INSERT when the DML
> comnabd UPDATE is used.
>
> for things like that usually a rule is used instead, but I can see where
> that may be unsuitable for your needs. I found the following
> to work on a simple test case.
>
>
> The problem is that INSERT in PLPGSQL needs a fixed table-name, and
> that "EXECUTE" can't use variable-names, and further that quote_literal
> doesn't convert ROW variables into something that can be used in a
> VALUES clause.
>
> so, Here's what I did.
>
> CREATE OR REPLACE FUNCTION versionize()
> RETURNS TRIGGER
> AS $$
> BEGIN
>
> -- Not havign a definition for addContentRevision
> -- I had this line commented out during testing.
> NEW.revision := addContentRevision (OLD.content_id, OLD.revision);
>
> EXECUTE 'INSERT INTO '||TG_TABLE_NAME||' SELECT (' ||
> QUOTE_LITERAL(NEW) || '::' || TG_TABLE_NAME ||').*' ;
>
> RETURN NULL;
>
> END;
> $$ LANGUAGE PLPGSQL VOLATILE;
>
> I take NEW, convert it to a quoted literal so I can use it in EXECUTE, cast it
> to the apreopreiate row type and split it into columns using SELECT
> and .*. That gets inserted.
>
> you should probably use QUOTE_IDENT on the TG_TABLE_NAME and possibly
> also use similarly quoted TG_SCHEMA_NAME

That's an quite interesting solution. I've tested it in several ways and
it works like i want. :)

Thank you very much - and every other responder - for your time.

Greetings from Germany,
Torsten

--
http://www.dddbl.de - ein Datenbank-Layer, der die Arbeit mit 8
verschiedenen Datenbanksystemen abstrahiert,
Queries von Applikationen trennt und automatisch die Query-Ergebnisse
auswerten kann.

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Kenneth Marshall 2010-05-18 19:08:32 How to get CURRENT_DATE in a pl/pgSQL function
Previous Message Scott Marlowe 2010-05-17 06:04:17 Re: import ignoring duplicates