Speed up financial reports
[ 1642765 ] problem with Facc_act_balance slow financial report Implemented a better approach (suggested by Heng Sin) - Dropped Fact_Acct_Balance table - Created Fact_Acct_Balance view for backward compatibility - Created speed up index on Fact_Acct - Replaced the accesses to Fact_Acct_Balance by accessing directly Fact_Acct in code - Don't need to "update balances" anymore
This commit is contained in:
parent
ef26def1bb
commit
f9fc05acb1
|
@ -112,9 +112,6 @@ public class FactAcctReset extends SvrProcess
|
|||
{
|
||||
pstmt = null;
|
||||
}
|
||||
// Balances
|
||||
if (p_DeletePosting)
|
||||
FinBalance.updateBalanceClient(getCtx(), p_AD_Client_ID); // delete
|
||||
//
|
||||
return "@Updated@ = " + m_countReset + ", @Deleted@ = " + m_countDelete;
|
||||
} // doIt
|
||||
|
|
|
@ -1,175 +0,0 @@
|
|||
/******************************************************************************
|
||||
* Product: Adempiere ERP & CRM Smart Business Solution *
|
||||
* Copyright (C) 1999-2006 ComPiere, Inc. All Rights Reserved. *
|
||||
* This program is free software; you can redistribute it and/or modify it *
|
||||
* under the terms version 2 of the GNU General Public License as published *
|
||||
* by the Free Software Foundation. This program is distributed in the hope *
|
||||
* that it will be useful, but WITHOUT ANY WARRANTY; without even the implied *
|
||||
* warranty of MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. *
|
||||
* See the GNU General Public License for more details. *
|
||||
* You should have received a copy of the GNU General Public License along *
|
||||
* with this program; if not, write to the Free Software Foundation, Inc., *
|
||||
* 59 Temple Place, Suite 330, Boston, MA 02111-1307 USA. *
|
||||
* For the text or an alternative of this public license, you may reach us *
|
||||
* ComPiere, Inc., 2620 Augustine Dr. #245, Santa Clara, CA 95054, USA *
|
||||
* or via info@compiere.org or http://www.compiere.org/license.html *
|
||||
*****************************************************************************/
|
||||
package org.compiere.report;
|
||||
|
||||
import java.math.*;
|
||||
import java.util.*;
|
||||
|
||||
import org.compiere.model.*;
|
||||
import org.compiere.process.*;
|
||||
import java.util.logging.*;
|
||||
import org.compiere.util.*;
|
||||
|
||||
/**
|
||||
* Financial Balance Maintenance Engine
|
||||
*
|
||||
* @author Jorg Janke
|
||||
* @version $Id: FinBalance.java,v 1.2 2006/07/30 00:51:05 jjanke Exp $
|
||||
* @author Low Heng Sin
|
||||
* - Make always delete + insert to resolved Feature Request [ 1557707 ] and
|
||||
* bug [1619917]
|
||||
*/
|
||||
public class FinBalance extends SvrProcess
|
||||
{
|
||||
/**
|
||||
* Financial Report Constructor
|
||||
*/
|
||||
public FinBalance()
|
||||
{
|
||||
super();
|
||||
log.info(" ");
|
||||
} // FinBalance
|
||||
|
||||
/** Logger */
|
||||
protected static CLogger s_log = CLogger.getCLogger (FinBalance.class);
|
||||
|
||||
private int p_C_AcctSchema_ID = 0;
|
||||
|
||||
/**
|
||||
* Prepare - e.g., get Parameters.
|
||||
*/
|
||||
protected void prepare()
|
||||
{
|
||||
// Parameter
|
||||
ProcessInfoParameter[] para = getParameter();
|
||||
for (int i = 0; i < para.length; i++)
|
||||
{
|
||||
String name = para[i].getParameterName();
|
||||
if (para[i].getParameter() == null)
|
||||
;
|
||||
else if (name.equals("C_AcctSchema_ID"))
|
||||
p_C_AcctSchema_ID = ((BigDecimal)para[i].getParameter()).intValue();
|
||||
else
|
||||
log.log(Level.SEVERE, "Unknown Parameter: " + name);
|
||||
}
|
||||
} // prepare
|
||||
|
||||
|
||||
/**
|
||||
* Perform process.
|
||||
* @return Message to be translated
|
||||
* @throws Exception
|
||||
*/
|
||||
protected String doIt() throws java.lang.Exception
|
||||
{
|
||||
log.fine("C_AcctSchema_ID=" + p_C_AcctSchema_ID);
|
||||
if (p_C_AcctSchema_ID != 0)
|
||||
updateBalance(p_C_AcctSchema_ID);
|
||||
else
|
||||
updateBalanceClient(getCtx(), getAD_Client_ID());
|
||||
return "";
|
||||
} // doIt
|
||||
|
||||
/**
|
||||
* Delete Balances
|
||||
* @param C_AcctSchema_ID accounting schema 0 for all
|
||||
* @return Message to be translated
|
||||
*/
|
||||
public static String deleteBalance (int C_AcctSchema_ID)
|
||||
{
|
||||
StringBuffer sql = new StringBuffer ("DELETE FROM Fact_Acct_Balance WHERE ");
|
||||
if (C_AcctSchema_ID != 0)
|
||||
sql.append ("C_AcctSchema_ID=").append (C_AcctSchema_ID);
|
||||
//
|
||||
int no = DB.executeUpdate(sql.toString(), null); // out of trx
|
||||
String msg = "@Deleted@=" + no;
|
||||
s_log.fine("C_AcctSchema_ID=" + C_AcctSchema_ID + " #=" + no);
|
||||
//
|
||||
return msg;
|
||||
} // deleteBalance
|
||||
|
||||
/**
|
||||
* Update / Create Balances.
|
||||
* Called from FinReport, FactAcctReset (indirect)
|
||||
* @param C_AcctSchema_ID accounting schema
|
||||
* @param deleteFirst delete (all) balances first
|
||||
* @return Message to be translated
|
||||
*/
|
||||
public static String updateBalance (int C_AcctSchema_ID)
|
||||
{
|
||||
s_log.info("C_AcctSchema_ID=" + C_AcctSchema_ID);
|
||||
long start = System.currentTimeMillis();
|
||||
|
||||
int no = DB.executeUpdate("DELETE FROM Fact_Acct_Balance WHERE C_AcctSchema_ID=?",
|
||||
C_AcctSchema_ID, null);
|
||||
s_log.fine("Deleted=" + no);
|
||||
|
||||
String sql = null;
|
||||
/** Insert **/
|
||||
sql = "INSERT INTO Fact_Acct_Balance "
|
||||
+ "(AD_Client_ID, AD_Org_ID, C_AcctSchema_ID, DateAcct,"
|
||||
+ " Account_ID, PostingType, M_Product_ID, C_BPartner_ID,"
|
||||
+ " C_Project_ID, AD_OrgTrx_ID, C_SalesRegion_ID,C_Activity_ID,"
|
||||
+ " C_Campaign_ID, C_LocTo_ID, C_LocFrom_ID, User1_ID, User2_ID, UserElement1_ID, UserElement2_ID, GL_Budget_ID,"
|
||||
+ " AmtAcctDr, AmtAcctCr, Qty) "
|
||||
//
|
||||
+ "SELECT AD_Client_ID, AD_Org_ID, C_AcctSchema_ID, TRUNC(DateAcct),"
|
||||
+ " Account_ID, PostingType, M_Product_ID, C_BPartner_ID,"
|
||||
+ " C_Project_ID, AD_OrgTrx_ID, C_SalesRegion_ID,C_Activity_ID,"
|
||||
+ " C_Campaign_ID, C_LocTo_ID, C_LocFrom_ID, User1_ID, User2_ID, UserElement1_ID, UserElement2_ID, GL_Budget_ID,"
|
||||
+ " COALESCE(SUM(AmtAcctDr),0), COALESCE(SUM(AmtAcctCr),0), COALESCE(SUM(Qty),0) "
|
||||
+ "FROM Fact_Acct a "
|
||||
+ "WHERE C_AcctSchema_ID=" + C_AcctSchema_ID;
|
||||
|
||||
sql += " GROUP BY AD_Client_ID,AD_Org_ID, C_AcctSchema_ID, TRUNC(DateAcct),"
|
||||
+ " Account_ID, PostingType, M_Product_ID, C_BPartner_ID,"
|
||||
+ " C_Project_ID, AD_OrgTrx_ID, C_SalesRegion_ID, C_Activity_ID,"
|
||||
+ " C_Campaign_ID, C_LocTo_ID, C_LocFrom_ID, User1_ID, User2_ID, UserElement1_ID, UserElement2_ID, GL_Budget_ID";
|
||||
no = DB.executeUpdate(sql, null);
|
||||
s_log.fine("Inserts=" + no);
|
||||
|
||||
start = System.currentTimeMillis() - start;
|
||||
s_log.info((start/1000) + " sec");
|
||||
return "";
|
||||
} // updateBalance
|
||||
|
||||
/**
|
||||
* Update Balance of Client
|
||||
* @param ctx context
|
||||
* @param AD_Client_ID client
|
||||
* @param deleteFirst delete first
|
||||
* @return error or ""
|
||||
*/
|
||||
public static String updateBalanceClient (Properties ctx, int AD_Client_ID)
|
||||
{
|
||||
MAcctSchema[] ass = MAcctSchema.getClientAcctSchema(ctx, AD_Client_ID);
|
||||
for (int i = 0; i < ass.length; i++)
|
||||
updateBalance(ass[i].getC_AcctSchema_ID());
|
||||
return "";
|
||||
} // updateBalanceClient
|
||||
|
||||
|
||||
/**************************************************************************
|
||||
* Test
|
||||
* @param args ignored
|
||||
*/
|
||||
public static void main(String[] args)
|
||||
{
|
||||
FinBalance finBalance1 = new FinBalance();
|
||||
} // main
|
||||
|
||||
} // FinBalance
|
|
@ -1,5 +1,5 @@
|
|||
/******************************************************************************
|
||||
* Product: Adempiere ERP & CRM Smart Business Solution *
|
||||
* Product: Adempiere ERP & CRM Smart Business Solution *
|
||||
* Copyright (C) 1999-2006 ComPiere, Inc. All Rights Reserved. *
|
||||
* This program is free software; you can redistribute it and/or modify it *
|
||||
* under the terms version 2 of the GNU General Public License as published *
|
||||
|
@ -59,8 +59,6 @@ public class FinReport extends SvrProcess
|
|||
private int p_C_SalesRegion_ID = 0;
|
||||
/** Campaign Parameter */
|
||||
private int p_C_Campaign_ID = 0;
|
||||
/** Update Balances Parameter */
|
||||
private boolean p_UpdateBalances = true;
|
||||
/** Details before Lines */
|
||||
private boolean p_DetailsSourceFirst = false;
|
||||
/** Hierarchy */
|
||||
|
@ -115,8 +113,6 @@ public class FinReport extends SvrProcess
|
|||
p_C_SalesRegion_ID = ((BigDecimal)para[i].getParameter()).intValue();
|
||||
else if (name.equals("C_Campaign_ID"))
|
||||
p_C_Campaign_ID = ((BigDecimal)para[i].getParameter()).intValue();
|
||||
else if (name.equals("UpdateBalances"))
|
||||
p_UpdateBalances = "Y".equals(para[i].getParameter());
|
||||
else if (name.equals("DetailsSourceFirst"))
|
||||
p_DetailsSourceFirst = "Y".equals(para[i].getParameter());
|
||||
else
|
||||
|
@ -242,10 +238,6 @@ public class FinReport extends SvrProcess
|
|||
int no = DB.executeUpdate(sql.toString(), get_TrxName());
|
||||
log.fine("Report Lines = " + no);
|
||||
|
||||
// Update AcctSchema Balances
|
||||
if (p_UpdateBalances)
|
||||
FinBalance.updateBalance (m_report.getC_AcctSchema_ID());
|
||||
|
||||
// ** Get Data ** Segment Values
|
||||
m_columns = m_report.getColumnSet().getColumns();
|
||||
if (m_columns.length == 0)
|
||||
|
@ -324,7 +316,7 @@ public class FinReport extends SvrProcess
|
|||
}
|
||||
|
||||
// Get Period/Date info
|
||||
select.append(" FROM Fact_Acct_Balance WHERE DateAcct ");
|
||||
select.append(" FROM Fact_Acct WHERE TRUNC(DateAcct) ");
|
||||
BigDecimal relativeOffset = null; // current
|
||||
if (m_columns[col].isColumnTypeRelativePeriod())
|
||||
relativeOffset = m_columns[col].getRelativePeriod();
|
||||
|
@ -1020,7 +1012,7 @@ public class FinReport extends SvrProcess
|
|||
}
|
||||
|
||||
// Get Period info
|
||||
select.append(" FROM Fact_Acct_Balance fb WHERE DateAcct ");
|
||||
select.append(" FROM Fact_Acct fb WHERE TRUNC(DateAcct) ");
|
||||
FinReportPeriod frp = getPeriod (m_columns[col].getRelativePeriod());
|
||||
if (m_lines[line].getAmountType() != null) // line amount type overwrites column
|
||||
{
|
||||
|
@ -1104,7 +1096,7 @@ public class FinReport extends SvrProcess
|
|||
insert.append("(").append(select).append(")");
|
||||
}
|
||||
//
|
||||
insert.append(" FROM Fact_Acct_Balance x WHERE ")
|
||||
insert.append(" FROM Fact_Acct x WHERE ")
|
||||
.append(m_lines[line].getWhereClause(p_PA_Hierarchy_ID)); // (sources, posting type)
|
||||
String s = m_report.getWhereClause();
|
||||
if (s != null && s.length() > 0)
|
||||
|
@ -1190,7 +1182,7 @@ public class FinReport extends SvrProcess
|
|||
insert.append(" AND ").append(s);
|
||||
// Period restriction
|
||||
FinReportPeriod frp = getPeriod (0);
|
||||
insert.append(" AND DateAcct ")
|
||||
insert.append(" AND TRUNC(DateAcct) ")
|
||||
.append(frp.getPeriodWhere());
|
||||
// PostingType ??
|
||||
// if (!m_lines[line].isPostingType()) // only if not defined on line
|
||||
|
|
|
@ -1,5 +1,5 @@
|
|||
/******************************************************************************
|
||||
* Product: Adempiere ERP & CRM Smart Business Solution *
|
||||
* Product: Adempiere ERP & CRM Smart Business Solution *
|
||||
* Copyright (C) 1999-2006 ComPiere, Inc. All Rights Reserved. *
|
||||
* This program is free software; you can redistribute it and/or modify it *
|
||||
* under the terms version 2 of the GNU General Public License as published *
|
||||
|
@ -71,8 +71,6 @@ public class FinStatement extends SvrProcess
|
|||
private int p_C_SalesRegion_ID = 0;
|
||||
/** Campaign Parameter */
|
||||
private int p_C_Campaign_ID = 0;
|
||||
/** Update Balances Parameter */
|
||||
private boolean p_UpdateBalances = true;
|
||||
/** Hierarchy */
|
||||
private int p_PA_Hierarchy_ID = 0;
|
||||
|
||||
|
@ -127,8 +125,6 @@ public class FinStatement extends SvrProcess
|
|||
p_C_SalesRegion_ID = ((BigDecimal)para[i].getParameter()).intValue();
|
||||
else if (name.equals("C_Campaign_ID"))
|
||||
p_C_Campaign_ID = ((BigDecimal)para[i].getParameter()).intValue();
|
||||
else if (name.equals("UpdateBalances"))
|
||||
p_UpdateBalances = "Y".equals(para[i].getParameter());
|
||||
else
|
||||
log.log(Level.SEVERE, "Unknown Parameter: " + name);
|
||||
}
|
||||
|
@ -237,10 +233,6 @@ public class FinStatement extends SvrProcess
|
|||
*/
|
||||
protected String doIt()
|
||||
{
|
||||
// Update AcctSchema Balances
|
||||
if (p_UpdateBalances)
|
||||
FinBalance.updateBalance (p_C_AcctSchema_ID);
|
||||
|
||||
createBalanceLine();
|
||||
createDetailLines();
|
||||
|
||||
|
@ -267,9 +259,9 @@ public class FinStatement extends SvrProcess
|
|||
.append(DB.TO_DATE(p_DateAcct_From, true)).append(",")
|
||||
.append(DB.TO_STRING(Msg.getMsg(Env.getCtx(), "BeginningBalance"))).append(",NULL,"
|
||||
+ "COALESCE(SUM(AmtAcctDr),0), COALESCE(SUM(AmtAcctCr),0), COALESCE(SUM(AmtAcctDr-AmtAcctCr),0), COALESCE(SUM(Qty),0) "
|
||||
+ "FROM Fact_Acct_Balance "
|
||||
+ "FROM Fact_Acct "
|
||||
+ "WHERE ").append(m_parameterWhere)
|
||||
.append(" AND DateAcct < ").append(DB.TO_DATE(p_DateAcct_From));
|
||||
.append(" AND TRUNC(DateAcct) < ").append(DB.TO_DATE(p_DateAcct_From));
|
||||
|
||||
// Start Beginning of Year
|
||||
if (p_Account_ID > 0)
|
||||
|
@ -279,7 +271,7 @@ public class FinStatement extends SvrProcess
|
|||
{
|
||||
MPeriod first = MPeriod.getFirstInYear (getCtx(), p_DateAcct_From);
|
||||
if (first != null)
|
||||
sb.append(" AND DateAcct >= ").append(DB.TO_DATE(first.getStartDate()));
|
||||
sb.append(" AND TRUNC(DateAcct) >= ").append(DB.TO_DATE(first.getStartDate()));
|
||||
else
|
||||
log.log(Level.SEVERE, "First period not found");
|
||||
}
|
||||
|
@ -300,11 +292,11 @@ public class FinStatement extends SvrProcess
|
|||
+ "DateAcct, Name, Description,"
|
||||
+ "AmtAcctDr, AmtAcctCr, Balance, Qty) ");
|
||||
sb.append("SELECT ").append(getAD_PInstance_ID()).append(",Fact_Acct_ID,1,")
|
||||
.append("DateAcct,NULL,NULL,"
|
||||
.append("TRUNC(DateAcct),NULL,NULL,"
|
||||
+ "AmtAcctDr, AmtAcctCr, AmtAcctDr-AmtAcctCr, Qty "
|
||||
+ "FROM Fact_Acct "
|
||||
+ "WHERE ").append(m_parameterWhere)
|
||||
.append(" AND DateAcct BETWEEN ").append(DB.TO_DATE(p_DateAcct_From))
|
||||
.append(" AND TRUNC(DateAcct) BETWEEN ").append(DB.TO_DATE(p_DateAcct_From))
|
||||
.append(" AND ").append(DB.TO_DATE(p_DateAcct_To));
|
||||
//
|
||||
int no = DB.executeUpdate(sb.toString(), get_TrxName());
|
||||
|
|
|
@ -1,111 +0,0 @@
|
|||
<?xml version="1.0"?>
|
||||
<!DOCTYPE database SYSTEM "http://db.apache.org/torque/dtd/database">
|
||||
<database name="default" defaultIdMethod="none">
|
||||
<table name="FACT_ACCT_BALANCE">
|
||||
<column name="AD_CLIENT_ID" primaryKey="false" required="true" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="AD_ORG_ID" primaryKey="false" required="true" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="C_ACCTSCHEMA_ID" primaryKey="false" required="true" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="DATEACCT" primaryKey="false" required="true" type="TIMESTAMP" size="7" autoIncrement="false"/>
|
||||
<column name="ACCOUNT_ID" primaryKey="false" required="true" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="POSTINGTYPE" primaryKey="false" required="true" type="CHAR" size="1" autoIncrement="false"/>
|
||||
<column name="M_PRODUCT_ID" primaryKey="false" required="false" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="C_BPARTNER_ID" primaryKey="false" required="false" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="C_PROJECT_ID" primaryKey="false" required="false" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="AD_ORGTRX_ID" primaryKey="false" required="false" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="C_SALESREGION_ID" primaryKey="false" required="false" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="C_ACTIVITY_ID" primaryKey="false" required="false" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="C_CAMPAIGN_ID" primaryKey="false" required="false" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="C_LOCTO_ID" primaryKey="false" required="false" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="C_LOCFROM_ID" primaryKey="false" required="false" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="USER1_ID" primaryKey="false" required="false" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="USER2_ID" primaryKey="false" required="false" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="GL_BUDGET_ID" primaryKey="false" required="false" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="AMTACCTDR" primaryKey="false" required="true" type="DECIMAL" default="0" autoIncrement="false"/>
|
||||
<column name="AMTACCTCR" primaryKey="false" required="true" type="DECIMAL" default="0" autoIncrement="false"/>
|
||||
<column name="QTY" primaryKey="false" required="true" type="DECIMAL" default="0" autoIncrement="false"/>
|
||||
<column name="CREATEDBY" primaryKey="false" required="true" type="ID" size="10" default="0" autoIncrement="false"/>
|
||||
<column name="CREATED" primaryKey="false" required="true" type="TIMESTAMP" size="7" default="CURRENT_TIMESTAMP" autoIncrement="false"/>
|
||||
<column name="UPDATEDBY" primaryKey="false" required="true" type="ID" size="10" default="0" autoIncrement="false"/>
|
||||
<column name="UPDATED" primaryKey="false" required="true" type="TIMESTAMP" size="7" default="CURRENT_TIMESTAMP" autoIncrement="false"/>
|
||||
<column name="ISACTIVE" primaryKey="false" required="true" type="CHAR" size="1" default="Y" autoIncrement="false"/>
|
||||
<column name="C_SUBACCT_ID" primaryKey="false" required="false" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="USERELEMENT1_ID" primaryKey="false" required="false" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="USERELEMENT2_ID" primaryKey="false" required="false" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="C_PROJECTPHASE_ID" primaryKey="false" required="false" type="ID" size="10" autoIncrement="false"/>
|
||||
<column name="C_PROJECTTASK_ID" primaryKey="false" required="false" type="ID" size="10" autoIncrement="false"/>
|
||||
<foreign-key foreignTable="AD_CLIENT" name="ADCLIENT_FACTACCTBAL" onDelete="none">
|
||||
<reference local="AD_CLIENT_ID" foreign="AD_CLIENT_ID"/>
|
||||
</foreign-key>
|
||||
<foreign-key foreignTable="AD_ORG" name="ADORG_FACTACCTBAL" onDelete="cascade">
|
||||
<reference local="AD_ORG_ID" foreign="AD_ORG_ID"/>
|
||||
</foreign-key>
|
||||
<foreign-key foreignTable="AD_ORG" name="ADORGTRX_FACTACCTBAL" onDelete="none">
|
||||
<reference local="AD_ORGTRX_ID" foreign="AD_ORG_ID"/>
|
||||
</foreign-key>
|
||||
<foreign-key foreignTable="C_ACCTSCHEMA" name="CACCTSCHEMA_FACTACCTBAL" onDelete="none">
|
||||
<reference local="C_ACCTSCHEMA_ID" foreign="C_ACCTSCHEMA_ID"/>
|
||||
</foreign-key>
|
||||
<foreign-key foreignTable="C_ACTIVITY" name="CACTIVITY_FACTACCTBAL" onDelete="none">
|
||||
<reference local="C_ACTIVITY_ID" foreign="C_ACTIVITY_ID"/>
|
||||
</foreign-key>
|
||||
<foreign-key foreignTable="C_BPARTNER" name="CBPARTNER_FACTACCTBAL" onDelete="none">
|
||||
<reference local="C_BPARTNER_ID" foreign="C_BPARTNER_ID"/>
|
||||
</foreign-key>
|
||||
<foreign-key foreignTable="C_CAMPAIGN" name="CCAMPAIGN_FACTACCTBAL" onDelete="none">
|
||||
<reference local="C_CAMPAIGN_ID" foreign="C_CAMPAIGN_ID"/>
|
||||
</foreign-key>
|
||||
<foreign-key foreignTable="C_ELEMENTVALUE" name="CELEMENTVALUEU2_FACTACCTBAL" onDelete="none">
|
||||
<reference local="USER2_ID" foreign="C_ELEMENTVALUE_ID"/>
|
||||
</foreign-key>
|
||||
<foreign-key foreignTable="C_ELEMENTVALUE" name="CELEMENTVALUEU1_FACTACCTBAL" onDelete="none">
|
||||
<reference local="USER1_ID" foreign="C_ELEMENTVALUE_ID"/>
|
||||
</foreign-key>
|
||||
<foreign-key foreignTable="C_ELEMENTVALUE" name="CELEMENTVALUEACCT_FACTACCTBAL" onDelete="none">
|
||||
<reference local="ACCOUNT_ID" foreign="C_ELEMENTVALUE_ID"/>
|
||||
</foreign-key>
|
||||
<foreign-key foreignTable="C_LOCATION" name="CLOCTO_FACTACCTBAL" onDelete="none">
|
||||
<reference local="C_LOCTO_ID" foreign="C_LOCATION_ID"/>
|
||||
</foreign-key>
|
||||
<foreign-key foreignTable="C_LOCATION" name="CLOCFROM_FACTACCTBALANCE" onDelete="none">
|
||||
<reference local="C_LOCFROM_ID" foreign="C_LOCATION_ID"/>
|
||||
</foreign-key>
|
||||
<foreign-key foreignTable="C_PROJECT" name="CPROJECT_FACTACCTBAL" onDelete="none">
|
||||
<reference local="C_PROJECT_ID" foreign="C_PROJECT_ID"/>
|
||||
</foreign-key>
|
||||
<foreign-key foreignTable="C_PROJECTPHASE" name="CPROJECTPHASE_FACTACCTBALANCE" onDelete="setnull">
|
||||
<reference local="C_PROJECTPHASE_ID" foreign="C_PROJECTPHASE_ID"/>
|
||||
</foreign-key>
|
||||
<foreign-key foreignTable="C_PROJECTTASK" name="CPROJECTTASK_FACTACCTBALANCE" onDelete="setnull">
|
||||
<reference local="C_PROJECTTASK_ID" foreign="C_PROJECTTASK_ID"/>
|
||||
</foreign-key>
|
||||
<foreign-key foreignTable="C_SALESREGION" name="CSALESREGION_FACTACCTBAL" onDelete="none">
|
||||
<reference local="C_SALESREGION_ID" foreign="C_SALESREGION_ID"/>
|
||||
</foreign-key>
|
||||
<foreign-key foreignTable="GL_BUDGET" name="GLBUDGET_FACTACCTBALANCE" onDelete="none">
|
||||
<reference local="GL_BUDGET_ID" foreign="GL_BUDGET_ID"/>
|
||||
</foreign-key>
|
||||
<foreign-key foreignTable="M_PRODUCT" name="MPRODUCT_FACTACCTBAL" onDelete="none">
|
||||
<reference local="M_PRODUCT_ID" foreign="M_PRODUCT_ID"/>
|
||||
</foreign-key>
|
||||
<unique name="FACT_ACCT_BALANCE_AKEY">
|
||||
<unique-column name="AD_CLIENT_ID"/>
|
||||
<unique-column name="AD_ORG_ID"/>
|
||||
<unique-column name="C_ACCTSCHEMA_ID"/>
|
||||
<unique-column name="DATEACCT"/>
|
||||
<unique-column name="ACCOUNT_ID"/>
|
||||
<unique-column name="POSTINGTYPE"/>
|
||||
<unique-column name="M_PRODUCT_ID"/>
|
||||
<unique-column name="C_BPARTNER_ID"/>
|
||||
<unique-column name="C_PROJECT_ID"/>
|
||||
<unique-column name="AD_ORGTRX_ID"/>
|
||||
<unique-column name="C_SALESREGION_ID"/>
|
||||
<unique-column name="C_ACTIVITY_ID"/>
|
||||
<unique-column name="C_CAMPAIGN_ID"/>
|
||||
<unique-column name="C_LOCTO_ID"/>
|
||||
<unique-column name="C_LOCFROM_ID"/>
|
||||
<unique-column name="USER1_ID"/>
|
||||
<unique-column name="USER2_ID"/>
|
||||
<unique-column name="GL_BUDGET_ID"/>
|
||||
</unique>
|
||||
</table>
|
||||
</database>
|
|
@ -0,0 +1,24 @@
|
|||
CREATE OR REPLACE VIEW fact_acct_balance
|
||||
AS
|
||||
SELECT ad_client_id, ad_org_id, c_acctschema_id,
|
||||
TRUNC (dateacct) as dateacct, account_id, postingtype,
|
||||
m_product_id, c_bpartner_id, c_project_id, ad_orgtrx_id,
|
||||
c_salesregion_id, c_activity_id, c_campaign_id, c_locto_id,
|
||||
c_locfrom_id, user1_id, user2_id, gl_budget_id,
|
||||
COALESCE (SUM (amtacctdr), 0) as amtacctdr,
|
||||
COALESCE (SUM (amtacctcr), 0) as amtacctcr,
|
||||
COALESCE (SUM (qty), 0) as qty, MAX (createdby) as createdby,
|
||||
MAX (created) as created, MAX (updatedby) as updatedby,
|
||||
MAX (updated) as updated, MAX (isactive) as isactive,
|
||||
MAX (c_subacct_id) as c_subacct_id, userelement1_id,
|
||||
userelement2_id, MAX (c_projectphase_id) as c_projectphase_id,
|
||||
MAX (c_projecttask_id) as c_projecttask_id
|
||||
FROM fact_acct a
|
||||
GROUP BY ad_client_id, ad_org_id, c_acctschema_id,
|
||||
TRUNC (dateacct), account_id, postingtype,
|
||||
m_product_id, c_bpartner_id, c_project_id, ad_orgtrx_id,
|
||||
c_salesregion_id, c_activity_id, c_campaign_id, c_locto_id,
|
||||
c_locfrom_id, user1_id, user2_id,
|
||||
userelement1_id, userelement2_id,
|
||||
gl_budget_id
|
||||
;
|
|
@ -0,0 +1,24 @@
|
|||
CREATE OR REPLACE VIEW fact_acct_balance
|
||||
AS
|
||||
SELECT ad_client_id, ad_org_id, c_acctschema_id,
|
||||
TRUNC (dateacct) as dateacct, account_id, postingtype,
|
||||
m_product_id, c_bpartner_id, c_project_id, ad_orgtrx_id,
|
||||
c_salesregion_id, c_activity_id, c_campaign_id, c_locto_id,
|
||||
c_locfrom_id, user1_id, user2_id, gl_budget_id,
|
||||
COALESCE (SUM (amtacctdr), 0) as amtacctdr,
|
||||
COALESCE (SUM (amtacctcr), 0) as amtacctcr,
|
||||
COALESCE (SUM (qty), 0) as qty, MAX (createdby) as createdby,
|
||||
MAX (created) as created, MAX (updatedby) as updatedby,
|
||||
MAX (updated) as updated, MAX (isactive) as isactive,
|
||||
MAX (c_subacct_id) as c_subacct_id, userelement1_id,
|
||||
userelement2_id, MAX (c_projectphase_id) as c_projectphase_id,
|
||||
MAX (c_projecttask_id) as c_projecttask_id
|
||||
FROM fact_acct a
|
||||
GROUP BY ad_client_id, ad_org_id, c_acctschema_id,
|
||||
TRUNC (dateacct), account_id, postingtype,
|
||||
m_product_id, c_bpartner_id, c_project_id, ad_orgtrx_id,
|
||||
c_salesregion_id, c_activity_id, c_campaign_id, c_locto_id,
|
||||
c_locfrom_id, user1_id, user2_id,
|
||||
userelement1_id, userelement2_id,
|
||||
gl_budget_id
|
||||
;
|
|
@ -0,0 +1,67 @@
|
|||
-- 1642765 - problem with Facc_act_balance slow financial report
|
||||
|
||||
DROP TABLE FACT_ACCT_BALANCE
|
||||
;
|
||||
|
||||
CREATE OR REPLACE VIEW fact_acct_balance
|
||||
AS
|
||||
SELECT ad_client_id, ad_org_id, c_acctschema_id,
|
||||
TRUNC (dateacct) as dateacct, account_id, postingtype,
|
||||
m_product_id, c_bpartner_id, c_project_id, ad_orgtrx_id,
|
||||
c_salesregion_id, c_activity_id, c_campaign_id, c_locto_id,
|
||||
c_locfrom_id, user1_id, user2_id, gl_budget_id,
|
||||
COALESCE (SUM (amtacctdr), 0) as amtacctdr,
|
||||
COALESCE (SUM (amtacctcr), 0) as amtacctcr,
|
||||
COALESCE (SUM (qty), 0) as qty, MAX (createdby) as createdby,
|
||||
MAX (created) as created, MAX (updatedby) as updatedby,
|
||||
MAX (updated) as updated, MAX (isactive) as isactive,
|
||||
MAX (c_subacct_id) as c_subacct_id, userelement1_id,
|
||||
userelement2_id, MAX (c_projectphase_id) as c_projectphase_id,
|
||||
MAX (c_projecttask_id) as c_projecttask_id
|
||||
FROM fact_acct a
|
||||
GROUP BY ad_client_id, ad_org_id, c_acctschema_id,
|
||||
TRUNC (dateacct), account_id, postingtype,
|
||||
m_product_id, c_bpartner_id, c_project_id, ad_orgtrx_id,
|
||||
c_salesregion_id, c_activity_id, c_campaign_id, c_locto_id,
|
||||
c_locfrom_id, user1_id, user2_id,
|
||||
userelement1_id, userelement2_id,
|
||||
gl_budget_id
|
||||
;
|
||||
|
||||
CREATE INDEX FACT_ACCT_TRUNC_DATEACCT ON FACT_ACCT (TRUNC(dateacct))
|
||||
;
|
||||
|
||||
-- Jul 15, 2008 1:27:48 AM COT
|
||||
-- 1642765 - problem with Facc_act_balance slow financial report
|
||||
UPDATE AD_Table SET IsView='Y',Updated=TO_DATE('2008-07-15 01:27:48','YYYY-MM-DD HH24:MI:SS'),UpdatedBy=100 WHERE AD_Table_ID=547
|
||||
;
|
||||
|
||||
-- Jul 15, 2008 1:31:01 AM COT
|
||||
-- 1642765 - problem with Facc_act_balance slow financial report
|
||||
UPDATE AD_Process_Para SET IsActive = 'N',Updated=TO_DATE('2008-07-15 01:27:48','YYYY-MM-DD HH24:MI:SS'),UpdatedBy=100 WHERE AD_Process_Para_ID=283
|
||||
;
|
||||
|
||||
-- Jul 15, 2008 1:32:35 AM COT
|
||||
-- 1642765 - problem with Facc_act_balance slow financial report
|
||||
UPDATE AD_Menu SET IsActive = 'N',Updated=TO_DATE('2008-07-15 01:27:48','YYYY-MM-DD HH24:MI:SS'),UpdatedBy=100 WHERE AD_Menu_ID=393
|
||||
;
|
||||
|
||||
-- Jul 15, 2008 1:32:44 AM COT
|
||||
-- 1642765 - problem with Facc_act_balance slow financial report
|
||||
UPDATE AD_Process SET IsActive = 'N',Updated=TO_DATE('2008-07-15 01:27:48','YYYY-MM-DD HH24:MI:SS'),UpdatedBy=100 WHERE AD_Process_ID=203
|
||||
;
|
||||
|
||||
-- Jul 15, 2008 1:34:15 AM COT
|
||||
-- 1642765 - problem with Facc_act_balance slow financial report
|
||||
UPDATE AD_Process_Para SET IsActive = 'N',Updated=TO_DATE('2008-07-15 01:27:48','YYYY-MM-DD HH24:MI:SS'),UpdatedBy=100 WHERE AD_Process_Para_ID=453
|
||||
;
|
||||
|
||||
-- Jul 15, 2008 1:34:26 AM COT
|
||||
-- 1642765 - problem with Facc_act_balance slow financial report
|
||||
UPDATE AD_Process_Para SET IsActive = 'N',Updated=TO_DATE('2008-07-15 01:27:48','YYYY-MM-DD HH24:MI:SS'),UpdatedBy=100 WHERE AD_Process_Para_ID=53123
|
||||
;
|
||||
|
||||
-- Jul 15, 2008 1:35:05 AM COT
|
||||
-- 1642765 - problem with Facc_act_balance slow financial report
|
||||
UPDATE AD_Process_Para SET IsActive = 'N',Updated=TO_DATE('2008-07-15 01:27:48','YYYY-MM-DD HH24:MI:SS'),UpdatedBy=100 WHERE AD_Process_Para_ID=454
|
||||
;
|
|
@ -0,0 +1,67 @@
|
|||
-- 1642765 - problem with Facc_act_balance slow financial report
|
||||
|
||||
DROP TABLE FACT_ACCT_BALANCE
|
||||
;
|
||||
|
||||
CREATE OR REPLACE VIEW fact_acct_balance
|
||||
AS
|
||||
SELECT ad_client_id, ad_org_id, c_acctschema_id,
|
||||
TRUNC (dateacct) as dateacct, account_id, postingtype,
|
||||
m_product_id, c_bpartner_id, c_project_id, ad_orgtrx_id,
|
||||
c_salesregion_id, c_activity_id, c_campaign_id, c_locto_id,
|
||||
c_locfrom_id, user1_id, user2_id, gl_budget_id,
|
||||
COALESCE (SUM (amtacctdr), 0) as amtacctdr,
|
||||
COALESCE (SUM (amtacctcr), 0) as amtacctcr,
|
||||
COALESCE (SUM (qty), 0) as qty, MAX (createdby) as createdby,
|
||||
MAX (created) as created, MAX (updatedby) as updatedby,
|
||||
MAX (updated) as updated, MAX (isactive) as isactive,
|
||||
MAX (c_subacct_id) as c_subacct_id, userelement1_id,
|
||||
userelement2_id, MAX (c_projectphase_id) as c_projectphase_id,
|
||||
MAX (c_projecttask_id) as c_projecttask_id
|
||||
FROM fact_acct a
|
||||
GROUP BY ad_client_id, ad_org_id, c_acctschema_id,
|
||||
TRUNC (dateacct), account_id, postingtype,
|
||||
m_product_id, c_bpartner_id, c_project_id, ad_orgtrx_id,
|
||||
c_salesregion_id, c_activity_id, c_campaign_id, c_locto_id,
|
||||
c_locfrom_id, user1_id, user2_id,
|
||||
userelement1_id, userelement2_id,
|
||||
gl_budget_id
|
||||
;
|
||||
|
||||
CREATE INDEX FACT_ACCT_TRUNC_DATEACCT ON FACT_ACCT (CAST(dateacct AS DATE))
|
||||
;
|
||||
|
||||
-- Jul 15, 2008 1:27:48 AM COT
|
||||
-- 1642765 - problem with Facc_act_balance slow financial report
|
||||
UPDATE AD_Table SET IsView='Y',Updated=TO_TIMESTAMP('2008-07-15 01:27:48','YYYY-MM-DD HH24:MI:SS'),UpdatedBy=100 WHERE AD_Table_ID=547
|
||||
;
|
||||
|
||||
-- Jul 15, 2008 1:31:01 AM COT
|
||||
-- 1642765 - problem with Facc_act_balance slow financial report
|
||||
UPDATE AD_Process_Para SET IsActive = 'N',Updated=TO_TIMESTAMP('2008-07-15 01:27:48','YYYY-MM-DD HH24:MI:SS'),UpdatedBy=100 WHERE AD_Process_Para_ID=283
|
||||
;
|
||||
|
||||
-- Jul 15, 2008 1:32:35 AM COT
|
||||
-- 1642765 - problem with Facc_act_balance slow financial report
|
||||
UPDATE AD_Menu SET IsActive = 'N',Updated=TO_TIMESTAMP('2008-07-15 01:27:48','YYYY-MM-DD HH24:MI:SS'),UpdatedBy=100 WHERE AD_Menu_ID=393
|
||||
;
|
||||
|
||||
-- Jul 15, 2008 1:32:44 AM COT
|
||||
-- 1642765 - problem with Facc_act_balance slow financial report
|
||||
UPDATE AD_Process SET IsActive = 'N',Updated=TO_TIMESTAMP('2008-07-15 01:27:48','YYYY-MM-DD HH24:MI:SS'),UpdatedBy=100 WHERE AD_Process_ID=203
|
||||
;
|
||||
|
||||
-- Jul 15, 2008 1:34:15 AM COT
|
||||
-- 1642765 - problem with Facc_act_balance slow financial report
|
||||
UPDATE AD_Process_Para SET IsActive = 'N',Updated=TO_TIMESTAMP('2008-07-15 01:27:48','YYYY-MM-DD HH24:MI:SS'),UpdatedBy=100 WHERE AD_Process_Para_ID=453
|
||||
;
|
||||
|
||||
-- Jul 15, 2008 1:34:26 AM COT
|
||||
-- 1642765 - problem with Facc_act_balance slow financial report
|
||||
UPDATE AD_Process_Para SET IsActive = 'N',Updated=TO_TIMESTAMP('2008-07-15 01:27:48','YYYY-MM-DD HH24:MI:SS'),UpdatedBy=100 WHERE AD_Process_Para_ID=53123
|
||||
;
|
||||
|
||||
-- Jul 15, 2008 1:35:05 AM COT
|
||||
-- 1642765 - problem with Facc_act_balance slow financial report
|
||||
UPDATE AD_Process_Para SET IsActive = 'N',Updated=TO_TIMESTAMP('2008-07-15 01:27:48','YYYY-MM-DD HH24:MI:SS'),UpdatedBy=100 WHERE AD_Process_Para_ID=454
|
||||
;
|
Loading…
Reference in New Issue