Re: Select all table column names for a specified tablename (per the system catalogs)

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Joshua Drake <jd(at)commandprompt(dot)com>
Cc: kevin kempter <kevin(at)kevinkempterllc(dot)com>, pgsql-admin(at)postgresql(dot)org
Subject: Re: Select all table column names for a specified tablename (per the system catalogs)
Date: 2008-09-23 03:37:10
Message-ID: 16826.1222141030@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-admin

Joshua Drake <jd(at)commandprompt(dot)com> writes:
> kevin kempter <kevin(at)kevinkempterllc(dot)com> wrote:
>> ... I got this far (see
>> below) however this query produces additional rows with attname's
>> like tableoid, cmax, xmax ctid, etc.
>>
>> select attname from pg_attribute where attrelid = (select oid from
>> pg_class where relname = 'my_tablename');

> SELECT column_name FROM information_schema.columns WHERE table_name =
> 'table';

If you don't want to use information_schema (which you might well not
want to, because it's a bit slow), the bits you're missing are that you
want to exclude columns with attnum <= 0 (system columns) as well as
those with attisdropped (dropped columns). I don't care for the
subselect part of this either, mainly because it is not schema-aware.
Consider

select attname from pg_attribute
where attrelid = 'my_tablename'::regclass
and attnum > 0 and not attisdropped;

which generalizes to

select attname from pg_attribute
where attrelid = 'my_schema.my_tablename'::regclass
and attnum > 0 and not attisdropped;

whereas your original will not handle that easily.

regards, tom lane

In response to

Browse pgsql-admin by date

  From Date Subject
Next Message Jagadeesh 2008-09-23 03:41:11 Re: displaying enum
Previous Message Tom Lane 2008-09-23 03:15:29 Re: displaying enum