Last value inserted

Collapse
This topic is closed.
X
X
 
  • Time
  • Show
Clear All
new posts
  • MaRCeLO PeReiRA

    Last value inserted

    Hi guys,

    I am in troubles with a SERIAL field.

    I have five tables. A parent table and four child
    tables. When I do the INSERT in the parent table, I
    have an ID (generated) by the sequence (SERIAL field),
    and I have to use this ID to reference all child
    tables.

    Well, once I do an INSERT in the parent table, how can
    I know (for sure) which number id was generated by the
    sequence?

    Simple example:

    ------------------------------------------------------
    CREATE TABLE parent(id SERIAL, descrip CHAR(50));
    ------------------------------------------------------

    So,

    ------------------------------------------------------
    INSERT INTO parent (descrip) VALUES ('project 1');
    ------------------------------------------------------

    How can I now (for sure) with value was generated by
    the sequence to fill the field ID?

    (There is lots of users using the software at the same
    time, so I am not able to use the last_value()
    function on the sequence.)

    Best Regards,

    Marcelo Pereira
    Brazil





    _______________ _______________ _______________ __________
    Yahoo! Acesso Grátis - Internet rápida e grátis. Instale o discador agora! http://br.acesso.yahoo.com/

    ---------------------------(end of broadcast)---------------------------
    TIP 4: Don't 'kill -9' the postmaster

  • Franco Bruno Borghesi

    #2
    Re: Last value inserted

    I think the best way would be not to use a SERIAL field, but an INTEGER
    field and a sequence:

    CREATE SEQUENCE parent_seq;
    CREATE TABLE parent(id INTEGER, descrip CHAR(50));


    So when you want to insert on the parent table, you obtain the next
    value from the sequence and then you insert in the parent and child
    tables the value you obtained:

    newId:=SELECT nextval('parent _seq')
    INSERT INTO parent(id, descrip) VALUES (newId, 'XXXX');
    INSERT INTO child_1(..., ..., parentId) VALUES (..., ..., newId);
    INSERT INTO child_2(..., ..., parentId) VALUES (..., ..., newId);
    INSERT INTO child_3(..., ..., parentId) VALUES (..., ..., newId);


    hope it helps.

    MaRCeLO PeReiRA wrote:
    [color=blue]
    >Hi guys,
    >
    >I am in troubles with a SERIAL field.
    >
    >I have five tables. A parent table and four child
    >tables. When I do the INSERT in the parent table, I
    >have an ID (generated) by the sequence (SERIAL field),
    >and I have to use this ID to reference all child
    >tables.
    >
    >Well, once I do an INSERT in the parent table, how can
    >I know (for sure) which number id was generated by the
    >sequence?
    >
    >Simple example:
    >
    >------------------------------------------------------
    >CREATE TABLE parent(id SERIAL, descrip CHAR(50));
    >------------------------------------------------------
    >
    >So,
    >
    >------------------------------------------------------
    >INSERT INTO parent (descrip) VALUES ('project 1');
    >------------------------------------------------------
    >
    >How can I now (for sure) with value was generated by
    >the sequence to fill the field ID?
    >
    >(There is lots of users using the software at the same
    >time, so I am not able to use the last_value()
    >function on the sequence.)
    >
    >Best Regards,
    >
    >Marcelo Pereira
    >Brazil
    >
    >
    >
    >
    >
    >______________ _______________ _______________ ___________
    >Yahoo! Acesso Grátis - Internet rápida e grátis. Instale o discador agora! http://br.acesso.yahoo.com/
    >
    >---------------------------(end of broadcast)---------------------------
    >TIP 4: Don't 'kill -9' the postmaster
    >
    >
    >[/color]


    ---------------------------(end of broadcast)---------------------------
    TIP 2: you can get off all lists at once with the unregister command
    (send "unregister YourEmailAddres sHere" to majordomo@postg resql.org)

    Comment

    • Robby Russell

      #3
      Re: Last value inserted

      On Thu, 2004-11-11 at 09:59 -0300, MaRCeLO PeReiRA wrote:[color=blue]
      > Hi guys,
      >
      > I am in troubles with a SERIAL field.
      >
      > I have five tables. A parent table and four child
      > tables. When I do the INSERT in the parent table, I
      > have an ID (generated) by the sequence (SERIAL field),
      > and I have to use this ID to reference all child
      > tables.
      >
      > Well, once I do an INSERT in the parent table, how can
      > I know (for sure) which number id was generated by the
      > sequence?
      >
      > Simple example:
      >
      > ------------------------------------------------------
      > CREATE TABLE parent(id SERIAL, descrip CHAR(50));
      > ------------------------------------------------------
      >
      > So,
      >
      > ------------------------------------------------------
      > INSERT INTO parent (descrip) VALUES ('project 1');
      > ------------------------------------------------------
      >
      > How can I now (for sure) with value was generated by
      > the sequence to fill the field ID?
      >
      > (There is lots of users using the software at the same
      > time, so I am not able to use the last_value()
      > function on the sequence.)
      >
      > Best Regards,
      >
      > Marcelo Pereira
      > Brazil[/color]


      I just asked this same question about a week or two ago and I got a
      response from Jonathan Daugherty who helped me with the initial query,
      and in PHP I was able to come up with:



      This was on the list a few weeks ago:
      [color=blue]
      > -- get_sequence(sc hema_name, table_name, column_name)
      >
      > CREATE OR REPLACE FUNCTION get_sequence (text, text, text) RETURNS
      > text AS '
      > SELECT seq.relname::te xt
      > FROM pg_class src, pg_class seq, pg_namespace, pg_attribute,
      > pg_depend
      > WHERE
      > pg_depend.refob jsubid = pg_attribute.at tnum AND
      > pg_depend.refob jid = src.oid AND
      > seq.oid = pg_depend.objid AND
      > src.relnamespac e = pg_namespace.oi d AND
      > pg_attribute.at trelid = src.oid AND
      > pg_namespace.ns pname = $1 AND
      > src.relname = $2 AND
      > pg_attribute.at tname = $3;
      > ' language sql;[/color]

      hth,

      Robby

      --
      /*************** *************** *********
      * Robby Russell | Owner.Developer .Geek
      * PLANET ARGON | www.planetargon.com
      * Portland, OR | robby@planetarg on.com
      * 503.351.4730 | blog.planetargo n.com
      * PHP/PostgreSQL Hosting & Development
      * --- Now supporting PHP5 ---
      *************** *************** **********/

      -----BEGIN PGP SIGNATURE-----
      Version: GnuPG v1.2.6 (GNU/Linux)

      iD8DBQBBk6vN0Qa QZBaqXgwRAiK0AJ 9B6QPP/fjeHe4PoCqAFkss se6x4ACg3ad6
      gEQQ4QsuSQ8UGXO KPKc+8+4=
      =Xn7A
      -----END PGP SIGNATURE-----

      Comment

      • Uwe C. Schroeder

        #4
        Re: Last value inserted

        -----BEGIN PGP SIGNED MESSAGE-----
        Hash: SHA1


        option 1) use a stored procedure to create the record. Within a transaction
        the last value function will return the correct last value, not the one of a
        concurrent insert.
        option 2) if you know that this user uses the same connection for all his
        queries - or at least the ones in question - you can rely on the last value
        being the correct one. Like with transactions, if you use the same connection
        the last value will be the correct one.

        You're only in trouble if you're not within a transaction and you're not sure
        if the connection stays the same for the queries in question. The later could
        be due to connection pooling.

        UC


        On Thursday 11 November 2004 04:59 am, MaRCeLO PeReiRA wrote:[color=blue]
        > Hi guys,
        >
        > I am in troubles with a SERIAL field.
        >
        > I have five tables. A parent table and four child
        > tables. When I do the INSERT in the parent table, I
        > have an ID (generated) by the sequence (SERIAL field),
        > and I have to use this ID to reference all child
        > tables.
        >
        > Well, once I do an INSERT in the parent table, how can
        > I know (for sure) which number id was generated by the
        > sequence?
        >
        > Simple example:
        >
        > ------------------------------------------------------
        > CREATE TABLE parent(id SERIAL, descrip CHAR(50));
        > ------------------------------------------------------
        >
        > So,
        >
        > ------------------------------------------------------
        > INSERT INTO parent (descrip) VALUES ('project 1');
        > ------------------------------------------------------
        >
        > How can I now (for sure) with value was generated by
        > the sequence to fill the field ID?
        >
        > (There is lots of users using the software at the same
        > time, so I am not able to use the last_value()
        > function on the sequence.)
        >
        > Best Regards,
        >
        > Marcelo Pereira
        > Brazil
        >
        >
        >
        >
        >
        > _______________ _______________ _______________ __________
        > Yahoo! Acesso Grátis - Internet rápida e grátis. Instale o discadoragora!
        > http://br.acesso.yahoo.com/
        >
        > ---------------------------(end of broadcast)---------------------------
        > TIP 4: Don't 'kill -9' the postmaster[/color]
        -----BEGIN PGP SIGNATURE-----
        Version: GnuPG v1.2.3 (GNU/Linux)

        iD4DBQFBk6lnjqG XBvRToM4RAgOXAJ iVy9TG9Yv05pegz ACw2VPeN7USAKDR Yg/N
        H0BKK8WT1aOZ+CB 3rCl8WQ==
        =kiLq
        -----END PGP SIGNATURE-----


        ---------------------------(end of broadcast)---------------------------
        TIP 9: the planner will ignore your desire to choose an index scan if your
        joining column's datatypes do not match

        Comment

        • Bruno Wolff III

          #5
          Re: Last value inserted

          On Thu, Nov 11, 2004 at 09:59:16 -0300,
          MaRCeLO PeReiRA <gandalf_mp@yah oo.com.br> wrote:[color=blue]
          >
          > Well, once I do an INSERT in the parent table, how can
          > I know (for sure) which number id was generated by the
          > sequence?[/color]

          Use currval.

          ---------------------------(end of broadcast)---------------------------
          TIP 6: Have you searched our list archives?



          Comment

          • Richard Huxton

            #6
            Re: Last value inserted

            MaRCeLO PeReiRA wrote:
            [color=blue]
            > How can I now (for sure) with value was generated by
            > the sequence to fill the field ID?
            >
            > (There is lots of users using the software at the same
            > time, so I am not able to use the last_value()
            > function on the sequence.)[/color]

            Yes you are nextval()/currval() are multi-user safe. They return the
            next/current value *in the current connection*.

            --
            Richard Huxton
            Archonet Ltd

            ---------------------------(end of broadcast)---------------------------
            TIP 8: explain analyze is your friend

            Comment

            • Jerry III

              #7
              Re: Last value inserted

              Which means that sometimes they do not return the correct value - if you
              have a trigger that inserts another record you will not get the right value.
              MSSQL has @@IDENTITY and SCOPE_IDENTITY( ) to handle this case, I'm new to
              pgsql so I don't know if it has anything like that.

              Jerry

              "Richard Huxton" <dev@archonet.c om> wrote in message
              news:4193B30B.4 0905@archonet.c om...[color=blue]
              > MaRCeLO PeReiRA wrote:
              >[color=green]
              >> How can I now (for sure) with value was generated by
              >> the sequence to fill the field ID?
              >>
              >> (There is lots of users using the software at the same
              >> time, so I am not able to use the last_value()
              >> function on the sequence.)[/color]
              >
              > Yes you are nextval()/currval() are multi-user safe. They return the
              > next/current value *in the current connection*.
              >
              > --
              > Richard Huxton
              > Archonet Ltd
              >
              > ---------------------------(end of broadcast)---------------------------
              > TIP 8: explain analyze is your friend
              >[/color]


              Comment

              • Uwe C. Schroeder

                #8
                Re: Last value inserted

                -----BEGIN PGP SIGNED MESSAGE-----
                Hash: SHA1

                On Thursday 11 November 2004 10:23 am, Franco Bruno Borghesi wrote:[color=blue]
                > I think the best way would be not to use a SERIAL field, but an INTEGER
                > field and a sequence:[/color]

                a "serial" is just a convenient shortcut to an int with an automatically
                created sequence. As proof - just create a table with a serial and dump it
                with pg_dump: you'll end up with a table containing an int with a nextval(....
                as the default. The only difference is that in case of the "serial" field you
                don't name the sequence yourself.
                [color=blue]
                > CREATE SEQUENCE parent_seq;
                > CREATE TABLE parent(id INTEGER, descrip CHAR(50));
                >
                >
                > So when you want to insert on the parent table, you obtain the next
                > value from the sequence and then you insert in the parent and child
                > tables the value you obtained:
                >
                > newId:=SELECT nextval('parent _seq')
                > INSERT INTO parent(id, descrip) VALUES (newId, 'XXXX');
                > INSERT INTO child_1(..., ..., parentId) VALUES (..., ..., newId);
                > INSERT INTO child_2(..., ..., parentId) VALUES (..., ..., newId);
                > INSERT INTO child_3(..., ..., parentId) VALUES (..., ..., newId);[/color]

                which amounts to the curval in the same connection.
                [color=blue]
                >
                > hope it helps.
                >
                > MaRCeLO PeReiRA wrote:[color=green]
                > >Hi guys,
                > >
                > >I am in troubles with a SERIAL field.
                > >
                > >I have five tables. A parent table and four child
                > >tables. When I do the INSERT in the parent table, I
                > >have an ID (generated) by the sequence (SERIAL field),
                > >and I have to use this ID to reference all child
                > >tables.
                > >
                > >Well, once I do an INSERT in the parent table, how can
                > >I know (for sure) which number id was generated by the
                > >sequence?
                > >
                > >Simple example:
                > >
                > >------------------------------------------------------
                > >CREATE TABLE parent(id SERIAL, descrip CHAR(50));
                > >------------------------------------------------------
                > >
                > >So,
                > >
                > >------------------------------------------------------
                > >INSERT INTO parent (descrip) VALUES ('project 1');
                > >------------------------------------------------------
                > >
                > >How can I now (for sure) with value was generated by
                > >the sequence to fill the field ID?
                > >
                > >(There is lots of users using the software at the same
                > >time, so I am not able to use the last_value()
                > >function on the sequence.)
                > >
                > >Best Regards,
                > >
                > >Marcelo Pereira
                > >Brazil
                > >
                > >
                > >
                > >
                > >
                > >______________ _______________ _______________ ___________
                > >Yahoo! Acesso Grátis - Internet rápida e grátis. Instale o discador agora!
                > > http://br.acesso.yahoo.com/
                > >
                > >---------------------------(end of broadcast)---------------------------
                > >TIP 4: Don't 'kill -9' the postmaster[/color]
                >
                > ---------------------------(end of broadcast)---------------------------
                > TIP 2: you can get off all lists at once with the unregister command
                > (send "unregister YourEmailAddres sHere" to majordomo@postg resql.org)[/color]

                - --
                UC

                - --
                Open Source Solutions 4U, LLC 2570 Fleetwood Drive
                Phone: +1 650 872 2425 San Bruno, CA 94066
                Cell: +1 650 302 2405 United States
                Fax: +1 650 872 2417
                -----BEGIN PGP SIGNATURE-----
                Version: GnuPG v1.2.3 (GNU/Linux)

                iD8DBQFBlFD5jqG XBvRToM4RAmfQAJ 9JyQxERqcau1kCn vkrXNmpaGTwzwCg qK6L
                7zCpR+uO5pzvDuY/itTYCfs=
                =mq0M
                -----END PGP SIGNATURE-----


                ---------------------------(end of broadcast)---------------------------
                TIP 1: subscribe and unsubscribe commands go to majordomo@postg resql.org

                Comment

                • Jeff Eckermann

                  #9
                  Re: Last value inserted

                  --- Jerry III <jerryiii@hotma il.com> wrote:
                  [color=blue]
                  > Which means that sometimes they do not return the
                  > correct value - if you
                  > have a trigger that inserts another record you will
                  > not get the right value.[/color]

                  If you are new to PostgreSQL, as you say, then why are
                  you so sure of this? Perhaps you may profit from
                  looking a little more at how currval() works.
                  [color=blue]
                  > MSSQL has @@IDENTITY and SCOPE_IDENTITY( ) to handle
                  > this case, I'm new to
                  > pgsql so I don't know if it has anything like that.
                  >
                  > Jerry
                  >
                  > "Richard Huxton" <dev@archonet.c om> wrote in message
                  >
                  > news:4193B30B.4 0905@archonet.c om...[color=green]
                  > > MaRCeLO PeReiRA wrote:
                  > >[color=darkred]
                  > >> How can I now (for sure) with value was generated[/color][/color]
                  > by[color=green][color=darkred]
                  > >> the sequence to fill the field ID?
                  > >>
                  > >> (There is lots of users using the software at the[/color][/color]
                  > same[color=green][color=darkred]
                  > >> time, so I am not able to use the last_value()
                  > >> function on the sequence.)[/color]
                  > >
                  > > Yes you are nextval()/currval() are multi-user[/color]
                  > safe. They return the[color=green]
                  > > next/current value *in the current connection*.
                  > >
                  > > --
                  > > Richard Huxton
                  > > Archonet Ltd
                  > >
                  > > ---------------------------(end of[/color]
                  > broadcast)---------------------------[color=green]
                  > > TIP 8: explain analyze is your friend
                  > >[/color]
                  >
                  >
                  >
                  > ---------------------------(end of
                  > broadcast)---------------------------
                  > TIP 4: Don't 'kill -9' the postmaster
                  >[/color]




                  _______________ _______________ ____
                  Do you Yahoo!?
                  The all-new My Yahoo! - Get yours free!
                  Latest news coverage, email, free stock quotes, live scores and video are just the beginning. Discover more every day at Yahoo!




                  ---------------------------(end of broadcast)---------------------------
                  TIP 7: don't forget to increase your free space map settings

                  Comment

                  • Stephan Szabo

                    #10
                    Re: Last value inserted


                    On Tue, 16 Nov 2004, Jeff Eckermann wrote:
                    [color=blue]
                    > --- Jerry III <jerryiii@hotma il.com> wrote:
                    >[color=green]
                    > > Which means that sometimes they do not return the
                    > > correct value - if you
                    > > have a trigger that inserts another record you will
                    > > not get the right value.[/color]
                    >
                    > If you are new to PostgreSQL, as you say, then why are
                    > you so sure of this? Perhaps you may profit from
                    > looking a little more at how currval() works.[/color]

                    He's correct. One thing that currval will not help with is a
                    case where more than one row has been inserted by a statement
                    (whether due to the base statement or triggers).

                    A somewhat absurd example:

                    ---

                    create table q1(a serial, b int);

                    create function f1() returns trigger as 'begin if (random() >
                    0.5) then insert into q1 default values; end if; return NEW; end;'
                    language 'plpgsql';

                    create trigger q1_f1 after insert on q1 for each row execute
                    procedure f1();

                    insert into q1(b) values (3);

                    select currval('q1_a_s eq');

                    select * from q1;

                    ----

                    I got a currval of 3 which was the last row inserted, but that was from
                    the trigger, not the row created by my insert so it didn't have the
                    correct b value.

                    ---------------------------(end of broadcast)---------------------------
                    TIP 9: the planner will ignore your desire to choose an index scan if your
                    joining column's datatypes do not match

                    Comment

                    • Tom Lane

                      #11
                      Re: Last value inserted

                      Jeff Eckermann <jeff_eckermann @yahoo.com> writes:[color=blue]
                      > --- Jerry III <jerryiii@hotma il.com> wrote:[color=green]
                      >> Which means that sometimes they do not return the
                      >> correct value - if you
                      >> have a trigger that inserts another record you will
                      >> not get the right value.[/color][/color]
                      [color=blue]
                      > If you are new to PostgreSQL, as you say, then why are
                      > you so sure of this? Perhaps you may profit from
                      > looking a little more at how currval() works.[/color]

                      Jerry's correct, although the concern is more theoretical than real IMHO.
                      What he's imagining is a situation where you do, say,

                      INSERT INTO foo ...;
                      SELECT currval('foo_id _seq');

                      and there is an ON INSERT trigger on foo that directly or indirectly
                      does a nextval('foo_id _seq'). Execution of the trigger will then
                      advance the sequence beyond what was used to generate the inserted row,
                      and the subsequent currval() will return the wrong answer (or at least
                      not the answer you wanted). Note there is no race condition here; it's
                      just one process involved.

                      The reason I think this is mostly a theoretical issue is that I don't
                      see any good reason for such a trigger to be doing a nextval on the
                      table's ID sequence. The trigger is certainly not going to insert
                      additional rows in foo --- if it did that would lead to infinite
                      recursion of the trigger. So ISTM this scenario is really not
                      interesting. If it did happen it would represent a bug in your
                      application design, no more and no less. For instance, using the same
                      sequence to feed IDs for multiple tables would be a bug if you had a
                      trigger that did an insert on one of them as a consequence of an insert
                      on another.

                      regards, tom lane

                      ---------------------------(end of broadcast)---------------------------
                      TIP 9: the planner will ignore your desire to choose an index scan if your
                      joining column's datatypes do not match

                      Comment

                      Working...