-
Notifications
You must be signed in to change notification settings - Fork 3
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Moving WaterAllocation View to a Materialised View (#125)
* Moving WaterAllocation View to a Materialised View * Remove spots * Updates to allow water_allocation_and_usage_by_area to be refreshed * Fix up permission issue with materialized view * Turn effective_daily_consents back into a regular migration so we can ensure it is run before water_allocation_and_usage_by_area * Add materialized_views_role definition to LocalInfrastructure init script * Ensure materialized view is refreshed before running tests * Ensure materialized_views_role has the same permissions as eop_manager_app_user * Ensure view is materialized after generating test data * Remove old version of DB config - Has been superceded by LocalInfra folder * Limit materialized views role to Read only --------- Co-authored-by: Vim <[email protected]>
- Loading branch information
Showing
11 changed files
with
178 additions
and
174 deletions.
There are no files selected for viewing
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
This file was deleted.
Oops, something went wrong.
This file was deleted.
Oops, something went wrong.
This file was deleted.
Oops, something went wrong.
20 changes: 20 additions & 0 deletions
20
packages/Manager/src/main/kotlin/nz/govt/eop/tasks/WaterAllocationViewUpdater.kt
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,20 @@ | ||
package nz.govt.eop.tasks | ||
|
||
import java.util.concurrent.TimeUnit | ||
import net.javacrumbs.shedlock.spring.annotation.SchedulerLock | ||
import org.springframework.jdbc.core.JdbcTemplate | ||
import org.springframework.scheduling.annotation.Scheduled | ||
import org.springframework.stereotype.Component | ||
import org.springframework.transaction.annotation.Transactional | ||
|
||
@Component | ||
class WaterAllocationViewUpdater(val jdbcTemplate: JdbcTemplate) { | ||
|
||
@Scheduled(fixedDelay = 1, timeUnit = TimeUnit.HOURS) | ||
@SchedulerLock(name = "waterAllocationViewUpdater") | ||
@Transactional | ||
fun refresh() { | ||
jdbcTemplate.update( | ||
"SET ROLE materialized_views_role; REFRESH MATERIALIZED VIEW CONCURRENTLY water_allocation_and_usage_by_area;") | ||
} | ||
} |
31 changes: 1 addition & 30 deletions
31
packages/Manager/src/main/resources/db/migration/R__effective_daily_consents.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 |
---|---|---|
@@ -1,30 +1 @@ | ||
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 | ||
-- Replace by V0031 |
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
77 changes: 1 addition & 76 deletions
77
packages/Manager/src/main/resources/db/migration/R__water_allocation_and_usage_by_area.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 |
---|---|---|
@@ -1,76 +1 @@ | ||
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 | ||
-- Replace by V0032 |
30 changes: 30 additions & 0 deletions
30
packages/Manager/src/main/resources/db/migration/V0031__effective_daily_consents.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,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 |
92 changes: 92 additions & 0 deletions
92
...rc/main/resources/db/migration/V0032__water_allocation_and_usage_by_area_materialized.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,92 @@ | ||
drop view if exists water_allocation_and_usage_by_area; | ||
|
||
create materialized 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 | ||
-- This prevents initial generation so we don't block the app booting when migrations | ||
-- are run as part of app-deploy | ||
with no data; | ||
|
||
create index on water_allocation_and_usage_by_area (date); | ||
-- A unique index is required to refresh the view concurrently | ||
create unique index on water_allocation_and_usage_by_area (date, area_id); | ||
|
||
alter materialized view water_allocation_and_usage_by_area owner to materialized_views_role; | ||
|
||
-- After changing the owner, we need to ensure eop_manager_migrations_user still | ||
-- has rights on the table for commands in R__setup_permissions.sql to be able to | ||
-- to run without error | ||
set role materialized_views_role; | ||
grant all ON table water_allocation_and_usage_by_area to eop_manager_migrations_user; |
Oops, something went wrong.