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

Add views to aggregate daily allocations and usage by area #100

Merged
merged 11 commits into from
Oct 10, 2023
Original file line number Diff line number Diff line change
@@ -0,0 +1,30 @@
create or replace view effective_daily_consents as

with all_consents as (
select distinct source_id from water_allocations
),

days_in_last_year as (
select GENERATE_SERIES(DATE_TRUNC('day', now()) - INTERVAL '1 YEAR', DATE_TRUNC('day', now()) - INTERVAL '1 DAY', INTERVAL '1 DAY') as effective_on
),
data_per_day as (
select * from all_consents cross join days_in_last_year
),

effective_daily_data as (
select dpd.source_id, dpd.effective_on, wa.area_id, wa.allocation, wa.consent_id, wa.status, wa.is_metered, wa.metered_allocation_daily, wa.metered_allocation_yearly, wa.meters
from data_per_day dpd
left join lateral
(
select * from
water_allocations wai
where wai.source_id = dpd.source_id
and date(dpd.effective_on) >= date(wai.effective_from)
and (wai.effective_to is null or date(dpd.effective_on) < date(wai.effective_to))
order by wai.effective_from desc
limit 1
) wa
on wa.source_id = dpd.source_id
)

select * from effective_daily_data
Original file line number Diff line number Diff line change
@@ -0,0 +1,76 @@
create or replace view water_allocation_and_usage_by_area as

with all_days as (
select distinct date(effective_on) as effective_on from effective_daily_consents
),
all_areas as (
select distinct
area_id,
0 as allocation,
0 as metered_allocation_daily,
0 as metered_allocation_yearly,
false as is_metered,
'{}'::varchar[] as meters,
'inactive' as status
from effective_daily_consents
where area_id is not null
),
data_per_day as (
select * from all_days cross join all_areas
),
effective_consents_with_defaults as (
select * from data_per_day
union
select
date(effective_on),
area_id,
allocation,
metered_allocation_daily,
metered_allocation_yearly,
is_metered,
meters,
status
from effective_daily_consents
where area_id is not null and status = 'active'
),
observed_water_use_with_sites as (
select owu.*, os.name as site_name
from observed_water_use_aggregated_daily owu
inner join observation_sites os on os.id = owu.site_id
),
expanded_meters_per_area as
(select effective_on, area_id, UNNEST(meters) as meter from effective_consents_with_defaults where is_metered = true),
meter_use_by_area as (select effective_on,
area_id,
meter,
use.daily_usage
from expanded_meters_per_area
left join observed_water_use_with_sites use on effective_on = day_observed_at and meter = site_name),
total_daily_use_by_area as (select area_id,
effective_on as date,
SUM(daily_usage) as daily_usage
from meter_use_by_area
group by area_id, effective_on),
total_daily_allocation_by_area as (
select
area_id,
effective_on as date,
SUM(allocation) as allocation,
SUM(metered_allocation_daily) as allocation_daily,
SUM(metered_allocation_yearly) as metered_allocation_yearly
from effective_consents_with_defaults group by 1, 2
order by date
),
allocated_joined_with_use AS (
select
area_id,
date,
allocation,
allocation_daily,
metered_allocation_yearly,
coalesce(daily_usage, 0) as daily_usage
from total_daily_allocation_by_area
left join total_daily_use_by_area using (area_id, date)
)
SELECT *
FROM allocated_joined_with_use
Loading
Loading