Return Primary Key on INSERT statement

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

    Return Primary Key on INSERT statement

    I am inserting a record into a table that automatically generates
    unique ids (i.e. Primary Key). Is there anyway to return this id. As I
    am using this on ASP.net page and I really need the ID to update the
    page with the new details.

    I think on mysql there is something called LAST_INSERT_ID which does
    this.
  • Dan Guzman

    #2
    Re: Return Primary Key on INSERT statement

    So this is an IDENTITY column? In this case, you can use SCOPE_IDENTITY( )
    in SQL 2000 to return the last identity value generated on the current
    connection. With SQL 7 and earlier, you can use @@IDENTITY but the value
    will reflect identity values resulting from trigger inserts as well.

    --
    Hope this helps.

    Dan Guzman
    SQL Server MVP

    "ree32" <ree32@hotmail. com> wrote in message
    news:7606ccc8.0 410171625.610ef a24@posting.goo gle.com...[color=blue]
    >I am inserting a record into a table that automatically generates
    > unique ids (i.e. Primary Key). Is there anyway to return this id. As I
    > am using this on ASP.net page and I really need the ID to update the
    > page with the new details.
    >
    > I think on mysql there is something called LAST_INSERT_ID which does
    > this.[/color]


    Comment

    • ree32

      #3
      Re: Return Primary Key on INSERT statement

      Can you give an example with a set of values and column names as I am
      not sure how to use this statement.

      "Dan Guzman" <guzmanda@nospa m-online.sbcgloba l.net> wrote in message news:<tDEcd.694 5$Al3.4284@news svr30.news.prod igy.com>...[color=blue]
      > So this is an IDENTITY column? In this case, you can use SCOPE_IDENTITY( )
      > in SQL 2000 to return the last identity value generated on the current
      > connection. With SQL 7 and earlier, you can use @@IDENTITY but the value
      > will reflect identity values resulting from trigger inserts as well.
      >
      > --
      > Hope this helps.
      >
      > Dan Guzman
      > SQL Server MVP[/color]

      Comment

      • Dan Guzman

        #4
        Re: Return Primary Key on INSERT statement

        Here's an example that inserts a row using a proc with the generated value
        returned as a single-row, single-column result

        CREATE TABLE MyTable
        (
        MyPK int NOT NULL IDENTITY(1,1)
        CONSTRAINT PK_MyTable PRIMARY KEY,
        MyData int NOT NULL
        )
        GO

        CREATE PROC MyProc
        @MyData int
        AS
        SET NOCOUNT ON
        INSERT INTO MyTable (MyData) VALUES(1)
        SELECT SCOPE_IDENTITY( )
        GO

        EXEC MyProc @MyData = 1
        GO

        --
        Hope this helps.

        Dan Guzman
        SQL Server MVP

        "ree32" <ree32@hotmail. com> wrote in message
        news:7606ccc8.0 410181617.3661b f4e@posting.goo gle.com...[color=blue]
        > Can you give an example with a set of values and column names as I am
        > not sure how to use this statement.
        >
        > "Dan Guzman" <guzmanda@nospa m-online.sbcgloba l.net> wrote in message
        > news:<tDEcd.694 5$Al3.4284@news svr30.news.prod igy.com>...[color=green]
        >> So this is an IDENTITY column? In this case, you can use
        >> SCOPE_IDENTITY( )
        >> in SQL 2000 to return the last identity value generated on the current
        >> connection. With SQL 7 and earlier, you can use @@IDENTITY but the value
        >> will reflect identity values resulting from trigger inserts as well.
        >>
        >> --
        >> Hope this helps.
        >>
        >> Dan Guzman
        >> SQL Server MVP[/color][/color]


        Comment

        • Damien

          #5
          Re: Return Primary Key on INSERT statement

          "Dan Guzman" <guzmanda@nospa m-online.sbcgloba l.net> wrote in message news:<tDEcd.694 5$Al3.4284@news svr30.news.prod igy.com>...[color=blue]
          > So this is an IDENTITY column? In this case, you can use SCOPE_IDENTITY( )
          > in SQL 2000 to return the last identity value generated on the current
          > connection. With SQL 7 and earlier, you can use @@IDENTITY but the value
          > will reflect identity values resulting from trigger inserts as well.
          >
          > --
          > Hope this helps.
          >
          > Dan Guzman
          > SQL Server MVP
          >
          > "ree32" <ree32@hotmail. com> wrote in message
          > news:7606ccc8.0 410171625.610ef a24@posting.goo gle.com...[color=green]
          > >I am inserting a record into a table that automatically generates
          > > unique ids (i.e. Primary Key). Is there anyway to return this id. As I
          > > am using this on ASP.net page and I really need the ID to update the
          > > page with the new details.
          > >
          > > I think on mysql there is something called LAST_INSERT_ID which does
          > > this.[/color][/color]

          Can you help me - I'm starting to think I'm going insane:

          Last year, after spending several days trying to debug a few stored
          procedures, we stumbled accross a bug in SQL 7 where @@IDENTITY
          returned the wrong value if the table you'd just inserted into had a
          self-referencing foreign key.

          So I went through the stored procedure generator (code and sp
          generator to create our data access layer) and added a whole load of
          defensive coding in that detected that it was running on SQL 7 and
          "corrected" the return value by subtracting the number of self-ref
          foreign keys. This all worked fine for a while, and then stopped
          working (being in error on the low side now instead) so we removed
          this code, and everything has been fine since.

          My only question is, does anyone know when/what corrected this bug,
          since I cant seem to find it in any of the patch documents?

          As a side note to the OP, who Asked how to use the @@IDENTITY, do the
          following:

          INSERT INTO tblBlah1 (Col1,Col2,Col3 ) VALUES (Val1,Val2,Val3 );

          SELECT @@IDENTITY

          (If you want to have it returned in a result set of one row/one
          column) or

          SET @Variable = @@IDENTITY

          (If you want to store the value in a variable)

          Comment

          • Dan Guzman

            #6
            Re: Return Primary Key on INSERT statement

            > Last year, after spending several days trying to debug a few stored[color=blue]
            > procedures, we stumbled accross a bug in SQL 7 where @@IDENTITY
            > returned the wrong value if the table you'd just inserted into had a
            > self-referencing foreign key.[/color]

            This looks like the bug described in MSKB 322818
            <http://support.microso ft.com/default.aspx?sc id=kb;en-us;322818>.
            [color=blue]
            > So I went through the stored procedure generator (code and sp
            > generator to create our data access layer) and added a whole load of
            > defensive coding in that detected that it was running on SQL 7 and
            > "corrected" the return value by subtracting the number of self-ref
            > foreign keys. This all worked fine for a while, and then stopped
            > working (being in error on the low side now instead) so we removed
            > this code, and everything has been fine since.[/color]

            The work-around suggested in the article is to remove the self-referencing
            foreign key(s) rather than manually adjust the value returned by @@IDENTITY.
            You can use an insert trigger to enforce referential integrity instead.
            This way, you won't have to change your code if/when the bug is fixed in SQL
            7 or you upgrade to SQL 2000.
            [color=blue]
            > My only question is, does anyone know when/what corrected this bug,
            > since I cant seem to find it in any of the patch documents?[/color]

            Particularly with hotfixes, bugs may get addressed (or introduced) without
            accompanying documentation and this may happen with service packs as well.
            This is why one should regression test fixes before applying to production.

            I don't have a SQL 7 box handy to test this on but I can try to find out
            more information. What service pack/patch level are you running?

            --
            Hope this helps.

            Dan Guzman
            SQL Server MVP


            Comment

            • ree32

              #7
              Re: Return Primary Key on INSERT statement

              So you cannot use these SQL statements from ASP.net pages. i.e you
              have to create the procedures on the SQL server?

              "Dan Guzman" <guzmanda@nospa m-online.sbcgloba l.net> wrote in message news:<vr0dd.755 0$q%7.1727@news svr11.news.prod igy.com>...[color=blue]
              > Here's an example that inserts a row using a proc with the generated value
              > returned as a single-row, single-column result
              >
              > CREATE TABLE MyTable
              > (
              > MyPK int NOT NULL IDENTITY(1,1)
              > CONSTRAINT PK_MyTable PRIMARY KEY,
              > MyData int NOT NULL
              > )
              > GO
              >
              > CREATE PROC MyProc
              > @MyData int
              > AS
              > SET NOCOUNT ON
              > INSERT INTO MyTable (MyData) VALUES(1)
              > SELECT SCOPE_IDENTITY( )
              > GO
              >
              > EXEC MyProc @MyData = 1
              > GO
              >
              > --
              > Hope this helps.
              >
              > Dan Guzman
              > SQL Server MVP
              >
              >[/color]

              Comment

              • Dan Guzman

                #8
                Re: Return Primary Key on INSERT statement

                > So you cannot use these SQL statements from ASP.net pages. i.e you[color=blue]
                > have to create the procedures on the SQL server?[/color]

                You can also run the INSERT/SELECT script directly from your code:

                SET NOCOUNT ON
                INSERT INTO MyTable (MyData) VALUES(1)
                SELECT SCOPE_IDENTITY( )

                --
                Hope this helps.

                Dan Guzman
                SQL Server MVP

                "ree32" <ree32@hotmail. com> wrote in message
                news:7606ccc8.0 410191712.6f14e 3d5@posting.goo gle.com...[color=blue]
                > So you cannot use these SQL statements from ASP.net pages. i.e you
                > have to create the procedures on the SQL server?
                >
                > "Dan Guzman" <guzmanda@nospa m-online.sbcgloba l.net> wrote in message
                > news:<vr0dd.755 0$q%7.1727@news svr11.news.prod igy.com>...[color=green]
                >> Here's an example that inserts a row using a proc with the generated
                >> value
                >> returned as a single-row, single-column result
                >>
                >> CREATE TABLE MyTable
                >> (
                >> MyPK int NOT NULL IDENTITY(1,1)
                >> CONSTRAINT PK_MyTable PRIMARY KEY,
                >> MyData int NOT NULL
                >> )
                >> GO
                >>
                >> CREATE PROC MyProc
                >> @MyData int
                >> AS
                >> SET NOCOUNT ON
                >> INSERT INTO MyTable (MyData) VALUES(1)
                >> SELECT SCOPE_IDENTITY( )
                >> GO
                >>
                >> EXEC MyProc @MyData = 1
                >> GO
                >>
                >> --
                >> Hope this helps.
                >>
                >> Dan Guzman
                >> SQL Server MVP
                >>
                >>[/color][/color]


                Comment

                • Damien

                  #9
                  Re: Return Primary Key on INSERT statement

                  "Dan Guzman" <guzmanda@nospa m-online.sbcgloba l.net> wrote in message news:<zu8dd.764 5$q%7.2314@news svr11.news.prod igy.com>...[color=blue][color=green]
                  > > Last year, after spending several days trying to debug a few stored
                  > > procedures, we stumbled accross a bug in SQL 7 where @@IDENTITY
                  > > returned the wrong value if the table you'd just inserted into had a
                  > > self-referencing foreign key.[/color]
                  >
                  > This looks like the bug described in MSKB 322818
                  > <http://support.microso ft.com/default.aspx?sc id=kb;en-us;322818>.
                  >[/color]
                  It was indeed this bug. I was just curious if anyone knew when/where
                  it was fixed, but I'm not going to worry about it too badly
                  (especially since I lost SA/DBO access on most of the boxes recently,
                  so dont have access to nearly so much information :-()

                  Comment

                  • ree32

                    #10
                    Re: Return Primary Key on INSERT statement

                    Thank you so much. IT works!!!

                    "Dan Guzman" <guzmanda@nospa m-online.sbcgloba l.net> wrote in message news:<WXsdd.789 9$q%7.7112@news svr11.news.prod igy.com>...[color=blue][color=green]
                    > > So you cannot use these SQL statements from ASP.net pages. i.e you
                    > > have to create the procedures on the SQL server?[/color]
                    >
                    > You can also run the INSERT/SELECT script directly from your code:
                    >
                    > SET NOCOUNT ON
                    > INSERT INTO MyTable (MyData) VALUES(1)
                    > SELECT SCOPE_IDENTITY( )
                    >
                    > --
                    > Hope this helps.
                    >
                    > Dan Guzman
                    > SQL Server MVP[/color]

                    Comment

                    • Dan Guzman

                      #11
                      Re: Return Primary Key on INSERT statement

                      I'm glad I was able to help you out.

                      --
                      Dan Guzman
                      SQL Server MVP

                      "ree32" <ree32@hotmail. com> wrote in message
                      news:7606ccc8.0 410211556.4dadb 53f@posting.goo gle.com...[color=blue]
                      > Thank you so much. IT works!!!
                      >
                      > "Dan Guzman" <guzmanda@nospa m-online.sbcgloba l.net> wrote in message
                      > news:<WXsdd.789 9$q%7.7112@news svr11.news.prod igy.com>...[color=green][color=darkred]
                      >> > So you cannot use these SQL statements from ASP.net pages. i.e you
                      >> > have to create the procedures on the SQL server?[/color]
                      >>
                      >> You can also run the INSERT/SELECT script directly from your code:
                      >>
                      >> SET NOCOUNT ON
                      >> INSERT INTO MyTable (MyData) VALUES(1)
                      >> SELECT SCOPE_IDENTITY( )
                      >>
                      >> --
                      >> Hope this helps.
                      >>
                      >> Dan Guzman
                      >> SQL Server MVP[/color][/color]


                      Comment

                      Working...