Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Get the Foreign Key Hierarchy Expand / Collapse
Author
Message
Posted Saturday, October 13, 2007 11:42 PM


SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, September 4, 2007 4:36 AM
Points: 27, Visits: 1
Comments posted to this topic are about the item Get the Foreign Key Hierarchy


Post #410549
Posted Wednesday, May 27, 2009 2:53 PM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Today @ 12:03 PM
Points: 71, Visits: 832
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.
Post #724589
Posted Monday, February 1, 2010 11:29 PM


SSCoach

SSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoach

Group: General Forum Members
Last Login: Today @ 8:49 PM
Points: 17,967, Visits: 15,979
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
Post #857737
Posted Wednesday, June 19, 2013 3:23 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Wednesday, July 31, 2013 11:08 AM
Points: 17, Visits: 50
How would you start with a specific table and get everything down from that?
Post #1465402
Posted Wednesday, June 19, 2013 3:28 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 1:23 PM
Points: 12,927, Visits: 32,330
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

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1465405
Posted Wednesday, June 19, 2013 3:34 PM


SSCoach

SSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoach

Group: General Forum Members
Last Login: Today @ 8:49 PM
Points: 17,967, Visits: 15,979
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
Post #1465408
Posted Thursday, June 20, 2013 10:47 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Wednesday, July 31, 2013 11:08 AM
Points: 17, 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.
Post #1465845
Posted Thursday, June 20, 2013 11:22 AM


SSCoach

SSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoach

Group: General Forum Members
Last Login: Today @ 8:49 PM
Points: 17,967, Visits: 15,979
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
Post #1465859
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse