Skip to content

Commit

Permalink
Update dbt views to select from other dbt models where possible (#71)
Browse files Browse the repository at this point in the history
* Update dbt views to select from other dbt models where possible

* Bump error threshold for vw_pin_appeal tests again

* Switch to dot notation for namespacing dbt resources

* Switch to using sources for dbt resources created outside the DAG
  • Loading branch information
jeancochrane authored Aug 17, 2023
1 parent b1e3182 commit 7a3d0e0
Show file tree
Hide file tree
Showing 218 changed files with 503 additions and 633 deletions.
6 changes: 3 additions & 3 deletions aws-athena/views/census-vw_acs5_stat.sql
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
-- View to convert raw ACS5 variables into useable statistics
WITH distinct_years AS (
SELECT DISTINCT year
FROM spatial.parcel
FROM {{ source('spatial', 'parcel') }}
),

acs5_forward_fill AS (
Expand All @@ -12,12 +12,12 @@ acs5_forward_fill AS (
SELECT
dy.year AS filled_year,
MAX(df.year) AS fill_year
FROM census.acs5 AS df
FROM {{ source('census', 'acs5') }} AS df
CROSS JOIN distinct_years AS dy
WHERE dy.year >= df.year
GROUP BY dy.year
) AS fill_years
LEFT JOIN census.acs5 AS fill_data
LEFT JOIN {{ source('census', 'acs5') }} AS fill_data
ON fill_years.fill_year = fill_data.year
)

Expand Down
10 changes: 5 additions & 5 deletions aws-athena/views/default-vw_card_res_char.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,7 @@ WITH multicodes AS (
taxyr,
COALESCE(COUNT(*) > 1, FALSE) AS pin_is_multicard,
COUNT(*) AS pin_num_cards
FROM iasworld.dweldat
FROM {{ source('iasworld', 'dweldat') }}
GROUP BY parid, taxyr
),

Expand All @@ -17,7 +17,7 @@ aggregate_land AS (
COALESCE(COUNT(*) > 1, FALSE) AS pin_is_multiland,
COUNT(*) AS pin_num_landlines,
SUM(sf) AS total_land_sf
FROM iasworld.land
FROM {{ source('iasworld', 'land') }}
GROUP BY parid, taxyr
),

Expand All @@ -26,7 +26,7 @@ townships AS (
parid,
taxyr,
user1 AS township_code
FROM iasworld.legdat
FROM {{ source('iasworld', 'legdat') }}
)

SELECT
Expand Down Expand Up @@ -128,8 +128,8 @@ SELECT
dwel.user7 AS char_air,
dwel.user5 AS char_tp_plan

FROM iasworld.dweldat AS dwel
LEFT JOIN iasworld.pardat
FROM {{ source('iasworld', 'dweldat') }} AS dwel
LEFT JOIN {{ source('iasworld', 'pardat') }} AS pardat
ON dwel.parid = pardat.parid
AND dwel.taxyr = pardat.taxyr
LEFT JOIN multicodes
Expand Down
6 changes: 3 additions & 3 deletions aws-athena/views/default-vw_pin_address.sql
Original file line number Diff line number Diff line change
Expand Up @@ -48,10 +48,10 @@ SELECT
NULLIF(own.zip1, '00000') AS mail_address_zipcode_1,
NULLIF(own.zip2, '0000') AS mail_address_zipcode_2

FROM iasworld.pardat AS par
LEFT JOIN iasworld.legdat AS leg
FROM {{ source('iasworld', 'pardat') }} AS par
LEFT JOIN {{ source('iasworld', 'legdat') }} AS leg
ON par.parid = leg.parid
AND par.taxyr = leg.taxyr
LEFT JOIN iasworld.owndat AS own
LEFT JOIN {{ source('iasworld', 'owndat') }} AS own
ON par.parid = own.parid
AND par.taxyr = own.taxyr
10 changes: 5 additions & 5 deletions aws-athena/views/default-vw_pin_appeal.sql
Original file line number Diff line number Diff line change
Expand Up @@ -61,17 +61,17 @@ SELECT
WHEN htpar.hrstatus = 'P' THEN 'pending'
WHEN htpar.hrstatus = 'X' THEN 'closed pending c of e'
END AS status
FROM iasworld.htpar
LEFT JOIN iasworld.pardat
FROM {{ source('iasworld', 'htpar') }} AS htpar
LEFT JOIN {{ source('iasworld', 'pardat') }} AS pardat
ON htpar.parid = pardat.parid
AND htpar.taxyr = pardat.taxyr
LEFT JOIN iasworld.legdat
LEFT JOIN {{ source('iasworld', 'legdat') }} AS legdat
ON htpar.parid = legdat.parid
AND htpar.taxyr = legdat.taxyr
LEFT JOIN {{ ref('vw_pin_value') }} AS vwpv
LEFT JOIN {{ ref('default.vw_pin_value') }} AS vwpv
ON htpar.parid = vwpv.pin
AND htpar.taxyr = vwpv.year
LEFT JOIN iasworld.htagnt
LEFT JOIN {{ source('iasworld', 'htagnt') }} AS htagnt
ON htpar.cpatty = htagnt.agent
WHERE htpar.cur = 'Y'
AND htpar.caseno IS NOT NULL
18 changes: 9 additions & 9 deletions aws-athena/views/default-vw_pin_condo_char.sql
Original file line number Diff line number Diff line change
Expand Up @@ -16,7 +16,7 @@ WITH aggregate_land AS (
COALESCE(COUNT(*) > 1, FALSE) AS pin_is_multiland,
COUNT(*) AS pin_num_landlines,
SUM(sf) AS total_building_land_sf
FROM iasworld.land
FROM {{ source('iasworld', 'land') }}
GROUP BY parid, taxyr
),

Expand All @@ -25,7 +25,7 @@ questionable_gr AS (
SELECT
pin,
TRUE AS is_question_garage_unit
FROM ccao.pin_questionable_garage_units
FROM {{ source('ccao', 'pin_questionable_garage_units') }}
),

-- For some reason PINs can have cur != 'Y' in the current year even
Expand All @@ -40,7 +40,7 @@ oby_filtered AS (
ROW_NUMBER()
OVER (PARTITION BY parid, taxyr ORDER BY wen DESC)
AS row_no
FROM iasworld.oby
FROM {{ source('iasworld', 'oby') }}
WHERE class IN ('299', '2-99', '200')
)
WHERE (cur = 'Y' OR (cur_count = 0 AND row_no = 1))
Expand All @@ -56,7 +56,7 @@ comdat_filtered AS (
ROW_NUMBER()
OVER (PARTITION BY parid, taxyr ORDER BY wen DESC)
AS row_no
FROM iasworld.comdat
FROM {{ source('iasworld', 'comdat') }}
WHERE class = '399'
)
WHERE (cur = 'Y' OR (cur_count = 0 AND row_no = 1))
Expand All @@ -80,7 +80,7 @@ prior_values AS (
THEN valasm3
END
) AS oneyr_pri_board_tot
FROM iasworld.asmt_all
FROM {{ source('iasworld', 'asmt_all') }}
WHERE class IN ('299', '2-99', '399')
GROUP BY parid, taxyr
),
Expand Down Expand Up @@ -185,7 +185,7 @@ chars AS (
)
> 0, FALSE)
AS bldg_is_mixed_use
FROM iasworld.pardat AS par
FROM {{ source('iasworld', 'pardat') }} AS par

