On Friday 07 November 2008 21:09:33 Tom Lane wrote:
> Andreas Joseph Krogh <[EMAIL PROTECTED]> writes:
> > AFAICS this lists all tables which have a column named '?', which is not 
> > what I'm after. I'm after listing all columns referencing 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 only one spending lots of time in 
there. It's probably not in in the standard, but i would be a nice PG-extention 
to allow retrieving 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 (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 
  AND confrelid::regclass = 'my_table'::regclass AND af.attname = 
'my_referenced_column';

-- 
Andreas Joseph Krogh <[EMAIL PROTECTED]>
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

Reply via email to