Skip to content

Commit

Permalink
#6718 Fix uomconvertdirect.sql and MD_Stock_From_HUs_V.sql (#6755)
Browse files Browse the repository at this point in the history
  • Loading branch information
metas-ts committed May 29, 2020
1 parent 0cb5753 commit 2259f58
Show file tree
Hide file tree
Showing 9 changed files with 200 additions and 59 deletions.
Expand Up @@ -29,9 +29,12 @@ begin
select MultiplyRate
into v_MultiplyRate
from C_UOM_Conversion c
where c.M_Product_ID=p_M_Product_ID
and c.C_UOM_ID = p_C_UOM_From_ID and c.C_UOM_To_ID = p_C_UOM_To_ID
and c.IsActive='Y';
-- there might be product-independent conversion rates; we allow them, but prefer ones with a product
where (c.M_Product_ID IS NULL OR c.M_Product_ID=p_M_Product_ID)
and c.C_UOM_ID = p_C_UOM_From_ID and c.C_UOM_To_ID = p_C_UOM_To_ID
and c.IsActive='Y'
order by c.M_Product_ID NULLS LAST
;

--
-- Direct (reversed): p_C_UOM_To_ID -> p_C_UOM_From_ID
Expand All @@ -40,9 +43,12 @@ begin
select DivideRate
into v_MultiplyRate
from C_UOM_Conversion c
where c.M_Product_ID=p_M_Product_ID
and c.C_UOM_ID = p_C_UOM_To_ID and c.C_UOM_To_ID = p_C_UOM_From_ID
and c.IsActive='Y';
-- there might be product-independent conversion rates; we allow them, but prefer ones with a product
where (c.M_Product_ID IS NULL OR c.M_Product_ID=p_M_Product_ID)
and c.C_UOM_ID = p_C_UOM_To_ID and c.C_UOM_To_ID = p_C_UOM_From_ID
and c.IsActive='Y'
order by c.M_Product_ID NULLS LAST
;
end if;

if (v_MultiplyRate is null)
Expand Down
@@ -0,0 +1,71 @@

create or replace function uomConvertDirect
(
p_M_Product_ID numeric
, p_C_UOM_From_ID numeric
, p_C_UOM_To_ID numeric
, p_Qty numeric
)
returns numeric
as
$BODY$
declare
v_MultiplyRate numeric;
v_QtyConv numeric;
begin
-- If quantity is null or zero, there is no point to convert
if (p_Qty is null or p_Qty = 0)
then
return p_Qty;
end if;

-- If same UOM, there is no point to convert
if (p_C_UOM_From_ID = p_C_UOM_To_ID)
then
return p_Qty;
end if;

--
-- Direct: p_C_UOM_From_ID -> p_C_UOM_To_ID
select MultiplyRate
into v_MultiplyRate
from C_UOM_Conversion c
-- there might be product-independent conversion rates; we allow them, but prefer ones with a product
where (c.M_Product_ID IS NULL OR c.M_Product_ID=p_M_Product_ID)
and c.C_UOM_ID = p_C_UOM_From_ID and c.C_UOM_To_ID = p_C_UOM_To_ID
and c.IsActive='Y'
order by c.M_Product_ID NULLS LAST
;

--
-- Direct (reversed): p_C_UOM_To_ID -> p_C_UOM_From_ID
if (v_MultiplyRate is null)
then
select DivideRate
into v_MultiplyRate
from C_UOM_Conversion c
-- there might be product-independent conversion rates; we allow them, but prefer ones with a product
where (c.M_Product_ID IS NULL OR c.M_Product_ID=p_M_Product_ID)
and c.C_UOM_ID = p_C_UOM_To_ID and c.C_UOM_To_ID = p_C_UOM_From_ID
and c.IsActive='Y'
order by c.M_Product_ID NULLS LAST
;
end if;

if (v_MultiplyRate is null)
then
return null;
end if;

v_QtyConv := p_Qty * v_MultiplyRate;

return v_QtyConv;
end;
$BODY$
LANGUAGE plpgsql STABLE
COST 100;

COMMENT ON FUNCTION public.uomconvertdirect(numeric, numeric, numeric, numeric)
IS 'Attempts to convert between two UOMs by using the C_UOM_Conversion table. If there is no conversion table record it can use, the function returns null.
Note that the function tries both "directions" so we need just one C_UOM_Conversion record to convert both from "A" to "B" and from "B" to "A".';