-- Left joins because par contains both 299s & 399s (oby and comdat
-- do not) and pin_condo_char doesn't contain all condos
Expand All @@ -195,13 +195,13 @@ chars AS (
LEFT JOIN comdat_filtered AS com
ON par.parid = com.parid
AND par.taxyr = com.taxyr
LEFT JOIN ccao.pin_condo_char
LEFT JOIN {{ source('ccao', 'pin_condo_char') }} AS pin_condo_char
ON par.parid = pin_condo_char.pin
AND par.taxyr = pin_condo_char.year
LEFT JOIN iasworld.legdat AS leg
LEFT JOIN {{ source('iasworld', 'legdat') }} AS leg
ON par.parid = leg.parid
AND par.taxyr = leg.taxyr
LEFT JOIN ccao.pin_399_garage_units AS p3gu
LEFT JOIN {{ source('ccao', 'pin_399_garage_units') }} AS p3gu
ON par.parid = p3gu.parid
AND par.taxyr = p3gu.taxyr
)
Expand Down
14 changes: 8 additions & 6 deletions aws-athena/views/default-vw_pin_exempt.sql
Original file line number Diff line number Diff line change
Expand Up @@ -20,17 +20,19 @@ SELECT
LAST_VALUE(parcel.lat)
IGNORE NULLS OVER (PARTITION BY par.parid ORDER BY par.taxyr)
) AS lat
FROM iasworld.pardat AS par
FROM {{ source('iasworld', 'pardat') }} AS par
LEFT JOIN
iasworld.owndat AS own
{{ source('iasworld', 'owndat') }} AS own
ON par.parid = own.parid AND par.taxyr = own.taxyr
LEFT JOIN
iasworld.legdat AS leg
{{ source('iasworld', 'legdat') }} AS leg
ON par.parid = leg.parid AND par.taxyr = leg.taxyr
LEFT JOIN default.vw_pin_address AS vpa
LEFT JOIN {{ ref('default.vw_pin_address') }} AS vpa
ON par.parid = vpa.pin AND par.taxyr = vpa.year
LEFT JOIN spatial.parcel ON vpa.pin10 = parcel.pin10 AND vpa.year = parcel.year
LEFT JOIN spatial.township AS twn
LEFT JOIN
{{ source('spatial', 'parcel') }} AS parcel
ON vpa.pin10 = parcel.pin10 AND vpa.year = parcel.year
LEFT JOIN {{ source('spatial', 'township') }} AS twn
ON leg.user1 = CAST(twn.township_code AS VARCHAR)
WHERE
--- This condition is how we determine exempt status, not through class
Expand Down
8 changes: 4 additions & 4 deletions aws-athena/views/default-vw_pin_history.sql
Original file line number Diff line number Diff line change
Expand Up @@ -5,7 +5,7 @@ WITH classes AS (
parid,
taxyr,
class
FROM iasworld.pardat
FROM {{ source('iasworld', 'pardat') }}
),

