September 21, 2013 at 8:49 pm
Comments posted to this topic are about the item Get all the Child Tables up to N level
Every rule in a world of bits and bytes, can be bend or eventually be broken
MyBlog About Common dialog control
A Visualizer for viewing SqlCommand object script [/url]
September 22, 2013 at 11:42 pm
we have tables pointing to themselfes which causes endless recursion
September 25, 2013 at 3:51 am
well can you explain the scenario please because see the following code
USE tempdb
GO
CREATE TABLE [dbo].[EmpTbl](
[Employeeid] [int] NOT NULL,
[EmployeeName] [varchar](50) NULL,
[Department] [varbinary](50) NULL,
[Supervisorid] [int] NULL,
CONSTRAINT [PK_EmpTbl] PRIMARY KEY CLUSTERED
(
[Employeeid] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
ALTER TABLE [dbo].[EmpTbl] WITH CHECK ADD CONSTRAINT [FK_EmpTbl_EmpTbl] FOREIGN KEY([Supervisorid])
REFERENCES [dbo].[EmpTbl] ([Employeeid])
GO
ALTER TABLE [dbo].[EmpTbl] CHECK CONSTRAINT [FK_EmpTbl_EmpTbl]
GO
DECLARE @TableName AS VARCHAR(250)='EmpTbl'
;WITH cte AS
(
SELECT cast(OBJECT_NAME (fkc.parent_object_id) as VARCHAR(MAX)) AS TableRelation, OBJECT_NAME(fkc.parent_object_id) AS DependentTable, fkc.parent_object_id AS
childID, 1 AS ReLevel
FROM sys.foreign_key_columns fkc
WHERE fkc.referenced_object_id = OBJECT_ID (@TableName)
UNION ALL
SELECT cast(c.TableRelation +'-->'+ OBJECT_NAME (fkc.parent_object_id) AS VARCHAR(MAX)) AS TableRelation, OBJECT_NAME(fkc.parent_object_id) AS DependentTable, fkc.parent_object_id AS
childID, c.ReLevel + 1
FROM sys.foreign_key_columns fkc
INNER JOIN cte c
ON fkc.referenced_object_id = c.Childid AND fkc.parent_object_id<>c.childid
)
SELECT TableRelation,DependentTable
FROM cte
DROP TABLE EmpTbl
it only return one row
Every rule in a world of bits and bytes, can be bend or eventually be broken
MyBlog About Common dialog control
A Visualizer for viewing SqlCommand object script [/url]
September 25, 2013 at 7:44 am
Thanks for posting this. It is going to come in quite handy.
Kurt
Kurt W. Zimmerman
SR DBA
Lefrak Organization
New York, NY
http://www.linkedin.com/in/kurtwzimmerman
November 22, 2013 at 9:20 am
Thank you for this post,
How could i use this to find the order in which to delete tables so i do not receive foreign key violations?
December 10, 2013 at 3:27 am
sorry for the delay i am quite busy in an another work here is what i have you can modify for composite key
USE tempdb
IF OBJECT_ID('tempdb.dbo.Tblone') IS NOT NULL
BEGIN
DROP TABLE Tblthree
DROP TABLE TblTwo
DROP TABLE Tblone
END
GO
CREATE TABLE Tblone
(
oneid INT PRIMARY KEY
,NAME VARCHAR(100)
)
CREATE TABLE Tbltwo
(
twoid INT PRIMARY KEY
,oneid INT CONSTRAINT fk_two FOREIGN KEY REFERENCES tblone(oneid)
,NAME
VARCHAR(100)
)
CREATE TABLE Tblthree
(
Threeid1 INT
,Threeid2 INT
,twoid INT CONSTRAINT fk_three FOREIGN KEY REFERENCES tbltwo(twoid)
,NAME VARCHAR(100)
,CONSTRAINT pk_three PRIMARY KEY(threeid1 ,threeid2)
)
INSERT INTO Tblone
VALUES
(
1
,'11'
), (2 ,'22')
INSERT INTO Tbltwo
VALUES
( 1 ,1 ,'112' ), (2 ,2 ,'222'), (3 ,2 ,'221'), (4 ,2 ,'222')
INSERT INTO Tblthree
VALUES
(1,1,1,'112'), (2 ,1 ,1 ,'222'), (3 ,1 ,1 ,'221'), (4 ,1 ,1 ,'222'),
(1 ,2 ,2 ,'112'), (2 ,2 ,2 ,'222'), (3 ,2 ,2 ,'221'), (4 ,2 ,2 ,'222'),
(1 ,3 ,3 ,'112'), (2 ,3 ,3 ,'222'), (3 ,3 ,3 ,'221'), (4 ,3 ,3 ,'222'),
(1 ,4 ,4 ,'112'), (2 ,4 ,4 ,'222'), (3 ,4 ,4 ,'221'), (4 ,4 ,4 ,'222')
DECLARE @TableName AS VARCHAR(250)='TblOne'
DECLARE @Column AS VARCHAR(250)='Oneid'
DECLARE @Wstmt AS VARCHAR(MAX)=' '+@Column+' = @value';
WITH KeyDetails AS
(
SELECT D.name AS DependentTable
,Dc.name AS DependentColumn
,M.name AS MainTable
,Mc.Name AS MainColumn
,fkc.parent_object_id
,Fkc.referenced_object_id
FROM sys.foreign_key_columns fkc
INNER JOIN SYS.tables D
ON fkc.parent_object_id = D.[object_id]
INNER JOIN sys.syscolumns DC
ON fkc.parent_object_id = DC.id AND
fkc.parent_column_id = DC.colid
INNER JOIN SYS.tables M
ON fkc.referenced_object_id = M.[object_id]
INNER JOIN sys.syscolumns Mc
ON fkc.referenced_object_id = MC.id AND
fkc.referenced_column_id = MC.colid
),
DeptDetails AS
(
SELECT CAST(Fkc.DependentTable AS VARCHAR(MAX)) AS TableRelation
,fkc.DependentTable
,Fkc.DependentColumn
,Fkc.MainTable
,Fkc.MainColumn
,fkc.parent_object_id AS childID
,1 AS ReLevel
,CAST(
'SELECT 1 FROM '+FKC.DependentTable+' WHERE EXISTS(
SELECT 1 FROM '+FKC.MainTable+' WHERE '+FKC.MainTable+'.'+FKC.MainColumn+'='+FKC.DependentTable+'.'
+FKC.DependentColumn+' AND '+@Wstmt+')'
AS VARCHAR(MAX)
) AS STMT
FROM KeyDetails Fkc
WHERE fkc.referenced_object_id = OBJECT_ID(@TableName)
UNION ALL
SELECT CAST(c.TableRelation+'-->'+fkc.DependentTable AS VARCHAR(MAX)) AS TableRelation
,fkc.DependentTable
,Fkc.DependentColumn
,Fkc.MainTable
,Fkc.MainColumn
,fkc.parent_object_id AS childID
,c.ReLevel+1
,CAST(
'SELECT 1 FROM '+FKC.DependentTable+' WHERE EXISTS(
'+C.STMT+'
AND '+FKC.MainTable+'.'+FKC.MainColumn+'='+FKC.DependentTable+'.'+FKC.DependentColumn+')'
AS VARCHAR(MAX)
) AS STMT
FROM KeyDetails fkc
INNER JOIN DeptDetails c
ON fkc.referenced_object_id = c.Childid AND
fkc.parent_object_id<>c.childid
)
SELECT STMT
FROM DeptDetails
you can change the select statement according to the delete and the also change the order based on the level
Every rule in a world of bits and bytes, can be bend or eventually be broken
MyBlog About Common dialog control
A Visualizer for viewing SqlCommand object script [/url]
March 31, 2015 at 3:07 am
it seems if there is a circular dependency in your Database then this script is not working to avoid the circular dependency
use the following condition with the inner join of the recursive part
AND c.TableRelation not like c.DependentTable +'-->%'
Here is an Example
CREATE TABLE [dbo].[EmpTbl](
[Employeeid] [int] NOT NULL,
[EmployeeName] [varchar](50) NULL,
[Department] [varbinary](50) NULL,
[Supervisorid] [int] NULL,
CONSTRAINT [PK_EmpTbl] PRIMARY KEY CLUSTERED
(
[Employeeid] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
/*ALTER TABLE [dbo].[EmpTbl] WITH CHECK ADD CONSTRAINT [FK_EmpTbl_EmpTbl] FOREIGN KEY([Supervisorid])
REFERENCES [dbo].[EmpTbl] ([Employeeid])
GO
ALTER TABLE [dbo].[EmpTbl] CHECK CONSTRAINT [FK_EmpTbl_EmpTbl]
GO*/
Create Table [dbo].[ManagerTbl](
[Managerid] [int] NOT NULL,
[EmployeeName] [varchar](50) NULL,
[AsstManagerid] [int] NOT NULL,
CONSTRAINT [PK_Managerbl] PRIMARY KEY CLUSTERED
(
[Managerid] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
)
GO
ALTER TABLE [dbo].[ManagerTbl] WITH CHECK ADD CONSTRAINT [FK_ManagerTbl_EmpTbl] FOREIGN KEY([Managerid])
REFERENCES [dbo].[EmpTbl] ([Employeeid])
GO
ALTER TABLE [dbo].[ManagerTbl] WITH CHECK ADD CONSTRAINT [FK_ManagerTbl_EmpTbl_1] FOREIGN KEY([AsstManagerid])
REFERENCES [dbo].[ManagerTbl] ([Managerid])
GO
ALTER TABLE [dbo].[EmpTbl] WITH CHECK ADD CONSTRAINT [FK_EmpTbl_EmpTbl] FOREIGN KEY([Supervisorid])
REFERENCES [dbo].[ManagerTbl] ([Managerid])
GO
DECLARE @TableName AS VARCHAR(250)='EmpTbl'
;WITH cte AS
(
SELECT cast(OBJECT_NAME (fkc.parent_object_id) as VARCHAR(MAX)) AS TableRelation, OBJECT_NAME(fkc.parent_object_id) AS DependentTable, fkc.parent_object_id AS
childID, 1 AS ReLevel
FROM sys.foreign_key_columns fkc
WHERE fkc.referenced_object_id = OBJECT_ID (@TableName)
UNION ALL
SELECT cast(c.TableRelation +'-->'+ OBJECT_NAME (fkc.parent_object_id) AS VARCHAR(MAX)) AS TableRelation, OBJECT_NAME(fkc.parent_object_id) AS DependentTable, fkc.parent_object_id AS
childID, c.ReLevel + 1
FROM sys.foreign_key_columns fkc
INNER JOIN cte c
ON fkc.referenced_object_id = c.Childid
AND fkc.parent_object_id<>c.childid
AND c.TableRelation not like c.DependentTable +'-->%'
)
SELECT *
FROM cte
a
Every rule in a world of bits and bytes, can be bend or eventually be broken
MyBlog About Common dialog control
A Visualizer for viewing SqlCommand object script [/url]
April 27, 2016 at 4:55 pm
Great script, thank you.
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply