From a6ee2fec0f87f58fa1ddd3e86213b2ab826f0f63 Mon Sep 17 00:00:00 2001 From: Carlos Ruiz Date: Mon, 3 Dec 2012 15:21:10 -0500 Subject: [PATCH] IDEMPIERE-385 Resolve M_Storage locking and data consistency / Fix error on view (ERROR: column "m_storage_uu" does not exist) --- db/ddlutils/oracle/views/M_Storage.sql | 6 +- db/ddlutils/postgresql/views/M_Storage.sql | 6 +- .../oracle/201212031501_IDEMPIERE-385.sql | 63 ++++ .../postgresql/201212031501_IDEMPIERE-385.sql | 280 ++++++++++++++++++ 4 files changed, 349 insertions(+), 6 deletions(-) create mode 100644 migration/i1.0a-release/oracle/201212031501_IDEMPIERE-385.sql create mode 100644 migration/i1.0a-release/postgresql/201212031501_IDEMPIERE-385.sql diff --git a/db/ddlutils/oracle/views/M_Storage.sql b/db/ddlutils/oracle/views/M_Storage.sql index bc414b8657..e360a31fc1 100644 --- a/db/ddlutils/oracle/views/M_Storage.sql +++ b/db/ddlutils/oracle/views/M_Storage.sql @@ -14,7 +14,7 @@ AS 0 AS qtyordered, s.datelastinventory, s.m_attributesetinstance_id, - s.m_storageonhand_uu + s.m_storageonhand_uu AS m_storage_uu FROM m_storageonhand s UNION SELECT sr.m_product_id, @@ -31,7 +31,7 @@ AS 0 AS qtyordered, sr.datelastinventory, sr.m_attributesetinstance_id, - sr.m_storagereservation_uu + sr.m_storagereservation_uu AS m_storage_uu FROM m_storagereservation sr JOIN m_warehouse w ON sr.m_warehouse_id = w.m_warehouse_id @@ -51,7 +51,7 @@ AS so.qty AS qtyordered, so.datelastinventory, so.m_attributesetinstance_id, - so.m_storagereservation_uu + so.m_storagereservation_uu AS m_storage_uu FROM m_storagereservation so JOIN m_warehouse w ON so.m_warehouse_id = w.m_warehouse_id diff --git a/db/ddlutils/postgresql/views/M_Storage.sql b/db/ddlutils/postgresql/views/M_Storage.sql index bc414b8657..e360a31fc1 100644 --- a/db/ddlutils/postgresql/views/M_Storage.sql +++ b/db/ddlutils/postgresql/views/M_Storage.sql @@ -14,7 +14,7 @@ AS 0 AS qtyordered, s.datelastinventory, s.m_attributesetinstance_id, - s.m_storageonhand_uu + s.m_storageonhand_uu AS m_storage_uu FROM m_storageonhand s UNION SELECT sr.m_product_id, @@ -31,7 +31,7 @@ AS 0 AS qtyordered, sr.datelastinventory, sr.m_attributesetinstance_id, - sr.m_storagereservation_uu + sr.m_storagereservation_uu AS m_storage_uu FROM m_storagereservation sr JOIN m_warehouse w ON sr.m_warehouse_id = w.m_warehouse_id @@ -51,7 +51,7 @@ AS so.qty AS qtyordered, so.datelastinventory, so.m_attributesetinstance_id, - so.m_storagereservation_uu + so.m_storagereservation_uu AS m_storage_uu FROM m_storagereservation so JOIN m_warehouse w ON so.m_warehouse_id = w.m_warehouse_id diff --git a/migration/i1.0a-release/oracle/201212031501_IDEMPIERE-385.sql b/migration/i1.0a-release/oracle/201212031501_IDEMPIERE-385.sql new file mode 100644 index 0000000000..5641c36965 --- /dev/null +++ b/migration/i1.0a-release/oracle/201212031501_IDEMPIERE-385.sql @@ -0,0 +1,63 @@ +CREATE OR REPLACE VIEW m_storage +AS + SELECT s.m_product_id, + s.m_locator_id, + s.ad_client_id, + s.ad_org_id, + s.isactive, + s.created, + s.createdby, + s.updated, + s.updatedby, + s.qtyonhand, + 0 AS qtyreserved, + 0 AS qtyordered, + s.datelastinventory, + s.m_attributesetinstance_id, + s.m_storageonhand_uu AS m_storage_uu + FROM m_storageonhand s + UNION + SELECT sr.m_product_id, + w.m_reservelocator_id AS m_locator_id, + sr.ad_client_id, + sr.ad_org_id, + sr.isactive, + sr.created, + sr.createdby, + sr.updated, + sr.updatedby, + 0 AS qtyonhand, + sr.qty AS qtyreserved, + 0 AS qtyordered, + sr.datelastinventory, + sr.m_attributesetinstance_id, + sr.m_storagereservation_uu AS m_storage_uu + FROM m_storagereservation sr + JOIN m_warehouse w + ON sr.m_warehouse_id = w.m_warehouse_id + WHERE sr.issotrx = 'Y' + UNION + SELECT so.m_product_id, + w.m_reservelocator_id AS m_locator_id, + so.ad_client_id, + so.ad_org_id, + so.isactive, + so.created, + so.createdby, + so.updated, + so.updatedby, + 0 AS qtyonhand, + 0 AS qtyreserved, + so.qty AS qtyordered, + so.datelastinventory, + so.m_attributesetinstance_id, + so.m_storagereservation_uu AS m_storage_uu + FROM m_storagereservation so + JOIN m_warehouse w + ON so.m_warehouse_id = w.m_warehouse_id + WHERE so.issotrx = 'N' +; + +SELECT register_migration_script('201212031501_IDEMPIERE-385.sql') FROM dual +; + diff --git a/migration/i1.0a-release/postgresql/201212031501_IDEMPIERE-385.sql b/migration/i1.0a-release/postgresql/201212031501_IDEMPIERE-385.sql new file mode 100644 index 0000000000..8ff51bc622 --- /dev/null +++ b/migration/i1.0a-release/postgresql/201212031501_IDEMPIERE-385.sql @@ -0,0 +1,280 @@ +ALTER VIEW m_storage RENAME TO m_storage_bad +; + +CREATE OR REPLACE VIEW m_storage +AS + SELECT s.m_product_id, + s.m_locator_id, + s.ad_client_id, + s.ad_org_id, + s.isactive, + s.created, + s.createdby, + s.updated, + s.updatedby, + s.qtyonhand, + 0 AS qtyreserved, + 0 AS qtyordered, + s.datelastinventory, + s.m_attributesetinstance_id, + s.m_storageonhand_uu AS m_storage_uu + FROM m_storageonhand s + UNION + SELECT sr.m_product_id, + w.m_reservelocator_id AS m_locator_id, + sr.ad_client_id, + sr.ad_org_id, + sr.isactive, + sr.created, + sr.createdby, + sr.updated, + sr.updatedby, + 0 AS qtyonhand, + sr.qty AS qtyreserved, + 0 AS qtyordered, + sr.datelastinventory, + sr.m_attributesetinstance_id, + sr.m_storagereservation_uu AS m_storage_uu + FROM m_storagereservation sr + JOIN m_warehouse w + ON sr.m_warehouse_id = w.m_warehouse_id + WHERE sr.issotrx = 'Y' + UNION + SELECT so.m_product_id, + w.m_reservelocator_id AS m_locator_id, + so.ad_client_id, + so.ad_org_id, + so.isactive, + so.created, + so.createdby, + so.updated, + so.updatedby, + 0 AS qtyonhand, + 0 AS qtyreserved, + so.qty AS qtyordered, + so.datelastinventory, + so.m_attributesetinstance_id, + so.m_storagereservation_uu AS m_storage_uu + FROM m_storagereservation so + JOIN m_warehouse w + ON so.m_warehouse_id = w.m_warehouse_id + WHERE so.issotrx = 'N' +; + +-- PostgreSQL requires to recreate all views before dropping a table +CREATE OR REPLACE VIEW RV_STORAGE +(AD_CLIENT_ID, AD_ORG_ID, M_PRODUCT_ID, VALUE, NAME, + DESCRIPTION, UPC, SKU, C_UOM_ID, M_PRODUCT_CATEGORY_ID, + CLASSIFICATION, WEIGHT, VOLUME, VERSIONNO, GUARANTEEDAYS, + GUARANTEEDAYSMIN, M_LOCATOR_ID, M_WAREHOUSE_ID, X, Y, + Z, QTYONHAND, QTYRESERVED, QTYAVAILABLE, QTYORDERED, + DATELASTINVENTORY, M_ATTRIBUTESETINSTANCE_ID, M_ATTRIBUTESET_ID, SERNO, LOT, + M_LOT_ID, GUARANTEEDATE, SHELFLIFEDAYS, GOODFORDAYS, SHELFLIFEREMAININGPCT) +AS +SELECT s.AD_Client_ID, s.AD_Org_ID, + -- Product + s.M_Product_ID, p.Value,p.Name, p.Description, p.UPC, p.SKU, + p.C_UOM_ID, p.M_Product_Category_ID, p.Classification, p.Weight, p.Volume, p.VersionNo, + p.GuaranteeDays, p.GuaranteeDaysMin, + -- Locator + s.M_Locator_ID, l.M_Warehouse_ID, l.X, l.Y, l.Z, + -- Storage + s.QtyOnHand, s.QtyReserved, s.QtyOnHand-s.QtyReserved AS QtyAvailable, + s.QtyOrdered, s.DateLastInventory, + -- Instance + s.M_AttributeSetInstance_ID, asi.M_AttributeSet_ID, asi.SerNo, asi.Lot, asi.M_Lot_ID, + asi.GuaranteeDate, -- see PAttributeInstance.java + daysBetween(asi.GuaranteeDate,getdate()) AS ShelfLifeDays, + daysBetween(asi.GuaranteeDate,getdate())-p.GuaranteeDaysMin AS GoodForDays, + CASE WHEN COALESCE(p.GuaranteeDays,0)>0 + THEN ROUND((daysBetween(asi.GuaranteeDate,getdate())/p.GuaranteeDays)*100,0) + ELSE NULL + END AS ShelfLifeRemainingPct +FROM M_Storage s + INNER JOIN M_Locator l ON (s.M_Locator_ID=l.M_Locator_ID) + INNER JOIN M_Product p ON (s.M_Product_ID=p.M_Product_ID) + LEFT OUTER JOIN M_AttributeSetInstance asi ON (s.M_AttributeSetInstance_ID=asi.M_AttributeSetInstance_ID) +; + +CREATE OR REPLACE VIEW rv_pp_order_receipt_issue AS +SELECT obl.pp_order_bomline_id, +obl.iscritical, +p.value, +obl.m_product_id, +mos.name AS productname, +mos.m_attributesetinstance_id, +asi.description AS instancename, +mos.c_uom_id, +u.name AS uomname, +obl.qtyrequiered, +obl.qtyreserved AS qtyreserved_order, +mos.qtyonhand, +mos.qtyreserved AS qtyreserved_storage, +mos.qtyavailable, +mos.m_locator_id, +mos.m_warehouse_id, +w.name AS warehousename, +mos.qtybom, +mos.isqtypercentage, +mos.qtybatch, +obl.componenttype, +mos.qtyrequiered - obl.qtydelivered AS qtyopen, +obl.pp_order_id +FROM rv_pp_order_storage mos +JOIN pp_order_bomline obl ON mos.pp_order_bomline_id = obl.pp_order_bomline_id +JOIN m_attributesetinstance asi ON mos.m_attributesetinstance_id = asi.m_attributesetinstance_id +JOIN c_uom u ON mos.c_uom_id = u.c_uom_id +JOIN m_product p ON mos.m_product_id = p.m_product_id +JOIN m_warehouse w ON mos.m_warehouse_id = w.m_warehouse_id +; + +CREATE OR REPLACE VIEW rv_pp_order_storage AS +SELECT +obl.ad_client_id, +obl.ad_org_id, +obl.createdby, +obl.updatedby, +obl.updated, +obl.created, +obl.isactive, +obl.pp_order_bom_id, +obl.pp_order_bomline_id, +obl.pp_order_id, +obl.iscritical, +obl.m_product_id, +( SELECT p.name FROM m_product p WHERE p.m_product_id = o.m_product_id) AS name, +obl.c_uom_id, +s.qtyonhand, +round(obl.qtyrequiered, 4) AS qtyrequiered, +CASE WHEN o.qtybatchs = 0 THEN 1 ELSE round(obl.qtyrequiered / o.qtybatchs, 4) END AS qtybatchsize, +round(bomqtyreserved(obl.m_product_id,obl.m_warehouse_id, 0), 4) AS qtyreserved, +round(bomqtyavailable(obl.m_product_id, obl.m_warehouse_id,0), 4) AS qtyavailable, +obl.m_warehouse_id, +obl.qtybom, +obl.isqtypercentage, +round(obl.qtybatch, 4) AS qtybatch, +obl.m_attributesetinstance_id, +l.m_locator_id, +l.x, +l.y, +l.z +FROM pp_order_bomline obl +JOIN pp_order o ON o.pp_order_id = obl.pp_order_id +LEFT JOIN m_storage s ON s.m_product_id = obl.m_product_id AND s.qtyonhand <> 0 AND obl.m_warehouse_id = (( SELECT ld.m_warehouse_id FROM m_locator ld WHERE s.m_locator_id = ld.m_locator_id)) +LEFT JOIN m_locator l ON l.m_locator_id = s.m_locator_id +ORDER BY obl.m_product_id +; + +CREATE OR REPLACE VIEW rv_storage_per_product AS +SELECT strg.AD_Client_ID, strg.AD_Org_ID + , p.M_Product_ID, p.Value, p.Name + , p.Description, p.UPC, p.SKU + , p.C_UOM_ID, p.M_Product_Category_ID, p.Classification, p.Weight, p.Volume, p.VersionNo + , p.GuaranteeDays, p.GuaranteeDaysMin + , strg.SumQtyOnHand +FROM M_Product p + INNER JOIN ( SELECT M_Product_ID, M_Locator_ID, SUM (QtyOnHand) as SumQtyOnHand + , AD_Client_ID, AD_Org_ID + FROM RV_Storage + GROUP BY M_Product_ID, M_Locator_ID, AD_Client_ID, AD_Org_ID) strg ON (p.M_Product_ID = strg.M_Product_ID) + INNER JOIN M_Locator l ON (strg.M_Locator_ID=l.M_Locator_ID) +; + +CREATE OR REPLACE VIEW M_PRODUCT_STOCK_V +AS +SELECT +ms.IsActive, ms.Created, ms.CreatedBy, ms.Updated, ms.UpdatedBy, +mp.VALUE, mp.help, (ms.qtyonhand - ms.qtyreserved) AS qtyavailable, ms.qtyonhand, +ms.qtyreserved, mp.description, mw.NAME AS warehouse, mw.m_warehouse_id, mw.ad_client_id, +mw.ad_org_id, mp.documentnote +FROM M_STORAGE ms +JOIN M_PRODUCT mp ON ms.m_product_id = mp.m_product_id +JOIN M_LOCATOR ml ON ms.m_locator_id = ml.m_locator_id +JOIN M_WAREHOUSE mw ON ml.m_warehouse_id = mw.m_warehouse_id +ORDER BY mw.NAME; + +CREATE OR REPLACE VIEW M_PRODUCT_SUBSTITUTERELATED_V AS +SELECT s.ad_client_id, + s.ad_org_id, + s.isactive, + s.created, + s.createdby, + s.updated, + s.updatedby, + s.m_product_id, + s.substitute_id, + 'S' AS rowtype, + mp.name, + sum(ms.qtyonhand - ms.qtyreserved) AS qtyavailable, + sum(ms.qtyonhand) AS qtyonhand, + sum(ms.qtyreserved) AS qtyreserved, + ROUND(MAX(mpr.pricestd),0) AS pricestd, + mpr.m_pricelist_version_id, + mw.m_warehouse_id, + org.name AS orgname + FROM m_substitute s + JOIN m_storage ms ON ms.m_product_id = s.substitute_id + JOIN m_product mp ON ms.m_product_id = mp.m_product_id + JOIN m_locator ml ON ms.m_locator_id = ml.m_locator_id + JOIN m_warehouse mw ON ml.m_warehouse_id = mw.m_warehouse_id + JOIN m_productprice mpr ON ms.m_product_id = mpr.m_product_id + JOIN ad_org org ON org.ad_org_id = mw.ad_org_id + GROUP BY s.ad_client_id, + s.ad_org_id, + s.isactive, + s.created, + s.createdby, + s.updated, + s.updatedby, + s.m_product_id, + s.substitute_id, + mw.m_warehouse_id, + mpr.m_pricelist_version_id, + org.name, + mp.name + UNION + SELECT r.ad_client_id, + r.ad_org_id, + r.isactive, + r.created, + r.createdby, + r.updated, + r.updatedby, + r.m_product_id, + r.relatedproduct_id AS substitute_id, + 'R' AS rowtype, + mp.name, + sum(ms.qtyonhand - ms.qtyreserved) AS qtyavailable, + sum(ms.qtyonhand) AS qtyonhand, + sum(ms.qtyreserved) AS qtyreserved, + ROUND(MAX(mpr.pricestd),0) AS pricestd, + mpr.m_pricelist_version_id, + mw.m_warehouse_id, + org.name AS orgname + FROM m_relatedproduct r + JOIN m_storage ms ON ms.m_product_id = r.relatedproduct_id + JOIN m_product mp ON ms.m_product_id = mp.m_product_id + JOIN m_locator ml ON ms.m_locator_id = ml.m_locator_id + JOIN m_warehouse mw ON ml.m_warehouse_id = mw.m_warehouse_id + JOIN m_productprice mpr ON ms.m_product_id = mpr.m_product_id + JOIN ad_org org ON org.ad_org_id = mw.ad_org_id + GROUP BY r.ad_client_id, + r.ad_org_id, + r.isactive, + r.created, + r.createdby, + r.updated, + r.updatedby, + r.m_product_id, + r.relatedproduct_id, + mw.m_warehouse_id, + mpr.m_pricelist_version_id, + org.name, + mp.name; + +DROP VIEW m_storage_bad +; + +SELECT register_migration_script('201212031501_IDEMPIERE-385.sql') FROM dual +; +