IDEMPIERE-778 Improve PostgreSQL support.

This commit is contained in:
Heng Sin Low 2013-03-20 15:31:45 +08:00
parent 15b1404428
commit 5d9c7a3f1a
2 changed files with 154 additions and 61 deletions

View File

@ -155,7 +155,7 @@ public class ImportInventory extends SvrProcess
// Set Client, Org, Location, IsActive, Created/Updated // Set Client, Org, Location, IsActive, Created/Updated
sql = new StringBuilder ("UPDATE I_Inventory ") sql = new StringBuilder ("UPDATE I_Inventory ")
.append("SET AD_Client_ID = COALESCE (AD_Client_ID,").append (p_AD_Client_ID).append ("),") .append("SET AD_Client_ID = COALESCE (AD_Client_ID,").append (p_AD_Client_ID).append ("),")
.append(" AD_Org_ID = DECODE (NVL(AD_Org_ID),0,").append (p_AD_Org_ID).append (",AD_Org_ID),"); .append(" AD_Org_ID = CASE WHEN COALESCE(AD_Org_ID,0)=0 THEN ").append (p_AD_Org_ID).append (" ELSE AD_Org_ID END,");
if (p_MovementDate != null) if (p_MovementDate != null)
sql.append(" MovementDate = COALESCE (MovementDate,").append (DB.TO_DATE(p_MovementDate)).append ("),"); sql.append(" MovementDate = COALESCE (MovementDate,").append (DB.TO_DATE(p_MovementDate)).append ("),");
sql.append(" IsActive = COALESCE (IsActive, 'Y'),") sql.append(" IsActive = COALESCE (IsActive, 'Y'),")

View File

