From 3b8326b08d3ac7cf81e1381bb3f14c747d8fd44d Mon Sep 17 00:00:00 2001
From: miker <miker@dcc99617-32d9-48b4-a31d-7c20da2025e4>
Date: Wed, 23 Feb 2011 21:32:42 +0000
Subject: [PATCH] include copy/call_number deletedness in staff-version copy
 counts

git-svn-id: svn://svn.open-ils.org/ILS/trunk@19522 dcc99617-32d9-48b4-a31d-7c20da2025e4
---
 Open-ILS/src/sql/Pg/002.schema.config.sql          |   2 +-
 Open-ILS/src/sql/Pg/040.schema.asset.sql           |  16 +--
 .../0490.schema.staff-client-copy-counts.sql       | 132 +++++++++++++++++++++
 3 files changed, 141 insertions(+), 9 deletions(-)
 create mode 100644 Open-ILS/src/sql/Pg/upgrade/0490.schema.staff-client-copy-counts.sql

diff --git a/Open-ILS/src/sql/Pg/002.schema.config.sql b/Open-ILS/src/sql/Pg/002.schema.config.sql
index 2f0e06b496..294f2a4837 100644
--- a/Open-ILS/src/sql/Pg/002.schema.config.sql
+++ b/Open-ILS/src/sql/Pg/002.schema.config.sql
@@ -70,7 +70,7 @@ CREATE TABLE config.upgrade_log (
     install_date    TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
 );
 
-INSERT INTO config.upgrade_log (version) VALUES ('0489'); -- miker
+INSERT INTO config.upgrade_log (version) VALUES ('0490'); -- miker
 
 CREATE TABLE config.bib_source (
 	id		SERIAL	PRIMARY KEY,
diff --git a/Open-ILS/src/sql/Pg/040.schema.asset.sql b/Open-ILS/src/sql/Pg/040.schema.asset.sql
index cb738963e3..c7c14484de 100644
--- a/Open-ILS/src/sql/Pg/040.schema.asset.sql
+++ b/Open-ILS/src/sql/Pg/040.schema.asset.sql
@@ -469,8 +469,8 @@ BEGIN
                 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 = rid AND cn.id = cp.call_number)
+                JOIN asset.copy cp ON (cp.circ_lib = d.id AND NOT cp.deleted)
+                JOIN asset.call_number cn ON (cn.record = rid AND cn.id = cp.call_number AND NOT cn.deleted)
           GROUP BY 1,2,6;
 
         IF NOT FOUND THEN
@@ -500,8 +500,8 @@ BEGIN
                 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 = rid AND cn.id = cp.call_number)
+                JOIN asset.copy cp ON (cp.circ_lib = d.id AND NOT cp.deleted)
+                JOIN asset.call_number cn ON (cn.record = rid AND cn.id = cp.call_number AND NOT cn.deleted)
           GROUP BY 1,2,6;
 
         IF NOT FOUND THEN
@@ -615,8 +615,8 @@ BEGIN
                 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 = rid AND cn.id = cp.call_number)
+                JOIN asset.copy cp ON (cp.circ_lib = d.id AND NOT cp.deleted)
+                JOIN asset.call_number cn ON (cn.record = rid AND cn.id = cp.call_number AND NOT cn.deleted)
                 JOIN metabib.metarecord_source_map m ON (m.source = cn.record)
           GROUP BY 1,2,6;
 
@@ -647,8 +647,8 @@ BEGIN
                 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 = rid AND cn.id = cp.call_number)
+                JOIN asset.copy cp ON (cp.circ_lib = d.id AND NOT cp.deleted)
+                JOIN asset.call_number cn ON (cn.record = rid AND cn.id = cp.call_number AND NOT cn.deleted)
                 JOIN metabib.metarecord_source_map m ON (m.source = cn.record)
           GROUP BY 1,2,6;
 
diff --git a/Open-ILS/src/sql/Pg/upgrade/0490.schema.staff-client-copy-counts.sql b/Open-ILS/src/sql/Pg/upgrade/0490.schema.staff-client-copy-counts.sql
new file mode 100644
index 0000000000..6a70d535fb
--- /dev/null
+++ b/Open-ILS/src/sql/Pg/upgrade/0490.schema.staff-client-copy-counts.sql
@@ -0,0 +1,132 @@
+BEGIN;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0490'); -- miker
+
+CREATE OR REPLACE FUNCTION asset.staff_ou_record_copy_count (org INT, rid 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 = rid;
+
+    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 AND NOT cp.deleted)
+                JOIN asset.call_number cn ON (cn.record = rid AND cn.id = cp.call_number AND NOT cn.deleted)
+          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, rid 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 = rid;
+
+    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 AND NOT cp.deleted)
+                JOIN asset.call_number cn ON (cn.record = rid AND cn.id = cp.call_number AND NOT cn.deleted)
+          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, rid 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 = rid;
+
+    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 AND NOT cp.deleted)
+                JOIN asset.call_number cn ON (cn.record = rid AND cn.id = cp.call_number AND NOT cn.deleted)
+                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, rid 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 = rid;
+
+    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 AND NOT cp.deleted)
+                JOIN asset.call_number cn ON (cn.record = rid AND cn.id = cp.call_number AND NOT cn.deleted)
+                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;
+
+COMMIT;
+
-- 
2.11.0