Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 SQL Server 2005 Forums
 Transact-SQL (2005)
 extracting foreign key tables against a single pri

Author  Topic 

maifs
Yak Posting Veteran

57 Posts

Posted - 2010-04-14 : 13:45:59
how can i retrieve the all foreign keys against a single primary key.
i mean to say that if a table contain a primary key then it becomes as foreign keys in which tables.

i want to take that nam of that tables and on the base of that tables i also want to delete from all the entries.
e.g:
if a primary key's column entry deleted then all foreing key entries should also be deleted.
.


i want to do it from programatically.
i am using sql server 2005

Sachin.Nand

2937 Posts

Posted - 2010-04-14 : 13:58:38
Any reason why you wanna do it programmatically?

PBUH
Go to Top of Page

hanbingl
Aged Yak Warrior

652 Posts

Posted - 2010-04-14 : 15:17:16
did you setup your foreign key to ON DELETE CASCADE ?

quote:
Originally posted by maifs

how can i retrieve the all foreign keys against a single primary key.
i mean to say that if a table contain a primary key then it becomes as foreign keys in which tables.

i want to take that nam of that tables and on the base of that tables i also want to delete from all the entries.
e.g:
if a primary key's column entry deleted then all foreing key entries should also be deleted.
.


i want to do it from programatically.
i am using sql server 2005

Go to Top of Page

maifs
Yak Posting Veteran

57 Posts

Posted - 2010-04-14 : 15:22:13
because there are 988 tables in a single database.
it can't be possible to go for each table.
Go to Top of Page

maifs
Yak Posting Veteran

57 Posts

Posted - 2010-04-14 : 15:24:12
no these are simple. i didnt define over it.
Go to Top of Page

hanbingl
Aged Yak Warrior

652 Posts

Posted - 2010-04-14 : 15:25:23
[code]
SELECT
K_Table = FK.TABLE_NAME,
FK_Column = CU.COLUMN_NAME,
PK_Table = PK.TABLE_NAME,
PK_Column = PT.COLUMN_NAME,
Constraint_Name = C.CONSTRAINT_NAME
FROM INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS C
INNER JOIN INFORMATION_SCHEMA.TABLE_CONSTRAINTS FK ON C.CONSTRAINT_NAME = FK.CONSTRAINT_NAME
INNER JOIN INFORMATION_SCHEMA.TABLE_CONSTRAINTS PK ON C.UNIQUE_CONSTRAINT_NAME = PK.CONSTRAINT_NAME
INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE CU ON C.CONSTRAINT_NAME = CU.CONSTRAINT_NAME
INNER JOIN (
SELECT i1.TABLE_NAME, i2.COLUMN_NAME
FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS i1
INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE i2 ON i1.CONSTRAINT_NAME = i2.CONSTRAINT_NAME
WHERE i1.CONSTRAINT_TYPE = 'PRIMARY KEY'
) PT ON PT.TABLE_NAME = PK.TABLE_NAME
WHERE PK.TABLE_NAME='PKTABLENAME'
ORDER BY
1,2,3,4
[/code]
quote:
Originally posted by maifs

because there are 988 tables in a single database.
it can't be possible to go for each table.


Go to Top of Page

maifs
Yak Posting Veteran

57 Posts

Posted - 2010-04-14 : 15:49:40
Thanks but still deleting issue.
Go to Top of Page

maifs
Yak Posting Veteran

57 Posts

Posted - 2010-04-20 : 01:43:49
can it have any way to delete against foreign key priority wise?
mean to say that parent table contain primary key, child table contain foreign key , now there is another child table which dependent previous child table. then how can i delete all record against it?
Go to Top of Page

Transact Charlie
Master Smack Fu Yak Hacker

3451 Posts

Posted - 2010-04-20 : 05:18:06
Well -- You *should* know how all your tables are related. otherwise your documentation is bad.

You can run this to chart dependencies for a particular table. This is something I knocked up to try and work out a 3rd party schema.

/*** (Key Cascade Report) *****************************************************
*
* Charlie
*
* Set @tableName to the name of the Root table you want to chart
* Dependancies for. leave NULL for all tables.
*
******************************************************************************/

DECLARE @tableName VARCHAR(255) SET @tableName = NULL

/*****************************************************************************/

SET NOCOUNT ON

; WITH keyCas (
[baseTable]
, [tableName]
, [tableId]
, [keyname]
, [Key Column]
, [Target Column]
, [level]
, [tablePath]
, [tableIdPath]
)
AS (
-- Anchor Definition
SELECT
tbl.[name]
, tbl.[name]
, tbl.[object_ID]
, CAST('' AS VARCHAR(2000))
, CAST('' AS VARCHAR(2000))
, CAST('' AS VARCHAR(2000))
, 0
, CAST(tbl.[name] AS VARCHAR(MAX))
, CAST(tbl.[object_ID] AS VARCHAR(MAX))
FROM
sys.objects tbl
WHERE
[type] = 'U'
AND (
[name] = @tableName
OR
@tableName IS NULL
)

-- Recursive Defintion
UNION ALL SELECT
kc.[baseTable]
, tbl.[name]
, tbl.[object_Id]
, CAST(ky.[name] AS VARCHAR(2000))
, CAST(QUOTENAME(icp.[name]) AS VARCHAR(2000))
, CAST(QUOTENAME(kc.[tableName]) + '.' + QUOTENAME(icT.[name]) AS VARCHAR(2000))
, kc.[level] + 1
, kc.[tablePath] + CAST(' -> ' + tbl.[name] AS VARCHAR(MAX))
, kc.[tableIdPath] + CAST(',' + CAST(tbl.[object_ID] AS VARCHAR(255)) AS VARCHAR(MAX))
FROM
sys.foreign_key_columns fkc
JOIN sys.objects ky ON ky.[object_Id] = fkc.[constraint_object_id]
JOIN sys.objects tbl ON tbl.[object_id] = fkc.[parent_object_Id]
JOIN sys.objects target ON target.[object_ID] = fkc.[referenced_object_Id]

JOIN sys.columns icp ON
icp.[object_ID] = fkc.[parent_object_Id]
AND icp.[column_Id] = fkc.[parent_column_Id]

JOIN sys.columns icT ON
icT.[object_ID] = fkc.[referenced_object_Id]
AND icT.[column_Id] = fkc.[referenced_column_Id]

JOIN keyCas kc ON target.[object_ID] = kc.[tableId]
WHERE
kc.[tableIdPath] NOT LIKE '%' + CAST(tbl.[object_Id] AS VARCHAR(255)) + '%'
)
SELECT
[baseTable] AS [Root Table]
, [tableName] AS [Leaf Table]
, [keyname] AS [Key]
, [Key Column]
, [Target Column]
, [tablePath] AS [Dependancy List]
FROM
keyCas
ORDER BY
[tablePath]

OPTION (MAXRECURSION 1000)



Charlie
===============================================================
Msg 3903, Level 16, State 1, Line 1736
The ROLLBACK TRANSACTION request has no corresponding BEGIN TRANSACTION
Go to Top of Page
   

- Advertisement -