ca0d47c85757eec5ff583464ddc16ca4fa4df322
[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
30 <!-- sample reports entry
31     <report>
32         <name>name of report</name>
33         <iteration value='0' /> which version, the first version to run is 0, first backup is 1, then so on
34         <tag>money</tag>  arbitrary tags, each should go in separate tag
35         <report_title>Migrated Billings</report_title>  title used in the asciidoc output
36         <heading column='1'>Number of Billings.Migrated.Total</heading> period delimited 
37         <query>SELECT COUNT(id),x_migrate::TEXT,SUM(amount) FROM money_billing_legacy GROUP BY 2;</query>  query itself, will be replaced
38         <note>Arbitrary note that can be included in the entries.</note>
39     </report>
40 -->
41
42     <!-- CIRC REPORTS -->
43     <report>
44         <name>circ_count</name>
45         <tag>circs</tag>
46         <iteration>0</iteration>
47         <report_title>Migrated Circulations</report_title>
48         <heading>Circulation Status.Count of Circs</heading>
49         <query>SELECT 'Closed Circulations', COUNT(id) FROM action_circulation_legacy WHERE xact_finish IS NOT NULL AND x_migrate 
50             UNION ALL SELECT 'Open Circulations', COUNT(id) FROM action_circulation_legacy WHERE xact_finish IS NULL AND x_migrate</query>
51     </report>
52
53     <report>
54         <name>circ_count_unmigrated</name>
55         <tag>circs</tag>
56         <iteration>0</iteration>
57         <report_title>Open Un-migrated Circulations</report_title>
58         <heading>Circulation Status.Count of Circs</heading>
59         <query>SELECT 'No Matching User', COUNT(id) FROM action_circulation_legacy WHERE xact_finish IS NULL AND x_migrate = FALSE AND usr IS NULL 
60                 UNION ALL SELECT 'No Matching Item', COUNT(id) FROM action_circulation_legacy WHERE xact_finish IS NULL AND x_migrate = FALSE AND target_copy IS NULL </query>
61     </report>
62
63     <report>
64         <name>circ_count</name>
65         <tag>circs</tag>
66         <iteration>1</iteration>
67         <report_title>Open Circulations</report_title>
68         <heading>Circulation Status.Count of Circs</heading>
69         <query>SELECT 'Closed Circulations', COUNT(id) FROM action_circulation WHERE xact_finish IS NOT NULL UNION ALL SELECT 'Open Circulations', COUNT(id) FROM action_circulation WHERE xact_finish IS NULL</query>
70     </report>
71 <!-- intent is to add a report by circulated and item status
72     <report>
73         <name>circ_count_by_item_status</name>
74         <tag>circs</tag>
75         <iteration>0</iteration>
76         <report_title>Open Circulations</report_title>
77         <heading>Circulation Status.Migrated.Count of Circs</heading>
78         <query>SELECT 'Closed Circulations', x_migrate::TEXT, COUNT(id) FROM action_circulation_legacy WHERE xact_finish IS NOT NULL GROUP BY 2 UNION ALL SELECT 'Open Circulations', x_migrate::TEXT, COUNT(id) FROM action_circulation_legacy WHERE xact_finish IS NULL GROUP BY 2</query>
79     </report>
80 -->
81      <report>
82         <name>circ_by_orgunit</name>
83         <tag>circs</tag>
84         <iteration>0</iteration>
85         <report_title>Circulations by Org Unit</report_title>
86         <heading>Circulations Count.Migrated.Org Unit</heading>
87         <query>SELECT COUNT(acirc.id), acirc.x_migrate::TEXT, aou.name FROM action_circulation_legacy acirc JOIN actor.org_unit aou ON aou.id = acirc.circ_lib WHERE acirc.xact_finish IS NULL GROUP BY 2, 3</query>
88     </report>
89
90      <report>
91         <name>circ_by_orgunit</name>
92         <tag>circs</tag>
93         <iteration>1</iteration>
94         <report_title>Circulations by Org Unit</report_title>
95         <heading>Circulations Count.Org Unit</heading>
96         <query>SELECT COUNT(acirc.id), aou.name FROM action_circulation acirc JOIN actor.org_unit aou ON aou.id = acirc.circ_lib WHERE acirc.xact_finish IS NULL GROUP BY 2</query>
97     </report>
98
99      <report>
100         <name>circs_by_duration</name>
101         <tag>circs</tag>
102         <iteration>0</iteration>
103         <report_title>Migrated Circulations by Duration, Fine and Max Fine</report_title>
104         <heading>Count of Circs.Duration.Fine.Max Fine.Migrated</heading>
105         <query>SELECT COUNT(id), duration, recurring_fine, max_fine, x_migrate::TEXT FROM action_circulation_legacy WHERE x_migrate = TRUE GROUP BY 2, 3, 4, 5</query>
106     </report>
107
108      <report>
109         <name>circs_by_duration</name>
110         <tag>circs</tag>
111         <iteration>1</iteration>
112         <report_title>Circulations by Duration, Fine and Max Fine</report_title>
113         <heading>Count of Circs.Duration.Fine.Max Fine</heading>
114         <query>SELECT COUNT(id), duration, recurring_fine, max_fine FROM action_circulation GROUP BY 2, 3, 4 ORDER BY 2, 3, 4</query>
115     </report>
116
117      <report>
118         <name>circs_by_usrgroup</name>
119         <tag>circs</tag>
120         <iteration>0</iteration>
121         <report_title>Circulations by Rules and Patron Group</report_title>
122         <heading>Count of Circs.Duration.Fine.Max Fine.User Group.Matchpoints</heading>
123         <query>SELECT COUNT(acirc.id), acirc.duration, acirc.recurring_fine, acirc.max_fine, pgt.name, x.buildrows FROM 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 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>
124     </report>
125
126      <report>
127         <name>circs_by_usrgroup</name>
128         <tag>circs</tag>
129         <iteration>1</iteration>
130         <report_title>Circulations by Rules and Patron Group</report_title>
131         <heading>Count of Circs.Duration.Fine.Max Fine.User Group.Matchpoints</heading>
132         <query>SELECT COUNT(acirc.id), acirc.duration, acirc.recurring_fine, acirc.max_fine, pgt.name, x.buildrows FROM 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 action_circulation acirc) x ON x.id = acirc.id GROUP BY 2, 3, 4, 5, 6 ORDER BY 2, 3, 4, 5, 6</query>
133     </report>
134
135      <report>
136         <name>circs_by_circmod</name>
137         <tag>circs</tag>
138         <iteration>0</iteration>
139         <report_title>Circulations by Rules and Circulation Modifier</report_title>
140         <heading>Count of Circs.Duration.Fine.Max Fine.Circulation Modifier.Matchpoints</heading>
141         <query>SELECT COUNT(acirc.id), acirc.duration, acirc.recurring_fine, acirc.max_fine, ac.circ_modifier, x.buildrows FROM 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 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>
142     </report>
143
144      <report>
145         <name>circs_by_circmod</name>
146         <tag>circs</tag>
147         <iteration>1</iteration>
148         <report_title>Circulations by Rules and Circulation Modifier</report_title>
149         <heading>Count of Circs.Duration.Fine.Max Fine.Circulation Modifier.Matchpoints</heading>
150         <query>SELECT COUNT(acirc.id), acirc.duration, acirc.recurring_fine, acirc.max_fine, ac.circ_modifier, x.buildrows FROM 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 action_circulation acirc) x ON x.id = acirc.id
151              GROUP BY 2, 3, 4, 5, 6 ORDER BY 2, 3, 4, 5, 6</query>
152     </report>
153
154      <report>
155         <name>circs_by_orgunit</name>
156         <tag>circs</tag>
157         <iteration>0</iteration>
158         <report_title>Circulations by Rules and Org Unit</report_title>
159         <heading>Count of Circs.Duration.Fine.Max Fine.Library Branch</heading>
160         <query>SELECT COUNT(acirc.id), acirc.duration, acirc.recurring_fine, acirc.max_fine, aou.name FROM 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>
161     </report>
162
163      <report>
164         <name>circs_by_orgunit</name>
165         <tag>circs</tag>
166         <iteration>1</iteration>
167         <report_title>Circulations by Rules and Org Unit</report_title>
168         <heading>Count of Circs.Duration.Fine.Max Fine.Library Branch</heading>
169         <query>SELECT COUNT(acirc.id), acirc.duration, acirc.recurring_fine, acirc.max_fine, aou.name FROM 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>
170     </report>
171
172      <report>
173         <name>non_cat_circs</name>
174         <tag>circs</tag>
175         <iteration>0</iteration>
176         <report_title>Non-Cataloged Circulation</report_title>
177         <heading>Circulations Count.Migrated</heading>
178         <query>SELECT COUNT(id), x_migrate::TEXT FROM action_non_cataloged_circulation_legacy GROUP BY 2</query>
179     </report>
180
181      <report>
182         <name>non_cat_circs</name>
183         <tag>circs</tag>
184         <iteration>1</iteration>
185         <report_title>Non-Cataloged Circulation</report_title>
186         <heading>Circulations Count</heading>
187         <query>SELECT COUNT(id) FROM action_non_cataloged_circulation</query>
188     </report>
189
190      <report>
191         <name>in_house</name>
192         <tag>circs</tag>
193         <iteration>0</iteration>
194         <report_title>In House Use</report_title>
195         <heading>In House Use Records.Migrated</heading>
196         <query>SELECT COUNT(id), x_migrate::TEXT FROM action_in_house_use_legacy GROUP BY 2</query>
197     </report>
198
199      <report>
200         <name>in_house</name>
201         <tag>circs</tag>
202         <iteration>1</iteration>
203         <report_title>In House Use</report_title>
204         <heading>In House Use Records</heading>
205         <query>SELECT COUNT(id) FROM action_in_house_use</query>
206     </report>
207
208      <report>
209         <name>circs_missing_rules</name>
210         <tag>circs</tag>
211         <iteration>1</iteration>
212         <report_title>Circs Missing Rules</report_title>
213         <heading>Count.Field Missing</heading>
214         <query>SELECT COUNT(id), 'Duration Rule Value' FROM action_circulation WHERE duration IS NULL 
215             UNION ALL SELECT COUNT(id), 'Recurring Fine Rule Value' FROM action_circulation WHERE recurring_fine IS NULL 
216             UNION ALL SELECT COUNT(id), 'Max Fine Rule Value' FROM action_circulation WHERE max_fine IS NULL
217             UNION ALL SELECT COUNT(id), 'Duration Rule' FROM action_circulation WHERE duration_rule IS NULL       
218             UNION ALL SELECT COUNT(id), 'Recurring Fine Rule' FROM action_circulation WHERE recurring_fine_rule IS NULL      
219             UNION ALL SELECT COUNT(id), 'Max Fine Rule' FROM action_circulation WHERE max_fine_rule IS NULL
220         </query>
221     </report>
222
223      <report>
224         <name>circ_open_by_item_status</name>
225         <tag>circs</tag>
226         <iteration>0</iteration>
227         <report_title>Open Circulation and Status of Linked Items</report_title>
228         <heading>Count.Status</heading>
229         <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 action_circulation) GROUP BY 2 ORDER BY 2</query>
230     </report>
231
232     <!-- HOLDS REPORTS -->
233
234      <report>
235         <name>holds</name>
236         <tag>holds</tag>
237         <iteration>0</iteration>
238         <report_title>Migrated Holds</report_title>
239         <heading>Hold Type.Hold Count.Migrated</heading>
240         <query>SELECT 'Closed Holds', COUNT(id), x_migrate::TEXT FROM 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 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>
241     </report>
242
243      <report>
244         <name>holds_bytype</name>
245         <tag>holds</tag>
246         <iteration>0</iteration>
247         <report_title>Migrated Holds By Type</report_title>
248         <heading>Hold Type.Hold Count.Migrated</heading>
249         <query>SELECT hold_type as "Hold Type", COUNT(id), x_migrate::TEXT FROM action_hold_request_legacy GROUP BY 1, 3</query>
250     </report>
251
252      <report>
253         <name>transit_open_by_item_status</name>
254         <tag>holds</tag>
255         <iteration>0</iteration>
256         <report_title>Transit Copy Records and Status of Linked Items</report_title>
257         <heading>Count.Status</heading>
258         <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 action_transit_copy) AND atc.dest_recv_time IS NULL GROUP BY 2 ORDER BY 2</query>
259     </report>
260
261      <report>
262         <name>transit_copies_by_status</name>
263         <tag>holds</tag>
264         <iteration>0</iteration>
265         <report_title>Status of Items with Count of Open In Transits</report_title>
266         <heading>Count.Status.Count of Open Transits</heading>
267         <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 action_transit_copy) AND dest_recv_time IS NULL) atc ON atc.target_copy = ac.id WHERE ac.id IN (SELECT id from asset_copy) GROUP BY 2 ORDER BY 2</query>
268     </report>
269     
270      <report>
271         <name>hold_copies_by_status</name>
272         <tag>holds</tag>
273         <iteration>0</iteration>
274         <report_title>Captured Holds with Status of Items</report_title>
275         <heading>Count of Captured Hold.Status of Item</heading>
276         <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 action_hold_request) GROUP BY 2 ORDER By 2</query>
277     </report>
278
279       <report>
280         <name>hold_depth</name>
281         <tag>holds</tag>
282         <iteration>0</iteration>
283         <report_title>Depth of Unfilled Holds</report_title>
284         <heading>Count.Depth</heading>
285         <query>SELECT COUNT(ahr.id), ahr.selection_depth FROM action.hold_request ahr WHERE ahr.id IN (SELECT id FROM 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>
286     </report>
287
288     <!-- ASSET REPORTS -->
289     
290     <report>
291         <name>asset_copy_count</name>
292         <report_title>Count of Copies by Library</report_title>
293         <tag>assets</tag>
294         <iteration>0</iteration>
295         <heading>Copy Count.Library.Migrated</heading>
296         <query>SELECT COUNT(ac.id), aou.name, ac.x_migrate::TEXT FROM asset_copy_legacy ac JOIN actor.org_unit aou ON aou.id = ac.circ_lib GROUP BY 2, 3 ORDER BY 2, 3</query>
297     </report>
298
299     <report>
300         <name>asset_deleted_copies</name>
301         <report_title>Deleted Copies</report_title>
302         <tag>assets</tag>
303         <iteration>0</iteration>
304         <heading>Copy Count.Deleted.Migrated</heading>
305         <query>SELECT COUNT(ac.id), ac.deleted::TEXT, ac.x_migrate::TEXT FROM asset_copy_legacy ac GROUP BY 2, 3</query>
306     </report>
307
308     <report>
309         <name>asset_copies_by_status</name>
310         <report_title>Copies by Status</report_title>
311         <tag>assets</tag>
312         <iteration>0</iteration>
313         <heading>Copy Count.Status.Migrated</heading>
314         <query>SELECT COUNT(ac.id), cs.name, ac.x_migrate::TEXT FROM asset_copy_legacy ac JOIN config.copy_status cs ON cs.id = ac.status GROUP BY 2, 3 ORDER BY 2, 3</query>
315     </report>
316
317     <report>
318         <name>asset_precat</name>
319         <report_title>Precats (AKA Copies Without Bibs)</report_title>
320         <tag>assets</tag>
321         <iteration>0</iteration>
322         <heading>Copy Count.Migating</heading>
323         <query>SELECT COUNT(ac.id), ac.x_migrate::TEXT FROM asset_copy_legacy ac WHERE ac.x_bre_id = -1 GROUP BY 2</query>
324     </report>
325
326     <report>
327         <name>asset_circ_mod_copies_count</name>
328         <report_title>Copies by Circulation Modifier</report_title>
329         <tag>assets</tag>
330         <iteration>0</iteration>
331         <heading>Copy Count.Circulation Modifier.Migrated</heading>
332         <query>SELECT COUNT(ac.id), ac.circ_modifier, ac.x_migrate::TEXT FROM asset_copy_legacy ac GROUP BY 2, 3 ORDER BY 2, 3</query>
333     </report>
334
335     <report>
336         <name>asset_copy_notes</name>
337         <report_title>Copy Notes</report_title>
338         <tag>assets</tag>
339         <iteration>0</iteration>
340         <heading>Note Count.Public.Migrated</heading>
341         <query>SELECT COUNT(acnote.id), acnote.pub::TEXT, acnote.x_migrate::TEXT FROM asset_copy_note_legacy acnote GROUP BY 2, 3 ORDER BY 2, 3</query>
342     </report>
343
344     <report>
345         <name>asset_copy_notes</name>
346         <report_title>Copy Notes</report_title>
347         <tag>assets</tag>
348         <iteration>1</iteration>
349         <heading>Note Count.Public</heading>
350         <query>SELECT COUNT(acnote.id), acnote.pub::TEXT FROM asset_copy_note acnote GROUP BY 2 ORDER BY 2</query>
351     </report>
352
353    <report>
354         <name>asset_vols_by_lib</name>
355         <report_title>Volumes by Library</report_title>
356         <tag>assets</tag>
357         <iteration>0</iteration>
358         <heading>Volume Count.Library.Migrated</heading>
359         <query>SELECT COUNT(acn.id), aou.name, acn.x_migrate::TEXT FROM asset_call_number_legacy acn JOIN actor_org_unit_legacy aou ON aou.id = acn.owning_lib GROUP BY 2, 3 ORDER BY 2, 3</query>
360     </report>
361
362    <report>
363         <name>asset_vols_by_lib</name>
364         <report_title>Volumes by Library</report_title>
365         <tag>assets</tag>
366         <iteration>1</iteration>
367         <heading>Volume Count.Library</heading>
368         <query>SELECT COUNT(acn.id), aou.name FROM asset_call_number acn JOIN actor.org_unit aou ON aou.id = acn.owning_lib GROUP BY 2 ORDER BY 2</query>
369     </report>
370     <!--
371    <report>
372         <name>asset_cops_by_loc</name>
373         <report_title>Copies by Location</report_title>
374         <tag>assets</tag>
375         <iteration>0</iteration>
376         <heading>Copy Count.Library.Migrated</heading>
377         <query>SELECT COUNT(ac.id), acl.name, ac.x_migrate::TEXT FROM asset_copy_legacy ac JOIN asset.copy_location acl ON acl.id = ac.location GROUP BY 2, 3 ORDER BY 2, 3</query>
378     </report>
379    -->
380    <report>
381         <name>asset_cops_by_loc_and_org</name>
382         <report_title>Copies by Location</report_title>
383         <tag>assets</tag>
384         <iteration>0</iteration>
385         <heading>Copy Count.Library.Circ Library.Migrated</heading>
386         <query>SELECT COUNT(ac.id), acl.name, aou.name, ac.x_migrate::TEXT FROM 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 GROUP BY 2, 3, 4 ORDER BY 2, 3, 4</query>
387     </report>
388
389     <report>
390         <name>asset_barcode_lengths</name>
391         <report_title>Barcode Lengths by Library</report_title>
392         <tag>assets</tag>
393         <iteration>0</iteration>
394         <heading>Count of Barcode.Barcode Length.Library</heading>
395         <query>SELECT COUNT(ac.id), LENGTH(ac.barcode), aou.name FROM asset_copy_legacy ac JOIN actor.org_unit aou ON aou.id = ac.circ_lib WHERE ac.x_migrate = TRUE GROUP BY 2, 3 ORDER BY 3, 2</query>
396     </report>
397
398     <report>
399         <name>asset_barcode_patterns</name>
400         <report_title>Common Barcode Starting Patterns</report_title>
401         <tag>assets</tag>
402         <iteration>0</iteration>
403         <heading>Count of Barcodes (greater than 10).Left 60% of Characters</heading>
404         <query>SELECT COUNT(ac.id), LEFT(ac.barcode,(ROUND(LENGTH(ac.barcode)*.6))::INT) FROM asset_copy_legacy ac WHERE ac.x_migrate = TRUE GROUP BY 2 HAVING COUNT(ac.id) > 10 ORDER BY 2</query>
405     </report>
406
407     <report>
408         <name>asset_barcode_incumbent_collisions</name>
409         <report_title>Copy Barcode Incumbent Collisions</report_title>
410         <tag>assets</tag>
411         <iteration>0</iteration>
412         <heading>Collision Count</heading>
413         <query>SELECT COUNT(id) FROM asset_copy_legacy WHERE x_migrate = TRUE AND barcode ~* 'collision' and barcode ~* 'incumbent'</query>
414         <note>Incumbent collisions are those where the migrated barcodes collide with existing barcodes in the database.</note>
415     </report>
416
417     <report>
418         <name>asset_barcode_incumbent_collisions</name>
419         <report_title>Copy Barcode Incumbent Collisions</report_title>
420         <tag>assets</tag>
421         <iteration>1</iteration>
422         <heading>Collision Count</heading>
423         <query>SELECT COUNT(id) FROM asset_copy WHERE barcode ~* 'collision' and barcode ~* 'incumbent'</query>
424         <note>Incumbent collisions are those where the migrated barcodes collide with existing barcodes in the database.</note>
425     </report>
426
427     <report>
428         <name>asset_barcode_internal_collisions</name>
429         <report_title>Copy Barcode Internal Collisions</report_title>
430         <tag>assets</tag>
431         <iteration>0</iteration>
432         <heading>Collision Count</heading>
433         <query>SELECT COUNT(id) FROM asset_copy_legacy WHERE x_migrate = TRUE AND barcode ~* 'collision' and barcode ~* 'internal'</query>
434         <note>Internal collisions are those where the migrated barcodes have conflicts within their list of barcodes.</note>
435     </report>
436
437     <report>
438         <name>asset_barcode_internal_collisions</name>
439         <report_title>Copy Barcode Internal Collisions</report_title>
440         <tag>assets</tag>
441         <iteration>1</iteration>
442         <heading>Collision Count</heading>
443         <query>SELECT COUNT(id) FROM asset_copy WHERE barcode ~* 'collision' and barcode ~* 'internal'</query>
444         <note>Internal collisions are those where the migrated barcodes have conflicts within their list of barcodes.</note>
445     </report>
446
447     <report>
448         <name>asset_barcode_collisions_shortlist</name>
449         <report_title>Copy Barcode Collisions (first 20)</report_title>
450         <tag>assets</tag>
451         <iteration>0</iteration>
452         <heading>Collision List</heading>
453         <query>SELECT ac.barcode FROM asset_copy_legacy ac WHERE ac.barcode ~* 'collision' ORDER BY 1 LIMIT 20</query>
454         <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>
455     </report>
456
457     <report>
458         <name>asset_barcode_collisions_shortlist</name>
459         <report_title>Copy Barcode Collisions (first 20)</report_title>
460         <tag>assets</tag>
461         <iteration>1</iteration>
462         <heading>Collision List</heading>
463         <query>SELECT ac.barcode FROM asset_copy ac WHERE ac.barcode ~* 'collision' ORDER BY 1 LIMIT 20</query>
464         <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>
465     </report>
466
467     <report>
468         <name>asset_barcode_collision_patterns</name>
469         <report_title>Common Copy Barcode Collision Patterns</report_title>
470         <tag>assets</tag>
471         <iteration>0</iteration>
472         <heading>Number of Barcodes Matching Pattern Greater than 10.Left 60% of Characters</heading>
473         <query>SELECT COUNT(ac.id), LEFT(ac.barcode,(ROUND(LENGTH(ac.barcode)*.6))::INT) FROM asset_copy_legacy ac WHERE barcode ~* 'collision' GROUP BY 2 HAVING COUNT(ac.id) > 10 ORDER BY 2</query>
474     </report>
475
476     <report>
477         <name>asset_barcode_collision_patterns</name>
478         <report_title>Common Copy Barcode Collision Patterns</report_title>
479         <tag>assets</tag>
480         <iteration>1</iteration>
481         <heading>Number of Barcodes Matching Pattern Greater than 10.Left 60% of Characters</heading>
482         <query>SELECT COUNT(ac.id), LEFT(ac.barcode,(ROUND(LENGTH(ac.barcode)*.6))::INT) FROM asset_copy ac WHERE barcode ~* 'collision' GROUP BY 2 HAVING COUNT(ac.id) > 10 ORDER BY 2</query>
483     </report>
484
485     <report>
486          <name>asset_stat_cats</name>
487         <report_title>Copy Statistical Categories</report_title>
488         <tag>assets</tag>
489         <iteration>0</iteration>
490         <heading>Stat Cat Count.Library.Statistical Category</heading>
491         <query>SELECT COUNT(ac_sc.id), aou.name, ac_sc.name FROM 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>
492     </report>
493
494     <report>
495          <name>asset_stat_cats</name>
496         <report_title>Copy Statistical Categories</report_title>
497         <tag>assets</tag>
498         <iteration>1</iteration>
499         <heading>Stat Cat Count.Library.Statistical Category</heading>
500         <query>SELECT COUNT(ac_sc.id), aou.name, ac_sc.name FROM 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>
501     </report>
502
503     <report>
504         <name>asset_stat_cat_entries</name>
505         <report_title>Copy Stat Cat User Entries</report_title>
506         <tag>assets</tag>
507         <iteration>0</iteration>
508         <heading>Copy Stat Count.Library.Statistical Category</heading>
509         <query>SELECT COUNT(map.id), aou.name, ac_sc.name FROM asset_stat_cat_entry_copy_map_legacy map JOIN 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>
510     </report>
511
512     <report>
513         <name>asset_stat_cat_entries</name>
514         <report_title>Copy Stat Cat User Entries</report_title>
515         <tag>assets</tag>
516         <iteration>1</iteration>
517         <heading>Copy Stat Count.Library.Statistical Category</heading>
518         <query>SELECT COUNT(map.id), aou.name, ac_sc.name FROM asset_stat_cat_entry_copy_map map JOIN asset_stat_cat ac_sc ON ac_sc.id = map.stat_cat JOIN actor.org_unit aou ON aou.
519 id = ac_sc.owner GROUP BY 2,3 ORDER BY 2,3</query>
520     </report>
521
522     <report>
523          <name>asset_copy_tags</name>
524         <report_title>Copy Tags</report_title>
525         <tag>assets</tag>
526         <iteration>0</iteration>
527         <heading>Tag Count.Copy Tag Type.Copy Tag Label.Staff Note.Public</heading>
528         <query>SELECT COUNT(map.id), tag.tag_type, tag.label, tag.staff_note, tag.pub FROM asset_copy_tag tag JOIN asset_copy_tag_copy_map map ON map.tag = tag.id GROUP BY 2,3,4,5 ORDER BY 2,3</query>
529     </report>
530
531     <!-- MONEY REPORTS -->
532
533     <report>
534         <name>money_billing_voided</name>
535         <report_title>Bills Voided And Not</report_title>
536         <tag>money</tag>
537         <iteration>0</iteration>
538         <heading>Count.Voided.Sum.Migrated</heading>
539         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount), a.x_migrate::TEXT FROM money_billing_legacy a GROUP BY 2, 4 ORDER BY 2, 4</query>
540     </report>
541
542     <report>
543         <name>money_billing_voided</name>
544         <report_title>Bills Voided And Not</report_title>
545         <tag>money</tag>
546         <iteration>1</iteration>
547         <heading>Count.Voided.Sum</heading>
548         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount) FROM money_billing a GROUP BY 2 ORDER BY 2, 3</query>
549     </report>
550
551     <report>
552         <name>money_billing_by_type</name>
553         <report_title>Bills by Type</report_title>
554         <tag>money</tag>
555         <iteration>0</iteration>
556         <heading>Count.Billing Type.Migrated</heading>
557         <query>SELECT COUNT(a.id), a.billing_type, a.x_migrate::TEXT FROM money_billing_legacy a GROUP BY 2, 3 ORDER BY 2, 3</query>
558     </report>
559
560     <report>
561         <name>money_billing_by_type</name>
562         <report_title>Bills by Type</report_title>
563         <tag>money</tag>
564         <iteration>1</iteration>
565         <heading>Count.Billing Type</heading>
566         <query>SELECT COUNT(a.id), a.billing_type FROM money_billing a GROUP BY 2 ORDER BY 2</query>
567     </report>
568
569     <report>
570         <name>money_cash_payment</name>
571         <report_title>Cash Payments</report_title>
572         <tag>money</tag>
573         <iteration>0</iteration>
574         <heading>Count.Voided.Sum.Migrated</heading>
575         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount), a.x_migrate::TEXT FROM money_cash_payment_legacy a GROUP BY 2, 4 ORDER BY 2, 4</query>
576     </report>
577
578     <report>
579         <name>money_cash_payment</name>
580         <report_title>Cash Payments</report_title>
581         <tag>money</tag>
582         <iteration>1</iteration>
583         <heading>Count.Voided.Sum</heading>
584         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount) FROM money_cash_payment a GROUP BY 2 ORDER BY 2</query>
585     </report>
586
587     <report>
588         <name>money_check_payment</name>
589         <report_title>Check Payments</report_title>
590         <tag>money</tag>
591         <iteration>0</iteration>
592         <heading>Count.Voided.Sum.Migrated</heading>
593         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount), a.x_migrate::TEXT FROM money_check_payment_legacy a GROUP BY 2, 4 ORDER BY 2, 4</query>
594     </report>
595
596     <report>
597         <name>money_forgive_payment</name>
598         <report_title>Forgive Payments</report_title>
599         <tag>money</tag>
600         <iteration>0</iteration>
601         <heading>Count.Voided.Sum.Migrated</heading>
602         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount), a.x_migrate::TEXT FROM money_forgive_payment_legacy a GROUP BY 2, 4 ORDER BY 2, 4</query>
603     </report>
604
605     <report>
606         <name>money_forgive_payment</name>
607         <report_title>Forgive Payments</report_title>
608         <tag>money</tag>
609         <iteration>1</iteration>
610         <heading>Count.Voided.Sum</heading>
611         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount) FROM money_forgive_paymen a GROUP BY 2 ORDER BY 2</query>
612     </report>
613
614     <report>
615         <name>money_goods_payment</name>
616         <report_title>Goods Payments</report_title>
617         <tag>money</tag>
618         <iteration>0</iteration>
619         <heading>Count.Voided.Sum.Migrated</heading>
620         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount), a.x_migrate::TEXT FROM money_goods_payment_legacy a GROUP BY 2, 4 ORDER BY 2, 4</query>
621     </report>
622
623     <report>
624         <name>money_work_payment</name>
625         <report_title>Work Payments</report_title>
626         <tag>money</tag>
627         <iteration>0</iteration>
628         <heading>Count.Voided.Sum.Migrated</heading>
629         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount), a.x_migrate::TEXT FROM money_work_payment_legacy a GROUP BY 2, 4 ORDER BY 2, 4</query>
630     </report>
631
632     <report>
633         <name>money_credit_card_payment</name>
634         <report_title>Credit Card Payments</report_title>
635         <tag>money</tag>
636         <iteration>0</iteration>
637         <heading>Count.Voided.Sum.Migrated</heading>
638         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount), a.x_migrate::TEXT FROM money_credit_card_payment_legacy a GROUP BY 2, 4 ORDER BY 2, 4</query>
639     </report>
640
641     <report>
642         <name>money_credit_payment</name>
643         <report_title>Credit Payments</report_title>
644         <tag>money</tag>
645         <iteration>0</iteration>
646         <heading>Count.Voided.Sum.Migrated</heading>
647         <query>SELECT COUNT(a.id), a.voided::TEXT, SUM(a.amount), a.x_migrate::TEXT FROM money_credit_payment_legacy a GROUP BY 2, 4 ORDER BY 2, 4</query>
648     </report>
649
650
651     <!-- BIBS REPORTS -->
652
653     <report>
654         <name>bibs</name>
655         <report_title>Extracted Bibliographic Records</report_title>
656         <tag>bibs</tag>
657         <iteration>0</iteration>
658         <heading>Count.Sourcee.Migrated</heading>
659         <query>SELECT COUNT(bre.id), bre.x_source, bre.x_migrate::TEXT FROM biblio_record_entry_legacy bre GROUP BY 2, 3 ORDER BY 2, 3</query>
660         <note>False means the records are not deleted.</note>
661     </report>
662
663     <report>
664         <name>bibswovolumes</name>
665         <report_title>Bibliographic Records Without Volumes</report_title>
666         <tag>bibs</tag>
667         <iteration>0</iteration>
668         <heading>Count</heading>
669         <query>SELECT COUNT(id) FROM biblio_record_entry where id NOT IN (SELECT DISTINCT record FROM asset_call_number)</query>
670     </report>
671
672     <report>
673         <name>bibs_notes</name>
674         <report_title>Bib Record Notes</report_title>
675         <tag>bibs</tag>
676         <iteration>0</iteration>
677         <heading>Count.Migrated</heading>
678         <query>SELECT COUNT(b.id), b.x_migrate::TEXT FROM biblio_record_note_legacy b GROUP BY 2</query>
679     </report>
680
681     <report>
682         <name>bibs_notes</name>
683         <report_title>Bib Record Notes</report_title>
684         <tag>bibs</tag>
685         <iteration>1</iteration>
686         <heading>Count</heading>
687         <query>SELECT COUNT(b.id) FROM biblio_record_note b</query>
688     </report>
689
690     <report>
691         <name>bibs_peers</name>
692         <report_title>Peer Bib Copies</report_title>
693         <tag>bibs</tag>
694         <iteration>0</iteration>
695         <heading>Count.Migrated</heading>
696         <query>SELECT COUNT(b.id), b.x_migrate::TEXT FROM biblio_peer_bib_copy_map_legacy b GROUP BY 2</query>
697     </report>
698
699     <report>
700         <name>bibs_peers</name>
701         <report_title>Peer Bib Copies</report_title>
702         <tag>bibs</tag>
703         <iteration>1</iteration>
704         <heading>Count</heading>
705         <query>SELECT COUNT(b.id) FROM biblio_peer_bib_copy_map b</query>
706     </report>
707
708     <report>
709         <name>bibs_parts</name>
710         <report_title>Monograph Parts</report_title>
711         <tag>bibs</tag>
712         <iteration>0</iteration>
713         <heading>Count.Migrated</heading>
714         <query>SELECT COUNT(b.id), b.x_migrate::TEXT FROM biblio_monograph_part_legacy b GROUP BY 2</query>
715     </report>
716
717     <report>
718         <name>bibs_parts</name>
719         <report_title>Monograph Parts</report_title>
720         <tag>bibs</tag>
721         <iteration>1</iteration>
722         <heading>Count</heading>
723         <query>SELECT COUNT(b.id) FROM biblio_monograph_part b</query>
724     </report>
725
726     <!-- ACTORS REPORTS -->
727
728     <report>
729         <name>usrsbyorg</name>
730         <report_title>Patrons by Home Org</report_title>
731         <tag>actors</tag>
732         <iteration>0</iteration>
733         <heading>Count.Library.Deleted.Migrated</heading>
734         <query>SELECT COUNT(au.id), aou.name, au.deleted::TEXT, au.x_migrate::TEXT FROM actor_usr_legacy au JOIN actor.org_unit aou ON aou.id = au.home_ou GROUP BY 2, 3, 4 ORDER BY 2, 3, 4</query>
735     </report>
736
737     <report>
738         <name>usrsbypgt</name>
739         <report_title>Patrons by Permission Group</report_title>
740         <tag>actors</tag>
741         <iteration>0</iteration>
742         <heading>Count.Permission Group.Migrated</heading>
743         <query>SELECT COUNT(au.id), pgt.name, au.x_migrate::TEXT FROM actor_usr_legacy au JOIN permission.grp_tree pgt ON pgt.id = au.profile GROUP BY 2, 3 ORDER BY 2, 3</query>
744     </report>
745
746     <report>
747         <name>active_usrs</name>
748         <report_title>Patron by Active Status</report_title>
749         <tag>actors</tag>
750         <iteration>0</iteration>
751         <heading>Count of Users.Active.Migrated</heading>
752         <query>SELECT COUNT(id), active::TEXT, x_migrate::TEXT FROM actor_usr_legacy GROUP BY 2, 3</query>
753     </report>
754
755     <report>
756         <name>active_usrs</name>
757         <report_title>Patrons by Active Status</report_title>
758         <tag>actors</tag>
759         <iteration>1</iteration>
760         <heading>Count of Users.Active</heading>
761         <query>SELECT COUNT(id), active::TEXT FROM actor_usr GROUP BY 2</query>
762     </report>
763
764     <report>
765         <name>active_usr_barcodes</name>
766         <report_title>Patron Barcodes by Active Status</report_title>
767         <tag>actors</tag>
768         <iteration>0</iteration>
769         <heading>Count of Barcodes.Active.Migrated</heading>
770         <query>SELECT COUNT(id), active::TEXT, x_migrate::TEXT FROM actor_card_legacy GROUP BY 2, 3</query>
771     </report>
772
773     <report>
774         <name>active_usr_barcodes</name>
775         <report_title>Patron Barcodes by Active Status</report_title>
776         <tag>actors</tag>
777         <iteration>1</iteration>
778         <heading>Count of Barcodes.Active</heading>
779         <query>SELECT COUNT(id), active::TEXT FROM actor_card GROUP BY 2</query>
780     </report>
781
782     <report>
783         <name>usr_barcode_lengths</name>
784         <report_title>Barcode Lengths by Library</report_title>
785         <tag>actors</tag>
786         <iteration>0</iteration>
787         <heading>Count of Barcode.Barcode Length.Library</heading>
788         <query>SELECT COUNT(acard.id), LENGTH(acard.barcode), aou.name FROM actor_card_legacy acard JOIN actor_usr_legacy au ON au.id = acard.usr JOIN actor.org_unit aou ON aou.id = au.home_ou WHERE acard.x_migrate = TRUE GROUP BY 2, 3 ORDER BY 3, 2</query>
789     </report>
790
791     <report>
792         <name>usr_barcode_lengths</name>
793         <report_title>Barcode Lengths by Library</report_title>
794         <tag>actors</tag>
795         <iteration>1</iteration>
796         <heading>Count of Barcode.Barcode Length.Library</heading>
797         <query>SELECT COUNT(acard.id), LENGTH(acard.barcode), aou.name FROM actor_card acard JOIN actor_usr au ON au.id = acard.usr JOIN actor.org_unit aou ON aou.id = au.home_ou GROUP BY 2, 3 ORDER BY 3, 2</query>
798     </report>
799
800     <report>
801         <name>usr_barcode_patterns</name>
802         <report_title>Common Barcode Starting Patterns</report_title>
803         <tag>actors</tag>
804         <iteration>0</iteration>
805         <heading>Count of Barcodes (greater than 10).Left 60% of Characters</heading>
806         <query>SELECT COUNT(acard.id), LEFT(acard.barcode,(ROUND(LENGTH(acard.barcode)*.6))::INT) FROM actor_card_legacy acard WHERE acard.x_migrate = TRUE GROUP BY 2 HAVING COUNT(acard.id) > 10 ORDER BY 2</query>
807     </report>
808
809     <report>
810         <name>usr_barcode_patterns</name>
811         <report_title>Common Barcode Starting Patterns</report_title>
812         <tag>actors</tag>
813         <iteration>1</iteration>
814         <heading>Count of Barcodes (greater than 10).Left 60% of Characters</heading>
815         <query>SELECT COUNT(acard.id), LEFT(acard.barcode,(ROUND(LENGTH(acard.barcode)*.6))::INT) FROM actor_card acard GROUP BY 2 HAVING COUNT(acard.id) > 10 ORDER BY 2</query>
816     </report>
817
818     <report>
819         <name>usr_barcode_collisions</name>
820         <report_title>Patron Barcode Collisions</report_title>
821         <tag>actors</tag>
822         <iteration>0</iteration>
823         <heading>Collision Count</heading>
824         <query>SELECT COUNT(acard.id) FROM actor_card_legacy acard WHERE barcode ~* 'collision' AND x_migrate = TRUE</query>
825     </report>
826
827     <report>
828         <name>usr_barcode_collisions</name>
829         <report_title>Patron Barcode Collisions</report_title>
830         <tag>actors</tag>
831         <iteration>1</iteration>
832         <heading>Collision Count</heading>
833         <query>SELECT COUNT(acard.id) FROM actor_card acard WHERE barcode ~* 'collision'</query>
834     </report>
835
836     <report>
837         <name>usr_barcode_collision_shortlist</name>
838         <report_title>Patron Barcode Collisions (first 20)</report_title>
839         <tag>actors</tag>
840         <iteration>0</iteration>
841         <heading>Collision List</heading>
842         <query>SELECT acard.barcode FROM actor_card_legacy acard WHERE acard.barcode ~* 'collision' AND acard.x_migrate = TRUE ORDER BY 1 LIMIT 20</query>
843         <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>
844     </report>
845
846     <report>
847         <name>usr_barcode_collision_shortlist</name>
848         <report_title>Patron Barcode Collisions (first 20)</report_title>
849         <tag>actors</tag>
850         <iteration>1</iteration>
851         <heading>Collision List</heading>
852         <query>SELECT acard.barcode FROM actor_card acard WHERE acard.barcode ~* 'collision' ORDER BY 1 LIMIT 20</query>
853         <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>
854     </report>
855
856     <report>
857         <name>usr_barcode_collision_patterns</name>
858         <report_title>Common Patron Barcode Collision Patterns</report_title> a.x_migrate
859         <tag>actors</tag>
860         <iteration>0</iteration>
861         <heading>Number of Barcodes Matching Pattern Greater than 10.Left 60% of Characters</heading>
862         <query>SELECT COUNT(acard.id), LEFT(acard.barcode,(ROUND(LENGTH(acard.barcode)*.6))::INT) FROM actor_card_legacy acard WHERE acard.barcode ~* 'collision' AND acard.x_migrate = TRUE GROUP BY 2 HAVING COUNT(acard.id) > 10 ORDER BY 2</query>
863     </report>
864
865     <report>
866         <name>usr_barcode_collision_patterns</name>
867         <report_title>Common Patron Barcode Collision Patterns</report_title> a.x_migrate
868         <tag>actors</tag>
869         <iteration>1</iteration>
870         <heading>Number of Barcodes Matching Pattern Greater than 10.Left 60% of Characters</heading>
871         <query>SELECT COUNT(acard.id), LEFT(acard.barcode,(ROUND(LENGTH(acard.barcode)*.6))::INT) FROM actor_card acard WHERE acard.barcode ~* 'collision' GROUP BY 2 HAVING COUNT(acard.id) > 10 ORDER BY 2</query>
872     </report>
873
874     <report>
875         <name>usr_addressses_status</name>
876         <report_title>Patron Addresses by Valid Status</report_title>
877         <tag>actors</tag>
878         <iteration>0</iteration>
879         <heading>Count.Valid.Migrated</heading>
880         <query>SELECT COUNT(aua.id), valid::TEXT, x_migrate::TEXT FROM actor_usr_address_legacy aua GROUP BY 2, 3</query>
881     </report>
882
883     <report>
884         <name>usr_addressses_status</name>
885         <report_title>Patron Addresses by Valid Status</report_title>
886         <tag>actors</tag>
887         <iteration>1</iteration>
888         <heading>Count.Valid</heading>
889         <query>SELECT COUNT(aua.id), valid::TEXT FROM actor_usr_address aua GROUP BY 2</query>
890     </report>
891
892     <report>
893         <name>usr_addresses_pending</name>
894         <report_title>Patron Addresses by Pending Status</report_title>
895         <tag>actors</tag>
896         <iteration>0</iteration>
897         <heading>Count of Addresses.Pending.Migrated</heading>
898         <query>SELECT COUNT(aua.id), pending::TEXT, x_migrate::TEXT FROM actor_usr_address_legacy aua GROUP BY 2, 3</query>
899     </report>
900
901     <report>
902         <name>usr_addresses_pending</name>
903         <report_title>Patron Addresses by Pending Status</report_title>
904         <tag>actors</tag>
905         <iteration>1</iteration>
906         <heading>Count of Addresses.Pending</heading>
907         <query>SELECT COUNT(aua.id), pending::TEXT FROM actor_usr_address aua GROUP BY 2</query>
908     </report>
909
910     <report>
911         <name>usr_messages</name>
912         <report_title>Patron Messages</report_title>
913         <tag>actors</tag>
914         <iteration>0</iteration>
915         <heading>Count.Deleted.Migrated</heading>
916         <query>SELECT COUNT(aum.id), deleted::TEXT, x_migrate::TEXT FROM actor_usr_message_legacy aum GROUP BY 2, 3</query>
917     </report>
918
919     <report>
920         <name>usr_messages</name>
921         <report_title>Patron Messages</report_title>
922         <tag>actors</tag>
923         <iteration>1</iteration>
924         <heading>Count.Deleted</heading>
925         <query>SELECT COUNT(aum.id), deleted::TEXT FROM actor_usr_message_legacy aum GROUP BY 2</query>
926     </report>
927
928     <report>
929         <name>usr_notes</name>
930         <report_title>Patron Notes</report_title>
931         <tag>actors</tag>
932         <iteration>0</iteration>
933         <heading>Count.Public.Migrated</heading>
934         <query>SELECT COUNT(aun.id), pub::TEXT, x_migrate::TEXT FROM actor_usr_note_legacy aun GROUP BY 2, 3</query>
935     </report>
936
937     <report>
938         <name>usr_notes</name>
939         <report_title>Patron Notes</report_title>
940         <tag>actors</tag>
941         <iteration>1</iteration>
942         <heading>Count.Public</heading>
943         <query>SELECT COUNT(aun.id), pub::TEXT FROM actor_usr_note aun GROUP BY 2</query>
944     </report>
945
946     <report>
947          <name>usr_stat_cats</name>
948         <report_title>Patron Statistical Categories</report_title>
949         <tag>actors</tag>
950         <iteration>0</iteration>
951         <heading>Stat Cat Count.Library.Statistical Category.Migrated</heading>
952         <query>SELECT COUNT(au_sc.id), aou.name, au_sc.name, au_sc.x_migrate::TEXT FROM 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>
953     </report>
954
955     <report>
956          <name>usr_stat_cats</name>
957         <report_title>Patron Statistical Categories</report_title>
958         <tag>actors</tag>
959         <iteration>1</iteration>
960         <heading>Stat Cat Count.Library.Statistical Category</heading>
961         <query>SELECT COUNT(au_sc.id), aou.name, au_sc.name FROM 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>
962     </report>
963
964     <report>
965         <name>usr_stat_cat_entries</name>
966         <report_title>Patron Stat Cat User Entries</report_title>
967         <tag>actors</tag>
968         <iteration>0</iteration>
969         <heading>Patron Stat Count.Library.Statistical Category.Migrated</heading>
970         <query>SELECT COUNT(map.id), aou.name, au_sc.name, map.x_migrate::TEXT FROM actor_stat_cat_entry_usr_map_legacy map JOIN 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>
971     </report>
972
973     <report>
974         <name>usr_stat_cat_entries</name>
975         <report_title>Patron Stat Cat User Entries</report_title>
976         <tag>actors</tag>
977         <iteration>1</iteration>
978         <heading>Patron Stat Count.Library.Statistical Category</heading>
979         <query>SELECT COUNT(map.id), aou.name, au_sc.name FROM actor_stat_cat_entry_usr_map map JOIN 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>
980     </report>
981
982     <report>
983         <name>usr_thresholds</name>
984         <report_title>Patron Thresholds</report_title>
985         <tag>actors</tag>
986         <iteration>0</iteration>
987         <heading>Pateron Group.Org Unit.Penalty.Threshold</heading>
988         <query>SELECT pgt.name, aou.shortname, sp.name, p.threshold FROM permission_grp_penalty_threshold p 
989                 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
990                 ORDER BY 2, 1, 3</query>
991     </report>
992
993
994     <!-- ACQUISITIONS REPORTS -->
995     <report>
996         <name>fund_count</name>
997         <iteration>0</iteration>
998         <tag>acq</tag>
999         <report_title>Migrated Funds</report_title>
1000         <heading>Number of Funds.Migrated</heading>
1001         <query>SELECT COUNT(id), x_migrate::TEXT FROM acq_fund_legacy GROUP BY 2;</query>
1002     </report>
1003
1004     <report>                                                                        
1005         <name>fund_count</name>
1006         <iteration>1</iteration>
1007         <tag>acq</tag>
1008         <report_title>Migrated Funds</report_title>
1009         <heading>Number of Funds</heading>
1010         <query>SELECT COUNT(id) FROM acq_fund;</query>
1011     </report>
1012
1013     <report>
1014         <name>invoice_count</name>
1015         <iteration>0</iteration>
1016         <tag>acq</tag>
1017         <report_title>Migrated Invoices</report_title>
1018         <heading>Number of Invoices.Migrated</heading>
1019         <query>SELECT COUNT(id), x_migrate::TEXT FROM acq_invoice_legacy GROUP BY 2;</query>
1020     </report>
1021
1022     <report>
1023         <name>invoice_count</name>
1024         <iteration>1</iteration>
1025         <tag>acq</tag>
1026         <report_title>Migrated Invoices</report_title>
1027         <heading>Number of Funds</heading>
1028         <query>SELECT COUNT(id) FROM acq_invoice;</query>
1029     </report>    
1030
1031     <!-- SERIALS REPORTS -->
1032     <report>
1033         <name>serials_mfhd_count</name>
1034         <tag>serials</tag>
1035         <iteration>0</iteration>
1036         <report_title>Migrated Serial MFHDs</report_title>
1037         <heading>Number of MFHDs</heading>
1038         <query>SELECT COUNT(id) FROM serial_record_entry</query>
1039     </report>
1040
1041     <!-- DEDUPE REPORTS -->
1042
1043     <asset>
1044         <name>dedupe_explain</name>
1045         <tag>dedupe</tag>
1046         <file>dedupe_process.asciidoc</file> 
1047     </asset>
1048
1049     <report>
1050         <name>dedupe_bib_groups</name>
1051         <tag>dedupe</tag>
1052         <iteration>0</iteration>
1053         <report_title>Scoring and Bib Record Groups</report_title>
1054         <heading>Count.Bib Record Groups</heading>
1055         <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)
1056           UNION ALL SELECT (COUNT(DISTINCT incoming_bib)), 'Incoming Bibs With Matches Found' FROM bib_matches
1057           UNION ALL SELECT (COUNT(bre.id) - (SELECT COUNT(DISTINCT incoming_bib) FROM bib_matches)), 'Incoming Bibs With No Match' 
1058                 FROM biblio.record_entry bre WHERE bre.deleted IS FALSE AND bre.id IN (SELECT eg::BIGINT FROM bib_id_map)
1059           UNION ALL SELECT COUNT(DISTINCT incoming_bib), 'Incoming Bibs Being Merged into Incumbent' FROM bib_matches WHERE incumbent_bib_score &gt;= incoming_bib_score
1060           UNION ALL SELECT COUNT(id), 'Incumbent Bibs With Higher Scores to Incoming' FROM bib_matches WHERE incumbent_bib_score &gt; incoming_bib_score
1061           UNION ALL SELECT COUNT(id), 'Incumbent Bibs With Equal Scores to Incoming' FROM bib_matches WHERE incumbent_bib_score = incoming_bib_score
1062           UNION ALL SELECT COUNT(id), 'Incumbent Bibs  With Lower Scores to Incoming' FROM bib_matches WHERE incumbent_bib_score &lt; incoming_bib_score
1063           ;</query>
1064     </report>
1065
1066     <report>
1067         <name>dedupe_format_count</name>
1068         <tag>dedupe</tag>
1069         <iteration>0</iteration>
1070         <report_title>Count of Items Matching By Format</report_title>
1071         <heading>Count.Format(s)</heading>
1072         <query>SELECT COUNT(id), search_formats FROM bib_matches GROUP BY 2 ORDER BY 2;</query>
1073     </report>
1074     
1075     <report>
1076         <name>dedupe_score_ranges</name>
1077         <tag>dedupe</tag>
1078         <iteration>0</iteration>
1079         <report_title>Count of Items Matching By Format</report_title>
1080         <heading>Lowest Record Score.Largest Record Score.Record Set</heading>
1081         <query>SELECT MIN(incumbent_bib_score), MAX(incumbent_bib_score), 'Incumbent Records' FROM bib_matches 
1082             UNION ALL SELECT MIN(incoming_bib_score), MAX(incoming_bib_score), 'Incoming Records' FROM bib_matches ;
1083         </query>
1084     </report>
1085     
1086     
1087     <report>
1088         <name>dedupe_sample_set</name>
1089         <tag>dedupe</tag>
1090         <iteration>0</iteration>
1091         <report_title>Sample of 20 Matching Dedupe Record Sets</report_title>
1092         <heading>Bib Being Merged Into.Bib Being Merged</heading>
1093         <query>SELECT incumbent_bib, incoming_bib FROM bib_matches WHERE incumbent_bib_score &gt;= incoming_bib_score LIMIT 20 ;
1094         </query>
1095     </report>
1096
1097     <!-- NOTICES REPORTS -->
1098
1099     <report>
1100         <name>notices_overview</name>
1101         <tag>notices</tag>
1102         <iteration>0</iteration>
1103         <report_title>Overview of Notices for Migration</report_title>
1104         <heading>ID.Active.Owner.Name.Delay.Validator.Reactor</heading>
1105         <query>SELECT ed.id, ed.active, aou.shortname, LEFT(ed.name,25) || '...', ed.delay, ed.validator, ed.reactor 
1106             FROM action_trigger.event_definition ed 
1107             JOIN actor.org_unit aou ON aou.id = ed.owner 
1108             WHERE ed.owner IN (SELECT DISTINCT home_ou FROM actor_usr)
1109             OR ed.owner IN (SELECT DISTINCT parent_ou FROM actor.org_unit WHERE id in (SELECT DISTINCT home_ou FROM actor_usr));
1110         </query>
1111     </report>
1112
1113     <report>
1114         <name>notices_count</name>
1115         <tag>notices</tag>
1116         <iteration>0</iteration>
1117         <report_title>Count of Notices Run with State</report_title>
1118         <heading>Count of Notices.State.ID.Owner.Name</heading>
1119         <query>SELECT COUNT(ate.id), ate.state, ed.id, aou.shortname, LEFT(ed.name,25) || '...' 
1120             FROM action_trigger.event_definition ed 
1121             JOIN actor.org_unit aou ON aou.id = ed.owner 
1122             JOIN action_trigger.event ate ON ate.event_def = ed.id 
1123             WHERE ed.owner IN (SELECT DISTINCT home_ou FROM actor_usr)
1124             OR ed.owner IN (SELECT DISTINCT parent_ou FROM actor.org_unit WHERE id in (SELECT DISTINCT home_ou FROM actor_usr))
1125             GROUP BY 2,3,4;
1126         </query>
1127     </report>
1128
1129
1130 </reports_file>
1131