• sandeep.pote (9/23/2008)


    We can add constraints on table variable like primary key, unique key and chekc constraints etc ...

    ...

    We cannot create non clustered index on table variable ...

    Just to clarify this statement (again!):

    Both PKs and UNIQUE constraints are backed by indexes. By default, UNIQUE constraints are backed by nonclustered indexes. So by creating one of these constraints, you are in fact creating a nonclustered index. Therefore, it's fair to say that you can create both clustered and nonclustered indexes on a table variable.

    Need a non-unique index? No problem, just use an IDENTITY column as a "uniquifier"...

    DECLARE @n TABLE

    (

    x INT NOT NULL,

    y INT IDENTITY(1,1) NOT NULL,

    PRIMARY KEY(x,y)

    )

    The IDENTITY column will of course increase the row size, so if you do this and you won't be inserting more than ~64,000 rows, consider using SMALLINT rather than INT (you can seed the IDENTITY with -32,000 to give yourself more room).

    --
    Adam Machanic
    whoisactive