0

I have a process which dynamically alters my SQL2K5 table structure according to changes in a published meta-data layer.

For example, if a new column needs to be added and the table has NO dependancies - the steps would be: 1. Create scripts using T-SQL for any indexes & primary keys that already exist on the table [these scripts are included below] 2. Drop the table 3. Re-create the table from the meta-layer that has the new column 4. Execute the scripts created in step#1 5. Populate the table using BulkCopy

The above is initiated via a .NET assembly and runs in 3 concurrent streams on a daily basis.

I am receiving a deadlock error in step #1 - when I access the INFORMATION_SCHEMA tables to script out the indexes/keys. I have used the hint WITH(NOLOCK) in these scripts thinking this should prevent any locking when 3 streams of these actions are running concurrently. A table can only be processed (the create or scripting) in 1 stream.

Is there something more I need to do???

Any comments greatly appreciated.

[Scripts]

ALTER Procedure [dbo].[s$spScriptPrimaryKeyForTable]
@Tablename varchar(100)
AS 


-- Get all existing primary keys
DECLARE cPK CURSOR FOR
SELECT TABLE_NAME, CONSTRAINT_NAME 
FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS WITH(NOLOCK)
WHERE upper(TABLE_NAME)=upper(@Tablename)
ORDER BY TABLE_NAME

DECLARE @PkTable SYSNAME
DECLARE @PkName SYSNAME

-- Loop through all the primary keys
OPEN cPK
FETCH NEXT FROM cPK INTO @PkTable, @PkName
WHILE (@@FETCH_STATUS = 0)
BEGIN
DECLARE @PKSQL NVARCHAR(4000) SET @PKSQL = ''
SET @PKSQL = 'ALTER TABLE ' + @PkTable + ' ADD CONSTRAINT ' + @PkName + ' PRIMARY KEY CLUSTERED ('

-- Get all columns for the current primary key
DECLARE cPKColumn CURSOR FOR
SELECT COLUMN_NAME 
FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE WITH(NOLOCK)
WHERE TABLE_NAME = @PkTable AND CONSTRAINT_NAME = @PkName
ORDER BY ORDINAL_POSITION
OPEN cPKColumn

DECLARE @PkColumn SYSNAME
DECLARE @PkFirstColumn BIT SET @PkFirstColumn = 1
-- Loop through all columns and append the sql statement
FETCH NEXT FROM cPKColumn INTO @PkColumn
WHILE (@@FETCH_STATUS = 0)
BEGIN
IF (@PkFirstColumn = 1)
SET @PkFirstColumn = 0
ELSE
SET @PKSQL = @PKSQL + ', '

SET @PKSQL = @PKSQL + @PkColumn

FETCH NEXT FROM cPKColumn INTO @PkColumn
END
CLOSE cPKColumn
DEALLOCATE cPKColumn

SET @PKSQL = @PKSQL + ')'
-- Print the primary key statement
-- PRINT @PKSQL

FETCH NEXT FROM cPK INTO @PkTable, @PkName
END
CLOSE cPK
DEALLOCATE cPK


SELECT ISNULL(@PKSQL,' ')

================

ALTER Procedure [dbo].[s$spScriptIndexesForTable]
@Tablename varchar(100)

AS 

DECLARE @RetVal varchar(4000)
SET @RetVal = ''

-- Get all existing indexes, but NOT the primary keys 
DECLARE cIX CURSOR FOR 
SELECT OBJECT_NAME(SI.Object_ID), SI.Object_ID, SI.Name, SI.Index_ID 
FROM Sys.Indexes SI WITH(NOLOCK)
LEFT JOIN INFORMATION_SCHEMA.TABLE_CONSTRAINTS TC WITH(NOLOCK) ON SI.Name = TC.CONSTRAINT_NAME AND OBJECT_NAME(SI.Object_ID) = TC.TABLE_NAME 
WHERE TC.CONSTRAINT_NAME IS NULL 
AND OBJECTPROPERTY(SI.Object_ID, 'IsUserTable') = 1 
AND upper(OBJECT_NAME(SI.Object_ID))=upper(@Tablename)
ORDER BY OBJECT_NAME(SI.Object_ID), SI.Index_ID 

