Thread: Finding the primary key of tables

Finding the primary key of tables

From
George Silva
Date:
Hello guys,

I'm building a function which needs to know what is the primary key of a certain table (all in pgplsql).

I was using select * from information_schema.key_column_usage where table_schema='foo' and table_name = 'aaa'; but that will give me multiple results in case of additional keys in the table.

Any suggestions?

--
George R. C. Silva

Desenvolvimento em GIS
http://blog.geoprocessamento.net

Re: Finding the primary key of tables

From
John R Pierce
Date:
  On 08/03/10 12:13 PM, George Silva wrote:
> Hello guys,
>
> I'm building a function which needs to know what is the primary key of
> a certain table (all in pgplsql).
>
> I was using select * from information_schema.key_column_usage where
> table_schema='foo' and table_name = 'aaa'; but that will give me
> multiple results in case of additional keys in the table.

the primary key index is called tablename_pkey ... afaik, this is the
only thing that makes it special, otherwise, its just another index with
a unique constraint.



Re: Finding the primary key of tables

From
Merlin Moncure
Date:
On Tue, Aug 3, 2010 at 3:13 PM, George Silva <georger.silva@gmail.com> wrote:
> Hello guys,
>
> I'm building a function which needs to know what is the primary key of a
> certain table (all in pgplsql).
>
> I was using select * from information_schema.key_column_usage where
> table_schema='foo' and table_name = 'aaa'; but that will give me multiple
> results in case of additional keys in the table.
>
> Any suggestions?

take a look at information_schema.table_constraint and match on constraint_name.

merlin

Re: Finding the primary key of tables

From
Devrim GÜNDÜZ
Date:
On Tue, 2010-08-03 at 16:13 -0300, George Silva wrote:
> I'm building a function which needs to know what is the primary key of
> a
> certain table (all in pgplsql).
>
> I was using select * from information_schema.key_column_usage where
> table_schema='foo' and table_name = 'aaa'; but that will give me
> multiple
> results in case of additional keys in the table.
>
> Any suggestions?

See pg_index.indisprimary column. If it is true, then the it is the PK
of given table.

Regards,
--
Devrim GÜNDÜZ
PostgreSQL Danışmanı/Consultant, Red Hat Certified Engineer
PostgreSQL RPM Repository: http://yum.pgrpms.org
Community: devrim~PostgreSQL.org, devrim.gunduz~linux.org.tr
http://www.gunduz.org  Twitter: http://twitter.com/devrimgunduz

Attachment

Re: Finding the primary key of tables

From
George Silva
Date:
I'm going for Merlin's solution. Its the easiest one :P

But I'm also having a problem:

SELECT column_name FROM information_schema.key_column_usage k
    LEFT OUTER JOIN information_schema.table_constraints ON (k.table_name = table_constraints.table_name)
WHERE
        table_constraints.constraint_type = 'PRIMARY KEY'
        AND k.table_name = 'acidentes'
        AND k.table_schema = 'public'

this still returns me multiple columns. Did I forgot something?

2010/8/3 Devrim GÜNDÜZ <devrim@gunduz.org>
On Tue, 2010-08-03 at 16:13 -0300, George Silva wrote:
> I'm building a function which needs to know what is the primary key of
> a
> certain table (all in pgplsql).
>
> I was using select * from information_schema.key_column_usage where
> table_schema='foo' and table_name = 'aaa'; but that will give me
> multiple
> results in case of additional keys in the table.
>
> Any suggestions?

See pg_index.indisprimary column. If it is true, then the it is the PK
of given table.

Regards,
--
Devrim GÜNDÜZ
PostgreSQL Danışmanı/Consultant, Red Hat Certified Engineer
PostgreSQL RPM Repository: http://yum.pgrpms.org
Community: devrim~PostgreSQL.org, devrim.gunduz~linux.org.tr
http://www.gunduz.org  Twitter: http://twitter.com/devrimgunduz



--
George R. C. Silva

Desenvolvimento em GIS
http://blog.geoprocessamento.net

Re: Finding the primary key of tables

From
Merlin Moncure
Date:
2010/8/3 George Silva <georger.silva@gmail.com>:
> I'm going for Merlin's solution. Its the easiest one :P
>
> But I'm also having a problem:
>
> SELECT column_name FROM information_schema.key_column_usage k
>     LEFT OUTER JOIN information_schema.table_constraints ON (k.table_name =
> table_constraints.table_name)
> WHERE
>         table_constraints.constraint_type = 'PRIMARY KEY'
>         AND k.table_name = 'acidentes'
>         AND k.table_schema = 'public'
>
> this still returns me multiple columns. Did I forgot something?

yup -- you are supposed be matching on constraint_name, not just
table_name. try:
 SELECT column_name FROM information_schema.key_column_usage k
     LEFT OUTER JOIN information_schema.table_constraints USING
(table_schema, table_name, constraint_name)
 WHERE
         table_constraints.constraint_type = 'PRIMARY KEY'
         AND k.table_name = 'acidentes'
         AND k.table_schema = 'public'


merlin

Re: Finding the primary key of tables

From
George Silva
Date:
Thanks a million. Rusty SQL :P

2010/8/3 Merlin Moncure <mmoncure@gmail.com>
2010/8/3 George Silva <georger.silva@gmail.com>:
> I'm going for Merlin's solution. Its the easiest one :P
>
> But I'm also having a problem:
>
> SELECT column_name FROM information_schema.key_column_usage k
>     LEFT OUTER JOIN information_schema.table_constraints ON (k.table_name =
> table_constraints.table_name)
> WHERE
>         table_constraints.constraint_type = 'PRIMARY KEY'
>         AND k.table_name = 'acidentes'
>         AND k.table_schema = 'public'
>
> this still returns me multiple columns. Did I forgot something?

yup -- you are supposed be matching on constraint_name, not just
table_name. try:
 SELECT column_name FROM information_schema.key_column_usage k
    LEFT OUTER JOIN information_schema.table_constraints USING
(table_schema, table_name, constraint_name)
 WHERE
        table_constraints.constraint_type = 'PRIMARY KEY'
        AND k.table_name = 'acidentes'
        AND k.table_schema = 'public'


merlin



--
George R. C. Silva

Desenvolvimento em GIS
http://blog.geoprocessamento.net