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

svn at svn.open-ils.org svn at svn.open-ils.org
Tue Aug 10 13:18:09 EDT 2010


Author: miker
Date: 2010-08-10 13:18:06 -0400 (Tue, 10 Aug 2010)
New Revision: 17152

Added:
   trunk/Open-ILS/src/sql/Pg/upgrade/0367.schema.copy-visibility-count-as-stored-proc_output-sanity.sql
Modified:
   trunk/Open-ILS/src/sql/Pg/002.schema.config.sql
   trunk/Open-ILS/src/sql/Pg/040.schema.asset.sql
Log:
Two things: 1) match old output, with rows for no holdings 2) calculate transcendance only once per function call

Modified: trunk/Open-ILS/src/sql/Pg/002.schema.config.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/002.schema.config.sql	2010-08-10 16:16:53 UTC (rev 17151)
+++ trunk/Open-ILS/src/sql/Pg/002.schema.config.sql	2010-08-10 17:18:06 UTC (rev 17152)
@@ -68,7 +68,7 @@
     install_date    TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
 );
 
-INSERT INTO config.upgrade_log (version) VALUES ('0366'); -- miker
+INSERT INTO config.upgrade_log (version) VALUES ('0367'); -- miker
 
 CREATE TABLE config.bib_source (
 	id		SERIAL	PRIMARY KEY,

Modified: trunk/Open-ILS/src/sql/Pg/040.schema.asset.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/040.schema.asset.sql	2010-08-10 16:16:53 UTC (rev 17151)
+++ trunk/Open-ILS/src/sql/Pg/040.schema.asset.sql	2010-08-10 17:18:06 UTC (rev 17152)
@@ -388,7 +388,10 @@
 CREATE OR REPLACE FUNCTION asset.opac_ou_record_copy_count (org INT, record BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
 DECLARE
     ans RECORD;
+    trans INT;
 BEGIN
+    SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = record;
+
     FOR ans IN SELECT u.id, t.depth FROM actor.org_unit_ancestors(org) AS u JOIN actor.org_unit_type t ON (u.ou_type = t.id) LOOP
         RETURN QUERY
         SELECT  ans.depth,
@@ -401,9 +404,12 @@
                 actor.org_unit_descendants(ans.id) d
                 JOIN asset.opac_visible_copies av ON (av.record = record AND av.circ_lib = d.id)
                 JOIN asset.copy cp ON (cp.id = av.id)
-                JOIN biblio.record_entry b ON (b.id = av.record)
-                LEFT JOIN config.bib_source src ON (b.source = src.id)
           GROUP BY 1,2,6;
+
+        IF NOT FOUND THEN
+            RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans;
+        END IF;
+
     END LOOP;
 
     RETURN;
@@ -413,7 +419,10 @@
 CREATE OR REPLACE FUNCTION asset.opac_lasso_record_copy_count (i_lasso INT, record BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
 DECLARE
     ans RECORD;
+    trans INT;
 BEGIN
+    SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = record;
+
     FOR ans IN SELECT u.org_unit AS id FROM actor.org_lasso_map AS u WHERE lasso = i_lasso LOOP
         RETURN QUERY
         SELECT  -1,
@@ -421,14 +430,17 @@
                 COUNT( av.id ),
                 SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ),
                 COUNT( av.id ),
-                CASE WHEN src.transcendant THEN 1 ELSE NULL::INT END
+                trans
           FROM
                 actor.org_unit_descendants(ans.id) d
                 JOIN asset.opac_visible_copies av ON (av.record = record AND av.circ_lib = d.id)
                 JOIN asset.copy cp ON (cp.id = av.id)
-                JOIN biblio.record_entry b ON (b.id = av.record)
-                LEFT JOIN config.bib_source src ON (b.source = src.id)
           GROUP BY 1,2,6;
+
+        IF NOT FOUND THEN
+            RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans;
+        END IF;
+
     END LOOP;   
                 
     RETURN;     
@@ -438,7 +450,10 @@
 CREATE OR REPLACE FUNCTION asset.staff_ou_record_copy_count (org INT, record BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
 DECLARE         
     ans RECORD; 
+    trans INT;
 BEGIN           
+    SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = record;
+
     FOR ans IN SELECT u.id, t.depth FROM actor.org_unit_ancestors(org) AS u JOIN actor.org_unit_type t ON (u.ou_type = t.id) LOOP
         RETURN QUERY
         SELECT  ans.depth,
@@ -446,14 +461,17 @@
                 COUNT( cp.id ),
                 SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ),
                 COUNT( cp.id ),
-                CASE WHEN src.transcendant THEN 1 ELSE NULL::INT END 
+                trans
           FROM
                 actor.org_unit_descendants(ans.id) d
                 JOIN asset.copy cp ON (cp.circ_lib = d.id)
                 JOIN asset.call_number cn ON (cn.record = record AND cn.id = cp.call_number)
-                JOIN biblio.record_entry b ON (b.id = cn.record)
-                LEFT JOIN config.bib_source src ON (b.source = src.id)
           GROUP BY 1,2,6;
+
+        IF NOT FOUND THEN
+            RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans;
+        END IF;
+
     END LOOP;
 
     RETURN;
@@ -463,7 +481,10 @@
 CREATE OR REPLACE FUNCTION asset.staff_lasso_record_copy_count (i_lasso INT, record BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
 DECLARE
     ans RECORD;
+    trans INT;
 BEGIN
+    SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = record;
+
     FOR ans IN SELECT u.org_unit AS id FROM actor.org_lasso_map AS u WHERE lasso = i_lasso LOOP
         RETURN QUERY
         SELECT  -1,
@@ -471,14 +492,17 @@
                 COUNT( cp.id ),
                 SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ),
                 COUNT( cp.id ),
-                CASE WHEN src.transcendant THEN 1 ELSE NULL::INT END
+                trans
           FROM
                 actor.org_unit_descendants(ans.id) d
                 JOIN asset.copy cp ON (cp.circ_lib = d.id)
                 JOIN asset.call_number cn ON (cn.record = record AND cn.id = cp.call_number)
-                JOIN biblio.record_entry b ON (b.id = cn.record)
-                LEFT JOIN config.bib_source src ON (b.source = src.id)
           GROUP BY 1,2,6;
+
+        IF NOT FOUND THEN
+            RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans;
+        END IF;
+
     END LOOP;
 
     RETURN;
@@ -508,7 +532,10 @@
 CREATE OR REPLACE FUNCTION asset.opac_ou_metarecord_copy_count (org INT, record BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
 DECLARE
     ans RECORD;
+    trans INT;
 BEGIN
+    SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = record;
+
     FOR ans IN SELECT u.id, t.depth FROM actor.org_unit_ancestors(org) AS u JOIN actor.org_unit_type t ON (u.ou_type = t.id) LOOP
         RETURN QUERY
         SELECT  ans.depth,
@@ -516,15 +543,18 @@
                 COUNT( av.id ),
                 SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ),
                 COUNT( av.id ),
-                CASE WHEN src.transcendant THEN 1 ELSE NULL::INT END
+                trans
           FROM  
                 actor.org_unit_descendants(ans.id) d
                 JOIN asset.opac_visible_copies av ON (av.record = record AND av.circ_lib = d.id)
                 JOIN asset.copy cp ON (cp.id = av.id)
-                JOIN biblio.record_entry b ON (b.id = av.record)
                 JOIN metabib.metarecord_source_map m ON (m.source = av.record)
-                LEFT JOIN config.bib_source src ON (b.source = src.id)
           GROUP BY 1,2,6;
+
+        IF NOT FOUND THEN
+            RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans;
+        END IF;
+
     END LOOP;
 
     RETURN;
@@ -534,7 +564,10 @@
 CREATE OR REPLACE FUNCTION asset.opac_lasso_metarecord_copy_count (i_lasso INT, record BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
 DECLARE
     ans RECORD;
+    trans INT;
 BEGIN
+    SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = record;
+
     FOR ans IN SELECT u.org_unit AS id FROM actor.org_lasso_map AS u WHERE lasso = i_lasso LOOP
         RETURN QUERY
         SELECT  -1,
@@ -542,15 +575,18 @@
                 COUNT( av.id ),
                 SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ),
                 COUNT( av.id ),
-                CASE WHEN src.transcendant THEN 1 ELSE NULL::INT END
+                trans
           FROM
                 actor.org_unit_descendants(ans.id) d
                 JOIN asset.opac_visible_copies av ON (av.record = record AND av.circ_lib = d.id)
                 JOIN asset.copy cp ON (cp.id = av.id)
-                JOIN biblio.record_entry b ON (b.id = av.record)
                 JOIN metabib.metarecord_source_map m ON (m.source = av.record)
-                LEFT JOIN config.bib_source src ON (b.source = src.id)
           GROUP BY 1,2,6;
+
+        IF NOT FOUND THEN
+            RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans;
+        END IF;
+
     END LOOP;   
                 
     RETURN;     
@@ -560,7 +596,10 @@
 CREATE OR REPLACE FUNCTION asset.staff_ou_metarecord_copy_count (org INT, record BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
 DECLARE         
     ans RECORD; 
-BEGIN           
+    trans INT;
+BEGIN
+    SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = record;
+
     FOR ans IN SELECT u.id, t.depth FROM actor.org_unit_ancestors(org) AS u JOIN actor.org_unit_type t ON (u.ou_type = t.id) LOOP
         RETURN QUERY
         SELECT  ans.depth,
@@ -568,15 +607,18 @@
                 COUNT( cp.id ),
                 SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ),
                 COUNT( cp.id ),
-                CASE WHEN src.transcendant THEN 1 ELSE NULL::INT END 
+                trans
           FROM
                 actor.org_unit_descendants(ans.id) d
                 JOIN asset.copy cp ON (cp.circ_lib = d.id)
                 JOIN asset.call_number cn ON (cn.record = record AND cn.id = cp.call_number)
-                JOIN biblio.record_entry b ON (b.id = cn.record)
                 JOIN metabib.metarecord_source_map m ON (m.source = cn.record)
-                LEFT JOIN config.bib_source src ON (b.source = src.id)
           GROUP BY 1,2,6;
+
+        IF NOT FOUND THEN
+            RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans;
+        END IF;
+
     END LOOP;
 
     RETURN;
@@ -586,7 +628,10 @@
 CREATE OR REPLACE FUNCTION asset.staff_lasso_metarecord_copy_count (i_lasso INT, record BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
 DECLARE
     ans RECORD;
+    trans INT;
 BEGIN
+    SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = record;
+
     FOR ans IN SELECT u.org_unit AS id FROM actor.org_lasso_map AS u WHERE lasso = i_lasso LOOP
         RETURN QUERY
         SELECT  -1,
@@ -594,15 +639,18 @@
                 COUNT( cp.id ),
                 SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ),
                 COUNT( cp.id ),
-                CASE WHEN src.transcendant THEN 1 ELSE NULL::INT END
+                trans
           FROM
                 actor.org_unit_descendants(ans.id) d
                 JOIN asset.copy cp ON (cp.circ_lib = d.id)
                 JOIN asset.call_number cn ON (cn.record = record AND cn.id = cp.call_number)
-                JOIN biblio.record_entry b ON (b.id = cn.record)
                 JOIN metabib.metarecord_source_map m ON (m.source = cn.record)
-                LEFT JOIN config.bib_source src ON (b.source = src.id)
           GROUP BY 1,2,6;
+
+        IF NOT FOUND THEN
+            RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans;
+        END IF;
+
     END LOOP;
 
     RETURN;

Added: trunk/Open-ILS/src/sql/Pg/upgrade/0367.schema.copy-visibility-count-as-stored-proc_output-sanity.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/upgrade/0367.schema.copy-visibility-count-as-stored-proc_output-sanity.sql	                        (rev 0)
+++ trunk/Open-ILS/src/sql/Pg/upgrade/0367.schema.copy-visibility-count-as-stored-proc_output-sanity.sql	2010-08-10 17:18:06 UTC (rev 17152)
@@ -0,0 +1,298 @@
+BEGIN;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0367'); -- miker
+
+CREATE OR REPLACE FUNCTION asset.opac_ou_record_copy_count (org INT, record BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
+DECLARE
+    ans RECORD;
+    trans INT;
+BEGIN
+    SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = record;
+
+    FOR ans IN SELECT u.id, t.depth FROM actor.org_unit_ancestors(org) AS u JOIN actor.org_unit_type t ON (u.ou_type = t.id) LOOP
+        RETURN QUERY
+        SELECT  ans.depth,
+                ans.id,
+                COUNT( av.id ),
+                SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ),
+                COUNT( av.id ),
+                CASE WHEN src.transcendant THEN 1 ELSE NULL::INT END
+          FROM
+                actor.org_unit_descendants(ans.id) d
+                JOIN asset.opac_visible_copies av ON (av.record = record AND av.circ_lib = d.id)
+                JOIN asset.copy cp ON (cp.id = av.id)
+          GROUP BY 1,2,6;
+
+        IF NOT FOUND THEN
+            RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans;
+        END IF;
+
+    END LOOP;
+
+    RETURN;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION asset.opac_lasso_record_copy_count (i_lasso INT, record BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
+DECLARE
+    ans RECORD;
+    trans INT;
+BEGIN
+    SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = record;
+
+    FOR ans IN SELECT u.org_unit AS id FROM actor.org_lasso_map AS u WHERE lasso = i_lasso LOOP
+        RETURN QUERY
+        SELECT  -1,
+                ans.id,
+                COUNT( av.id ),
+                SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ),
+                COUNT( av.id ),
+                trans
+          FROM
+                actor.org_unit_descendants(ans.id) d
+                JOIN asset.opac_visible_copies av ON (av.record = record AND av.circ_lib = d.id)
+                JOIN asset.copy cp ON (cp.id = av.id)
+          GROUP BY 1,2,6;
+
+        IF NOT FOUND THEN
+            RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans;
+        END IF;
+
+    END LOOP;
+
+    RETURN;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION asset.staff_ou_record_copy_count (org INT, record BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
+DECLARE
+    ans RECORD;
+    trans INT;
+BEGIN
+    SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = record;
+
+    FOR ans IN SELECT u.id, t.depth FROM actor.org_unit_ancestors(org) AS u JOIN actor.org_unit_type t ON (u.ou_type = t.id) LOOP
+        RETURN QUERY
+        SELECT  ans.depth,
+                ans.id,
+                COUNT( cp.id ),
+                SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ),
+                COUNT( cp.id ),
+                trans
+          FROM
+                actor.org_unit_descendants(ans.id) d
+                JOIN asset.copy cp ON (cp.circ_lib = d.id)
+                JOIN asset.call_number cn ON (cn.record = record AND cn.id = cp.call_number)
+          GROUP BY 1,2,6;
+
+        IF NOT FOUND THEN
+            RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans;
+        END IF;
+
+    END LOOP;
+
+    RETURN;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION asset.staff_lasso_record_copy_count (i_lasso INT, record BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
+DECLARE
+    ans RECORD;
+    trans INT;
+BEGIN
+    SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = record;
+
+    FOR ans IN SELECT u.org_unit AS id FROM actor.org_lasso_map AS u WHERE lasso = i_lasso LOOP
+        RETURN QUERY
+        SELECT  -1,
+                ans.id,
+                COUNT( cp.id ),
+                SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ),
+                COUNT( cp.id ),
+                trans
+          FROM
+                actor.org_unit_descendants(ans.id) d
+                JOIN asset.copy cp ON (cp.circ_lib = d.id)
+                JOIN asset.call_number cn ON (cn.record = record AND cn.id = cp.call_number)
+          GROUP BY 1,2,6;
+
+        IF NOT FOUND THEN
+            RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans;
+        END IF;
+
+    END LOOP;
+
+    RETURN;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION asset.record_copy_count ( place INT, record BIGINT, staff BOOL) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
+BEGIN
+    IF staff IS TRUE THEN
+        IF place > 0 THEN
+            RETURN QUERY SELECT * FROM asset.staff_ou_record_copy_count( place, record );
+        ELSE
+            RETURN QUERY SELECT * FROM asset.staff_lasso_record_copy_count( -place, record );
+        END IF;
+    ELSE
+        IF place > 0 THEN
+            RETURN QUERY SELECT * FROM asset.opac_ou_record_copy_count( place, record );
+        ELSE
+            RETURN QUERY SELECT * FROM asset.opac_lasso_record_copy_count( -place, record );
+        END IF;
+    END IF;
+
+    RETURN;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION asset.opac_ou_metarecord_copy_count (org INT, record BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
+DECLARE
+    ans RECORD;
+    trans INT;
+BEGIN
+    SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = record;
+
+    FOR ans IN SELECT u.id, t.depth FROM actor.org_unit_ancestors(org) AS u JOIN actor.org_unit_type t ON (u.ou_type = t.id) LOOP
+        RETURN QUERY
+        SELECT  ans.depth,
+                ans.id,
+                COUNT( av.id ),
+                SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ),
+                COUNT( av.id ),
+                trans
+          FROM
+                actor.org_unit_descendants(ans.id) d
+                JOIN asset.opac_visible_copies av ON (av.record = record AND av.circ_lib = d.id)
+                JOIN asset.copy cp ON (cp.id = av.id)
+                JOIN metabib.metarecord_source_map m ON (m.source = av.record)
+          GROUP BY 1,2,6;
+
+        IF NOT FOUND THEN
+            RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans;
+        END IF;
+
+    END LOOP;
+
+    RETURN;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION asset.opac_lasso_metarecord_copy_count (i_lasso INT, record BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
+DECLARE
+    ans RECORD;
+    trans INT;
+BEGIN
+    SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = record;
+
+    FOR ans IN SELECT u.org_unit AS id FROM actor.org_lasso_map AS u WHERE lasso = i_lasso LOOP
+        RETURN QUERY
+        SELECT  -1,
+                ans.id,
+                COUNT( av.id ),
+                SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ),
+                COUNT( av.id ),
+                trans
+          FROM
+                actor.org_unit_descendants(ans.id) d
+                JOIN asset.opac_visible_copies av ON (av.record = record AND av.circ_lib = d.id)
+                JOIN asset.copy cp ON (cp.id = av.id)
+                JOIN metabib.metarecord_source_map m ON (m.source = av.record)
+          GROUP BY 1,2,6;
+
+        IF NOT FOUND THEN
+            RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans;
+        END IF;
+
+    END LOOP;
+
+    RETURN;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION asset.staff_ou_metarecord_copy_count (org INT, record BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
+DECLARE
+    ans RECORD;
+    trans INT;
+BEGIN
+    SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = record;
+
+    FOR ans IN SELECT u.id, t.depth FROM actor.org_unit_ancestors(org) AS u JOIN actor.org_unit_type t ON (u.ou_type = t.id) LOOP
+        RETURN QUERY
+        SELECT  ans.depth,
+                ans.id,
+                COUNT( cp.id ),
+                SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ),
+                COUNT( cp.id ),
+                trans
+          FROM
+                actor.org_unit_descendants(ans.id) d
+                JOIN asset.copy cp ON (cp.circ_lib = d.id)
+                JOIN asset.call_number cn ON (cn.record = record AND cn.id = cp.call_number)
+                JOIN metabib.metarecord_source_map m ON (m.source = cn.record)
+          GROUP BY 1,2,6;
+
+        IF NOT FOUND THEN
+            RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans;
+        END IF;
+
+    END LOOP;
+
+    RETURN;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION asset.staff_lasso_metarecord_copy_count (i_lasso INT, record BIGINT) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
+DECLARE
+    ans RECORD;
+    trans INT;
+BEGIN
+    SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = record;
+
+    FOR ans IN SELECT u.org_unit AS id FROM actor.org_lasso_map AS u WHERE lasso = i_lasso LOOP
+        RETURN QUERY
+        SELECT  -1,
+                ans.id,
+                COUNT( cp.id ),
+                SUM( CASE WHEN cp.status IN (0,7,12) THEN 1 ELSE 0 END ),
+                COUNT( cp.id ),
+                trans
+          FROM
+                actor.org_unit_descendants(ans.id) d
+                JOIN asset.copy cp ON (cp.circ_lib = d.id)
+                JOIN asset.call_number cn ON (cn.record = record AND cn.id = cp.call_number)
+                JOIN metabib.metarecord_source_map m ON (m.source = cn.record)
+          GROUP BY 1,2,6;
+
+        IF NOT FOUND THEN
+            RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans;
+        END IF;
+
+    END LOOP;
+
+    RETURN;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION asset.metarecord_copy_count ( place INT, record BIGINT, staff BOOL) RETURNS TABLE (depth INT, org_unit INT, visible BIGINT, available BIGINT, unshadow BIGINT, transcendant INT) AS $f$
+BEGIN
+    IF staff IS TRUE THEN
+        IF place > 0 THEN
+            RETURN QUERY SELECT * FROM asset.staff_ou_metarecord_copy_count( place, record );
+        ELSE
+            RETURN QUERY SELECT * FROM asset.staff_lasso_metarecord_copy_count( -place, record );
+        END IF;
+    ELSE
+        IF place > 0 THEN
+            RETURN QUERY SELECT * FROM asset.opac_ou_metarecord_copy_count( place, record );
+        ELSE
+            RETURN QUERY SELECT * FROM asset.opac_lasso_metarecord_copy_count( -place, record );
+        END IF;
+    END IF;
+
+    RETURN;
+END;
+$f$ LANGUAGE PLPGSQL;
+
+COMMIT;
+



More information about the open-ils-commits mailing list