IDEMPIERE-621 Postgresql altercolumn not able to alter some tables

This commit is contained in:
Carlos Ruiz 2013-02-08 13:55:24 -05:00
parent 16298c2c29
commit 298a49f444
3 changed files with 175 additions and 25 deletions

View File

@ -14,13 +14,13 @@ declare
begin begin
if datatype is not null then if datatype is not null then
select pg_type.typname, format_type(pg_type.oid, pg_attribute.atttypmod) select pg_type.typname, format_type(pg_type.oid, pg_attribute.atttypmod)
into typename, sqltype into typename, sqltype
from pg_class, pg_attribute, pg_type from pg_class, pg_attribute, pg_type
where relname = lower(tablename) where relname = lower(tablename)
and relkind = 'r' and relkind = 'r'
and pg_class.oid = pg_attribute.attrelid and pg_class.oid = pg_attribute.attrelid
and attname = lower(columnname) and attname = lower(columnname)
and atttypid = pg_type.oid; and atttypid = pg_type.oid;
sqltype_short := sqltype; sqltype_short := sqltype;
if typename = 'numeric' then if typename = 'numeric' then
sqltype_short := replace(sqltype, ',0', ''); sqltype_short := replace(sqltype, ',0', '');
@ -31,28 +31,41 @@ begin
end if; end if;
if lower(datatype) <> sqltype and lower(datatype) <> sqltype_short then if lower(datatype) <> sqltype and lower(datatype) <> sqltype_short then
i := 0; i := 0;
for v in select a.relname, a.oid for v in
from pg_class a, pg_depend b, pg_depend c, pg_class d, pg_attribute e with recursive depv(relname, viewoid, depth) as (
where a.oid = b.refobjid select distinct a.relname, a.oid, 1
and b.objid = c.objid from pg_class a, pg_depend b, pg_depend c, pg_class d, pg_attribute e
and b.refobjid <> c.refobjid where a.oid = b.refobjid
and b.deptype = 'n' and b.objid = c.objid
and c.refobjid = d.oid and b.refobjid <> c.refobjid
and d.relname = lower(tablename) and b.deptype = 'n'
and d.relkind = 'r' and c.refobjid = d.oid
and d.oid = e.attrelid and d.relname = lower(tablename)
and e.attname = lower(columnname) and d.relkind = 'r'
and c.refobjsubid = e.attnum and d.oid = e.attrelid
and a.relkind = 'v' and e.attname = lower(columnname)
loop and c.refobjsubid = e.attnum
and a.relkind = 'v'
union all
select distinct dependee.relname, dependee.oid, depv.depth+1
from pg_depend
join pg_rewrite on pg_depend.objid = pg_rewrite.oid
join pg_class as dependee on pg_rewrite.ev_class = dependee.oid
join pg_class as dependent on pg_depend.refobjid = dependent.oid
join pg_attribute ON pg_depend.refobjid = pg_attribute.attrelid and pg_depend.refobjsubid = pg_attribute.attnum and pg_attribute.attnum > 0
join depv on dependent.relname = depv.relname
)
select relname, viewoid, max(depth) from depv group by relname, viewoid order by 3 desc
loop
i := i + 1; i := i + 1;
viewtext[i] := pg_get_viewdef(v.oid); viewtext[i] := pg_get_viewdef(v.viewoid);
viewname[i] := v.relname; viewname[i] := v.relname;
end loop; end loop;
if i > 0 then if i > 0 then
begin begin
for j in 1 .. i loop for j in 1 .. i loop
command := 'drop view ' || viewname[j]; command := 'drop view ' || viewname[j];
raise notice 'executing -> %', command;
execute command; execute command;
dropviews[j] := viewname[j]; dropviews[j] := viewname[j];
end loop; end loop;
@ -60,20 +73,23 @@ begin
when others then when others then
i := array_upper(dropviews, 1); i := array_upper(dropviews, 1);
if i > 0 then if i > 0 then
for j in 1 .. i loop for j in reverse i .. 1 loop
command := 'create or replace view ' || dropviews[j] || ' as ' || viewtext[j]; command := 'create or replace view ' || dropviews[j] || ' as ' || viewtext[j];
raise notice 'executing -> %', 'create view ' || dropviews[j];
execute command; execute command;
end loop; end loop;
end if; end if;
raise exception 'Failed to recreate dependent view'; raise exception 'Failed to recreate dependent view. SQLERRM=%', SQLERRM;
end; end;
end if; end if;
command := 'alter table ' || lower(tablename) || ' alter column ' || lower(columnname) || ' type ' || lower(datatype); command := 'alter table ' || lower(tablename) || ' alter column ' || lower(columnname) || ' type ' || lower(datatype);
raise notice 'executing -> %', command;
execute command; execute command;
i := array_upper(dropviews, 1); i := array_upper(dropviews, 1);
if i > 0 then if i > 0 then
for j in 1 .. i loop for j in reverse i .. 1 loop
command := 'create or replace view ' || dropviews[j] || ' as ' || viewtext[j]; command := 'create or replace view ' || dropviews[j] || ' as ' || viewtext[j];
raise notice 'executing -> %', 'create view ' || dropviews[j];
execute command; execute command;
end loop; end loop;
end if; end if;
@ -86,24 +102,29 @@ begin
else else
command := 'alter table ' || lower(tablename) || ' alter column ' || lower(columnname) || ' set default ''' || defaultclause || ''''; command := 'alter table ' || lower(tablename) || ' alter column ' || lower(columnname) || ' set default ''' || defaultclause || '''';
end if; end if;
raise notice 'executing -> %', command;
execute command; execute command;
end if; end if;
if nullclause is not null then if nullclause is not null then
if lower(nullclause) = 'not null' then if lower(nullclause) = 'not null' then
command := 'alter table ' || lower(tablename) || ' alter column ' || lower(columnname) || ' set not null'; command := 'alter table ' || lower(tablename) || ' alter column ' || lower(columnname) || ' set not null';
raise notice 'executing -> %', command;
execute command; execute command;
elsif lower(nullclause) = 'null' then elsif lower(nullclause) = 'null' then
command := 'alter table ' || lower(tablename) || ' alter column ' || lower(columnname) || ' drop not null'; command := 'alter table ' || lower(tablename) || ' alter column ' || lower(columnname) || ' drop not null';
raise notice 'executing -> %', command;
execute command; execute command;
end if; end if;
end if; end if;
end; end;
$$ language plpgsql; $$ language plpgsql;
/*
create table t_alter_column create table t_alter_column
( tablename name, columnname name, datatype name, nullclause varchar(10), defaultclause varchar(200)); ( tablename name, columnname name, datatype name, nullclause varchar(10), defaultclause varchar(200));
create rule alter_column_rule as on insert to t_alter_column create rule alter_column_rule as on insert to t_alter_column
do instead select altercolumn(new.tablename, new.columnname, new.datatype, new.nullclause, do instead select altercolumn(new.tablename, new.columnname, new.datatype, new.nullclause,
new.defaultclause); new.defaultclause);
*/

View File

@ -0,0 +1,4 @@
-- just for postgresql
SELECT register_migration_script('201302081954_IDEMPIERE-621_altercolumn.sql') FROM dual
;

View File

@ -0,0 +1,125 @@
create or replace function altercolumn(tablename name, columnname name, datatype name,
nullclause varchar, defaultclause varchar) returns void as $$
declare
command text;
viewtext text[];
viewname name[];
dropviews name[];
i int;
j int;
v record;
sqltype text;
sqltype_short text;
typename name;
begin
if datatype is not null then
select pg_type.typname, format_type(pg_type.oid, pg_attribute.atttypmod)
into typename, sqltype
from pg_class, pg_attribute, pg_type
where relname = lower(tablename)
and relkind = 'r'
and pg_class.oid = pg_attribute.attrelid
and attname = lower(columnname)
and atttypid = pg_type.oid;
sqltype_short := sqltype;
if typename = 'numeric' then
sqltype_short := replace(sqltype, ',0', '');
elsif strpos(sqltype,'character varying') = 1 then
sqltype_short := replace(sqltype, 'character varying', 'varchar');
elsif sqltype = 'timestamp without time zone' then
sqltype_short := 'timestamp';
end if;
if lower(datatype) <> sqltype and lower(datatype) <> sqltype_short then
i := 0;
for v in
with recursive depv(relname, viewoid, depth) as (
select distinct a.relname, a.oid, 1
from pg_class a, pg_depend b, pg_depend c, pg_class d, pg_attribute e
where a.oid = b.refobjid
and b.objid = c.objid
and b.refobjid <> c.refobjid
and b.deptype = 'n'
and c.refobjid = d.oid
and d.relname = lower(tablename)
and d.relkind = 'r'
and d.oid = e.attrelid
and e.attname = lower(columnname)
and c.refobjsubid = e.attnum
and a.relkind = 'v'
union all
select distinct dependee.relname, dependee.oid, depv.depth+1
from pg_depend
join pg_rewrite on pg_depend.objid = pg_rewrite.oid
join pg_class as dependee on pg_rewrite.ev_class = dependee.oid
join pg_class as dependent on pg_depend.refobjid = dependent.oid
join pg_attribute ON pg_depend.refobjid = pg_attribute.attrelid and pg_depend.refobjsubid = pg_attribute.attnum and pg_attribute.attnum > 0
join depv on dependent.relname = depv.relname
)
select relname, viewoid, max(depth) from depv group by relname, viewoid order by 3 desc
loop
i := i + 1;
viewtext[i] := pg_get_viewdef(v.viewoid);
viewname[i] := v.relname;
end loop;
if i > 0 then
begin
for j in 1 .. i loop
command := 'drop view ' || viewname[j];
raise notice 'executing -> %', command;
execute command;
dropviews[j] := viewname[j];
end loop;
exception
when others then
i := array_upper(dropviews, 1);
if i > 0 then
for j in reverse i .. 1 loop
command := 'create or replace view ' || dropviews[j] || ' as ' || viewtext[j];
raise notice 'executing -> %', 'create view ' || dropviews[j];
execute command;
end loop;
end if;
raise exception 'Failed to recreate dependent view. SQLERRM=%', SQLERRM;
end;
end if;
command := 'alter table ' || lower(tablename) || ' alter column ' || lower(columnname) || ' type ' || lower(datatype);
raise notice 'executing -> %', command;
execute command;
i := array_upper(dropviews, 1);
if i > 0 then
for j in reverse i .. 1 loop
command := 'create or replace view ' || dropviews[j] || ' as ' || viewtext[j];
raise notice 'executing -> %', 'create view ' || dropviews[j];
execute command;
end loop;
end if;
end if;
end if;
if defaultclause is not null then
if lower(defaultclause) = 'null' then
command := 'alter table ' || lower(tablename) || ' alter column ' || lower(columnname) || ' drop default ';
else
command := 'alter table ' || lower(tablename) || ' alter column ' || lower(columnname) || ' set default ''' || defaultclause || '''';
end if;
raise notice 'executing -> %', command;
execute command;
end if;
if nullclause is not null then
if lower(nullclause) = 'not null' then
command := 'alter table ' || lower(tablename) || ' alter column ' || lower(columnname) || ' set not null';
raise notice 'executing -> %', command;
execute command;
elsif lower(nullclause) = 'null' then
command := 'alter table ' || lower(tablename) || ' alter column ' || lower(columnname) || ' drop not null';
raise notice 'executing -> %', command;
execute command;
end if;
end if;
end;
$$ language plpgsql;
SELECT register_migration_script('201302081954_IDEMPIERE-621_altercolumn.sql') FROM dual
;