From 2e569175f953e96911e30c9ef637fd1219be7b2f Mon Sep 17 00:00:00 2001 From: kontro Date: Thu, 28 Dec 2006 19:17:31 +0000 Subject: [PATCH] Feature request: [ 1614574 ] Port sqlj functions to pl/pgsql Functions from org.compiere.sql.Product Warning: Untested and badly documented. --- .../postgresql/functions/BOM_PriceLimit.sql | 48 ++++++++++++ .../postgresql/functions/BOM_PriceList.sql | 48 ++++++++++++ .../postgresql/functions/BOM_PriceStd.sql | 48 ++++++++++++ .../functions/Bom_Qty_Available.sql | 34 +++++++++ .../postgresql/functions/Bom_Qty_OnHand.sql | 74 +++++++++++++++++++ .../postgresql/functions/Bom_Qty_Ordered.sql | 74 +++++++++++++++++++ .../postgresql/functions/Bom_Qty_Reserved.sql | 74 +++++++++++++++++++ .../postgresql/functions/ProductAttribute.sql | 67 +++++++++++++++++ 8 files changed, 467 insertions(+) create mode 100644 db/ddlutils/postgresql/functions/BOM_PriceLimit.sql create mode 100644 db/ddlutils/postgresql/functions/BOM_PriceList.sql create mode 100644 db/ddlutils/postgresql/functions/BOM_PriceStd.sql create mode 100644 db/ddlutils/postgresql/functions/Bom_Qty_Available.sql create mode 100644 db/ddlutils/postgresql/functions/Bom_Qty_OnHand.sql create mode 100644 db/ddlutils/postgresql/functions/Bom_Qty_Ordered.sql create mode 100644 db/ddlutils/postgresql/functions/Bom_Qty_Reserved.sql create mode 100644 db/ddlutils/postgresql/functions/ProductAttribute.sql diff --git a/db/ddlutils/postgresql/functions/BOM_PriceLimit.sql b/db/ddlutils/postgresql/functions/BOM_PriceLimit.sql new file mode 100644 index 0000000000..ac72d2f93f --- /dev/null +++ b/db/ddlutils/postgresql/functions/BOM_PriceLimit.sql @@ -0,0 +1,48 @@ +/* + *This file is part of Adempiere ERP Bazaar + *http://www.adempiere.org + * + *Copyright (C) 2006 Timo Kontro + *Copyright (C) 1999-2006 ComPiere, inc + * + *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 + *of the License, or (at your option) any later version. + * + *This program is distributed in the hope that it will be useful, + *but WITHOUT ANY WARRANTY; without even the implied warranty of + *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + *GNU General Public License for more details. + * + *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 + */ + +SET search_path = adempiere, pg_catalog; + +CREATE OR REPLACE FUNCTION bompricelimit( + IN INTEGER, -- $1 product id + IN INTEGER -- $2 pricelist version id +) RETURNS NUMERIC AS +$$ + DECLARE + price NUMERIC; + productprice NUMERIC; + boms RECORD; + BEGIN + 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 + productprice := bompricelimit(boms.m_productbom_id, $2); + price := price + (boms.bomqty * productprice); + END LOOP; + END IF; + return price; + END; +$$ LANGUAGE plpgsql; diff --git a/db/ddlutils/postgresql/functions/BOM_PriceList.sql b/db/ddlutils/postgresql/functions/BOM_PriceList.sql new file mode 100644 index 0000000000..088c3abbbf --- /dev/null +++ b/db/ddlutils/postgresql/functions/BOM_PriceList.sql @@ -0,0 +1,48 @@ +/* + *This file is part of Adempiere ERP Bazaar + *http://www.adempiere.org + * + *Copyright (C) 2006 Timo Kontro + *Copyright (C) 1999-2006 ComPiere, inc + * + *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 + *of the License, or (at your option) any later version. + * + *This program is distributed in the hope that it will be useful, + *but WITHOUT ANY WARRANTY; without even the implied warranty of + *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + *GNU General Public License for more details. + * + *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 + */ + +SET search_path = adempiere, pg_catalog; + +CREATE OR REPLACE FUNCTION bompricelist( + IN INTEGER, -- $1 product id + IN INTEGER -- $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, m_product as p + WHERE t.m_productbom_id = p.m_product_id + AND 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; diff --git a/db/ddlutils/postgresql/functions/BOM_PriceStd.sql b/db/ddlutils/postgresql/functions/BOM_PriceStd.sql new file mode 100644 index 0000000000..127b0d1b75 --- /dev/null +++ b/db/ddlutils/postgresql/functions/BOM_PriceStd.sql @@ -0,0 +1,48 @@ +/* + *This file is part of Adempiere ERP Bazaar + *http://www.adempiere.org + * + *Copyright (C) 2006 Timo Kontro + *Copyright (C) 1999-2006 ComPiere, inc + * + *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 + *of the License, or (at your option) any later version. + * + *This program is distributed in the hope that it will be useful, + *but WITHOUT ANY WARRANTY; without even the implied warranty of + *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + *GNU General Public License for more details. + * + *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 + */ + +SET search_path = adempiere, pg_catalog; + +CREATE OR REPLACE FUNCTION bompricestd( + IN INTEGER, -- $1 product id + IN INTEGER -- $2 pricelist version id +) RETURNS NUMERIC AS +$$ + DECLARE + price NUMERIC; + 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, m_product as p + WHERE t.m_productbom_id = p.m_product_id + AND 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; diff --git a/db/ddlutils/postgresql/functions/Bom_Qty_Available.sql b/db/ddlutils/postgresql/functions/Bom_Qty_Available.sql new file mode 100644 index 0000000000..fd8af3d7ad --- /dev/null +++ b/db/ddlutils/postgresql/functions/Bom_Qty_Available.sql @@ -0,0 +1,34 @@ +/* + *This file is part of Adempiere ERP Bazaar + *http://www.adempiere.org + * + *Copyright (C) 2006 Timo Kontro + *Copyright (C) 1999-2006 ComPiere, inc + * + *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 + *of the License, or (at your option) any later version. + * + *This program is distributed in the hope that it will be useful, + *but WITHOUT ANY WARRANTY; without even the implied warranty of + *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + *GNU General Public License for more details. + * + *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 + */ + +SET search_path = adempiere, pg_catalog; + +CREATE OR REPLACE FUNCTION bomqtyavailable( + IN INTEGER, -- $1 product id + IN INTEGER, -- $2 warehouse id + IN INTEGER -- $3 locator id +) RETURNS NUMERIC AS +$$ + BEGIN + RETURN (bomqtyonhand($1,$2,$3) - bomqtyreserved($1,$2,$3)); + END; +$$ LANGUAGE plpgsql; diff --git a/db/ddlutils/postgresql/functions/Bom_Qty_OnHand.sql b/db/ddlutils/postgresql/functions/Bom_Qty_OnHand.sql new file mode 100644 index 0000000000..abf0e342ab --- /dev/null +++ b/db/ddlutils/postgresql/functions/Bom_Qty_OnHand.sql @@ -0,0 +1,74 @@ +/* + *This file is part of Adempiere ERP Bazaar + *http://www.adempiere.org + * + *Copyright (C) 2006 Timo Kontro + *Copyright (C) 1999-2006 ComPiere, inc + * + *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 + *of the License, or (at your option) any later version. + * + *This program is distributed in the hope that it will be useful, + *but WITHOUT ANY WARRANTY; without even the implied warranty of + *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + *GNU General Public License for more details. + * + *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 + */ + +SET search_path = adempiere, pg_catalog; + +CREATE OR REPLACE FUNCTION bomqtyonhand( + IN INTEGER, -- $1 product id + IN INTEGER, -- $2 warehouse id + IN INTEGER -- $3 locator id +) RETURNS NUMERIC AS +$$ + DECLARE + warehouse_id INTEGER; + isbom BOOLEAN; + isstocked BOOLEAN; + ptype CHAR(1); + bom RECORD; + qty NUMERIC; + quantity NUMERIC; + precision INTEGER; + BEGIN + quantity := 99999; + SELECT (t.isbom = 'Y'), t.producttype, (t.isstocked = 'Y') + INTO isbom, ptype, isstocked FROM m_product AS t + WHERE t.m_product_id = $1; + IF ptype = "I" AND isstocked THEN + IF COALESCE($3, 0) <> 0 THEN + SELECT t.qtyonhand INTO qty FROM m_storage t + WHERE m_product_id = $1 AND t.m_locator_id= $3; + quantity := COALESCE(qty,0); + ELSIF COALESCE($2, 0) <> 0 THEN + SELECT t.qtyonhand INTO qty FROM m_storage t + WHERE m_product_id = $1 AND EXISTS ( + SELECT * FROM m_locator l WHERE t.m_locator_id = l.m_locator_id + AND l.m_warehouse_id = $2); + quantity := COALESCE(qty,0); + END IF; + ELSIF isbom THEN + FOR bom IN SELECT b.m_productbom_id, b.bomqty, p.isbom, p.isstocked, + p.producttype FROM m_product_bom b, m_product p + WHERE b.m_productbom_id=p.m_product_id AND b.m_product_id = $1 + LOOP + qty = bomqtyonhand(bom.m_productbom_id, warehouse_id, $3); + SELECT t.stdprecision INTO precision + FROM c_uom t INNER JOIN m_product p + ON t.c_uom_id = p.c_uom_id + WHERE p.m_product_id = bom.m_productbom_id; + qty := ROUND((qty/bom.bomqty),precision); + quantity := LEAST(qty, quantity); + END LOOP; + END IF; + + RETURN quantity; + END; +$$ LANGUAGE plpgsql; diff --git a/db/ddlutils/postgresql/functions/Bom_Qty_Ordered.sql b/db/ddlutils/postgresql/functions/Bom_Qty_Ordered.sql new file mode 100644 index 0000000000..22d3763223 --- /dev/null +++ b/db/ddlutils/postgresql/functions/Bom_Qty_Ordered.sql @@ -0,0 +1,74 @@ +/* + *This file is part of Adempiere ERP Bazaar + *http://www.adempiere.org + * + *Copyright (C) 2006 Timo Kontro + *Copyright (C) 1999-2006 ComPiere, inc + * + *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 + *of the License, or (at your option) any later version. + * + *This program is distributed in the hope that it will be useful, + *but WITHOUT ANY WARRANTY; without even the implied warranty of + *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + *GNU General Public License for more details. + * + *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 + */ + +SET search_path = adempiere, pg_catalog; + +CREATE OR REPLACE FUNCTION bomqtyordered( + IN INTEGER, -- $1 product id + IN INTEGER, -- $2 warehouse id + IN INTEGER -- $3 locator id +) RETURNS NUMERIC AS +$$ + DECLARE + warehouse_id INTEGER; + isbom BOOLEAN; + isstocked BOOLEAN; + ptype CHAR(1); + bom RECORD; + qty NUMERIC; + quantity NUMERIC; + precision INTEGER; + BEGIN + quantity := 99999; + SELECT (t.isbom = 'Y'), t.producttype, (t.isstocked = 'Y') + INTO isbom, ptype, isstocked FROM m_product AS t + WHERE t.m_product_id = $1; + IF ptype = "I" AND isstocked THEN + IF COALESCE($3, 0) <> 0 THEN + SELECT t.qtyordered INTO qty FROM m_storage t + WHERE m_product_id = $1 AND t.m_locator_id= $3; + quantity := COALESCE(qty,0); + ELSIF COALESCE($2, 0) <> 0 THEN + SELECT t.qtyordered INTO qty FROM m_storage t + WHERE m_product_id = $1 AND EXISTS ( + SELECT * FROM m_locator l WHERE t.m_locator_id = l.m_locator_id + AND l.m_warehouse_id = $2); + quantity := COALESCE(qty,0); + END IF; + ELSIF isbom THEN + FOR bom IN SELECT b.m_productbom_id, b.bomqty, p.isbom, p.isstocked, + p.producttype FROM m_product_bom b, m_product p + WHERE b.m_productbom_id=p.m_product_id AND b.m_product_id = $1 + LOOP + qty = bomqtyordered(bom.m_productbom_id, warehouse_id, $3); + SELECT t.stdprecision INTO precision + FROM c_uom t INNER JOIN m_product p + ON t.c_uom_id = p.c_uom_id + WHERE p.m_product_id = bom.m_productbom_id; + qty := ROUND((qty/bom.bomqty),precision); + quantity := LEAST(qty, quantity); + END LOOP; + END IF; + + RETURN quantity; + END; +$$ LANGUAGE plpgsql; diff --git a/db/ddlutils/postgresql/functions/Bom_Qty_Reserved.sql b/db/ddlutils/postgresql/functions/Bom_Qty_Reserved.sql new file mode 100644 index 0000000000..effec1fb18 --- /dev/null +++ b/db/ddlutils/postgresql/functions/Bom_Qty_Reserved.sql @@ -0,0 +1,74 @@ +/* + *This file is part of Adempiere ERP Bazaar + *http://www.adempiere.org + * + *Copyright (C) 2006 Timo Kontro + *Copyright (C) 1999-2006 ComPiere, inc + * + *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 + *of the License, or (at your option) any later version. + * + *This program is distributed in the hope that it will be useful, + *but WITHOUT ANY WARRANTY; without even the implied warranty of + *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + *GNU General Public License for more details. + * + *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 + */ + +SET search_path = adempiere, pg_catalog; + +CREATE OR REPLACE FUNCTION bomqtyreserved( + IN INTEGER, -- $1 product id + IN INTEGER, -- $2 warehouse id + IN INTEGER -- $3 locator id +) RETURNS NUMERIC AS +$$ + DECLARE + warehouse_id INTEGER; + isbom BOOLEAN; + isstocked BOOLEAN; + ptype CHAR(1); + bom RECORD; + qty NUMERIC; + quantity NUMERIC; + precision INTEGER; + BEGIN + quantity := 99999; + SELECT (t.isbom = 'Y'), t.producttype, (t.isstocked = 'Y') + INTO isbom, ptype, isstocked FROM m_product AS t + WHERE t.m_product_id = $1; + IF ptype = "I" AND isstocked THEN + IF COALESCE($3, 0) <> 0 THEN + SELECT t.qtyreserved INTO qty FROM m_storage t + WHERE m_product_id = $1 AND t.m_locator_id= $3; + quantity := COALESCE(qty,0); + ELSIF COALESCE($2, 0) <> 0 THEN + SELECT t.qtyreserved INTO qty FROM m_storage t + WHERE m_product_id = $1 AND EXISTS ( + SELECT * FROM m_locator l WHERE t.m_locator_id = l.m_locator_id + AND l.m_warehouse_id = $2); + quantity := COALESCE(qty,0); + END IF; + ELSIF isbom THEN + FOR bom IN SELECT b.m_productbom_id, b.bomqty, p.isbom, p.isstocked, + p.producttype FROM m_product_bom b, m_product p + WHERE b.m_productbom_id=p.m_product_id AND b.m_product_id = $1 + LOOP + qty = bomqtyreserved(bom.m_productbom_id, warehouse_id, $3); + SELECT t.stdprecision INTO precision + FROM c_uom t INNER JOIN m_product p + ON t.c_uom_id = p.c_uom_id + WHERE p.m_product_id = bom.m_productbom_id; + qty := ROUND((qty/bom.bomqty),precision); + quantity := LEAST(qty, quantity); + END LOOP; + END IF; + + RETURN quantity; + END; +$$ LANGUAGE plpgsql; diff --git a/db/ddlutils/postgresql/functions/ProductAttribute.sql b/db/ddlutils/postgresql/functions/ProductAttribute.sql new file mode 100644 index 0000000000..5da74bb84e --- /dev/null +++ b/db/ddlutils/postgresql/functions/ProductAttribute.sql @@ -0,0 +1,67 @@ +/* + *This file is part of Adempiere ERP Bazaar + *http://www.adempiere.org + * + *Copyright (C) 2006 Timo Kontro + *Copyright (C) 1999-2006 ComPiere, inc + * + *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 + *of the License, or (at your option) any later version. + * + *This program is distributed in the hope that it will be useful, + *but WITHOUT ANY WARRANTY; without even the implied warranty of + *MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + *GNU General Public License for more details. + * + *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 + */ + +SET search_path = adempiere, pg_catalog; + +CREATE OR REPLACE FUNCTION productattribute ( + IN INTEGER -- $1 m_attributesetinstance_id +) RETURNS VARCHAR AS +$$ + DECLARE + lot VARCHAR; + serno VARCHAR; + gdate TIMESTAMP WITH TIME ZONE; + result VARCHAR; + r RECORD; + + BEGIN + IF COALESCE($1,0) = 0 THEN + RETURN ''; + END IF; + SELECT t.lot, t.serno, t.guaranteedate + INTO lot, serno, gdate + FROM m_attributesetinstance t + WHERE t.m_attributesetinstance_id = $1; + result := ''; + IF lot IS NOT NULL THEN + result := result || lot || ' '; + END IF; + IF serno IS NOT NULL THEN + result := result || '#' || serno || ' '; + END IF; + IF gdate IS NOT NULL THEN + result := result || date_trunc('minute', gdate) || ' '; + END IF; + FOR r IN SELECT ai.value, a.name FROM m_attributeinstance ai + INNER JOIN m_attribute a ON ai.m_attribute_id = a.m_attribute_id + WHERE a.IsIstanceAttribute = 'Y' AND ai.m_attributesetinstance_id = $1 + LOOP + result := result || r.value; + result := result || ':' || r.name || ' '; + END LOOP; + + IF CHAR_LENGTH(result) > 0 THEN + result := '"' || result || '"'; + END IF; + RETURN result; + END; +$$ LANGUAGE plpgsql;