8978099ddc82401b9b28e6024e546ca9156fb07f
[migration-tools.git] / mig-xml / evergreen_staged_report.xml
1 <reports_file>
2     <function>
3         <name>find_cmm</name>
4         <drop>DROP FUNCTION IF EXISTS find_cmm(BIGINT)</drop>
5         <create>
6             CREATE OR REPLACE FUNCTION find_cmm(circ_id BIGINT)
7                 RETURNS SETOF INTEGER[]
8                 LANGUAGE plpgsql
9             AS $function$
10             DECLARE
11                  aou     INTEGER;
12                  ac      INTEGER;
13                  au      INTEGER;
14                  r       INTEGER[];
15             BEGIN
16                 SELECT circ_lib FROM action.circulation WHERE id = circ_id INTO aou;
17                 SELECT target_copy FROM action.circulation WHERE id = circ_id INTO ac;
18                 SELECT usr FROM action.circulation WHERE id = circ_id INTO au;
19
20                 FOR r IN SELECT buildrows FROM action.find_circ_matrix_matchpoint(aou,ac,au,FALSE)
21                     LOOP
22                         RETURN NEXT r;
23                     END LOOP;
24                 RETURN;
25             END
26         $function$</create>
27     </function>
28
29     <table>
30         <name>create_subfield_u</name>
31         <drop>DROP TABLE IF EXISTS subfield_u</drop>
32         <create>CREATE UNLOGGED TABLE subfield_u AS SELECT UNNEST(oils_xpath( '//*[@tag="856"]/*[@code="u"]/text()', marc)) AS value FROM m_biblio_record_entry_legacy WHERE x_migrate</create>
33     </table>
34
35 <!-- sample reports entry
36     <report>
37         <name>name of report</name>
38         <iteration value='0' /> which version, the first version to run is 0, first backup is 1, then so on
39         <tag>money</tag>  arbitrary tags, each should go in separate tag
40         <report_title>Migrated Billings</report_title>  title used in the asciidoc output
41         <heading column='1'>Number of Billings.Migrated.Total</heading> period delimited 
42         <query>SELECT COUNT(id),x_migrate::TEXT,SUM(amount) FROM m_money_billing_legacy GROUP BY 2;</query>  query itself, will be replaced
43         <note>Arbitrary note that can be included in the entries.</note>
44     </report>
45 -->
46
47     <!-- CIRC REPORTS -->
48     <report>
49         <name>circ_count</name>
50         <tag>circs</tag>
51         <iteration>0</iteration>
52         <report_title>Migrated Circulations</report_title>
53         <heading>Circulation Status.Count of Circs</heading>
54         <query>SELECT 'Closed Circulations', COUNT(id) FROM m_action_circulation_legacy WHERE xact_finish IS NOT NULL AND x_migrate 
55             UNION ALL SELECT 'Open Circulations', COUNT(id) FROM m_action_circulation_legacy WHERE xact_finish IS NULL AND x_migrate</query>
56     </report>
57
58     <report>
59         <name>circ_count</name>
60         <tag>circs</tag>
61         <iteration>1</iteration>
62         <report_title>Open Circulations</report_title>
63         <heading>Circulation Status.Count of Circs</heading>
64         <query>SELECT 'Closed Circulations', COUNT(id) FROM m_action_circulation WHERE xact_finish IS NOT NULL UNION ALL SELECT 'Open Circulations', COUNT(id) FROM m_action_circulation WHERE xact_finish IS NULL</query>
65     </report>
66
67      <report>
68         <name>circ_by_orgunit</name>
69         <tag>circs</tag>
70         <iteration>0</iteration>
71         <report_title>Circulations by Org Unit</report_title>
72         <heading>Circulations Count.Org Unit</heading>
73         <query>SELECT COUNT(acirc.id), aou.name FROM m_action_circulation_legacy acirc JOIN actor.org_unit aou ON aou.id = acirc.circ_lib WHERE acirc.xact_finish IS NULL AND x_migrate = TRUE GROUP BY 2</query>
74     </report>
75
76      <report>
77         <name>circ_by_orgunit</name>
78         <tag>circs</tag>
79         <iteration>1</iteration>
80         <report_title>Circulations by Org Unit</report_title>
81         <heading>Circulations Count.Org Unit</heading>
82         <query>SELECT COUNT(acirc.id), aou.name FROM m_action_circulation acirc JOIN actor.org_unit aou ON aou.id = acirc.circ_lib WHERE acirc.xact_finish IS NULL GROUP BY 2</query>
83     </report>
84
85      <report>
86         <name>circs_by_duration</name>
87         <tag>circs</tag>
88         <iteration>0</iteration>
89         <report_title>Migrated Circulations by Duration, Fine and Max Fine</report_title>
90         <heading>Count of Circs.Duration.Fine.Max Fine</heading>
91         <query>SELECT COUNT(id), duration_rule, recurring_fine_rule, max_fine_rule FROM m_action_circulation_legacy WHERE x_migrate = TRUE GROUP BY 2, 3, 4</query>
92     </report>
93
94      <report>
95         <name>circs_by_duration</name>
96         <tag>circs</tag>
97         <iteration>1</iteration>
98         <report_title>Circulations by Duration, Fine and Max Fine</report_title>
99         <heading>Count of Circs.Duration.Fine.Max Fine</heading>
100         <query>SELECT COUNT(id), duration_rule, recurring_fine_rule, max_fine_rule FROM m_action_circulation GROUP BY 2, 3, 4 ORDER BY 2, 3, 4</query>
101     </report>
102
103      <report>
104         <name>circs_by_usrgroup</name>
105         <tag>circs</tag>
106         <iteration>0</iteration>
107         <report_title>Circulations by Rules and Patron Group</report_title>
108         <heading>Count of Circs.Duration.Fine.Max Fine.User Group.Matchpoints</heading>
109         <query>SELECT COUNT(acirc.id), acirc.duration_rule, acirc.recurring_fine_rule, acirc.max_fine_rule, pgt.name, x.buildrows FROM m_action_circulation_legacy acirc JOIN actor.usr au ON au.id = acirc.usr JOIN permission.grp_tree pgt ON pgt.id = au.profile JOIN (SELECT acirc.id, ARRAY_TO_STRING(find_cmm(acirc.id),',') AS buildrows FROM m_action_circulation_legacy acirc WHERE acirc.x_migrate = TRUE) x ON x.id = acirc.id WHERE acirc.x_migrate = TRUE GROUP BY 2, 3, 4, 5, 6 ORDER BY 2, 3, 4, 5, 6</query>
110     </report>
111
112      <report>
113         <name>circs_by_usrgroup</name>
114         <tag>circs</tag>
115         <iteration>1</iteration>
116         <report_title>Circulations by Rules and Patron Group</report_title>
117         <heading>Count of Circs.Duration.Fine.Max Fine.User Group.Matchpoints</heading>
118         <query>SELECT COUNT(acirc.id), acirc.duration_rule, acirc.recurring_fine_rule, acirc.max_fine_rule, pgt.name, x.buildrows FROM m_action_circulation acirc JOIN actor.usr au ON au.id = acirc.usr JOIN permission.grp_tree pgt ON pgt.id = au.profile JOIN (SELECT acirc.id, ARRAY_TO_STRING(find_cmm(acirc.id),',') AS buildrows FROM m_action_circulation acirc) x ON x.id = acirc.id GROUP BY 2, 3, 4, 5, 6 ORDER BY 2, 3, 4, 5, 6</query>
119     </report>
120
121      <report>
122         <name>circs_by_circmod</name>
123         <tag>circs</tag>
124         <iteration>0</iteration>
125         <report_title>Circulations by Rules and Circulation Modifier</report_title>
126         <heading>Count of Circs.Duration.Fine.Max Fine.Circulation Modifier.Matchpoints</heading>
127         <query>SELECT COUNT(acirc.id), acirc.duration_rule, acirc.recurring_fine_rule, acirc.max_fine_rule, ac.circ_modifier, x.buildrows FROM m_action_circulation_legacy acirc JOIN asset.copy ac ON ac.id = acirc.target_copy JOIN (SELECT acirc.id, ARRAY_TO_STRING(find_cmm(acirc.id),',') AS buildrows FROM m_action_circulation_legacy acirc WHERE acirc.x_migrate = TRUE) x ON x.id = acirc.id WHERE acirc.x_migrate = TRUE GROUP BY 2, 3, 4, 5, 6 ORDER BY 2, 3, 4, 5, 6</query>
128     </report>
129
130      <report>
131         <name>circs_by_circmod</name>
132         <tag>circs</tag>
133         <iteration>1</iteration>
134         <report_title>Circulations by Rules and Circulation Modifier</report_title>
135         <heading>Count of Circs.Duration.Fine.Max Fine.Circulation Modifier.Matchpoints</heading>
136         <query>SELECT COUNT(acirc.id), acirc.duration_rule, acirc.recurring_fine_rule, acirc.max_fine_rule, ac.circ_modifier, x.buildrows FROM m_action_circulation acirc JOIN asset.copy ac ON ac.id = acirc.target_copy JOIN (SELECT acirc.id, ARRAY_TO_STRING(find_cmm(acirc.id),',') AS buildrows FROM m_action_circulation acirc) x ON x.id = acirc.id
137              GROUP BY 2, 3, 4, 5, 6 ORDER BY 2, 3, 4, 5, 6</query>
138     </report>
139
140      <report>
141         <name>circs_by_orgunit</name>
142         <tag>circs</tag>
143         <iteration>0</iteration>
144         <report_title>Circulations by Rules and Org Unit</report_title>
145         <heading>Count of Circs.Duration.Fine.Max Fine.Library Branch</heading>
146         <query>SELECT COUNT(acirc.id), acirc.duration_rule, acirc.recurring_fine_rule, acirc.max_fine_rule, aou.name FROM m_action_circulation_legacy acirc JOIN actor.org_unit aou ON aou.id = acirc.circ_lib WHERE acirc.x_migrate = TRUE GROUP BY 2, 3, 4, 5 ORDER BY 2, 3, 4, 5</query>
147     </report>
148
149      <report>
150         <name>circs_by_orgunit</name>
151         <tag>circs</tag>
152         <iteration>1</iteration>
153         <report_title>Circulations by Rules and Org Unit</report_title>
154         <heading>Count of Circs.Duration.Fine.Max Fine.Library Branch</heading>
155         <query>SELECT COUNT(acirc.id), acirc.duration_rule, acirc.recurring_fine_rule, acirc.max_fine_rule, aou.name FROM m_action_circulation acirc JOIN actor.org_unit aou ON aou.id = acirc.circ_lib GROUP BY 2, 3, 4, 5 ORDER BY 2, 3, 4, 5</query>
156     </report>
157
158      <report>
159         <name>non_cat_circs</name>
160         <tag>circs</tag>
161         <iteration>0</iteration>
162         <report_title>Non-Cataloged Circulation</report_title>
163         <heading>Circulations Count.Migrated</heading>
164         <query>SELECT COUNT(id), x_migrate::TEXT FROM m_action_non_cataloged_circulation_legacy GROUP BY 2</query>
165     </report>
166
167      <report>
168         <name>non_cat_circs</name>
169         <tag>circs</tag>
170         <iteration>1</iteration>
171         <report_title>Non-Cataloged Circulation</report_title>
172         <heading>Circulations Count</heading>
173         <query>SELECT COUNT(id) FROM m_action_non_cataloged_circulation</query>
174     </report>
175
176      <report>
177         <name>in_house</name>
178         <tag>circs</tag>
179         <iteration>0</iteration>
180         <report_title>In House Use</report_title>
181         <heading>In House Use Records.Migrated</heading>
182         <query>SELECT COUNT(id), x_migrate::TEXT FROM m_action_in_house_use_legacy GROUP BY 2</query>
183     </report>
184
185      <report>
186         <name>in_house</name>
187         <tag>circs</tag>
188         <iteration>1</iteration>
189         <report_title>In House Use</report_title>
190         <heading>In House Use Records</heading>
191         <query>SELECT COUNT(id) FROM m_action_in_house_use</query>
192     </report>
193
194      <report>
195         <name>circs_missing_rules</name>
196         <tag>circs</tag>
197         <iteration>1</iteration>
198         <report_title>Circs Missing Rules</report_title>
199         <heading>Count.Field Missing</heading>
200         <query>SELECT COUNT(id), 'Duration Rule Value' FROM m_action_circulation WHERE duration IS NULL 
201             UNION ALL SELECT COUNT(id), 'Recurring Fine Rule Value' FROM m_action_circulation WHERE recurring_fine IS NULL 
202             UNION ALL SELECT COUNT(id), 'Max Fine Rule Value' FROM m_action_circulation WHERE max_fine IS NULL
203             UNION ALL SELECT COUNT(id), 'Duration Rule' FROM m_action_circulation WHERE duration_rule IS NULL       
204             UNION ALL SELECT COUNT(id), 'Recurring Fine Rule' FROM m_action_circulation WHERE recurring_fine_rule IS NULL      
205             UNION ALL SELECT COUNT(id), 'Max Fine Rule' FROM m_action_circulation WHERE max_fine_rule IS NULL
206         </query>
207     </report>
208
209      <report>
210         <name>circ_open_by_item_status</name>
211         <tag>circs</tag>
212         <iteration>0</iteration>
213         <report_title>Status of Currently Circulating Items</report_title>
214         <heading>Count.Status</heading>
215         <query>SELECT COUNT(acirc.id), ccs.name FROM action.circulation acirc JOIN asset.copy ac ON ac.id = acirc.target_copy JOIN config.copy_status ccs ON ccs.id = ac.status WHERE acirc.xact_finish IS NULL AND acirc.checkin_time IS NULL AND acirc.id IN (SELECT id FROM m_action_circulation) GROUP BY 2 ORDER BY 2</query>
216     </report>
217
218     <!-- HOLDS REPORTS -->
219
220      <report>
221         <name>holds</name>
222         <tag>holds</tag>
223         <iteration>0</iteration>
224         <report_title>Migrated and Non-Migrated Holds</report_title>
225         <heading>Hold Type.Hold Count.Migrated</heading>
226         <query>SELECT 'Closed Holds', COUNT(id), x_migrate::TEXT FROM m_action_hold_request_legacy WHERE (expire_time::TIMESTAMP &lt; now()) OR cancel_time IS NOT NULL OR fulfillment_time IS NOT NULL GROUP BY 3 UNION ALL SELECT 'Open Holds', COUNT(id), x_migrate::TEXT FROM m_action_hold_request_legacy WHERE (expire_time IS NULL OR expire_time::TIMESTAMP &gt; now()) AND cancel_time IS NULL AND fulfillment_time IS NULL GROUP BY 3</query>
227     </report>
228
229      <report>
230         <name>holds_bytype</name>
231         <tag>holds</tag>
232         <iteration>0</iteration>
233         <report_title>Migrated Holds By Type</report_title>
234         <heading>Hold Type.Hold Count</heading>
235         <query>SELECT hold_type as "Hold Type", COUNT(id) FROM m_action_hold_request_legacy WHERE x_migrate = TRUE GROUP BY 1</query>
236     </report>
237
238      <report>
239         <name>transit_open_by_item_status</name>
240         <tag>holds</tag>
241         <iteration>0</iteration>
242         <report_title>Transit Copy Records and Status of Linked Items</report_title>
243         <heading>Count.Status</heading>
244         <query>SELECT COUNT(atc.id), ccs.name FROM action.transit_copy atc JOIN asset.copy ac ON ac.id = atc.target_copy JOIN config.copy_status ccs ON ccs.id = ac.status WHERE atc.id IN (SELECT id FROM m_action_transit_copy) AND atc.dest_recv_time IS NULL GROUP BY 2 ORDER BY 2</query>
245     </report>
246
247      <report>
248         <name>transit_copies_by_status</name>
249         <tag>holds</tag>
250         <iteration>0</iteration>
251         <report_title>Status of Items with Count of Open In Transits</report_title>
252         <heading>Count.Status.Count of Open Transits</heading>
253         <query>SELECT COUNT(ac.id), ccs.name, SUM(CASE WHEN atc.id IS NULL THEN 0 ELSE 1 END) FROM asset.copy ac JOIN config.copy_status ccs ON ccs.id = ac.status LEFT JOIN (SELECT * FROM action.transit_copy WHERE id IN (SELECT id FROM m_action_transit_copy) AND dest_recv_time IS NULL) atc ON atc.target_copy = ac.id WHERE ac.id IN (SELECT id from m_asset_copy) GROUP BY 2 ORDER BY 2</query>
254     </report>
255     
256      <report>
257         <name>hold_copies_by_status</name>
258         <tag>holds</tag>
259         <iteration>0</iteration>
260         <report_title>Captured Holds with Status of Items</report_title>
261         <heading>Count of Captured Hold.Status of Item</heading>
262         <query>SELECT COUNT(ahr.id), ccs.name FROM action.hold_request ahr JOIN asset.copy ac ON ac.id = ahr.current_copy JOIN config.copy_status ccs ON ccs.id = ac.status WHERE ahr.capture_time IS NOT NULL AND ahr.fulfillment_time IS NULL and ahr.cancel_time IS NULL AND ahr.id IN (SELECT id FROM m_action_hold_request) GROUP BY 2 ORDER By 2</query>
263     </report>
264
265       <report>
266         <name>hold_depth</name>
267         <tag>holds</tag>
268         <iteration>0</iteration>
269         <report_title>Depth of Unfilled Holds</report_title>
270         <heading>Count.Depth</heading>
271         <query>SELECT COUNT(ahr.id), ahr.selection_depth FROM action.hold_request ahr WHERE ahr.id IN (SELECT id FROM m_action_hold_request) AND ahr.cancel_time IS NULL AND ahr.capture_time IS NULL AND ahr.fulfillment_time IS NULL GROUP BY 2 ORDER BY 2</query>
272     </report>
273
274     <!-- ASSET REPORTS -->
275     
276     <report>
277         <name>m_asset_copy_count</name>
278         <report_title>Count of Copies by Library</report_title>
279         <tag>assets</tag>
280         <iteration>0</iteration>
281         <heading>Copy Count.Library</heading>
282         <query>SELECT COUNT(ac.id), aou.name FROM m_asset_copy_legacy ac JOIN actor.org_unit aou ON aou.id = ac.circ_lib WHERE ac.x_migrate = TRUE GROUP BY 2 ORDER BY 2</query>
283     </report>
284
285     <report>
286         <name>m_asset_copy_count_non_migrated</name>
287         <report_title>Non-Migrated Count of Copies by Library</report_title>
288         <tag>assets</tag>
289         <iteration>0</iteration>
290         <heading>Copy Count.Library</heading>
291         <query>SELECT COUNT(ac.id), aou.name FROM m_asset_copy_legacy ac JOIN actor.org_unit aou ON aou.id = ac.circ_lib WHERE ac.x_migrate = FALSE GROUP BY 2 ORDER BY 2</query>
292     </report>
293
294     <report>
295         <name>m_asset_copies_by_status</name>
296         <report_title>Copies by Status</report_title>
297         <tag>assets</tag>
298         <iteration>0</iteration>
299         <heading>Copy Count.Status</heading>
300         <query>SELECT COUNT(ac.id), cs.name FROM m_asset_copy_legacy ac JOIN config.copy_status cs ON cs.id = ac.status WHERE ac.x_migrate = TRUE GROUP BY 2 ORDER BY 2</query>
301     </report>
302
303     <report>
304         <name>m_asset_circ_mod_copies_count</name>
305         <report_title>Copies by Circulation Modifier</report_title>
306         <tag>assets</tag>
307         <iteration>0</iteration>
308         <heading>Copy Count.Circulation Modifier</heading>
309         <query>SELECT COUNT(ac.id), ac.circ_modifier FROM m_asset_copy_legacy ac WHERE ac.x_migrate = TRUE GROUP BY 2 ORDER BY 2</query>
310     </report>
311
312     <report>
313         <name>m_asset_copy_notes</name>
314         <report_title>Copy Notes</report_title>
315         <tag>assets</tag>
316         <iteration>0</iteration>
317         <heading>Note Count.Public</heading>
318         <query>SELECT COUNT(acnote.id), acnote.pub::TEXT FROM m_asset_copy_note_legacy acnote WHERE acnote.x_migrate = TRUE GROUP BY 2 ORDER BY 2</query>
319     </report>
320
321     <report>
322         <name>m_asset_copy_notes</name>
323         <report_title>Copy Notes</report_title>
324         <tag>assets</tag>
325         <iteration>1</iteration>
326         <heading>Note Count.Public</heading>
327         <query>SELECT COUNT(acnote.id), acnote.pub::TEXT FROM m_asset_copy_note acnote GROUP BY 2 ORDER BY 2</query>
328     </report>
329
330    <report>
331         <name>m_asset_vols_by_lib</name>
332         <report_title>Volumes by Library</report_title>
333         <tag>assets</tag>
334         <iteration>0</iteration>
335         <heading>Volume Count.Library</heading>
336         <query>SELECT COUNT(acn.id), aou.name FROM m_asset_call_number_legacy acn JOIN m_actor_org_unit_legacy aou ON aou.id = acn.owning_lib WHERE acn.x_migrate = TRUE GROUP BY 2 ORDER BY 2</query>
337     </report>
338
339    <report>
340         <name>m_asset_vols_by_lib</name>
341         <report_title>Volumes by Library</report_title>
342         <tag>assets</tag>
343         <iteration>1</iteration>
344         <heading>Volume Count.Library</heading>
345         <query>SELECT COUNT(acn.id), aou.name FROM m_asset_call_number acn JOIN actor.org_unit aou ON aou.id = acn.owning_lib GROUP BY 2 ORDER BY 2</query>
346     </report>
347
348    <report>
349         <name>m_asset_cops_by_loc_and_org</name>
350         <report_title>Copies by Location</report_title>
351         <tag>assets</tag>
352         <iteration>0</iteration>
353         <heading>Copy Count.Library.Circ Library</heading>
354         <query>SELECT COUNT(ac.id), acl.name, aou.name FROM m_asset_copy_legacy ac JOIN asset.copy_location acl ON acl.id = ac.location JOIN actor.org_unit aou ON aou.id = ac.circ_lib WHERE ac.x_migrate = TRUE GROUP BY 2, 3 ORDER BY 2, 3</query>
355     </report>
356
357    <report>
358         <name>m_asset_cops_w_loc_one</name>
359         <report_title>Copies with a Location of Stacks</report_title>
360         <tag>assets</tag>
361         <iteration>0</iteration>
362         <heading>Barcode</heading>
363         <query>SELECT barcode FROM m_asset_copy_legacy WHERE location = 1 AND x_migrate</query>
364     </report>
365
366     <report>
367         <name>m_asset_no_barcode</name>
368         <report_title>Items Without Barcodes</report_title>
369         <tag>assets</tag>
370         <iteration>0</iteration>
371         <heading>Assigned Barcode</heading>
372         <query>SELECT barcode FROM m_asset_copy_legacy WHERE barcode ~* 'no_barocde' AND x_migrate</query>
373     </report>
374
375     <report>
376         <name>m_asset_barcode_patterns</name>
377         <report_title>Common Barcode Starting Patterns</report_title>
378         <tag>assets</tag>
379         <iteration>0</iteration>
380         <heading>Count of Barcodes (greater than 10).Left 60% of Characters</heading>
381         <query>SELECT COUNT(ac.id), LEFT(ac.barcode,(ROUND(LENGTH(ac.barcode)*.6))::INT) FROM m_asset_copy_legacy ac WHERE ac.x_migrate = TRUE GROUP BY 2 HAVING COUNT(ac.id) > 10 ORDER BY 2</query>
382     </report>
383
384     <report>
385         <name>m_asset_barcode_collisions</name>
386         <report_title>Copy Barcode Collisions</report_title>
387         <tag>assets</tag>
388         <iteration>0</iteration>
389         <heading>Collision Count</heading>
390         <query>SELECT COUNT(id) FROM m_asset_copy_legacy WHERE x_migrate = TRUE AND barcode ~* '^x_'</query>
391         <note>Incumbent collisions are those where the migrated barcodes collide with existing barcodes in the database.</note>
392     </report>
393
394     <report>
395         <name>m_asset_barcode_collisions</name>
396         <report_title>Copy Barcode Collisions</report_title>
397         <tag>assets</tag>
398         <iteration>1</iteration>
399         <heading>Collision Count</heading>
400         <query>SELECT COUNT(id) FROM m_asset_copy WHERE barcode ~* '^x_'</query>
401         <note>Incumbent collisions are those where the migrated barcodes collide with existing barcodes in the database.</note>
402     </report>
403
404     <report>
405         <name>m_asset_barcode_collisions_shortlist</name>
406         <report_title>Copy Barcode Collisions (first 20)</report_title>
407         <tag>assets</tag>
408         <iteration>0</iteration>
409         <heading>Collision List</heading>
410         <query>SELECT ac.barcode FROM m_asset_copy_legacy ac WHERE ac.barcode ~* '^x_' AND ac.x_migrate = TRUE ORDER BY 1 LIMIT 20</query>
411         <note>This is a shortlist of copy barcode collisions that maxes out at 20.  If there are more collisions we will need to run a custom report.</note>
412     </report>
413
414     <report>
415         <name>m_asset_barcode_collisions_shortlist</name>
416         <report_title>Copy Barcode Collisions (first 20)</report_title>
417         <tag>assets</tag>
418         <iteration>1</iteration>
419         <heading>Collision List</heading>
420         <query>SELECT ac.barcode FROM m_asset_copy ac WHERE ac.barcode ~* '^x_' ORDER BY 1 LIMIT 20</query>
421         <note>This is a shortlist of patron barcode collisions that maxes out at 20.  If there are more collisions we will need to run a custom report.</note>
422     </report>
423
424     <report>
425         <name>m_asset_barcode_collision_patterns</name>
426         <report_title>Common Copy Barcode Collision Patterns</report_title>
427         <tag>assets</tag>
428         <iteration>0</iteration>
429         <heading>Number of Barcodes Matching Pattern Greater than 10.Left 60% of Characters</heading>
430         <query>SELECT COUNT(ac.id), LEFT(ac.barcode,(ROUND(LENGTH(ac.barcode)*.6))::INT) FROM m_asset_copy_legacy ac WHERE barcode ~* '^x_' AND ac.x_migrate = TRUE GROUP BY 2 HAVING COUNT(ac.id) > 10 ORDER BY 2</query>
431     </report>
432
433     <report>
434         <name>m_asset_barcode_collision_patterns</name>
435         <report_title>Common Copy Barcode Collision Patterns</report_title>
436         <tag>assets</tag>
437         <iteration>1</iteration>
438         <heading>Number of Barcodes Matching Pattern Greater than 10.Left 60% of Characters</heading>
439         <query>SELECT COUNT(ac.id), LEFT(ac.barcode,(ROUND(LENGTH(ac.barcode)*.6))::INT) FROM m_asset_copy ac WHERE barcode ~* '^x_' GROUP BY 2 HAVING COUNT(ac.id) > 10 ORDER BY 2</query>
440     </report>
441
442     <report>
443          <name>m_asset_stat_cats</name>
444         <report_title>Copy Statistical Categories</report_title>
445         <tag>assets</tag>
446         <iteration>0</iteration>
447         <heading>Stat Cat Count.Library.Statistical Category</heading>
448         <query>SELECT COUNT(ac_sc.id), aou.name, ac_sc.name FROM m_asset_stat_cat_legacy ac_sc JOIN actor.org_unit aou ON aou.id = ac_sc.owner GROUP BY 2,3 ORDER BY 2,3</query>
449     </report>
450
451     <report>
452          <name>m_asset_stat_cats</name>
453         <report_title>Copy Statistical Categories</report_title>
454         <tag>assets</tag>
455         <iteration>1</iteration>
456         <heading>Stat Cat Count.Library.Statistical Category</heading>
457         <query>SELECT COUNT(ac_sc.id), aou.name, ac_sc.name FROM m_asset_stat_cat ac_sc JOIN actor.org_unit aou ON aou.id = ac_sc.owner GROUP BY 2,3 ORDER BY 2,3</query>
458     </report>
459
460     <report>
461         <name>m_asset_stat_cat_entries</name>
462         <report_title>Copy Stat Cat User Entries</report_title>
463         <tag>assets</tag>
464         <iteration>0</iteration>
465         <heading>Copy Stat Count.Library.Statistical Category</heading>
466         <query>SELECT COUNT(map.id), aou.name, ac_sc.name FROM m_asset_stat_cat_entry_copy_map_legacy map JOIN m_asset_stat_cat_legacy ac_sc ON ac_sc.id = map.stat_cat JOIN actor.org_unit aou ON aou.id = ac_sc.owner GROUP BY 2,3 ORDER BY 2,3</query>
467     </report>
468
469     <report>
470         <name>m_asset_stat_cat_entries</name>
471         <report_title>Copy Stat Cat User Entries</report_title>
472         <tag>assets</tag>
473         <iteration>1</iteration>
474         <heading>Copy Stat Count.Library.Statistical Category</heading>
475         <query>SELECT COUNT(map.id), aou.name, ac_sc.name FROM m_asset_stat_cat_entry_copy_map map JOIN m_asset_stat_cat ac_sc ON ac_sc.id = map.stat_cat JOIN actor.org_unit aou ON aou.
476 id = ac_sc.owner GROUP BY 2,3 ORDER BY 2,3</query>
477     </report>
478
479     <report>
480          <name>m_asset_copy_tags</name>
481         <report_title>Copy Tags</report_title>
482         <tag>assets</tag>
483         <iteration>0</iteration>
484         <heading>Tag Count.Copy Tag Type.Copy Tag Label.Staff Note.Public</heading>
485         <query>SELECT COUNT(map.id), tag.tag_type, tag.label, tag.staff_note, tag.pub FROM m_asset_copy_tag tag JOIN m_asset_copy_tag_copy_map map ON map.tag = tag.id GROUP BY 2,3,4,5 ORDER BY 2,3</query>
486     </report>
487
488     <report>
489          <name>m_asset_copy_alerts</name>
490         <report_title>Copy Alerts</report_title>
491         <tag>assets</tag>
492         <iteration>0</iteration>
493         <heading>Alert Count.Alert Type</heading>
494                 <query>SELECT COUNT(*), cat.name FROM m_asset_copy_alert aca JOIN config.copy_alert_type cat ON cat.id = aca.alert_type GROUP BY 2</query>
495     </report>
496
497     <!-- MONEY REPORTS -->
498
499     <report>
500         <name>m_money_billing_voided</name>
501         <report_title>Bills Voided And Not</report_title>
502         <tag>money</tag>
503         <iteration>0</iteration>
504         <heading>Count.Voided.Sum.Migrated</heading>
505         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount), a.x_migrate::TEXT FROM m_money_billing_legacy a GROUP BY 2, 4 ORDER BY 2, 4</query>
506     </report>
507
508     <report>
509         <name>m_money_billing_voided</name>
510         <report_title>Bills Voided And Not</report_title>
511         <tag>money</tag>
512         <iteration>1</iteration>
513         <heading>Count.Voided.Sum</heading>
514         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount) FROM m_money_billing a GROUP BY 2 ORDER BY 2, 3</query>
515     </report>
516
517     <report>
518         <name>m_money_billing_by_type</name>
519         <report_title>Bills by Type</report_title>
520         <tag>money</tag>
521         <iteration>0</iteration>
522         <heading>Count.Billing Type.Migrated</heading>
523         <query>SELECT COUNT(a.id), a.billing_type, a.x_migrate::TEXT FROM m_money_billing_legacy a GROUP BY 2, 3 ORDER BY 2, 3</query>
524     </report>
525
526     <report>
527         <name>m_money_billing_by_type</name>
528         <report_title>Bills by Type</report_title>
529         <tag>money</tag>
530         <iteration>1</iteration>
531         <heading>Count.Billing Type</heading>
532         <query>SELECT COUNT(a.id), a.billing_type FROM m_money_billing a GROUP BY 2 ORDER BY 2</query>
533     </report>
534
535     <report>
536         <name>m_money_cash_payment</name>
537         <report_title>Cash Payments</report_title>
538         <tag>money</tag>
539         <iteration>0</iteration>
540         <heading>Count.Voided.Sum.Migrated</heading>
541         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount), a.x_migrate::TEXT FROM m_money_cash_payment_legacy a GROUP BY 2, 4 ORDER BY 2, 4</query>
542     </report>
543
544     <report>
545         <name>m_money_cash_payment</name>
546         <report_title>Cash Payments</report_title>
547         <tag>money</tag>
548         <iteration>1</iteration>
549         <heading>Count.Voided.Sum</heading>
550         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount) FROM m_money_cash_payment a GROUP BY 2 ORDER BY 2</query>
551     </report>
552
553     <report>
554         <name>m_money_check_payment</name>
555         <report_title>Check Payments</report_title>
556         <tag>money</tag>
557         <iteration>0</iteration>
558         <heading>Count.Voided.Sum.Migrated</heading>
559         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount), a.x_migrate::TEXT FROM m_money_check_payment_legacy a GROUP BY 2, 4 ORDER BY 2, 4</query>
560     </report>
561
562     <report>
563         <name>m_money_forgive_payment</name>
564         <report_title>Forgive Payments</report_title>
565         <tag>money</tag>
566         <iteration>0</iteration>
567         <heading>Count.Voided.Sum.Migrated</heading>
568         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount), a.x_migrate::TEXT FROM m_money_forgive_payment_legacy a GROUP BY 2, 4 ORDER BY 2, 4</query>
569     </report>
570
571     <report>
572         <name>m_money_forgive_payment</name>
573         <report_title>Forgive Payments</report_title>
574         <tag>money</tag>
575         <iteration>1</iteration>
576         <heading>Count.Voided.Sum</heading>
577         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount) FROM m_money_forgive_paymen a GROUP BY 2 ORDER BY 2</query>
578     </report>
579
580     <report>
581         <name>m_money_goods_payment</name>
582         <report_title>Goods Payments</report_title>
583         <tag>money</tag>
584         <iteration>0</iteration>
585         <heading>Count.Voided.Sum.Migrated</heading>
586         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount), a.x_migrate::TEXT FROM m_money_goods_payment_legacy a GROUP BY 2, 4 ORDER BY 2, 4</query>
587     </report>
588
589     <report>
590         <name>m_money_work_payment</name>
591         <report_title>Work Payments</report_title>
592         <tag>money</tag>
593         <iteration>0</iteration>
594         <heading>Count.Voided.Sum.Migrated</heading>
595         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount), a.x_migrate::TEXT FROM m_money_work_payment_legacy a GROUP BY 2, 4 ORDER BY 2, 4</query>
596     </report>
597
598     <report>
599         <name>m_money_credit_card_payment</name>
600         <report_title>Credit Card Payments</report_title>
601         <tag>money</tag>
602         <iteration>0</iteration>
603         <heading>Count.Voided.Sum.Migrated</heading>
604         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount), a.x_migrate::TEXT FROM m_money_credit_card_payment_legacy a GROUP BY 2, 4 ORDER BY 2, 4</query>
605     </report>
606
607     <report>
608         <name>m_money_credit_payment</name>
609         <report_title>Credit Payments</report_title>
610         <tag>money</tag>
611         <iteration>0</iteration>
612         <heading>Count.Voided.Sum.Migrated</heading>
613         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount), a.x_migrate::TEXT FROM m_money_credit_payment_legacy a GROUP BY 2, 4 ORDER BY 2, 4</query>
614     </report>
615
616
617     <!-- BIBS REPORTS -->
618
619     <report>
620         <name>bibs_loaded</name>
621         <report_title>Loaded Bibliographic Records</report_title>
622         <tag>bibs</tag>
623         <iteration>0</iteration>
624         <heading>Count</heading>
625         <query>SELECT COUNT(bre.id) FROM m_biblio_record_entry_legacy bre WHERE id IN (SELECT id FROM biblio.record_entry) ORDER BY 1</query>
626     </report>
627
628     <report>
629         <name>bibs_loaded</name>
630         <report_title>Loaded Bibliographic Records</report_title>
631         <tag>bibs</tag>
632         <iteration>1</iteration>
633         <heading>Count</heading>
634         <query>SELECT COUNT(bre.id) FROM m_biblio_record_entry bre WHERE id IN (SELECT id FROM biblio.record_entry) ORDER BY 1</query>
635     </report>
636
637     <report>
638         <name>bibswovolumes</name>
639         <report_title>Bibliographic Records Without Volumes</report_title>
640         <tag>bibs</tag>
641         <iteration>0</iteration>
642         <heading>Count</heading>
643         <query>SELECT COUNT(id) FROM m_biblio_record_entry where id NOT IN (SELECT DISTINCT record FROM m_asset_call_number)</query>
644                 <note>These records would not have been loaded but many may be deduplicated against incumbent records.</note>
645     </report>
646
647     <report>
648         <name>bibswovolumesanduri</name>
649         <report_title>Bibliographic Records Without Volumes And Recognized URI</report_title>
650         <tag>bibs</tag>
651         <iteration>0</iteration>
652         <heading>Service.Domain.Count</heading>
653         <query>SELECT '3M','ebook.3m.com', COUNT(*) FROM subfield_u WHERE value ~* 'ebook.3m.com' GROUP BY 1, 2 UNION ALL
654                 SELECT 'Axis 360','axis360.baker-taylor.com', COUNT(*) FROM subfield_u WHERE value ~* 'axis360.baker-taylor.com' GROUP BY 1, 2 UNION ALL
655                 SELECT 'Book Flix','bookflix.digital.scholastic.com', COUNT(*) FROM subfield_u WHERE value ~* 'bookflix.digital.scholastic.com' GROUP BY 1, 2 UNION ALL
656                 SELECT 'Book Flix','bkflix.grolier.com', COUNT(*) FROM subfield_u WHERE value ~* 'bkflix.grolier.com' GROUP BY 1, 2 UNION ALL
657                 SELECT 'Comics Plus','library.comicsplusapp.com', COUNT(*) FROM subfield_u WHERE value ~* 'library.comicsplusapp.com' GROUP BY 1, 2 UNION ALL
658                 SELECT 'Ebrary','site.ebrary.com', COUNT(*) FROM subfield_u WHERE value ~* 'site.ebrary.com' GROUP BY 1, 2 UNION ALL
659                 SELECT 'Freading','freading.com', COUNT(*) FROM subfield_u WHERE value ~* 'freading.com' GROUP BY 1, 2 UNION ALL
660                 SELECT 'Hoopla','hoopladigital.com', COUNT(*) FROM subfield_u WHERE value ~* 'hoopladigital.com' GROUP BY 1, 2 UNION ALL
661                 SELECT 'Infobase','avod.infobase.com', COUNT(*) FROM subfield_u WHERE value ~* 'avod.infobase.com' GROUP BY 1, 2 UNION ALL
662                 SELECT 'Learning Express','learningexpresslibrary.com', COUNT(*) FROM subfield_u WHERE value ~* 'learningexpresslibrary.com' GROUP BY 1, 2 UNION ALL
663                 SELECT 'Missouri Overdrive','molib2go.org', COUNT(*) FROM subfield_u WHERE value ~* 'molib2go.org' GROUP BY 1, 2 UNION ALL
664                 SELECT 'netLibrary','netLibrary.com', COUNT(*) FROM subfield_u WHERE value ~* 'netLibrary.com' GROUP BY 1, 2 UNION ALL
665                 SELECT 'OneClickDigital','oneclickdigital.com', COUNT(*) FROM subfield_u WHERE value ~* 'oneclickdigital.com' GROUP BY 1, 2 UNION ALL
666                 SELECT 'Overdrive','overdrive.com', COUNT(*) FROM subfield_u WHERE value ~* 'overdrive.com' GROUP BY 1, 2 UNION ALL
667                 SELECT 'ProQuest','ebookcentral.proquest.com', COUNT(*) FROM subfield_u WHERE value ~* 'ebookcentral.proquest.com' GROUP BY 1, 2 UNION ALL
668                 SELECT 'RB Digital','rbdigital.com', COUNT(*) FROM subfield_u WHERE value ~* 'rbdigital.com' GROUP BY 1, 2 UNION ALL
669                 SELECT 'U.S. Government Sites','.gov', COUNT(*) FROM subfield_u WHERE value ~* '\.gov' GROUP BY 1,2;;
670                 </query>
671         <note>This list is built from known services and domains. If you have records for electronic resources that are not here please let us know.</note>
672     </report>
673
674     <report>
675         <name>bibswuri</name>
676         <report_title>Bibliographic Records With 856$9s</report_title>
677         <tag>bibs</tag>
678         <iteration>0</iteration>
679         <heading>Count</heading>
680         <query>SELECT COUNT(id) FROM m_biblio_record_entry where id IN (SELECT record FROM asset.call_number WHERE label ~* '##URI##')</query>
681     </report>
682
683         <report>
684                 <name>bibsff</name>
685                 <report_title>Bibliographic Records with Adjusted Fixed Fields</report_title>
686                 <tag>bibs</tag>
687                 <iteration>0</iteration>
688                 <heading>Count.Original Search Format.New Search Format</heading>
689                 <query>SELECT COUNT(*), ARRAY_TO_STRING(x_search_format,','), ARRAY_TO_STRING(x_after_search_format,',') FROM m_biblio_record_entry_legacy WHERE x_migrate AND x_after_search_format IS NOT NULL GROUP BY 2, 3 ORDER BY 3,2</query>
690         </report>
691
692     <report>
693         <name>bibs_notes</name>
694         <report_title>Bib Record Notes</report_title>
695         <tag>bibs</tag>
696         <iteration>0</iteration>
697         <heading>Count.Migrated</heading>
698         <query>SELECT COUNT(b.id), b.x_migrate::TEXT FROM m_biblio_record_note_legacy b GROUP BY 2</query>
699     </report>
700
701     <report>
702         <name>bibs_notes</name>
703         <report_title>Bib Record Notes</report_title>
704         <tag>bibs</tag>
705         <iteration>1</iteration>
706         <heading>Count</heading>
707         <query>SELECT COUNT(b.id) FROM m_biblio_record_note b</query>
708     </report>
709
710     <report>
711         <name>bibs_peers</name>
712         <report_title>Peer Bib Copies</report_title>
713         <tag>bibs</tag>
714         <iteration>0</iteration>
715         <heading>Count.Migrated</heading>
716         <query>SELECT COUNT(b.id), b.x_migrate::TEXT FROM m_biblio_peer_bib_copy_map_legacy b GROUP BY 2</query>
717     </report>
718
719     <report>
720         <name>bibs_peers</name>
721         <report_title>Peer Bib Copies</report_title>
722         <tag>bibs</tag>
723         <iteration>1</iteration>
724         <heading>Count</heading>
725         <query>SELECT COUNT(b.id) FROM m_biblio_peer_bib_copy_map b</query>
726     </report>
727
728     <report>
729         <name>bibs_parts</name>
730         <report_title>Monograph Parts</report_title>
731         <tag>bibs</tag>
732         <iteration>0</iteration>
733         <heading>Count.Migrated</heading>
734         <query>SELECT COUNT(b.id), b.x_migrate::TEXT FROM m_biblio_monograph_part_legacy b GROUP BY 2</query>
735     </report>
736
737     <report>
738         <name>bibs_parts</name>
739         <report_title>Monograph Parts</report_title>
740         <tag>bibs</tag>
741         <iteration>1</iteration>
742         <heading>Count</heading>
743         <query>SELECT COUNT(b.id) FROM m_biblio_monograph_part b</query>
744     </report>
745
746     <report>
747         <name>bib_merges</name>
748         <report_title>Bibliographic Merge Count</report_title>
749         <tag>bibs</tag>
750         <iteration>0</iteration>
751         <heading>Records Merged.Incumbent Records Merged Into</heading>
752         <query>SELECT SUM(array_length(records,1)), COUNT(*) FROM groups</query>
753     </report>
754
755     <!-- ACTORS REPORTS -->
756
757     <report>
758         <name>usrsbyorg</name>
759         <report_title>Migrated Patrons by Home Org</report_title>
760         <tag>actors</tag>
761         <iteration>0</iteration>
762         <heading>Count.Library</heading>
763         <query>SELECT COUNT(au.id), aou.name FROM m_actor_usr_legacy au JOIN actor.org_unit aou ON aou.id = au.home_ou WHERE au.x_migrate = TRUE GROUP BY 2 ORDER BY 2</query>
764     </report>
765
766     <report>
767         <name>nonmigusrsbyorg</name>
768         <report_title>Non-Migrated Patrons by Home Org</report_title>
769         <tag>actors</tag>
770         <iteration>0</iteration>
771         <heading>Count.Library</heading>
772         <query>SELECT COUNT(au.id), aou.name FROM m_actor_usr_legacy au JOIN actor.org_unit aou ON aou.id = au.home_ou WHERE au.x_migrate = FALSE GROUP BY 2 ORDER BY 2</query>
773     </report>
774
775     <report>
776         <name>usrsbypgt</name>
777         <report_title>Migrated Patrons by Permission Group</report_title>
778         <tag>actors</tag>
779         <iteration>0</iteration>
780         <heading>Count.Permission Group</heading>
781         <query>SELECT COUNT(au.id), pgt.name FROM m_actor_usr_legacy au JOIN permission.grp_tree pgt ON pgt.id = au.profile WHERE au.x_migrate = TRUE GROUP BY 2 ORDER BY 2</query>
782     </report>
783
784     <report>
785         <name>active_usrs</name>
786         <report_title>Patron by Active Status</report_title>
787         <tag>actors</tag>
788         <iteration>0</iteration>
789         <heading>Count of Users.Active</heading>
790         <query>SELECT COUNT(id), active::TEXT FROM m_actor_usr_legacy WHERE x_migrate = TRUE GROUP BY 2</query>
791     </report>
792
793     <report>
794         <name>active_usrs</name>
795         <report_title>Patron Cards</report_title>
796         <tag>actors</tag>
797         <iteration>1</iteration>
798         <heading>Count of Users</heading>
799         <query>SELECT COUNT(id) FROM m_actor_usr</query>
800     </report>
801
802     <report>
803         <name>active_usr_barcodes</name>
804         <report_title>Patron Barcodes by Active Status</report_title>
805         <tag>actors</tag>
806         <iteration>0</iteration>
807         <heading>Count of Barcodes.Active.Migrated</heading>
808         <query>SELECT COUNT(id), active::TEXT, x_migrate::TEXT FROM m_actor_card_legacy GROUP BY 2, 3</query>
809     </report>
810
811     <report>
812         <name>active_usr_barcodes</name>
813         <report_title>Patron Barcodes by Active Status</report_title>
814         <tag>actors</tag>
815         <iteration>1</iteration>
816         <heading>Count of Barcodes.Active</heading>
817         <query>SELECT COUNT(id), active::TEXT FROM m_actor_card GROUP BY 2</query>
818     </report>
819
820     <report>
821         <name>usr_barcode_patterns</name>
822         <report_title>Common Barcode Starting Patterns</report_title>
823         <tag>actors</tag>
824         <iteration>0</iteration>
825         <heading>Count of Barcodes (greater than 10).Left 60% of Characters</heading>
826         <query>SELECT COUNT(acard.id), LEFT(acard.barcode,(ROUND(LENGTH(acard.barcode)*.6))::INT) FROM m_actor_card_legacy acard WHERE acard.x_migrate = TRUE GROUP BY 2 HAVING COUNT(acard.id) > 10 ORDER BY 2</query>
827     </report>
828
829     <report>
830         <name>usr_barcode_patterns</name>
831         <report_title>Common Barcode Starting Patterns</report_title>
832         <tag>actors</tag>
833         <iteration>1</iteration>
834         <heading>Count of Barcodes (greater than 10).Left 60% of Characters</heading>
835         <query>SELECT COUNT(acard.id), LEFT(acard.barcode,(ROUND(LENGTH(acard.barcode)*.6))::INT) FROM m_actor_card acard GROUP BY 2 HAVING COUNT(acard.id) > 10 ORDER BY 2</query>
836     </report>
837  
838    <report>
839         <name>usr_barcode_collisions</name>
840         <report_title>Patron Barcode Collisions</report_title>
841         <tag>actors</tag>
842         <iteration>0</iteration>
843         <heading>Collision Count</heading>
844         <query>SELECT COUNT(acard.id) FROM m_actor_card_legacy acard WHERE barcode ~* '^x_' AND x_migrate = TRUE</query>
845     </report>
846
847     <report>
848         <name>usr_barcode_collisions</name>
849         <report_title>Patron Barcode Collisions</report_title>
850         <tag>actors</tag>
851         <iteration>1</iteration>
852         <heading>Collision Count</heading>
853         <query>SELECT COUNT(acard.id) FROM m_actor_card acard WHERE barcode ~* '^x_'</query>
854     </report>
855
856     <report>
857         <name>usr_barcode_collision_shortlist</name>
858         <report_title>Patron Barcode Collisions (first 20)</report_title>
859         <tag>actors</tag>
860         <iteration>0</iteration>
861         <heading>Collision List</heading>
862         <query>SELECT acard.barcode FROM m_actor_card_legacy acard WHERE acard.barcode ~* '^x_' AND acard.x_migrate = TRUE ORDER BY 1 LIMIT 20</query>
863         <note>This is a shortlist of patron barcode collisions that maxes out at 20.  If there are more collisions we will need to run a custom report.  In some cases we may flag individual accounts to not migrate.</note>
864     </report>
865
866     <report>
867         <name>usr_barcode_collision_shortlist</name>
868         <report_title>Patron Barcode Collisions (first 20)</report_title>
869         <tag>actors</tag>
870         <iteration>1</iteration>
871         <heading>Collision List</heading>
872         <query>SELECT acard.barcode FROM m_actor_card acard WHERE acard.barcode ~* '^x_%' ORDER BY 1 LIMIT 20</query>
873         <note>This is a shortlist of patron barcode collisions that maxes out at 20.  If there are more collisions we will need to run a custom report.  In some cases we may flag individual accounts to not migrate.</note>
874     </report>
875
876     <report>
877         <name>usr_barcode_collision_patterns</name>
878         <report_title>Common Patron Barcode Collision Patterns</report_title> a.x_migrate
879         <tag>actors</tag>
880         <iteration>0</iteration>
881         <heading>Number of Barcodes Matching Pattern Greater than 10.Left 60% of Characters</heading>
882         <query>SELECT COUNT(acard.id), LEFT(acard.barcode,(ROUND(LENGTH(acard.barcode)*.6))::INT) FROM m_actor_card_legacy acard WHERE (acard.barcode ~* 'collision' OR acard.barcode ~* '^x_') AND acard.x_migrate = TRUE GROUP BY 2 HAVING COUNT(acard.id) > 10 ORDER BY 2</query>
883     </report>
884
885     <report>
886         <name>usr_barcode_collision_patterns</name>
887         <report_title>Common Patron Barcode Collision Patterns</report_title> a.x_migrate
888         <tag>actors</tag>
889         <iteration>1</iteration>
890         <heading>Number of Barcodes Matching Pattern Greater than 10.Left 60% of Characters</heading>
891         <query>SELECT COUNT(acard.id), LEFT(acard.barcode,(ROUND(LENGTH(acard.barcode)*.6))::INT) FROM m_actor_card acard WHERE (acard.barcode ~* 'collision' OR acard.barcode ~* '^x_') GROUP BY 2 HAVING COUNT(acard.id) > 10 ORDER BY 2</query>
892     </report>
893
894     <report>
895         <name>usr_addressses_status</name>
896         <report_title>Patron Addresses</report_title>
897         <tag>actors</tag>
898         <iteration>0</iteration>
899         <heading>Count</heading>
900         <query>SELECT COUNT(aua.id) FROM m_actor_usr_address_legacy aua WHERE aua.x_migrate = TRUE</query>
901     </report>
902
903     <report>
904         <name>usr_addressses_status</name>
905         <report_title>Patron Addresses</report_title>
906         <tag>actors</tag>
907         <iteration>1</iteration>
908         <heading>Count</heading>
909         <query>SELECT COUNT(aua.id) FROM m_actor_usr_address aua</query>
910     </report>
911
912     <report>
913         <name>usr_addresses_pending</name>
914         <report_title>Patron Addresses by Pending Status</report_title>
915         <tag>actors</tag>
916         <iteration>0</iteration>
917         <heading>Count of Addresses.Pending</heading>
918         <query>SELECT COUNT(aua.id), pending::TEXT FROM m_actor_usr_address_legacy aua WHERE aua.x_migrate = TRUE GROUP BY 2</query>
919     </report>
920
921     <report>
922         <name>usr_addresses_pending</name>
923         <report_title>Patron Addresses by Pending Status</report_title>
924         <tag>actors</tag>
925         <iteration>1</iteration>
926         <heading>Count of Addresses.Pending</heading>
927         <query>SELECT COUNT(aua.id), pending::TEXT FROM m_actor_usr_address aua GROUP BY 2</query>
928     </report>
929
930     <report>
931         <name>usr_messages</name>
932         <report_title>Patron Messages</report_title>
933         <tag>actors</tag>
934         <iteration>0</iteration>
935         <heading>Count.Deleted.Migrated</heading>
936         <query>SELECT COUNT(aum.id), deleted::TEXT, x_migrate::TEXT FROM m_actor_usr_message_legacy aum GROUP BY 2, 3</query>
937     </report>
938
939     <report>
940         <name>usr_messages</name>
941         <report_title>Patron Messages</report_title>
942         <tag>actors</tag>
943         <iteration>1</iteration>
944         <heading>Count.Deleted</heading>
945         <query>SELECT COUNT(aum.id), deleted::TEXT FROM m_actor_usr_message_legacy aum GROUP BY 2</query>
946     </report>
947
948     <report>
949         <name>usr_notes</name>
950         <report_title>Patron Notes</report_title>
951         <tag>actors</tag>
952         <iteration>0</iteration>
953         <heading>Count.Public.Migrated</heading>
954         <query>SELECT COUNT(aun.id), pub::TEXT, x_migrate::TEXT FROM m_actor_usr_note_legacy aun GROUP BY 2, 3</query>
955     </report>
956
957     <report>
958         <name>usr_notes</name>
959         <report_title>Patron Notes</report_title>
960         <tag>actors</tag>
961         <iteration>1</iteration>
962         <heading>Count.Public</heading>
963         <query>SELECT COUNT(aun.id), pub::TEXT FROM m_actor_usr_note aun GROUP BY 2</query>
964     </report>
965
966     <report>
967          <name>usr_stat_cats</name>
968         <report_title>Patron Statistical Categories</report_title>
969         <tag>actors</tag>
970         <iteration>0</iteration>
971         <heading>Stat Cat Count.Library.Statistical Category.Migrated</heading>
972         <query>SELECT COUNT(au_sc.id), aou.name, au_sc.name, au_sc.x_migrate::TEXT FROM m_actor_stat_cat_legacy au_sc JOIN actor.org_unit aou ON aou.id = au_sc.owner GROUP BY 2, 3, 4 ORDER BY 2, 3, 4</query>
973     </report>
974
975     <report>
976          <name>usr_stat_cats</name>
977         <report_title>Patron Statistical Categories</report_title>
978         <tag>actors</tag>
979         <iteration>1</iteration>
980         <heading>Stat Cat Count.Library.Statistical Category</heading>
981         <query>SELECT COUNT(au_sc.id), aou.name, au_sc.name FROM m_actor_stat_cat au_sc JOIN actor.org_unit aou ON aou.id = au_sc.owner GROUP BY 2, 3 ORDER BY 2, 3</query>
982     </report>
983
984     <report>
985         <name>usr_stat_cat_entries</name>
986         <report_title>Patron Stat Cat User Entries</report_title>
987         <tag>actors</tag>
988         <iteration>0</iteration>
989         <heading>Patron Stat Count.Library.Statistical Category.Migrated</heading>
990         <query>SELECT COUNT(map.id), aou.name, au_sc.name, map.x_migrate::TEXT FROM m_actor_stat_cat_entry_usr_map_legacy map JOIN m_actor_stat_cat_legacy au_sc ON au_sc.id = map.stat_cat JOIN actor.org_unit aou ON aou.id = au_sc.owner GROUP BY 2, 3, 4 ORDER BY 2,3, 4</query>
991     </report>
992
993     <report>
994         <name>usr_stat_cat_entries</name>
995         <report_title>Patron Stat Cat User Entries</report_title>
996         <tag>actors</tag>
997         <iteration>1</iteration>
998         <heading>Patron Stat Count.Library.Statistical Category</heading>
999         <query>SELECT COUNT(map.id), aou.name, au_sc.name FROM m_actor_stat_cat_entry_usr_map map JOIN m_actor_stat_cat au_sc ON au_sc.id = map.stat_cat JOIN actor.org_unit aou ON aou.id = au_sc.owner GROUP BY 2, 3 ORDER BY 2,3</query>
1000     </report>
1001
1002     <report>
1003         <name>usr_thresholds</name>
1004         <report_title>Patron Thresholds</report_title>
1005         <tag>actors</tag>
1006         <iteration>0</iteration>
1007         <heading>Pateron Group.Org Unit.Penalty.Threshold</heading>
1008         <query>SELECT pgt.name, aou.shortname, sp.name, p.threshold FROM permission_grp_penalty_threshold p 
1009                 JOIN actor.org_unit aou ON aou.id = p.org_unit JOIN permission.grp_tree pgt ON pgt.id = p.grp JOIN config.standing_penalty sp ON sp.id = p.penalty
1010                 ORDER BY 2, 1, 3</query>
1011     </report>
1012
1013     <report>
1014         <name>usr_settings</name>
1015         <report_title>Patron Settings</report_title>
1016         <tag>actors</tag>
1017         <iteration>0</iteration>
1018         <heading>Count.Setting.Value</heading>
1019         <query>SELECT COUNT(*), name, 'User''s Phone' FROM m_actor_usr_setting WHERE name IN ('opac.default_phone') GROUP BY 2, 3 
1020                         UNION ALL SELECT COUNT(*), name, value FROM m_actor_usr_setting WHERE name IN ('opac.hold_notify') GROUP BY 2, 3 
1021                         UNION ALL SELECT COUNT(*), a.name, aou.shortname FROM m_actor_usr_setting a JOIN actor.org_unit aou ON aou.id = REPLACE(a.value,'"','')::INTEGER 
1022                                 WHERE a.name IN ('opac.default_pickup_location','opac.default_search_location') GROUP BY 2, 3 ORDER BY 2, 3;</query>
1023     </report>
1024
1025     <!-- ACQUISITIONS REPORTS -->
1026     <report>
1027         <name>fund_count</name>
1028         <iteration>0</iteration>
1029         <tag>acq</tag>
1030         <report_title>Migrated Funds</report_title>
1031         <heading>Number of Funds.Migrated</heading>
1032         <query>SELECT COUNT(id), x_migrate::TEXT FROM m_acq_fund_legacy GROUP BY 2;</query>
1033     </report>
1034
1035     <report>                                                                        
1036         <name>fund_count</name>
1037         <iteration>1</iteration>
1038         <tag>acq</tag>
1039         <report_title>Migrated Funds</report_title>
1040         <heading>Number of Funds</heading>
1041         <query>SELECT COUNT(id) FROM m_acq_fund;</query>
1042     </report>
1043
1044     <report>
1045         <name>invoice_count</name>
1046         <iteration>0</iteration>
1047         <tag>acq</tag>
1048         <report_title>Migrated Invoices</report_title>
1049         <heading>Number of Invoices.Migrated</heading>
1050         <query>SELECT COUNT(id), x_migrate::TEXT FROM m_acq_invoice_legacy GROUP BY 2;</query>
1051     </report>
1052
1053     <report>
1054         <name>invoice_count</name>
1055         <iteration>1</iteration>
1056         <tag>acq</tag>
1057         <report_title>Migrated Invoices</report_title>
1058         <heading>Number of Funds</heading>
1059         <query>SELECT COUNT(id) FROM m_acq_invoice;</query>
1060     </report>    
1061
1062     <!-- SERIALS REPORTS -->
1063     <report>
1064         <name>serials_mfhd_count</name>
1065         <tag>serials</tag>
1066         <iteration>0</iteration>
1067         <report_title>Migrated Serial MFHDs</report_title>
1068         <heading>Number of MFHDs</heading>
1069         <query>SELECT COUNT(id) FROM m_serial_record_entry</query>
1070     </report>
1071
1072     <!-- DEDUPE REPORTS -->
1073
1074     <asset>
1075         <name>dedupe_explain</name>
1076         <tag>dedupe</tag>
1077         <file>dedupe_process.asciidoc</file> 
1078     </asset>
1079
1080     <report>
1081         <name>dedupe_bib_groups</name>
1082         <tag>dedupe</tag>
1083         <iteration>0</iteration>
1084         <report_title>Scoring and Bib Record Groups</report_title>
1085         <heading>Count.Bib Record Groups</heading>
1086         <query>SELECT COUNT(id), 'Total Bibs Being Evaluated' FROM biblio.record_entry WHERE deleted IS FALSE AND id IN (SELECT eg::BIGINT FROM bib_id_map)
1087           UNION ALL SELECT (COUNT(DISTINCT incoming_bib)), 'Incoming Bibs With Matches Found' FROM bib_matches
1088           UNION ALL SELECT (COUNT(bre.id) - (SELECT COUNT(DISTINCT incoming_bib) FROM bib_matches)), 'Incoming Bibs With No Match' 
1089                 FROM biblio.record_entry bre WHERE bre.deleted IS FALSE AND bre.id IN (SELECT eg::BIGINT FROM bib_id_map)
1090           UNION ALL SELECT COUNT(DISTINCT incoming_bib), 'Incoming Bibs Being Merged into Incumbent' FROM bib_matches WHERE incumbent_bib_score &gt;= incoming_bib_score
1091           UNION ALL SELECT COUNT(id), 'Incumbent Bibs With Higher Scores to Incoming' FROM bib_matches WHERE incumbent_bib_score &gt; incoming_bib_score
1092           UNION ALL SELECT COUNT(id), 'Incumbent Bibs With Equal Scores to Incoming' FROM bib_matches WHERE incumbent_bib_score = incoming_bib_score
1093           UNION ALL SELECT COUNT(id), 'Incumbent Bibs  With Lower Scores to Incoming' FROM bib_matches WHERE incumbent_bib_score &lt; incoming_bib_score
1094           ;</query>
1095     </report>
1096
1097     <report>
1098         <name>dedupe_format_count</name>
1099         <tag>dedupe</tag>
1100         <iteration>0</iteration>
1101         <report_title>Count of Items Matching By Format</report_title>
1102         <heading>Count.Format(s)</heading>
1103         <query>SELECT COUNT(id), search_formats FROM bib_matches GROUP BY 2 ORDER BY 2;</query>
1104     </report>
1105     
1106     <report>
1107         <name>dedupe_score_ranges</name>
1108         <tag>dedupe</tag>
1109         <iteration>0</iteration>
1110         <report_title>Count of Items Matching By Format</report_title>
1111         <heading>Lowest Record Score.Largest Record Score.Record Set</heading>
1112         <query>SELECT MIN(incumbent_bib_score), MAX(incumbent_bib_score), 'Incumbent Records' FROM bib_matches 
1113             UNION ALL SELECT MIN(incoming_bib_score), MAX(incoming_bib_score), 'Incoming Records' FROM bib_matches ;
1114         </query>
1115     </report>
1116     
1117     
1118     <report>
1119         <name>dedupe_sample_set</name>
1120         <tag>dedupe</tag>
1121         <iteration>0</iteration>
1122         <report_title>Sample of 20 Matching Dedupe Record Sets</report_title>
1123         <heading>Bib Being Merged Into.Bib Being Merged</heading>
1124         <query>SELECT incumbent_bib, incoming_bib FROM bib_matches WHERE incumbent_bib_score &gt;= incoming_bib_score LIMIT 20 ;
1125         </query>
1126     </report>
1127
1128     <!-- NOTICES REPORTS -->
1129
1130     <report>
1131         <name>notices_overview</name>
1132         <tag>notices</tag>
1133         <iteration>0</iteration>
1134         <report_title>Action Triggers Setup for Notices</report_title>
1135         <heading>ID.Active.Owner.Name</heading>
1136         <query>SELECT ed.id, ed.active, aou.shortname, ed.name
1137             FROM action_trigger.event_definition ed 
1138             JOIN actor.org_unit aou ON aou.id = ed.owner 
1139             WHERE ed.owner IN (SELECT DISTINCT home_ou FROM m_actor_usr)
1140             OR ed.owner IN (SELECT DISTINCT parent_ou FROM actor.org_unit WHERE id in (SELECT DISTINCT home_ou FROM m_actor_usr));
1141         </query>
1142     </report>
1143
1144     <report>
1145         <name>notices_count</name>
1146         <tag>notices</tag>
1147         <iteration>0</iteration>
1148         <report_title>Count of Notices Run with State</report_title>
1149         <heading>Count of Notices.State.ID.Owner.Name</heading>
1150         <query>SELECT COUNT(ate.id), ate.state, ed.id, aou.shortname, ed.name 
1151             FROM action_trigger.event_definition ed 
1152             JOIN actor.org_unit aou ON aou.id = ed.owner 
1153             JOIN action_trigger.event ate ON ate.event_def = ed.id 
1154             WHERE ed.owner IN (SELECT DISTINCT home_ou FROM m_actor_usr)
1155             OR ed.owner IN (SELECT DISTINCT parent_ou FROM actor.org_unit WHERE id in (SELECT DISTINCT home_ou FROM m_actor_usr))
1156             GROUP BY 2,3,4;
1157         </query>
1158     </report>
1159
1160
1161 </reports_file>
1162