Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Interim1 #762

Merged
merged 6 commits into from
Sep 11, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -43,42 +43,45 @@ INSERT INTO juror_mod.juror (juror_number,poll_number,title,last_name,first_name
('415000029',NULL,NULL,'LNAME29','FNAME29',NULL,'ADDRESS LINE 1',NULL,NULL,'ADDRESS LINE 4',NULL,'CH1 2AB',NULL,NULL,NULL,true,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,'NOT_CHECKED',NULL,NULL,NULL,NULL,0,0,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,false,NULL,0,false),
('415000030',NULL,NULL,'LNAME30','FNAME30',NULL,'ADDRESS LINE 1',NULL,NULL,'ADDRESS LINE 4',NULL,'CH1 2AB',NULL,NULL,NULL,true,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,'NOT_CHECKED',NULL,NULL,NULL,NULL,0,0,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,false,NULL,0,false),
('415000031',NULL,NULL,'LNAME31','FNAME31',NULL,'ADDRESS LINE 1',NULL,NULL,'ADDRESS LINE 4',NULL,'CH1 2AB',NULL,NULL,NULL,true,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,'NOT_CHECKED',NULL,NULL,NULL,NULL,0,0,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,false,NULL,0,false),
('415000032',NULL,NULL,'LNAME32','FNAME32',NULL,'ADDRESS LINE 1',NULL,NULL,'ADDRESS LINE 4',NULL,'CH1 2AB',NULL,NULL,NULL,true,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,'NOT_CHECKED',NULL,NULL,NULL,NULL,0,0,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,false,NULL,0,false);
('415000032',NULL,NULL,'LNAME32','FNAME32',NULL,'ADDRESS LINE 1',NULL,NULL,'ADDRESS LINE 4',NULL,'CH1 2AB',NULL,NULL,NULL,true,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,'NOT_CHECKED',NULL,NULL,NULL,NULL,0,0,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,false,NULL,0,false),
('415000033',NULL,NULL,'LNAME33','FNAME33',NULL,'ADDRESS LINE 1',NULL,NULL,'ADDRESS LINE 4',NULL,'CH1 2AB',NULL,NULL,NULL,true,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,'NOT_CHECKED',NULL,NULL,NULL,NULL,0,0,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,false,NULL,0,false),
('415000034',NULL,NULL,'LNAME34','FNAME34',NULL,'ADDRESS LINE 1',NULL,NULL,'ADDRESS LINE 4',NULL,'CH1 2AB',NULL,NULL,NULL,true,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,'NOT_CHECKED',NULL,NULL,NULL,NULL,0,0,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,false,NULL,0,false);


INSERT INTO juror_mod.juror_pool (juror_number,pool_number,"owner",user_edtq,is_active,status,times_sel,def_date,"location",no_attendances,no_attended,no_fta,no_awol,pool_seq,edit_tag,next_date,on_call,smart_card,was_deferred,deferral_code,id_checked,postpone,paid_cash,scan_code,last_update,reminder_sent,transfer_date,date_created) VALUES
('415000001','415231101','415',NULL,true,3,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000002','415231101','415',NULL,true,3,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000003','415231101','415',NULL,true,3,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000004','415231102','415',NULL,true,3,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000005','415231102','415',NULL,true,3,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000006','415231102','415',NULL,true,3,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000007','415231102','415',NULL,true,3,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000008','415231102','415',NULL,true,3,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000009','415231103','415',NULL,true,3,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000010','415231103','415',NULL,true,3,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000011','415231103','415',NULL,true,3,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000012','415231103','415',NULL,true,3,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000013','415231103','415',NULL,true,3,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000014','415231104','415',NULL,true,4,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000015','415231104','415',NULL,true,4,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000016','415231104','415',NULL,true,4,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000017','415231104','415',NULL,true,4,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000018','415231104','415',NULL,true,1,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000020','415231105','415',NULL,true,4,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000021','415231105','415',NULL,true,4,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000022','415231106','415',NULL,true,2,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000023','415231106','415',NULL,true,2,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000024','415231105','415',NULL,true,5,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000025','415231105','415',NULL,true,6,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000026','415231106','415',NULL,true,7,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000027','415231106','415',NULL,true,8,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000028','415231106','415',NULL,true,9,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000029','415231106','415',NULL,true,10,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000030','415231106','415',NULL,true,11,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000031','415231106','415',NULL,true,12,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL),
('415000032','415231106','415',NULL,true,13,NULL,NULL,'415',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL);

INSERT INTO juror_mod.juror_pool (juror_number,pool_number,"owner",user_edtq,is_active,status,times_sel,def_date,"location") VALUES
('415000001','415231101','415',NULL,true,3,NULL,NULL,'415'),
('415000002','415231101','415',NULL,true,3,NULL,NULL,'415'),
('415000003','415231101','415',NULL,true,3,NULL,NULL,'415'),
('415000004','415231102','415',NULL,true,3,NULL,NULL,'415'),
('415000005','415231102','415',NULL,true,3,NULL,NULL,'415'),
('415000006','415231102','415',NULL,true,3,NULL,NULL,'415'),
('415000007','415231102','415',NULL,true,3,NULL,NULL,'415'),
('415000008','415231102','415',NULL,true,3,NULL,NULL,'415'),
('415000009','415231103','415',NULL,true,3,NULL,NULL,'415'),
('415000010','415231103','415',NULL,true,3,NULL,NULL,'415'),
('415000011','415231103','415',NULL,true,3,NULL,NULL,'415'),
('415000012','415231103','415',NULL,true,3,NULL,NULL,'415'),
('415000013','415231103','415',NULL,true,3,NULL,NULL,'415'),
('415000014','415231104','415',NULL,true,4,NULL,NULL,'415'),
('415000015','415231104','415',NULL,true,4,NULL,NULL,'415'),
('415000016','415231104','415',NULL,true,4,NULL,NULL,'415'),
('415000017','415231104','415',NULL,true,4,NULL,NULL,'415'),
('415000018','415231104','415',NULL,true,1,NULL,NULL,'415'),
('415000020','415231105','415',NULL,true,4,NULL,NULL,'415'),
('415000021','415231105','415',NULL,true,4,NULL,NULL,'415'),
('415000022','415231106','415',NULL,true,2,NULL,NULL,'415'),
('415000023','415231106','415',NULL,true,2,NULL,NULL,'415'),
('415000024','415231105','415',NULL,true,5,NULL,NULL,'415'),
('415000025','415231105','415',NULL,true,6,NULL,NULL,'415'),
('415000026','415231106','415',NULL,true,7,NULL,NULL,'415'),
('415000027','415231106','415',NULL,true,8,NULL,NULL,'415'),
('415000028','415231106','415',NULL,true,9,NULL,NULL,'415'),
('415000029','415231106','415',NULL,true,10,NULL,NULL,'415'),
('415000030','415231106','415',NULL,true,11,NULL,NULL,'415'),
('415000031','415231106','415',NULL,true,12,NULL,NULL,'415'),
('415000032','415231106','415',NULL,true,13,NULL,NULL,'415'),
('415000033','415231106','415',NULL,true,7,NULL,NULL,'415'),
('415000034','415231106','415',NULL,true,5,NULL,NULL,'415');

INSERT INTO juror_mod.appearance (attendance_date,juror_number,loc_code,time_in,time_out,trial_number,non_attendance,no_show,misc_description,pay_cash,last_updated_by,created_by,public_transport_total_due,public_transport_total_paid,hired_vehicle_total_due,hired_vehicle_total_paid,motorcycle_total_due,motorcycle_total_paid,car_total_due,car_total_paid,pedal_cycle_total_due,pedal_cycle_total_paid,childcare_total_due,childcare_total_paid,parking_total_due,parking_total_paid,misc_total_due,misc_total_paid,smart_card_due,is_draft_expense,f_audit,sat_on_jury,pool_number,appearance_stage,loss_of_earnings_due,loss_of_earnings_paid,subsistence_due,subsistence_paid,attendance_type,smart_card_paid,travel_time,travel_jurors_taken_by_car,travel_by_car,travel_jurors_taken_by_motorcycle,travel_by_motorcycle,travel_by_bicycle,miles_traveled,food_and_drink_claim_type,"version",expense_rates_id,attendance_audit_number) VALUES
('2024-05-08','415000001','415','09:00:00.5603',NULL,NULL,false,NULL,NULL,false,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,true,NULL,NULL,'415231101',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,1,NULL,NULL),
Expand Down Expand Up @@ -204,4 +207,3 @@ INSERT INTO juror_mod.holiday (loc_code,holiday,description,public) VALUES
('415','2024-04-26','TEST',false),
('415','2024-09-20','TEST',false),
(NULL,'2024-04-01','PUBLIC HOLIDAY',true);

23 changes: 23 additions & 0 deletions src/main/resources/db/migrationv2/V2_30__util_report_update.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@

-- utility function to return list of all days within the report window and holiday flag
-- updated to correctly handle no trial days added by a court and multiple holidays on the same day
CREATE OR REPLACE FUNCTION juror_mod.util_report_report_days_list(p_loc_code text, p_start_date date, p_end_date date)
RETURNS TABLE(report_date date, holiday boolean)
LANGUAGE plpgsql
AS $function$
begin

return query

with report_days as (
select generate_series(p_start_date, p_end_date, '1 day'::interval)::date as report_day)

select distinct(report_days.report_day) as report_date,
case when h.holiday is not null then true else false end as holiday
from report_days
left join juror_mod.holiday h on (report_days.report_day = h.holiday and (h.loc_code is null or h.loc_code = p_loc_code))
order by report_days.report_day;

END;
$function$
;
38 changes: 38 additions & 0 deletions src/main/resources/db/migrationv2/V2_31__util_report_update.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,38 @@

-- This function is used to generate a list of jurors who are in a pool during a given date range.
-- Updated the query to only count genuine appearances rather than non-attendance or no-shows.
CREATE OR REPLACE FUNCTION juror_mod.util_report_pool_members_list(p_loc_code text, p_start_date date, p_end_date date)
RETURNS TABLE(juror_number character varying, attendance_date date, return_date date, service_start_date date, service_end_date date, min_status integer)
LANGUAGE plpgsql
AS $function$
begin

return query select
jp.juror_number,
min(a.attendance_date) attendance_date,
min(case when jp.is_active = true then p.return_date else to_date('01/12/2099', 'dd/mm/yyyy') end ) return_date,
greatest(least(coalesce(min(a.attendance_date), min(case when jp.is_active = true then p.return_date else to_date('01/12/2099', 'dd/mm/yyyy') end )),
min(case when jp.is_active = true then p.return_date else to_date('01/12/2099','dd/mm/yyyy') end )), p_start_date) service_start,
-- figure out if an appearance occurred before service start date and use that if applicable
least(min(coalesce(case when jp.status = 10 then jp.transfer_date else date(j.completion_date) end, p_end_date)),p_end_date) service_end,
min(status) min_status
from juror_mod.juror_pool jp
join juror_mod.juror j
on jp.juror_number = j.juror_number
join juror_mod.pool p
on jp.pool_number = p.pool_no
left join juror_mod.appearance a
on jp.juror_number = a.juror_number
where p.loc_code = a.loc_code
and (((jp.status in (2,3,4,10,13) or (jp.status = 7 and a.attendance_date is not null)) and jp.is_active = true)
or (jp.status = 8 and a.attendance_date is not null and j.completion_date is not null))
and (a.non_attendance is null or a.non_attendance = false) and (a.no_show is null or a.no_show = false)
and p.loc_code = p_loc_code
and ((jp.status = 10 and jp.transfer_date >= p_start_date)
or (jp.status <> 10 and (j.completion_date is null or j.completion_date >= p_start_date)))
group by jp.juror_number
having (least(coalesce(min(a.attendance_date), min(case when jp.is_active = true then p.return_date else to_date('01/12/2099', 'dd/mm/yyyy') end)),
min(case when jp.is_active = true then p.return_date else to_date('01/12/2099', 'dd/mm/yyyy') end)) <= p_end_date);
END;
$function$
;