From 2f4f806acfbc471fc43df94a240b92a09dc9e4e0 Mon Sep 17 00:00:00 2001 From: Carlos Ruiz Date: Fri, 8 Feb 2013 10:07:27 -0500 Subject: [PATCH 1/4] Add registration to 2013012430719_IDEMPIERE-90.sql --- migration/i1.0a-release/oracle/2013012430719_IDEMPIERE-90.sql | 3 +++ .../i1.0a-release/postgresql/2013012430719_IDEMPIERE-90.sql | 3 +++ 2 files changed, 6 insertions(+) diff --git a/migration/i1.0a-release/oracle/2013012430719_IDEMPIERE-90.sql b/migration/i1.0a-release/oracle/2013012430719_IDEMPIERE-90.sql index eab6751c50..276261fa36 100644 --- a/migration/i1.0a-release/oracle/2013012430719_IDEMPIERE-90.sql +++ b/migration/i1.0a-release/oracle/2013012430719_IDEMPIERE-90.sql @@ -38,3 +38,6 @@ INSERT INTO AD_Message (AD_Client_ID,AD_Message_ID,AD_Message_UU,AD_Org_ID,Creat INSERT INTO AD_Message_Trl (AD_Language,AD_Message_ID, MsgText,MsgTip, IsTranslated,AD_Client_ID,AD_Org_ID,Created,Createdby,Updated,UpdatedBy,AD_Message_Trl_UU ) SELECT l.AD_Language,t.AD_Message_ID, t.MsgText,t.MsgTip, 'N',t.AD_Client_ID,t.AD_Org_ID,t.Created,t.Createdby,t.Updated,t.UpdatedBy,Generate_UUID() FROM AD_Language l, AD_Message t WHERE l.IsActive='Y' AND l.IsSystemLanguage='Y' AND l.IsBaseLanguage='N' AND t.AD_Message_ID=200138 AND NOT EXISTS (SELECT * FROM AD_Message_Trl tt WHERE tt.AD_Language=l.AD_Language AND tt.AD_Message_ID=t.AD_Message_ID) ; +SELECT register_migration_script('2013012430719_IDEMPIERE-90.sql') FROM dual +; + diff --git a/migration/i1.0a-release/postgresql/2013012430719_IDEMPIERE-90.sql b/migration/i1.0a-release/postgresql/2013012430719_IDEMPIERE-90.sql index 6ace886f75..f2d34354f7 100644 --- a/migration/i1.0a-release/postgresql/2013012430719_IDEMPIERE-90.sql +++ b/migration/i1.0a-release/postgresql/2013012430719_IDEMPIERE-90.sql @@ -38,3 +38,6 @@ INSERT INTO AD_Message (AD_Client_ID,AD_Message_ID,AD_Message_UU,AD_Org_ID,Creat INSERT INTO AD_Message_Trl (AD_Language,AD_Message_ID, MsgText,MsgTip, IsTranslated,AD_Client_ID,AD_Org_ID,Created,Createdby,Updated,UpdatedBy,AD_Message_Trl_UU ) SELECT l.AD_Language,t.AD_Message_ID, t.MsgText,t.MsgTip, 'N',t.AD_Client_ID,t.AD_Org_ID,t.Created,t.Createdby,t.Updated,t.UpdatedBy,Generate_UUID() FROM AD_Language l, AD_Message t WHERE l.IsActive='Y' AND l.IsSystemLanguage='Y' AND l.IsBaseLanguage='N' AND t.AD_Message_ID=200138 AND NOT EXISTS (SELECT * FROM AD_Message_Trl tt WHERE tt.AD_Language=l.AD_Language AND tt.AD_Message_ID=t.AD_Message_ID) ; +SELECT register_migration_script('2013012430719_IDEMPIERE-90.sql') FROM dual +; + From 1aaf64fa7be6d04ff4f28f3adfe31a79211388d7 Mon Sep 17 00:00:00 2001 From: Carlos Ruiz Date: Fri, 8 Feb 2013 10:52:01 -0500 Subject: [PATCH 2/4] remove duplicate (altercolumn was there at functions and now is duplicated at procedures) --- .../postgresql/procedures/altercolumn.sql | 111 ------------------ .../src/org/compiere/model/MTable.java | 52 ++++---- 2 files changed, 22 insertions(+), 141 deletions(-) delete mode 100644 db/ddlutils/postgresql/procedures/altercolumn.sql diff --git a/db/ddlutils/postgresql/procedures/altercolumn.sql b/db/ddlutils/postgresql/procedures/altercolumn.sql deleted file mode 100644 index f6f2c8e91f..0000000000 --- a/db/ddlutils/postgresql/procedures/altercolumn.sql +++ /dev/null @@ -1,111 +0,0 @@ -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 select a.relname, a.oid - 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' - loop - i := i + 1; - viewtext[i] := pg_get_viewdef(v.oid); - viewname[i] := v.relname; - end loop; - if i > 0 then - begin - for j in 1 .. i loop - command := 'drop view ' || viewname[j]; - execute command; - dropviews[j] := viewname[j]; - end loop; - exception - when others then - i := array_upper(dropviews, 1); - if i > 0 then - for j in 1 .. i loop - command := 'create or replace view ' || dropviews[j] || ' as ' || viewtext[j]; - execute command; - end loop; - end if; - raise exception 'Failed to recreate dependent view'; - end; - end if; - command := 'alter table ' || lower(tablename) || ' alter column ' || lower(columnname) || ' type ' || lower(datatype); - execute command; - i := array_upper(dropviews, 1); - if i > 0 then - for j in 1 .. i loop - command := 'create or replace view ' || dropviews[j] || ' as ' || viewtext[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; - 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'; - execute command; - elsif lower(nullclause) = 'null' then - command := 'alter table ' || lower(tablename) || ' alter column ' || lower(columnname) || ' drop not null'; - execute command; - end if; - end if; -end; -$$ language plpgsql; - -/* -create table t_alter_column -( tablename name, columnname name, datatype name, nullclause varchar(10), defaultclause varchar(200)); - -create rule alter_column_rule as on insert to t_alter_column -do instead select altercolumn(new.tablename, new.columnname, new.datatype, new.nullclause, -new.defaultclause); -*/ diff --git a/org.adempiere.base/src/org/compiere/model/MTable.java b/org.adempiere.base/src/org/compiere/model/MTable.java index 2ceb8c62a0..de34054496 100644 --- a/org.adempiere.base/src/org/compiere/model/MTable.java +++ b/org.adempiere.base/src/org/compiere/model/MTable.java @@ -104,30 +104,23 @@ public class MTable extends X_AD_Table MTable retValue = null; String sql = "SELECT * FROM AD_Table WHERE UPPER(TableName)=?"; PreparedStatement pstmt = null; + ResultSet rs = null; try { pstmt = DB.prepareStatement (sql, null); pstmt.setString(1, tableName.toUpperCase()); - ResultSet rs = pstmt.executeQuery (); - if (rs.next ()) + rs = pstmt.executeQuery (); + if (rs.next()) retValue = new MTable (ctx, rs, null); - rs.close (); - pstmt.close (); - pstmt = null; } catch (Exception e) { s_log.log(Level.SEVERE, sql, e); } - try + finally { - if (pstmt != null) - pstmt.close (); - pstmt = null; - } - catch (Exception e) - { - pstmt = null; + DB.close(rs, pstmt); + rs = null; pstmt = null; } if (retValue != null) @@ -229,37 +222,30 @@ public class MTable extends X_AD_Table return m_columns; m_columnNameMap = new HashMap(); m_columnIdMap = new HashMap(); - String sql = "SELECT * FROM AD_Column WHERE AD_Table_ID=? ORDER BY ColumnName"; + String sql = "SELECT * FROM AD_Column WHERE AD_Table_ID=? AND IsActive='Y' ORDER BY ColumnName"; ArrayList list = new ArrayList(); PreparedStatement pstmt = null; + ResultSet rs = null; try { pstmt = DB.prepareStatement (sql, get_TrxName()); pstmt.setInt (1, getAD_Table_ID()); - ResultSet rs = pstmt.executeQuery (); + rs = pstmt.executeQuery (); while (rs.next ()) { MColumn column = new MColumn (getCtx(), rs, get_TrxName()); list.add (column); m_columnNameMap.put(column.getColumnName().toUpperCase(), list.size() - 1); m_columnIdMap.put(column.getAD_Column_ID(), list.size() - 1); } - rs.close (); - pstmt.close (); - pstmt = null; } catch (Exception e) { log.log(Level.SEVERE, sql, e); } - try + finally { - if (pstmt != null) - pstmt.close (); - pstmt = null; - } - catch (Exception e) - { - pstmt = null; + DB.close(rs, pstmt); + rs = null; pstmt = null; } // m_columns = new MColumn[list.size ()]; @@ -476,6 +462,7 @@ public class MTable extends X_AD_Table finally { DB.close(rs, pstmt); + rs = null; pstmt = null; } return po; @@ -581,21 +568,26 @@ public class MTable extends X_AD_Table public static int getTable_ID(String tableName) { int retValue = 0; String SQL = "SELECT AD_Table_ID FROM AD_Table WHERE tablename = ?"; + PreparedStatement pstmt = null; + ResultSet rs = null; try { - PreparedStatement pstmt = DB.prepareStatement(SQL, null); + pstmt = DB.prepareStatement(SQL, null); pstmt.setString(1, tableName); - ResultSet rs = pstmt.executeQuery(); + rs = pstmt.executeQuery(); if (rs.next()) retValue = rs.getInt(1); - rs.close(); - pstmt.close(); } catch (Exception e) { s_log.log(Level.SEVERE, SQL, e); retValue = -1; } + finally + { + DB.close(rs, pstmt); + rs = null; pstmt = null; + } return retValue; } From 16298c2c294e6ccc129e59c8da203c1008e5fc99 Mon Sep 17 00:00:00 2001 From: Carlos Ruiz Date: Fri, 8 Feb 2013 13:17:23 -0500 Subject: [PATCH 3/4] Correct synchronize terminology - delete temporary patch --- .../postgresql/02_SynchronizeTerminology.sql | 3 +-- 1 file changed, 1 insertion(+), 2 deletions(-) diff --git a/migration/processes_post_migration/postgresql/02_SynchronizeTerminology.sql b/migration/processes_post_migration/postgresql/02_SynchronizeTerminology.sql index ab7867d1aa..ad083908ee 100644 --- a/migration/processes_post_migration/postgresql/02_SynchronizeTerminology.sql +++ b/migration/processes_post_migration/postgresql/02_SynchronizeTerminology.sql @@ -349,8 +349,7 @@ ORDER BY UPPER (columnname), columnname; UPDATE AD_PROCESS_PARA SET columnname = (SELECT e.columnname FROM AD_ELEMENT e - -- WHERE UPPER (e.columnname) = UPPER (AD_PROCESS_PARA.columnname)) - WHERE e.columnname = AD_PROCESS_PARA.columnname) -- Temporary patch Fixed Assets are broking it + WHERE UPPER (e.columnname) = UPPER (AD_PROCESS_PARA.columnname)) WHERE AD_PROCESS_PARA.iscentrallymaintained = 'Y' AND AD_PROCESS_PARA.isactive = 'Y' AND EXISTS ( From 298a49f444760c395ab1e7630629c439e925a3bf Mon Sep 17 00:00:00 2001 From: Carlos Ruiz Date: Fri, 8 Feb 2013 13:55:24 -0500 Subject: [PATCH 4/4] IDEMPIERE-621 Postgresql altercolumn not able to alter some tables --- .../postgresql/functions/altercolumn.sql | 71 ++++++---- ...201302081954_IDEMPIERE-621_altercolumn.sql | 4 + ...201302081954_IDEMPIERE-621_altercolumn.sql | 125 ++++++++++++++++++ 3 files changed, 175 insertions(+), 25 deletions(-) create mode 100644 migration/i1.0a-release/oracle/201302081954_IDEMPIERE-621_altercolumn.sql create mode 100644 migration/i1.0a-release/postgresql/201302081954_IDEMPIERE-621_altercolumn.sql diff --git a/db/ddlutils/postgresql/functions/altercolumn.sql b/db/ddlutils/postgresql/functions/altercolumn.sql index 2f385a14ed..5724d52e2c 100644 --- a/db/ddlutils/postgresql/functions/altercolumn.sql +++ b/db/ddlutils/postgresql/functions/altercolumn.sql @@ -14,13 +14,13 @@ declare 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; + 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', ''); @@ -31,28 +31,41 @@ begin end if; if lower(datatype) <> sqltype and lower(datatype) <> sqltype_short then i := 0; - for v in select a.relname, a.oid - 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' - loop + 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.oid); + 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; @@ -60,20 +73,23 @@ begin when others then i := array_upper(dropviews, 1); 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]; + raise notice 'executing -> %', 'create view ' || dropviews[j]; execute command; end loop; end if; - raise exception 'Failed to recreate dependent view'; + 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 1 .. i loop + 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; @@ -86,24 +102,29 @@ begin 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; +/* create table t_alter_column ( tablename name, columnname name, datatype name, nullclause varchar(10), defaultclause varchar(200)); create rule alter_column_rule as on insert to t_alter_column do instead select altercolumn(new.tablename, new.columnname, new.datatype, new.nullclause, new.defaultclause); +*/ diff --git a/migration/i1.0a-release/oracle/201302081954_IDEMPIERE-621_altercolumn.sql b/migration/i1.0a-release/oracle/201302081954_IDEMPIERE-621_altercolumn.sql new file mode 100644 index 0000000000..871002d904 --- /dev/null +++ b/migration/i1.0a-release/oracle/201302081954_IDEMPIERE-621_altercolumn.sql @@ -0,0 +1,4 @@ +-- just for postgresql +SELECT register_migration_script('201302081954_IDEMPIERE-621_altercolumn.sql') FROM dual +; + diff --git a/migration/i1.0a-release/postgresql/201302081954_IDEMPIERE-621_altercolumn.sql b/migration/i1.0a-release/postgresql/201302081954_IDEMPIERE-621_altercolumn.sql new file mode 100644 index 0000000000..b8ea1b5f73 --- /dev/null +++ b/migration/i1.0a-release/postgresql/201302081954_IDEMPIERE-621_altercolumn.sql @@ -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 +; +