Discussion:
Converting char to varchar automatically
Andrus
2014-10-06 10:29:11 UTC
Permalink
Database contains about 300 tables.
Most of them contain columns of char(n) type.

How to convert all those columns to varchar automatically ?

Is it possible to run some update commands in system tables for this ?
Or is it possible to create pgsql script which creates dynamically alter table alter column commands and PERFORMs them ?

Any tables have primary keys with char(n) columns and foreign keys on them. Foreign keys are deferrable and initially immediate.
Will foreign keys allow to perform such alter table alter column commands ?
Or is there better way.

Andrus.
Andy Colson
2014-10-06 14:04:09 UTC
Permalink
Post by Andrus
Database contains about 300 tables.
Most of them contain columns of char(n) type.
How to convert all those columns to varchar automatically ?
Is it possible to run some update commands in system tables for this ?
Or is it possible to create pgsql script which creates dynamically alter
table alter column commands and PERFORMs them ?
Any tables have primary keys with char(n) columns and foreign keys on
them. Foreign keys are deferrable and initially immediate.
Will foreign keys allow to perform such alter table alter column commands ?
Or is there better way.
Andrus.
I'd use a little perl.

Or if your editor has macros, you could use that.

change:
create table bob (
id char(50),
..
)

to

alter table bob alter id type varchar(50);

You might be able to query them out if you wanted:

select table_name, column_name, character_maximum_length
from information_schema.columns
where data_type = 'character'

Then use that to generate the alter table commands. Hum... this might
also work:

select 'alter table ' || table_name || ' alter ' || column_name .... etc

but that might try changing system tables which would be bad.

