SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Get the Foreign Key Hierarchy


Get the Foreign Key Hierarchy

Author
Message
Mike Pearson
Mike Pearson
Right there with Babe
Right there with Babe (763 reputation)Right there with Babe (763 reputation)Right there with Babe (763 reputation)Right there with Babe (763 reputation)Right there with Babe (763 reputation)Right there with Babe (763 reputation)Right there with Babe (763 reputation)Right there with Babe (763 reputation)

Group: General Forum Members
Points: 763 Visits: 1
Comments posted to this topic are about the item Get the Foreign Key Hierarchy



don.schaeffer
don.schaeffer
SSChasing Mays
SSChasing Mays (645 reputation)SSChasing Mays (645 reputation)SSChasing Mays (645 reputation)SSChasing Mays (645 reputation)SSChasing Mays (645 reputation)SSChasing Mays (645 reputation)SSChasing Mays (645 reputation)SSChasing Mays (645 reputation)

Group: General Forum Members
Points: 645 Visits: 1062
Table with self references seem to cause an infinite loop in this script. I added "where S1.name <> SO.Name" to the table population query to avoid this.
SQLRNNR
SQLRNNR
SSC Guru
SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)

Group: General Forum Members
Points: 144839 Visits: 18651
I think this is a nice foundation script.

Jason...AKA CirqueDeSQLeil
_______________________________________________
I have given a name to my pain...MCM SQL Server, MVP
SQL RNNR
Posting Performance Based Questions - Gail Shaw
Learn Extended Events

MarkR-251611
MarkR-251611
Old Hand
Old Hand (357 reputation)Old Hand (357 reputation)Old Hand (357 reputation)Old Hand (357 reputation)Old Hand (357 reputation)Old Hand (357 reputation)Old Hand (357 reputation)Old Hand (357 reputation)

Group: General Forum Members
Points: 357 Visits: 50
How would you start with a specific table and get everything down from that?
Lowell
Lowell
SSC Guru
SSC Guru (183K reputation)SSC Guru (183K reputation)SSC Guru (183K reputation)SSC Guru (183K reputation)SSC Guru (183K reputation)SSC Guru (183K reputation)SSC Guru (183K reputation)SSC Guru (183K reputation)

Group: General Forum Members
Points: 183677 Visits: 41569
for a single table, i have this saved from Jason's website(the guy who posted before you

--http://jasonbrimhall.info/2011/07/11/foreign-key-hierarchy-update/

--SET XACT_ABORT ON
--BEGIN TRAN

DECLARE @StartParentTable VARCHAR(256)

SELECT @StartParentTable = 'GMACT'

