From: | hari(dot)fuchs(at)gmail(dot)com |
---|---|
To: | pgsql-general(at)postgresql(dot)org |
Subject: | Re: Converting char to varchar automatically |
Date: | 2014-10-09 12:12:25 |
Message-ID: | 871tqhphli.fsf@hf.protecting.net |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-general |
"Andrus" <kobruleht2(at)hot(dot)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;
From | Date | Subject | |
---|---|---|---|
Next Message | Sergey Konoplev | 2014-10-09 15:19:36 | Re: Understanding and implementing a GiST Index |
Previous Message | pinker | 2014-10-09 10:52:45 | Optimal checkpoint_setting |