Reverse Engineering ADTs - Part III
Foreign key constraint.
In this article we are going to see how to change ADT that is linked to columns defined as Primary and Foreign Keys. Run script 'Create two tables with PK, FK and ADT' to create two tables - dbo.tblDepartment and dbo.tblTestEmployee with Primary Key Constraints, Foreign Key Constraint and link ADT to column DepartmentId.
You can view the previous articles below:
We can see that ADT adt_IntId is linked to column DepartmentId of parent
table dbo.tblDepartment and to column DepartmentId of the child table dbo.tblTestEmployee:
select * from INFORMATION_SCHEMA.COLUMN_DOMAIN_USAGE where Table_Name in ('tblDepartment', 'tblTestEmployee')
The data type of ADT adt_IntId is integer.
select data_type from INFORMATION_SCHEMA.DOMAINS where Domain_Name = 'adt_IntId'
Now, we have a urgent request to change data type of adt_IntId from int to
bigint.
We know that we will have simular requests coming often and we decide to
write a procedure that will do
this task automatically, so we should not spend time on analyzing new coming
requests.
Here is the plan:
- Generate sql statements for create and drop Primary and Foreign Keys Constraints that are tied with columns controled by ADT and save source code
- drop all table constraints identified in step 1
- link new ADT to selected columns
- recreate all dropped constraints
This plan is implemented in stored procedure dbo.up_AlterADT.
Lets review some building blocks of the procedure dbo.up_AlterADT:
A. Here is how we can obtain information about Foreign Key Constraint using
user defined function:
declare @objname nvarchar(776) declare @ctype char(2) set @objname = 'tblTestEmployee' set @ctype = 'F' select * from dbo.ufn_helpconstraint(@objname, @ctype)
B. Here is how to generate create Foreign Key Constraint statement
using the same user defined function:
declare @TableName nvarchar(776) declare @ConstraintType char(2) set @TableName = 'tblTestEmployee' set @ConstraintType = 'F' select 'alter table ' + 'dbo.' + @TableName + ' add constraint ' + ConstraintName + ' ' + ConstraintType + ' (' + ConstraintKeys + ')' + ' ' + FkReferences from dbo.ufn_helpconstraint(@TableName, @ConstraintType)
C. Here is how to generate drop Foreign Key Constraint statement:
declare @TableName nvarchar(776) declare @ConstraintType char(2) set @TableName = 'tblTestEmployee' set @ConstraintType = 'F' select 'alter table ' + 'dbo.' + @TableName + ' drop constraint ' + ConstraintName from dbo.ufn_helpconstraint(@TableName, @ConstraintType)
D. Here is how to identify tables, primary keys and foriegn keys affected by
data type change:
declare @AdtName sysname set @AdtName = 'adt_IntId' select TC.Constraint_Type ,CU.Constraint_schema ,CU.Constraint_Name ,CU.Table_Schema ,CU.Table_Name ,CU.Column_Name from INFORMATION_SCHEMA.KEY_COLUMN_USAGE CU inner join INFORMATION_SCHEMA.TABLE_CONSTRAINTS TC on CU.Constraint_Catalog = TC.Constraint_Catalog and CU.Constraint_Schema = TC.Constraint_Schema and CU.Constraint_Name = TC.Constraint_Name and CU.Table_Catalog = TC.Table_Catalog and CU.Table_Schema = TC.Table_Schema and CU.Table_Name = TC.Table_Name and CU.Constraint_Name = TC.Constraint_Name inner join INFORMATION_SCHEMA.Columns C on CU.Column_Name = C.Column_Name and CU.Table_Catalog = C.Table_Catalog and CU.Table_Schema = C.Table_Schema and CU.Table_Name = C.Table_Name and Domain_Name = @AdtName
E. Here is how to check data type of selected column
SELECT TABLE_NAME as TableName ,COLUMN_NAME as ColumnName ,DATA_TYPE as DataType FROM INFORMATION_SCHEMA.COLUMNS WHERE Table_Name in ( 'tblTestEmployee', 'tblDepartment') and Column_Name = 'DepartmentId'
F. Here is how to create a new ADT with data type bigint
if exists( select * from systypes where [name] = 'adt_BigIntId') exec sp_droptype 'adt_BigIntId' exec sp_addtype @typename = 'adt_BigIntId' ,@phystype = 'Bigint' ,@nulltype = 'NOT NULL' ,@owner = 'dbo'
G. Here is how to see table constraints:
select * from INFORMATION_SCHEMA.TABLE_CONSTRAINTS where Table_Name in ('tblDepartment', 'tblTestEmployee')
Having all mentioned building blocks I wrote a stored procedure dbo.up_AlterADT
that will replace existing ADT with new specified ADT. Here is how to execute it:
declare @AdtName sysname set @AdtName = 'adt_IntId' declare @NewAdtName sysname set @NewAdtName = 'adt_BigIntId' exec dbo.up_AlterADT @AdtName, @NewAdtName
Here is how to check the results:
SELECT TABLE_NAME as TableName ,COLUMN_NAME as ColumnName ,DATA_TYPE as DataType FROM INFORMATION_SCHEMA.COLUMNS WHERE Table_Name in ( 'tblTestEmployee', 'tblDepartment') and Column_Name = 'DepartmentId'
Here are additional two test cases to review:
- Create self reference table with PK, FK and ADT.txt
- Create star schema with PK, FK and ADT.txt
- change ADT data type using stored procedure dbo.up_AlterADT.txt
Credits:
my wife, my kids, my teacher Ilya Petrenko
my coworkers from Viatech Inc.
sqlservercentral Forums
Links for reference: