From d74fc3788b113e9e0d3a041b7eef7b93810e8a18 Mon Sep 17 00:00:00 2001 From: Carlos Ruiz Date: Wed, 7 Nov 2012 09:12:41 -0500 Subject: [PATCH] IDEMPIERE-422 Complete Native Sequence feature / Fix broken oracle procedure --- .../oracle/procedures/C_Order_DrillDown.sql | 20 +- .../oracle/201211070846_IDEMPIERE-422.sql | 177 ++++++++++++++++++ .../postgresql/201211070846_IDEMPIERE-422.sql | 5 + 3 files changed, 192 insertions(+), 10 deletions(-) create mode 100644 migration/i1.0a-release/oracle/201211070846_IDEMPIERE-422.sql create mode 100644 migration/i1.0a-release/postgresql/201211070846_IDEMPIERE-422.sql diff --git a/db/ddlutils/oracle/procedures/C_Order_DrillDown.sql b/db/ddlutils/oracle/procedures/C_Order_DrillDown.sql index 3e55c3e299..4cc3b8169f 100644 --- a/db/ddlutils/oracle/procedures/C_Order_DrillDown.sql +++ b/db/ddlutils/oracle/procedures/C_Order_DrillDown.sql @@ -1,12 +1,12 @@ -CREATE OR REPLACE PROCEDURE C_Order_DrillDown +CREATE OR REPLACE PROCEDURE C_ORDER_DRILLDOWN ( PInstance_ID IN NUMBER ) /****************************************************************************** - * ** Adempiere Product ** Copyright (c) 1999-2001 Accorto, Inc. USA + * ** Compiere Product ** Copyright (c) 1999-2001 Accorto, Inc. USA * Open Source Software Provided "AS IS" without warranty or liability - * When you use any parts (changed or unchanged), add "Powered by Adempiere" to - * your product name; See license details http://www.adempiere.org/license.html + * When you use any parts (changed or unchanged), add "Powered by Compiere" to + * your product name; See license details http://www.compiere.org/license.html ****************************************************************************** * List Orders with their Shipments and Invoices * Spool to T_Spool @@ -58,7 +58,7 @@ BEGIN -- Order Info FOR o IN Cur_Order LOOP - INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, T_Spool_Seq.NextVal, + INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, nextidfunc(1173, 'N'), o.Name || ' ' || o.DocumentNo || ': @DocStatus@=' || o.DocStatus || ', @DocAction@=' || o.DocAction || ', @Processed@=' || o.Processed); @@ -71,7 +71,7 @@ BEGIN ORDER BY Line; BEGIN FOR ol IN Cur_OrderLine LOOP - INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, T_Spool_Seq.NextVal, + INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, nextidfunc(1173, 'N'), ' @QtyOrdered@=' || ol.QtyOrdered || ', @QtyReserved@=' || ol.QtyReserved || ', @QtyDelivered@=' || ol.QtyDelivered || ', @QtyInvoiced@=' || ol.QtyInvoiced || ' - Wh=' || ol.M_Warehouse_ID @@ -88,7 +88,7 @@ BEGIN AND s.C_DocType_ID=d.C_DocType_ID; BEGIN FOR s IN Cur_InOut LOOP - INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, T_Spool_Seq.NextVal, + INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, nextidfunc(1173, 'N'), '> ' || s.Name || ' ' || s.DocumentNo || ': @DocStatus@=' || s.DocStatus || ', @Processed@=' || s.Processed || ', Wh=' || s.M_Warehouse_ID); @@ -101,7 +101,7 @@ BEGIN ORDER BY Line; BEGIN FOR sl IN Cur_InOutLine LOOP - INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, T_Spool_Seq.NextVal, + INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, nextidfunc(1173, 'N'), ' @QtyDelivered@=' || sl.MovementQty || ', Prd=' || sl.M_Product_ID); END LOOP; END; -- Shipment Lines @@ -121,7 +121,7 @@ BEGIN BEGIN FOR i IN Cur_Invoice LOOP - INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, T_Spool_Seq.NextVal, + INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, nextidfunc(1173, 'N'), '> ' || i.Name || ' ' || i.DocumentNo || ': @DocStatus@=' || i.DocStatus || ', @Processed@=' || i.Processed); @@ -134,7 +134,7 @@ BEGIN ORDER BY Line; BEGIN FOR il IN Cur_InvoiceLine LOOP - INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, T_Spool_Seq.NextVal, + INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, nextidfunc(1173, 'N'), ' @QtyInvoiced@=' || il.QtyInvoiced || ', Prd=' || il.M_Product_ID); END LOOP; END; -- Invoice Lines diff --git a/migration/i1.0a-release/oracle/201211070846_IDEMPIERE-422.sql b/migration/i1.0a-release/oracle/201211070846_IDEMPIERE-422.sql new file mode 100644 index 0000000000..4e9e3e6232 --- /dev/null +++ b/migration/i1.0a-release/oracle/201211070846_IDEMPIERE-422.sql @@ -0,0 +1,177 @@ +CREATE OR REPLACE PROCEDURE C_ORDER_DRILLDOWN +( + PInstance_ID IN NUMBER +) +/****************************************************************************** + * ** Compiere Product ** Copyright (c) 1999-2001 Accorto, Inc. USA + * Open Source Software Provided "AS IS" without warranty or liability + * When you use any parts (changed or unchanged), add "Powered by Compiere" to + * your product name; See license details http://www.compiere.org/license.html + ****************************************************************************** + * List Orders with their Shipments and Invoices + * Spool to T_Spool + */ +AS + ResultStr VARCHAR2(2000); + Message VARCHAR2(2000); + Record_ID NUMBER; + CURSOR Cur_Parameter (PInstance NUMBER) IS + SELECT i.Record_ID, p.ParameterName, p.P_String, p.P_Number, p.P_Date + FROM AD_PInstance i, AD_PInstance_Para p + WHERE i.AD_PInstance_ID=PInstance + AND i.AD_PInstance_ID=p.AD_PInstance_ID(+) + ORDER BY p.SeqNo; + -- Parameter + C_Order_ID NUMBER; + -- + CURSOR Cur_Order IS + SELECT o.C_Order_ID, d.Name, o.DocumentNo, o.DocStatus, o.DocAction, o.Processed + FROM C_Order o, C_DocType d + WHERE o.C_Order_ID=C_Order_ID + AND o.C_DocType_ID=d.C_DocType_ID + ORDER BY o.DocumentNo DESC; + +BEGIN + -- No locking or Updating + + -- Get Parameters + ResultStr := 'ReadingParameters'; + FOR p IN Cur_Parameter (PInstance_ID) LOOP + Record_ID := p.Record_ID; + IF (p.ParameterName = 'C_Order_ID') THEN + C_Order_ID := p.P_Number; + DBMS_OUTPUT.PUT_LINE(' C_Order_ID=' || C_Order_ID); + ELSE + DBMS_OUTPUT.PUT_LINE('*** Unknown Parameter=' || p.ParameterName); + END IF; + END LOOP; -- Get Parameter + DBMS_OUTPUT.PUT_LINE(' Record_ID=' || Record_ID); + + IF (C_Order_ID IS NULL) THEN + C_Order_ID := Record_ID; + END IF; + + -- Should be nothing there + DELETE T_Spool + WHERE AD_PInstance_ID=PInstance_ID; + + -- Order Info + FOR o IN Cur_Order LOOP + + INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, nextidfunc(1173, 'N'), + o.Name || ' ' || o.DocumentNo || ': @DocStatus@=' || o.DocStatus + || ', @DocAction@=' || o.DocAction || ', @Processed@=' || o.Processed); + + -- Order Lines + DECLARE + CURSOR Cur_OrderLine IS + SELECT * + FROM C_OrderLine + WHERE C_Order_ID=o.C_Order_ID + ORDER BY Line; + BEGIN + FOR ol IN Cur_OrderLine LOOP + INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, nextidfunc(1173, 'N'), + ' @QtyOrdered@=' || ol.QtyOrdered || ', @QtyReserved@=' || ol.QtyReserved + || ', @QtyDelivered@=' || ol.QtyDelivered || ', @QtyInvoiced@=' || ol.QtyInvoiced + || ' - Wh=' || ol.M_Warehouse_ID + || ', Prd=' || ol.M_Product_ID); + END LOOP; + END; + + -- Shipment + DECLARE + CURSOR Cur_InOut IS + SELECT s.M_InOut_ID, d.Name, s.DocumentNo, s.DocStatus, s.Processed, s.M_Warehouse_ID + FROM M_InOut s, C_DocType d + WHERE s.C_Order_ID = o.C_Order_ID + AND s.C_DocType_ID=d.C_DocType_ID; + BEGIN + FOR s IN Cur_InOut LOOP + INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, nextidfunc(1173, 'N'), + '> ' || s.Name || ' ' || s.DocumentNo || ': @DocStatus@=' || s.DocStatus + || ', @Processed@=' || s.Processed || ', Wh=' || s.M_Warehouse_ID); + + -- Shipment Lines + DECLARE + CURSOR Cur_InOutLine IS + SELECT * + FROM M_InOutLine + WHERE M_InOut_ID=s.M_InOut_ID + ORDER BY Line; + BEGIN + FOR sl IN Cur_InOutLine LOOP + INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, nextidfunc(1173, 'N'), + ' @QtyDelivered@=' || sl.MovementQty || ', Prd=' || sl.M_Product_ID); + END LOOP; + END; -- Shipment Lines + END LOOP; -- Shipments + END; -- Shipment + + -- Invoice + DECLARE + CURSOR Cur_Invoice IS + SELECT i.C_Invoice_ID, d.Name, i.DocumentNo, i.DocStatus, i.Processed + FROM C_Invoice i, C_DocType d + WHERE i.C_DocType_ID=d.C_DocType_ID + AND EXISTS (SELECT * FROM C_InvoiceLine l, C_OrderLine ol + WHERE i.C_Invoice_ID = l.C_Invoice_ID + AND l.C_OrderLine_ID = ol.C_OrderLine_ID + AND ol.C_Order_ID=o.C_Order_ID); + BEGIN + FOR i IN Cur_Invoice LOOP + + INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, nextidfunc(1173, 'N'), + '> ' || i.Name || ' ' || i.DocumentNo || ': @DocStatus@=' || i.DocStatus + || ', @Processed@=' || i.Processed); + + -- Invoice Lines + DECLARE + CURSOR Cur_InvoiceLine IS + SELECT * + FROM C_InvoiceLine + WHERE C_Invoice_ID=i.C_Invoice_ID + ORDER BY Line; + BEGIN + FOR il IN Cur_InvoiceLine LOOP + INSERT INTO T_Spool (AD_PInstance_ID, SeqNo, MsgText) VALUES (PInstance_ID, nextidfunc(1173, 'N'), + ' @QtyInvoiced@=' || il.QtyInvoiced || ', Prd=' || il.M_Product_ID); + END LOOP; + END; -- Invoice Lines + END LOOP; -- Invoices + END; -- Invoice + + END LOOP; -- Order + + +<> + -- Update AD_PInstance + DBMS_OUTPUT.PUT_LINE('Updating PInstance - Finished ' || Message); + UPDATE AD_PInstance + SET Updated = SysDate, + IsProcessing = 'N', + Result = 1, -- success + ErrorMsg = Message + WHERE AD_PInstance_ID=PInstance_ID; + COMMIT; + RETURN; + +EXCEPTION + WHEN OTHERS THEN + ResultStr := ResultStr || ': ' || SQLERRM || ' - ' || Message; + DBMS_OUTPUT.PUT_LINE(ResultStr); + UPDATE AD_PInstance + SET Updated = SysDate, + IsProcessing = 'N', + Result = 0, -- failure + ErrorMsg = ResultStr + WHERE AD_PInstance_ID=PInstance_ID; + COMMIT; + RETURN; + +END C_Order_DrillDown; +/ + +SELECT register_migration_script('201211070846_IDEMPIERE-422.sql') FROM dual +; + diff --git a/migration/i1.0a-release/postgresql/201211070846_IDEMPIERE-422.sql b/migration/i1.0a-release/postgresql/201211070846_IDEMPIERE-422.sql new file mode 100644 index 0000000000..54bd2ba367 --- /dev/null +++ b/migration/i1.0a-release/postgresql/201211070846_IDEMPIERE-422.sql @@ -0,0 +1,5 @@ +-- just for oracle + +SELECT register_migration_script('201211070846_IDEMPIERE-422.sql') FROM dual +; +