[open-ils-commits] r14740 - in trunk/Open-ILS/src/sql/Pg: . upgrade (miker)

svn at svn.open-ils.org svn at svn.open-ils.org
Tue Nov 3 11:45:23 EST 2009


Author: miker
Date: 2009-11-03 11:45:20 -0500 (Tue, 03 Nov 2009)
New Revision: 14740

Added:
   trunk/Open-ILS/src/sql/Pg/upgrade/0067.schema.hold-copy-ratios.sql
Modified:
   trunk/Open-ILS/src/sql/Pg/002.schema.config.sql
   trunk/Open-ILS/src/sql/Pg/999.functions.global.sql
Log:
adding stored procedure for calculating available and total copy/hold ratios for a given copy

Modified: trunk/Open-ILS/src/sql/Pg/002.schema.config.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/002.schema.config.sql	2009-11-03 15:43:45 UTC (rev 14739)
+++ trunk/Open-ILS/src/sql/Pg/002.schema.config.sql	2009-11-03 16:45:20 UTC (rev 14740)
@@ -51,7 +51,7 @@
     install_date    TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
 );
 
-INSERT INTO config.upgrade_log (version) VALUES ('0065'); -- Scott McKellar
+INSERT INTO config.upgrade_log (version) VALUES ('0067'); -- miker
 
 CREATE TABLE config.bib_source (
 	id		SERIAL	PRIMARY KEY,

Modified: trunk/Open-ILS/src/sql/Pg/999.functions.global.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/999.functions.global.sql	2009-11-03 15:43:45 UTC (rev 14739)
+++ trunk/Open-ILS/src/sql/Pg/999.functions.global.sql	2009-11-03 16:45:20 UTC (rev 14740)
@@ -1108,3 +1108,54 @@
 END;
 $func$ LANGUAGE plpgsql;
 
+CREATE TYPE action.hold_stats AS (
+    hold_count              INT,
+    copy_count              INT,
+    available_count         INT,
+    total_copy_ratio        FLOAT,
+    available_copy_ratio    FLOAT
+);
+
+CREATE OR REPLACE FUNCTION action.copy_related_hold_stats (copy_id INT) RETURNS action.hold_stats AS $func$
+DECLARE
+    output          action.hold_stats%ROWTYPE;
+    hold_count      INT := 0;
+    copy_count      INT := 0;
+    available_count INT := 0;
+    hold_map_data   RECORD;
+BEGIN
+
+    output.hold_count := 0;
+    output.copy_count := 0;
+    output.available_count := 0;
+
+    SELECT  COUNT( DISTINCT m.hold ) INTO hold_count
+      FROM  action.hold_copy_map m
+            JOIN action.hold_request h ON (m.hold = h.id)
+      WHERE m.target_copy = copy_id
+            AND NOT h.frozen;
+
+    output.hold_count := hold_count;
+
+    FOR hold_map_data IN
+        SELECT  DISTINCT m.target_copy,
+                acp.status
+          FROM  action.hold_copy_map m
+                JOIN asset.copy acp ON (m.target_copy = acp.id)
+                JOIN action.hold_request h ON (m.hold = h.id)
+          WHERE m.hold IN ( SELECT DISTINCT hold FROM action.hold_copy_map WHERE target_copy = copy_id ) AND NOT h.frozen
+    LOOP
+        output.copy_count := output.copy_count + 1;
+        IF hold_map_data.status IN (0,7,12) THEN
+            output.available_count := output.available_count + 1;
+        END IF;
+    END LOOP;
+
+    output.total_copy_ratio = output.copy_count::FLOAT / output.hold_count::FLOAT;
+    output.available_copy_ratio = output.available_count::FLOAT / output.hold_count::FLOAT;
+
+    RETURN output;
+
+END;
+$func$ LANGUAGE PLPGSQL;
+

Added: trunk/Open-ILS/src/sql/Pg/upgrade/0067.schema.hold-copy-ratios.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/upgrade/0067.schema.hold-copy-ratios.sql	                        (rev 0)
+++ trunk/Open-ILS/src/sql/Pg/upgrade/0067.schema.hold-copy-ratios.sql	2009-11-03 16:45:20 UTC (rev 14740)
@@ -0,0 +1,57 @@
+BEGIN;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0067');
+
+CREATE TYPE action.hold_stats AS (
+    hold_count              INT,
+    copy_count              INT,
+    available_count         INT,
+    total_copy_ratio        FLOAT,
+    available_copy_ratio    FLOAT
+);
+
+CREATE OR REPLACE FUNCTION action.copy_related_hold_stats (copy_id INT) RETURNS action.hold_stats AS $func$
+DECLARE
+    output          action.hold_stats%ROWTYPE;
+    hold_count      INT := 0;
+    copy_count      INT := 0;
+    available_count INT := 0;
+    hold_map_data   RECORD;
+BEGIN
+
+    output.hold_count := 0;
+    output.copy_count := 0;
+    output.available_count := 0;
+
+    SELECT  COUNT( DISTINCT m.hold ) INTO hold_count
+      FROM  action.hold_copy_map m
+            JOIN action.hold_request h ON (m.hold = h.id)
+      WHERE m.target_copy = copy_id
+            AND NOT h.frozen;
+
+    output.hold_count := hold_count;
+
+    FOR hold_map_data IN
+        SELECT  DISTINCT m.target_copy,
+                acp.status
+          FROM  action.hold_copy_map m
+                JOIN asset.copy acp ON (m.target_copy = acp.id)
+                JOIN action.hold_request h ON (m.hold = h.id)
+          WHERE m.hold IN ( SELECT DISTINCT hold FROM action.hold_copy_map WHERE target_copy = copy_id ) AND NOT h.frozen
+    LOOP
+        output.copy_count := output.copy_count + 1;
+        IF hold_map_data.status IN (0,7,12) THEN
+            output.available_count := output.available_count + 1;
+        END IF;
+    END LOOP;
+
+    output.total_copy_ratio = output.copy_count::FLOAT / output.hold_count::FLOAT;
+    output.available_copy_ratio = output.available_count::FLOAT / output.hold_count::FLOAT;
+
+    RETURN output;
+
+END;
+$func$ LANGUAGE PLPGSQL;
+
+COMMIT;
+



More information about the open-ils-commits mailing list