@ -583,30 +583,53 @@ public class FinReport extends SvrProcess
oper_1 = oper_2; oper_1 = oper_2;
oper_2 = temp; oper_2 = temp;
} }
StringBuilder sb = new StringBuilder ("UPDATE T_Report SET ("); StringBuilder sb = new StringBuilder ("UPDATE T_Report SET ");
for (int col : addList) if (DB.isPostgreSQL()) {
{ for (int col : addList)
if (col > 0) {
sb.append(","); if (col > 0)
sb.append ("Col_").append (col); sb.append(",");
} sb.append ("Col_").append (col)
sb.append(") = (SELECT "); .append("=")
for (int col : addList) .append("r2.c").append (col);
{ }
if (col > 0) sb.append(" FROM ( SELECT ");
sb.append(","); for (int col : addList)
sb.append ("COALESCE(SUM(r2.Col_").append (col).append("),0)"); {
if (col > 0)
sb.append(",");
sb.append ("COALESCE(SUM(r2.Col_").append (col).append("),0) AS c").append(col);
}
} else {
sb.append(" (");
for (int col : addList)
{
if (col > 0)
sb.append(",");
sb.append ("Col_").append (col);
}
sb.append(") = (SELECT ");
for (int col : addList)
{
if (col > 0)
sb.append(",");
sb.append ("COALESCE(SUM(r2.Col_").append (col).append("),0)");
}
} }
sb.append(" FROM T_Report r2 WHERE r2.AD_PInstance_ID=").append(getAD_PInstance_ID()) sb.append(" FROM T_Report r2 WHERE r2.AD_PInstance_ID=").append(getAD_PInstance_ID())
.append(" AND r2.PA_ReportLine_ID IN ("); .append(" AND r2.PA_ReportLine_ID IN (");
if (m_lines[line].isCalculationTypeAdd()) if (m_lines[line].isCalculationTypeAdd())
sb.append(oper_1).append(",").append(oper_2); sb.append(oper_1).append(",").append(oper_2);
else else
sb.append(getLineIDs (oper_1, oper_2)); // list of columns to add up sb.append(getLineIDs (oper_1, oper_2)); // list of columns to add up
sb.append(") AND ABS(r2.LevelNo)<1) " // 0=Line 1=Acct sb.append(") AND ABS(r2.LevelNo)<1) "); // 0=Line 1=Acct
+ "WHERE AD_PInstance_ID=").append(getAD_PInstance_ID()) if (DB.isPostgreSQL()) {
.append(" AND PA_ReportLine_ID=").append(m_lines[line].getPA_ReportLine_ID()) sb.append(" r2 ");
.append(" AND ABS(LevelNo)<1"); // not trx }
sb.append("WHERE T_Report.AD_PInstance_ID=").append(getAD_PInstance_ID())
.append(" AND T_Report.PA_ReportLine_ID=").append(m_lines[line].getPA_ReportLine_ID())
.append(" AND ABS(T_Report.LevelNo)<1"); // not trx
int no = DB.executeUpdate(sb.toString(), get_TrxName()); int no = DB.executeUpdate(sb.toString(), get_TrxName());
if (no != 1) if (no != 1)
log.log(Level.SEVERE, "(+) #=" + no + " for " + m_lines[line] + " - " + sb.toString()); log.log(Level.SEVERE, "(+) #=" + no + " for " + m_lines[line] + " - " + sb.toString());
@ -624,27 +647,52 @@ public class FinReport extends SvrProcess
int oper_2 = m_lines[line].getOper_2_ID(); int oper_2 = m_lines[line].getOper_2_ID();
// Step 1 - get First Value or 0 in there // Step 1 - get First Value or 0 in there
StringBuilder sb = new StringBuilder ("UPDATE T_Report SET ("); StringBuilder sb = new StringBuilder ("UPDATE T_Report SET ");
for (int col : notAddList) if (DB.isPostgreSQL())
{ {
if (col > 0) for (int col : notAddList)
sb.append(","); {
sb.append ("Col_").append (col); if (col > 0)
sb.append(",");
sb.append ("Col_").append (col)
.append("=r2.c").append(col);
}
sb.append(" FROM (SELECT ");
for (int col : notAddList)
{
if (col > 0)
sb.append(",");
sb.append ("COALESCE(r2.Col_").append (col).append(",0) AS c").append(col);
}
} }
sb.append(") = (SELECT "); else
for (int col : notAddList)
{ {
if (col > 0) sb.append(" (");
sb.append(","); for (int col : notAddList)
sb.append ("COALESCE(r2.Col_").append (col).append(",0)"); {
if (col > 0)
sb.append(",");
sb.append ("Col_").append (col);
}
sb.append(") = (SELECT ");
for (int col : notAddList)
{
if (col > 0)
sb.append(",");
sb.append ("COALESCE(r2.Col_").append (col).append(",0)");
}
} }
sb.append(" FROM T_Report r2 WHERE r2.AD_PInstance_ID=").append(getAD_PInstance_ID()) sb.append(" FROM T_Report r2 WHERE r2.AD_PInstance_ID=").append(getAD_PInstance_ID())
.append(" AND r2.PA_ReportLine_ID=").append(oper_1) .append(" AND r2.PA_ReportLine_ID=").append(oper_1)
.append(" AND r2.Record_ID=0 AND r2.Fact_Acct_ID=0) " .append(" AND r2.Record_ID=0 AND r2.Fact_Acct_ID=0) ");
if (DB.isPostgreSQL())
{
sb.append(" r2 ");
}
// //
+ "WHERE AD_PInstance_ID=").append(getAD_PInstance_ID()) sb.append("WHERE T_Report.AD_PInstance_ID=").append(getAD_PInstance_ID())
.append(" AND PA_ReportLine_ID=").append(m_lines[line].getPA_ReportLine_ID()) .append(" AND T_Report.PA_ReportLine_ID=").append(m_lines[line].getPA_ReportLine_ID())
.append(" AND ABS(LevelNo)<1"); // 0=Line 1=Acct .append(" AND ABS(T_Report.LevelNo)<1"); // 0=Line 1=Acct
int no = DB.executeUpdate(sb.toString(), get_TrxName()); int no = DB.executeUpdate(sb.toString(), get_TrxName());
if (no != 1) if (no != 1)
{ {
@ -653,41 +701,86 @@ public class FinReport extends SvrProcess
} }
// Step 2 - do Calculation with Second Value // Step 2 - do Calculation with Second Value
sb = new StringBuilder ("UPDATE T_Report r1 SET ("); sb = new StringBuilder ("UPDATE T_Report r1 SET ");
for (int col : notAddList) if (DB.isPostgreSQL())
{ {
if (col > 0) for (int col : notAddList)
sb.append(","); {
sb.append ("Col_").append (col); if (col > 0)
} sb.append(",");
sb.append(") = (SELECT "); sb.append ("Col_").append (col).append("=");
for (int col : notAddList) sb.append ("COALESCE(r1.Col_").append (col).append(",0)");
{ // fix bug [ 1563664 ] Errors in values shown in Financial Reports
if (col > 0) // Carlos Ruiz - globalqss
sb.append(","); if (m_lines[line].isCalculationTypeSubtract()) {
sb.append ("COALESCE(r1.Col_").append (col).append(",0)"); sb.append("-");
// fix bug [ 1563664 ] Errors in values shown in Financial Reports // Solution, for subtraction replace the null with 0, instead of 0.000000001
// Carlos Ruiz - globalqss sb.append (" r2.c").append (col);
if (m_lines[line].isCalculationTypeSubtract()) { } else {
sb.append("-"); // Solution, for division don't replace the null, convert 0 to null (avoid ORA-01476)
// Solution, for subtraction replace the null with 0, instead of 0.000000001 sb.append("/ r2.c").append(col);
sb.append ("COALESCE(r2.Col_").append (col).append(",0)"); }
} else { // end fix bug [ 1563664 ]
// Solution, for division don't replace the null, convert 0 to null (avoid ORA-01476) if (m_lines[line].isCalculationTypePercent())
sb.append("/"); sb.append(" *100");
sb.append ("DECODE (r2.Col_").append (col).append(", 0, NULL, r2.Col_").append (col).append(")"); }
sb.append(" FROM (SELECT ");
for (int col : notAddList)
{
if (col > 0)
sb.append(",");
if (m_lines[line].isCalculationTypeSubtract()) {
// Solution, for subtraction replace the null with 0, instead of 0.000000001
sb.append ("COALESCE(r2.Col_").append (col).append(",0) AS c").append(col);
} else {
// Solution, for division don't replace the null, convert 0 to null (avoid ORA-01476)
sb.append ("CASE WHEN r2.Col_").append (col).append("=0 THEN NULL ELSE r2.Col_").append (col).append(" END AS c").append(col);
}
}
}
else
{
sb.append(" (");
for (int col : notAddList)
{
if (col > 0)
sb.append(",");
sb.append ("Col_").append (col);
}
sb.append(") = (SELECT ");
for (int col : notAddList)
{
if (col > 0)
sb.append(",");
sb.append ("COALESCE(r1.Col_").append (col).append(",0)");
// fix bug [ 1563664 ] Errors in values shown in Financial Reports
// Carlos Ruiz - globalqss
if (m_lines[line].isCalculationTypeSubtract()) {
sb.append("-");
// Solution, for subtraction replace the null with 0, instead of 0.000000001
sb.append ("COALESCE(r2.Col_").append (col).append(",0)");
} else {
// Solution, for division don't replace the null, convert 0 to null (avoid ORA-01476)
sb.append("/");
sb.append ("CASE WHEN r2.Col_").append (col).append("=0 THEN NULL ELSE r2.Col_").append (col).append(" END");
}
// end fix bug [ 1563664 ]
if (m_lines[line].isCalculationTypePercent())
sb.append(" *100");
} }
// end fix bug [ 1563664 ]
if (m_lines[line].isCalculationTypePercent())
sb.append(" *100");
} }
sb.append(" FROM T_Report r2 WHERE r2.AD_PInstance_ID=").append(getAD_PInstance_ID()) sb.append(" FROM T_Report r2 WHERE r2.AD_PInstance_ID=").append(getAD_PInstance_ID())
.append(" AND r2.PA_ReportLine_ID=").append(oper_2) .append(" AND r2.PA_ReportLine_ID=").append(oper_2)
.append(" AND r2.Record_ID=0 AND r2.Fact_Acct_ID=0) " .append(" AND r2.Record_ID=0 AND r2.Fact_Acct_ID=0) ");
if (DB.isPostgreSQL())
{
sb.append(" r2 ");
}
// //
+ "WHERE AD_PInstance_ID=").append(getAD_PInstance_ID()) sb.append("WHERE r1.AD_PInstance_ID=").append(getAD_PInstance_ID())
.append(" AND PA_ReportLine_ID=").append(m_lines[line].getPA_ReportLine_ID()) .append(" AND r1.PA_ReportLine_ID=").append(m_lines[line].getPA_ReportLine_ID())
.append(" AND ABS(LevelNo)<1"); // 0=Line 1=Acct .append(" AND ABS(r1.LevelNo)<1"); // 0=Line 1=Acct
no = DB.executeUpdate(sb.toString(), get_TrxName()); no = DB.executeUpdate(sb.toString(), get_TrxName());
if (no != 1) if (no != 1)
log.severe ("(x) #=" + no + " for " + m_lines[line] + " - " + sb.toString ()); log.severe ("(x) #=" + no + " for " + m_lines[line] + " - " + sb.toString ());