[open-ils-commits] r15925 - in trunk/Open-ILS/src: perlmods/OpenILS/Application/Storage/Publisher sql/Pg sql/Pg/upgrade (miker)
svn at svn.open-ils.org
svn at svn.open-ils.org
Sun Mar 21 16:08:23 EDT 2010
Author: miker
Date: 2010-03-21 16:08:18 -0400 (Sun, 21 Mar 2010)
New Revision: 15925
Added:
trunk/Open-ILS/src/sql/Pg/upgrade/0202.schema.query-parser-based-fts-SP.sql
Modified:
trunk/Open-ILS/src/perlmods/OpenILS/Application/Storage/Publisher/metabib.pm
trunk/Open-ILS/src/sql/Pg/300.schema.staged_search.sql
Log:
QueryParser-based stored proc, and adjustments to calling perl -- next up, a compat wrapper and testing
Modified: trunk/Open-ILS/src/perlmods/OpenILS/Application/Storage/Publisher/metabib.pm
===================================================================
--- trunk/Open-ILS/src/perlmods/OpenILS/Application/Storage/Publisher/metabib.pm 2010-03-21 20:05:38 UTC (rev 15924)
+++ trunk/Open-ILS/src/perlmods/OpenILS/Application/Storage/Publisher/metabib.pm 2010-03-21 20:08:18 UTC (rev 15925)
@@ -2920,12 +2920,21 @@
}
+ my $param_limit = $self->QueryParser->superpage_size || 'NULL';
+ my $param_offset = 'NULL';
+
+ my $sp = $self->QueryParser->superpage || 1;
+ if ($sp > 1) {
+ $param_offset = ($sp - 1) * $sp_size;
+ }
+
my $param_search_ou = $ou;
my $param_depth = $depth; $param_depth = 'NULL' unless (defined($depth) and length($depth) > 0 );
my $param_core_query = $query->parse_tree->toSQL;
my $param_statuses = '$${' . join(',', map { s/\$//go; "\"$_\""} @statuses) . '}$$';
my $param_locations = '$${' . join(',', map { s/\$//go; "\"$_\""} @location) . '}$$';
my $staff = ($self->api_name =~ /staff/ or $query->parse_tree->find_modifier('staff')) ? "'t'" : "'f'";
+ my $metarecord = ($self->api_name =~ /metabib/ or $query->parse_tree->find_modifier('metabib') or $query->parse_tree->find_modifier('metarecord')) ? "'t'" : "'f'";
my $sth = metabib::metarecord_source_map->db_Main->prepare(<<" SQL");
SELECT *
@@ -2935,7 +2944,10 @@
$param_core_query\:\:TEXT,
$param_statuses\:\:INT[],
$param_locations\:\:INT[],
+ $param_offset\:\:INT,
+ $param_limit\:\:INT,
$staff\:\:BOOL,
+ $metarecord\:\:BOOL
);
SQL
@@ -2962,6 +2974,12 @@
delete $$summary_row{rel};
delete $$summary_row{record};
+ if (defined($args{_simple_plan})) {
+ $$summary_row{complex_query} = $args{_simple_plan};
+ } else {
+ $$summary_row{complex_query} = $query->simple_plan ? 0 : 1;
+ }
+
$client->respond( $summary_row );
$log->debug("Search yielded ".scalar(@$recs)." checked, visible results with an approximate visible total of $estimate.",DEBUG);
Modified: trunk/Open-ILS/src/sql/Pg/300.schema.staged_search.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/300.schema.staged_search.sql 2010-03-21 20:05:38 UTC (rev 15924)
+++ trunk/Open-ILS/src/sql/Pg/300.schema.staged_search.sql 2010-03-21 20:08:18 UTC (rev 15925)
@@ -634,6 +634,286 @@
$perlcode$ LANGUAGE PLPERLU;
+/*
+ SELECT *
+ FROM search.query_parser_fts(
+ $param_search_ou\:\:INT,
+ $param_depth\:\:INT,
+ $param_core_query\:\:TEXT,
+ $param_statuses\:\:INT[],
+ $param_locations\:\:INT[],
+ $staff\:\:BOOL,
+ );
+*/
+CREATE OR REPLACE FUNCTION search.query_parser_fts (
+
+ param_search_ou INT,
+ param_depth INT,
+ param_query TEXT,
+ param_statuses INT[],
+ param_locations INT[],
+ param_offset INT,
+ param_limit INT,
+ metarecord BOOL,
+ staff BOOL
+
+) RETURNS SETOF search.search_result AS $func$
+DECLARE
+
+ current_res search.search_result%ROWTYPE;
+ search_org_list INT[];
+
+ core_limit INT;
+ core_offset INT;
+ tmp_int INT;
+
+ core_result RECORD;
+ core_cursor REFCURSOR;
+ core_rel_query TEXT;
+
+ total_count INT := 0;
+ check_count INT := 0;
+ deleted_count INT := 0;
+ visible_count INT := 0;
+ excluded_count INT := 0;
+
+BEGIN
+
+ core_offset := COALESCE( param_offset, 0 );
+ core_limit := COALESCE( param_limit, 1000 );
+
+ -- core_skip_chk := COALESCE( param_skip_chk, 1 );
+
+ IF param_search_ou > 0 THEN
+ IF param_depth IS NOT NULL THEN
+ SELECT array_accum(distinct id) INTO search_org_list FROM actor.org_unit_descendants( param_search_ou, param_depth );
+ ELSE
+ SELECT array_accum(distinct id) INTO search_org_list FROM actor.org_unit_descendants( param_search_ou );
+ END IF;
+ ELSIF param_search_ou < 0 THEN
+ SELECT array_accum(distinct org_unit) INTO search_org_list FROM actor.org_lasso_map WHERE lasso = -param_search_ou;
+ ELSIF param_search_ou = 0 THEN
+ -- reserved for user lassos (ou_buckets/type='lasso') with ID passed in depth ... hack? sure.
+ END IF;
+
+ OPEN core_cursor FOR EXECUTE param_query;
+
+ LOOP
+
+ FETCH core_cursor INTO core_result;
+ EXIT WHEN NOT FOUND;
+
+ total_count := total_count + 1;
+ CONTINUE WHEN (total_count - 1 < core_offset);
+
+ check_count := check_count + 1;
+ CONTINUE WHEN (check_count > core_limit);
+
+ PERFORM 1 FROM biblio.record_entry b WHERE NOT b.deleted AND b.id IN ( SELECT * FROM search.explode_array( core_result.records ) );
+ IF NOT FOUND THEN
+ -- RAISE NOTICE ' % were all deleted ... ', core_result.records;
+ deleted_count := deleted_count + 1;
+ CONTINUE;
+ END IF;
+
+ PERFORM 1
+ FROM biblio.record_entry b
+ JOIN config.bib_source s ON (b.source = s.id)
+ WHERE s.transcendant
+ AND b.id IN ( SELECT * FROM search.explode_array( core_result.records ) );
+
+ IF FOUND THEN
+ -- RAISE NOTICE ' % were all transcendant ... ', core_result.records;
+ visible_count := visible_count + 1;
+
+ current_res.id = core_result.id;
+ current_res.rel = core_result.rel;
+
+ tmp_int := 1;
+ IF metarecord THEN
+ SELECT COUNT(DISTINCT s.source) INTO tmp_int FROM metabib.metarecord_source_map s WHERE s.metarecord = core_result.id;
+ END IF;
+
+ IF tmp_int = 1 THEN
+ current_res.record = core_result.records[1];
+ ELSE
+ current_res.record = NULL;
+ END IF;
+
+ RETURN NEXT current_res;
+
+ CONTINUE;
+ END IF;
+
+ PERFORM 1
+ FROM asset.call_number cn
+ JOIN asset.uri_call_number_map map ON (map.call_number = cn.id)
+ JOIN asset.uri uri ON (map.uri = uri.id)
+ WHERE NOT cn.deleted
+ AND cn.label = '##URI##'
+ AND uri.active
+ AND ( param_locations IS NULL OR array_upper(param_locations, 1) IS NULL )
+ AND cn.record IN ( SELECT * FROM search.explode_array( core_result.records ) )
+ AND cn.owning_lib IN ( SELECT * FROM search.explode_array( search_org_list ) )
+ LIMIT 1;
+
+ IF FOUND THEN
+ -- RAISE NOTICE ' % have at least one URI ... ', core_result.records;
+ visible_count := visible_count + 1;
+
+ current_res.id = core_result.id;
+ current_res.rel = core_result.rel;
+
+ tmp_int := 1;
+ IF metarecord THEN
+ SELECT COUNT(DISTINCT s.source) INTO tmp_int FROM metabib.metarecord_source_map s WHERE s.metarecord = core_result.id;
+ END IF;
+
+ IF tmp_int = 1 THEN
+ current_res.record = core_result.records[1];
+ ELSE
+ current_res.record = NULL;
+ END IF;
+
+ RETURN NEXT current_res;
+
+ CONTINUE;
+ END IF;
+
+ IF param_statuses IS NOT NULL AND array_upper(param_statuses, 1) > 0 THEN
+
+ PERFORM 1
+ FROM asset.call_number cn
+ JOIN asset.copy cp ON (cp.call_number = cn.id)
+ WHERE NOT cn.deleted
+ AND NOT cp.deleted
+ AND cp.status IN ( SELECT * FROM search.explode_array( param_statuses ) )
+ AND cn.record IN ( SELECT * FROM search.explode_array( core_result.records ) )
+ AND cp.circ_lib IN ( SELECT * FROM search.explode_array( search_org_list ) )
+ LIMIT 1;
+
+ IF NOT FOUND THEN
+ -- RAISE NOTICE ' % were all status-excluded ... ', core_result.records;
+ excluded_count := excluded_count + 1;
+ CONTINUE;
+ END IF;
+
+ END IF;
+
+ IF param_locations IS NOT NULL AND array_upper(param_locations, 1) > 0 THEN
+
+ PERFORM 1
+ FROM asset.call_number cn
+ JOIN asset.copy cp ON (cp.call_number = cn.id)
+ WHERE NOT cn.deleted
+ AND NOT cp.deleted
+ AND cp.location IN ( SELECT * FROM search.explode_array( param_locations ) )
+ AND cn.record IN ( SELECT * FROM search.explode_array( core_result.records ) )
+ AND cp.circ_lib IN ( SELECT * FROM search.explode_array( search_org_list ) )
+ LIMIT 1;
+
+ IF NOT FOUND THEN
+ -- RAISE NOTICE ' % were all copy_location-excluded ... ', core_result.records;
+ excluded_count := excluded_count + 1;
+ CONTINUE;
+ END IF;
+
+ END IF;
+
+ IF staff IS NULL OR NOT staff THEN
+
+ PERFORM 1
+ FROM asset.call_number cn
+ JOIN asset.copy cp ON (cp.call_number = cn.id)
+ JOIN actor.org_unit a ON (cp.circ_lib = a.id)
+ JOIN asset.copy_location cl ON (cp.location = cl.id)
+ JOIN config.copy_status cs ON (cp.status = cs.id)
+ WHERE NOT cn.deleted
+ AND NOT cp.deleted
+ AND cs.opac_visible
+ AND cl.opac_visible
+ AND cp.opac_visible
+ AND a.opac_visible
+ AND cp.circ_lib IN ( SELECT * FROM search.explode_array( search_org_list ) )
+ AND cn.record IN ( SELECT * FROM search.explode_array( core_result.records ) )
+ LIMIT 1;
+
+ IF NOT FOUND THEN
+ -- RAISE NOTICE ' % were all visibility-excluded ... ', core_result.records;
+ excluded_count := excluded_count + 1;
+ CONTINUE;
+ END IF;
+
+ ELSE
+
+ PERFORM 1
+ FROM asset.call_number cn
+ JOIN asset.copy cp ON (cp.call_number = cn.id)
+ JOIN actor.org_unit a ON (cp.circ_lib = a.id)
+ JOIN asset.copy_location cl ON (cp.location = cl.id)
+ WHERE NOT cn.deleted
+ AND NOT cp.deleted
+ AND cp.circ_lib IN ( SELECT * FROM search.explode_array( search_org_list ) )
+ AND cn.record IN ( SELECT * FROM search.explode_array( core_result.records ) )
+ LIMIT 1;
+
+ IF NOT FOUND THEN
+
+ PERFORM 1
+ FROM asset.call_number cn
+ WHERE cn.record IN ( SELECT * FROM search.explode_array( core_result.records ) )
+ LIMIT 1;
+
+ IF FOUND THEN
+ -- RAISE NOTICE ' % were all visibility-excluded ... ', core_result.records;
+ excluded_count := excluded_count + 1;
+ CONTINUE;
+ END IF;
+
+ END IF;
+
+ END IF;
+
+ visible_count := visible_count + 1;
+
+ current_res.id = core_result.id;
+ current_res.rel = core_result.rel;
+
+ tmp_int := 1;
+ IF metarecord THEN
+ SELECT COUNT(DISTINCT s.source) INTO tmp_int FROM metabib.metarecord_source_map s WHERE s.metarecord = core_result.id;
+ END IF;
+
+ IF tmp_int = 1 THEN
+ current_res.record = core_result.records[1];
+ ELSE
+ current_res.record = NULL;
+ END IF;
+
+ RETURN NEXT current_res;
+
+ IF visible_count % 1000 = 0 THEN
+ -- RAISE NOTICE ' % visible so far ... ', visible_count;
+ END IF;
+
+ END LOOP;
+
+ current_res.id = NULL;
+ current_res.rel = NULL;
+ current_res.record = NULL;
+ current_res.total = total_count;
+ current_res.checked = check_count;
+ current_res.deleted = deleted_count;
+ current_res.visible = visible_count;
+ current_res.excluded = excluded_count;
+
+ CLOSE core_cursor;
+
+ RETURN NEXT current_res;
+
+END;
+$func$ LANGUAGE PLPGSQL;
+
COMMIT;
Added: trunk/Open-ILS/src/sql/Pg/upgrade/0202.schema.query-parser-based-fts-SP.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/upgrade/0202.schema.query-parser-based-fts-SP.sql (rev 0)
+++ trunk/Open-ILS/src/sql/Pg/upgrade/0202.schema.query-parser-based-fts-SP.sql 2010-03-21 20:08:18 UTC (rev 15925)
@@ -0,0 +1,288 @@
+BEGIN;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0202'); -- miker
+
+
+/*
+ SELECT *
+ FROM search.query_parser_fts(
+ $param_search_ou\:\:INT,
+ $param_depth\:\:INT,
+ $param_core_query\:\:TEXT,
+ $param_statuses\:\:INT[],
+ $param_locations\:\:INT[],
+ $staff\:\:BOOL,
+ );
+*/
+
+CREATE OR REPLACE FUNCTION search.query_parser_fts (
+
+ param_search_ou INT,
+ param_depth INT,
+ param_query TEXT,
+ param_statuses INT[],
+ param_locations INT[],
+ param_offset INT,
+ param_limit INT,
+ metarecord BOOL,
+ staff BOOL
+
+) RETURNS SETOF search.search_result AS $func$
+DECLARE
+
+ current_res search.search_result%ROWTYPE;
+ search_org_list INT[];
+
+ core_limit INT;
+ core_offset INT;
+ tmp_int INT;
+
+ core_result RECORD;
+ core_cursor REFCURSOR;
+ core_rel_query TEXT;
+
+ total_count INT := 0;
+ check_count INT := 0;
+ deleted_count INT := 0;
+ visible_count INT := 0;
+ excluded_count INT := 0;
+
+BEGIN
+
+ core_offset := COALESCE( param_offset, 0 );
+ core_limit := COALESCE( param_limit, 1000 );
+
+ -- core_skip_chk := COALESCE( param_skip_chk, 1 );
+
+ IF param_search_ou > 0 THEN
+ IF param_depth IS NOT NULL THEN
+ SELECT array_accum(distinct id) INTO search_org_list FROM actor.org_unit_descendants( param_search_ou, param_depth );
+ ELSE
+ SELECT array_accum(distinct id) INTO search_org_list FROM actor.org_unit_descendants( param_search_ou );
+ END IF;
+ ELSIF param_search_ou < 0 THEN
+ SELECT array_accum(distinct org_unit) INTO search_org_list FROM actor.org_lasso_map WHERE lasso = -param_search_ou;
+ ELSIF param_search_ou = 0 THEN
+ -- reserved for user lassos (ou_buckets/type='lasso') with ID passed in depth ... hack? sure.
+ END IF;
+
+ OPEN core_cursor FOR EXECUTE param_query;
+
+ LOOP
+
+ FETCH core_cursor INTO core_result;
+ EXIT WHEN NOT FOUND;
+
+ total_count := total_count + 1;
+ CONTINUE WHEN (total_count - 1 < core_offset);
+
+ check_count := check_count + 1;
+ CONTINUE WHEN (check_count > core_limit);
+
+ PERFORM 1 FROM biblio.record_entry b WHERE NOT b.deleted AND b.id IN ( SELECT * FROM search.explode_array( core_result.records ) );
+ IF NOT FOUND THEN
+ -- RAISE NOTICE ' % were all deleted ... ', core_result.records;
+ deleted_count := deleted_count + 1;
+ CONTINUE;
+ END IF;
+
+ PERFORM 1
+ FROM biblio.record_entry b
+ JOIN config.bib_source s ON (b.source = s.id)
+ WHERE s.transcendant
+ AND b.id IN ( SELECT * FROM search.explode_array( core_result.records ) );
+
+ IF FOUND THEN
+ -- RAISE NOTICE ' % were all transcendant ... ', core_result.records;
+ visible_count := visible_count + 1;
+
+ current_res.id = core_result.id;
+ current_res.rel = core_result.rel;
+
+ tmp_int := 1;
+ IF metarecord THEN
+ SELECT COUNT(DISTINCT s.source) INTO tmp_int FROM metabib.metarecord_source_map s WHERE s.metarecord = core_result.id;
+ END IF;
+
+ IF tmp_int = 1 THEN
+ current_res.record = core_result.records[1];
+ ELSE
+ current_res.record = NULL;
+ END IF;
+
+ RETURN NEXT current_res;
+
+ CONTINUE;
+ END IF;
+
+ PERFORM 1
+ FROM asset.call_number cn
+ JOIN asset.uri_call_number_map map ON (map.call_number = cn.id)
+ JOIN asset.uri uri ON (map.uri = uri.id)
+ WHERE NOT cn.deleted
+ AND cn.label = '##URI##'
+ AND uri.active
+ AND ( param_locations IS NULL OR array_upper(param_locations, 1) IS NULL )
+ AND cn.record IN ( SELECT * FROM search.explode_array( core_result.records ) )
+ AND cn.owning_lib IN ( SELECT * FROM search.explode_array( search_org_list ) )
+ LIMIT 1;
+
+ IF FOUND THEN
+ -- RAISE NOTICE ' % have at least one URI ... ', core_result.records;
+ visible_count := visible_count + 1;
+
+ current_res.id = core_result.id;
+ current_res.rel = core_result.rel;
+
+ tmp_int := 1;
+ IF metarecord THEN
+ SELECT COUNT(DISTINCT s.source) INTO tmp_int FROM metabib.metarecord_source_map s WHERE s.metarecord = core_result.id;
+ END IF;
+
+ IF tmp_int = 1 THEN
+ current_res.record = core_result.records[1];
+ ELSE
+ current_res.record = NULL;
+ END IF;
+
+ RETURN NEXT current_res;
+
+ CONTINUE;
+ END IF;
+
+ IF param_statuses IS NOT NULL AND array_upper(param_statuses, 1) > 0 THEN
+
+ PERFORM 1
+ FROM asset.call_number cn
+ JOIN asset.copy cp ON (cp.call_number = cn.id)
+ WHERE NOT cn.deleted
+ AND NOT cp.deleted
+ AND cp.status IN ( SELECT * FROM search.explode_array( param_statuses ) )
+ AND cn.record IN ( SELECT * FROM search.explode_array( core_result.records ) )
+ AND cp.circ_lib IN ( SELECT * FROM search.explode_array( search_org_list ) )
+ LIMIT 1;
+
+ IF NOT FOUND THEN
+ -- RAISE NOTICE ' % were all status-excluded ... ', core_result.records;
+ excluded_count := excluded_count + 1;
+ CONTINUE;
+ END IF;
+
+ END IF;
+
+ IF param_locations IS NOT NULL AND array_upper(param_locations, 1) > 0 THEN
+
+ PERFORM 1
+ FROM asset.call_number cn
+ JOIN asset.copy cp ON (cp.call_number = cn.id)
+ WHERE NOT cn.deleted
+ AND NOT cp.deleted
+ AND cp.location IN ( SELECT * FROM search.explode_array( param_locations ) )
+ AND cn.record IN ( SELECT * FROM search.explode_array( core_result.records ) )
+ AND cp.circ_lib IN ( SELECT * FROM search.explode_array( search_org_list ) )
+ LIMIT 1;
+
+ IF NOT FOUND THEN
+ -- RAISE NOTICE ' % were all copy_location-excluded ... ', core_result.records;
+ excluded_count := excluded_count + 1;
+ CONTINUE;
+ END IF;
+
+ END IF;
+
+ IF staff IS NULL OR NOT staff THEN
+
+ PERFORM 1
+ FROM asset.call_number cn
+ JOIN asset.copy cp ON (cp.call_number = cn.id)
+ JOIN actor.org_unit a ON (cp.circ_lib = a.id)
+ JOIN asset.copy_location cl ON (cp.location = cl.id)
+ JOIN config.copy_status cs ON (cp.status = cs.id)
+ WHERE NOT cn.deleted
+ AND NOT cp.deleted
+ AND cs.opac_visible
+ AND cl.opac_visible
+ AND cp.opac_visible
+ AND a.opac_visible
+ AND cp.circ_lib IN ( SELECT * FROM search.explode_array( search_org_list ) )
+ AND cn.record IN ( SELECT * FROM search.explode_array( core_result.records ) )
+ LIMIT 1;
+
+ IF NOT FOUND THEN
+ -- RAISE NOTICE ' % were all visibility-excluded ... ', core_result.records;
+ excluded_count := excluded_count + 1;
+ CONTINUE;
+ END IF;
+
+ ELSE
+
+ PERFORM 1
+ FROM asset.call_number cn
+ JOIN asset.copy cp ON (cp.call_number = cn.id)
+ JOIN actor.org_unit a ON (cp.circ_lib = a.id)
+ JOIN asset.copy_location cl ON (cp.location = cl.id)
+ WHERE NOT cn.deleted
+ AND NOT cp.deleted
+ AND cp.circ_lib IN ( SELECT * FROM search.explode_array( search_org_list ) )
+ AND cn.record IN ( SELECT * FROM search.explode_array( core_result.records ) )
+ LIMIT 1;
+
+ IF NOT FOUND THEN
+
+ PERFORM 1
+ FROM asset.call_number cn
+ WHERE cn.record IN ( SELECT * FROM search.explode_array( core_result.records ) )
+ LIMIT 1;
+
+ IF FOUND THEN
+ -- RAISE NOTICE ' % were all visibility-excluded ... ', core_result.records;
+ excluded_count := excluded_count + 1;
+ CONTINUE;
+ END IF;
+
+ END IF;
+
+ END IF;
+
+ visible_count := visible_count + 1;
+
+ current_res.id = core_result.id;
+ current_res.rel = core_result.rel;
+
+ tmp_int := 1;
+ IF metarecord THEN
+ SELECT COUNT(DISTINCT s.source) INTO tmp_int FROM metabib.metarecord_source_map s WHERE s.metarecord = core_result.id;
+ END IF;
+
+ IF tmp_int = 1 THEN
+ current_res.record = core_result.records[1];
+ ELSE
+ current_res.record = NULL;
+ END IF;
+
+ RETURN NEXT current_res;
+
+ IF visible_count % 1000 = 0 THEN
+ -- RAISE NOTICE ' % visible so far ... ', visible_count;
+ END IF;
+
+ END LOOP;
+
+ current_res.id = NULL;
+ current_res.rel = NULL;
+ current_res.record = NULL;
+ current_res.total = total_count;
+ current_res.checked = check_count;
+ current_res.deleted = deleted_count;
+ current_res.visible = visible_count;
+ current_res.excluded = excluded_count;
+
+ CLOSE core_cursor;
+
+ RETURN NEXT current_res;
+
+END;
+$func$ LANGUAGE PLPGSQL;
+
+COMMIT;
+
More information about the open-ils-commits
mailing list