-- Add township number
Expand All @@ -14,15 +14,15 @@ townships AS (
parid,
taxyr,
user1 AS township_code
FROM iasworld.legdat
FROM {{ source('iasworld', 'legdat') }}
),

-- Add township name
town_names AS (
SELECT
township_name,
township_code
FROM spatial.township
FROM {{ source('spatial', 'township') }}
)

-- Add lagged values for previous two years
Expand Down Expand Up @@ -106,7 +106,7 @@ SELECT
ORDER BY vwpv.pin, vwpv.year
) AS twoyr_pri_board_tot

FROM {{ ref('vw_pin_value') }} AS vwpv
FROM {{ ref('default.vw_pin_value') }} AS vwpv
LEFT JOIN townships
ON vwpv.pin = townships.parid
AND vwpv.year = townships.taxyr
Expand Down
8 changes: 4 additions & 4 deletions aws-athena/views/default-vw_pin_sale.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,8 +7,8 @@ WITH town_class AS (
par.taxyr,
leg.user1 AS township_code,
CONCAT(leg.user1, SUBSTR(par.nbhd, 3, 3)) AS nbhd
FROM iasworld.pardat AS par
LEFT JOIN iasworld.legdat AS leg
FROM {{ source('iasworld', 'pardat') }} AS par
LEFT JOIN {{ source('iasworld', 'legdat') }} AS leg
ON par.parid = leg.parid
AND par.taxyr = leg.taxyr
),
Expand All @@ -19,7 +19,7 @@ calculated AS (
SELECT
instruno,
COUNT(*) AS nopar_calculated
FROM iasworld.sales
FROM {{ source('iasworld', 'sales') }}
WHERE deactivat IS NULL
GROUP BY instruno
),
Expand Down Expand Up @@ -72,7 +72,7 @@ unique_sales AS (
PARTITION BY sales.parid, sales.price
ORDER BY sales.saledt ASC, sales.salekey ASC
) AS same_price_earlier_date
FROM iasworld.sales
FROM {{ source('iasworld', 'sales') }} AS sales
LEFT JOIN calculated
ON sales.instruno = calculated.instruno
LEFT JOIN
Expand Down
10 changes: 5 additions & 5 deletions aws-athena/views/default-vw_pin_universe.sql
Original file line number Diff line number Diff line change
Expand Up @@ -118,15 +118,15 @@ SELECT
vwl.access_cmap_walk_data_year,
vwl.misc_subdivision_id,
vwl.misc_subdivision_data_year
FROM iasworld.pardat AS par
LEFT JOIN iasworld.legdat AS leg
FROM {{ source('iasworld', 'pardat') }} AS par
LEFT JOIN {{ source('iasworld', 'legdat') }} AS leg
ON par.parid = leg.parid
AND par.taxyr = leg.taxyr
LEFT JOIN spatial.parcel AS sp
LEFT JOIN {{ source('spatial', 'parcel') }} AS sp
ON SUBSTR(par.parid, 1, 10) = sp.pin10
AND par.taxyr = sp.year
LEFT JOIN {{ ref('vw_pin10_location') }} AS vwl
LEFT JOIN {{ ref('location.vw_pin10_location') }} AS vwl
ON SUBSTR(par.parid, 1, 10) = vwl.pin10
AND par.taxyr = vwl.year
LEFT JOIN spatial.township AS twn
LEFT JOIN {{ source('spatial', 'township') }} AS twn
ON leg.user1 = CAST(twn.township_code AS VARCHAR)
2 changes: 1 addition & 1 deletion aws-athena/views/default-vw_pin_value.sql
Original file line number Diff line number Diff line change
Expand Up @@ -60,7 +60,7 @@ SELECT
WHEN procname = 'BORVALUE' AND taxyr >= '2020' THEN valasm3
END
) AS board_tot
FROM iasworld.asmt_all
FROM {{ source('iasworld', 'asmt_all') }}
WHERE procname IN ('CCAOVALUE', 'CCAOFINAL', 'BORVALUE')
AND rolltype != 'RR'
AND deactivat IS NULL
Expand Down
22 changes: 11 additions & 11 deletions aws-athena/views/location-vw_pin10_location.sql
Original file line number Diff line number Diff line change
Expand Up @@ -111,34 +111,34 @@ SELECT
other.misc_subdivision_id,
other.misc_subdivision_data_year