DECLARE @IxTable SYSNAME 
DECLARE @IxTableID INT 
DECLARE @IxName SYSNAME 
DECLARE @IxID INT 

-- Loop through all indexes 
OPEN cIX 
FETCH NEXT FROM cIX INTO @IxTable, @IxTableID, @IxName, @IxID 
WHILE (@@FETCH_STATUS = 0) 
BEGIN 
DECLARE @IXSQL NVARCHAR(4000) 
--SET @PKSQL = '' 
SET @IXSQL = 'CREATE ' 

-- Check if the index is unique 
IF (INDEXPROPERTY(@IxTableID, @IxName, 'IsUnique') = 1) 
SET @IXSQL = @IXSQL + 'UNIQUE ' 
-- Check if the index is clustered 
IF (INDEXPROPERTY(@IxTableID, @IxName, 'IsClustered') = 1) 
SET @IXSQL = @IXSQL + 'CLUSTERED ' 

SET @IXSQL = @IXSQL + 'INDEX ' + @IxName + ' ON [' + @IxTable + '] (' 

-- Get all columns of the index 
DECLARE cIxColumn CURSOR FOR 
SELECT SC.Name,IC.[is_included_column],IC.is_descending_key 
FROM Sys.Index_Columns IC WITH(NOLOCK)
JOIN Sys.Columns SC WITH(NOLOCK) ON IC.Object_ID = SC.Object_ID AND IC.Column_ID = SC.Column_ID 
WHERE IC.Object_ID = @IxTableID AND Index_ID = @IxID 
ORDER BY IC.Index_Column_ID,IC.is_included_column 

DECLARE @IxColumn SYSNAME 
DECLARE @IxIncl bit 
DECLARE @Desc bit 
DECLARE @IxIsIncl bit set @IxIsIncl = 0 
DECLARE @IxFirstColumn BIT SET @IxFirstColumn = 1 

-- Loop throug all columns of the index and append them to the CREATE statement 
OPEN cIxColumn 
FETCH NEXT FROM cIxColumn INTO @IxColumn, @IxIncl, @Desc 
WHILE (@@FETCH_STATUS = 0) 
BEGIN 

IF (@IxFirstColumn = 1) 
BEGIN 
SET @IxFirstColumn = 0 
END 
ELSE 
BEGIN 
--check to see if it's an included column 
IF ((@IxIsIncl = 0) AND (@IxIncl = 1)) 
BEGIN 
SET @IxIsIncl = 1 
SET @IXSQL = @IXSQL + ') INCLUDE (' 
END 
ELSE 
BEGIN 
SET @IXSQL = @IXSQL + ', ' 
END 
END 

SET @IXSQL = @IXSQL + '[' + @IxColumn + ']' 
--check to see if it's DESC 
IF @Desc = 1 
SET @IXSQL = @IXSQL + ' DESC' 

FETCH NEXT FROM cIxColumn INTO @IxColumn, @IxIncl, @Desc 
END 
CLOSE cIxColumn 
DEALLOCATE cIxColumn 

SET @IXSQL = @IXSQL + ')' 

-- Print out the CREATE statement for the index 
--SELECT 'IXSQL: ' + @IXSQL
IF @RetVal IS NULL
SET @RetVal = ''
--SELECT 'Retval: ' + @RetVal
SET @RetVal = @RetVal + @IXSQL + ' ' 

FETCH NEXT FROM cIX INTO @IxTable, @IxTableID, @IxName, @IxID 
END 

CLOSE cIX 
DEALLOCATE cIX 

SELECT ISNULL(@RetVal,' ')
simon
  • 3
  • 1
  • 3
  • Which procedure is causing the deadlock, the one that scripts the primary keys, or the one that scripts the indexes? Why are you using INFORMATION_SCHEMA, INDEXPROPERTY etc. instead of sys.key_constraints, sys.index_columns, sys.indexes.is_clustered, etc.? – Aaron Bertrand Aug 08 '11 at 00:43

1 Answers1