-Andy
--
Sent via pgsql-general mailing list (pgsql-***@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Melvin Davidson
2014-10-06 15:25:28 UTC
Permalink
This query might work for you, but double check all result statements first.

SELECT 'ALTER TABLE ' || quote_ident(n.nspname) || '.' ||
quote_ident(c.relname)
|| ' ALTER COLUMN ' || quote_ident(a.attname) || ' TYPE varchar;'
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
WHERE t.typname = 'char'
AND n.nspname <> 'pg_catalog';
Post by Andrus
Database contains about 300 tables.
Most of them contain columns of char(n) type.
How to convert all those columns to varchar automatically ?
Is it possible to run some update commands in system tables for this ?
Or is it possible to create pgsql script which creates dynamically alter
table alter column commands and PERFORMs them ?
Any tables have primary keys with char(n) columns and foreign keys on
them. Foreign keys are deferrable and initially immediate.
Will foreign keys allow to perform such alter table alter column commands ?
Or is there better way.
Andrus.
--
*Melvin Davidson*
I reserve the right to fantasize. Whether or not you
wish to share my fantasy is entirely up to you.
Andrus
2014-10-06 17:11:11 UTC
Permalink
Hi!
SELECT 'ALTER TABLE ' || quote_ident(n.nspname) || '.' || quote_ident(c.relname)
|| ' ALTER COLUMN ' || quote_ident(a.attname) || ' TYPE varchar;'
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
WHERE t.typname = 'char'
AND n.nspname <> 'pg_catalog';
It does not return any data.
Andrus.
h***@public.gmane.org
2014-10-06 17:41:20 UTC
Permalink
Post by Melvin Davidson
This query might work for you, but double check all result statements first.
SELECT 'ALTER TABLE ' || quote_ident(n.nspname) || '.' ||
quote_ident(c.relname)
|| ' ALTER COLUMN ' || quote_ident(a.attname) || ' TYPE varchar;'
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
WHERE t.typname = 'char'
AND n.nspname <> 'pg_catalog';
Make that "t.typname = 'bpchar'".
--
Sent via pgsql-general mailing list (pgsql-general-RDL/***@public.gmane.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Jim Nasby
2014-10-06 22:18:13 UTC
Permalink
Post by h***@public.gmane.org
Post by Melvin Davidson
This query might work for you, but double check all result statements first.
SELECT 'ALTER TABLE ' || quote_ident(n.nspname) || '.' ||
quote_ident(c.relname)
|| ' ALTER COLUMN ' || quote_ident(a.attname) || ' TYPE varchar;'
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
WHERE t.typname = 'char'
AND n.nspname <> 'pg_catalog';
Make that "t.typname = 'bpchar'".
Just a heads-up: each of those ALTER's will rewrite the table, so unless your database is tiny this will be a slow process. There's ways to work around that, but they're significantly more complicated.
--
Jim Nasby, Data Architect, Blue Treble
Data in Trouble? Get it in Treble! http://BlueTreble.com
--
Sent via pgsql-general mailing list (pgsql-***@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Melvin Davidson
2014-10-06 22:49:25 UTC
Permalink
Also, don't forget to test for relkind = 'r'. My bad from before.
Revised query is below.

SELECT 'ALTER TABLE ' || quote_ident(n.nspname) || '.'
|| quote_ident(c.relname)
|| ' ALTER COLUMN ' || quote_ident(a.attname) || ' TYPE
varchar;'
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
WHERE t.typname = 'bpchar'
AND c.relkind = 'r'
AND n.nspname <> 'pg_catalog';
Post by Jim Nasby
Post by Melvin Davidson
This query might work for you, but double check all result statements
Post by Melvin Davidson
first.
SELECT 'ALTER TABLE ' || quote_ident(n.nspname) || '.' ||
quote_ident(c.relname)
|| ' ALTER COLUMN ' || quote_ident(a.attname) || ' TYPE varchar;'
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
WHERE t.typname = 'char'
AND n.nspname <> 'pg_catalog';
Make that "t.typname = 'bpchar'".
Just a heads-up: each of those ALTER's will rewrite the table, so unless
your database is tiny this will be a slow process. There's ways to work
around that, but they're significantly more complicated.
--
Jim Nasby, Data Architect, Blue Treble
Data in Trouble? Get it in Treble! http://BlueTreble.com
--
http://www.postgresql.org/mailpref/pgsql-general
--
*Melvin Davidson*
I reserve the right to fantasize. Whether or not you
wish to share my fantasy is entirely up to you.
Tom Lane
2014-10-06 23:20:31 UTC
Permalink
Post by Melvin Davidson
Also, don't forget to test for relkind = 'r'. My bad from before.
In principle you need to ignore attisdropped columns as well.

Thinking about Jim's point about speed: it'd be wise to collapse any
updates for multiple columns in the same table into one ALTER command,
so that you only rewrite the table once, not once per column.

regards, tom lane
--
Sent via pgsql-general mailing list (pgsql-***@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Sergey Konoplev
2014-10-07 15:29:50 UTC
Permalink
BTW, where can I find a list of type1->type2 pairs that doesn't
require full table lock for conversion?

ps. Sorry for top posting.
Post by Tom Lane
Post by Melvin Davidson
Also, don't forget to test for relkind = 'r'. My bad from before.
In principle you need to ignore attisdropped columns as well.
Thinking about Jim's point about speed: it'd be wise to collapse any
updates for multiple columns in the same table into one ALTER command,
so that you only rewrite the table once, not once per column.
regards, tom lane
--
http://www.postgresql.org/mailpref/pgsql-general
--
Kind regards,
Sergey Konoplev
PostgreSQL Consultant and DBA

http://www.linkedin.com/in/grayhemp
+1 (415) 867-9984, +7 (499) 346-7196, +7 (988) 888-1979
***@gmail.com
--
Sent via pgsql-general mailing list (pgsql-***@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Tom Lane
2014-10-07 17:16:38 UTC
Permalink
Post by Sergey Konoplev
BTW, where can I find a list of type1->type2 pairs that doesn't
require full table lock for conversion?
There aren't any. Sometimes you can skip a table rewrite, but that
doesn't mean that a lesser lock is possible.

regards, tom lane
--
Sent via pgsql-general mailing list (pgsql-***@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Sergey Konoplev
2014-10-07 17:19:15 UTC
Permalink
Post by Tom Lane
Post by Sergey Konoplev
BTW, where can I find a list of type1->type2 pairs that doesn't
require full table lock for conversion?
There aren't any. Sometimes you can skip a table rewrite, but that
doesn't mean that a lesser lock is possible.
Oh, sorry, it was a typo, I meant "that doesn't require a full table rewrite".
--
Kind regards,
Sergey Konoplev
PostgreSQL Consultant and DBA

http://www.linkedin.com/in/grayhemp
+1 (415) 867-9984, +7 (499) 346-7196, +7 (988) 888-1979
***@gmail.com
--
Sent via pgsql-general mailing list (pgsql-***@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Tom Lane
2014-10-07 18:02:51 UTC
Permalink
Post by Sergey Konoplev
Post by Tom Lane
Post by Sergey Konoplev
BTW, where can I find a list of type1->type2 pairs that doesn't
require full table lock for conversion?
There aren't any. Sometimes you can skip a table rewrite, but that
doesn't mean that a lesser lock is possible.
Oh, sorry, it was a typo, I meant "that doesn't require a full table rewrite".
Roughly speaking it's the pairs that have a binary (WITHOUT FUNCTION)
coercion according to pg_cast, although we have special logic for a few
cases such as varchar(M) -> varchar(N).

regards, tom lane
--
Sent via pgsql-general mailing list (pgsql-***@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Sergey Konoplev
2014-10-07 19:28:04 UTC
Permalink
Post by Tom Lane
Roughly speaking it's the pairs that have a binary (WITHOUT FUNCTION)
coercion according to pg_cast, although we have special logic for a few
cases such as varchar(M) -> varchar(N).
That ones?

select t1.typname, t2.typname
from pg_cast, pg_type as t1, pg_type as t2
where
t1.oid = castsource and t2.oid = casttarget and
castmethod = 'b' order by 1, 2;
--
Kind regards,
Sergey Konoplev
PostgreSQL Consultant and DBA

http://www.linkedin.com/in/grayhemp
+1 (415) 867-9984, +7 (499) 346-7196, +7 (988) 888-1979
***@gmail.com
--
Sent via pgsql-general mailing list (pgsql-***@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Tom Lane
2014-10-06 23:16:56 UTC
Permalink
Post by Jim Nasby
Just a heads-up: each of those ALTER's will rewrite the table, so unless your database is tiny this will be a slow process. There's ways to work around that, but they're significantly more complicated.
I think he's trying to get rid of all the blank-padding he's got right
now, so table rewrites are unavoidable.

regards, tom lane
--
Sent via pgsql-general mailing list (pgsql-***@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Jim Nasby
2014-10-08 00:33:22 UTC
Permalink
Post by Tom Lane
Post by Jim Nasby
Just a heads-up: each of those ALTER's will rewrite the table, so unless your database is tiny this will be a slow process. There's ways to work around that, but they're significantly more complicated.
I think he's trying to get rid of all the blank-padding he's got right
now, so table rewrites are unavoidable.
Right, but there's other ways this could be done without requiring an outage. Like creating the new column with temporary name, put trigger on table, etc, etc.

Having dealt with an environment where downtime was thousands of dollars per minute I've gotten very creative at not taking outages. :)
--
Jim Nasby, Data Architect, Blue Treble Consulting
Data in Trouble? Get it in Treble! http://BlueTreble.com
--
Sent via pgsql-general mailing list (pgsql-***@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Andrus
2014-10-08 19:34:56 UTC
Permalink
Hi!

Using Toms recommendation I added not attisdropped and now got the query

SELECT 'ALTER TABLE ' || quote_ident(n.nspname) || '.'
|| quote_ident(c.relname)
|| ' ALTER COLUMN ' || quote_ident(a.attname) || ' TYPE
varchar;'
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
WHERE t.typname = 'bpchar'
AND c.relkind = 'r'
AND n.nspname <> 'pg_catalog' and not attisdropped;

Will this create commands which replace all user-defined char things in
database to varchar ?

"TYPE varchar" creates single character column so most alter table command
will fail.
How to change this so that original char column width is kept ?
I looked into tables used in this query but havent found column which holds
char column defined width.
How get it or is it better to re-write this query using informational_schema
?

How to change this query so that it creates single alter table command for
every table
(with multiple alter column clauses) to increase conversion speed ?

Andrus.
--
Sent via pgsql-general mailing list (pgsql-***@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Melvin Davidson
2014-10-08 21:19:21 UTC
Permalink
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;
Post by Andrus
Hi!
Using Toms recommendation I added not attisdropped and now got the query
SELECT 'ALTER TABLE ' || quote_ident(n.nspname) || '.'
|| quote_ident(c.relname)
|| ' ALTER COLUMN ' || quote_ident(a.attname) || ' TYPE varchar;'
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
WHERE t.typname = 'bpchar'
AND c.relkind = 'r'
AND n.nspname <> 'pg_catalog' and not attisdropped;
Will this create commands which replace all user-defined char things in
database to varchar ?
"TYPE varchar" creates single character column so most alter table command
will fail.
How to change this so that original char column width is kept ?
I looked into tables used in this query but havent found column which holds
char column defined width.
How get it or is it better to re-write this query using
informational_schema
?
How to change this query so that it creates single alter table command for
every table
(with multiple alter column clauses) to increase conversion speed ?
Andrus.
--
*Melvin Davidson*
I reserve the right to fantasize. Whether or not you
wish to share my fantasy is entirely up to you.
Andrus
2014-10-08 22:21:54 UTC
Permalink
Hi!

Thank you.
Post by Melvin Davidson
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 ?

Andrus.
Melvin Davidson
2014-10-08 23:08:45 UTC
Permalink
There really is no easy way to make a single ALTER for each table unless
you use a programming language. However, adding a
GROUP BY c.relname,
a.attname

would certainly simplify editing. Then you can combine all the
ALTER COLUMN's for each table.
Post by Andrus
Hi!
Thank you.
Post by Melvin Davidson
SELECT 'ALTER TABLE ' || quote_ident(n.nspname) || '.'
|| quote_ident(c.relname)
|| ' ALTER COLUMN ' || quote_ident(a.attname) || ' TYPE
varchar(' || i.character_maximum_length || ');'
Post by Melvin Davidson
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)
Post by Melvin Davidson
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 ?
Andrus.
--
*Melvin Davidson*
I reserve the right to fantasize. Whether or not you
wish to share my fantasy is entirely up to you.
Andrus
2014-10-09 05:41:52 UTC
Permalink
Hi!
There really is no easy way to make a single ALTER for each table unless you use a programming language.
I’snt SQL a programming language ?
However, adding a GROUP BY c.relname, a.attname
would certainly simplify editing. Then you can combine all the
ALTER COLUMN's for each table.
I wrote

with stem as (
SELECT 'ALTER TABLE ' || quote_ident(n.nspname) || '.'
|| quote_ident(c.relname) as prefix ,
string_agg(
' ALTER COLUMN ' || quote_ident(a.attname) || ' TYPE varchar(' || i.character_maximum_length ||')',
',' ) as body
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 1
)

select prefix || ' '|| body || ';' as statement
from stem

Is this prefect ?

Andrus.
Jim Nasby
2014-10-10 20:29:55 UTC
Permalink
Hi!
There really is no easy way to make a single ALTER for each table unless you use a programming language.
I’snt SQL a programming language ?
However, adding a GROUP BY c.relname,a.attname
would certainly simplify editing. Then you can combine all the
ALTER COLUMN's for each table.
with stem as (
SELECT 'ALTER TABLE ' || quote_ident(n.nspname) || '.'
|| quote_ident(c.relname) as prefix ,
string_agg(
' ALTER COLUMN ' || quote_ident(a.attname) || ' TYPE varchar(' || i.character_maximum_length ||')',
',' ) as body
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 1
)
select prefix || ' '|| body || ';' as statement
from stem
Is this prefect ?
That looks sane, though you didn't need the WITH.

In the future, you'll probably find it easier to go with information schema directly since then you don't have to worry about things like attisdropped.

Also, you mentioned that type "varchar" restricts length to 1. That's not true. varchar with no specifier has unlimited[1] length:

***@decina.attlocal=# create table t(t varchar);
CREATE TABLE
***@decina.attlocal=# \d t
Table "public.t"
Column | Type | Modifiers
--------+-------------------+-----------
t | character varying |

***@decina.attlocal=# insert into t values( '123' );
INSERT 0 1
***@decina.attlocal=#

[1]: In reality you're limited to ~1GB of data
--
Jim Nasby, Data Architect, Blue Treble Consulting
Data in Trouble? Get it in Treble! http://BlueTreble.com
--
Sent via pgsql-general mailing list (pgsql-***@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
h***@public.gmane.org
2014-10-09 12:12:25 UTC
Permalink
Post by Andrus
Hi!
Thank you.
Post by Melvin Davidson
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-RDL/***@public.gmane.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Andrus
2014-10-08 11:49:01 UTC
Permalink
Hi!

also, it generates statement which tries to change all columns to one character length columns.

Andrus.


From: Andrus
Sent: Monday, October 06, 2014 8:11 PM
To: Melvin Davidson
Cc: pgsql-***@postgresql.org
Subject: Re: [GENERAL] Converting char to varchar automatically

Hi!
SELECT 'ALTER TABLE ' || quote_ident(n.nspname) || '.' || quote_ident(c.relname)
|| ' ALTER COLUMN ' || quote_ident(a.attname) || ' TYPE varchar;'
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
WHERE t.typname = 'char'
AND n.nspname <> 'pg_catalog';
It does not return any data.
Andrus.
Loading...