Commit ac35c6ff authored by dwentzel's avatar dwentzel

adding UntrustedForeignKeys.sql

parent 580591f4
/*
UntrustedForeignKeys.sql
http://www.davewentzel.com/content/find-and-fix-untrusted-foreign-keys
This script determines which FKs are not trusted
It then determines if it can make them trusted. You can modify the script to actually do the trusting.
Otherwise it constructs the query and output to tell the DBA why the constraints are failing validation
It is always best to determine WHY your constraints are not trusted, but this script can help you trust those
constraints that can be trusted.
This script only handles single-column foreign keys.
*/
declare @oops int
PRINT 'Server:' + @@servername
PRINT 'Database: ' + db_name()
select @oops = COUNT(*) from sys.foreign_keys
PRINT 'There are ' + convert(varchar(200),@oops) + ' FKs in this database.'
GO
PRINT ''
PRINT ''
PRINT ''
GO
declare @exec_str varchar(4000)
,@exec_str2 varchar(4000)
,@exec_str3 varchar(4000)
,@FKName varchar(2000)
,@tblname varchar(200)
,@ReferencedTable varchar(200)
,@FKColName varchar(200)
,@ParentTableColName varchar(200) , @Sch varchar(200)
declare fk cursor for
--this will only handle single column foreign keys
select
fk.name AS FKName,
OBJECT_NAME(fk.parent_object_id) AS tblname,
object_name(fk.referenced_object_id) AS ReferencedTable,
parentcol.Name AS FKColName,
ReferencedCol.Name AS ParentTableColName,
schema_name(fk.schema_id) AS Sch
from sys.foreign_keys fk
join sys.foreign_key_columns fkc
on fk.object_id = fkc.constraint_object_id
join sys.columns parentcol
on fkc.parent_object_id = parentcol.object_id
and fkc.parent_column_id = parentcol.column_id
join sys.columns ReferencedCol
on fkc.referenced_object_id = ReferencedCol.object_id
and fkc.referenced_column_id = ReferencedCol.column_id
where is_not_trusted = 1
open fk
fetch next from fk into
@FKName
,@tblname
,@ReferencedTable
,@FKColName
,@ParentTableColName ,@Sch
while @@FETCH_STATUS = 0
BEGIN
PRINT '--------------------------------------------------------------'
PRINT 'FK ' + @FKName + ' is not trusted.'
SELECT @exec_str = '', @exec_str2 = '', @exec_str3 = ''
SELECT @exec_str2 = '
SELECT count(1)
FROM ' + @Sch + '.' + @tblname + ' par WITH (NOLOCK)
LEFT JOIN ' + @ReferencedTable + ' chld WITH (NOLOCK)
ON par.' + @FKColName + ' = chld.' + @ParentTableColName
SELECT @exec_str2 = @exec_str2 + ' WHERE chld.' + @ParentTableColName + ' IS NULL AND par.' + @FKColName + ' IS NOT NULL'
SELECT @exec_str3 = 'ALTER TABLE ' + @Sch + '.' + @tblname + ' WITH CHECK CHECK CONSTRAINT ' + @FKName + ';'
SELECT @exec_str = 'if not exists (
' + @exec_str2 + '
)
BEGIN
PRINT ''Data can be trusted. No issue. Run this:''
PRINT ''' + @exec_str3 + '''
END
ELSE
BEGIN
PRINT ''Trusting will fail due to bad data. Run this command to figure out why:'';
PRINT ''' + @exec_str2 + ''';
END;'
PRINT @exec_str
--EXEC (@exec_str)
PRINT '--------------------------------------------------------------'
fetch next from fk into
@FKName
,@tblname
,@ReferencedTable
,@FKColName
,@ParentTableColName ,@Sch
END
close fk
deallocate fk
\ No newline at end of file
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment