Pages

Friday, December 30, 2016

Code to generate all foreign keys of SQL Server database

How to draft all the foreign keys of SQL Server database


DBA do end up in a situation where we need to copy all the foreign keys of the SQL Server to perform certain operations.

Like:

Archiving activity (When data is not consistent and gives constraint error when deleting records)
Recreating database due to fail over
Multiple publications going under re snapshot due to a release work
Any other application demand due to which FK's have to remove and then recreated.

Generally we do take a full backup of the database for any of the activities that are mentioned above, but that would should be last scenario where have to use the full backup restore method as it is time consuming.

Take the backup of entire FK's is better approach and then compare it once any of the above activity  is done. We can easily put back the missing FK's so that application logic is undisturbed.

Please use the below code to generate all the FK's in the entire database. A simple action keyword will create two kinds of scripts.


DECLARE @schema_name sysname;
DECLARE @table_name sysname;
DECLARE @constraint_name sysname;
DECLARE @constraint_object_id int;
DECLARE @referenced_object_name sysname;
DECLARE @is_disabled bit;
DECLARE @is_not_for_replication bit;
DECLARE @is_not_trusted bit;
DECLARE @delete_referential_action tinyint;
DECLARE @update_referential_action tinyint;
DECLARE @tsql nvarchar(4000);
DECLARE @tsql2 nvarchar(4000);
DECLARE @fkCol sysname;
DECLARE @pkCol sysname;
DECLARE @col1 bit;
DECLARE @action char(6);

--SET @action = 'DROP';
--SET @action = 'CREATE';

DECLARE FKcursor CURSOR FOR
select OBJECT_SCHEMA_NAME(parent_object_id)
, OBJECT_NAME(parent_object_id), name, OBJECT_NAME(referenced_object_id)
, object_id
, is_disabled, is_not_for_replication, is_not_trusted
, delete_referential_action, update_referential_action
from sys.foreign_keys
order by 1,2;

OPEN FKcursor;

FETCH NEXT FROM FKcursor INTO @schema_name, @table_name, @constraint_name
, @referenced_object_name, @constraint_object_id
, @is_disabled, @is_not_for_replication, @is_not_trusted
, @delete_referential_action, @update_referential_action;

WHILE @@FETCH_STATUS = 0
BEGIN
    IF @action <> 'CREATE'
        SET @tsql = 'ALTER TABLE '
                  + QUOTENAME(@schema_name) + '.' + QUOTENAME(@table_name)
                  + ' DROP CONSTRAINT ' + QUOTENAME(@constraint_name) + ';';
    ELSE
        BEGIN
        SET @tsql = 'ALTER TABLE '
                  + QUOTENAME(@schema_name) + '.' + QUOTENAME(@table_name)
                  + CASE @is_not_trusted
 WHEN 0 THEN ' WITH CHECK '
     ELSE ' WITH NOCHECK '
END
         + ' ADD CONSTRAINT ' + QUOTENAME(@constraint_name)
 + ' FOREIGN KEY ('

        SET @tsql2 = '';

DECLARE ColumnCursor CURSOR FOR
select COL_NAME(fk.parent_object_id, fkc.parent_column_id)
, COL_NAME(fk.referenced_object_id, fkc.referenced_column_id)
from sys.foreign_keys fk
inner join sys.foreign_key_columns fkc
on fk.object_id = fkc.constraint_object_id
where fkc.constraint_object_id = @constraint_object_id
order by fkc.constraint_column_id;
OPEN ColumnCursor;
SET @col1 = 1;
FETCH NEXT FROM ColumnCursor INTO @fkCol, @pkCol;
WHILE @@FETCH_STATUS = 0
BEGIN
   IF (@col1 = 1)
   SET @col1 = 0
ELSE
BEGIN
SET @tsql = @tsql + ',';
SET @tsql2 = @tsql2 + ',';
END;
   SET @tsql = @tsql + QUOTENAME(@fkCol);
SET @tsql2 = @tsql2 + QUOTENAME(@pkCol);
FETCH NEXT FROM ColumnCursor INTO @fkCol, @pkCol;
END;
CLOSE ColumnCursor;
DEALLOCATE ColumnCursor;

SET @tsql = @tsql + ' ) REFERENCES ' + QUOTENAME(@schema_name) + '.' + QUOTENAME(@referenced_object_name)+ ' (' + @tsql2 + ')';          
    SET @tsql = @tsql+ ' ON UPDATE ' +
CASE
@update_referential_action
WHEN 0 THEN 'NO ACTION '
    WHEN 1 THEN 'CASCADE '
    WHEN 2 THEN 'SET NULL '
    ELSE 'SET DEFAULT '
    END
    + ' ON DELETE ' +
CASE
@delete_referential_action
    WHEN 0 THEN 'NO ACTION '
    WHEN 1 THEN 'CASCADE '
    WHEN 2 THEN 'SET NULL '
    ELSE 'SET DEFAULT '
    END
    + CASE
@is_not_for_replication
    WHEN 1 THEN ' NOT FOR REPLICATION '
    ELSE ''
    END
    + ';';
  END;

PRINT @tsql;

IF @action = 'CREATE'
BEGIN
SET @tsql = 'ALTER TABLE '
        + QUOTENAME(@schema_name) + '.' + QUOTENAME(@table_name)
        + CASE @is_disabled
        WHEN 0 THEN ' CHECK '
        ELSE ' NOCHECK '
        END
        + 'CONSTRAINT ' + QUOTENAME(@constraint_name)
        + ';';
        PRINT @tsql;
        END;

    FETCH NEXT FROM FKcursor INTO @schema_name, @table_name, @constraint_name
        , @referenced_object_name, @constraint_object_id
        , @is_disabled, @is_not_for_replication, @is_not_trusted
        , @delete_referential_action, @update_referential_action;

END;

CLOSE FKcursor;
DEALLOCATE FKcursor;