Re: SQL INSERT/TRIGGER Help

Lists: pgsql-sql
From: "Poovendran Moodley" <poovenm(at)gmail(dot)com>
To: pgsql-sql(at)postgresql(dot)org
Subject: SQL INSERT/TRIGGER Help
Date: 2007-12-10 06:36:44
Message-ID: b18bbf6f0712092236m48fa2e28s80b7bbb30c80dc22@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

Hi all, I'm not sure how to phrase this question... I have a table that
requires a foreign key of another table - this foreign key is automatically
generated and the key field in the 'foreign' table. So I have the following
situation (kind of):

Table *Observation*

*Time_Stamp* - *primary key*

...

Observation_ID - *foreign key*

Table *Observation_Value*

*Observation_ID* - *primary key*

...

So obviously I need to insert into the table *Observation_Value* first
before I can insert into table *Observation*, but how to I get the
automatically generated foreign key?

I was thinking of using a trigger - when a value is inserted into *
Observation_Value* then add the primary key to a new table (probably a view)
and get that value for insertion into *Observation* then drop temporary
table. I wanted to know if there's an easier way to do this? I can't change
the table structure in any way either.... any help would be appreciated. I'm
not even sure what type of search query I should use to find help on this
topic either...

Regards,
Pooven


From: "A(dot) Kretschmer" <andreas(dot)kretschmer(at)schollglas(dot)com>
To: pgsql-sql(at)postgresql(dot)org
Subject: Re: SQL INSERT/TRIGGER Help
Date: 2007-12-10 06:44:25
Message-ID: 20071210064425.GA917@a-kretschmer.de
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

am Mon, dem 10.12.2007, um 8:36:44 +0200 mailte Poovendran Moodley folgendes:
> So obviously I need to insert into the table Observation_Value first before I
> can insert into table Observation, but how to I get the automatically generated
> foreign key?

You can simple use currval() for this.

Andreas
--
Andreas Kretschmer
Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header)
GnuPG-ID: 0x3FFF606C, privat 0x7F4584DA http://wwwkeys.de.pgp.net


From: "Poovendran Moodley" <poovenm(at)gmail(dot)com>
To: "A(dot) Kretschmer" <andreas(dot)kretschmer(at)schollglas(dot)com>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: SQL INSERT/TRIGGER Help
Date: 2007-12-10 07:27:58
Message-ID: b18bbf6f0712092327v1924db67n234bcb37aab634a9@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

I'm not really sure how to the *currval() *method. I've read up on it and I
noticed it works with *nextval()* and *setval()*. The parameter for *
currval()* is a regex - is there a regex to represent the most recently
automatically generated number ( i.e. a serial field)? If there isn't, I was
thinking that a trigger could be used so that when an *INSERT* is executed
against the *Observation_Value* table then I'll use *setval()* to store the
automatically generated field. However I'm having some trouble
defining a *TRIGGER
*in PostGres. I noticed that one can implement a C code to achieve the
effect of a trigger, however, would normal SQL work as well? I have the
following:

CREATE FUNCTION doInsert(id int)
AS 'SELECT setval('observation_id', new.observation_id)';

CREATE TRIGGER onObservationEntry
AFTER INSERT ON Observation_Key
FOR EACH STATEMENT
EXECUTE PROCEDURE doInsert(new.observation_id );

Which doesn't work. I get the following error: ERROR: syntax error at or
near "observation_id". I know that usually new represents, in this case, the
inserted tuple, however, new doesn't seem to work with PostGres; what is the
correct way to do this? I used a function because it appears that this is
the only way to define a trigger. If I can simply execute the SQL statement
in my function that would be awesome - but what is the syntax for this? Well
I'm not really sure if I've defined my function correctly - I just imitated
an example I've seen.

Thanks for your help Andreas, one step closer :) *currval()* is so much
better than creating a view.

Regards,
Pooven

On Dec 10, 2007 8:44 AM, A. Kretschmer < andreas(dot)kretschmer(at)schollglas(dot)com>
wrote:

> am Mon, dem 10.12.2007, um 8:36:44 +0200 mailte Poovendran Moodley
> folgendes:
> > So obviously I need to insert into the table Observation_Value first
> before I
> > can insert into table Observation, but how to I get the automatically
> generated
> > foreign key?
>
> You can simple use currval() for this.
>
>
> Andreas
> --
> Andreas Kretschmer
> Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header)
> GnuPG-ID: 0x3FFF606C, privat 0x7F4584DA http://wwwkeys.de.pgp.net
>
> ---------------------------(end of broadcast)---------------------------
> TIP 9: In versions below 8.0, the planner will ignore your desire to
> choose an index scan if your joining column's datatypes do not
> match
>


From: "A(dot) Kretschmer" <andreas(dot)kretschmer(at)schollglas(dot)com>
To: pgsql-sql(at)postgresql(dot)org
Subject: Re: SQL INSERT/TRIGGER Help
Date: 2007-12-10 07:43:47
Message-ID: 20071210074347.GB917@a-kretschmer.de
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

