Thread: Finding all tables that have foreign keys referencing a table
Hi. I see the last comment here suggests a solution for $subject: http://www.postgresql.org/docs/8.1/interactive/ddl-constraints.html But it turns out it assumes constraint_name is unique, which is not the case. It is only unique pr. table. In other words,it produces a lot of false results. I'm trying to make a function which finds all my old "$1" constraints and replaces those names with proper names (_fkey). So - anybody who knows a good solution for how to find all tables with constraint-names that have foreign keys referencinga table's particluar colum? -- Andreas Joseph Krogh <andreak@officenet.no> Senior Software Developer / CEO ------------------------+---------------------------------------------+ OfficeNet AS | The most difficult thing in the world is to | Karenslyst Allé 11 | know how to do a thing and to watch | PO. Box 529 Skøyen | somebody else doing it wrong, without | 0214 Oslo | comment. | NORWAY | | Tlf: +47 24 15 38 90 | | Fax: +47 24 15 38 91 | | Mobile: +47 909 56 963 | | ------------------------+---------------------------------------------+
Try this
select table_schema, table_name
from information_schema.columns
where table_schema not in
('information_schema','pg_catalog')
and column_name = '?'
De: Andreas Joseph Krogh <andreak@officenet.no>
Para: pgsql-sql@postgresql.org
Enviadas: Quinta-feira, 6 de Novembro de 2008 19:35:23
Assunto: [SQL] Finding all tables that have foreign keys referencing a table
Hi.
I see the last comment here suggests a solution for $subject:
http://www.postgresql.org/docs/8.1/interactive/ddl-constraints.html
But it turns out it assumes constraint_name is unique, which is not the case. It is only unique pr. table. In other words, it produces a lot of false results.
I'm trying to make a function which finds all my old "$1" constraints and replaces those names with proper names (_fkey).
So - anybody who knows a good solution for how to find all tables with constraint-names that have foreign keys referencing a table's particluar colum?
--
Andreas Joseph Krogh <andreak@officenet.no>
Senior Software Developer / CEO
------------------------+---------------------------------------------+
OfficeNet AS | The most difficult thing in the world is to |
Karenslyst Allé 11 | know how to do a thing and to watch |
PO. Box 529 Skøyen | somebody else doing it wrong, without |
0214 Oslo | comment. |
NORWAY | |
Tlf: +47 24 15 38 90 | |
Fax: +47 24 15 38 91 | |
Mobile: +47 909 56 963 | |
------------------------+---------------------------------------------+
--
Sent via pgsql-sql mailing list (pgsql-sql@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-sql
Novos endereços, o Yahoo! que você conhece. Crie um email novo com a sua cara @ymail.com ou @rocketmail.com.
Re: Res: Finding all tables that have foreign keys referencing a table
From
Andreas Joseph Krogh
Date:
On Friday 07 November 2008 15:15:49 paulo matadr wrote: > Try this > > select table_schema, table_name > from information_schema.columns > where table_schema not in > ('information_schema','pg_catalog') > and column_name = '?' AFAICS this lists all tables which have a column named '?', which is not what I'm after. I'm after listing all columns referencinga certain column as a FOREIGN KEY. Example, making the FK's names "$1" to mimic old PG-behaviour, and proving my point about the FK-names not needing to beglobaly unique: CREATE TABLE test1( id INTEGER PRIMARY KEY ); CREATE TABLE test2( id INTEGER PRIMARY KEY ); CREATE TABLE test_ref1( id INTEGER PRIMARY KEY, entity_id INTEGER, CONSTRAINT "$1" FOREIGN KEY (entity_id) REFERENCES test1(id) ); CREATE TABLE test_ref2( id INTEGER PRIMARY KEY, entity_id INTEGER, CONSTRAINT "$1" FOREIGN KEY (entity_id) REFERENCES test2(id) ); andreak=# \d test_ref1 Table "public.test_ref1" Column | Type | Modifiers -----------+---------+-----------id | integer | not nullentity_id | integer | Indexes: "test_ref1_pkey" PRIMARY KEY, btree (id) Foreign-key constraints: "$1" FOREIGN KEY (entity_id) REFERENCES test1(id) andreak=# \d test_ref2 Table "public.test_ref2" Column | Type | Modifiers -----------+---------+-----------id | integer | not nullentity_id | integer | Indexes: "test_ref2_pkey" PRIMARY KEY, btree (id) Foreign-key constraints: "$1" FOREIGN KEY (entity_id) REFERENCES test2(id) andreak=# Now, any idea about how to safely get all columns which reference test1.id? -hackers; Any hints? BTW: andreak=# select version(); version -----------------------------------------------------------------------------------------------PostgreSQL 8.3.3 on i486-pc-linux-gnu,compiled by GCC cc (GCC) 4.2.3 (Ubuntu 4.2.3-2ubuntu7) -- Andreas Joseph Krogh <andreak@officenet.no> Senior Software Developer / CEO ------------------------+---------------------------------------------+ OfficeNet AS | The most difficult thing in the world is to | Karenslyst Allé 11 | know how to do a thing and to watch | PO. Box 529 Skøyen | somebody else doing it wrong, without | 0214 Oslo | comment. | NORWAY | | Tlf: +47 24 15 38 90 | | Fax: +47 24 15 38 91 | | Mobile: +47 909 56 963 | | ------------------------+---------------------------------------------+
Andreas Joseph Krogh <andreak@officenet.no> writes: > AFAICS this lists all tables which have a column named '?', which is not what I'm after. I'm after listing all columnsreferencing a certain column as a FOREIGN KEY. Should be possible to dredge that out of pg_constraint ... about like this: select confrelid::regclass, af.attname as fcol, conrelid::regclass, a.attname as col from pg_attribute af, pg_attribute a, (select conrelid,confrelid,conkey[i] as conkey, confkey[i] as confkey from (selectconrelid,confrelid,conkey,confkey, generate_series(1,array_upper(conkey,1)) as i from pg_constraintwhere contype = 'f') ss) ss2 where af.attnum = confkey and af.attrelid = confrelid and a.attnum = conkey and a.attrelid = conrelid; Deconstructing those arrays in parallel is a bit of a pain :-( regards, tom lane
Re: Res: Finding all tables that have foreign keys referencing a table
From
Andreas Joseph Krogh
Date:
On Friday 07 November 2008 21:09:33 Tom Lane wrote: > Andreas Joseph Krogh <andreak@officenet.no> writes: > > AFAICS this lists all tables which have a column named '?', which is not what I'm after. I'm after listing all columnsreferencing a certain column as a FOREIGN KEY. > > Should be possible to dredge that out of pg_constraint ... about like > this: > > select confrelid::regclass, af.attname as fcol, > conrelid::regclass, a.attname as col > from pg_attribute af, pg_attribute a, > (select conrelid,confrelid,conkey[i] as conkey, confkey[i] as confkey > from (select conrelid,confrelid,conkey,confkey, > generate_series(1,array_upper(conkey,1)) as i > from pg_constraint where contype = 'f') ss) ss2 > where af.attnum = confkey and af.attrelid = confrelid and > a.attnum = conkey and a.attrelid = conrelid; > > Deconstructing those arrays in parallel is a bit of a pain :-( What can I say, you're the man. Thank you very much! Needless to say that it would be nice if this information was available in the information_schema, I'm probably not the onlyone spending lots of time in there. It's probably not in in the standard, but i would be a nice PG-extention to allowretrieving that info in a more intuitive way. For the archive, here is a complete example with table_name and column_name: select confrelid::regclass, af.attname as fcol, conrelid::regclass, a.attname as col from pg_attribute af, pg_attribute a, (select conrelid,confrelid,conkey[i] as conkey, confkey[i] as confkey from (selectconrelid,confrelid,conkey,confkey, generate_series(1,array_upper(conkey,1)) as i from pg_constraintwhere contype = 'f') ss) ss2 where af.attnum = confkey and af.attrelid = confrelid and a.attnum = conkey and a.attrelid = conrelid AND confrelid::regclass= 'my_table'::regclass AND af.attname = 'my_referenced_column'; -- Andreas Joseph Krogh <andreak@officenet.no> Senior Software Developer / CEO ------------------------+---------------------------------------------+ OfficeNet AS | The most difficult thing in the world is to | Karenslyst Allé 11 | know how to do a thing and to watch | PO. Box 529 Skøyen | somebody else doing it wrong, without | 0214 Oslo | comment. | NORWAY | | Tlf: +47 24 15 38 90 | | Fax: +47 24 15 38 91 | | Mobile: +47 909 56 963 | | ------------------------+---------------------------------------------+
Andreas Joseph Krogh <andreak@officenet.no> writes: > Needless to say that it would be nice if this information was available in the information_schema, I'm probably not theonly one spending lots of time in there. It's probably not in in the standard, but i would be a nice PG-extention to allowretrieving that info in a more intuitive way. Unfortunately, the whole point of information_schema is to be standardized; the notion of a "PG extension" to it is just wrong. Feel free to lobby the SQL committee to fix their oversight ... regards, tom lane