Feature request: [ 1614574 ] Port sqlj functions to pl/pgsql
Some optimizations and simple testing script for BOM_PriceXXX.sql scripts.
This commit is contained in:
parent
b01af39951
commit
e4f56664c3
|
@ -49,7 +49,7 @@ $$
|
|||
accType CHAR(1); --account type
|
||||
accSign CHAR(1); --account sign
|
||||
BEGIN
|
||||
IF COALESCE($1, 0) != 0 THEN
|
||||
IF $1 != 0 THEN
|
||||
SELECT t.AccountType, t.AccountSign
|
||||
INTO accType, accSign
|
||||
FROM C_ElementValue AS t WHERE t.C_ElementValue_ID = $1;
|
||||
|
@ -59,9 +59,11 @@ $$
|
|||
accSign := 'C';
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
IF accSign = 'C' THEN
|
||||
RETURN (COALESCE($2, 0) - COALESCE($3, 0));
|
||||
RETURN $2 - $3;
|
||||
ELSE
|
||||
RETURN $3 - $2;
|
||||
END IF;
|
||||
RETURN (COALESCE($3, 0) - COALESCE($2, 0));
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
$$ LANGUAGE plpgsql STABLE STRICT;
|
||||
|
|
|
@ -2,7 +2,7 @@
|
|||
*This file is part of Adempiere ERP Bazaar
|
||||
*http://www.adempiere.org
|
||||
*
|
||||
*Copyright (C) 2006 Timo Kontro
|
||||
*Copyright (C) 2006-2007 Timo Kontro
|
||||
*Copyright (C) 1999-2006 ComPiere, inc
|
||||
*
|
||||
*This program is free software; you can redistribute it and/or
|
||||
|
@ -21,9 +21,9 @@
|
|||
*/
|
||||
|
||||
/*
|
||||
* Loops recursively through BOM and returns BOM's total pricelimit.
|
||||
* Loops recursively through BOM and returns BOM's total limit price.
|
||||
*/
|
||||
CREATE OR REPLACE FUNCTION adempiere.bompricelimit(
|
||||
CREATE OR REPLACE FUNCTION bompricelimit(
|
||||
IN NUMERIC, -- $1 product id
|
||||
IN NUMERIC -- $2 pricelist version id
|
||||
) RETURNS NUMERIC AS
|
||||
|
@ -33,17 +33,17 @@ $$
|
|||
productprice NUMERIC;
|
||||
boms RECORD;
|
||||
BEGIN
|
||||
SELECT COALESCE(t.PriceLimit, 0) INTO price FROM m_productprice as t
|
||||
SELECT COALESCE(t.PriceLimit,0) INTO price FROM m_productprice as t
|
||||
WHERE t.m_pricelist_version_id = $2 AND t.m_product_id = $1;
|
||||
IF price = 0 THEN
|
||||
FOR boms IN SELECT t.m_productbom_id, t.bomqty
|
||||
FROM m_product_bom as t, m_product as p
|
||||
WHERE t.m_productbom_id = p.m_product_id
|
||||
AND t.m_product_id = $1 LOOP
|
||||
FROM t.m_product_bom
|
||||
WHERE t.m_product_id = $1
|
||||
LOOP
|
||||
productprice := bompricelimit(boms.m_productbom_id, $2);
|
||||
price := price + (boms.bomqty * productprice);
|
||||
END LOOP;
|
||||
END IF;
|
||||
return price;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
$$ LANGUAGE plpgsql STABLE STRICT;
|
||||
|
|
|
@ -37,13 +37,12 @@ $$
|
|||
WHERE t.m_pricelist_version_id = $2 AND t.m_product_id = $1;
|
||||
IF price = 0 THEN
|
||||
FOR boms IN SELECT t.m_productbom_id, t.bomqty
|
||||
FROM m_product_bom as t, m_product as p
|
||||
WHERE t.m_productbom_id = p.m_product_id
|
||||
AND t.m_product_id = $1 LOOP
|
||||
FROM m_product_bom as t
|
||||
WHERE t.m_product_id = $1 LOOP
|
||||
productprice := bompricelist(boms.m_productbom_id, $2);
|
||||
price := price + (boms.bomqty * productprice);
|
||||
END LOOP;
|
||||
END IF;
|
||||
return price;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
$$ LANGUAGE plpgsql STABLE STRICT;
|
||||
|
|
|
@ -21,7 +21,7 @@
|
|||
*/
|
||||
|
||||
/*
|
||||
* Loops recursively through BOM and returns sum of the bricestd fields.
|
||||
* Loops recursively through BOM and returns sum of the pricestd fields.
|
||||
*/
|
||||
CREATE OR REPLACE FUNCTION bompricestd(
|
||||
IN NUMERIC, -- $1 product id
|
||||
|
@ -37,13 +37,12 @@ $$
|
|||
WHERE t.m_pricelist_version_id = $2 AND t.m_product_id = $1;
|
||||
IF price = 0 THEN
|
||||
FOR boms IN SELECT t.m_productbom_id, t.bomqty
|
||||
FROM m_product_bom as t, m_product as p
|
||||
WHERE t.m_productbom_id = p.m_product_id
|
||||
AND t.m_product_id = $1 LOOP
|
||||
FROM m_product_bom as t
|
||||
WHERE t.m_product_id = $1 LOOP
|
||||
productprice := bompricestd(boms.m_productbom_id, $2);
|
||||
price := price + (boms.bomqty * productprice);
|
||||
END LOOP;
|
||||
END IF;
|
||||
return price;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
$$ LANGUAGE plpgsql STABLE STRICT;
|
||||
|
|
|
@ -0,0 +1,42 @@
|
|||
CREATE TABLE m_productprice (
|
||||
m_pricelist_version_id numeric,
|
||||
m_product_id numeric,
|
||||
pricelist numeric,
|
||||
pricestd numeric,
|
||||
pricelimit numeric
|
||||
);
|
||||
|
||||
CREATE TABLE m_product_bom (
|
||||
m_product_bom_id numeric(10,0),
|
||||
m_product_id numeric(10,0),
|
||||
m_productbom_id numeric(10,0),
|
||||
bomqty numeric(22,0)
|
||||
);
|
||||
|
||||
INSERT INTO m_productprice VALUES (1.,1.,0.,0.,0.);
|
||||
INSERT INTO m_productprice VALUES (1.,2.,10.20,12.20,1.50);
|
||||
INSERT INTO m_productprice VALUES (1.,3.,10.20,12.20,2.00);
|
||||
INSERT INTO m_productprice VALUES (1.,4.,0,0,0);
|
||||
|
||||
INSERT INTO m_product_bom VALUES (1.,1.,2.,5.);
|
||||
INSERT INTO m_product_bom VALUES (1.,3.,2.,1.);
|
||||
INSERT INTO m_product_bom VALUES (1.,1.,2.,2.);
|
||||
INSERT INTO m_product_bom VALUES (1.,4.,1.,3.);
|
||||
|
||||
|
||||
SELECT 1 AS TestNo, bompricelimit(2.,1.), 1.50 AS ExpectedValue;
|
||||
SELECT 2 AS TestNo, bompricelimit(1.,1.), 10.50 AS ExpectedValue;
|
||||
SELECT 3 AS TestNo, bompricelimit(4.,1.), 31.50 AS ExpectedValue;
|
||||
|
||||
|
||||
SELECT 4 AS TestNo, bompricelist(2.,1.), 10.20 AS ExpectedValue;
|
||||
SELECT 5 AS TestNo, bompricelist(1.,1.), 71.40 AS ExpectedValue;
|
||||
SELECT 6 AS TestNo, bompricelist(4.,1.), 214.20 AS ExpectedValue;
|
||||
|
||||
SELECT 5 AS TestNo, bompricestd(2.,1.), 12.20 AS ExpectedValue;
|
||||
SELECT 6 AS TestNo, bompricestd(1.,1.), 85.40 AS ExpectedValue;
|
||||
SELECT 7 AS TestNo, bompricestd(4.,1.), 256.20 AS ExpectedValue;
|
||||
|
||||
DROP TABLE m_product_bom;
|
||||
DROP TABLE m_productprice;
|
||||
|
Loading…
Reference in New Issue