return undef unless (@$results);
- # The query we're constructing
- #
- # select mfae.field as id,
- # mfae.value,
- # count(distinct mmrsm.appropriate-id-field )
- # from metabib.facet_entry mfae
- # join metabib.metarecord_sourc_map mmrsm on (mfae.source = mmrsm.source)
- # where mmrsm.appropriate-id-field in IDLIST
- # group by 1,2;
-
- my $count_field = $metabib ? 'metarecord' : 'source';
+ my $facets_function = $metabib ? 'search.facets_for_metarecord_set'
+ : 'search.facets_for_record_set';
+ my $results_str = '{' . join(',', @$results) . '}';
+ my $ignore_str = ref($ignore) ? '{' . join(',', @$ignore) . '}'
+ : '{}';
my $query = {
- select => {
- mfae => [ { column => 'field', alias => 'id'}, 'value' ],
- mmrsm => [{
- transform => 'count',
- distinct => 1,
- column => $count_field,
- alias => 'count',
- aggregate => 1
- }]
- },
- from => {
- mfae => {
- mmrsm => { field => 'source', fkey => 'source' },
- cmf => { field => 'id', fkey => 'field' }
- }
- },
- where => {
- '+mmrsm' => { $count_field => $results },
- '+cmf' => { facet_field => 't' }
- }
+ from => [ $facets_function, $ignore_str, $results_str ]
};
- $query->{where}->{'+cmf'}->{field_class} = {'not in' => $ignore}
- if ref($ignore) and @$ignore > 0;
-
my $facets = OpenILS::Utils::CStoreEditor->new->json_query($query, {substream => 1});
for my $facet (@$facets) {
END;
$func$ LANGUAGE PLPGSQL;
-
+CREATE OR REPLACE FUNCTION search.facets_for_record_set(ignore_facet_classes TEXT[], hits BIGINT[]) RETURNS TABLE (id INT, value TEXT, count BIGINT) AS $$
+ SELECT id, value, count FROM (
+ SELECT mfae.field AS id,
+ mfae.value,
+ COUNT(DISTINCT mmrsm.source),
+ row_number() OVER (
+ PARTITION BY mfae.field ORDER BY COUNT(distinct mmrsm.source) DESC
+ ) AS rownum
+ FROM metabib.facet_entry mfae
+ JOIN metabib.metarecord_source_map mmrsm ON (mfae.source = mmrsm.source)
+ JOIN config.metabib_field cmf ON (cmf.id = mfae.field)
+ WHERE mmrsm.source IN (SELECT * FROM unnest(hits))
+ AND cmf.facet_field
+ AND cmf.field_class NOT IN (SELECT * FROM unnest(ignore_facet_classes))
+ GROUP by 1, 2
+ ) all_facets
+ WHERE rownum <= (SELECT COALESCE((SELECT value::INT FROM config.global_flag WHERE name = 'search.max_facets_per_field' AND enabled), 1000));
+$$ LANGUAGE SQL;
+
+CREATE OR REPLACE FUNCTION search.facets_for_metarecord_set(ignore_facet_classes TEXT[], hits BIGINT[]) RETURNS TABLE (id INT, value TEXT, count BIGINT) AS $$
+ SELECT id, value, count FROM (
+ SELECT mfae.field AS id,
+ mfae.value,
+ COUNT(DISTINCT mmrsm.metarecord),
+ row_number() OVER (
+ PARTITION BY mfae.field ORDER BY COUNT(distinct mmrsm.metarecord) DESC
+ ) AS rownum
+ FROM metabib.facet_entry mfae
+ JOIN metabib.metarecord_source_map mmrsm ON (mfae.source = mmrsm.source)
+ JOIN config.metabib_field cmf ON (cmf.id = mfae.field)
+ WHERE mmrsm.metarecord IN (SELECT * FROM unnest(hits))
+ AND cmf.facet_field
+ AND cmf.field_class NOT IN (SELECT * FROM unnest(ignore_facet_classes))
+ GROUP by 1, 2
+ ) all_facets
+ WHERE rownum <= (SELECT COALESCE((SELECT value::INT FROM config.global_flag WHERE name = 'search.max_facets_per_field' AND enabled), 1000));
+$$ LANGUAGE SQL;
+
COMMIT;
TRUE
);
+INSERT INTO config.global_flag (name, value, label, enabled)
+ VALUES (
+ 'search.max_facets_per_field',
+ '1000',
+ oils_i18n_gettext(
+ 'search.max_facets_per_field',
+ 'Search: maximum number of facet values to retrieve for each facet field',
+ 'cgf',
+ 'label'
+ ),
+ TRUE
+ );
+
INSERT INTO config.org_unit_setting_type
(name, grp, label, description, datatype)
VALUES
--- /dev/null
+BEGIN;
+
+--- SELECT evergreen.upgrade_deps_block_check('XXXX', :eg_version);
+
+CREATE OR REPLACE FUNCTION search.facets_for_record_set(ignore_facet_classes TEXT[], hits BIGINT[]) RETURNS TABLE (id INT, value TEXT, count BIGINT) AS $$
+ SELECT id, value, count FROM (
+ SELECT mfae.field AS id,
+ mfae.value,
+ COUNT(DISTINCT mmrsm.source),
+ row_number() OVER (
+ PARTITION BY mfae.field ORDER BY COUNT(distinct mmrsm.source) DESC
+ ) AS rownum
+ FROM metabib.facet_entry mfae
+ JOIN metabib.metarecord_source_map mmrsm ON (mfae.source = mmrsm.source)
+ JOIN config.metabib_field cmf ON (cmf.id = mfae.field)
+ WHERE mmrsm.source IN (SELECT * FROM unnest(hits))
+ AND cmf.facet_field
+ AND cmf.field_class NOT IN (SELECT * FROM unnest(ignore_facet_classes))
+ GROUP by 1, 2
+ ) all_facets
+ WHERE rownum <= (SELECT COALESCE((SELECT value::INT FROM config.global_flag WHERE name = 'search.max_facets_per_field' AND enabled), 1000));
+$$ LANGUAGE SQL;
+
+CREATE OR REPLACE FUNCTION search.facets_for_metarecord_set(ignore_facet_classes TEXT[], hits BIGINT[]) RETURNS TABLE (id INT, value TEXT, count BIGINT) AS $$
+ SELECT id, value, count FROM (
+ SELECT mfae.field AS id,
+ mfae.value,
+ COUNT(DISTINCT mmrsm.metarecord),
+ row_number() OVER (
+ PARTITION BY mfae.field ORDER BY COUNT(distinct mmrsm.metarecord) DESC
+ ) AS rownum
+ FROM metabib.facet_entry mfae
+ JOIN metabib.metarecord_source_map mmrsm ON (mfae.source = mmrsm.source)
+ JOIN config.metabib_field cmf ON (cmf.id = mfae.field)
+ WHERE mmrsm.metarecord IN (SELECT * FROM unnest(hits))
+ AND cmf.facet_field
+ AND cmf.field_class NOT IN (SELECT * FROM unnest(ignore_facet_classes))
+ GROUP by 1, 2
+ ) all_facets
+ WHERE rownum <= (SELECT COALESCE((SELECT value::INT FROM config.global_flag WHERE name = 'search.max_facets_per_field' AND enabled), 1000));
+$$ LANGUAGE SQL;
+
+INSERT INTO config.global_flag (name, value, label, enabled)
+ VALUES (
+ 'search.max_facets_per_field',
+ '1000',
+ oils_i18n_gettext(
+ 'search.max_facets_per_field',
+ 'Search: maximum number of facet values to retrieve for each facet field',
+ 'cgf',
+ 'label'
+ ),
+ TRUE
+ );
+
+COMMIT;