Thread: Returning with the inserted id
Hi all A table was created with:CREATE TABLE test ( id integer, nev varchar(25), datum timestamp); A sequence to hold the id was defined with:CREATE SEQUENCE "public"."test_azon_seq" INCREMENT 1 MINVALUE 101 MAXVALUE9223372036854775807 START 101 CACHE 1; The function wich allocates the id and defines the datum is:CREATE FUNCTION test_verif() RETURNS trigger AS $test_verif$ BEGIN select into NEW.id nextval('test_azon_seq'); NEW.datum := current_timestamp; RETURNNEW; END;$test_verif$ LANGUAGE plpgsql; and the before insert trigger is:CREATE TRIGGER test_verif BEFORE INSERT ON test FOR EACH ROW EXECUTE PROCEDURE test_verif(); When I issue an insert (see below) how can I retrieve the inserted value of id? I need something like Oracle's returns for insert. insert into "public"."test" (nev) values ('text'); -- László Graf
Graf László wrote: > > A sequence to hold the id was defined with: > CREATE SEQUENCE "public"."test_azon_seq" > INCREMENT 1 MINVALUE 101 > MAXVALUE 9223372036854775807 START 101 > CACHE 1; > > The function wich allocates the id and defines the datum is: > CREATE FUNCTION test_verif() RETURNS trigger AS $test_verif$ > BEGIN > select into NEW.id nextval('test_azon_seq'); > NEW.datum := current_timestamp; > RETURN NEW; > END; > $test_verif$ LANGUAGE plpgsql; I take it this is just an example, because you could do this with DEFAULTs on both columns. > When I issue an insert (see below) how can I retrieve the > inserted value of id? I need something like Oracle's returns > for insert. > > insert into "public"."test" (nev) values ('text'); SELECT currval('public.test_azon_seq'); And yes, it will cope with multiple concurrent connections inserting. -- Richard Huxton Archonet Ltd