From 344c9427ad00be8f9d7c3d0040b879b2e58d716d Mon Sep 17 00:00:00 2001 From: gmc Date: Fri, 13 May 2011 15:41:10 +0000 Subject: [PATCH] fix query in various copy count functions Signed-off-by: Galen Charlton git-svn-id: svn://svn.open-ils.org/ILS/trunk@20468 dcc99617-32d9-48b4-a31d-7c20da2025e4 --- Open-ILS/src/sql/Pg/002.schema.config.sql | 2 +- Open-ILS/src/sql/Pg/040.schema.asset.sql | 8 +- .../upgrade/0532.schema.fix_copy_count_funcs.sql | 131 ++++++++++++++++++++ 3 files changed, 136 insertions(+), 5 deletions(-) create mode 100644 Open-ILS/src/sql/Pg/upgrade/0532.schema.fix_copy_count_funcs.sql diff --git a/Open-ILS/src/sql/Pg/002.schema.config.sql b/Open-ILS/src/sql/Pg/002.schema.config.sql index 998b131..c922417 100644 --- a/Open-ILS/src/sql/Pg/002.schema.config.sql +++ b/Open-ILS/src/sql/Pg/002.schema.config.sql @@ -86,7 +86,7 @@ CREATE TRIGGER no_overlapping_deps 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, diff --git a/Open-ILS/src/sql/Pg/040.schema.asset.sql b/Open-ILS/src/sql/Pg/040.schema.asset.sql index 591543f..3e46a19 100644 --- a/Open-ILS/src/sql/Pg/040.schema.asset.sql +++ b/Open-ILS/src/sql/Pg/040.schema.asset.sql @@ -433,7 +433,7 @@ BEGIN 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 @@ BEGIN 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 @@ BEGIN 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 @@ BEGIN 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; diff --git a/Open-ILS/src/sql/Pg/upgrade/0532.schema.fix_copy_count_funcs.sql b/Open-ILS/src/sql/Pg/upgrade/0532.schema.fix_copy_count_funcs.sql new file mode 100644 index 0000000..06c3922 --- /dev/null +++ b/Open-ILS/src/sql/Pg/upgrade/0532.schema.fix_copy_count_funcs.sql @@ -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; -- 1.7.2.5