;With Hierarchy (ParentTable,ParentColumn, ChildTable,ChildColumn, FKLevel, SortCol) AS (
SELECT OBJECT_NAME(sfk.referenced_object_id) AS ParentTable
,COL_NAME(sfkc.referenced_object_id,sfkc.referenced_column_id) AS ParentColumn
,OBJECT_NAME(sfk.Parent_object_id) AS ChildTable
,COL_NAME(sfkc.parent_object_id,sfkc.parent_column_id) AS ChildColumn
,0 AS FKLevel
,CAST('.'+CAST(OBJECT_NAME(sfk.referenced_object_id) AS VARCHAR(MAX))+'.' AS VARCHAR(MAX))
FROM sys.foreign_key_columns sfkc
INNER Join sys.foreign_keys sfk
ON sfkc.constraint_object_id = sfk.OBJECT_ID
WHERE OBJECT_NAME(sfk.referenced_object_id) = @StartParentTable
UNION All
SELECT OBJECT_NAME(sfk.referenced_object_id) AS ParentTable
,COL_NAME(sfkc.referenced_object_id,sfkc.referenced_column_id) AS ParentColumn
,OBJECT_NAME(sfk.Parent_object_id) AS ChildTable
,COL_NAME(sfkc.parent_object_id,sfkc.parent_column_id) AS ChildColumn
,FKLevel + 1
,STUFF(('.' + F.SortCol + CAST(CAST(OBJECT_NAME(sfk.referenced_object_id) AS VARCHAR(MAX)) + '.' AS VARCHAR(MAX))
),1,1,'')
FROM sys.foreign_keys sfk
INNER Join Hierarchy F
ON OBJECT_NAME(sfk.referenced_object_id) = f.ChildTable
And F.SortCol NOT LIKE '%'+CAST(OBJECT_NAME(sfk.referenced_object_id) AS VARCHAR(MAX))+'%'
INNER Join sys.foreign_key_columns sfkc
ON sfkc.constraint_object_id = sfk.OBJECT_ID
WHERE OBJECT_NAME(sfk.referenced_object_id) <> @StartParentTable
And sfk.referenced_object_id <> sfk.parent_object_id
), Ancestry (ParentTable,ParentColumn, ChildTable,ChildColumn, FKLevel, SortCol) AS (
SELECT DISTINCT OBJECT_NAME(sfk.referenced_object_id) AS ParentTable
,COL_NAME(sfkc.referenced_object_id,sfkc.referenced_column_id) AS ParentColumn
,OBJECT_NAME(sfk.Parent_object_id) AS ChildTable
,COL_NAME(sfkc.parent_object_id,sfkc.parent_column_id) AS ChildColumn
,-1 AS FKLevel
,CAST('.'+CAST(OBJECT_NAME(sfk.referenced_object_id) AS VARCHAR(MAX))+'.' AS VARCHAR(MAX))
FROM Hierarchy F
INNER Join sys.foreign_keys sfk
ON f.ChildTable = OBJECT_NAME(sfk.parent_object_id)
And F.ParentTable <> OBJECT_NAME(sfk.referenced_object_id)
INNER Join sys.foreign_key_columns sfkc
ON sfkc.constraint_object_id = sfk.OBJECT_ID
UNION All
SELECT OBJECT_NAME(sfk.referenced_object_id) AS ParentTable
,COL_NAME(sfkc.referenced_object_id,sfkc.referenced_column_id) AS ParentColumn
,OBJECT_NAME(sfk.Parent_object_id) AS ChildTable
,COL_NAME(sfkc.parent_object_id,sfkc.parent_column_id) AS ChildColumn
,f.FKLevel -1
,STUFF(('.' + SortCol + CAST(CAST(OBJECT_NAME(sfk.referenced_object_id) AS VARCHAR(MAX)) + '.' AS VARCHAR(MAX))
),1,1,'')
FROM Ancestry F
INNER Join sys.foreign_keys sfk
ON f.parentTable = OBJECT_NAME(sfk.parent_object_id)
INNER Join sys.foreign_key_columns sfkc
ON sfkc.constraint_object_id = sfk.OBJECT_ID
WHERE f.parentTable not in (SELECT ParentTable FROM Hierarchy)
And sfk.referenced_object_id <> sfk.parent_object_id
And f.ChildTable not IN (SELECT ChildTable FROM Hierarchy)
)

SELECT ParentTable,ParentColumn, ChildTable,ChildColumn, FKLevel, SortCol
FROM Hierarchy
UNION All
SELECT ParentTable,ParentColumn, ChildTable,ChildColumn, FKLevel, SortCol
FROM Ancestry
ORDER BY SortCol ASC
OPTION (maxrecursion 500)


--ROLLBACK TRAN
--COMMIT TRAN



Lowell
--help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!
SQLRNNR
SQLRNNR
SSC Guru
SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)

Group: General Forum Members
Points: 144839 Visits: 18651
Lowell (6/19/2013)
for a single table, i have this saved from Jason's website(the guy who posted before you

--http://jasonbrimhall.info/2011/07/11/foreign-key-hierarchy-update/

--SET XACT_ABORT ON
--BEGIN TRAN

DECLARE @StartParentTable VARCHAR(256)

SELECT @StartParentTable = 'GMACT'