1
  1. INFORMATION_SCHEMA views are just that - views. You can't update them so they are unlikely to cause any deadlocks. If you want to determine the real source (which I assume has something to do with your alters, or other code within the cursor that you didn't show, or other code you're calling in combination with calling these procedures - since selects against views and then selecting variables can't be the cause), I suggest reading Gail Shaw's blog post on interpreting deadlocks.

  2. In spite of (1) I still suggest using more modern catalog views than INFORMATION_SCHEMA. The same information can be derived from, for example, sys.key_constraints.

  3. You're using the default cursor options; and you're nesting cursors. If you end up still using cursors, you should get in the habit of using a less resource intensive cursor (e.g. LOCAL STATIC FORWARD_ONLY READ_ONLY).

  4. You don't actually need a cursor to do this. Here is how I would re-write the PK table script:

    CREATE PROCEDURE dbo.ScriptPKForTable
        @TableName SYSNAME
    AS
    BEGIN
        SET NOCOUNT ON;
    
        DECLARE 
          @pkName    SYSNAME,
          @clustered BIT,
          @object_id INT,
          @sql       NVARCHAR(MAX);
    
        SELECT
          @object_id = OBJECT_ID(UPPER(@TableName));
    
        SELECT
          @pkName = kc.name,
          @clustered = CASE i.[type] 
            WHEN 1 THEN 1 ELSE 0 END
        FROM 
            sys.key_constraints AS kc
        INNER JOIN 
            sys.indexes AS i
            ON kc.parent_object_id = i.[object_id]
            AND kc.unique_index_id = i.index_id
        WHERE
            kc.parent_object_id = @object_id
            AND kc.[type] = 'pk';
    
        SET @sql = N'ALTER TABLE ' + QUOTENAME(@TableName)
          + ' ADD CONSTRAINT ' + @pkName 
          + ' PRIMARY KEY ' + CASE @clustered 
          WHEN 1 THEN 'CLUSTERED' ELSE '' END + ' (';
    
        SELECT
          @sql = @sql + c.name + ','
        FROM 
          sys.index_columns AS ic
        INNER JOIN
          sys.indexes AS i 
          ON ic.index_id = i.index_id
          AND ic.[object_id] = i.[object_id]
        INNER JOIN 
          sys.key_constraints AS kc
          ON i.[object_id] = kc.[parent_object_id]
          AND kc.unique_index_id = i.index_id
        INNER JOIN 
          sys.columns AS c
          ON i.[object_id] = c.[object_id]
          AND ic.column_id = c.column_id
        WHERE
          kc.[type] = 'PK'
          AND kc.parent_object_id = @object_id
        ORDER BY key_ordinal;
    
        SET @sql = LEFT(@sql, LEN(@sql) - 1) + ');';
    
        SELECT COALESCE(@sql, ' ');
    END
    GO
    

As for the index creation script, I think there is a better way to do this (again without explicit cursors, not that avoiding the cursor is the goal, but the code is going to be a LOT cleaner). First you need a function to build either key or include columns from the index:

CREATE FUNCTION dbo.BuildIndexColumns
(
    @object_id        INT,
    @index_id         INT,
    @included_columns BIT
)
RETURNS NVARCHAR(MAX)
AS
BEGIN
  DECLARE @s NVARCHAR(MAX);

  SELECT @s = N'';

  SELECT @s = @s + c.name + CASE ic.is_descending_key
    WHEN 1 THEN ' DESC' ELSE '' END + ',' 
    FROM sys.index_columns AS ic
    INNER JOIN sys.columns AS c
    ON ic.[object_id] = c.[object_id]
    AND ic.column_id = c.column_id
    WHERE c.[object_id] = @object_id
    AND ic.[object_id] = @object_id
    AND ic.index_id = @index_id
    AND ic.is_included_column = @included_columns
    ORDER BY ic.key_ordinal;

  IF @s > N''
    SET @s = LEFT(@s, LEN(@s)-1);

  RETURN (NULLIF(@s, N''));
END
GO

With that function in place, a ScriptIndexes procedure is pretty easy:

CREATE PROCEDURE dbo.ScriptIndexesForTable
    @TableName SYSNAME
