Get NEWSEQUENTIALID

  • Comments posted to this topic are about the item Get NEWSEQUENTIALID

  • Good idea.

    Maybe I'm missing something, but, I don't think you need @NextSequentialID at all, or the XxX column, or some other complexity in the table.

    This seems to work:

    CREATE PROCEDURE dbo.sp_NewSequentialId

    (@Id AS UNIQUEIDENTIFIER OUTPUT)

    AS

    BEGIN

    SET NOCOUNT ON;

    DECLARE @NewSequentialId AS TABLE (Id UNIQUEIDENTIFIER DEFAULT(NEWSEQUENTIALID()))

    INSERT INTO @NewSequentialId DEFAULT VALUES;

    SELECT @Id = Id

    FROM @NewSequentialId;

    END

    GO

  • thanks a lot...

    "INSERT INTO @NewSequentialId DEFAULT VALUES;"

    actually i don't know i can use DEFAULT VALUES :)-

  • Yes, that should be the right way to do.

    Thanks gil.milbauer...

    CREATE PROCEDURE dbo.sp_NewSequentialId

    (@Id AS UNIQUEIDENTIFIER OUTPUT)

    AS

    BEGIN

    SET NOCOUNT ON;

    DECLARE @NewSequentialId AS TABLE (Id UNIQUEIDENTIFIER DEFAULT(NEWSEQUENTIALID()))

    INSERT INTO @NewSequentialId DEFAULT VALUES;

    SELECT @Id = Id

    FROM @NewSequentialId;

    END

    GO

  • I think I'm missing something too...

    The purpose of the newsequentialid() is to be sequential in the context of a given table, yes? Therefore the SP would need to know the last uniqueidentifier used in a particular table in order to generate the next sequential uniqueidentifier, yes?

    Perhaps the SP would need to accept a table name as a parameter, which it would query to find the last uniqueidentifier that would then use as the 'seed' value in the temp table, then inserting a new row to get the newsequentialid.

    No?

    Sorry if I'm missing something

  • Even though it has "Sequential" in name, the values themselves are not really adjacent to each other. It's just that the next value will be greater than any previous value from the function on this computer, so there's no need to reference the last value in the table. I guess that the "sequential" part means that if you use it as a clustered key, each row will be stored sequentially in the order they were created.

  • Ok... I guess I didn't really understand how the uniqueidentifier is generated - looks like it involves a sort of hex timestamp for the first 4 octets.

    Thanks!

  • Hello SQL-ers,

    It would seem that the very exact sounding error message is misleading...

    "The newsequentialid() built-in function can only be used in a DEFAULT expression for a column of type 'uniqueidentifier' in a CREATE TABLE or ALTER TABLE statement. It cannot be combined with other operators to form a complex scalar expression."

    One of our our devs kindly disproved this by inserting into a table with a newsequentialid() default column, just by a slightly different insert syntax.

    Imagine the table has two columns, the second being the default column in question.

    I was using:

    insert [thetable] select 1

    ...which got the error msg - (oh no, I'm going to have to use newid() which causes fragmentation etc)

    Whereas he succeeded using a column list in the insert defintion, ie:

    insert [thetable] (col1) select 1

    ...which resulted in 1 in the first column and a correct newsequentialid() in the second column.

    (this is all part of manually cranking the prep of tables for some merge replication crusade :-))

  • Paul,

    It seems that you had just tried to supply the wrong number of columns in the original insert, and has nothing to do with newsequentialid() (it could have been any datatype with a default). If you don't specify the list of columns to be inserted, then SQL Server will expect all of the non-identity columns to be supplied by the subsequent value-providing clause.

    I'm surprised you didn't get this error:

    Column name or number of supplied values does not match table definition.

    Specifying the column list (always a good practice) told SQL Server which column(s) to expect and to use the default value for any other column(s).

  • Thanks for the script.

Viewing 10 posts - 1 through 9 (of 9 total)

You must be logged in to reply to this topic. Login to reply