diff --git a/db/postgresql/functions/altercolumn.sql b/db/postgresql/functions/altercolumn.sql index 6676e12671..53263d706a 100644 --- a/db/postgresql/functions/altercolumn.sql +++ b/db/postgresql/functions/altercolumn.sql @@ -1,4 +1,4 @@ -CREATE OR REPLACE FUNCTION adempiere.altercolumn(tablename name, columnname name, datatype name, nullclause character varying, defaultclause character varying, namespace name) +CREATE OR REPLACE FUNCTION adempiere.altercolumn(tablename name, columnname name, datatype name, nullclause character varying, defaultclause character varying) RETURNS void LANGUAGE plpgsql AS $function$ @@ -7,8 +7,6 @@ declare viewtext text[]; viewname name[]; dropviews name[]; - perms text[]; - privs text; i int; j int; v record; @@ -19,14 +17,12 @@ 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, pg_namespace + 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 - and pg_class.relnamespace = pg_namespace.oid - and pg_namespace.nspname = lower(namespace); + and atttypid = pg_type.oid; sqltype_short := sqltype; if typename = 'numeric' then sqltype_short := replace(sqltype, ',0', ''); @@ -40,11 +36,10 @@ begin 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, pg_namespace + 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' @@ -52,8 +47,6 @@ begin and e.attname = lower(columnname) and c.refobjsubid = e.attnum and a.relkind = 'v' - and a.relnamespace = pg_namespace.oid - and pg_namespace.nspname = lower(namespace) union all select distinct dependee.relname, dependee.oid, depv.depth+1 from pg_depend @@ -62,12 +55,9 @@ begin 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 - join pg_namespace on dependee.relnamespace = pg_namespace.oid - where pg_namespace.nspname = lower(namespace) ) select relname, viewoid, max(depth) from depv group by relname, viewoid order by 3 desc loop - raise notice 'view -> % %', v.relname, v.viewoid; i := i + 1; viewtext[i] := pg_get_viewdef(v.viewoid); viewname[i] := v.relname; @@ -75,11 +65,6 @@ begin if i > 0 then begin for j in 1 .. i loop - SELECT String_agg('grant ' || privilege_type || ' on ' || viewname[j] || ' to "' || grantee || '"', '; ') - into privs - FROM information_schema.role_table_grants - WHERE table_name=viewname[j]; - perms[j] := privs; command := 'drop view ' || viewname[j]; raise notice 'executing -> %', command; execute command; @@ -107,9 +92,6 @@ begin command := 'create or replace view ' || dropviews[j] || ' as ' || viewtext[j]; raise notice 'executing -> %', 'create view ' || dropviews[j]; execute command; - command := perms[j]; - raise notice 'executing -> %', 'grant ' || perms[j]; - execute command; end loop; end if; end if; diff --git a/migration/iD11/oracle/202402011900_IDEMPIERE-6027.sql b/migration/iD11/oracle/202402011900_IDEMPIERE-6027.sql new file mode 100644 index 0000000000..761988e7f5 --- /dev/null +++ b/migration/iD11/oracle/202402011900_IDEMPIERE-6027.sql @@ -0,0 +1,4 @@ +-- IDEMPIERE-6027 Alter column fail with PostgreSQL 16.1 +SELECT register_migration_script('202402011900_IDEMPIERE-6027.sql') FROM dual; + +--PostgreSQL only diff --git a/migration/iD11/postgresql/202402011900_IDEMPIERE-6027.sql b/migration/iD11/postgresql/202402011900_IDEMPIERE-6027.sql new file mode 100644 index 0000000000..949583a296 --- /dev/null +++ b/migration/iD11/postgresql/202402011900_IDEMPIERE-6027.sql @@ -0,0 +1,132 @@ +-- IDEMPIERE-6027 Alter column fail with PostgreSQL 16.1 +SELECT register_migration_script('202402011900_IDEMPIERE-6027.sql') FROM dual; + +DROP FUNCTION IF EXISTS adempiere.altercolumn(name, name, name, character varying, character varying, name) +; + +CREATE OR REPLACE FUNCTION adempiere.altercolumn(tablename name, columnname name, datatype name, nullclause character varying, defaultclause character varying) + RETURNS void + LANGUAGE plpgsql +AS $function$ +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 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 + if defaultclause ~ '.*[(].*[)].*' or lower(defaultclause) = 'current_timestamp' then + command := 'alter table ' || lower(tablename) || ' alter column ' || lower(columnname) || ' set default ' || defaultclause; + else + command := 'alter table ' || lower(tablename) || ' alter column ' || lower(columnname) || ' set default ''' || defaultclause || ''''; + end if; + 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; +$function$ diff --git a/org.idempiere.test/src/org/idempiere/test/AbstractTestCase.java b/org.idempiere.test/src/org/idempiere/test/AbstractTestCase.java index 2b8792ab33..0fc9b92024 100644 --- a/org.idempiere.test/src/org/idempiere/test/AbstractTestCase.java +++ b/org.idempiere.test/src/org/idempiere/test/AbstractTestCase.java @@ -53,11 +53,11 @@ public abstract class AbstractTestCase { private Trx trx; private LoginDetails loginDetails; - protected final int GARDEN_WORLD_CLIENT = 11; - protected final int GARDEN_WORLD_HQ_ORG = 11; - protected final int GARDEN_WORLD_ADMIN_USER = 101; - protected final int GARDEN_WORLD_ADMIN_ROLE = 102; - protected final int GARDEN_WORLD_HQ_WAREHOUSE = 103; + protected final int GARDEN_WORLD_CLIENT = DictionaryIDs.AD_Client.GARDEN_WORLD.id; + protected final int GARDEN_WORLD_HQ_ORG = DictionaryIDs.AD_Org.HQ.id; + protected final int GARDEN_WORLD_ADMIN_USER = DictionaryIDs.AD_User.GARDEN_ADMIN.id; + protected final int GARDEN_WORLD_ADMIN_ROLE = DictionaryIDs.AD_Role.GARDEN_WORLD_ADMIN.id; + protected final int GARDEN_WORLD_HQ_WAREHOUSE = DictionaryIDs.M_Warehouse.HQ.id; @BeforeAll /** diff --git a/org.idempiere.test/src/org/idempiere/test/DictionaryIDs.java b/org.idempiere.test/src/org/idempiere/test/DictionaryIDs.java index 4333921bfb..fd143db2bc 100644 --- a/org.idempiere.test/src/org/idempiere/test/DictionaryIDs.java +++ b/org.idempiere.test/src/org/idempiere/test/DictionaryIDs.java @@ -54,6 +54,17 @@ public final class DictionaryIDs { } } + public enum AD_Client { + GARDEN_WORLD(11), + SYSTEM(0); + + public final int id; + + private AD_Client(int id) { + this.id = id; + } + } + public enum AD_Org { GLOBAL(0), HQ(11), @@ -76,7 +87,8 @@ public final class DictionaryIDs { public enum AD_Role { GARDEN_WORLD_ADMIN(102), GARDEN_WORLD_USER(103), - GARDEN_WORLD_ADMIN_NOT_ADVANCED(200001); + GARDEN_WORLD_ADMIN_NOT_ADVANCED(200001), + SYSTEM_ADMINISTRATOR(0); public final int id; @@ -87,7 +99,8 @@ public final class DictionaryIDs { public enum AD_User { GARDEN_ADMIN(101), - GARDEN_USER(102); + GARDEN_USER(102), + SUPER_USER(100); public final int id; diff --git a/org.idempiere.test/src/org/idempiere/test/base/DBTest.java b/org.idempiere.test/src/org/idempiere/test/base/DBTest.java index a55a25982c..da8e19b2f2 100644 --- a/org.idempiere.test/src/org/idempiere/test/base/DBTest.java +++ b/org.idempiere.test/src/org/idempiere/test/base/DBTest.java @@ -28,18 +28,22 @@ import java.util.List; import org.adempiere.exceptions.DBException; import org.compiere.model.MBPartner; +import org.compiere.model.MColumn; import org.compiere.model.MOrder; import org.compiere.model.MTable; import org.compiere.model.X_Test; import org.compiere.util.DB; import org.compiere.util.Env; import org.compiere.util.KeyNamePair; +import org.compiere.util.Language; import org.compiere.util.TimeUtil; import org.compiere.util.Trx; import org.compiere.util.ValueNamePair; import org.idempiere.test.AbstractTestCase; import org.idempiere.test.DictionaryIDs; +import org.idempiere.test.LoginDetails; import org.junit.jupiter.api.Test; +import org.junit.jupiter.api.TestInfo; /** * Test {@link org.compiere.util.DB} class @@ -373,4 +377,37 @@ public class DBTest extends AbstractTestCase rollback(); } } + + @Test + public void testPostgreSQLSyncColumn() { + if (!DB.isPostgreSQL() || !DB.getDatabase().isNativeMode()) + return; + + MTable table = MTable.get(MOrder.Table_ID); + MColumn column = table.getColumn("Description"); + MColumn description = new MColumn(Env.getCtx(), column.getAD_Column_ID(), getTrxName()); + description.setFieldLength(description.getFieldLength()+1); + description.saveEx(); + + String error = null; + String sql = description.getSQLModify(table, false); + try { + DB.executeUpdateEx(sql, getTrxName()); + } catch (Exception ex) { + error = ex.getMessage(); + } + assertNull(error, error); + } + + @Override + protected LoginDetails newLoginDetails(TestInfo testInfo) { + if (testInfo.getTestMethod().get().getName().equals("testPostgreSQLSyncColumn")) { + return new LoginDetails(DictionaryIDs.AD_Client.SYSTEM.id, 0, DictionaryIDs.AD_User.SUPER_USER.id, DictionaryIDs.AD_Role.SYSTEM_ADMINISTRATOR.id, + DictionaryIDs.AD_Role.SYSTEM_ADMINISTRATOR.id, new Timestamp(System.currentTimeMillis()), Language.getLanguage("en_US")); + } else { + return super.newLoginDetails(testInfo); + } + } + + }