AS
BEGIN
  SET NOCOUNT ON;

  DECLARE
      @sql       NVARCHAR(MAX),
      @object_id INT;

  SELECT @sql = N'', @object_id = OBJECT_ID(UPPER(@TableName));

  SELECT @sql = @sql + 'CREATE '
      + CASE i.is_unique WHEN 1 THEN 'UNIQUE ' ELSE '' END
      + CASE i.[type] WHEN 1 THEN 'CLUSTERED ' ELSE '' END
      + ' INDEX ' + i.name + ' ON ' + QUOTENAME(@TableName) + ' (' 
      + dbo.BuildIndexColumns(@object_id, i.index_id, 0)
      + ')' + COALESCE(' INCLUDE(' 
      + dbo.BuildIndexColumns(@object_id, i.index_id, 1)
      + ')', '') + ';' + CHAR(13) + CHAR(10)
  FROM
      sys.indexes AS i
  WHERE
      i.[object_id] = @object_id
      -- since this will be covered by ScriptPKForTable:
      AND i.is_primary_key = 0
  ORDER BY i.index_id;

  SELECT COALESCE(@sql, ' ');
END
GO

Note that my solution does not assume the PK is clustered (your PK script hard-codes CLUSTERED but then your index script assumes that any of the indexes could be clustered). I also ignore additional properties such as filegroup, partitioning, or filtered indexes (not supported in 2005 anyway).