am Mon, dem 10.12.2007, um 9:27:58 +0200 mailte Poovendran Moodley folgendes:
> I'm not really sure how to the currval() method. I've read up on it and I
> noticed it works with nextval() and setval(). The parameter for currval() is a
> regex - is there a regex to represent the most recently automatically generated
> number ( i.e. a serial field)? If there isn't, I was thinking that a trigger
> could be used so that when an INSERT is executed against the Observation_Value

Okay, i explain this a little bit more:

first, i create two tables, master and slave. master contains a
serial-field, this field is referenced by the slave table:

test=# create table master (id serial primary key, name text);
NOTICE: CREATE TABLE will create implicit sequence "master_id_seq" for serial column "master.id"
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "master_pkey" for table "master"
CREATE TABLE
test=*# create table slave(master_id int references master, val text);
CREATE TABLE

Now i have 2 tables and a sequence named 'master_id_seq', and now the
insert's:

test=*# insert into master (name) values ('test');
INSERT 0 1
test=*# insert into slave (master_id, val) values (currval('master_id_seq'), 'value');
INSERT 0 1

The parameter for currval() is the name of the sequence. Note: you have to
insert in the master table first, this calls the nextval() for the
sequence. After, within this database session, you can use currval() to
obtain the actual value for this sequence. And yes, this way is safe
also for concurrency.

Andreas
--
Andreas Kretschmer
Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header)
GnuPG-ID: 0x3FFF606C, privat 0x7F4584DA http://wwwkeys.de.pgp.net


From: "Poovendran Moodley" <poovenm(at)gmail(dot)com>
To: "A(dot) Kretschmer" <andreas(dot)kretschmer(at)schollglas(dot)com>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: SQL INSERT/TRIGGER Help
Date: 2007-12-10 09:13:49
Message-ID: b18bbf6f0712100113h5937e2c3pcc0ef236e3733635@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

Aww man thank you so much! It worked like a charm! Have a smashing day :D

On Dec 10, 2007 9:43 AM, A. Kretschmer <andreas(dot)kretschmer(at)schollglas(dot)com>
wrote:

> am Mon, dem 10.12.2007, um 9:27:58 +0200 mailte Poovendran Moodley
> folgendes:
> > I'm not really sure how to the currval() method. I've read up on it and
> I
> > noticed it works with nextval() and setval(). The parameter for
> currval() is a
> > regex - is there a regex to represent the most recently automatically
> generated
> > number ( i.e. a serial field)? If there isn't, I was thinking that a
> trigger
> > could be used so that when an INSERT is executed against the
> Observation_Value
>
>
> Okay, i explain this a little bit more:
>
> first, i create two tables, master and slave. master contains a
> serial-field, this field is referenced by the slave table:
>
> test=# create table master (id serial primary key, name text);
> NOTICE: CREATE TABLE will create implicit sequence "master_id_seq" for
> serial column "master.id"
> NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index
> "master_pkey" for table "master"
> CREATE TABLE
> test=*# create table slave(master_id int references master, val text);
> CREATE TABLE
>
>
> Now i have 2 tables and a sequence named 'master_id_seq', and now the
> insert's:
>
>
> test=*# insert into master (name) values ('test');
> INSERT 0 1
> test=*# insert into slave (master_id, val) values
> (currval('master_id_seq'), 'value');
> INSERT 0 1
>
>
>
> The parameter for currval() is the name of the sequence. Note: you have to
> insert in the master table first, this calls the nextval() for the
> sequence. After, within this database session, you can use currval() to
> obtain the actual value for this sequence. And yes, this way is safe
> also for concurrency.
>
>
> Andreas
> --
> Andreas Kretschmer
> Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header)
> GnuPG-ID: 0x3FFF606C, privat 0x7F4584DA http://wwwkeys.de.pgp.net
>
> ---------------------------(end of broadcast)---------------------------
> TIP 6: explain analyze is your friend
>


From: Alvaro Herrera <alvherre(at)alvh(dot)no-ip(dot)org>
To: Poovendran Moodley <poovenm(at)gmail(dot)com>
Cc: "A(dot) Kretschmer" <andreas(dot)kretschmer(at)schollglas(dot)com>, pgsql-sql(at)postgresql(dot)org
Subject: Re: SQL INSERT/TRIGGER Help
Date: 2007-12-10 14:08:05
Message-ID: 20071210140805.GD8036@alvh.no-ip.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

Poovendran Moodley escribiĆ³:
> I'm not really sure how to the *currval() *method. I've read up on it and I
> noticed it works with *nextval()* and *setval()*. The parameter for *
> currval()* is a regex - is there a regex to represent the most recently
> automatically generated number ( i.e. a serial field)?

It's not a regex. I assume you are confused because it says "regclass".
This is shorthand for "registered class" (where "class" is a synonymous
for "relation", in this case a sequence).

--
Alvaro Herrera http://www.amazon.com/gp/registry/5ZYLFMCVHXC
"La felicidad no es maƱana. La felicidad es ahora"