From c978848d17959a6e1fd623b09f8981536f40aa71 Mon Sep 17 00:00:00 2001 From: vpj-cd Date: Thu, 30 Oct 2008 01:54:12 +0000 Subject: [PATCH] [ 1840219 ] Migration from pl/java to pl/pgSQL for PostgreSQL http://sourceforge.net/tracker/index.php?func=detail&aid=1840219&group_id=176962&atid=879335 --- .../postgresql/functions/BOM_PriceList.sql | 72 +++++++++++-------- .../postgresql/functions/BOM_PriceStd.sql | 71 ++++++++++-------- 2 files changed, 83 insertions(+), 60 deletions(-) diff --git a/db/ddlutils/postgresql/functions/BOM_PriceList.sql b/db/ddlutils/postgresql/functions/BOM_PriceList.sql index 3d583f97ce..380ad4aa90 100644 --- a/db/ddlutils/postgresql/functions/BOM_PriceList.sql +++ b/db/ddlutils/postgresql/functions/BOM_PriceList.sql @@ -1,10 +1,7 @@ /* *This file is part of Adempiere ERP Bazaar *http://www.adempiere.org - * - *Copyright (C) 2006 Timo Kontro - *Copyright (C) 1999-2006 ComPiere, inc - * + *Copyright (C) 2006-2008 victor.perez@e-evolution.com, e-Evolution *This program is free software; you can redistribute it and/or *modify it under the terms of the GNU General Public License *as published by the Free Software Foundation; either version 2 @@ -18,31 +15,46 @@ *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., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of + * Title: Return List Price of Product/BOM + * Description: */ +CREATE OR REPLACE FUNCTION Bompricelist +( + Product_ID numeric, + PriceList_Version_ID numeric +) +RETURNS numeric +AS +$BODY$ +DECLARE + v_Price numeric; + v_ProductPrice numeric; + bom record; +BEGIN + -- Try to get price from pricelist directly + SELECT COALESCE (SUM(PriceList), 0) + INTO v_Price + FROM M_PRODUCTPRICE + WHERE M_PriceList_Version_ID=PriceList_Version_ID AND M_Product_ID=Product_ID; +-- DBMS_OUTPUT.PUT_LINE('Price=' || Price); -/* - * Loops recursively through bom and returns sum of list prices (pricelist). - */ -CREATE OR REPLACE FUNCTION bompricelist( - IN NUMERIC, -- $1 product id - IN NUMERIC -- $2 pricelist version id -) RETURNS NUMERIC AS -$$ - DECLARE - price NUMERIC; - productprice NUMERIC; - boms RECORD; - BEGIN - SELECT COALESCE(t.PriceList, 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 - 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 STABLE STRICT; + -- No Price - Check if BOM + IF (v_Price = 0) THEN + FOR bom IN + --Get BOM Product info + SELECT bl.M_Product_ID AS M_ProductBOM_ID, CASE WHEN bl.IsQtyPercentage = 'N' THEN bl.QtyBOM ELSE bl.QtyBatch / 100 END AS BomQty , p.IsBOM + FROM PP_PRODUCT_BOM b + INNER JOIN M_PRODUCT p ON (p.M_Product_ID=b.M_Product_ID) + INNER JOIN PP_PRODUCT_BOMLINE bl ON (bl.PP_Product_BOM_ID=b.PP_Product_BOM_ID) + WHERE b.M_Product_ID = Product_ID + LOOP + v_ProductPrice := Bompricelist (bom.M_ProductBOM_ID, PriceList_Version_ID); + v_Price := v_Price + (bom.BOMQty * v_ProductPrice); + -- DBMS_OUTPUT.PUT_LINE('Qry=' || bom.BOMQty || ' @ ' || v_ProductPrice || ', Price=' || v_Price); + END LOOP; -- BOM + END IF; + -- + RETURN v_Price; +END; +$BODY$ + LANGUAGE 'plpgsql' STABLE STRICT diff --git a/db/ddlutils/postgresql/functions/BOM_PriceStd.sql b/db/ddlutils/postgresql/functions/BOM_PriceStd.sql index 898363607e..5e3cb86c25 100644 --- a/db/ddlutils/postgresql/functions/BOM_PriceStd.sql +++ b/db/ddlutils/postgresql/functions/BOM_PriceStd.sql @@ -1,10 +1,7 @@ /* *This file is part of Adempiere ERP Bazaar *http://www.adempiere.org - * - *Copyright (C) 2006-2007 Timo Kontro - *Copyright (C) 1999-2006 ComPiere, inc - * + *Copyright (C) 2006-2008 victor.perez@e-evolution.com, e-Evolution *This program is free software; you can redistribute it and/or *modify it under the terms of the GNU General Public License *as published by the Free Software Foundation; either version 2 @@ -18,31 +15,45 @@ *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., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.of + * Title: Return Standard Price of Product/BOM + * Description: */ +CREATE OR REPLACE FUNCTION Bompricestd +( + Product_ID numeric, + PriceList_Version_ID numeric +) +RETURNS numeric +AS +$BODY$ +DECLARE + v_Price numeric; + v_ProductPrice numeric; + bom record; +BEGIN + -- Try to get price from pricelist directly + SELECT COALESCE(SUM(PriceStd), 0) + INTO v_Price + FROM M_PRODUCTPRICE + WHERE M_PriceList_Version_ID=PriceList_Version_ID AND M_Product_ID=Product_ID; +-- DBMS_OUTPUT.PUT_LINE('Price=' || v_Price); -/* - * Loops recursively through BOM and returns sum of the pricestd fields. - */ -CREATE OR REPLACE FUNCTION bompricestd( - IN NUMERIC, -- $1 product id - IN NUMERIC -- $2 pricelist version id -) RETURNS NUMERIC AS -$$ - DECLARE - price NUMERIC; --used to store total sum - productprice NUMERIC; - boms RECORD; - BEGIN - SELECT COALESCE(t.Pricestd, 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 - 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 STABLE STRICT; + -- No Price - Check if BOM + IF (v_Price = 0) THEN + FOR bom IN -- Get BOM Product info + SELECT bl.M_Product_ID AS M_ProductBOM_ID, CASE WHEN bl.IsQtyPercentage = 'N' THEN bl.QtyBOM ELSE bl.QtyBatch / 100 END AS BomQty , p.IsBOM + FROM PP_PRODUCT_BOM b + INNER JOIN M_PRODUCT p ON (p.M_Product_ID=b.M_Product_ID) + INNER JOIN PP_PRODUCT_BOMLINE bl ON (bl.PP_Product_BOM_ID=b.PP_Product_BOM_ID) + WHERE b.M_Product_ID = Product_ID + LOOP + v_ProductPrice := Bompricestd (bom.M_ProductBOM_ID, PriceList_Version_ID); + v_Price := v_Price + (bom.BOMQty * v_ProductPrice); + -- DBMS_OUTPUT.PUT_LINE('Price=' || v_Price); + END LOOP; -- BOM + END IF; + -- + RETURN v_Price; +END; +$BODY$ + LANGUAGE 'plpgsql' STABLE STRICT