Skip to content

Commit

Permalink
Replace all aggregate land calculations with pulls from agg land view (
Browse files Browse the repository at this point in the history
  • Loading branch information
wrridgeway authored Aug 30, 2023
1 parent 4540f35 commit 8e7a22f
Show file tree
Hide file tree
Showing 7 changed files with 71 additions and 20 deletions.
13 changes: 6 additions & 7 deletions aws-athena/views/default-vw_card_res_char.sql
Original file line number Diff line number Diff line change
Expand Up @@ -12,13 +12,12 @@ WITH multicodes AS (

aggregate_land AS (
SELECT
parid,
taxyr,
COALESCE(COUNT(*) > 1, FALSE) AS pin_is_multiland,
COUNT(*) AS pin_num_landlines,
SUM(sf) AS total_land_sf
FROM {{ source('iasworld', 'land') }}
GROUP BY parid, taxyr
pin AS parid,
year AS taxyr,
COALESCE(num_landlines > 1, FALSE) AS pin_is_multiland,
num_landlines AS pin_num_landlines,
sf AS total_land_sf
FROM {{ ref('default.vw_pin_land') }}
),

townships AS (
Expand Down
13 changes: 6 additions & 7 deletions aws-athena/views/default-vw_pin_condo_char.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,13 +11,12 @@ workbooks rather than iasWorld.

WITH aggregate_land AS (
SELECT
parid,
taxyr,
COALESCE(COUNT(*) > 1, FALSE) AS pin_is_multiland,
COUNT(*) AS pin_num_landlines,
SUM(sf) AS total_building_land_sf
FROM {{ source('iasworld', 'land') }}
GROUP BY parid, taxyr
pin AS parid,
year AS taxyr,
COALESCE(num_landlines > 1, FALSE) AS pin_is_multiland,
num_landlines AS pin_num_landlines,
sf AS total_building_land_sf
FROM {{ ref('default.vw_pin_land') }}
),

-- Valuations-provided PINs that shouldn't be considered parking spaces
Expand Down
46 changes: 46 additions & 0 deletions aws-athena/views/default-vw_pin_land.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,46 @@
-- A view to properly aggregate land square footage at the PIN level. Parcels
-- can have multiple land lines that are sometimes summed or ignored.
WITH total_influ AS (
SELECT
land.parid,
land.taxyr,
land.lline,
COUNT(*)
OVER (PARTITION BY land.parid, land.taxyr)
AS num_landlines,
SUM(land.sf) OVER (PARTITION BY land.parid, land.taxyr) AS sf_sum,
-- We explicitly want to take the top line land sf if we're only taking
-- one line.
FIRST_VALUE(land.sf)
OVER (PARTITION BY land.parid, land.taxyr ORDER BY land.lline)
AS sf_top,
SUM(CASE WHEN land.influ IS NULL THEN 0 ELSE 1 END)
OVER (PARTITION BY land.parid, land.taxyr)
AS non_null_influ,
MAX(land.sf) OVER (PARTITION BY land.parid, land.taxyr) AS max_sf,
MIN(land.sf) OVER (PARTITION BY land.parid, land.taxyr) AS min_sf,
-- When the first landline for a pin is deactived we should take the
-- minimum value of lline as the top line.
MIN(land.lline) OVER (PARTITION BY land.parid, land.taxyr) AS top_line
FROM {{ source('iasworld', 'land') }} AS land
WHERE
land.cur = 'Y'
AND land.deactivat IS NULL
)

SELECT
total_influ.parid AS pin,
total_influ.taxyr AS year,
total_influ.num_landlines,
CASE
-- When there are multiple non-null values for influ across land lines
-- and all sf values are the same, we choose the topline land sf,
-- otherwise we sum land sf.
WHEN
total_influ.non_null_influ > 1
AND total_influ.max_sf = total_influ.min_sf
THEN total_influ.sf_top
ELSE total_influ.sf_sum
END AS sf
FROM total_influ
WHERE total_influ.lline = total_influ.top_line
10 changes: 5 additions & 5 deletions aws-athena/views/reporting-vw_res_report_summary.sql
Original file line number Diff line number Diff line change
Expand Up @@ -190,13 +190,13 @@ sales AS (
-- Aggregate land for all parcels
aggregate_land AS (
SELECT
parid,
taxyr,
SUM(sf) AS total_land_sf
FROM {{ source('iasworld', 'land') }}
GROUP BY parid, taxyr
pin AS parid,
year AS taxyr,
sf AS total_land_sf
FROM {{ ref('default.vw_pin_land') }}
),


-- Combined SF/MF and condo characteristics
chars AS (
SELECT
Expand Down
1 change: 1 addition & 0 deletions dbt/models/default/default.vw_pin_land.sql
4 changes: 4 additions & 0 deletions dbt/models/default/docs.md
Original file line number Diff line number Diff line change
Expand Up @@ -98,3 +98,7 @@ Source of truth view for PIN location.
for current year can be relatively sparse
* `spatial.township` is not yearly
{% enddocs %}

{% docs vw_pin_land %}
View containing aggregated land square footage.
{% enddocs %}
4 changes: 3 additions & 1 deletion dbt/models/default/schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -89,7 +89,7 @@ models:
- char_renovation
- char_recent_renovation
config:
error_if: ">73941"
error_if: ">73942"
# TODO: Characteristics columns should adhere to pre-determined criteria
- name: default.vw_pin_address
description: '{{ doc("vw_pin_address") }}'
Expand Down Expand Up @@ -135,6 +135,8 @@ models:
# 10-digit PIN
# TODO: Sum of proration rate never exceeds 1 per 10-digit PIN
# TODO: Characteristics columns should adhere to pre-determined criteria
- name: default.vw_pin_land
description: '{{ doc("vw_pin_land") }}'
- name: default.vw_pin_sale
description: '{{ doc("vw_pin_sale") }}'
columns:
Expand Down

0 comments on commit 8e7a22f

Please sign in to comment.