[open-ils-commits] r20468 - in trunk/Open-ILS/src/sql/Pg: . upgrade (gmc)
svn at svn.open-ils.org
svn at svn.open-ils.org
Fri May 13 11:41:13 EDT 2011
Author: gmc
Date: 2011-05-13 11:41:10 -0400 (Fri, 13 May 2011)
New Revision: 20468
Added:
trunk/Open-ILS/src/sql/Pg/upgrade/0532.schema.fix_copy_count_funcs.sql
Modified:
trunk/Open-ILS/src/sql/Pg/002.schema.config.sql
trunk/Open-ILS/src/sql/Pg/040.schema.asset.sql
Log:
fix query in various copy count functions
Signed-off-by: Galen Charlton <gmc at esilibrary.com>
Modified: trunk/Open-ILS/src/sql/Pg/002.schema.config.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/002.schema.config.sql 2011-05-13 13:26:46 UTC (rev 20467)
+++ trunk/Open-ILS/src/sql/Pg/002.schema.config.sql 2011-05-13 15:41:10 UTC (rev 20468)
@@ -86,7 +86,7 @@
BEFORE INSERT OR UPDATE ON config.db_patch_dependencies
FOR EACH ROW EXECUTE PROCEDURE evergreen.array_overlap_check ('deprecates');
-INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0531', :eg_version); -- gmc
+INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0532', :eg_version); -- gmc
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 2011-05-13 13:26:46 UTC (rev 20467)
+++ trunk/Open-ILS/src/sql/Pg/040.schema.asset.sql 2011-05-13 15:41:10 UTC (rev 20468)
@@ -433,7 +433,7 @@
FROM
actor.org_unit_descendants(ans.id) d
JOIN asset.opac_visible_copies av ON (av.record = rid AND av.circ_lib = d.id)
- JOIN asset.copy cp ON (cp.id = av.id)
+ JOIN asset.copy cp ON (cp.id = av.copy_id)
GROUP BY 1,2,6;
IF NOT FOUND THEN
@@ -464,7 +464,7 @@
FROM
actor.org_unit_descendants(ans.id) d
JOIN asset.opac_visible_copies av ON (av.record = rid AND av.circ_lib = d.id)
- JOIN asset.copy cp ON (cp.id = av.id)
+ JOIN asset.copy cp ON (cp.id = av.copy_id)
GROUP BY 1,2,6;
IF NOT FOUND THEN
@@ -577,7 +577,7 @@
FROM
actor.org_unit_descendants(ans.id) d
JOIN asset.opac_visible_copies av ON (av.record = rid AND av.circ_lib = d.id)
- JOIN asset.copy cp ON (cp.id = av.id)
+ JOIN asset.copy cp ON (cp.id = av.copy_id)
JOIN metabib.metarecord_source_map m ON (m.source = av.record)
GROUP BY 1,2,6;
@@ -609,7 +609,7 @@
FROM
actor.org_unit_descendants(ans.id) d
JOIN asset.opac_visible_copies av ON (av.record = rid AND av.circ_lib = d.id)
- JOIN asset.copy cp ON (cp.id = av.id)
+ JOIN asset.copy cp ON (cp.id = av.copy_id)
JOIN metabib.metarecord_source_map m ON (m.source = av.record)
GROUP BY 1,2,6;
Added: trunk/Open-ILS/src/sql/Pg/upgrade/0532.schema.fix_copy_count_funcs.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/upgrade/0532.schema.fix_copy_count_funcs.sql (rev 0)
+++ trunk/Open-ILS/src/sql/Pg/upgrade/0532.schema.fix_copy_count_funcs.sql 2011-05-13 15:41:10 UTC (rev 20468)
@@ -0,0 +1,131 @@
+BEGIN;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0532'); --gmc
+
+CREATE OR REPLACE FUNCTION asset.opac_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( 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 = rid AND av.circ_lib = d.id)
+ JOIN asset.copy cp ON (cp.id = av.copy_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, 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( 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 = rid AND av.circ_lib = d.id)
+ JOIN asset.copy cp ON (cp.id = av.copy_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_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( 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 = rid AND av.circ_lib = d.id)
+ JOIN asset.copy cp ON (cp.id = av.copy_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, 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( 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 = rid AND av.circ_lib = d.id)
+ JOIN asset.copy cp ON (cp.id = av.copy_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;
+
+COMMIT;
More information about the open-ils-commits
mailing list