Stored Procedure to return resultset from multiple delete statements. - Mailing list pgsql-sql

From Jason Aleski
Subject Stored Procedure to return resultset from multiple delete statements.
Date
Msg-id 55C188F5.7020904@gmail.com
Whole thread Raw
Responses Re: Stored Procedure to return resultset from multiple delete statements.  ("David G. Johnston" <david.g.johnston@gmail.com>)
List pgsql-sql
I have a function that will purge an item out of our inventory system.  
This script works and displays the appropriate information in the 
messages/notices pane.  I would like it to return the notices in a 
resultset format because only developers have access to the 
messages/notices pane.  I would like to display the results as a 
resultset in my application.  The problem is that I'm issuing multiple 
delete commands which cannot be joined.  I tried creating a temp table 
at the top of the procedure, then inserted data (rows affected) into the 
table; but I could not get that method to work. Can anyone point me in a 
direction on what to look at to get the "table affected" and the "number 
of rows affected by the delete" into some sort of result set?  Below is 
my current procedure that is working.  There are actually 3 more tables 
that need to be purged, but I removed those for now.

CREATE OR REPLACE FUNCTION purgeInventoryItemByCode (IN t text)
   RETURNS void AS

$BODY$

DECLARE
   RCprice_history             int;
   RCinventory_transaction_log int;
   RCitem_code                 int;

BEGIN
   --Purging price history of item.
   DELETE FROM price_history
         WHERE item_id IN (SELECT row_id
                               FROM item
                              WHERE item_code = $1);
   IF found
   THEN
      GET DIAGNOSTICS RCprice_history = ROW_COUNT;
      RAISE NOTICE 'DELETE % row(s) FROM price_history', RCprice_history;
   END IF;
   --Purging item from inventory transaction log.
   DELETE FROM inventory_transaction_log
          WHERE item_id IN (SELECT row_id
                               FROM item
                              WHERE item_code = $1);
   IF found
   THEN
      GET DIAGNOSTICS RCinventory_transaction_log = ROW_COUNT;
      RAISE NOTICE 'DELETE % row(s) FROM inventory_transaction_log', RCinventory_transaction_log;
   END IF;
   --Purging item from Master Items table
   DELETE FROM items
         WHERE item_code = $1;
   IF found
   THEN
      GET DIAGNOSTICS RCitem_code = ROW_COUNT;
      RAISE NOTICE 'DELETE % row(s) FROM items', RCitem_code;
   END IF;

END;

$BODY$
   LANGUAGE plpgsql
   VOLATILE
   COST 100

-- 
Jason Aleski / IT Specialist




pgsql-sql by date:

Previous
From: Mario Splivalo
Date:
Subject: Re: Re: Getting the list of foreign keys (for deleting data from the database)
Next
From: "David G. Johnston"
Date:
Subject: Re: Stored Procedure to return resultset from multiple delete statements.