Expand Up @@ -57,7 +57,6 @@ public M_Transaction(
/**
* Note: it's important to enqueue the transaction after it was saved and before it is deleted, because we need its ID.
*
* @param purchaseCandidate
* @task https://github.com/metasfresh/metasfresh/issues/710
*/
@ModelChange(timings = {
Expand Down
Expand Up @@ -74,10 +74,6 @@ class M_Transaction_HuDescriptor
private final IHUAssignmentDAO huAssignmentDAO = Services.get(IHUAssignmentDAO.class);
private final IAttributeSetInstanceBL attributeSetInstanceBL = Services.get(IAttributeSetInstanceBL.class);

public M_Transaction_HuDescriptor()
{
}

public ImmutableList<HUDescriptor> createHuDescriptorsForInOutLine(
@NonNull final InOutAndLineId inOutLineId,
final boolean deleted)
Expand Down
Expand Up @@ -112,7 +112,7 @@ public Quantity getQty()
@Override
public final Quantity getQty(final I_C_UOM uom)
{
UOMConversionContext conversionCtx = UOMConversionContext.of(getProductId());
final UOMConversionContext conversionCtx = UOMConversionContext.of(getProductId());

final IUOMConversionBL uomConversionBL = Services.get(IUOMConversionBL.class);
return uomConversionBL.convertQuantityTo(getQty(), conversionCtx, uom);
Expand Down
Expand Up @@ -206,7 +206,7 @@ private M_Transaction_HuDescriptor createM_Transaction_HuDescriptor(@NonNull fin

return new M_Transaction_HuDescriptor()
{
public ImmutableList<HUDescriptor> createHuDescriptorsForInOutLine(InOutAndLineId inOutLineId, boolean deleted)
public ImmutableList<HUDescriptor> createHuDescriptorsForInOutLine(@NonNull InOutAndLineId inOutLineId, boolean deleted)
{
return ImmutableList.of(huDescriptor);
}
Expand Down
@@ -1,50 +1,59 @@

DROP VIEW IF EXISTS MD_Stock_From_HUs_V;
CREATE VIEW MD_Stock_From_HUs_V AS
SELECT
COALESCE(hu_agg.AD_Client_ID, s.AD_Client_ID) AS AD_Client_ID,
COALESCE(hu_agg.AD_Org_ID, s.AD_Org_ID) AS AD_Org_ID,
COALESCE(hu_agg.M_Warehouse_ID, s.M_Warehouse_ID) AS M_Warehouse_ID,
COALESCE(hu_agg.M_Product_ID, s.M_Product_ID) AS M_Product_ID,
COALESCE(hu_agg.C_UOM_ID, p.C_UOM_ID) AS C_UOM_ID,
COALESCE(hu_agg.AttributesKey, s.AttributesKey) AS AttributesKey,
COALESCE(hu_agg.QtyOnHand, 0) AS QtyOnHand,
COALESCE(hu_agg.QtyOnHand, 0) - COALESCE(s.QtyOnHand, 0) AS QtyOnHandChange
FROM
MD_Stock s
LEFT JOIN M_Product p ON p.M_Product_ID = s.M_Product_ID /*needed for its C_UOM_ID*/
FULL OUTER JOIN
(
SELECT
hu.AD_Client_ID,
hu.AD_Org_ID,
l.M_Warehouse_ID,
hus.M_Product_ID,
hus.C_UOM_ID,
GenerateHUAttributesKey(hu.m_hu_id) as AttributesKey,
SUM(hus.Qty) as QtyOnHand
FROM m_hu hu
JOIN M_HU_Storage hus ON hus.M_HU_ID = hu.M_HU_ID
JOIN M_Locator l ON l.M_Locator_ID=hu.M_Locator_ID
WHERE hu.isactive='Y'
and M_HU_Item_Parent_ID IS NULL
SELECT
/*the COALESCEs are for the case of missing hu_agg (i.e. nothing on stock)*/
COALESCE(hu_agg.AD_Client_ID, s.AD_Client_ID) AS AD_Client_ID,
COALESCE(hu_agg.AD_Org_ID, s.AD_Org_ID) AS AD_Org_ID,
COALESCE(hu_agg.M_Warehouse_ID, s.M_Warehouse_ID) AS M_Warehouse_ID,
COALESCE(hu_agg.M_Product_ID, s.M_Product_ID) AS M_Product_ID,
COALESCE(hu_agg.C_UOM_ID, p.C_UOM_ID) AS C_UOM_ID,
COALESCE(hu_agg.AttributesKey, s.AttributesKey) AS AttributesKey,
COALESCE(hu_agg.QtyOnHand, 0) AS QtyOnHand,

-- QtyOnHandChange is the quantity - in the view's UOM - to add to the *current* MD_Stock.QtyOnHand to get the *correct* qtyOnHand
COALESCE(hu_agg.QtyOnHand, 0) -
uomconvert(
COALESCE(hu_agg.M_Product_ID, s.M_Product_ID),
p.C_UOM_ID,
COALESCE(hu_agg.C_UOM_ID, p.C_UOM_ID),
COALESCE(s.QtyOnHand, 0)) AS QtyOnHandChange
FROM
MD_Stock s
LEFT JOIN M_Product p ON p.M_Product_ID = s.M_Product_ID /*needed for its C_UOM_ID*/
FULL OUTER JOIN
(
SELECT
hu.AD_Client_ID,
hu.AD_Org_ID,
l.M_Warehouse_ID,
hus.M_Product_ID,
hus.C_UOM_ID,
GenerateHUAttributesKey(hu.m_hu_id) as AttributesKey,
SUM(hus.Qty) as QtyOnHand
FROM m_hu hu
JOIN M_HU_Storage hus ON hus.M_HU_ID = hu.M_HU_ID
JOIN M_Locator l ON l.M_Locator_ID=hu.M_Locator_ID
WHERE hu.isactive='Y'
and M_HU_Item_Parent_ID IS NULL

/*please keep in sync with de.metas.handlingunits.IHUStatusBL.isPhysicalHU(I_M_HU)*/
and hu.HuStatus NOT IN ('P'/*Planning*/,'D'/*Destroyed*/,'E'/*Shipped*/)
GROUP BY
hu.AD_Client_ID,
hu.AD_Org_ID,
l.M_Warehouse_ID,
hus.M_Product_ID,
hus.C_UOM_ID,
GenerateHUAttributesKey(hu.m_hu_id)
) hu_agg ON true
AND hu_agg.AD_Client_ID = s.AD_Client_ID
AND hu_agg.AD_Org_ID=s.AD_Org_ID
AND hu_agg.M_Warehouse_ID = s.M_Warehouse_ID
AND hu_agg.M_Product_ID = s.M_Product_ID
AND hu_agg.AttributesKey = s.AttributesKey
/*please keep in sync with de.metas.handlingunits.IHUStatusBL.isPhysicalHU(I_M_HU)*/
and hu.HuStatus NOT IN ('P'/*Planning*/,'D'/*Destroyed*/,'E'/*Shipped*/)
GROUP BY
hu.AD_Client_ID,
hu.AD_Org_ID,
l.M_Warehouse_ID,
hus.M_Product_ID,
hus.C_UOM_ID,
GenerateHUAttributesKey(hu.m_hu_id)
) hu_agg ON true
AND hu_agg.AD_Client_ID = s.AD_Client_ID
AND hu_agg.AD_Org_ID=s.AD_Org_ID
AND hu_agg.M_Warehouse_ID = s.M_Warehouse_ID
AND hu_agg.M_Product_ID = s.M_Product_ID
AND hu_agg.AttributesKey = s.AttributesKey
;
COMMENT ON VIEW MD_Stock_From_HUs_V IS
'This view is used by the process MD_Stock_Reset_From_M_HUs to intitialize or reset the MD_stock table.
Note that due to the outer join, existing MD_Stock records that currently don''t have any HU-storage are also represented (with qty=0)
Belongs to issue "Show onhand quantity in new WebUI MRP Product Info Window" https://github.com/metasfresh/metasfresh-webui-api/issues/762';
COMMENT ON VIEW MD_Stock_From_HUs_V IS
'This view is used by the process MD_Stock_Reset_From_M_HUs to initialize or reset the MD_stock table.
Note that due to the outer join, existing MD_Stock records that currently don''t have any HU-storage are also represented (with qty=0)
Belongs to issue "Show onhand quantity in new WebUI MRP Product Info Window" https://github.com/metasfresh/metasfresh-webui-api/issues/762';
@@ -0,0 +1,59 @@

DROP VIEW IF EXISTS MD_Stock_From_HUs_V;
CREATE VIEW MD_Stock_From_HUs_V AS
SELECT
/*the COALESCEs are for the case of missing hu_agg (i.e. nothing on stock)*/
COALESCE(hu_agg.AD_Client_ID, s.AD_Client_ID) AS AD_Client_ID,
COALESCE(hu_agg.AD_Org_ID, s.AD_Org_ID) AS AD_Org_ID,
COALESCE(hu_agg.M_Warehouse_ID, s.M_Warehouse_ID) AS M_Warehouse_ID,
COALESCE(hu_agg.M_Product_ID, s.M_Product_ID) AS M_Product_ID,
COALESCE(hu_agg.C_UOM_ID, p.C_UOM_ID) AS C_UOM_ID,
COALESCE(hu_agg.AttributesKey, s.AttributesKey) AS AttributesKey,
COALESCE(hu_agg.QtyOnHand, 0) AS QtyOnHand,

-- QtyOnHandChange is the quantity - in the view's UOM - to add to the *current* MD_Stock.QtyOnHand to get the *correct* qtyOnHand
COALESCE(hu_agg.QtyOnHand, 0) -
uomconvert(
COALESCE(hu_agg.M_Product_ID, s.M_Product_ID),
p.C_UOM_ID,
COALESCE(hu_agg.C_UOM_ID, p.C_UOM_ID),
COALESCE(s.QtyOnHand, 0)) AS QtyOnHandChange
FROM
MD_Stock s
LEFT JOIN M_Product p ON p.M_Product_ID = s.M_Product_ID /*needed for its C_UOM_ID*/
FULL OUTER JOIN
(
SELECT
hu.AD_Client_ID,
hu.AD_Org_ID,
l.M_Warehouse_ID,
hus.M_Product_ID,
hus.C_UOM_ID,
GenerateHUAttributesKey(hu.m_hu_id) as AttributesKey,
SUM(hus.Qty) as QtyOnHand
FROM m_hu hu
JOIN M_HU_Storage hus ON hus.M_HU_ID = hu.M_HU_ID
JOIN M_Locator l ON l.M_Locator_ID=hu.M_Locator_ID
WHERE hu.isactive='Y'
and M_HU_Item_Parent_ID IS NULL

/*please keep in sync with de.metas.handlingunits.IHUStatusBL.isPhysicalHU(I_M_HU)*/
and hu.HuStatus NOT IN ('P'/*Planning*/,'D'/*Destroyed*/,'E'/*Shipped*/)
GROUP BY
hu.AD_Client_ID,
hu.AD_Org_ID,
l.M_Warehouse_ID,
hus.M_Product_ID,
hus.C_UOM_ID,
GenerateHUAttributesKey(hu.m_hu_id)
) hu_agg ON true
AND hu_agg.AD_Client_ID = s.AD_Client_ID
AND hu_agg.AD_Org_ID=s.AD_Org_ID
AND hu_agg.M_Warehouse_ID = s.M_Warehouse_ID
AND hu_agg.M_Product_ID = s.M_Product_ID
AND hu_agg.AttributesKey = s.AttributesKey
;
COMMENT ON VIEW MD_Stock_From_HUs_V IS
'This view is used by the process MD_Stock_Reset_From_M_HUs to initialize or reset the MD_stock table.
Note that due to the outer join, existing MD_Stock records that currently don''t have any HU-storage are also represented (with qty=0)
Belongs to issue "Show onhand quantity in new WebUI MRP Product Info Window" https://github.com/metasfresh/metasfresh-webui-api/issues/762';
Expand Up @@ -43,6 +43,7 @@ public class HUDescriptor
ProductDescriptor productDescriptor;
int huId;

/** all quantities are in the product's stocking-UOM */
BigDecimal quantity;
BigDecimal quantityDelta;

Expand Down

0 comments on commit 2259f58

Please sign in to comment.