From 7501dd511e163fa3a36370a15500ad984ad3470e Mon Sep 17 00:00:00 2001 From: Vim Date: Tue, 3 Oct 2023 13:47:41 +1300 Subject: [PATCH 01/11] Add views to aggregate consent allocations and usage by day --- .../V0032__effective_daily_consents.sql | 73 +++++++++++++++++++ ...33__water_allocation_and_usage_by_area.sql | 31 ++++++++ 2 files changed, 104 insertions(+) create mode 100644 packages/Manager/src/main/resources/db/migration/V0032__effective_daily_consents.sql create mode 100644 packages/Manager/src/main/resources/db/migration/V0033__water_allocation_and_usage_by_area.sql diff --git a/packages/Manager/src/main/resources/db/migration/V0032__effective_daily_consents.sql b/packages/Manager/src/main/resources/db/migration/V0032__effective_daily_consents.sql new file mode 100644 index 00000000..35fbcaf3 --- /dev/null +++ b/packages/Manager/src/main/resources/db/migration/V0032__effective_daily_consents.sql @@ -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 diff --git a/packages/Manager/src/main/resources/db/migration/V0033__water_allocation_and_usage_by_area.sql b/packages/Manager/src/main/resources/db/migration/V0033__water_allocation_and_usage_by_area.sql new file mode 100644 index 00000000..d716244b --- /dev/null +++ b/packages/Manager/src/main/resources/db/migration/V0033__water_allocation_and_usage_by_area.sql @@ -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 From 1e1ba58714f44e3a15d5b9ceaa7dfb271e6829a1 Mon Sep 17 00:00:00 2001 From: Vim Date: Tue, 3 Oct 2023 15:59:41 +1300 Subject: [PATCH 02/11] Start writing tests --- .../WaterAllocationAndUsageViewsTest.kt | 90 +++++++++++++++++++ 1 file changed, 90 insertions(+) create mode 100644 packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt diff --git a/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt new file mode 100644 index 00000000..51798bb7 --- /dev/null +++ b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt @@ -0,0 +1,90 @@ +package nz.govt.eop.plan_limits + +import io.kotest.matchers.collections.shouldContain +import io.kotest.matchers.shouldBe +import java.time.LocalDate +import org.junit.jupiter.api.BeforeEach +import org.junit.jupiter.api.Test +import org.springframework.beans.factory.annotation.Autowired +import org.springframework.boot.test.context.SpringBootTest +import org.springframework.jdbc.core.JdbcTemplate +import org.springframework.test.context.ActiveProfiles +import org.springframework.test.web.servlet.request.MockMvcRequestBuilders.* +import org.springframework.test.web.servlet.result.MockMvcResultMatchers.* +import org.springframework.transaction.annotation.Transactional + +@ActiveProfiles("test") +@SpringBootTest +@Transactional +class WaterAllocationAndUsageViewsTest(@Autowired val jdbcTemplate: JdbcTemplate) { + + @BeforeEach + fun resetTestData() { + truncateTestData() + createTestData() + } + + @Test + fun `should be empty with no data`() { + truncateTestData() + val result = + jdbcTemplate.queryForObject( + "select count(*) from water_allocation_and_usage_by_area", Int::class.java) + result shouldBe 0 + } + + @Test + fun `should include a year of data`() { + val result = + jdbcTemplate.queryForMap( + "select count(*) as count, min(date) as min_date, max(date) as max_date from water_allocation_and_usage_by_area") + arrayOf(365L, 366L) shouldContain result["count"] as Long + val min = LocalDate.parse(result["min_date"].toString()) + val max = LocalDate.parse(result["max_date"].toString()) + min.plusYears(1) shouldBe max + } + + // Pending tests + // Single consent + fun `should not include data before a consent was effective`() {} + fun `should data once a consent is active`() {} + fun `should handle changes in consent data`() {} + fun `should not include data when a consent status is not active`() {} + fun `should not include observations when is_metered is false`() {} + + // Multiple consents + // Multiple meters + + fun truncateTestData() { + jdbcTemplate.execute("truncate water_allocations cascade") + jdbcTemplate.execute("truncate observations cascade") + jdbcTemplate.execute("truncate observation_sites_measurements cascade") + jdbcTemplate.execute("truncate observation_sites cascade") + } + + fun createTestData() { + val siteId = 1 + val councilId = 9 + val measurementId = 1 + val measurementName = "Water Meter Reading" + val observationTimestamp = "2023-09-10 06:00:00+00" + val consentAreaId = "area-id" + val consentSourceId = "source-id" + val consentAllocation = 10 + val consentEffectiveFrom = "2023-09-01 06:00:00+00" + jdbcTemplate.update( + """INSERT INTO observation_sites (id, council_id, name) VALUES ($siteId, $councilId, 'Test site')""") + jdbcTemplate.update( + """ + INSERT INTO observation_sites_measurements (id, site_id, measurement_name, first_observation_at, last_observation_at, observation_count) + VALUES ($measurementId, $siteId, '$measurementName', now(), now(), 0)""" + .trimIndent()) + jdbcTemplate.update( + """INSERT INTO observations (observation_measurement_id, amount, observed_at) VALUES ($measurementId, 1, '$observationTimestamp')""") + jdbcTemplate.update( + """ + INSERT INTO water_allocations (area_id, allocation, ingest_id, source_id, consent_id, status, is_metered, metered_allocation_daily, metered_allocation_yearly, meters, effective_from, effective_to, created_at, updated_at) + VALUES ('$consentAreaId', '$consentAllocation', 'ingest-id', '$consentSourceId', 'consent-id', 'active', true, 10, 100, '{$siteId}', '$consentEffectiveFrom', null, now(), now())""" + .trimIndent()) + } +} From 9b5f81b128145c3f4ea3cb5242a81f3c81f411a3 Mon Sep 17 00:00:00 2001 From: Vim Date: Wed, 4 Oct 2023 16:06:54 +1300 Subject: [PATCH 03/11] Allow easier setup and assertion against test data, start adding more tests --- ...33__water_allocation_and_usage_by_area.sql | 4 +- .../WaterAllocationAndUsageViewsTest.kt | 183 +++++++++++++++--- 2 files changed, 153 insertions(+), 34 deletions(-) diff --git a/packages/Manager/src/main/resources/db/migration/V0033__water_allocation_and_usage_by_area.sql b/packages/Manager/src/main/resources/db/migration/V0033__water_allocation_and_usage_by_area.sql index d716244b..1a25e862 100644 --- a/packages/Manager/src/main/resources/db/migration/V0033__water_allocation_and_usage_by_area.sql +++ b/packages/Manager/src/main/resources/db/migration/V0033__water_allocation_and_usage_by_area.sql @@ -14,9 +14,9 @@ area_defaults as ( 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 + select area_id, date(effective_from) as date, allocation, allocation_daily, metered_allocation_yearly, case when is_metered = true then daily_usage else null end as daily_usage from effective_daily_consents - inner join observed_water_use_aggregated_daily + left outer join observed_water_use_aggregated_daily on day_observed_at = date(effective_daily_consents.effective_from) and site_id::varchar in( select unnest(meters) diff --git a/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt index 51798bb7..ea9cb570 100644 --- a/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt +++ b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt @@ -1,31 +1,81 @@ package nz.govt.eop.plan_limits +import io.kotest.inspectors.forAll import io.kotest.matchers.collections.shouldContain import io.kotest.matchers.shouldBe +import java.math.BigDecimal +import java.time.Instant import java.time.LocalDate +import java.time.LocalDateTime +import java.time.ZoneOffset +import nz.govt.eop.messages.ConsentStatus import org.junit.jupiter.api.BeforeEach import org.junit.jupiter.api.Test import org.springframework.beans.factory.annotation.Autowired import org.springframework.boot.test.context.SpringBootTest +import org.springframework.jdbc.core.DataClassRowMapper import org.springframework.jdbc.core.JdbcTemplate +import org.springframework.jdbc.core.query +import org.springframework.jdbc.support.GeneratedKeyHolder +import org.springframework.jdbc.support.KeyHolder import org.springframework.test.context.ActiveProfiles import org.springframework.test.web.servlet.request.MockMvcRequestBuilders.* import org.springframework.test.web.servlet.result.MockMvcResultMatchers.* import org.springframework.transaction.annotation.Transactional +data class WaterAllocationUsageRow( + val areaId: String, + val date: LocalDate, + val allocation: BigDecimal, + val allocationDaily: BigDecimal, + val meteredAllocationYearly: BigDecimal, + val dailyUsage: BigDecimal, +) + +data class AllocationRow( + val sourceId: String, + val consentId: String, + val status: ConsentStatus, + val areaId: String, + val allocation: BigDecimal, + val isMetered: Boolean, + val meteredAllocationDaily: BigDecimal, + val meteredAllocationYearly: BigDecimal, + val meters: List, + val ingestId: String, + val effectiveFrom: Instant, + val effectiveTo: Instant? +) + @ActiveProfiles("test") @SpringBootTest @Transactional class WaterAllocationAndUsageViewsTest(@Autowired val jdbcTemplate: JdbcTemplate) { + val testSiteId = 1 + val testAreaId = "test-area-id" + val testEffectiveFrom: LocalDateTime = LocalDate.now().atStartOfDay().minusDays(100) + val testAllocation = + AllocationRow( + "source-id", + "consent-id", + ConsentStatus.active, + testAreaId, + BigDecimal(100), + true, + BigDecimal(10), + BigDecimal(10), + listOf(testSiteId.toString()), + "ingest-id", + testEffectiveFrom.toInstant(ZoneOffset.UTC), + null) @BeforeEach fun resetTestData() { truncateTestData() - createTestData() } @Test - fun `should be empty with no data`() { + fun `should be empty with no allocations`() { truncateTestData() val result = jdbcTemplate.queryForObject( @@ -34,26 +84,57 @@ class WaterAllocationAndUsageViewsTest(@Autowired val jdbcTemplate: JdbcTemplate } @Test - fun `should include a year of data`() { + fun `should include a year of data for each area`() { + createTestAllocation(testAllocation) val result = jdbcTemplate.queryForMap( - "select count(*) as count, min(date) as min_date, max(date) as max_date from water_allocation_and_usage_by_area") + "select count(*) as count, min(date) as min_date, max(date) as max_date from water_allocation_and_usage_by_area where area_id = '${testAllocation.areaId}'") arrayOf(365L, 366L) shouldContain result["count"] as Long val min = LocalDate.parse(result["min_date"].toString()) val max = LocalDate.parse(result["max_date"].toString()) min.plusYears(1) shouldBe max } + @Test + fun `should use default allocation before the effective date`() { + createTestAllocation(testAllocation) + val dateFilter = testEffectiveFrom.toString() + val result = + jdbcTemplate.query( + """select * from water_allocation_and_usage_by_area where date < '$dateFilter'""", + DataClassRowMapper.newInstance(WaterAllocationUsageRow::class.java)) + result.forAll { + it.areaId shouldBe testAllocation.areaId + it.allocation shouldBe BigDecimal(0) + it.allocationDaily shouldBe BigDecimal(0) + it.meteredAllocationYearly shouldBe BigDecimal(0) + it.dailyUsage shouldBe BigDecimal(0) + } + } - // Pending tests - // Single consent - fun `should not include data before a consent was effective`() {} - fun `should data once a consent is active`() {} - fun `should handle changes in consent data`() {} - fun `should not include data when a consent status is not active`() {} - fun `should not include observations when is_metered is false`() {} + @Test + fun `should aggregate allocation from the effective date`() { + createTestAllocation(testAllocation) + val dateFilter = testEffectiveFrom.toString() + val result = + jdbcTemplate.query( + """select * from water_allocation_and_usage_by_area where date >= '$dateFilter'""", + DataClassRowMapper.newInstance(WaterAllocationUsageRow::class.java)) + result.forAll { + it.areaId shouldBe testAllocation.areaId + it.allocation shouldBe testAllocation.allocation + it.allocationDaily shouldBe testAllocation.meteredAllocationDaily + it.meteredAllocationYearly shouldBe testAllocation.meteredAllocationYearly + it.dailyUsage shouldBe BigDecimal(0) + } + } - // Multiple consents - // Multiple meters + fun `should aggregate observation data`() {} + fun `should handle changes to allocations`() {} + fun `should handle changes to allocations in the same day`() {} + fun `should use null data before an allocation is effective`() {} + fun `should handle an allocation being before the earliest time period`() {} + fun `should not include allocation data when a consent status is not active`() {} + fun `should not include an allocations observations when is_metered is false`() {} fun truncateTestData() { jdbcTemplate.execute("truncate water_allocations cascade") @@ -62,29 +143,67 @@ class WaterAllocationAndUsageViewsTest(@Autowired val jdbcTemplate: JdbcTemplate jdbcTemplate.execute("truncate observation_sites cascade") } - fun createTestData() { - val siteId = 1 - val councilId = 9 - val measurementId = 1 - val measurementName = "Water Meter Reading" - val observationTimestamp = "2023-09-10 06:00:00+00" - val consentAreaId = "area-id" - val consentSourceId = "source-id" - val consentAllocation = 10 - val consentEffectiveFrom = "2023-09-01 06:00:00+00" - jdbcTemplate.update( - """INSERT INTO observation_sites (id, council_id, name) VALUES ($siteId, $councilId, 'Test site')""") + fun createTestAllocation(allocation: AllocationRow) { + + val effectiveTo = if (allocation.effectiveTo != null) "'${allocation.effectiveTo}'" else null + val meters = allocation.meters.joinToString(",") + jdbcTemplate.update( """ - INSERT INTO observation_sites_measurements (id, site_id, measurement_name, first_observation_at, last_observation_at, observation_count) - VALUES ($measurementId, $siteId, '$measurementName', now(), now(), 0)""" - .trimIndent()) + INSERT INTO water_allocations (area_id, allocation, ingest_id, source_id, consent_id, status, is_metered, metered_allocation_daily, metered_allocation_yearly, meters, effective_from, effective_to, created_at, updated_at) + VALUES ( + '${allocation.areaId}', + '${allocation.allocation}', + '${allocation.ingestId}', + '${allocation.sourceId}', + '${allocation.consentId}', + '${allocation.status}', + '${allocation.isMetered}', + '${allocation.meteredAllocationDaily}', + '${allocation.meteredAllocationYearly}', + '{$meters}', + '${allocation.effectiveFrom}', + $effectiveTo, + now(), + now() + ) + """) + } + + fun createTestObservation(siteId: Int, amount: Int, timestamp: Instant) { + + val measurementId = createOrRetrieveSiteAndMeasurement(siteId) jdbcTemplate.update( - """INSERT INTO observations (observation_measurement_id, amount, observed_at) VALUES ($measurementId, 1, '$observationTimestamp')""") + """ + INSERT INTO observations (observation_measurement_id, amount, observed_at) + VALUES ($measurementId, $amount, '$timestamp') + """) + } + + fun createOrRetrieveSiteAndMeasurement(siteId: Int): Int { + val councilId = 9 + val measurementName = "Water Meter Reading" + val keyHolder: KeyHolder = GeneratedKeyHolder() + jdbcTemplate.update( """ - INSERT INTO water_allocations (area_id, allocation, ingest_id, source_id, consent_id, status, is_metered, metered_allocation_daily, metered_allocation_yearly, meters, effective_from, effective_to, created_at, updated_at) - VALUES ('$consentAreaId', '$consentAllocation', 'ingest-id', '$consentSourceId', 'consent-id', 'active', true, 10, 100, '{$siteId}', '$consentEffectiveFrom', null, now(), now())""" - .trimIndent()) + INSERT INTO observation_sites (id, council_id, name) + VALUES ($siteId, $councilId, 'Test site') + ON CONFLICT (id) DO NOTHING + """) + + jdbcTemplate.update( + { connection -> + connection.prepareStatement( + """ + INSERT INTO observation_sites_measurements (site_id, measurement_name, first_observation_at, last_observation_at, observation_count) + VALUES ($siteId, '$measurementName', now(), now(), 0) + ON CONFLICT(site_id, measurement_name) DO UPDATE SET measurement_name = '$measurementName' + RETURNING id + """, + arrayOf("id")) + }, + keyHolder) + return keyHolder.keys?.get("id") as Int } } From 5d105d0cc76805b44939af799140f9bcc5ec6b71 Mon Sep 17 00:00:00 2001 From: Vim Date: Thu, 5 Oct 2023 10:29:56 +1300 Subject: [PATCH 04/11] Add tests for various allocation scenarios --- .../WaterAllocationAndUsageViewsTest.kt | 251 +++++++++++++++--- 1 file changed, 211 insertions(+), 40 deletions(-) diff --git a/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt index ea9cb570..b4b460cf 100644 --- a/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt +++ b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt @@ -9,13 +9,11 @@ import java.time.LocalDate import java.time.LocalDateTime import java.time.ZoneOffset import nz.govt.eop.messages.ConsentStatus -import org.junit.jupiter.api.BeforeEach import org.junit.jupiter.api.Test import org.springframework.beans.factory.annotation.Autowired import org.springframework.boot.test.context.SpringBootTest import org.springframework.jdbc.core.DataClassRowMapper import org.springframework.jdbc.core.JdbcTemplate -import org.springframework.jdbc.core.query import org.springframework.jdbc.support.GeneratedKeyHolder import org.springframework.jdbc.support.KeyHolder import org.springframework.test.context.ActiveProfiles @@ -69,72 +67,246 @@ class WaterAllocationAndUsageViewsTest(@Autowired val jdbcTemplate: JdbcTemplate "ingest-id", testEffectiveFrom.toInstant(ZoneOffset.UTC), null) - @BeforeEach - fun resetTestData() { - truncateTestData() - } @Test fun `should be empty with no allocations`() { - truncateTestData() + // GIVEN + // WHEN val result = jdbcTemplate.queryForObject( "select count(*) from water_allocation_and_usage_by_area", Int::class.java) + + // THEN result shouldBe 0 } @Test - fun `should include a year of data for each area`() { + fun `should include a year of data for an area`() { + // GIVEN createTestAllocation(testAllocation) + + // WHEN val result = jdbcTemplate.queryForMap( "select count(*) as count, min(date) as min_date, max(date) as max_date from water_allocation_and_usage_by_area where area_id = '${testAllocation.areaId}'") + + // THEN arrayOf(365L, 366L) shouldContain result["count"] as Long val min = LocalDate.parse(result["min_date"].toString()) val max = LocalDate.parse(result["max_date"].toString()) min.plusYears(1) shouldBe max } @Test - fun `should use default allocation before the effective date`() { + fun `should use default allocation data before the effective date`() { + // GIVEN createTestAllocation(testAllocation) + + // WHEN val dateFilter = testEffectiveFrom.toString() - val result = - jdbcTemplate.query( - """select * from water_allocation_and_usage_by_area where date < '$dateFilter'""", - DataClassRowMapper.newInstance(WaterAllocationUsageRow::class.java)) - result.forAll { - it.areaId shouldBe testAllocation.areaId - it.allocation shouldBe BigDecimal(0) - it.allocationDaily shouldBe BigDecimal(0) - it.meteredAllocationYearly shouldBe BigDecimal(0) - it.dailyUsage shouldBe BigDecimal(0) - } + val results = + queryAllocationsAndUsage( + "where area_id = '${testAllocation.areaId}' and date < '$dateFilter'") + + // THEN + checkResults(results, testAreaId, BigDecimal(0), BigDecimal(0), BigDecimal(0)) } @Test - fun `should aggregate allocation from the effective date`() { + fun `should aggregate allocation data from the effective date`() { + // GIVEN createTestAllocation(testAllocation) + + // WHEN val dateFilter = testEffectiveFrom.toString() + val results = + queryAllocationsAndUsage( + "where area_id = '${testAllocation.areaId}' and date >= '$dateFilter'") + + // THEN + checkResults( + results, + testAllocation.areaId, + testAllocation.allocation, + testAllocation.meteredAllocationDaily, + testAllocation.meteredAllocationYearly) + } + @Test + fun `should handle an allocation being effective before the earliest time period`() { + // GIVEN + val dateOlderThanAYear = LocalDate.now().atStartOfDay().minusYears(2).toInstant(ZoneOffset.UTC) + val oldAllocation = testAllocation.copy(effectiveFrom = dateOlderThanAYear) + createTestAllocation(oldAllocation) + + // WHEN + val results = + queryAllocationsAndUsage( + "where area_id = '${oldAllocation.areaId}' and date >= '$dateOlderThanAYear'") + + // THEN + checkResults( + results, + oldAllocation.areaId, + oldAllocation.allocation, + oldAllocation.meteredAllocationDaily, + oldAllocation.meteredAllocationYearly) + } + + @Test + fun `should aggregate observation data`() { + // GIVEN + val observationDate = LocalDate.now().atStartOfDay().minusDays(10) + createTestAllocation(testAllocation) + createTestObservation(testSiteId, 10, observationDate.toInstant(ZoneOffset.UTC)) + + // WHEN + val whereClause = "where area_id = '${testAllocation.areaId}' and date = '${observationDate}'" + + // THEN + val result = queryAllocationsAndUsage(whereClause) + result.size shouldBe 1 + result[0].dailyUsage.compareTo(BigDecimal(864)) shouldBe 0 + + // GIVEN + createTestObservation(testSiteId, 5, observationDate.plusHours(1).toInstant(ZoneOffset.UTC)) + + // WHEN + val secondResult = queryAllocationsAndUsage(whereClause) + + // THEN + secondResult[0].dailyUsage.compareTo(BigDecimal(648)) shouldBe 0 + } + + @Test + fun `should handle changes to allocation data`() { + // GIVEN + val allocationUpdatedAt = LocalDate.now().atStartOfDay().minusDays(10) + val initialAllocation = + testAllocation.copy(effectiveTo = allocationUpdatedAt.toInstant(ZoneOffset.UTC)) + createTestAllocation(initialAllocation) + val updateAllocation = + testAllocation.copy( + allocation = BigDecimal(200), + meteredAllocationDaily = BigDecimal(20), + meteredAllocationYearly = BigDecimal(20), + meters = listOf(), + effectiveFrom = allocationUpdatedAt.toInstant(ZoneOffset.UTC)) + createTestAllocation(updateAllocation) + createTestObservation(testSiteId, 10, allocationUpdatedAt.toInstant(ZoneOffset.UTC)) + + // WHEN + val resultBeforeUpdate = + queryAllocationsAndUsage( + "where area_id = '${initialAllocation.areaId}' and date >= '${initialAllocation.effectiveFrom}' and date < '${allocationUpdatedAt}'") + + // THEN + checkResults( + resultBeforeUpdate, + initialAllocation.areaId, + initialAllocation.allocation, + initialAllocation.meteredAllocationDaily, + initialAllocation.meteredAllocationYearly, + BigDecimal(0)) + + // WHEN + val resultAfterUpdate = + queryAllocationsAndUsage( + "where area_id = '${updateAllocation.areaId}' and date >= '${allocationUpdatedAt}'") + + // THEN + checkResults( + resultAfterUpdate, + updateAllocation.areaId, + updateAllocation.allocation, + updateAllocation.meteredAllocationDaily, + updateAllocation.meteredAllocationYearly, + BigDecimal(0)) + } + + @Test + fun `should handle changes to allocation data in the same day`() { + // GIVEN + val firstAllocationUpdatedAt = LocalDate.now().atStartOfDay().minusDays(10) + val secondAllocationUpdatedAt = firstAllocationUpdatedAt.plusHours(2) + createTestAllocation( + testAllocation.copy(effectiveTo = firstAllocationUpdatedAt.toInstant(ZoneOffset.UTC))) + createTestAllocation( + testAllocation.copy( + allocation = BigDecimal(20), + effectiveFrom = firstAllocationUpdatedAt.toInstant(ZoneOffset.UTC), + effectiveTo = secondAllocationUpdatedAt.toInstant(ZoneOffset.UTC))) + createTestAllocation( + testAllocation.copy( + allocation = BigDecimal(30), + effectiveFrom = secondAllocationUpdatedAt.toInstant(ZoneOffset.UTC))) + + // WHEN + val results = + queryAllocationsAndUsage( + "where area_id = '${testAllocation.areaId}' and date = '${secondAllocationUpdatedAt}'") + + // THEN + checkResults(results, testAreaId, allocation = BigDecimal(30)) + } + @Test + fun `should not include allocation data when a consent status is not active`() { + // GIVEN + val allocationUpdatedAt = LocalDate.now().atStartOfDay().minusDays(10) + val initialAllocation = + testAllocation.copy(effectiveTo = allocationUpdatedAt.toInstant(ZoneOffset.UTC)) + createTestAllocation(initialAllocation) + val updatedAllocation = + testAllocation.copy( + effectiveFrom = allocationUpdatedAt.toInstant(ZoneOffset.UTC), + status = ConsentStatus.inactive) + createTestAllocation(updatedAllocation) + + // WHEN + val results = + queryAllocationsAndUsage( + "where area_id = '${updatedAllocation.areaId}' and date >= '${allocationUpdatedAt}'") + + // THEN + checkResults(results, updatedAllocation.areaId, BigDecimal(0), BigDecimal(0), BigDecimal(0)) + } + @Test + fun `should not include an allocations observations when is_metered is false`() { + // GIVEN + val allocationWithIsMeteredFalse = testAllocation.copy(isMetered = false) + createTestAllocation(allocationWithIsMeteredFalse) + val observationDate = LocalDate.now().atStartOfDay().minusDays(10) + createTestObservation(testSiteId, 10, observationDate.toInstant(ZoneOffset.UTC)) + + // WHEN val result = - jdbcTemplate.query( - """select * from water_allocation_and_usage_by_area where date >= '$dateFilter'""", - DataClassRowMapper.newInstance(WaterAllocationUsageRow::class.java)) - result.forAll { - it.areaId shouldBe testAllocation.areaId - it.allocation shouldBe testAllocation.allocation - it.allocationDaily shouldBe testAllocation.meteredAllocationDaily - it.meteredAllocationYearly shouldBe testAllocation.meteredAllocationYearly - it.dailyUsage shouldBe BigDecimal(0) - } + queryAllocationsAndUsage( + "where area_id = '${testAllocation.areaId}' and date = '${observationDate}'") + + // THEN + result[0].dailyUsage.compareTo(BigDecimal(0)) shouldBe 0 } - fun `should aggregate observation data`() {} - fun `should handle changes to allocations`() {} - fun `should handle changes to allocations in the same day`() {} - fun `should use null data before an allocation is effective`() {} - fun `should handle an allocation being before the earliest time period`() {} - fun `should not include allocation data when a consent status is not active`() {} - fun `should not include an allocations observations when is_metered is false`() {} + fun queryAllocationsAndUsage(whereClause: String): MutableList = + jdbcTemplate.query( + """select * from water_allocation_and_usage_by_area $whereClause""", + DataClassRowMapper.newInstance(WaterAllocationUsageRow::class.java)) + + fun checkResults( + results: List, + areaId: String? = null, + allocation: BigDecimal? = null, + meteredAllocationDaily: BigDecimal? = null, + meteredAllocationYearly: BigDecimal? = null, + dailyUsage: BigDecimal? = null + ) { + results.forAll { + if (areaId != null) it.areaId shouldBe areaId + if (allocation != null) it.allocation shouldBe allocation + if (meteredAllocationDaily != null) it.allocationDaily shouldBe meteredAllocationDaily + if (meteredAllocationYearly != null) + it.meteredAllocationYearly shouldBe meteredAllocationYearly + if (dailyUsage != null) it.dailyUsage shouldBe dailyUsage + } + } fun truncateTestData() { jdbcTemplate.execute("truncate water_allocations cascade") @@ -144,7 +316,6 @@ class WaterAllocationAndUsageViewsTest(@Autowired val jdbcTemplate: JdbcTemplate } fun createTestAllocation(allocation: AllocationRow) { - val effectiveTo = if (allocation.effectiveTo != null) "'${allocation.effectiveTo}'" else null val meters = allocation.meters.joinToString(",") @@ -182,7 +353,7 @@ class WaterAllocationAndUsageViewsTest(@Autowired val jdbcTemplate: JdbcTemplate fun createOrRetrieveSiteAndMeasurement(siteId: Int): Int { val councilId = 9 - val measurementName = "Water Meter Reading" + val measurementName = "Water Meter Volume" val keyHolder: KeyHolder = GeneratedKeyHolder() jdbcTemplate.update( From 79c673b62d623b2a6850da185ff06cd1b2d32fba Mon Sep 17 00:00:00 2001 From: Vim Date: Thu, 5 Oct 2023 14:57:40 +1300 Subject: [PATCH 05/11] Add failing test for aggregating data across different areas --- .../WaterAllocationAndUsageViewsTest.kt | 47 ++++++++++++++++++- 1 file changed, 46 insertions(+), 1 deletion(-) diff --git a/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt index b4b460cf..9b9684ff 100644 --- a/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt +++ b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt @@ -285,6 +285,51 @@ class WaterAllocationAndUsageViewsTest(@Autowired val jdbcTemplate: JdbcTemplate result[0].dailyUsage.compareTo(BigDecimal(0)) shouldBe 0 } + @Test + fun `should aggregate allocation data for different areas separately`() { + // GIVEN + createTestAllocation(testAllocation) + val secondAllocationInSameArea = + testAllocation.copy(sourceId = "another-source-same-area", meters = listOf("2", "3")) + createTestAllocation(secondAllocationInSameArea) + + val allocationInDifferentArea = + testAllocation.copy( + areaId = "different-area-id", + sourceId = "another-source-different-area", + meters = listOf("4")) + createTestAllocation(allocationInDifferentArea) + + val observationDate = LocalDate.now().atStartOfDay().minusDays(10) + createTestObservation(testSiteId, 10, observationDate.toInstant(ZoneOffset.UTC)) + createTestObservation( + secondAllocationInSameArea.meters[0].toInt(), 5, observationDate.toInstant(ZoneOffset.UTC)) + createTestObservation( + secondAllocationInSameArea.meters[1].toInt(), 5, observationDate.toInstant(ZoneOffset.UTC)) + createTestObservation( + allocationInDifferentArea.meters.first().toInt(), + 30, + observationDate.toInstant(ZoneOffset.UTC)) + + // WHEN + val results = + queryAllocationsAndUsage( + "where area_id = '${testAllocation.areaId}' and date = '$observationDate'") + + // THEN + results.size shouldBe 1 + checkResults( + results, + testAllocation.areaId, + testAllocation.allocation + secondAllocationInSameArea.allocation, + testAllocation.meteredAllocationDaily + secondAllocationInSameArea.meteredAllocationDaily, + testAllocation.meteredAllocationYearly + secondAllocationInSameArea.meteredAllocationYearly) + + // TODO: Add an assertion for the aggregated amount in results for testAllocation.areaId + // TODO: Add assertions for separate results matching allocationInDifferentArea.areaId + + } + fun queryAllocationsAndUsage(whereClause: String): MutableList = jdbcTemplate.query( """select * from water_allocation_and_usage_by_area $whereClause""", @@ -359,7 +404,7 @@ class WaterAllocationAndUsageViewsTest(@Autowired val jdbcTemplate: JdbcTemplate jdbcTemplate.update( """ INSERT INTO observation_sites (id, council_id, name) - VALUES ($siteId, $councilId, 'Test site') + VALUES ($siteId, $councilId, 'Test site $siteId') ON CONFLICT (id) DO NOTHING """) From 862830295e5c7ebc93d437025bc544d34bb7174c Mon Sep 17 00:00:00 2001 From: Vim Date: Fri, 6 Oct 2023 15:19:46 +1300 Subject: [PATCH 06/11] Simplify views --- .../V0032__effective_daily_consents.sql | 73 ++++--------------- ...33__water_allocation_and_usage_by_area.sql | 63 +++++++++------- .../WaterAllocationAndUsageViewsTest.kt | 2 +- 3 files changed, 54 insertions(+), 84 deletions(-) diff --git a/packages/Manager/src/main/resources/db/migration/V0032__effective_daily_consents.sql b/packages/Manager/src/main/resources/db/migration/V0032__effective_daily_consents.sql index 35fbcaf3..9c135c42 100644 --- a/packages/Manager/src/main/resources/db/migration/V0032__effective_daily_consents.sql +++ b/packages/Manager/src/main/resources/db/migration/V0032__effective_daily_consents.sql @@ -1,73 +1,30 @@ 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 + 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') as effective_from + 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 - 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 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 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 + 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 grouped_effective_data +select * from effective_daily_data diff --git a/packages/Manager/src/main/resources/db/migration/V0033__water_allocation_and_usage_by_area.sql b/packages/Manager/src/main/resources/db/migration/V0033__water_allocation_and_usage_by_area.sql index 1a25e862..78ba0772 100644 --- a/packages/Manager/src/main/resources/db/migration/V0033__water_allocation_and_usage_by_area.sql +++ b/packages/Manager/src/main/resources/db/migration/V0033__water_allocation_and_usage_by_area.sql @@ -1,31 +1,44 @@ 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 + +with all_days as ( + select distinct effective_on from effective_daily_consents ), -all_dates as ( - select distinct date(effective_from) as date +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 ), -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 null end as daily_usage +data_per_day as ( + select * from all_days cross join all_areas +) +, +effective_consents_with_defaults as +( + select * from data_per_day + union + select effective_on, area_id, allocation, metered_allocation_daily, metered_allocation_yearly, is_metered, meters, status from effective_daily_consents - left outer 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 + where area_id is not null + and status = 'active' ) - -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 +select + area_id, + date(effective_on) as date, + sum(allocation) as allocation, + sum(metered_allocation_daily) as allocation_daily, + sum(metered_allocation_yearly) as metered_allocation_yearly, + coalesce(sum(case when is_metered = true then daily_usage else 0 end), 0) as daily_usage +from effective_consents_with_defaults edc +left join observed_water_use_aggregated_daily owuage +on edc.effective_on = owuage.day_observed_at +and owuage.site_id::varchar in(select unnest(meters)) +and status = 'active' +group by area_id, effective_on +order by date \ No newline at end of file diff --git a/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt index 9b9684ff..f30911ad 100644 --- a/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt +++ b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt @@ -94,7 +94,7 @@ class WaterAllocationAndUsageViewsTest(@Autowired val jdbcTemplate: JdbcTemplate arrayOf(365L, 366L) shouldContain result["count"] as Long val min = LocalDate.parse(result["min_date"].toString()) val max = LocalDate.parse(result["max_date"].toString()) - min.plusYears(1) shouldBe max + min.plusYears(1).plusDays(-1) shouldBe max } @Test fun `should use default allocation data before the effective date`() { From fa1b7414fc399a7014728adbac191c0ae299d8a6 Mon Sep 17 00:00:00 2001 From: Steve Mosley Date: Mon, 9 Oct 2023 16:53:59 +1300 Subject: [PATCH 07/11] Splitting out the calculation of daily useage by area --- ...ts.sql => R__effective_daily_consents.sql} | 0 .../R__water_allocation_and_usage_by_area.sql | 71 +++++++++++++++++++ ...33__water_allocation_and_usage_by_area.sql | 44 ------------ 3 files changed, 71 insertions(+), 44 deletions(-) rename packages/Manager/src/main/resources/db/migration/{V0032__effective_daily_consents.sql => R__effective_daily_consents.sql} (100%) create mode 100644 packages/Manager/src/main/resources/db/migration/R__water_allocation_and_usage_by_area.sql delete mode 100644 packages/Manager/src/main/resources/db/migration/V0033__water_allocation_and_usage_by_area.sql diff --git a/packages/Manager/src/main/resources/db/migration/V0032__effective_daily_consents.sql b/packages/Manager/src/main/resources/db/migration/R__effective_daily_consents.sql similarity index 100% rename from packages/Manager/src/main/resources/db/migration/V0032__effective_daily_consents.sql rename to packages/Manager/src/main/resources/db/migration/R__effective_daily_consents.sql diff --git a/packages/Manager/src/main/resources/db/migration/R__water_allocation_and_usage_by_area.sql b/packages/Manager/src/main/resources/db/migration/R__water_allocation_and_usage_by_area.sql new file mode 100644 index 00000000..69ac0bcd --- /dev/null +++ b/packages/Manager/src/main/resources/db/migration/R__water_allocation_and_usage_by_area.sql @@ -0,0 +1,71 @@ +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' +), +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_aggregated_daily use on effective_on = day_observed_at and meter = site_id::varchar), +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 \ No newline at end of file diff --git a/packages/Manager/src/main/resources/db/migration/V0033__water_allocation_and_usage_by_area.sql b/packages/Manager/src/main/resources/db/migration/V0033__water_allocation_and_usage_by_area.sql deleted file mode 100644 index 78ba0772..00000000 --- a/packages/Manager/src/main/resources/db/migration/V0033__water_allocation_and_usage_by_area.sql +++ /dev/null @@ -1,44 +0,0 @@ -create or replace view water_allocation_and_usage_by_area as - -with all_days as ( - select distinct 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 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' -) -select - area_id, - date(effective_on) as date, - sum(allocation) as allocation, - sum(metered_allocation_daily) as allocation_daily, - sum(metered_allocation_yearly) as metered_allocation_yearly, - coalesce(sum(case when is_metered = true then daily_usage else 0 end), 0) as daily_usage -from effective_consents_with_defaults edc -left join observed_water_use_aggregated_daily owuage -on edc.effective_on = owuage.day_observed_at -and owuage.site_id::varchar in(select unnest(meters)) -and status = 'active' -group by area_id, effective_on -order by date \ No newline at end of file From 6608714ce044a32a304bcd433706d7b712b60a95 Mon Sep 17 00:00:00 2001 From: Vim Date: Tue, 10 Oct 2023 09:41:06 +1300 Subject: [PATCH 08/11] Add more assertions for aggregation of different areas --- .../WaterAllocationAndUsageViewsTest.kt | 26 +++++++++---------- 1 file changed, 12 insertions(+), 14 deletions(-) diff --git a/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt index f30911ad..55c395cc 100644 --- a/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt +++ b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt @@ -323,11 +323,16 @@ class WaterAllocationAndUsageViewsTest(@Autowired val jdbcTemplate: JdbcTemplate testAllocation.areaId, testAllocation.allocation + secondAllocationInSameArea.allocation, testAllocation.meteredAllocationDaily + secondAllocationInSameArea.meteredAllocationDaily, - testAllocation.meteredAllocationYearly + secondAllocationInSameArea.meteredAllocationYearly) + testAllocation.meteredAllocationYearly + secondAllocationInSameArea.meteredAllocationYearly, + BigDecimal(1728)) - // TODO: Add an assertion for the aggregated amount in results for testAllocation.areaId - // TODO: Add assertions for separate results matching allocationInDifferentArea.areaId + // WHEN + val resultsInADifferentArea = + queryAllocationsAndUsage( + "where area_id = '${allocationInDifferentArea.areaId}' and date = '$observationDate'") + // THEN + resultsInADifferentArea[0].dailyUsage.compareTo(BigDecimal(2592)) shouldBe 0 } fun queryAllocationsAndUsage(whereClause: String): MutableList = @@ -345,21 +350,14 @@ class WaterAllocationAndUsageViewsTest(@Autowired val jdbcTemplate: JdbcTemplate ) { results.forAll { if (areaId != null) it.areaId shouldBe areaId - if (allocation != null) it.allocation shouldBe allocation - if (meteredAllocationDaily != null) it.allocationDaily shouldBe meteredAllocationDaily + if (allocation != null) it.allocation.compareTo(allocation) shouldBe 0 + if (meteredAllocationDaily != null) it.allocationDaily.compareTo(meteredAllocationDaily) shouldBe 0 if (meteredAllocationYearly != null) - it.meteredAllocationYearly shouldBe meteredAllocationYearly - if (dailyUsage != null) it.dailyUsage shouldBe dailyUsage + it.meteredAllocationYearly.compareTo(meteredAllocationYearly) shouldBe 0 + if (dailyUsage != null) it.dailyUsage.compareTo(dailyUsage) shouldBe 0 } } - fun truncateTestData() { - jdbcTemplate.execute("truncate water_allocations cascade") - jdbcTemplate.execute("truncate observations cascade") - jdbcTemplate.execute("truncate observation_sites_measurements cascade") - jdbcTemplate.execute("truncate observation_sites cascade") - } - fun createTestAllocation(allocation: AllocationRow) { val effectiveTo = if (allocation.effectiveTo != null) "'${allocation.effectiveTo}'" else null val meters = allocation.meters.joinToString(",") From 947053b7bb0e761c18ebddf499b3317b64911e49 Mon Sep 17 00:00:00 2001 From: Vim Date: Tue, 10 Oct 2023 12:35:37 +1300 Subject: [PATCH 09/11] water_allocation.meter should correlate with observation_site.name --- .../db/migration/R__water_allocation_and_usage_by_area.sql | 7 ++++++- .../eop/plan_limits/WaterAllocationAndUsageViewsTest.kt | 2 +- 2 files changed, 7 insertions(+), 2 deletions(-) diff --git a/packages/Manager/src/main/resources/db/migration/R__water_allocation_and_usage_by_area.sql b/packages/Manager/src/main/resources/db/migration/R__water_allocation_and_usage_by_area.sql index 69ac0bcd..47100cbd 100644 --- a/packages/Manager/src/main/resources/db/migration/R__water_allocation_and_usage_by_area.sql +++ b/packages/Manager/src/main/resources/db/migration/R__water_allocation_and_usage_by_area.sql @@ -33,6 +33,11 @@ effective_consents_with_defaults as ( 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, @@ -40,7 +45,7 @@ meter_use_by_area as (select effective_on, meter, use.daily_usage from expanded_meters_per_area - left join observed_water_use_aggregated_daily use on effective_on = day_observed_at and meter = site_id::varchar), + 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 diff --git a/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt index 55c395cc..3efa8006 100644 --- a/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt +++ b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt @@ -402,7 +402,7 @@ class WaterAllocationAndUsageViewsTest(@Autowired val jdbcTemplate: JdbcTemplate jdbcTemplate.update( """ INSERT INTO observation_sites (id, council_id, name) - VALUES ($siteId, $councilId, 'Test site $siteId') + VALUES ($siteId, $councilId, '$siteId') ON CONFLICT (id) DO NOTHING """) From a98dbbd028d4cb739a6da910cf762648f8b1dc9d Mon Sep 17 00:00:00 2001 From: Vim Date: Tue, 10 Oct 2023 12:37:39 +1300 Subject: [PATCH 10/11] Format code --- .../WaterAllocationAndUsageViewsTest.kt | 15 ++++++++------- 1 file changed, 8 insertions(+), 7 deletions(-) diff --git a/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt index 3efa8006..71cb4e2b 100644 --- a/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt +++ b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt @@ -326,13 +326,13 @@ class WaterAllocationAndUsageViewsTest(@Autowired val jdbcTemplate: JdbcTemplate testAllocation.meteredAllocationYearly + secondAllocationInSameArea.meteredAllocationYearly, BigDecimal(1728)) - // WHEN - val resultsInADifferentArea = - queryAllocationsAndUsage( - "where area_id = '${allocationInDifferentArea.areaId}' and date = '$observationDate'") + // WHEN + val resultsInADifferentArea = + queryAllocationsAndUsage( + "where area_id = '${allocationInDifferentArea.areaId}' and date = '$observationDate'") - // THEN - resultsInADifferentArea[0].dailyUsage.compareTo(BigDecimal(2592)) shouldBe 0 + // THEN + resultsInADifferentArea[0].dailyUsage.compareTo(BigDecimal(2592)) shouldBe 0 } fun queryAllocationsAndUsage(whereClause: String): MutableList = @@ -351,7 +351,8 @@ class WaterAllocationAndUsageViewsTest(@Autowired val jdbcTemplate: JdbcTemplate results.forAll { if (areaId != null) it.areaId shouldBe areaId if (allocation != null) it.allocation.compareTo(allocation) shouldBe 0 - if (meteredAllocationDaily != null) it.allocationDaily.compareTo(meteredAllocationDaily) shouldBe 0 + if (meteredAllocationDaily != null) + it.allocationDaily.compareTo(meteredAllocationDaily) shouldBe 0 if (meteredAllocationYearly != null) it.meteredAllocationYearly.compareTo(meteredAllocationYearly) shouldBe 0 if (dailyUsage != null) it.dailyUsage.compareTo(dailyUsage) shouldBe 0 From a5e9c88a44ebf4367970b41a4cbf45fe5672d9a1 Mon Sep 17 00:00:00 2001 From: Vim Date: Tue, 10 Oct 2023 15:48:08 +1300 Subject: [PATCH 11/11] Feedback from PR review --- .../nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt | 1 + 1 file changed, 1 insertion(+) diff --git a/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt index 71cb4e2b..3ed59470 100644 --- a/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt +++ b/packages/Manager/src/test/kotlin/nz/govt/eop/plan_limits/WaterAllocationAndUsageViewsTest.kt @@ -268,6 +268,7 @@ class WaterAllocationAndUsageViewsTest(@Autowired val jdbcTemplate: JdbcTemplate // THEN checkResults(results, updatedAllocation.areaId, BigDecimal(0), BigDecimal(0), BigDecimal(0)) } + @Test fun `should not include an allocations observations when is_metered is false`() { // GIVEN