Aaron Bertrand
  • 272,866
  • 37
  • 466
  • 490
  • Thanks for your comments & script Aaron! (I’m definitely interested to see your index creation script) The error originates from the scripting procedure rather than one that creates/alters the tables - which does sound odd if you’re confident that calling these views shouldn’t have an impact. However, I can’t tell from my logs whether it bombs on the call to the indexes or primary key stored proc. – simon Aug 08 '11 at 02:12
  • When I construct my CREATE TABLE script I start with the following: 'Construct SQL tsql = "USE [" & info.SQLServerDestDatabase & "] " & vbNewLine tsql &= "SET ANSI_NULLS ON " & vbNewLine tsql &= "SET QUOTED_IDENTIFIER ON " & vbNewLine tsql &= "CREATE TABLE [dbo].[" & info.SQLServerDestTableName & "](" & vbNewLine ... I then simply execute the statement using: SqlHelper.ExecuteNonQuery(sqlConnString, CommandType.Text, tsql) Is there something I could do protect against a deadlock leading up to this point? – simon Aug 08 '11 at 02:13
  • Again, I'm not seeing anything in your comment that would yell out "deadlock! deadlock!" You're going to have to pin it down more accurately than just guessing at which part of the script is leading to deadlocks. In both cases, your stored procedures are just running a SELECT after building the cursors, so it must be elsewhere (I suspect AFTER you've called the procedures). The first thing to do would be to fix your cursors... – Aaron Bertrand Aug 08 '11 at 02:20
  • Ok - I've switched on a 1222 trace. Hopefully we'll get some further info out of that. Thanks Aaron. – simon Aug 08 '11 at 02:53
  • I've updated my answer to include a procedure for generating index creation scripts for a given table (with some caveats, and a companion function for building each column list for key and include columns). – Aaron Bertrand Aug 08 '11 at 02:57
  • Hi Aaron...the deadlock ocurred again and the trace output follows. Does anything scream out to you? Date,Source,Severity,Message 08/11/2011 22:00:31,spid16s,Unknown,waiter id=process9492e8 mode=X requestType=convert 08/11/2011 22:00:31,spid16s,Unknown,waiter-list 08/11/2011 22:00:31,spid16s,Unknown,owner id=processdcde28 mode=S 08/11/2011 22:00:31,spid16s,Unknown,owner-list – simon Aug 11 '11 at 20:45
  • 08/11/2011 22:00:31,spid16s,Unknown,keylock hobtid=281474980249600 dbid=17 objectname=SER DB Foundation HB.sys.sysidxstats indexname=clst id=lock53b0ab00 mode=U associatedObjectId=281474980249600 08/11/2011 22:00:31,spid16s,Unknown,waiter id=processdcde28 mode=Sch-S requestType=wait 08/11/2011 22:00:31,spid16s,Unknown,waiter-list 08/11/2011 22:00:31,spid16s,Unknown,owner id=process9492e8 mode=Sch-M 08/11/2011 22:00:31,spid16s,Unknown,owner-list 08/11/2011 22:00:31,spid16s,Unknown,objectlock lockPartition=0 objid=1360085423 subresource=FULL dbid=17 objectname=1360085423 id=lock505f2b00 – simon Aug 11 '11 at 20:46
  • mode=Sch-M associatedObjectId=1360085423 08/11/2011 22:00:31,spid16s,Unknown,resource-list 08/11/2011 22:00:31,spid16s,Unknown,Proc [Database Id = 17 Object Id = 252579988] 08/11/2011 22:00:31,spid16s,Unknown,inputbuf 08/11/2011 22:00:31,spid16s,Unknown,OPEN cIX – simon Aug 11 '11 at 20:46
  • 08/11/2011 22:00:31,spid16s,Unknown,frame procname=SER DB Foundation HB.dbo.s$spScriptIndexesForTable line=29 stmtstart=1646 stmtend=1666 sqlhandle=0x0300110094100e0f381de7009a9d00000100000000000000 08/11/2011 22:00:31,spid16s,Unknown,executionStack – simon Aug 11 '11 at 20:47
  • 08/11/2011 22:00:31,spid16s,Unknown,process id=processdcde28 taskpriority=0 logused=0 waitresource=OBJECT: 17:1360085423:0 waittime=2890 ownerId=53264291 transactionname=I4ObjPropI4Str lasttranstarted=2011-08-11T22:00:28.570 XDES=0x1121c8d0 lockMode=Sch-S schedulerid=8 kpid=828 status=suspended spid=134 sbid=0 ecid=0 priority=0 transcount=0 lastbatchstarted=2011-08-11T22:00:28.553 lastbatchcompleted=2011-08-11T22:00:28.553 clientapp=.Net SqlClient Data Provider hostname=SCEIS hostpid=8268 loginname=SXBS1\sqlservice isolationlevel=read committed (2) xactid=53263711 – simon Aug 11 '11 at 20:48
  • currentdb=17 lockTimeout=4294967295 clientoption1=671088672 clientoption2=128056 08/11/2011 22:00:31,spid16s,Unknown,DROP TABLE [dbo].[s$tblAnalysisCodes] 08/11/2011 22:00:31,spid16s,Unknown,USE [SER DB Foundation HB] 08/11/2011 22:00:31,spid16s,Unknown,inputbuf 08/11/2011 22:00:31,spid16s,Unknown,DROP TABLE [dbo].[s$tblAnalysisCodes] 08/11/2011 22:00:31,spid16s,Unknown,frame procname=adhoc line=2 stmtstart=56 sqlhandle=0x01001100e191ce0b0058a234000000000000000000000000 – simon Aug 11 '11 at 20:49
  • 08/11/2011 22:00:31,spid16s,Unknown,executionStack – simon Aug 11 '11 at 20:50
  • 08/11/2011 22:00:31,spid16s,Unknown,process id=process9492e8 taskpriority=0 logused=2224 waitresource=KEY: 17:281474980249600 (b0005bfb897e) waittime=2875 ownerId=53264105 transactionname=DROPOBJ lasttranstarted=2011-08-11T22:00:28.570 XDES=0xc52cfd0 lockMode=X schedulerid=2 kpid=9452 status=suspended spid=156 sbid=0 ecid=0 priority=0 transcount=2 lastbatchstarted=2011-08-11T22:00:28.570 lastbatchcompleted=2011-08-11T22:00:28.570 clientapp=.Net SqlClient Data Provider hostname=SCEIS hostpid=8268 loginname=SXBS1 – simon Aug 11 '11 at 20:50
  • currentdb=17 lockTimeout=4294967295 clientoption1=671088672 clientoption2=128056 08/11/2011 22:00:31,spid16s,Unknown,process-list 08/11/2011 22:00:31,spid16s,Unknown,deadlock victim=processdcde28 08/11/2011 22:00:31,spid16s,Unknown,deadlock-list – simon Aug 11 '11 at 20:50