FROM spatial.parcel AS pin
LEFT JOIN location.census
FROM {{ source('spatial', 'parcel') }} AS pin
LEFT JOIN {{ source('location', 'census') }} AS census
ON pin.pin10 = census.pin10
AND pin.year = census.year
LEFT JOIN location.census_acs5
LEFT JOIN {{ source('location', 'census_acs5') }} AS census_acs5
ON pin.pin10 = census_acs5.pin10
AND pin.year = census_acs5.year
LEFT JOIN location.political
LEFT JOIN {{ source('location', 'political') }} AS political
ON pin.pin10 = political.pin10
AND pin.year = political.year
LEFT JOIN location.chicago
LEFT JOIN {{ source('location', 'chicago') }} AS chicago
ON pin.pin10 = chicago.pin10
AND pin.year = chicago.year
LEFT JOIN location.economy
LEFT JOIN {{ source('location', 'economy') }} AS economy
ON pin.pin10 = economy.pin10
AND pin.year = economy.year
LEFT JOIN location.environment
LEFT JOIN {{ source('location', 'environment') }} AS environment
ON pin.pin10 = environment.pin10
AND pin.year = environment.year
LEFT JOIN location.school
LEFT JOIN {{ source('location', 'school') }} AS school
ON pin.pin10 = school.pin10
AND pin.year = school.year
LEFT JOIN location.tax
LEFT JOIN {{ source('location', 'tax') }} AS tax
ON pin.pin10 = tax.pin10
AND pin.year = tax.year
LEFT JOIN location.access
LEFT JOIN {{ source('location', 'access') }} AS access
ON pin.pin10 = access.pin10
AND pin.year = access.year
LEFT JOIN location.other
LEFT JOIN {{ source('location', 'other') }} AS other
ON pin.pin10 = other.pin10
AND pin.year = other.year
Loading

0 comments on commit 7a3d0e0

Please sign in to comment.