-
Notifications
You must be signed in to change notification settings - Fork 4
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Loading branch information
Showing
1 changed file
with
116 additions
and
0 deletions.
There are no files selected for viewing
116 changes: 116 additions & 0 deletions
116
db/migrations/20241211133732_update-annual-email-report-prepare-2024-template.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,116 @@ | ||
-- migrate:up | ||
drop view annual_email_report; | ||
|
||
create view annual_email_report as | ||
with const as ( | ||
select | ||
date_trunc('year', now() - interval '9 months') as year_from, | ||
date_trunc('year', now() + interval '3 months') as year_to | ||
), | ||
data as ( | ||
select | ||
p.tin, | ||
p.email, | ||
d.tax_deductible, | ||
c.transfer_id, | ||
sum(d.amount) as total | ||
from | ||
const | ||
cross join donor_with_sensitive_info p | ||
join donation d on p.id = d.donor_id | ||
join charge c on d.id = c.donation_id | ||
where | ||
c.status = 'charged' | ||
and d.recipient != 'Giv Effektivt' | ||
and c.created_at <@ tstzrange(year_from, year_to, '[)') | ||
group by | ||
p.tin, | ||
p.email, | ||
d.tax_deductible, | ||
c.transfer_id | ||
), | ||
members_confirmed as ( | ||
select distinct on (p.tin) | ||
p.tin, | ||
p.email | ||
from | ||
const | ||
cross join donor_with_sensitive_info p | ||
inner join donation d on d.donor_id = p.id | ||
inner join charge c on c.donation_id = d.id | ||
where | ||
c.status = 'charged' | ||
and d.recipient = 'Giv Effektivt' | ||
and c.created_at <@ tstzrange(year_from, year_to, '[)') | ||
), | ||
email_to_tin_guess as ( | ||
select distinct on (email) | ||
p.email, | ||
p.tin | ||
from | ||
const | ||
cross join donor_with_sensitive_info p | ||
join donation d on p.id = d.donor_id | ||
join charge c on d.id = c.donation_id | ||
where | ||
c.status = 'charged' | ||
and p.tin is not null | ||
order by | ||
email, | ||
p.tin, | ||
c.created_at desc | ||
), | ||
with_tax as ( | ||
select | ||
* | ||
from | ||
data | ||
where | ||
tax_deductible | ||
), | ||
with_tin_no_tax as ( | ||
select | ||
* | ||
from | ||
data | ||
where | ||
not tax_deductible | ||
and tin is not null | ||
), | ||
with_no_tin_no_tax as ( | ||
select | ||
* | ||
from | ||
data | ||
where | ||
not tax_deductible | ||
and tin is null | ||
) | ||
select | ||
coalesce(a.tin, b.tin, d.tin) as tin, | ||
coalesce(a.email, b.email, c.email) as email, | ||
coalesce(a.tin, b.tin) is null | ||
and d.tin is not null as is_tin_guessed, | ||
length(coalesce(a.tin, b.tin, d.tin, '')) = 8 as is_company, | ||
e.tin is not null as is_member, | ||
coalesce(a.transfer_id, b.transfer_id, c.transfer_id) as transfer_id, | ||
a.total as amount_tax_deductible, | ||
nullif(coalesce(b.total, 0) + coalesce(c.total, 0), 0) as amount_not_tax_deductible, | ||
coalesce(a.total, 0) + coalesce(b.total, 0) + coalesce(c.total, 0) as amount_total | ||
from | ||
with_tax a | ||
full join with_tin_no_tax b on a.tin is not distinct from b.tin | ||
and a.email = b.email | ||
and a.transfer_id is not distinct from b.transfer_id | ||
full join with_no_tin_no_tax c on coalesce(a.email, b.email) = c.email | ||
and coalesce(a.transfer_id, b.transfer_id) is not distinct from c.transfer_id | ||
left join email_to_tin_guess d on coalesce(a.email, b.email, c.email) = d.email | ||
left join members_confirmed e on coalesce(a.tin, b.tin, d.tin) = e.tin | ||
order by | ||
email, | ||
tin, | ||
coalesce(a.transfer_id, b.transfer_id, c.transfer_id); | ||
|
||
grant select on annual_email_report to reader_sensitive; | ||
|
||
-- migrate:down |