From aa0f27f31aea3dab4254d1d2c3c94c65e16852dc Mon Sep 17 00:00:00 2001 From: Carlos Ruiz Date: Tue, 30 May 2023 03:37:03 +0200 Subject: [PATCH] IDEMPIERE-5739 Allow Inventory Valuation Report for more than one warehouse (#1857) --- .../oracle/202305262207_IDEMPIERE-5739.sql | 18 + .../202305262207_IDEMPIERE-5739.sql | 15 + .../org/compiere/process/InventoryValue.java | 336 +++++++++--------- 3 files changed, 200 insertions(+), 169 deletions(-) create mode 100644 migration/iD10/oracle/202305262207_IDEMPIERE-5739.sql create mode 100644 migration/iD10/postgresql/202305262207_IDEMPIERE-5739.sql diff --git a/migration/iD10/oracle/202305262207_IDEMPIERE-5739.sql b/migration/iD10/oracle/202305262207_IDEMPIERE-5739.sql new file mode 100644 index 0000000000..7b342f596e --- /dev/null +++ b/migration/iD10/oracle/202305262207_IDEMPIERE-5739.sql @@ -0,0 +1,18 @@ +-- IDEMPIERE-5739 Allow Inventory Valuation Report for more than one warehouse +SELECT register_migration_script('202305262207_IDEMPIERE-5739.sql') FROM dual; + +SET SQLBLANKLINES ON +SET DEFINE OFF + +-- May 26, 2023, 10:07:05 PM CEST +INSERT INTO AD_Element (AD_Element_ID,AD_Client_ID,AD_Org_ID,IsActive,Created,CreatedBy,Updated,UpdatedBy,ColumnName,Name,Description,Help,PrintName,EntityType,AD_Element_UU) VALUES (203812,0,0,'Y',TO_TIMESTAMP('2023-05-26 22:06:31','YYYY-MM-DD HH24:MI:SS'),100,TO_TIMESTAMP('2023-05-26 22:06:31','YYYY-MM-DD HH24:MI:SS'),100,'M_Warehouse_IDs','Warehouses',NULL,NULL,'Storage Warehouses and Service Points','D','ed8c53b8-6032-4e6a-b226-07c2c7624d63') +; + +-- May 26, 2023, 10:09:14 PM CEST +UPDATE AD_Process_Para SET IsActive='N', SeqNo=5, IsCentrallyMaintained='N',Updated=TO_TIMESTAMP('2023-05-26 22:09:14','YYYY-MM-DD HH24:MI:SS'),UpdatedBy=100 WHERE AD_Process_Para_ID=230 +; + +-- May 26, 2023, 10:09:19 PM CEST +INSERT INTO AD_Process_Para (AD_Process_Para_ID,AD_Client_ID,AD_Org_ID,IsActive,Created,CreatedBy,Updated,UpdatedBy,Name,AD_Process_ID,SeqNo,AD_Reference_ID,AD_Reference_Value_ID,IsRange,FieldLength,IsMandatory,ColumnName,IsCentrallyMaintained,EntityType,AD_Element_ID,AD_Process_Para_UU,IsEncrypted,IsAutocomplete,DateRangeOption,IsShowNegateButton) VALUES (200438,0,0,'Y',TO_TIMESTAMP('2023-05-26 22:09:19','YYYY-MM-DD HH24:MI:SS'),100,TO_TIMESTAMP('2023-05-26 22:09:19','YYYY-MM-DD HH24:MI:SS'),100,'Warehouses',180,10,200162,197,'N',1000,'N','M_Warehouse_IDs','Y','D',203812,'74c772f8-692e-4eea-9dff-24652fa878e9','N','N','D','N') +; + diff --git a/migration/iD10/postgresql/202305262207_IDEMPIERE-5739.sql b/migration/iD10/postgresql/202305262207_IDEMPIERE-5739.sql new file mode 100644 index 0000000000..7eaa939c0b --- /dev/null +++ b/migration/iD10/postgresql/202305262207_IDEMPIERE-5739.sql @@ -0,0 +1,15 @@ +-- IDEMPIERE-5739 Allow Inventory Valuation Report for more than one warehouse +SELECT register_migration_script('202305262207_IDEMPIERE-5739.sql') FROM dual; + +-- May 26, 2023, 10:07:05 PM CEST +INSERT INTO AD_Element (AD_Element_ID,AD_Client_ID,AD_Org_ID,IsActive,Created,CreatedBy,Updated,UpdatedBy,ColumnName,Name,Description,Help,PrintName,EntityType,AD_Element_UU) VALUES (203812,0,0,'Y',TO_TIMESTAMP('2023-05-26 22:06:31','YYYY-MM-DD HH24:MI:SS'),100,TO_TIMESTAMP('2023-05-26 22:06:31','YYYY-MM-DD HH24:MI:SS'),100,'M_Warehouse_IDs','Warehouses',NULL,NULL,'Storage Warehouses and Service Points','D','ed8c53b8-6032-4e6a-b226-07c2c7624d63') +; + +-- May 26, 2023, 10:09:14 PM CEST +UPDATE AD_Process_Para SET IsActive='N', SeqNo=5, IsCentrallyMaintained='N',Updated=TO_TIMESTAMP('2023-05-26 22:09:14','YYYY-MM-DD HH24:MI:SS'),UpdatedBy=100 WHERE AD_Process_Para_ID=230 +; + +-- May 26, 2023, 10:09:19 PM CEST +INSERT INTO AD_Process_Para (AD_Process_Para_ID,AD_Client_ID,AD_Org_ID,IsActive,Created,CreatedBy,Updated,UpdatedBy,Name,AD_Process_ID,SeqNo,AD_Reference_ID,AD_Reference_Value_ID,IsRange,FieldLength,IsMandatory,ColumnName,IsCentrallyMaintained,EntityType,AD_Element_ID,AD_Process_Para_UU,IsEncrypted,IsAutocomplete,DateRangeOption,IsShowNegateButton) VALUES (200438,0,0,'Y',TO_TIMESTAMP('2023-05-26 22:09:19','YYYY-MM-DD HH24:MI:SS'),100,TO_TIMESTAMP('2023-05-26 22:09:19','YYYY-MM-DD HH24:MI:SS'),100,'Warehouses',180,10,200162,197,'N',1000,'N','M_Warehouse_IDs','Y','D',203812,'74c772f8-692e-4eea-9dff-24652fa878e9','N','N','D','N') +; + diff --git a/org.adempiere.base.process/src/org/compiere/process/InventoryValue.java b/org.adempiere.base.process/src/org/compiere/process/InventoryValue.java index bc40607947..3f46707ec1 100644 --- a/org.adempiere.base.process/src/org/compiere/process/InventoryValue.java +++ b/org.adempiere.base.process/src/org/compiere/process/InventoryValue.java @@ -17,6 +17,7 @@ package org.compiere.process; import java.sql.Timestamp; +import java.util.Arrays; import java.util.logging.Level; import org.compiere.model.MAcctSchema; @@ -24,6 +25,7 @@ import org.compiere.model.MClient; import org.compiere.model.MProcessPara; import org.compiere.model.MWarehouse; import org.compiere.util.DB; +import org.compiere.util.TimeUtil; /** @@ -42,8 +44,8 @@ public class InventoryValue extends SvrProcess private int p_M_PriceList_Version_ID; /** Valuation Date */ private Timestamp p_DateValue; - /** Warehouse */ - private int p_M_Warehouse_ID; + /** Warehouses */ + private int[] p_M_Warehouse_IDs; /** Currency */ private int p_C_Currency_ID; /** Optional Cost Element */ @@ -64,8 +66,8 @@ public class InventoryValue extends SvrProcess p_M_PriceList_Version_ID = para[i].getParameterAsInt(); else if (name.equals("DateValue")) p_DateValue = (Timestamp)para[i].getParameter(); - else if (name.equals("M_Warehouse_ID")) - p_M_Warehouse_ID = para[i].getParameterAsInt(); + else if (name.equals("M_Warehouse_IDs")) + p_M_Warehouse_IDs = para[i].getParameterAsIntArray(); else if (name.equals("C_Currency_ID")) p_C_Currency_ID = para[i].getParameterAsInt(); else if (name.equals("M_CostElement_ID")) @@ -88,216 +90,212 @@ public class InventoryValue extends SvrProcess */ protected String doIt() throws Exception { - if (log.isLoggable(Level.INFO)) log.info("M_Warehouse_ID=" + p_M_Warehouse_ID + if (log.isLoggable(Level.INFO)) log.info("M_Warehouse_IDs=" + Arrays.toString(p_M_Warehouse_IDs) + ",C_Currency_ID=" + p_C_Currency_ID + ",DateValue=" + p_DateValue + ",M_PriceList_Version_ID=" + p_M_PriceList_Version_ID + ",M_CostElement_ID=" + p_M_CostElement_ID); - - MWarehouse wh = MWarehouse.get(getCtx(), p_M_Warehouse_ID); - MClient c = MClient.get(getCtx(), wh.getAD_Client_ID()); - MAcctSchema as = c.getAcctSchema(); - - // Delete (just to be sure) - StringBuilder sql = new StringBuilder ("DELETE FROM T_InventoryValue WHERE AD_PInstance_ID="); - sql.append(getAD_PInstance_ID()); - int no = DB.executeUpdateEx(sql.toString(), get_TrxName()); + + // Delete (just to be sure) + final String sql0 = "DELETE FROM T_InventoryValue WHERE AD_PInstance_ID=?"; + int no = DB.executeUpdateEx(sql0, new Object[] {getAD_PInstance_ID()}, get_TrxName()); + + MClient c = MClient.get(getCtx(), getAD_Client_ID()); + MAcctSchema as = c.getAcctSchema(); + String msg = ""; + + if (p_M_Warehouse_IDs == null) // process all warehouses + p_M_Warehouse_IDs = DB.getIDsEx(get_TrxName(), "SELECT M_Warehouse_ID FROM M_Warehouse WHERE AD_Client_ID=? AND IsActive='Y'", getAD_Client_ID()); + + for (int l_M_Warehouse_ID: p_M_Warehouse_IDs) { + MWarehouse wh = MWarehouse.get(getCtx(), l_M_Warehouse_ID); // Insert Standard Costs - sql = new StringBuilder ("INSERT INTO T_InventoryValue ") - .append("(AD_PInstance_ID, M_Warehouse_ID, M_Product_ID, M_AttributeSetInstance_ID,") - .append(" AD_Client_ID, AD_Org_ID, CostStandard) ") - .append("SELECT ").append(getAD_PInstance_ID()) - .append(", w.M_Warehouse_ID, c.M_Product_ID, c.M_AttributeSetInstance_ID,") - .append(" w.AD_Client_ID, w.AD_Org_ID, c.CurrentCostPrice ") - .append("FROM M_Warehouse w") - .append(" INNER JOIN AD_ClientInfo ci ON (w.AD_Client_ID=ci.AD_Client_ID)") - .append(" INNER JOIN C_AcctSchema acs ON (ci.C_AcctSchema1_ID=acs.C_AcctSchema_ID)") - .append(" INNER JOIN M_Cost c ON (acs.C_AcctSchema_ID=c.C_AcctSchema_ID AND acs.M_CostType_ID=c.M_CostType_ID AND c.AD_Org_ID IN (0, w.AD_Org_ID))") - .append(" INNER JOIN M_CostElement ce ON (c.M_CostElement_ID=ce.M_CostElement_ID AND ce.CostingMethod='S' AND ce.CostElementType='M') ") - .append("WHERE w.M_Warehouse_ID=").append(p_M_Warehouse_ID); - int noInsertStd = DB.executeUpdateEx(sql.toString(), get_TrxName()); + final String sql1 = "INSERT INTO T_InventoryValue " + + "(AD_PInstance_ID, M_Warehouse_ID, M_Product_ID, M_AttributeSetInstance_ID," + + " AD_Client_ID, AD_Org_ID, CostStandard, T_InventoryValue_UU) " + + "SELECT ? " + + ", w.M_Warehouse_ID, c.M_Product_ID, c.M_AttributeSetInstance_ID," + + " w.AD_Client_ID, w.AD_Org_ID, c.CurrentCostPrice, generate_UUID() " + + "FROM M_Warehouse w" + + " INNER JOIN AD_ClientInfo ci ON (w.AD_Client_ID=ci.AD_Client_ID)" + + " INNER JOIN C_AcctSchema acs ON (ci.C_AcctSchema1_ID=acs.C_AcctSchema_ID)" + + " INNER JOIN M_Cost c ON (acs.C_AcctSchema_ID=c.C_AcctSchema_ID AND acs.M_CostType_ID=c.M_CostType_ID AND c.AD_Org_ID IN (0, w.AD_Org_ID))" + + " INNER JOIN M_CostElement ce ON (c.M_CostElement_ID=ce.M_CostElement_ID AND ce.CostingMethod='S' AND ce.CostElementType='M') " + + "WHERE w.M_Warehouse_ID=?"; + int noInsertStd = DB.executeUpdateEx(sql1, new Object[] {getAD_PInstance_ID(), l_M_Warehouse_ID}, get_TrxName()); if (log.isLoggable(Level.FINE)) log.fine("Inserted Std=" + noInsertStd); // Insert addl Costs int noInsertCost = 0; if (p_M_CostElement_ID != 0) { - sql = new StringBuilder ("INSERT INTO T_InventoryValue ") - .append("(AD_PInstance_ID, M_Warehouse_ID, M_Product_ID, M_AttributeSetInstance_ID,") - .append(" AD_Client_ID, AD_Org_ID, CostStandard, Cost, M_CostElement_ID) ") - .append("SELECT ").append(getAD_PInstance_ID()) - .append(", w.M_Warehouse_ID, c.M_Product_ID, c.M_AttributeSetInstance_ID,") - .append(" w.AD_Client_ID, w.AD_Org_ID, 0, c.CurrentCostPrice, c.M_CostElement_ID ") - .append("FROM M_Warehouse w") - .append(" INNER JOIN AD_ClientInfo ci ON (w.AD_Client_ID=ci.AD_Client_ID)") - .append(" INNER JOIN C_AcctSchema acs ON (ci.C_AcctSchema1_ID=acs.C_AcctSchema_ID)") - .append(" INNER JOIN M_Cost c ON (acs.C_AcctSchema_ID=c.C_AcctSchema_ID AND acs.M_CostType_ID=c.M_CostType_ID AND c.AD_Org_ID IN (0, w.AD_Org_ID)) ") - .append("WHERE w.M_Warehouse_ID=").append(p_M_Warehouse_ID) - .append(" AND c.M_CostElement_ID=").append(p_M_CostElement_ID) - .append(" AND NOT EXISTS (SELECT * FROM T_InventoryValue iv ") - .append("WHERE iv.AD_PInstance_ID=").append(getAD_PInstance_ID()) - .append(" AND iv.M_Warehouse_ID=w.M_Warehouse_ID") - .append(" AND iv.M_Product_ID=c.M_Product_ID") - .append(" AND iv.M_AttributeSetInstance_ID=c.M_AttributeSetInstance_ID)"); - noInsertCost = DB.executeUpdateEx(sql.toString(), get_TrxName()); + final String sql2 = "INSERT INTO T_InventoryValue " + + "(AD_PInstance_ID, M_Warehouse_ID, M_Product_ID, M_AttributeSetInstance_ID," + + " AD_Client_ID, AD_Org_ID, CostStandard, Cost, M_CostElement_ID, T_InventoryValue_UU) " + + "SELECT ?" + + ", w.M_Warehouse_ID, c.M_Product_ID, c.M_AttributeSetInstance_ID," + + " w.AD_Client_ID, w.AD_Org_ID, 0, c.CurrentCostPrice, c.M_CostElement_ID, generate_UUID() " + + "FROM M_Warehouse w" + + " INNER JOIN AD_ClientInfo ci ON (w.AD_Client_ID=ci.AD_Client_ID)" + + " INNER JOIN C_AcctSchema acs ON (ci.C_AcctSchema1_ID=acs.C_AcctSchema_ID)" + + " INNER JOIN M_Cost c ON (acs.C_AcctSchema_ID=c.C_AcctSchema_ID AND acs.M_CostType_ID=c.M_CostType_ID AND c.AD_Org_ID IN (0, w.AD_Org_ID)) " + + "WHERE w.M_Warehouse_ID=?" + + " AND c.M_CostElement_ID=?" + + " AND NOT EXISTS (SELECT * FROM T_InventoryValue iv " + + "WHERE iv.AD_PInstance_ID=?" + + " AND iv.M_Warehouse_ID=w.M_Warehouse_ID" + + " AND iv.M_Product_ID=c.M_Product_ID" + + " AND iv.M_AttributeSetInstance_ID=c.M_AttributeSetInstance_ID)"; + noInsertCost = DB.executeUpdateEx(sql2.toString(), new Object[] {getAD_PInstance_ID(), l_M_Warehouse_ID, p_M_CostElement_ID, getAD_PInstance_ID()}, get_TrxName()); if (log.isLoggable(Level.FINE)) log.fine("Inserted Cost=" + noInsertCost); // Update Std Cost Records - sql = new StringBuilder ("UPDATE T_InventoryValue iv ") - .append("SET (Cost, M_CostElement_ID)=") - .append("(SELECT c.CurrentCostPrice, c.M_CostElement_ID ") - .append("FROM M_Warehouse w") - .append(" INNER JOIN AD_ClientInfo ci ON (w.AD_Client_ID=ci.AD_Client_ID)") - .append(" INNER JOIN C_AcctSchema acs ON (ci.C_AcctSchema1_ID=acs.C_AcctSchema_ID)") - .append(" INNER JOIN M_Cost c ON (acs.C_AcctSchema_ID=c.C_AcctSchema_ID") - .append(" AND acs.M_CostType_ID=c.M_CostType_ID AND c.AD_Org_ID IN (0, w.AD_Org_ID)) ") - .append("WHERE c.M_CostElement_ID=").append(p_M_CostElement_ID) - .append(" AND iv.M_Warehouse_ID=w.M_Warehouse_ID") - .append(" AND iv.M_Product_ID=c.M_Product_ID") - .append(" AND iv.AD_PInstance_ID=? ") - .append(" AND iv.M_AttributeSetInstance_ID=c.M_AttributeSetInstance_ID) ") - .append("WHERE EXISTS (SELECT * FROM T_InventoryValue ivv ") - .append("WHERE ivv.AD_PInstance_ID=").append(getAD_PInstance_ID()) - .append(" AND ivv.M_CostElement_ID IS NULL)"); - int noUpdatedCost = DB.executeUpdateEx(sql.toString(), new Object[] {getAD_PInstance_ID()}, get_TrxName()); + final String sql3 = "UPDATE T_InventoryValue iv " + + "SET (Cost, M_CostElement_ID)=" + + "(SELECT c.CurrentCostPrice, c.M_CostElement_ID " + + "FROM M_Warehouse w" + + " INNER JOIN AD_ClientInfo ci ON (w.AD_Client_ID=ci.AD_Client_ID)" + + " INNER JOIN C_AcctSchema acs ON (ci.C_AcctSchema1_ID=acs.C_AcctSchema_ID)" + + " INNER JOIN M_Cost c ON (acs.C_AcctSchema_ID=c.C_AcctSchema_ID" + + " AND acs.M_CostType_ID=c.M_CostType_ID AND c.AD_Org_ID IN (0, w.AD_Org_ID)) " + + "WHERE c.M_CostElement_ID=?" + + " AND iv.M_Warehouse_ID=w.M_Warehouse_ID" + + " AND iv.M_Product_ID=c.M_Product_ID" + + " AND iv.AD_PInstance_ID=? " + + " AND iv.M_AttributeSetInstance_ID=c.M_AttributeSetInstance_ID) " + + "WHERE M_Warehouse_ID=? AND EXISTS (SELECT * FROM T_InventoryValue ivv " + + "WHERE ivv.AD_PInstance_ID=?" + + " AND ivv.M_CostElement_ID IS NULL" + + " AND ivv.M_Warehouse_ID=?)"; + int noUpdatedCost = DB.executeUpdateEx(sql3, new Object[] {p_M_CostElement_ID, getAD_PInstance_ID(), l_M_Warehouse_ID, getAD_PInstance_ID(), l_M_Warehouse_ID}, get_TrxName()); if (log.isLoggable(Level.FINE)) log.fine("Updated Cost=" + noUpdatedCost); } if ((noInsertStd+noInsertCost) == 0) - return "No Costs found"; + return "No Costs found in warehouse " + wh.getName(); // Update Constants - // YYYY-MM-DD HH24:MI:SS.mmmm JDBC Timestamp format - String myDate = p_DateValue.toString(); - sql = new StringBuilder ("UPDATE T_InventoryValue SET DateValue="); - if (DB.isPostgreSQL()) - sql.append("TO_TIMESTAMP('"); - else - sql.append("TO_DATE('"); - sql.append(myDate.substring(0,10)) - .append(" 23:59:59','YYYY-MM-DD HH24:MI:SS'),") - .append("M_PriceList_Version_ID=").append(p_M_PriceList_Version_ID).append(",") - .append("C_Currency_ID=").append(p_C_Currency_ID) - .append(" WHERE AD_PInstance_ID=").append(getAD_PInstance_ID()); - no = DB.executeUpdateEx(sql.toString(), get_TrxName()); + Timestamp l_DateValue = new Timestamp(TimeUtil.addDays(TimeUtil.getDay(p_DateValue), 1).getTime() - 1); // 23:59:59 from param date + final String sql4 = "UPDATE T_InventoryValue SET DateValue=?," + + "M_PriceList_Version_ID=?," + + "C_Currency_ID=?" + + " WHERE AD_PInstance_ID=? AND M_Warehouse_ID=?"; + no = DB.executeUpdateEx(sql4.toString(), new Object[] {l_DateValue, p_M_PriceList_Version_ID, p_C_Currency_ID, getAD_PInstance_ID(), l_M_Warehouse_ID}, get_TrxName()); if (log.isLoggable(Level.FINE)) log.fine("Constants=" + no); // Get current QtyOnHand with ASI - sql = new StringBuilder ("UPDATE T_InventoryValue iv SET QtyOnHand = ") - .append("(SELECT SUM(QtyOnHand) FROM M_StorageOnHand s") - .append(" INNER JOIN M_Locator l ON (l.M_Locator_ID=s.M_Locator_ID) ") - .append("WHERE iv.M_Product_ID=s.M_Product_ID") - .append(" AND iv.M_Warehouse_ID=l.M_Warehouse_ID") - .append(" AND iv.M_AttributeSetInstance_ID=s.M_AttributeSetInstance_ID) ") - .append("WHERE AD_PInstance_ID=").append(getAD_PInstance_ID()) - .append(" AND iv.M_AttributeSetInstance_ID<>0"); - no = DB.executeUpdateEx(sql.toString(), get_TrxName()); + final String sql5 = "UPDATE T_InventoryValue iv SET QtyOnHand = " + + "(SELECT SUM(QtyOnHand) FROM M_StorageOnHand s" + + " INNER JOIN M_Locator l ON (l.M_Locator_ID=s.M_Locator_ID) " + + "WHERE iv.M_Product_ID=s.M_Product_ID" + + " AND iv.M_Warehouse_ID=l.M_Warehouse_ID" + + " AND iv.M_AttributeSetInstance_ID=s.M_AttributeSetInstance_ID) " + + "WHERE M_Warehouse_ID=? AND AD_PInstance_ID=?" + + " AND iv.M_AttributeSetInstance_ID<>0"; + no = DB.executeUpdateEx(sql5, new Object[] {l_M_Warehouse_ID, getAD_PInstance_ID()}, get_TrxName()); if (log.isLoggable(Level.FINE)) log.fine("QtHand with ASI=" + no); // Get current QtyOnHand without ASI - sql = new StringBuilder ("UPDATE T_InventoryValue iv SET QtyOnHand = ") - .append("(SELECT SUM(QtyOnHand) FROM M_StorageOnHand s") - .append(" INNER JOIN M_Locator l ON (l.M_Locator_ID=s.M_Locator_ID) ") - .append("WHERE iv.M_Product_ID=s.M_Product_ID") - .append(" AND iv.M_Warehouse_ID=l.M_Warehouse_ID) ") - .append("WHERE iv.AD_PInstance_ID=").append(getAD_PInstance_ID()) - .append(" AND iv.M_AttributeSetInstance_ID=0"); - no = DB.executeUpdateEx(sql.toString(), get_TrxName()); + final String sql6 = "UPDATE T_InventoryValue iv SET QtyOnHand = " + + "(SELECT SUM(QtyOnHand) FROM M_StorageOnHand s" + + " INNER JOIN M_Locator l ON (l.M_Locator_ID=s.M_Locator_ID) " + + "WHERE iv.M_Product_ID=s.M_Product_ID" + + " AND iv.M_Warehouse_ID=l.M_Warehouse_ID) " + + "WHERE iv.M_Warehouse_ID=? AND iv.AD_PInstance_ID=?" + + " AND iv.M_AttributeSetInstance_ID=0"; + no = DB.executeUpdateEx(sql6, new Object[] {l_M_Warehouse_ID, getAD_PInstance_ID()}, get_TrxName()); if (log.isLoggable(Level.FINE)) log.fine("QtHand w/o ASI=" + no); // Adjust for Valuation Date - sql = new StringBuilder("UPDATE T_InventoryValue iv ") - .append("SET QtyOnHand=") - .append("(SELECT iv.QtyOnHand - NVL(SUM(t.MovementQty), 0) ") - .append("FROM M_Transaction t") - .append(" INNER JOIN M_Locator l ON (t.M_Locator_ID=l.M_Locator_ID) ") - .append("WHERE t.M_Product_ID=iv.M_Product_ID") - .append(" AND t.M_AttributeSetInstance_ID=iv.M_AttributeSetInstance_ID") - .append(" AND t.MovementDate > iv.DateValue") - .append(" AND l.M_Warehouse_ID=iv.M_Warehouse_ID) ") - .append("WHERE iv.M_AttributeSetInstance_ID<>0" ) - .append(" AND iv.AD_PInstance_ID=").append(getAD_PInstance_ID()); - no = DB.executeUpdateEx(sql.toString(), get_TrxName()); + final String sql7 = "UPDATE T_InventoryValue iv " + + "SET QtyOnHand=" + + "(SELECT iv.QtyOnHand - NVL(SUM(t.MovementQty), 0) " + + "FROM M_Transaction t" + + " INNER JOIN M_Locator l ON (t.M_Locator_ID=l.M_Locator_ID) " + + "WHERE t.M_Product_ID=iv.M_Product_ID" + + " AND t.M_AttributeSetInstance_ID=iv.M_AttributeSetInstance_ID" + + " AND t.MovementDate > iv.DateValue" + + " AND l.M_Warehouse_ID=iv.M_Warehouse_ID) " + + "WHERE iv.M_AttributeSetInstance_ID<>0" + + " AND iv.M_Warehouse_ID=? AND iv.AD_PInstance_ID=?"; + no = DB.executeUpdateEx(sql7, new Object[] {l_M_Warehouse_ID, getAD_PInstance_ID()}, get_TrxName()); if (log.isLoggable(Level.FINE)) log.fine("Update with ASI=" + no); // - sql = new StringBuilder("UPDATE T_InventoryValue iv ") - .append("SET QtyOnHand=") - .append("(SELECT iv.QtyOnHand - NVL(SUM(t.MovementQty), 0) ") - .append("FROM M_Transaction t") - .append(" INNER JOIN M_Locator l ON (t.M_Locator_ID=l.M_Locator_ID) ") - .append("WHERE t.M_Product_ID=iv.M_Product_ID") - .append(" AND t.MovementDate > iv.DateValue") - .append(" AND l.M_Warehouse_ID=iv.M_Warehouse_ID) ") - .append("WHERE iv.M_AttributeSetInstance_ID=0 ") - .append("AND iv.AD_PInstance_ID=").append(getAD_PInstance_ID()); - - no = DB.executeUpdateEx(sql.toString(), get_TrxName()); + final String sql8 = "UPDATE T_InventoryValue iv " + + "SET QtyOnHand=" + + "(SELECT iv.QtyOnHand - NVL(SUM(t.MovementQty), 0) " + + "FROM M_Transaction t" + + " INNER JOIN M_Locator l ON (t.M_Locator_ID=l.M_Locator_ID) " + + "WHERE t.M_Product_ID=iv.M_Product_ID" + + " AND t.MovementDate > iv.DateValue" + + " AND l.M_Warehouse_ID=iv.M_Warehouse_ID) " + + "WHERE iv.M_AttributeSetInstance_ID=0 " + + "AND iv.M_Warehouse_ID=? AND iv.AD_PInstance_ID=?"; + no = DB.executeUpdateEx(sql8, new Object[] {l_M_Warehouse_ID, getAD_PInstance_ID()}, get_TrxName()); if (log.isLoggable(Level.FINE)) log.fine("Update w/o ASI=" + no); // Delete Records w/o OnHand Qty - sql = new StringBuilder("DELETE FROM T_InventoryValue ") - .append("WHERE (QtyOnHand=0 OR QtyOnHand IS NULL) AND AD_PInstance_ID=").append(getAD_PInstance_ID()); - int noQty = DB.executeUpdateEx (sql.toString(), get_TrxName()); + final String sql9 = "DELETE FROM T_InventoryValue " + + "WHERE (QtyOnHand=0 OR QtyOnHand IS NULL) AND M_Warehouse_ID=? AND AD_PInstance_ID=?"; + int noQty = DB.executeUpdateEx (sql9, new Object[] {l_M_Warehouse_ID, getAD_PInstance_ID()}, get_TrxName()); if (log.isLoggable(Level.FINE)) log.fine("NoQty Deleted=" + noQty); // Update Prices - sql = new StringBuilder("UPDATE T_InventoryValue iv ") - .append("SET PricePO = ") - .append("(SELECT MAX(currencyConvert (po.PriceList,po.C_Currency_ID,iv.C_Currency_ID,iv.DateValue,null, po.AD_Client_ID,po.AD_Org_ID))") - .append(" FROM M_Product_PO po WHERE po.M_Product_ID=iv.M_Product_ID") - .append(" AND po.IsCurrentVendor='Y'), ") - .append("PriceList = ") - .append("(SELECT currencyConvert(pp.PriceList,pl.C_Currency_ID,iv.C_Currency_ID,iv.DateValue,null, pl.AD_Client_ID,pl.AD_Org_ID)") - .append(" FROM M_PriceList pl, M_PriceList_Version plv, M_ProductPrice pp") - .append(" WHERE pp.M_Product_ID=iv.M_Product_ID AND pp.M_PriceList_Version_ID=iv.M_PriceList_Version_ID") - .append(" AND pp.M_PriceList_Version_ID=plv.M_PriceList_Version_ID") - .append(" AND plv.M_PriceList_ID=pl.M_PriceList_ID), ") - .append("PriceStd = ") - .append("(SELECT currencyConvert(pp.PriceStd,pl.C_Currency_ID,iv.C_Currency_ID,iv.DateValue,null, pl.AD_Client_ID,pl.AD_Org_ID)") - .append(" FROM M_PriceList pl, M_PriceList_Version plv, M_ProductPrice pp") - .append(" WHERE pp.M_Product_ID=iv.M_Product_ID AND pp.M_PriceList_Version_ID=iv.M_PriceList_Version_ID") - .append(" AND pp.M_PriceList_Version_ID=plv.M_PriceList_Version_ID") - .append(" AND plv.M_PriceList_ID=pl.M_PriceList_ID), ") - .append("PriceLimit = ") - .append("(SELECT currencyConvert(pp.PriceLimit,pl.C_Currency_ID,iv.C_Currency_ID,iv.DateValue,null, pl.AD_Client_ID,pl.AD_Org_ID)") - .append(" FROM M_PriceList pl, M_PriceList_Version plv, M_ProductPrice pp") - .append(" WHERE pp.M_Product_ID=iv.M_Product_ID AND pp.M_PriceList_Version_ID=iv.M_PriceList_Version_ID") - .append(" AND pp.M_PriceList_Version_ID=plv.M_PriceList_Version_ID") - .append(" AND plv.M_PriceList_ID=pl.M_PriceList_ID)") - .append(" WHERE iv.AD_PInstance_ID=").append(getAD_PInstance_ID()); - - no = DB.executeUpdateEx (sql.toString(), get_TrxName()); - String msg = ""; + final String sql10 = "UPDATE T_InventoryValue iv " + + "SET PricePO = " + + "(SELECT MAX(currencyConvert (po.PriceList,po.C_Currency_ID,iv.C_Currency_ID,iv.DateValue,null, po.AD_Client_ID,po.AD_Org_ID))" + + " FROM M_Product_PO po WHERE po.M_Product_ID=iv.M_Product_ID" + + " AND po.IsCurrentVendor='Y'), " + + "PriceList = " + + "(SELECT currencyConvert(pp.PriceList,pl.C_Currency_ID,iv.C_Currency_ID,iv.DateValue,null, pl.AD_Client_ID,pl.AD_Org_ID)" + + " FROM M_PriceList pl, M_PriceList_Version plv, M_ProductPrice pp" + + " WHERE pp.M_Product_ID=iv.M_Product_ID AND pp.M_PriceList_Version_ID=iv.M_PriceList_Version_ID" + + " AND pp.M_PriceList_Version_ID=plv.M_PriceList_Version_ID" + + " AND plv.M_PriceList_ID=pl.M_PriceList_ID), " + + "PriceStd = " + + "(SELECT currencyConvert(pp.PriceStd,pl.C_Currency_ID,iv.C_Currency_ID,iv.DateValue,null, pl.AD_Client_ID,pl.AD_Org_ID)" + + " FROM M_PriceList pl, M_PriceList_Version plv, M_ProductPrice pp" + + " WHERE pp.M_Product_ID=iv.M_Product_ID AND pp.M_PriceList_Version_ID=iv.M_PriceList_Version_ID" + + " AND pp.M_PriceList_Version_ID=plv.M_PriceList_Version_ID" + + " AND plv.M_PriceList_ID=pl.M_PriceList_ID), " + + "PriceLimit = " + + "(SELECT currencyConvert(pp.PriceLimit,pl.C_Currency_ID,iv.C_Currency_ID,iv.DateValue,null, pl.AD_Client_ID,pl.AD_Org_ID)" + + " FROM M_PriceList pl, M_PriceList_Version plv, M_ProductPrice pp" + + " WHERE pp.M_Product_ID=iv.M_Product_ID AND pp.M_PriceList_Version_ID=iv.M_PriceList_Version_ID" + + " AND pp.M_PriceList_Version_ID=plv.M_PriceList_Version_ID" + + " AND plv.M_PriceList_ID=pl.M_PriceList_ID)" + + " WHERE iv.M_Warehouse_ID=? AND iv.AD_PInstance_ID=?"; + no = DB.executeUpdateEx (sql10, new Object[] {l_M_Warehouse_ID, getAD_PInstance_ID()}, get_TrxName()); if (no == 0) - msg = "No Prices"; + msg = msg + " / No Prices in warehouse " + wh.getName(); // Convert if different Currency if (as.getC_Currency_ID() != p_C_Currency_ID) { - sql = new StringBuilder ("UPDATE T_InventoryValue iv ") - .append("SET CostStandard= ") - .append("(SELECT currencyConvert(iv.CostStandard,acs.C_Currency_ID,iv.C_Currency_ID,iv.DateValue,null, iv.AD_Client_ID,iv.AD_Org_ID) ") - .append("FROM C_AcctSchema acs WHERE acs.C_AcctSchema_ID=").append(as.getC_AcctSchema_ID()).append("),") - .append(" Cost= ") - .append("(SELECT currencyConvert(iv.Cost,acs.C_Currency_ID,iv.C_Currency_ID,iv.DateValue,null, iv.AD_Client_ID,iv.AD_Org_ID) ") - .append("FROM C_AcctSchema acs WHERE acs.C_AcctSchema_ID=").append(as.getC_AcctSchema_ID()).append(") ") - .append("WHERE iv.AD_PInstance_ID=").append(getAD_PInstance_ID()); - no = DB.executeUpdateEx (sql.toString(), get_TrxName()); + final String sql11 = "UPDATE T_InventoryValue iv " + + "SET CostStandard= " + + "(SELECT currencyConvert(iv.CostStandard,acs.C_Currency_ID,iv.C_Currency_ID,iv.DateValue,null, iv.AD_Client_ID,iv.AD_Org_ID) " + + "FROM C_AcctSchema acs WHERE acs.C_AcctSchema_ID=?)," + + " Cost= " + + "(SELECT currencyConvert(iv.Cost,acs.C_Currency_ID,iv.C_Currency_ID,iv.DateValue,null, iv.AD_Client_ID,iv.AD_Org_ID) " + + "FROM C_AcctSchema acs WHERE acs.C_AcctSchema_ID=?) " + + "WHERE iv.M_Warehouse_ID=? AND iv.AD_PInstance_ID=?"; + no = DB.executeUpdateEx (sql11, new Object[] {as.getC_AcctSchema_ID(), as.getC_AcctSchema_ID(), l_M_Warehouse_ID, getAD_PInstance_ID()}, get_TrxName()); if (log.isLoggable(Level.FINE)) log.fine("Converted=" + no); } // Update Values - StringBuilder dbeux = new StringBuilder("UPDATE T_InventoryValue SET ") - .append("PricePOAmt = QtyOnHand * PricePO, ") - .append("PriceListAmt = QtyOnHand * PriceList, ") - .append("PriceStdAmt = QtyOnHand * PriceStd, ") - .append("PriceLimitAmt = QtyOnHand * PriceLimit, ") - .append("CostStandardAmt = QtyOnHand * CostStandard, ") - .append("CostAmt = QtyOnHand * Cost ") - .append("WHERE AD_PInstance_ID=").append(getAD_PInstance_ID() - ); - no = DB.executeUpdateEx(dbeux.toString(), get_TrxName()); + final String dbeux = "UPDATE T_InventoryValue SET " + + "PricePOAmt = QtyOnHand * PricePO, " + + "PriceListAmt = QtyOnHand * PriceList, " + + "PriceStdAmt = QtyOnHand * PriceStd, " + + "PriceLimitAmt = QtyOnHand * PriceLimit, " + + "CostStandardAmt = QtyOnHand * CostStandard, " + + "CostAmt = QtyOnHand * Cost " + + "WHERE M_Warehouse_ID=? AND AD_PInstance_ID=?"; + no = DB.executeUpdateEx(dbeux.toString(), new Object[] {l_M_Warehouse_ID, getAD_PInstance_ID()}, get_TrxName()); if (log.isLoggable(Level.FINE)) log.fine("Calculation=" + no); - // - return msg; + } + // + return "@OK@"; } // doIt } // InventoryValue