-
Notifications
You must be signed in to change notification settings - Fork 4
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Split reporting.res_report_summary input CTEs out into dedicated tables
- Loading branch information
1 parent
1ae727e
commit dd4b6e4
Showing
5 changed files
with
210 additions
and
121 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 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
39 changes: 39 additions & 0 deletions
39
dbt/models/reporting/reporting.res_report_summary_sales_input.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,39 @@ | ||
/* | ||
Input table for `reporting.res_report_summary` that produces the raw sales data | ||
that `res_report_summary` aggregates. We split these input data out into a | ||
separate table to speed up query time for `res_report_summary`, since otherwise | ||
it needs to rerun the query logic below for every possible geography and | ||
reporting group combination. | ||
See `reporting.res_report_summary` for a full description of these data. | ||
Intended to be materialized daily through a GitHub action. | ||
*/ | ||
|
||
{{ | ||
config( | ||
materialized='table', | ||
partitioned_by=['sale_year'] | ||
) | ||
}} | ||
|
||
-- Sales, filtered to exclude outliers and mutlisales | ||
SELECT | ||
vwps.pin, | ||
vwps.doc_no, | ||
vwps.sale_price, | ||
tc.property_group, | ||
tc.township_code, | ||
vwps.nbhd AS townnbhd, | ||
vwps.year AS sale_year | ||
FROM {{ ref('default.vw_pin_sale') }} AS vwps | ||
LEFT JOIN {{ ref('reporting.vw_pin_township_class') }} AS tc | ||
ON vwps.pin = tc.pin | ||
AND vwps.year = tc.year | ||
WHERE NOT vwps.is_multisale | ||
AND NOT vwps.sale_filter_is_outlier | ||
AND NOT vwps.sale_filter_deed_type | ||
AND NOT vwps.sale_filter_less_than_10k | ||
AND NOT vwps.sale_filter_same_sale_within_365 | ||
AND tc.property_group IS NOT NULL | ||
AND tc.triad_name IS NOT NULL |
106 changes: 106 additions & 0 deletions
106
dbt/models/reporting/reporting.res_report_summary_values_input.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,106 @@ | ||
/* | ||
Input table for `reporting.res_report_summary` that produces the raw | ||
characteristic and value data that `res_report_summary` aggregates. We split | ||
these input data out into a separate table to speed up query time for | ||
`res_report_summary`, since otherwise it needs to rerun the query logic below | ||
for every possible geography and reporting group combination. | ||
This table takes model and assessment values from two separate tables and | ||
stacks them. Model and assessment values are gathered independently and | ||
aggregated via a UNION rather than a JOIN, so it's important to keep in mind | ||
that years for model and assessment stages do NOT need to match, i.e. we can | ||
have 2023 model values in the table before there are any 2023 assessment values | ||
to report on. | ||
See `reporting.res_report_summary` for a full description of these data. | ||
Intended to be materialized daily through a GitHub action. | ||
*/ | ||
|
||
{{ | ||
config( | ||
materialized='table', | ||
partitioned_by=['year'] | ||
) | ||
}} | ||
|
||
-- AVs and model values | ||
WITH all_fmvs AS ( | ||
SELECT | ||
ap.meta_pin AS pin, | ||
ap.year, | ||
'model' AS assessment_stage, | ||
ap.pred_pin_final_fmv_round AS total | ||
FROM {{ source('model', 'assessment_pin') }} AS ap | ||
INNER JOIN {{ ref('model.final_model') }} AS fm | ||
ON ap.run_id = fm.run_id | ||
AND ap.year = fm.year | ||
AND ( | ||
-- If reassessment year, use different models for different towns | ||
( | ||
CONTAINS(fm.township_code_coverage, ap.township_code) | ||
AND ap.meta_triad_code = fm.triad_code | ||
) | ||
-- Otherwise, just use whichever model is "final" | ||
OR (ap.meta_triad_code != fm.triad_code AND fm.is_final) | ||
) | ||
|
||
UNION ALL | ||
|
||
SELECT | ||
pin, | ||
year, | ||
stage_name AS assessment_stage, | ||
tot * 10 AS total | ||
FROM {{ ref('reporting.vw_pin_value_long') }} | ||
WHERE year >= '2021' | ||
), | ||
|
||
-- Combined SF/MF and condo characteristics | ||
chars AS ( | ||
SELECT | ||
parid AS pin, | ||
taxyr AS year, | ||
MIN(yrblt) AS yrblt, | ||
SUM(sfla) AS total_bldg_sf | ||
FROM {{ source('iasworld', 'dweldat') }} | ||
WHERE cur = 'Y' | ||
AND deactivat IS NULL | ||
GROUP BY parid, taxyr | ||
UNION ALL | ||
SELECT | ||
pin, | ||
year, | ||
char_yrblt AS yrblt, | ||
char_building_sf AS total_bldg_sf | ||
FROM {{ ref('default.vw_pin_condo_char') }} | ||
WHERE NOT is_parking_space | ||
AND NOT is_common_area | ||
) | ||
|
||
-- Join land, chars, and reporting groups to values | ||
SELECT | ||
fmvs.pin, | ||
vptc.property_group, | ||
vptc.class, | ||
vptc.triad_name AS triad, | ||
vptc.township_code, | ||
CONCAT(vptc.township_code, vptc.nbhd) AS townnbhd, | ||
fmvs.assessment_stage, | ||
fmvs.total, | ||
chars.yrblt, | ||
chars.total_bldg_sf, | ||
vpl.sf AS total_land_sf, | ||
fmvs.year | ||
FROM all_fmvs AS fmvs | ||
LEFT JOIN {{ ref('reporting.vw_pin_township_class') }} AS vptc | ||
ON fmvs.pin = vptc.pin | ||
AND fmvs.year = vptc.year | ||
INNER JOIN chars | ||
ON fmvs.pin = chars.pin | ||
AND fmvs.year = chars.year | ||
LEFT JOIN {{ ref('default.vw_pin_land') }} AS vpl | ||
ON fmvs.pin = vpl.pin | ||
AND fmvs.year = vpl.year | ||
WHERE vptc.property_group IS NOT NULL | ||
AND vptc.triad_name IS NOT NULL |
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