;With Hierarchy (ParentTable,ParentColumn, ChildTable,ChildColumn, FKLevel, SortCol) AS (
SELECT OBJECT_NAME(sfk.referenced_object_id) AS ParentTable
,COL_NAME(sfkc.referenced_object_id,sfkc.referenced_column_id) AS ParentColumn
,OBJECT_NAME(sfk.Parent_object_id) AS ChildTable
,COL_NAME(sfkc.parent_object_id,sfkc.parent_column_id) AS ChildColumn
,0 AS FKLevel
,CAST('.'+CAST(OBJECT_NAME(sfk.referenced_object_id) AS VARCHAR(MAX))+'.' AS VARCHAR(MAX))
FROM sys.foreign_key_columns sfkc
INNER Join sys.foreign_keys sfk
ON sfkc.constraint_object_id = sfk.OBJECT_ID
WHERE OBJECT_NAME(sfk.referenced_object_id) = @StartParentTable
UNION All
SELECT OBJECT_NAME(sfk.referenced_object_id) AS ParentTable
,COL_NAME(sfkc.referenced_object_id,sfkc.referenced_column_id) AS ParentColumn
,OBJECT_NAME(sfk.Parent_object_id) AS ChildTable
,COL_NAME(sfkc.parent_object_id,sfkc.parent_column_id) AS ChildColumn
,FKLevel + 1
,STUFF(('.' + F.SortCol + CAST(CAST(OBJECT_NAME(sfk.referenced_object_id) AS VARCHAR(MAX)) + '.' AS VARCHAR(MAX))
),1,1,'')
FROM sys.foreign_keys sfk
INNER Join Hierarchy F
ON OBJECT_NAME(sfk.referenced_object_id) = f.ChildTable
And F.SortCol NOT LIKE '%'+CAST(OBJECT_NAME(sfk.referenced_object_id) AS VARCHAR(MAX))+'%'
INNER Join sys.foreign_key_columns sfkc
ON sfkc.constraint_object_id = sfk.OBJECT_ID
WHERE OBJECT_NAME(sfk.referenced_object_id) <> @StartParentTable
And sfk.referenced_object_id <> sfk.parent_object_id
), Ancestry (ParentTable,ParentColumn, ChildTable,ChildColumn, FKLevel, SortCol) AS (
SELECT DISTINCT OBJECT_NAME(sfk.referenced_object_id) AS ParentTable
,COL_NAME(sfkc.referenced_object_id,sfkc.referenced_column_id) AS ParentColumn
,OBJECT_NAME(sfk.Parent_object_id) AS ChildTable
,COL_NAME(sfkc.parent_object_id,sfkc.parent_column_id) AS ChildColumn
,-1 AS FKLevel
,CAST('.'+CAST(OBJECT_NAME(sfk.referenced_object_id) AS VARCHAR(MAX))+'.' AS VARCHAR(MAX))
FROM Hierarchy F
INNER Join sys.foreign_keys sfk
ON f.ChildTable = OBJECT_NAME(sfk.parent_object_id)
And F.ParentTable <> OBJECT_NAME(sfk.referenced_object_id)
INNER Join sys.foreign_key_columns sfkc
ON sfkc.constraint_object_id = sfk.OBJECT_ID
UNION All
SELECT OBJECT_NAME(sfk.referenced_object_id) AS ParentTable
,COL_NAME(sfkc.referenced_object_id,sfkc.referenced_column_id) AS ParentColumn
,OBJECT_NAME(sfk.Parent_object_id) AS ChildTable
,COL_NAME(sfkc.parent_object_id,sfkc.parent_column_id) AS ChildColumn
,f.FKLevel -1
,STUFF(('.' + SortCol + CAST(CAST(OBJECT_NAME(sfk.referenced_object_id) AS VARCHAR(MAX)) + '.' AS VARCHAR(MAX))
),1,1,'')
FROM Ancestry F
INNER Join sys.foreign_keys sfk
ON f.parentTable = OBJECT_NAME(sfk.parent_object_id)
INNER Join sys.foreign_key_columns sfkc
ON sfkc.constraint_object_id = sfk.OBJECT_ID
WHERE f.parentTable not in (SELECT ParentTable FROM Hierarchy)
And sfk.referenced_object_id <> sfk.parent_object_id
And f.ChildTable not IN (SELECT ChildTable FROM Hierarchy)
)

SELECT ParentTable,ParentColumn, ChildTable,ChildColumn, FKLevel, SortCol
FROM Hierarchy
UNION All
SELECT ParentTable,ParentColumn, ChildTable,ChildColumn, FKLevel, SortCol
FROM Ancestry
ORDER BY SortCol ASC
OPTION (maxrecursion 500)


--ROLLBACK TRAN
--COMMIT TRAN



Thanks for that follow-up Lowell.

Jason...AKA CirqueDeSQLeil
_______________________________________________
I have given a name to my pain...MCM SQL Server, MVP
SQL RNNR
Posting Performance Based Questions - Gail Shaw
Learn Extended Events

MarkR-251611
MarkR-251611
Old Hand
Old Hand (357 reputation)Old Hand (357 reputation)Old Hand (357 reputation)Old Hand (357 reputation)Old Hand (357 reputation)Old Hand (357 reputation)Old Hand (357 reputation)Old Hand (357 reputation)

Group: General Forum Members
Points: 357 Visits: 50
Thanks, that worked great. Now I need to find only columns with a foreign key back to the original column. This gives me a good start.
SQLRNNR
SQLRNNR
SSC Guru
SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)SSC Guru (144K reputation)

Group: General Forum Members
Points: 144839 Visits: 18651
This reminds me, I think I have an update for that script.

Jason...AKA CirqueDeSQLeil
_______________________________________________
I have given a name to my pain...MCM SQL Server, MVP
SQL RNNR
Posting Performance Based Questions - Gail Shaw
Learn Extended Events

Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum








































































































































































SQLServerCentral


Search