core_scripts = $(examples)/oils_ctl.sh \
$(supportscr)/fine_generator.pl \
+ $(supportscr)/tattler.pl \
$(supportscr)/hold_targeter.pl \
$(supportscr)/hold_targeter_legacy.pl \
$(supportscr)/reshelving_complete.srfsh \
$(do_subst) @srcdir@/extras/import/parallel_pg_loader.pl.in > "$@"
chmod 755 "$@"
+$(supportscr)/tattler.pl: Makefile $(supportscr)/tattler.pl.in
+ $(do_subst) $(supportscr)/tattler.pl.in > "$@"
+ chmod 755 "$@"
+
$(supportscr)/action_trigger_runner.pl: Makefile $(supportscr)/action_trigger_runner.pl.in
$(do_subst) $(supportscr)/action_trigger_runner.pl.in > "$@"
chmod 755 "$@"
sed -i 's|BINDIR|@bindir@|g' '$(DESTDIR)@bindir@/purge_pending_users.srfsh'
sed -i 's|LOCALSTATEDIR|@localstatedir@|g' '$(DESTDIR)@bindir@/oils_ctl.sh'
sed -i 's|SYSCONFDIR|@sysconfdir@|g' '$(DESTDIR)@bindir@/oils_ctl.sh'
+ cp -r '$(supportscr)/tattle-tale-scripts' '$(DESTDIR)@bindir@/tattle-tale-scripts'
reporter-install:
sed -i 's|SYSCONFDIR|@sysconfdir@|g' '$(DESTDIR)@bindir@/clark-kent.pl'
--- /dev/null
+DROP TABLE IF EXISTS dvd_mis;
+DROP TABLE IF EXISTS icon_formats;
+CREATE TEMP TABLE icon_formats AS
+SELECT id,STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ GROUP BY ID HAVING count(id) = 1;
+
+CREATE TEMP TABLE dvd_mis AS
+select BRE.id as bib_id,AC.id as copy_id,ACN.LABEL as call_number_label,icon_formats."FORMAT",crtr.id as creator_id, crtr.email as creator_email, edtr.id editor_id, edtr.email editor_email,AOU.NAME, ac.circ_lib
+from biblio.record_entry BRE, ASSET.COPY AC, ACTOR.ORG_UNIT AOU,ASSET.CALL_NUMBER ACN,ASSET.COPY_LOCATION ACL,ACTOR.USR EDTR,ACTOR.USR CRTR, icon_formats where
+AOU.ID=AC.CIRC_LIB AND
+EDTR.ID = AC.EDITOR AND
+CRTR.ID = AC.CREATOR AND
+BRE.ID=ACN.RECORD AND
+BRE.ID=icon_formats.id AND
+ACN.ID=AC.CALL_NUMBER AND
+ACL.ID=AC.LOCATION AND
+NOT ACN.DELETED AND
+NOT AC.DELETED AND
+BRE.ID>0 AND
+(
+ACN.ID IN(SELECT ID FROM ASSET.CALL_NUMBER WHERE (LOWER(LABEL)~$$ dvd$$ OR LOWER(LABEL)~$$^dvd$$) )
+OR
+ACL.ID IN(SELECT ID FROM ASSET.COPY_LOCATION WHERE (LOWER(NAME)~$$ dvd$$ OR LOWER(NAME)~$$^dvd$$) )
+OR
+lower(ac.circ_modifier) ~* $$ dvd$$ OR
+lower(ac.circ_modifier) ~* $$^dvd$$
+)
+AND
+icon_formats."FORMAT"!~$$dvd$$
+UNION
+select BRE.id as bib_id,AC.id as copy_id,ACN.LABEL as call_number_label,icon_formats."FORMAT",crtr.id as creator_id, crtr.email as creator_email, edtr.id editor_id, edtr.email editor_email,AOU.NAME, ac.circ_lib
+from biblio.record_entry BRE, ASSET.COPY AC, ACTOR.ORG_UNIT AOU,ASSET.CALL_NUMBER ACN,ASSET.COPY_LOCATION ACL, ACTOR.USR EDTR,ACTOR.USR CRTR, icon_formats where
+AOU.ID=AC.CIRC_LIB AND
+EDTR.ID = AC.EDITOR AND
+CRTR.ID = AC.CREATOR AND
+BRE.ID=ACN.RECORD AND
+BRE.ID=icon_formats.id AND
+ACN.ID=AC.CALL_NUMBER AND
+ACL.ID=AC.LOCATION AND
+NOT ACN.DELETED AND
+NOT AC.DELETED AND
+BRE.ID>0 AND
+(
+ lower(acn.label) !~* $$ dvd$$ and
+ lower(acn.label) !~* $$^dvd$$ and
+ lower(acn.label) !~* $$movie$$ and
+ lower(acn.label) !~* $$video$$
+)
+and
+(
+ lower(acl.name) !~* $$ dvd$$ and
+ lower(acl.name) !~* $$^dvd$$ and
+ lower(acl.name) !~* $$movie$$ and
+ lower(acl.name) !~* $$video$$
+)
+and
+(
+ lower(ac.circ_modifier) !~* $$ dvd$$ and
+ lower(ac.circ_modifier) !~* $$^dvd$$ and
+ lower(ac.circ_modifier) !~* $$movie$$ and
+ lower(ac.circ_modifier) !~* $$video$$
+)
+AND
+icon_formats."FORMAT"~$$dvd$$
+
+order by 1;
+
+select * from (select id as system_id from actor.org_unit where parent_ou = 1) as systems
+join lateral ( select dvd_mis.*,aou.name from dvd_mis join actor.org_unit aou on aou.id = circ_lib where copy_id not in (select target_copy from tattler.ignore_list where org_unit = system_id and report_name = ?) and (select id from actor.org_unit_ancestor_at_depth(circ_lib, 1)) = system_id limit ?
+) as p on true
+
+order by system_id;
\ No newline at end of file
--- /dev/null
+DROP TABLE IF EXISTS audio_bibs;
+CREATE TEMP TABLE audio_bibs AS
+select bre.id as bib_id,ac.id as copy_id, ac.circ_lib from biblio.record_entry bre, actor.usr crtr, actor.usr edtr, asset.call_number acn, asset.copy ac
+where
+bre.ID=acn.RECORD AND
+acn.ID=ac.CALL_NUMBER AND
+
+not bre.deleted and lower(marc) ~ $$<datafield tag="856" ind1="4" ind2="0">$$ and edtr.id = bre.editor and crtr.id = bre.creator
+and
+(
+ marc ~ $$tag="008">.......................[oqs]$$
+ or
+ marc ~ $$tag="006">......[oqs]$$
+)
+and
+(
+ marc ~ $$<leader>......i$$
+);
+
+select * from (select id as system_id from actor.org_unit where parent_ou = 1) as systems
+join lateral ( select audio_bibs.*,aou.name from audio_bibs join actor.org_unit aou on aou.id = circ_lib where copy_id not in (select target_copy from tattler.ignore_list where org_unit = system_id and report_name = ?) and (select id from actor.org_unit_ancestor_at_depth(circ_lib, 1)) = system_id limit ?) as p on true;
--- /dev/null
+DROP TABLE IF EXISTS vhs_mis;
+DROP TABLE IF EXISTS icon_formats;
+CREATE TEMP TABLE icon_formats AS
+SELECT id,STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ GROUP BY ID HAVING count(id) = 1;
+CREATE TEMP TABLE vhs_mis AS
+select BRE.id as bib_id,AC.id as copy_id,ACN.LABEL,icon_formats."FORMAT",crtr.id as creator_id, crtr.email as creator_email, edtr.id editor_id, edtr.email editor_email,AOU.NAME, ac.circ_lib
+from biblio.record_entry BRE, ASSET.COPY AC, ACTOR.ORG_UNIT AOU,ASSET.CALL_NUMBER ACN,ASSET.COPY_LOCATION ACL, ACTOR.USR EDTR,ACTOR.USR CRTR,icon_formats where
+AOU.ID=AC.CIRC_LIB AND
+EDTR.ID = AC.EDITOR AND
+CRTR.ID = AC.CREATOR AND
+BRE.ID=ACN.RECORD AND
+BRE.ID=icon_formats.id AND
+ACN.ID=AC.CALL_NUMBER AND
+ACL.ID=AC.LOCATION AND
+NOT ACN.DELETED AND
+NOT AC.DELETED AND
+BRE.ID>0 AND
+(
+ACN.ID IN(SELECT ID FROM ASSET.CALL_NUMBER WHERE (LOWER(LABEL)~$$vhs$$) )
+OR
+ACL.ID IN(SELECT ID FROM ASSET.COPY_LOCATION WHERE (LOWER(NAME)~$$vhs$$) )
+OR
+lower(ac.circ_modifier) ~* $$vhs$$
+)
+AND
+icon_formats."FORMAT"!~$$vhs$$
+UNION
+select BRE.id bib_id,AC.id as copy_id,ACN.LABEL,icon_formats."FORMAT",crtr.id as creator_id, crtr.email as creator_email, edtr.id editor_id, edtr.email editor_email,AOU.NAME, ac.circ_lib
+from biblio.record_entry BRE, ASSET.COPY AC, ACTOR.ORG_UNIT AOU,ASSET.CALL_NUMBER ACN,ASSET.COPY_LOCATION ACL, ACTOR.USR EDTR,ACTOR.USR CRTR,icon_formats where
+AOU.ID=AC.CIRC_LIB AND
+EDTR.ID = AC.EDITOR AND
+CRTR.ID = AC.CREATOR AND
+BRE.ID=ACN.RECORD AND
+BRE.ID=icon_formats.id AND
+ACN.ID=AC.CALL_NUMBER AND
+ACL.ID=AC.LOCATION AND
+NOT ACN.DELETED AND
+NOT AC.DELETED AND
+BRE.ID>0 AND
+(
+ lower(acn.label) !~* $$movie$$ and
+ lower(acn.label) !~* $$vhs$$ and
+ lower(acn.label) !~* $$video$$
+)
+and
+(
+ lower(acl.name) !~* $$movie$$ and
+ lower(acl.name) !~* $$vhs$$ and
+ lower(acl.name) !~* $$video$$
+)
+and
+(
+ lower(ac.circ_modifier) !~* $$movie$$ and
+ lower(ac.circ_modifier) !~* $$vhs$$ and
+ lower(ac.circ_modifier) !~* $$video$$
+)
+AND
+icon_formats."FORMAT"~$$vhs$$
+order by 1;
+
+select * from (select id as system_id from actor.org_unit where parent_ou = 1) as systems
+join lateral ( select vhs_mis.*,aou.name from vhs_mis join actor.org_unit aou on aou.id = circ_lib where copy_id not in (select target_copy from tattler.ignore_list where org_unit = system_id and report_name = ?) and (select id from actor.org_unit_ancestor_at_depth(circ_lib, 1)) = system_id limit ?
+) as p on true
+order by system_id;
--- /dev/null
+DROP TABLE IF EXISTS audio_copies;
+CREATE TEMP TABLE audio_copies AS
+select bre.id as bib_id, ac.id as copy_id,bre.marc,string_agg(ac.barcode,$$,$$),crtr.id as creator_id, crtr.email as creator_email, edtr.id editor_id, edtr.email editor_email, ac.circ_lib from biblio.record_entry bre, asset.copy ac, asset.call_number acn, asset.copy_location acl, actor.usr crtr, actor.usr edtr where
+
+acl.id=ac.location and
+crtr.id = ac.creator and
+edtr.id = ac.editor and
+bre.id=acn.record and
+acn.id=ac.call_number and
+not acn.deleted and
+not ac.deleted and
+not bre.deleted and
+(
+ lower(acn.label) ~* $$cass$$ or
+ lower(acn.label) ~* $$aud$$ or
+ lower(acn.label) ~* $$disc$$ or
+ lower(acn.label) ~* $$mus$$ or
+ lower(acn.label) ~* $$ cd$$ or
+ lower(acn.label) ~* $$^cd$$ or
+ lower(acn.label) ~* $$disk$$
+or
+ lower(acl.name) ~* $$cas$$ or
+ lower(acl.name) ~* $$aud$$ or
+ lower(acl.name) ~* $$disc$$ or
+ lower(acl.name) ~* $$mus$$ or
+ lower(acl.name) ~* $$ cd$$ or
+ lower(acl.name) ~* $$^cd$$ or
+ lower(acl.name) ~* $$disk$$
+)
+and
+ac.circ_modifier in ( $$AudioBooks$$,$$CD$$ ) and
+(
+(
+
+(SELECT STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ AND ID=BRE.ID GROUP BY ID) !~ $$music$$ and
+(SELECT STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ AND ID=BRE.ID GROUP BY ID) !~ $$casaudiobook$$ and
+(SELECT STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ AND ID=BRE.ID GROUP BY ID) !~ $$casmusic$$ and
+(SELECT STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ AND ID=BRE.ID GROUP BY ID) !~ $$cassette$$ and
+(SELECT STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ AND ID=BRE.ID GROUP BY ID) !~ $$cd$$ and
+(SELECT STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ AND ID=BRE.ID GROUP BY ID) !~ $$cdaudiobook$$ and
+(SELECT STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ AND ID=BRE.ID GROUP BY ID) !~ $$cdmusic$$ and
+(SELECT STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ AND ID=BRE.ID GROUP BY ID) !~ $$playaway$$ and
+(SELECT STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ AND ID=BRE.ID GROUP BY ID) !~ $$kit$$
+)
+OR
+(SELECT STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ AND ID=BRE.ID GROUP BY ID) IS NULL
+)
+group by bre.id,ac.id,bre.marc,creator_id,editor_id, ac.circ_lib;
+
+select * from (select id as system_id from actor.org_unit where parent_ou = 1) as systems
+join lateral ( select audio_copies.*,aou.name from audio_copies join actor.org_unit aou on aou.id = circ_lib where (select id from actor.org_unit_ancestor_at_depth(circ_lib, 1)) = system_id and copy_id not in (select target_copy from tattler.ignore_list where org_unit = system_id and report_name = ?) limit ?) as p on true order by system_id;
--- /dev/null
+DROP TABLE IF EXISTS del_bibs;
+CREATE TEMP TABLE del_bibs AS
+select BRE.id as bib_id,AC.id as copy_id,ACN.LABEL,(SELECT STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ AND ID=BRE.ID GROUP BY ID),AOU.NAME, circ_lib, DELUSR.id as deletor_id, DELUSR.email as deletor_email
+from biblio.record_entry BRE, ASSET.COPY AC, ACTOR.ORG_UNIT AOU,ASSET.CALL_NUMBER ACN,ASSET.COPY_LOCATION ACL, ACTOR.USR DELUSR where
+AOU.ID=AC.CIRC_LIB AND
+BRE.ID=ACN.RECORD AND
+DELUSR.ID = BRE.EDITOR AND
+ACN.ID=AC.CALL_NUMBER AND
+ACL.ID=AC.LOCATION AND
+NOT BRE.DELETED AND
+BRE.EDITOR != 1 AND
+BRE.ID > 0 AND
+NOT AC.DELETED AND
+lower(BRE.marc) ~ $$<datafield tag="856" ind1="4" ind2="0">$$ AND
+BRE.id in
+(
+select record from asset.call_number where not deleted and id in(select call_number from asset.copy where not deleted)
+)
+and
+(
+ BRE.marc ~ $$tag="008">.......................[oqs]$$
+ or
+ BRE.marc ~ $$tag="006">......[oqs]$$
+)
+and
+(
+ BRE.marc ~ $$<leader>......[at]$$
+)
+and
+(
+ BRE.marc ~ $$<leader>.......[acdm]$$
+);
+
+select * from (select id as system_id from actor.org_unit where parent_ou = 1) as systems
+join lateral ( select * from del_bibs where copy_id not in (select target_copy from tattler.ignore_list where org_unit = system_id and report_name = ?) and (select id from actor.org_unit_ancestor_at_depth(circ_lib, 1)) = system_id limit ?
+) as p on true
+
+order by system_id;
--- /dev/null
+DROP TABLE IF EXISTS lp_bibs;
+CREATE TEMP TABLE lp_bibs AS
+select BRE.id as bib_id,AC.id as copy_id,ACN.LABEL,(SELECT STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ AND ID=BRE.ID GROUP BY ID),AOU.NAME as library_name, circ_lib, crtr.id as creator_id, crtr.email as creator_email
+
+from biblio.record_entry BRE, ASSET.COPY AC, ACTOR.ORG_UNIT AOU,ASSET.CALL_NUMBER ACN,ASSET.COPY_LOCATION ACL, ACTOR.USR CRTR where
+
+
+AOU.ID=AC.CIRC_LIB AND
+CRTR.ID = AC.CREATOR AND
+
+BRE.ID=ACN.RECORD AND
+
+ACN.ID=AC.CALL_NUMBER AND
+
+ACL.ID=AC.LOCATION AND
+
+NOT ACN.DELETED AND
+
+NOT AC.DELETED AND
+
+(
+
+ACN.ID IN(SELECT ID FROM ASSET.CALL_NUMBER WHERE (LOWER(LABEL)~$$ lp$$ OR LOWER(LABEL)~$$^lp$$ OR LOWER(LABEL)~$$large$$ OR LOWER(LABEL)~$$lg$$ OR LOWER(LABEL)~$$sight$$) )
+
+OR
+
+ACL.ID IN(SELECT ID FROM ASSET.COPY_LOCATION WHERE (LOWER(NAME)~$$ lp$$ OR LOWER(NAME)~$$^lp$$ OR LOWER(NAME)~$$large$$ OR LOWER(NAME)~$$lg$$ OR LOWER(NAME)~$$sight$$) )
+
+)
+
+AND
+
+BRE.ID IN
+
+(
+SELECT A.ID FROM
+ (
+
+SELECT STRING_AGG(VALUE,$$ $$) "FORMAT",ID from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ GROUP BY ID) AS A
+
+ WHERE A."FORMAT"!~$$lpbook$$
+UNION
+
+ SELECT ID FROM BIBLIO.RECORD_ENTRY WHERE ID NOT IN(SELECT ID from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$)
+
+) AND
+
+BRE.ID > 0
+order by ac.edit_date desc;
+
+
+select * from (select id as system_id from actor.org_unit where parent_ou = 1) as systems
+join lateral (select * from lp_bibs where copy_id not in (select target_copy from tattler.ignore_list where org_unit = system_id and report_name = ?) and (select id from actor.org_unit_ancestor_at_depth(circ_lib, 1)) = system_id limit ?
+) p on true
+
+order by system_id;
\ No newline at end of file
--- /dev/null
+DROP TABLE IF EXISTS non_audio_copies;
+CREATE TEMP TABLE non_audio_copies AS
+select bre.id as bib_id,ac.id as copy_id,bre.marc,string_agg(ac.barcode,$$,$$), crtr.id as creator_id, crtr.email as creator_email, edtr.id editor_id, edtr.email editor_email, ac.circ_lib from biblio.record_entry bre, asset.copy ac, asset.call_number acn, asset.copy_location acl, actor.usr crtr, actor.usr edtr where
+bre.marc ~ $$<leader>......i$$ and
+acl.id=ac.location and
+crtr.id = ac.creator and
+edtr.id = ac.editor and
+bre.id=acn.record and
+acn.id=ac.call_number and
+not acn.deleted and
+not ac.deleted and
+not bre.deleted and
+BRE.ID>0 AND
+(
+ lower(acn.label) !~* $$cass$$ and
+ lower(acn.label) !~* $$aud$$ and
+ lower(acn.label) !~* $$disc$$ and
+ lower(acn.label) !~* $$mus$$ and
+ lower(acn.label) !~* $$ cd$$ and
+ lower(acn.label) !~* $$^cd$$ and
+ lower(acn.label) !~* $$disk$$
+)
+and
+(
+ lower(acl.name) !~* $$cas$$ and
+ lower(acl.name) !~* $$aud$$ and
+ lower(acl.name) !~* $$disc$$ and
+ lower(acl.name) !~* $$mus$$ and
+ lower(acl.name) !~* $$ cd$$ and
+ lower(acl.name) !~* $$^cd$$ and
+ lower(acl.name) !~* $$disk$$
+)
+and
+ac.circ_modifier not in ( $$AudioBooks$$,$$CD$$ )
+group by bre.id,ac.id,bre.marc,crtr.id,edtr.id,ac.circ_lib;
+
+select * from (select id as system_id from actor.org_unit where parent_ou = 1) as systems
+join lateral ( select non_audio_copies.*,aou.name from non_audio_copies join actor.org_unit aou on aou.id = circ_lib where copy_id not in (select target_copy from tattler.ignore_list where org_unit = system_id and report_name = ?) and (select id from actor.org_unit_ancestor_at_depth(circ_lib, 1)) = system_id limit ?) as p on true
+order by system_id;
--- /dev/null
+DROP TABLE IF EXISTS lp_bibs;
+CREATE TEMP TABLE lp_bibs AS
+select BRE.id as bib_id,AC.id as copy_id,ACN.LABEL,(SELECT STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ AND ID=BRE.ID GROUP BY ID), AC.circ_lib,AOU.NAME,crtr.id, crtr.email
+
+from biblio.record_entry BRE, ASSET.COPY AC, ACTOR.ORG_UNIT AOU,ASSET.CALL_NUMBER ACN,ASSET.COPY_LOCATION ACL, ACTOR.USR CRTR where
+
+AOU.ID=AC.CIRC_LIB AND
+CRTR.ID = AC.CREATOR AND
+BRE.ID=ACN.RECORD AND
+ACN.ID=AC.CALL_NUMBER AND
+ACL.ID=AC.LOCATION AND
+NOT ACN.DELETED AND
+
+
+
+
+
+NOT AC.DELETED AND
+
+(
+ACN.ID IN(SELECT ID FROM ASSET.CALL_NUMBER WHERE (LOWER(LABEL)!~$$ lp$$ AND LOWER(LABEL)!~$$^lp$$ AND LOWER(LABEL)!~$$large$$ AND LOWER(LABEL)!~$$lg$$ AND LOWER(LABEL)!~$$sight$$ AND LOWER(LABEL)!~$$s\.s\.$$) )AND
+
+ACL.ID IN(SELECT ID FROM ASSET.COPY_LOCATION WHERE (LOWER(NAME)!~$$ lp$$ AND LOWER(NAME)!~$$^lp$$ AND LOWER(NAME)!~$$large$$ AND LOWER(NAME)!~$$lg$$ AND LOWER(NAME)!~$$sight$$ AND LOWER(NAME)!~$$s\.s\.$$) )
+)
+AND
+BRE.ID IN
+(
+ SELECT A.ID FROM
+ (
+ SELECT STRING_AGG(VALUE,$$ $$) "FORMAT",ID from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ GROUP BY ID
+ ) AS A
+ WHERE A."FORMAT"~$$lpbook$$
+) AND
+BRE.ID > 0
+order by ac.edit_date desc;
+
+select * from (select id as system_id from actor.org_unit where parent_ou = 1) as systems
+join lateral (
+select * from lp_bibs
+where copy_id not in (select target_copy from tattler.ignore_list where org_unit = system_id and report_name = ?) and (select id from actor.org_unit_ancestor_at_depth(circ_lib, 1)) = system_id
+limit ?
+) p on true
+order by system_id;
--- /dev/null
+DROP TABLE IF EXISTS mus_mis;
+CREATE TEMP TABLE mus_mis AS
+select BRE.id as bib_id,AC.id as copy_id,ACN.LABEL,(SELECT STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ AND ID=BRE.ID GROUP BY ID),AC.CIRC_LIB,AOU.NAME
+from biblio.record_entry BRE, ASSET.COPY AC, ACTOR.ORG_UNIT AOU,ASSET.CALL_NUMBER ACN,ASSET.COPY_LOCATION ACL where
+AOU.ID=AC.CIRC_LIB AND
+BRE.ID=ACN.RECORD AND
+ACN.ID=AC.CALL_NUMBER AND
+ACL.ID=AC.LOCATION AND
+NOT ACN.DELETED AND
+NOT AC.DELETED AND
+BRE.ID>0 AND
+(
+ACN.ID IN(SELECT ID FROM ASSET.CALL_NUMBER WHERE (LOWER(LABEL)~$$music$$ OR LOWER(LABEL)~$$^folk$$ OR LOWER(LABEL)~$$ folk$$ OR LOWER(LABEL)~$$classical$$) AND LOWER(LABEL)!~$$folktale$$ )
+OR
+ACL.ID IN(SELECT ID FROM ASSET.COPY_LOCATION WHERE (LOWER(NAME)~$$music$$) )
+OR
+lower(ac.circ_modifier) ~* $$music$$
+)
+AND
+BRE.ID IN
+(
+ SELECT A.ID FROM
+ (
+ SELECT STRING_AGG(VALUE,$$ $$) "FORMAT",ID from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ GROUP BY ID
+ ) AS A
+ WHERE A."FORMAT"!~$$music$$
+ UNION
+ SELECT ID FROM BIBLIO.RECORD_ENTRY WHERE ID NOT IN(SELECT ID from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$)
+)
+UNION
+select BRE.id as bib_id,AC.id as copy_id,ACN.LABEL,(SELECT STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ AND ID=BRE.ID GROUP BY ID),AC.CIRC_LIB,AOU.NAME
+from biblio.record_entry BRE, ASSET.COPY AC, ACTOR.ORG_UNIT AOU,ASSET.CALL_NUMBER ACN,ASSET.COPY_LOCATION ACL where
+AOU.ID=AC.CIRC_LIB AND
+BRE.ID=ACN.RECORD AND
+ACN.ID=AC.CALL_NUMBER AND
+ACL.ID=AC.LOCATION AND
+NOT ACN.DELETED AND
+NOT AC.DELETED AND
+BRE.ID>0 AND
+(
+ lower(acn.label) !~* $$music$$ and
+ lower(acn.label) !~* $$ folk$$ and
+ lower(acn.label) !~* $$^folk$$ and
+ lower(acn.label) !~* $$readalong$$ and
+ lower(acn.label) !~* $$singalong$$ and
+ lower(acn.label) !~* $$classical$$
+
+)
+and
+(
+ lower(acl.name) !~* $$music$$ and
+ lower(acl.name) !~* $$singalong$$ and
+ lower(acl.name) !~* $$readalong$$
+)
+and
+(
+ lower(ac.circ_modifier) !~* $$music$$ and
+ lower(ac.circ_modifier) !~* $$cd$$
+)
+AND
+BRE.ID IN
+(
+ SELECT A.ID FROM
+ (
+ SELECT STRING_AGG(VALUE,$$ $$) "FORMAT",ID from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ GROUP BY ID
+ ) AS A
+ WHERE A."FORMAT"~$$music$$
+)
+order by 1;
+select * from (select id as system_id from actor.org_unit where parent_ou = 1) as systems
+join lateral (select * from mus_mis where copy_id not in (select target_copy from tattler.ignore_list where org_unit = system_id and report_name = ?) and (select id from actor.org_unit_ancestor_at_depth(circ_lib, 1)) = system_id limit ?
+) p on true
+
+order by system_id;
\ No newline at end of file
--- /dev/null
+DROP TABLE IF EXISTS vid_mis;
+CREATE TEMP TABLE vid_mis AS
+select BRE.id as bib_id,AC.id as copy_id,ACN.LABEL,(SELECT STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ AND ID=BRE.ID GROUP BY ID),crtr.id as creator_id, crtr.email as creator_email, edtr.id editor_id, edtr.email editor_email,AOU.NAME, ac.circ_lib
+from biblio.record_entry BRE, ASSET.COPY AC, ACTOR.ORG_UNIT AOU,ASSET.CALL_NUMBER ACN,ASSET.COPY_LOCATION ACL, ACTOR.USR EDTR,ACTOR.USR CRTR where
+AOU.ID=AC.CIRC_LIB AND
+EDTR.ID = AC.EDITOR AND
+CRTR.ID = AC.CREATOR AND
+BRE.ID=ACN.RECORD AND
+ACN.ID=AC.CALL_NUMBER AND
+ACL.ID=AC.LOCATION AND
+NOT ACN.DELETED AND
+NOT AC.DELETED AND
+BRE.ID>0 AND
+(
+ACN.ID IN(SELECT ID FROM ASSET.CALL_NUMBER WHERE (LOWER(LABEL)~$$ dvd$$ OR LOWER(LABEL)~$$^dvd$$ OR LOWER(LABEL)~$$vhs$$ OR LOWER(LABEL)~$$video$$ OR LOWER(LABEL)~$$movie$$) )
+OR
+ACL.ID IN(SELECT ID FROM ASSET.COPY_LOCATION WHERE (LOWER(NAME)~$$ dvd$$ OR LOWER(NAME)~$$^dvd$$ OR LOWER(NAME)~$$vhs$$ OR LOWER(NAME)~$$video$$ OR LOWER(NAME)~$$movie$$) )
+OR
+lower(ac.circ_modifier) ~* $$ dvd$$ OR
+lower(ac.circ_modifier) ~* $$^dvd$$ OR
+lower(ac.circ_modifier) ~* $$movie$$ OR
+lower(ac.circ_modifier) ~* $$vhs$$ OR
+lower(ac.circ_modifier) ~* $$video$$
+)
+AND
+BRE.ID IN
+(
+ SELECT A.ID FROM
+ (
+ SELECT STRING_AGG(VALUE,$$ $$) "FORMAT",ID from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ GROUP BY ID
+ ) AS A
+ WHERE A."FORMAT"!~$$dvd$$ AND A."FORMAT"!~$$vhs$$ AND A."FORMAT"!~$$blu$$
+ UNION
+ SELECT ID FROM BIBLIO.RECORD_ENTRY WHERE ID NOT IN(SELECT ID from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$)
+)
+UNION
+select BRE.id as bib_id,AC.id as copy_id,ACN.LABEL,(SELECT STRING_AGG(VALUE,$$ $$) "FORMAT" from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ AND ID=BRE.ID GROUP BY ID),crtr.id as creator_id, crtr.email as creator_email, edtr.id editor_id, edtr.email editor_email,AOU.NAME, circ_lib
+from biblio.record_entry BRE, ASSET.COPY AC, ACTOR.ORG_UNIT AOU,ASSET.CALL_NUMBER ACN,ASSET.COPY_LOCATION ACL, ACTOR.USR EDTR,ACTOR.USR CRTR where
+AOU.ID=AC.CIRC_LIB AND
+EDTR.ID = AC.EDITOR AND
+CRTR.ID = AC.CREATOR AND
+BRE.ID=ACN.RECORD AND
+ACN.ID=AC.CALL_NUMBER AND
+ACL.ID=AC.LOCATION AND
+NOT ACN.DELETED AND
+NOT AC.DELETED AND
+BRE.ID>0 AND
+(
+ lower(acn.label) !~* $$ dvd$$ and
+ lower(acn.label) !~* $$^dvd$$ and
+ lower(acn.label) !~* $$movie$$ and
+ lower(acn.label) !~* $$vhs$$ and
+ lower(acn.label) !~* $$video$$
+)
+and
+(
+ lower(acl.name) !~* $$ dvd$$ and
+ lower(acl.name) !~* $$^dvd$$ and
+ lower(acl.name) !~* $$movie$$ and
+ lower(acl.name) !~* $$vhs$$ and
+ lower(acl.name) !~* $$video$$
+)
+and
+(
+ lower(ac.circ_modifier) !~* $$ dvd$$ and
+ lower(ac.circ_modifier) !~* $$^dvd$$ and
+ lower(ac.circ_modifier) !~* $$movie$$ and
+ lower(ac.circ_modifier) !~* $$vhs$$ and
+ lower(ac.circ_modifier) !~* $$video$$
+)
+AND
+BRE.ID IN
+(
+ SELECT A.ID FROM
+ (
+ SELECT STRING_AGG(VALUE,$$ $$) "FORMAT",ID from METABIB.RECORD_ATTR_FLAT WHERE ATTR=$$icon_format$$ GROUP BY ID
+ ) AS A
+ WHERE A."FORMAT"~$$dvd$$ or A."FORMAT"~$$blu$$ or A."FORMAT"~$$vhs$$
+)
+order by 1;
+select * from (select id as system_id from actor.org_unit where parent_ou = 1) as systems
+join lateral ( select vid_mis.* from vid_mis where copy_id not in (select target_copy from tattler.ignore_list where org_unit = system_id and report_name = ?) and (select id from actor.org_unit_ancestor_at_depth(circ_lib, 1)) = system_id limit ?
+) as p on true
+
+order by system_id;
--- /dev/null
+use strict;
+use warnings;
+use DBI;
+use File::Spec;
+use File::Basename;
+use File::Path qw(remove_tree rmtree);
+use OpenSRF::System;
+
+#ssh host
+my $total_time_start = time();
+my $config = '@sysconfdir@/opensrf_core.xml';
+OpenSRF::System->bootstrap_client( config_file => $config );
+
+my (%data_db, %state_db);
+
+my $sc = OpenSRF::Utils::SettingsClient->new;
+
+my $driver = $sc->config_value( reporter => setup => database => 'driver' );
+my $host = $sc->config_value( reporter => setup => database => 'host' );
+my $port = $sc->config_value( reporter => setup => database => 'port' );
+my $db = $sc->config_value( reporter => setup => database => 'db' );
+if (!$db) {
+ $db = $sc->config_value( reporter => setup => database => 'name' );
+ print STDERR "WARN: <database><name> is a deprecated setting for database name. For future compatibility, you should use <database><db> instead." if $db;
+}
+my $usr = $sc->config_value( reporter => setup => database => 'user' );
+my $pwrd = $sc->config_value( reporter => setup => database => 'pw' );
+
+
+my $dsn = "dbi:$driver:dbname='$db';host='$host';port='$port';";
+
+# folders to output web content
+my $output_folder = "../var/web/tattler-output/";
+# script will run every report in this folder
+my $sqldir = "./tattle-tale-scripts";
+# how many rows to return per report
+my $limit = 15;
+my $copy_url = "/eg/staff/cat/item/";
+my $bib_url = "/eg/staff/cat/catalog/record/";
+my $patron_url = "/eg/staff/circ/patron/";
+my $tattler_url = "/eg/opac/tattler";
+my $dbh =DBI->connect($dsn, $usr, $pwrd, {AutoCommit => 0}) or die ( "Couldn't connect to database: " . DBI->errstr );
+
+# get org unit names and shortnames
+my $org_st = $dbh->prepare("select * from actor.org_unit");
+my %org_name;
+my %org_shortname;
+print("Retrieving org unit data\n");
+$org_st->execute();
+for((0..$org_st->rows-1)){
+ my $sql_hash_ref = $org_st->fetchrow_hashref;
+ $org_name{$sql_hash_ref->{'id'}} = $sql_hash_ref->{'name'};
+ $org_shortname{$sql_hash_ref->{'id'}} = $sql_hash_ref->{'shortname'};
+ # remove directory if it exists so we will have fresh results
+ my $sys_dir = "$output_folder/$sql_hash_ref->{'shortname'}";
+ if(-d $sys_dir){
+ print("removing $sys_dir\n");
+ rmtree($sys_dir);
+ }
+}
+$org_st->finish();
+
+my @files = glob $sqldir."/*.sql";
+# iterate over all SQl scripts in the sql directory
+foreach my $sql_file (@files) {
+ my ($report_title,$dir,$ext) = fileparse($sql_file,'\..*');
+ my $nice_report_title = "$report_title";
+ # report title is the file name with the extension removed and dashes turned to spaces
+ $nice_report_title =~ s/-/ /g;;
+
+ print "running " . $report_title . "\n";
+ open my $fh, '<', $sql_file or die "Can't open file $!";
+ my $statement_body = do { local $/; <$fh> };
+
+ # prepare statement
+ my $sth = $dbh->prepare($statement_body);
+ my $start_time = time();
+ # the first bind variable is the name of the report, it is used with the ignore table
+ # the second bind variable is the number of rows to return per system
+ $sth->execute($report_title,$limit);
+ my $header_ref = $sth->{NAME_lc};
+ my @headers = @$header_ref;
+ my $data_ref = $sth->fetchall_arrayref();
+ my @data = @$data_ref;
+ my ($sys_id_index) = grep { $headers[$_] eq 'system_id' } (0 .. (scalar @headers)-1);
+ my ($bib_id_index) = grep { $headers[$_] eq 'bib_id' } (0 .. (scalar @headers)-1);
+ my ($copy_id_index) = grep { $headers[$_] eq 'copy_id' } (0 .. (scalar @headers)-1);
+ my ($circ_lib_index) = grep { $headers[$_] eq 'circ_lib' } (0 .. (scalar @headers)-1);
+
+ $sth->finish;
+ my $current_system = 0;
+ my $current_count = 1;
+ my $current_file;
+ my $l = $#data + 1;
+ my $complete_time = (time() - $start_time)/60.0;
+ print("retrieved $l rows in $complete_time minutes\n");
+ # for each row returned
+ for(my $i = 0; $i < $l; $i++){
+ my $sql_row_ref = $data[$i];
+ my @sql_row = @$sql_row_ref;
+
+ # set up file if this is new system
+ if($sql_row[$sys_id_index] != $current_system){
+ # set new current system
+ $current_system = $sql_row[$sys_id_index];
+ $current_count = 1;
+
+ # end previous file
+ if(defined $current_file){
+ print $current_file "</tbody></tr></table>";
+ print $current_file "</form>";
+ print $current_file "</html>";
+ close $current_file;
+ }
+ my $sys_dir = "$output_folder/$org_shortname{$current_system}";
+ mkdir $sys_dir unless -d $sys_dir;
+ my $file = $sys_dir."/".$report_title.".html";
+
+ # create the file.
+ unless(open $current_file, '>'.$file) {
+ die "\nUnable to create $file\n";
+ }
+
+ # init file
+ # set up style for file
+ # TODO: Move style stuff into a static CSS file
+ print $current_file "<html><style>
+ input[type=\"submit\"]{display: inline-block;margin-bottom: 20px;font-weight: 400;text-align: center;white-space: nowrap;vertical-align: middle;-ms-touch-action: manipulation;touch-action: manipulation;cursor: pointer;background-image: none;border: 1px solid transparent;padding: 6px 12px;font-size: 14px;line-height: 1.42857143;border-radius: 4px; user-select: none;color: #333; background-color: #fff;border-color: #ccc; } body{font-family: arial;} .tt-table{border-collapse:collapse;} .tt-table td{padding-left: 15px; padding-top: 5px; padding-bottom: 5px; padding-right: 15px;} .tt-table thead tr{color: rgb(100, 100, 100); background-color:rgb(225, 225, 225);border-bottom-style: solid; border-bottom-width: 1.5px; border-bottom-color:rgb(200, 200, 200); border-collapse: collapse; font-weight: bold;} .tt-table tbody td:nth-child(1){color: rgb(100, 100, 100); background-color:rgb(225, 225, 225);border-right-style: solid; border-right-width: 1.5px; border-right-color:rgb(200, 200, 200); border-collapse: collapse; font-weight: bold;border-bottom-color:rgb(128, 200, 200) !important;} .tt-table tbody tr { border-bottom-style: solid; border-bottom-width: 1px; border-bottom-color:rgb(221, 221, 221); border-collapse: collapse;} .tt-table tbody tr:nth-child(odd){background-color:rgb(245, 245, 245);}</style>";
+ print $current_file "<h1>$org_name{$current_system}</h1>";
+ print $current_file "<h2>$nice_report_title</h2>";
+ print $current_file "<a href=\"index.html\">Return to index</a>";
+ print $current_file "<hr/>";
+ # create form for user created ignore list
+ print $current_file "<form action=\"$tattler_url\" method=\"POST\" id=\"ignoreForm\">";
+ print $current_file "<p>Check the boxes within the table to ignore to a copy. That copy will not appear on the next report that is generated.</p>";
+ print $current_file "<input type=\"hidden\" id=\"reportName\" name=\"reportName\" value=\"$report_title\">";
+ print $current_file "<input type=\"hidden\" id=\"systemID\" name=\"systemID\" value=\"$current_system\">";
+ print $current_file "<input type=\"submit\">";
+ print $current_file "<table class=\"tt-table\">";
+ print $current_file "<thead><tr>";
+ print $current_file "<td>#</td>";
+ print $current_file "<td>Ignore</td>";
+ # init headers from data in table
+ for (@headers){
+ print $current_file "<td>$_</td>";
+ }
+ print $current_file "</tr></thead>";
+ print $current_file "<tbody>";
+ }
+ # send staff to the right subdomain for their system, assumed to be their system's shortname
+ my $subdomain ="https://";
+ $subdomain .= $org_shortname{$current_system}.".";
+ my $copy_id = $sql_row[$copy_id_index];
+ print $current_file "<tr>";
+ print $current_file "<td>$current_count</td>";
+ # check box marks this copy to be ignored next time
+ print $current_file "<td><input type=\"checkbox\" name=\"copyID[]\" value=\"$copy_id\"></td>";
+ while (my ($index, $elem) = each @sql_row) {
+ # set up links to Evergreen based on header name
+ if(defined($elem)){
+ if ($headers[$index] =~ m/email/ ) {
+ print $current_file "<td><a href=\"mailto:$elem\">$elem</a></td>";
+ }
+ elsif ($headers[$index] =~ m/bib_id/ ) {
+ print $current_file "<td><a href=\"$subdomain$bib_url$elem\">$elem</a></td>";
+ }
+ elsif ($headers[$index] =~ m/copy_id/ ) {
+ print $current_file "<td><a href=\"$subdomain$copy_url$elem\">$elem</a></td>";
+ }
+ elsif ($headers[$index] =~ m/creator_id/ ) {
+ print $current_file "<td><a href=\"$subdomain$patron_url$elem/checkout\">$elem</a></td>";
+ }
+ elsif ($headers[$index] =~ m/editor_id/ ) {
+ print $current_file "<td><a href=\"$subdomain$patron_url$elem/checkout\">$elem</a></td>";
+ }
+ elsif ($headers[$index] =~ m/deletor_id/ ) {
+ print $current_file "<td><a href=\"$subdomain$patron_url$elem/checkout\">$elem</a></td>";
+ }
+ else{
+ print $current_file "<td>$elem</td>";
+ }
+ }
+ else{
+ print $current_file "<td></td>";
+ }
+ }
+ print $current_file "</tr>";
+
+ $current_count += 1;
+ }
+ # end last file
+ if(defined $current_file){
+ print $current_file "</tbody></tr></table>";
+ print $current_file "</form>";
+ print $current_file "</html>";
+ close $current_file;
+ }
+}
+# close connection to database
+$dbh->disconnect;
+# begin root index
+my $index_data = "<html><style> body{font-family: arial;}</style><body><ul>";
+# build index for all webpages output
+foreach my $current_system (keys %org_shortname){
+ my $current_folder = "$output_folder/$org_shortname{$current_system}";
+ if(-d $current_folder){
+ # add this system to the root index
+ $index_data .= "<li><a href=\"$org_shortname{$current_system}\">$org_shortname{$current_system}</a></li>";
+ my @report_files;
+ opendir(DIR, $current_folder) or die $!;
+
+ while (my $file = readdir(DIR))
+ {
+ next unless (-f "$current_folder/$file");
+ # Use a regular expression to find files ending in .html
+ next if (lc$file =~ m/index/);
+ next unless (lc$file =~ m/\.html$/);
+ push(@report_files,$file);
+ }
+ closedir(DIR);
+
+ my $index_file;
+ my $index_file_name = $current_folder."/index.html";
+ unless(open $index_file, '>'.$index_file_name) {
+ die "\nUnable to create $index_file_name\n";
+ }
+ print $index_file "<html>";
+ print $index_file "<style> body{font-family: arial;}</style>";
+ print $index_file "<h1>$org_name{$current_system}</h1>";
+ print $index_file "<a href=\"../index.html\">Return to index</a>";
+ print $index_file "<hr/>\n";
+ print $index_file "<ul>\n";
+ foreach(@report_files)
+ {
+ my $file = $_;
+ my @s1 = split(/\./,$file);
+ my @s2 = split(/-/,$s1[0]);
+ my $nice_report_title = join(" ",@s2);
+
+ print $index_file "<li><a href=\"$file\">$nice_report_title</a></li>\n";
+ }
+
+ print $index_file "</ul>\n";
+ print $index_file "</html>";
+ close $index_file;
+ }
+}
+$index_data .= "</ul></body></html>";
+# create root index file
+my $index_file;
+my $index_file_name = $output_folder."/index.html";
+unless(open $index_file, '>'.$index_file_name) {
+ die "\nUnable to create $index_file_name\n";
+ }
+print $index_file $index_data;
+close $index_file;
+my $complete_time = (time() - $total_time_start)/60.0;
+print("script finished in $complete_time minutes\n");
+