Skip to content

Commit

Permalink
Add views to aggregate consent allocations and usage by day
Browse files Browse the repository at this point in the history
  • Loading branch information
vimto committed Oct 3, 2023
1 parent abfeb11 commit 7501dd5
Show file tree
Hide file tree
Showing 2 changed files with 104 additions and 0 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1,73 @@
create or replace view effective_daily_consents as

with all_consents as (
select distinct source_id,
null::varchar as area_id,
null::varchar as status,
null::numeric as allocation,
null::boolean as is_metered,
null::numeric as metered_allocation_daily,
null::numeric as metered_allocation_yearly,
null::varchar[] as meters,
0 as is_real
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') as effective_from
),

data_per_day as (
select * from all_consents cross join days_in_last_year
union
SELECT source_id,
area_id,
status,
allocation,
is_metered,
metered_allocation_daily,
metered_allocation_yearly,
meters,
1 as is_real,
effective_from
from water_allocations
),

latest_values as (
select source_id, effective_from, area_id, status, allocation, is_metered, metered_allocation_daily, metered_allocation_yearly, meters, is_real,
sum (case when area_id is not null then 1 end) over (partition by source_id order by effective_from, is_real) as is_area_id_null,
sum (case when status is not null then 1 end) over (partition by source_id order by effective_from, is_real) as is_status_null,
sum (case when allocation is not null then 1 end) over (partition by source_id order by effective_from, is_real) as is_allocation_null,
sum (case when is_metered is not null then 1 end) over (partition by source_id order by effective_from, is_real) as is_is_metered_null,
sum (case when metered_allocation_daily is not null then 1 end) over (partition by source_id order by effective_from, is_real) as is_mad_null,
sum (case when metered_allocation_yearly is not null then 1 end) over (partition by source_id order by effective_from, is_real) as is_may_null,
sum (case when meters is not null then 1 end) over (partition by source_id order by effective_from, is_real) as is_meters_null
from data_per_day
),

effective_daily_data as (
select source_id, effective_from,
first_value(area_id) over (partition by source_id, latest_values.is_area_id_null) as area_id,
first_value(status) over (partition by source_id, latest_values.is_status_null) as status,
first_value(allocation) over (partition by source_id, latest_values.is_allocation_null) as allocation,
first_value(is_metered) over (partition by source_id, latest_values.is_is_metered_null) as is_metered,
first_value(metered_allocation_daily) over (partition by source_id, latest_values.is_mad_null) as allocation_daily,
first_value(metered_allocation_yearly) over (partition by source_id, latest_values.is_may_null) as metered_allocation_yearly,
first_value(meters) over (partition by source_id, latest_values.is_meters_null) as meters,
ROW_NUMBER() over(order by source_id, effective_from, is_real) as row_number
from latest_values),

grouped_effective_data as (
select ea.* from effective_daily_data ea
inner join
(
select source_id, date(effective_from) as effective_from, max(row_number) as max_row_number
from effective_daily_data
group by source_id, date(effective_from)
) lef
on lef.source_id = ea.source_id
and lef.max_row_number = ea.row_number
order by source_id, effective_from
)

select * from grouped_effective_data
Original file line number Diff line number Diff line change
@@ -0,0 +1,31 @@
create or replace view water_allocation_and_usage_by_area as
with all_areas as
(
select distinct area_id
from effective_daily_consents
where area_id is not null
),
all_dates as (
select distinct date(effective_from) as date
from effective_daily_consents
),
area_defaults as (
select area_id, date, 0 as allocation, 0 as allocation_daily, 0 as metered_allocation_yearly, 0 as daily_usage
from all_areas cross join all_dates
),
usage as (
select area_id, date(effective_from) as date, allocation, allocation_daily, metered_allocation_yearly, case when is_metered = true then daily_usage else 0 end as daily_usage
from effective_daily_consents
inner join observed_water_use_aggregated_daily
on day_observed_at = date(effective_daily_consents.effective_from)
and site_id::varchar in(
select unnest(meters)
)
where status = 'active'
union
select * from area_defaults
)

select area_id, date, sum(allocation) as allocation, sum(allocation_daily) as allocation_daily, sum(metered_allocation_yearly) as metered_allocation_yearly, sum(daily_usage) as daily_usage
from usage
group by area_id, date

0 comments on commit 7501dd5

Please sign in to comment.