Created
August 27, 2018 17:51
-
-
Save DCCoder90/c05eb38fb2b006ee2f1a378d101962c1 to your computer and use it in GitHub Desktop.
Truncate tables with respect to FKs
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
SET NOCOUNT ON | |
GO | |
DECLARE @table TABLE( | |
RowId INT PRIMARY KEY IDENTITY(1, 1), | |
ForeignKeyConstraintName NVARCHAR(200), | |
ForeignKeyConstraintTableSchema NVARCHAR(200), | |
ForeignKeyConstraintTableName NVARCHAR(200), | |
ForeignKeyConstraintColumnName NVARCHAR(200), | |
PrimaryKeyConstraintName NVARCHAR(200), | |
PrimaryKeyConstraintTableSchema NVARCHAR(200), | |
PrimaryKeyConstraintTableName NVARCHAR(200), | |
PrimaryKeyConstraintColumnName NVARCHAR(200) | |
) | |
INSERT INTO @table(ForeignKeyConstraintName, ForeignKeyConstraintTableSchema, ForeignKeyConstraintTableName, ForeignKeyConstraintColumnName) | |
SELECT | |
U.CONSTRAINT_NAME, | |
U.TABLE_SCHEMA, | |
U.TABLE_NAME, | |
U.COLUMN_NAME | |
FROM | |
INFORMATION_SCHEMA.KEY_COLUMN_USAGE U | |
INNER JOIN INFORMATION_SCHEMA.TABLE_CONSTRAINTS C | |
ON U.CONSTRAINT_NAME = C.CONSTRAINT_NAME | |
WHERE | |
C.CONSTRAINT_TYPE = 'FOREIGN KEY' | |
UPDATE @table SET | |
PrimaryKeyConstraintName = UNIQUE_CONSTRAINT_NAME | |
FROM | |
@table T | |
INNER JOIN INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS R | |
ON T.ForeignKeyConstraintName = R.CONSTRAINT_NAME | |
UPDATE @table SET | |
PrimaryKeyConstraintTableSchema = TABLE_SCHEMA, | |
PrimaryKeyConstraintTableName = TABLE_NAME | |
FROM @table T | |
INNER JOIN INFORMATION_SCHEMA.TABLE_CONSTRAINTS C | |
ON T.PrimaryKeyConstraintName = C.CONSTRAINT_NAME | |
UPDATE @table SET | |
PrimaryKeyConstraintColumnName = COLUMN_NAME | |
FROM @table T | |
INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE U | |
ON T.PrimaryKeyConstraintName = U.CONSTRAINT_NAME | |
--DROP CONSTRAINT: | |
DECLARE @dynSQL varchar(MAX); | |
DECLARE cur CURSOR FOR | |
SELECT | |
' | |
ALTER TABLE [' + ForeignKeyConstraintTableSchema + '].[' + ForeignKeyConstraintTableName + '] | |
DROP CONSTRAINT ' + ForeignKeyConstraintName + ' | |
' | |
FROM | |
@table | |
OPEN cur | |
FETCH cur into @dynSQL | |
WHILE @@FETCH_STATUS = 0 | |
BEGIN | |
exec(@dynSQL) | |
print @dynSQL | |
FETCH cur into @dynSQL | |
END | |
CLOSE cur | |
DEALLOCATE cur | |
--------------------- | |
--INSERT TRUNCATE STATEMENTS HERE | |
--------------------- | |
--ADD CONSTRAINT: | |
DECLARE cur2 CURSOR FOR | |
SELECT | |
' | |
ALTER TABLE [' + ForeignKeyConstraintTableSchema + '].[' + ForeignKeyConstraintTableName + '] | |
ADD CONSTRAINT ' + ForeignKeyConstraintName + ' FOREIGN KEY(' + ForeignKeyConstraintColumnName + ') REFERENCES [' + PrimaryKeyConstraintTableSchema + '].[' + PrimaryKeyConstraintTableName + '](' + PrimaryKeyConstraintColumnName + ') | |
' | |
FROM | |
@table | |
OPEN cur2 | |
FETCH cur2 into @dynSQL | |
WHILE @@FETCH_STATUS = 0 | |
BEGIN | |
exec(@dynSQL) | |
print @dynSQL | |
FETCH cur2 into @dynSQL | |
END | |
CLOSE cur2 | |
DEALLOCATE cur2 |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment