October 24, 2012 at 10:51 pm
Hi,
we are having more than 3000 tables in our DB, But none of the tables are designed with foreign key relationships.
Is there anyway we can find relationship between tables without having foreign Key, Please share your thoughts..
Regards,
Tony
October 25, 2012 at 1:28 am
Hi,
I havnt got your question fully but i assume that you want to find tables that "can have relation
base on the column name"
Like Parent table having USERID as primary key and some other table having USERID normal column
than it may have relation between them and you want those tables
if above which i assume is same then
this query might help you
i havent check it for 3000 table but for 10 it's working
;WITH CTE AS
(
select TAB.object_id,TAB.name,COL.name AS COLNAME,COL.column_id,COL.is_identity
from
sys.tables TAB
INNER JOIN sys.columns COL ON TAB.object_id=COL.object_id
)
SELECT
Child.object_id as 'Child Objectid'
,Child.name as 'Child TableName'
,Child.COLNAME as 'Child ColumnName'
,Parent.object_id as 'Parent Objectid'
,Parent.name as 'Parent TableName'
,Parent.COLNAME as 'Parent ColumnName'
FROM
cte Child
INNER JOIN CTE Parent
ON Child.COLNAME=Parent.COLNAME AND Child.name<>Parent.name AND Child.is_identity+1=Parent.is_identity
October 25, 2012 at 1:41 am
yeshupandit_2002 (10/25/2012)
Hi,I havnt got your question fully but i assume that you want to find tables that "can have relation
base on the column name"
Like Parent table having USERID as primary key and some other table having USERID normal column
than it may have relation between them and you want those tables
if above which i assume is same then
this query might help you
i havent check it for 3000 table but for 10 it's working
;WITH CTE AS
(
select TAB.object_id,TAB.name,COL.name AS COLNAME,COL.column_id,COL.is_identity
from
sys.tables TAB
INNER JOIN sys.columns COL ON TAB.object_id=COL.object_id
)
SELECT
Child.object_id as 'Child Objectid'
,Child.name as 'Child TableName'
,Child.COLNAME as 'Child ColumnName'
,Parent.object_id as 'Parent Objectid'
,Parent.name as 'Parent TableName'
,Parent.COLNAME as 'Parent ColumnName'
FROM
cte Child
INNER JOIN CTE Parent
ON Child.COLNAME=Parent.COLNAME AND Child.name<>Parent.name AND Child.is_identity+1=Parent.is_identity
i havent checked your query as i dont have sql environment right now but how would you decide which table will act as parent or child and how the different column's name columns will get foreign key level match here. certainly here manual intervention plus ER logic required
-------Bhuvnesh----------
I work only to learn Sql Server...though my company pays me for getting their stuff done;-)
October 25, 2012 at 1:47 am
Ok,column which is having identity will be parent table and second one will act as as child
and yes if column name is same both tables then only query will work else need to do some manual work
October 25, 2012 at 3:19 am
Still this query doesn't work, it is not pulling the common field name from all tables and just pulling few field and tables.. Please need more help on this.
October 25, 2012 at 3:43 am
can you tell me more in detail whats happening and what is output when you run
few field and few tables means?
if its fine to you can you share some of your table and its column
so i can check
October 25, 2012 at 4:07 am
Hi,
Please find the following few tables for your reference
--Person
Enterpriseid
Person_Id
LastName
FirstName
--Person_Relationship
Person_Id
Relations_Code
CreatedDate
--Person_Employers
Person_Id
Employee_id
Occuapation
Person,Person_Relationship and Person_Employers are tables.
The common field is Person_Id, But there is no Foreign Key relationship. Like this i have 3000 tables without having Foreign Key relationship
Is there any way can we get all tables relationship through Person_Id Field? like this we have lot of common field names.
Using this i want to find which all tables are linked without foreign Key relationship.
Regards,
tony
October 25, 2012 at 4:16 am
is your Person_Id column is "identity column" in Primary table
October 25, 2012 at 4:38 am
Person_Id field created with uniqueidentifier
October 25, 2012 at 4:51 am
try this and let me know
Line "and Parent.user_type_id =36" is for uniqueidentifier
and
Line "AND Child.is_identity+1=Parent.is_identity"(which is comment in this query) is for column which is
identity column in primary table
run this and let me know result
;WITH CTE AS
(
select TAB.object_id,TAB.name,COL.name AS COLNAME,COL.column_id,COL.is_identity ,col.user_type_id
from
sys.tables TAB
INNER JOIN sys.columns COL ON TAB.object_id=COL.object_id
)
SELECT
Child.object_id as 'Child Objectid'
,Child.name as 'Child TableName'
,Child.COLNAME as 'Child ColumnName'
,Parent.object_id as 'Parent Objectid'
,Parent.name as 'Parent TableName'
,Parent.COLNAME as 'Parent ColumnName'
FROM
cte Child
INNER JOIN CTE Parent
ON Child.COLNAME=Parent.COLNAME AND Child.name<>Parent.name
--AND Child.is_identity+1=Parent.is_identity
and Parent.user_type_id =36
October 25, 2012 at 5:02 am
This works Great.. Thanks a lot
October 25, 2012 at 5:06 am
It is my pleasure helping you:-)
Viewing 12 posts - 1 through 11 (of 11 total)
You must be logged in to reply to this topic. Login to reply