"Andrus" <kobrule...@hot.ee> writes:

> Hi!
>
> Thank you.
>
>>This revised query should give you what you need:
>>SELECT 'ALTER TABLE ' || quote_ident(n.nspname) || '.'
>>            || quote_ident(c.relname)
>>            || ' ALTER COLUMN ' || quote_ident(a.attname) || ' TYPE varchar(' 
>> || i.character_maximum_length || ');'
>>  FROM pg_class c
>>    JOIN pg_namespace n ON n.oid = c.relnamespace
>>    JOIN pg_attribute a ON a.attrelid = c.oid
>>    JOIN pg_type t ON t.oid = a.atttypid
>>    JOIN information_schema.columns i ON (i.table_name = c.relname AND 
>> i.column_name = a.attname)
>>WHERE t.typname = 'bpchar'
>>   AND c.relkind = 'r'
>>   AND n.nspname <> 'pg_catalog' and not attisdropped;
>
> How to create single alter table command for every table ?
> Can we use string concat aggregate function or window functions or plpgsql or 
> something other ?

string_agg should do it:

SELECT 'ALTER TABLE ' || quote_ident(n.nspname) ||
       '.' || quote_ident(c.relname) || ' ' ||
       string_agg('ALTER COLUMN ' || quote_ident(a.attname) ||
       ' TYPE varchar(' || i.character_maximum_length || ')', ', ') || ';'
FROM pg_class c
JOIN pg_namespace n ON n.oid = c.relnamespace
JOIN pg_attribute a ON a.attrelid = c.oid
JOIN pg_type t ON t.oid = a.atttypid
JOIN information_schema.columns i ON
  i.table_name = c.relname AND i.column_name = a.attname
WHERE t.typname = 'bpchar'
  AND c.relkind = 'r'
  AND n.nspname <> 'pg_catalog' and not attisdropped
GROUP BY n.nspname, c.relname;



-- 
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general

Reply via email to