Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Properties that most impact each school district's property taxes #629

8 changes: 8 additions & 0 deletions dbt/models/reporting/docs.md
Original file line number Diff line number Diff line change
Expand Up @@ -78,6 +78,14 @@ PINs without sales have `NULL` sale values.
**Primary Key**: `year`, `pin`
{% enddocs %}

# vw_pin_school_impact

{% docs view_vw_pin_school_impact %}
View to get the 10 highest AVs by school district taxing agency and year.

**Primary Key**: `year`, `agency_num`, `pin`
{% enddocs %}

# vw_pin_township_class

{% docs view_vw_pin_township_class %}
Expand Down
89 changes: 89 additions & 0 deletions dbt/models/reporting/reporting.vw_pin_school_impact.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,89 @@
-- Script that returns the 10 PINs with the highest AV per school district
-- taxing agency, by year.
WITH ranking AS (
SELECT
info.agency_name,
info.agency_num,
RANK() OVER (
PARTITION BY
info.agency_name,
pin.year
ORDER BY pin.av_board DESC
) AS av_board_rank,
pin.pin,
pin.class,
pin.av_mailed,
pin.av_certified,
pin.av_board,
CAST((pin.av_board * fact.eq_factor_final) - (
pin.exe_homeowner
+ pin.exe_senior
+ pin.exe_freeze
+ pin.exe_longtime_homeowner
+ pin.exe_disabled
+ pin.exe_vet_returning
+ pin.exe_vet_dis_lt50
+ pin.exe_vet_dis_50_69
+ pin.exe_vet_dis_ge70
+ pin.exe_abate
) AS INT) AS taxable_eav,
pin.tax_bill_total,
RANK() OVER (
PARTITION BY
info.agency_name,
pin.year
ORDER BY pin.tax_bill_total DESC
) AS bill_rank,
code.tax_code_num,
code.tax_code_rate,
pin.year
FROM {{ source('tax', 'pin') }} AS pin
LEFT JOIN {{ source('tax', 'tax_code') }} AS code
ON pin.tax_code_num = code.tax_code_num
AND pin.year = code.year
INNER JOIN
{{ source('tax', 'agency_info') }} AS info
ON code.agency_num = info.agency_num
LEFT JOIN {{ source('tax', 'eq_factor') }} AS fact ON pin.year = fact.year
WHERE info.major_type = 'SCHOOL'
-- Class 0 PINs have 0 AV but can lead to huge ties if there are many in
-- a district with few PINs
AND pin.class != '0'
),

-- We need to use array_agg for this CTE since some parcels can be in multiple
-- SSAs
tif_ssa AS (
SELECT
pin.pin,
pin.year,
info.minor_type,
ARRAY_AGG(info.agency_name) AS agency_name
FROM {{ source('tax', 'pin') }} AS pin
LEFT JOIN {{ source('tax', 'tax_code') }} AS code
ON pin.tax_code_num = code.tax_code_num
AND pin.year = code.year
INNER JOIN
{{ source('tax', 'agency_info') }} AS info
ON code.agency_num = info.agency_num
GROUP BY pin.pin, pin.year, info.minor_type
)

SELECT
ranking.*,
tif.agency_name AS tif,
ssa.agency_name AS ssa
FROM ranking
LEFT JOIN tif_ssa AS tif
ON ranking.pin = tif.pin
AND ranking.year = tif.year
AND tif.minor_type = 'TIF'
LEFT JOIN tif_ssa AS ssa
ON ranking.pin = ssa.pin
AND ranking.year = ssa.year
AND ssa.minor_type = 'SSA'
WHERE ranking.av_board_rank <= 10
ORDER BY
ranking.year,
ranking.agency_num,
ranking.av_board_rank
16 changes: 16 additions & 0 deletions dbt/models/reporting/schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -203,6 +203,22 @@ models:
combination_of_columns:
- pin

- name: reporting.vw_pin_school_impact
description: '{{ doc("view_vw_pin_school_impact") }}'
data_tests:
- accepted_range:
name: reporting_vw_school_impact_av_board_rank_range
column_name: av_board_rank
min_value: 1
max_value: 10
- unique_combination_of_columns:
name: reporting_vw_school_impact_unique_by_agency_num_pin_year
combination_of_columns:
- agency_num
- pin
- year


- name: reporting.vw_pin_township_class
description: '{{ doc("view_vw_pin_township_class") }}'
data_tests:
Expand Down
Loading