diff --git a/dbt/macros/pre_stage_filters.sql b/dbt/macros/pre_stage_filters.sql new file mode 100644 index 000000000..cc03e5e09 --- /dev/null +++ b/dbt/macros/pre_stage_filters.sql @@ -0,0 +1,21 @@ +-- Macros to simplify the filter conditions that produce pre-mailed and +-- pre-certified values. +-- +-- Note that the `cur = 'Y'` filter is not necessary in the +-- default.vw_pin_value query that is the main consumer of these macros, since +-- that query already filters rows where `cur = 'Y'`; however, we leave the +-- filter in here so that it might make the macro more generally useful in +-- other instances where we may not filter queries the same way +{% macro pre_stage_filters(tablename, stage_name) %} + {{ tablename }}.procname is null + and {{ tablename }}.cur = 'Y' + and not contains(stages.procnames, '{{ stage_name }}') +{% endmacro %} + +{% macro pre_mailed_filters(tablename) %} + {{- pre_stage_filters(tablename, "CCAOVALUE") -}} +{% endmacro %} + +{% macro pre_certified_filters(tablename) %} + {{- pre_stage_filters(tablename, "CCAOFINAL") -}} +{% endmacro %} diff --git a/dbt/macros/tests/test_all.sql b/dbt/macros/tests/test_all.sql index 3a1a77c19..6ac0dc855 100644 --- a/dbt/macros/tests/test_all.sql +++ b/dbt/macros/tests/test_all.sql @@ -5,4 +5,5 @@ {% do test_generate_schema_name() %} {% do test_generate_alias_name() %} {% do test_format_additional_select_columns() %} + {% do test_pre_stage_filters() %} {% endmacro %} diff --git a/dbt/macros/tests/test_pre_stage_filters.sql b/dbt/macros/tests/test_pre_stage_filters.sql new file mode 100644 index 000000000..6c831da86 --- /dev/null +++ b/dbt/macros/tests/test_pre_stage_filters.sql @@ -0,0 +1,47 @@ +{% macro test_pre_stage_filters() %} + {% do test_pre_stage_filters_params() %} + {% do test_pre_mailed_filters() %} + {% do test_pre_certified_filters() %} +{% endmacro %} + +{% macro expected_pre_mailed_filters() %} + asmt.procname is null + and asmt.cur = 'Y' + and not contains(stages.procnames, 'CCAOVALUE') +{% endmacro %} + +{% macro expected_pre_certified_filters() %} + asmt.procname is null + and asmt.cur = 'Y' + and not contains(stages.procnames, 'CCAOFINAL') +{% endmacro %} + +{% macro test_pre_stage_filters_params() %} + {{ + assert_equals( + "test_pre_stage_filters_params", + pre_stage_filters("asmt", "CCAOVALUE"), + expected_pre_mailed_filters(), + ) + }} +{% endmacro %} + +{% macro test_pre_mailed_filters() %} + {{ + assert_equals( + "test_pre_mailed_filters_params", + pre_mailed_filters("asmt"), + expected_pre_mailed_filters(), + ) + }} +{% endmacro %} + +{% macro test_pre_certified_filters() %} + {{ + assert_equals( + "test_pre_certified_filters_params", + pre_certified_filters("asmt"), + expected_pre_certified_filters(), + ) + }} +{% endmacro %} diff --git a/dbt/models/default/default.vw_pin_value.sql b/dbt/models/default/default.vw_pin_value.sql index e5908bee1..5664c829d 100644 --- a/dbt/models/default/default.vw_pin_value.sql +++ b/dbt/models/default/default.vw_pin_value.sql @@ -1,190 +1,476 @@ -- View containing values from each stage of assessment by PIN and year -- in wide format +-- Stage name constants +{% set stage_name_pre_mailed = 'PRE-MAILED' %} +{% set stage_name_mailed = 'MAILED' %} +{% set stage_name_pre_certified = 'ASSESSOR PRE-CERTIFIED' %} +{% set stage_name_certified = 'ASSESSOR CERTIFIED' %} +{% set stage_name_board = 'BOARD CERTIFIED' %} + +-- Get a list of completed stages for all PINs in all years. This will allow us +-- to disambiguate pre-mailed values from pre-certified values based on which +-- stages are present for which PINs (i.e. if CCAOVALUE is present, the value +-- cannot be pre-mail, since we have already mailed a value for the PIN) +WITH stages AS ( + SELECT + parid, + taxyr, + ARRAY_AGG(procname) AS procnames + FROM {{ source('iasworld', 'asmt_all') }} + WHERE procname IN ('CCAOVALUE', 'CCAOFINAL', 'BORVALUE') + AND rolltype != 'RR' + AND deactivat IS NULL + AND valclass IS NULL + GROUP BY parid, taxyr +), + -- CCAO mailed, CCAO final, and BOR final values for each PIN by year. -- We use ARBITRARY functions here for two reasons: 1) To flatten three stages -- of assessment into one row, and 2) to deduplicate PINs with multiple rows for -- a given stage/pin/year combination. Values are always the same within these -- duplicates. -WITH stage_values AS ( +stage_values AS ( SELECT - parid AS pin, - taxyr AS year, + asmt.parid AS pin, + asmt.taxyr AS year, + -- Pre-mailed values + ARBITRARY( + CASE + WHEN + {{ pre_mailed_filters('asmt') }} + THEN REGEXP_REPLACE(asmt.class, '[^[:alnum:]]', '') + END + ) AS pre_mailed_class, + ARBITRARY( + CASE + WHEN + {{ pre_mailed_filters('asmt') }} AND asmt.taxyr < '2020' + THEN asmt.ovrvalasm2 + WHEN + {{ pre_mailed_filters('asmt') }} AND asmt.taxyr >= '2020' + THEN asmt.valasm2 + END + ) AS pre_mailed_bldg, + ARBITRARY( + CASE + WHEN + {{ pre_mailed_filters('asmt') }} AND asmt.taxyr < '2020' + THEN asmt.ovrvalasm1 + WHEN + {{ pre_mailed_filters('asmt') }} AND asmt.taxyr >= '2020' + THEN asmt.valasm1 + END + ) AS pre_mailed_land, + ARBITRARY( + CASE + WHEN + {{ pre_mailed_filters('asmt') }} AND asmt.taxyr < '2020' + THEN asmt.ovrvalasm3 + WHEN + {{ pre_mailed_filters('asmt') }} AND asmt.taxyr >= '2020' + THEN asmt.valasm3 + END + ) AS pre_mailed_tot, + -- Pre-mailed market values + ARBITRARY( + CASE + WHEN + {{ pre_mailed_filters('asmt') }} AND asmt.taxyr < '2020' + THEN NULL + WHEN + {{ pre_mailed_filters('asmt') }} AND asmt.taxyr >= '2020' + THEN asmt.valapr2 + END + ) AS pre_mailed_bldg_mv, + ARBITRARY( + CASE + WHEN + {{ pre_mailed_filters('asmt') }} AND asmt.taxyr < '2020' + THEN NULL + WHEN + {{ pre_mailed_filters('asmt') }} AND asmt.taxyr >= '2020' + THEN asmt.valapr1 + END + ) AS pre_mailed_land_mv, + ARBITRARY( + CASE + WHEN + {{ pre_mailed_filters('asmt') }} AND asmt.taxyr < '2020' + THEN NULL + WHEN + {{ pre_mailed_filters('asmt') }} AND asmt.taxyr >= '2020' + THEN asmt.valapr3 + END + ) AS pre_mailed_tot_mv, -- Mailed values ARBITRARY( CASE WHEN - procname = 'CCAOVALUE' - THEN REGEXP_REPLACE(class, '[^[:alnum:]]', '') + asmt.procname = 'CCAOVALUE' + THEN REGEXP_REPLACE(asmt.class, '[^[:alnum:]]', '') END ) AS mailed_class, ARBITRARY( CASE - WHEN procname = 'CCAOVALUE' AND taxyr < '2020' THEN ovrvalasm2 - WHEN procname = 'CCAOVALUE' AND taxyr >= '2020' THEN valasm2 + WHEN + asmt.procname = 'CCAOVALUE' AND asmt.taxyr < '2020' + THEN asmt.ovrvalasm2 + WHEN + asmt.procname = 'CCAOVALUE' AND asmt.taxyr >= '2020' + THEN asmt.valasm2 END ) AS mailed_bldg, ARBITRARY( CASE - WHEN procname = 'CCAOVALUE' AND taxyr < '2020' THEN ovrvalasm1 - WHEN procname = 'CCAOVALUE' AND taxyr >= '2020' THEN valasm1 + WHEN + asmt.procname = 'CCAOVALUE' AND asmt.taxyr < '2020' + THEN asmt.ovrvalasm1 + WHEN + asmt.procname = 'CCAOVALUE' AND asmt.taxyr >= '2020' + THEN asmt.valasm1 END ) AS mailed_land, ARBITRARY( CASE - WHEN procname = 'CCAOVALUE' AND taxyr < '2020' THEN ovrvalasm3 - WHEN procname = 'CCAOVALUE' AND taxyr >= '2020' THEN valasm3 + WHEN + asmt.procname = 'CCAOVALUE' AND asmt.taxyr < '2020' + THEN asmt.ovrvalasm3 + WHEN + asmt.procname = 'CCAOVALUE' AND asmt.taxyr >= '2020' + THEN asmt.valasm3 END ) AS mailed_tot, -- Mailed market values ARBITRARY( CASE - WHEN procname = 'CCAOVALUE' AND taxyr < '2020' THEN NULL - WHEN procname = 'CCAOVALUE' AND taxyr >= '2020' THEN valapr2 + WHEN + asmt.procname = 'CCAOVALUE' AND asmt.taxyr < '2020' + THEN NULL + WHEN + asmt.procname = 'CCAOVALUE' AND asmt.taxyr >= '2020' + THEN asmt.valapr2 END ) AS mailed_bldg_mv, ARBITRARY( CASE - WHEN procname = 'CCAOVALUE' AND taxyr < '2020' THEN NULL - WHEN procname = 'CCAOVALUE' AND taxyr >= '2020' THEN valapr1 + WHEN + asmt.procname = 'CCAOVALUE' AND asmt.taxyr < '2020' + THEN NULL + WHEN + asmt.procname = 'CCAOVALUE' AND asmt.taxyr >= '2020' + THEN asmt.valapr1 END ) AS mailed_land_mv, ARBITRARY( CASE - WHEN procname = 'CCAOVALUE' AND taxyr < '2020' THEN NULL - WHEN procname = 'CCAOVALUE' AND taxyr >= '2020' THEN valapr3 + WHEN + asmt.procname = 'CCAOVALUE' AND asmt.taxyr < '2020' + THEN NULL + WHEN + asmt.procname = 'CCAOVALUE' AND asmt.taxyr >= '2020' + THEN asmt.valapr3 END ) AS mailed_tot_mv, + -- Assessor pre-certified values + ARBITRARY( + CASE + WHEN + {{ pre_certified_filters('asmt') }} + THEN REGEXP_REPLACE(asmt.class, '[^[:alnum:]]', '') + END + ) AS pre_certified_class, + ARBITRARY( + CASE + WHEN + {{ pre_certified_filters('asmt') }} AND asmt.taxyr < '2020' + THEN asmt.ovrvalasm2 + WHEN + {{ pre_certified_filters('asmt') }} AND asmt.taxyr >= '2020' + THEN asmt.valasm2 + END + ) AS pre_certified_bldg, + ARBITRARY( + CASE + WHEN + {{ pre_certified_filters('asmt') }} AND asmt.taxyr < '2020' + THEN asmt.ovrvalasm1 + WHEN + {{ pre_certified_filters('asmt') }} AND asmt.taxyr >= '2020' + THEN asmt.valasm1 + END + ) AS pre_certified_land, + ARBITRARY( + CASE + WHEN + {{ pre_certified_filters('asmt') }} AND asmt.taxyr < '2020' + THEN asmt.ovrvalasm3 + WHEN + {{ pre_certified_filters('asmt') }} AND asmt.taxyr >= '2020' + THEN asmt.valasm3 + END + ) AS pre_certified_tot, + -- Assessor pre-certified market values + ARBITRARY( + CASE + WHEN + {{ pre_certified_filters('asmt') }} AND asmt.taxyr < '2020' + THEN NULL + WHEN + {{ pre_certified_filters('asmt') }} AND asmt.taxyr >= '2020' + THEN asmt.valapr2 + END + ) AS pre_certified_bldg_mv, + ARBITRARY( + CASE + WHEN + {{ pre_certified_filters('asmt') }} AND asmt.taxyr < '2020' + THEN NULL + WHEN + {{ pre_certified_filters('asmt') }} AND asmt.taxyr >= '2020' + THEN asmt.valapr1 + END + ) AS pre_certified_land_mv, + ARBITRARY( + CASE + WHEN + {{ pre_certified_filters('asmt') }} AND asmt.taxyr < '2020' + THEN NULL + WHEN + {{ pre_certified_filters('asmt') }} AND asmt.taxyr >= '2020' + THEN asmt.valapr3 + END + ) AS pre_certified_tot_mv, -- Assessor certified values ARBITRARY( CASE WHEN - procname = 'CCAOFINAL' - THEN REGEXP_REPLACE(class, '[^[:alnum:]]', '') + asmt.procname = 'CCAOFINAL' + THEN REGEXP_REPLACE(asmt.class, '[^[:alnum:]]', '') END ) AS certified_class, ARBITRARY( CASE - WHEN procname = 'CCAOFINAL' AND taxyr < '2020' THEN ovrvalasm2 - WHEN procname = 'CCAOFINAL' AND taxyr >= '2020' THEN valasm2 + WHEN + asmt.procname = 'CCAOFINAL' AND asmt.taxyr < '2020' + THEN asmt.ovrvalasm2 + WHEN + asmt.procname = 'CCAOFINAL' AND asmt.taxyr >= '2020' + THEN asmt.valasm2 END ) AS certified_bldg, ARBITRARY( CASE - WHEN procname = 'CCAOFINAL' AND taxyr < '2020' THEN ovrvalasm1 - WHEN procname = 'CCAOFINAL' AND taxyr >= '2020' THEN valasm1 + WHEN + asmt.procname = 'CCAOFINAL' AND asmt.taxyr < '2020' + THEN asmt.ovrvalasm1 + WHEN + asmt.procname = 'CCAOFINAL' AND asmt.taxyr >= '2020' + THEN asmt.valasm1 END ) AS certified_land, ARBITRARY( CASE - WHEN procname = 'CCAOFINAL' AND taxyr < '2020' THEN ovrvalasm3 - WHEN procname = 'CCAOFINAL' AND taxyr >= '2020' THEN valasm3 + WHEN + asmt.procname = 'CCAOFINAL' AND asmt.taxyr < '2020' + THEN asmt.ovrvalasm3 + WHEN + asmt.procname = 'CCAOFINAL' AND asmt.taxyr >= '2020' + THEN asmt.valasm3 END ) AS certified_tot, -- Assessor certified market values ARBITRARY( CASE - WHEN procname = 'CCAOFINAL' AND taxyr < '2020' THEN NULL - WHEN procname = 'CCAOFINAL' AND taxyr >= '2020' THEN valapr2 + WHEN + asmt.procname = 'CCAOFINAL' AND asmt.taxyr < '2020' + THEN NULL + WHEN + asmt.procname = 'CCAOFINAL' AND asmt.taxyr >= '2020' + THEN asmt.valapr2 END ) AS certified_bldg_mv, ARBITRARY( CASE - WHEN procname = 'CCAOFINAL' AND taxyr < '2020' THEN NULL - WHEN procname = 'CCAOFINAL' AND taxyr >= '2020' THEN valapr1 + WHEN + asmt.procname = 'CCAOFINAL' AND asmt.taxyr < '2020' + THEN NULL + WHEN + asmt.procname = 'CCAOFINAL' AND asmt.taxyr >= '2020' + THEN asmt.valapr1 END ) AS certified_land_mv, ARBITRARY( CASE - WHEN procname = 'CCAOFINAL' AND taxyr < '2020' THEN NULL - WHEN procname = 'CCAOFINAL' AND taxyr >= '2020' THEN valapr3 + WHEN + asmt.procname = 'CCAOFINAL' AND asmt.taxyr < '2020' + THEN NULL + WHEN + asmt.procname = 'CCAOFINAL' AND asmt.taxyr >= '2020' + THEN asmt.valapr3 END ) AS certified_tot_mv, -- Board certified values ARBITRARY( CASE WHEN - procname = 'BORVALUE' - THEN REGEXP_REPLACE(class, '[^[:alnum:]]', '') + asmt.procname = 'BORVALUE' + THEN REGEXP_REPLACE(asmt.class, '[^[:alnum:]]', '') END ) AS board_class, ARBITRARY( CASE - WHEN procname = 'BORVALUE' AND taxyr < '2020' THEN ovrvalasm2 - WHEN procname = 'BORVALUE' AND taxyr >= '2020' THEN valasm2 + WHEN + asmt.procname = 'BORVALUE' AND asmt.taxyr < '2020' + THEN asmt.ovrvalasm2 + WHEN + asmt.procname = 'BORVALUE' AND asmt.taxyr >= '2020' + THEN asmt.valasm2 END ) AS board_bldg, ARBITRARY( CASE - WHEN procname = 'BORVALUE' AND taxyr < '2020' THEN ovrvalasm1 - WHEN procname = 'BORVALUE' AND taxyr >= '2020' THEN valasm1 + WHEN + asmt.procname = 'BORVALUE' AND asmt.taxyr < '2020' + THEN asmt.ovrvalasm1 + WHEN + asmt.procname = 'BORVALUE' AND asmt.taxyr >= '2020' + THEN asmt.valasm1 END ) AS board_land, ARBITRARY( CASE - WHEN procname = 'BORVALUE' AND taxyr < '2020' THEN ovrvalasm3 - WHEN procname = 'BORVALUE' AND taxyr >= '2020' THEN valasm3 + WHEN + asmt.procname = 'BORVALUE' AND asmt.taxyr < '2020' + THEN asmt.ovrvalasm3 + WHEN + asmt.procname = 'BORVALUE' AND asmt.taxyr >= '2020' + THEN asmt.valasm3 END ) AS board_tot, -- Board certified market values ARBITRARY( CASE - WHEN procname = 'BORVALUE' AND taxyr < '2020' THEN NULL - WHEN procname = 'BORVALUE' AND taxyr >= '2020' THEN valapr2 + WHEN + asmt.procname = 'BORVALUE' AND asmt.taxyr < '2020' + THEN NULL + WHEN + asmt.procname = 'BORVALUE' AND asmt.taxyr >= '2020' + THEN asmt.valapr2 END ) AS board_bldg_mv, ARBITRARY( CASE - WHEN procname = 'BORVALUE' AND taxyr < '2020' THEN NULL - WHEN procname = 'BORVALUE' AND taxyr >= '2020' THEN valapr1 + WHEN + asmt.procname = 'BORVALUE' AND asmt.taxyr < '2020' + THEN NULL + WHEN + asmt.procname = 'BORVALUE' AND asmt.taxyr >= '2020' + THEN asmt.valapr1 END ) AS board_land_mv, ARBITRARY( CASE - WHEN procname = 'BORVALUE' AND taxyr < '2020' THEN NULL - WHEN procname = 'BORVALUE' AND taxyr >= '2020' THEN valapr3 + WHEN + asmt.procname = 'BORVALUE' AND asmt.taxyr < '2020' + THEN NULL + WHEN + asmt.procname = 'BORVALUE' AND asmt.taxyr >= '2020' + THEN asmt.valapr3 END ) AS board_tot_mv - FROM {{ source('iasworld', 'asmt_all') }} - WHERE procname IN ('CCAOVALUE', 'CCAOFINAL', 'BORVALUE') - AND rolltype != 'RR' - AND deactivat IS NULL - AND valclass IS NULL - GROUP BY parid, taxyr + FROM {{ source('iasworld', 'asmt_all') }} AS asmt + LEFT JOIN stages + ON asmt.parid = stages.parid + AND asmt.taxyr = stages.taxyr + WHERE ( + -- Check for two possible situations: Either the record is stamped + -- with a procname corresponding to a stage, in which case the record + -- corresponds to a final value for a stage, or the procname is null + -- and other fields indicate that it is a provisional value for an + -- upcoming stage + asmt.procname IN ('CCAOVALUE', 'CCAOFINAL', 'BORVALUE') + OR ( + asmt.procname IS NULL + AND asmt.cur = 'Y' + AND ( + -- If the PIN has no stages but its year is not the current + -- assessment year, it is likely a data error from a prior + -- year that we don't want to include in our results. In + -- contrast, if the PIN is in the current year but has no + -- stages, it is most likely a provisional value for a PIN + -- that has not mailed yet + CARDINALITY(stages.procnames) != 0 + OR asmt.taxyr = DATE_FORMAT(NOW(), '%Y') + ) + ) + ) + AND asmt.rolltype != 'RR' + AND asmt.deactivat IS NULL + AND asmt.valclass IS NULL + GROUP BY asmt.parid, asmt.taxyr ), +-- Add stage names and stage numbers to the values based on the columns that +-- are present clean_values AS ( SELECT stage_values.*, -- Current stage indicator CASE - WHEN stage_values.board_tot IS NOT NULL THEN 'BOARD CERTIFIED' + WHEN + stage_values.board_tot IS NOT NULL + THEN '{{ stage_name_board }}' WHEN stage_values.certified_tot IS NOT NULL - THEN 'ASSESSOR CERTIFIED' - WHEN stage_values.mailed_tot IS NOT NULL THEN 'MAILED' + THEN '{{ stage_name_certified }}' + WHEN + stage_values.pre_certified_tot IS NOT NULL + THEN '{{ stage_name_pre_certified }}' + WHEN + stage_values.mailed_tot IS NOT NULL + THEN '{{ stage_name_mailed }}' + WHEN + stage_values.pre_mailed_tot IS NOT NULL + THEN '{{ stage_name_pre_mailed }}' END AS stage_name, CASE WHEN stage_values.board_tot IS NOT NULL THEN 3 WHEN stage_values.certified_tot IS NOT NULL THEN 2 + WHEN stage_values.pre_certified_tot IS NOT NULL THEN 1.5 WHEN stage_values.mailed_tot IS NOT NULL THEN 1 + WHEN stage_values.pre_mailed_tot IS NOT NULL THEN 0.5 END AS stage_num FROM stage_values ), +-- Query change reason codes for each PIN so that we can add it to the stage +-- values for context change_reasons AS ( SELECT - parid AS pin, - taxyr AS year, - reascd, + aprval.parid AS pin, + aprval.taxyr AS year, + aprval.reascd, CASE - WHEN procname = 'CCAOVALUE' THEN 'MAILED' - WHEN procname = 'CCAOFINAL' THEN 'ASSESSOR CERTIFIED' - WHEN procname = 'BORVALUE' THEN 'BOARD CERTIFIED' + WHEN + {{ pre_mailed_filters('aprval') }} + THEN '{{ stage_name_pre_mailed }}' + WHEN aprval.procname = 'CCAOVALUE' THEN '{{ stage_name_mailed }}' + WHEN + {{ pre_certified_filters('aprval') }} + THEN '{{ stage_name_pre_certified }}' + WHEN aprval.procname = 'CCAOFINAL' THEN '{{ stage_name_certified }}' + WHEN aprval.procname = 'BORVALUE' THEN '{{ stage_name_board }}' END AS stage_name - FROM {{ source('iasworld', 'aprval') }} - WHERE reascd IS NOT NULL - AND procname IS NOT NULL + FROM {{ source('iasworld', 'aprval') }} AS aprval + LEFT JOIN stages + ON aprval.parid = stages.parid + AND aprval.taxyr = stages.taxyr + WHERE aprval.reascd IS NOT NULL + AND ( + aprval.procname IS NULL + OR aprval.procname IN ('CCAOVALUE', 'CCAOFINAL', 'BORVALUE') + ) ) SELECT diff --git a/dbt/models/default/schema/default.vw_pin_value.yml b/dbt/models/default/schema/default.vw_pin_value.yml index 124c12383..ad02bda65 100644 --- a/dbt/models/default/schema/default.vw_pin_value.yml +++ b/dbt/models/default/schema/default.vw_pin_value.yml @@ -23,6 +23,11 @@ models: description: '{{ doc("shared_column_certified_bldg") }}' - name: certified_class description: '{{ doc("shared_column_certified_class") }}' + data_tests: + - is_null: + name: default_vw_pin_value_certified_class_is_null_when_pre_certified + config: + where: stage_name = 'ASSESSOR PRE-CERTIFIED' - name: certified_land description: '{{ doc("shared_column_certified_land") }}' - name: certified_land_mv @@ -39,6 +44,15 @@ models: description: '{{ doc("shared_column_mailed_bldg") }}' - name: mailed_class description: '{{ doc("shared_column_mailed_class") }}' + data_tests: + - is_null: + name: default_vw_pin_value_mailed_class_is_null_when_pre_mailed + config: + where: stage_name = 'PRE-MAILED' + - not_null: + name: default_vw_pin_value_mailed_class_not_null_when_pre_certified + config: + where: stage_name = 'ASSESSOR PRE-CERTIFIED' - name: mailed_land description: '{{ doc("shared_column_mailed_land") }}' - name: mailed_land_mv @@ -49,24 +63,153 @@ models: description: '{{ doc("shared_column_mailed_tot") }}' - name: pin description: '{{ doc("shared_column_pin") }}' + - name: pre_certified_bldg + description: '{{ doc("shared_column_pre_certified_bldg") }}' + - name: pre_certified_bldg_mv + description: '{{ doc("shared_column_pre_certified_bldg") }}' + - name: pre_certified_class + description: '{{ doc("shared_column_pre_certified_class") }}' + - name: pre_certified_land + description: '{{ doc("shared_column_pre_certified_land") }}' + - name: pre_certified_land_mv + description: '{{ doc("shared_column_pre_certified_land") }}' + - name: pre_certified_tot + description: '{{ doc("shared_column_pre_certified_tot") }}' + - name: pre_certified_tot_mv + description: '{{ doc("shared_column_pre_certified_land") }}' + - name: pre_mailed_bldg + description: '{{ doc("shared_column_pre_mailed_bldg") }}' + - name: pre_mailed_bldg_mv + description: '{{ doc("shared_column_pre_mailed_bldg") }}' + - name: pre_mailed_class + description: '{{ doc("shared_column_pre_mailed_class") }}' + - name: pre_mailed_land + description: '{{ doc("shared_column_pre_mailed_land") }}' + - name: pre_mailed_land_mv + description: '{{ doc("shared_column_pre_mailed_land") }}' + - name: pre_mailed_tot + description: '{{ doc("shared_column_pre_mailed_tot") }}' + - name: pre_mailed_tot_mv + description: '{{ doc("shared_column_pre_mailed_land") }}' - name: stage_name description: | Name of currently active/open stages. - One of `MAILED`, `ASSESSOR CERTIFIED`, or `BOARD CERTIFIED` + The possible values include: + + - `PRE-MAILED` + - `MAILED` + - `ASSESSOR PRE-CERTIFIED` + - `ASSESSOR CERTIFIED` + - `BOARD CERTIFIED` + data_tests: + - not_null: + name: default_vw_pin_value_stage_name_not_null - name: stage_num description: | Number of currently active/open stages. The possible values include: + - `0.5` = Pre-mailed - `1` = Mailed - - `2` = Certified - - `3` = Board + - `1.5` = Assessor pre-certified + - `2` = Assessor certified + - `3` = Board certified - name: year description: '{{ doc("shared_column_year") }}' data_tests: + - not_null: + name: default_vw_pin_value_board_class_not_null + column_name: board_class + config: + where: CAST(year AS int) < {{ var('data_test_iasworld_year_start') }} - 1 + error_if: ">1260" + - not_null: + name: default_vw_pin_value_board_tot_mv_not_null + column_name: board_tot_mv + config: + where: | + CAST(year AS int) < {{ var('data_test_iasworld_year_start') }} - 1 AND + year >= '2020' + error_if: ">1260" + - not_null: + name: default_vw_pin_value_board_tot_not_null + column_name: board_tot + config: + where: CAST(year AS int) < {{ var('data_test_iasworld_year_start') }} - 1 + error_if: ">1260" + - not_null: + name: default_vw_pin_value_certified_class_not_null + column_name: certified_class + config: + where: CAST(year AS int) < {{ var('data_test_iasworld_year_start') }} + error_if: ">15" + - not_null: + name: default_vw_pin_value_certified_tot_mv_not_null + column_name: certified_tot_mv + config: + where: | + CAST(year AS int) < {{ var('data_test_iasworld_year_start') }} AND + year >= '2021' + error_if: ">15" + - not_null: + name: default_vw_pin_value_certified_tot_not_null + column_name: certified_tot + config: + where: CAST(year AS int) < {{ var('data_test_iasworld_year_start') }} + error_if: ">15" + - expression_is_true: + name: default_vw_pin_value_class_is_null_when_values_are_null + meta: + description: > + Test that the 'class' column for each assessment stage is null + whenever the value columns for that stage are null, which is an + assumption that downstream consumers of this view depend upon + expression: | + {% set stages = ['pre_mailed', 'mailed', 'pre_certified', 'certified', 'board'] %} + {% set cols = ['bldg', 'land', 'tot', 'bldg_mv', 'land_mv', 'tot_mv'] %} + + {% for stage in stages %} + {% for null_status in ['IS NULL', 'IS NOT NULL'] %} + ( + {{ stage }}_class {{ null_status }} + AND ( + {% for col in cols %} + {{ stage }}_{{ col }} {{ null_status }} + {% if not loop.last %}AND{% endif %} + {% endfor %} + ) + ) + {% if not loop.last %}OR{% endif %} + {% endfor %} + {% if not loop.last %}OR{% endif %} + {% endfor %} + - not_accepted_values: + name: default_vw_pin_value_mailed_class_no_hyphens + column_name: mailed_class + values: "2-99" + - not_null: + name: default_vw_pin_value_mailed_class_not_null + column_name: mailed_class + config: + where: CAST(year AS int) < {{ var('data_test_iasworld_year_start') }} + error_if: ">289" + - not_null: + name: default_vw_pin_value_mailed_tot_mv_not_null + column_name: mailed_tot_mv + config: + where: | + CAST(year AS int) < {{ var('data_test_iasworld_year_start') }} AND + year >= '2021' + error_if: ">310" + - not_null: + name: default_vw_pin_value_mailed_tot_not_null + column_name: mailed_tot + config: + where: CAST(year AS int) < {{ var('data_test_iasworld_year_start') }} + error_if: ">310" - unique_combination_of_columns: name: default_vw_pin_value_unique_by_14_digit_pin_and_year combination_of_columns: diff --git a/dbt/models/reporting/docs.md b/dbt/models/reporting/docs.md index 8650ea8be..a3a80111f 100644 --- a/dbt/models/reporting/docs.md +++ b/dbt/models/reporting/docs.md @@ -102,16 +102,18 @@ Assessed and market values by PIN and year, for each assessment stage. The assessment stages are: -1. `mailed` - Values initially mailed by the Assessor -2. `certified` - Values after the Assessor has finished processing appeals -2. `board` - Values after the Board of Review has finished their appeals +1. `PRE-MAILED` - Provisional values that are slated to be mailed by the + Assessor once first-pass desk review completes +2. `MAILED` - Values initially mailed by the Assessor +3. `ASSESSOR PRE-CERTIFIED` - Provisional values that are slated to be set by + the Assessor once appeals are finished +4. `ASSESSOR CERTIFIED` - Values after the Assessor has finished processing + appeals +5. `BOARD CERTIFIED` - Values after the Board of Review has finished their + appeals ### Assumptions -- Taking an arbitrary value by 14-digit PIN and year is sufficient for accurate - values. We do this because even given the criteria to de-dupe `asmt_all`, - we still end up with duplicates by PIN and year. - - Market value (`_mv`) columns accurately reflect incentives, statute, levels of assessment, building splits, etc. diff --git a/dbt/models/reporting/reporting.vw_pin_value_long.sql b/dbt/models/reporting/reporting.vw_pin_value_long.sql index e5671146c..50092fc4f 100644 --- a/dbt/models/reporting/reporting.vw_pin_value_long.sql +++ b/dbt/models/reporting/reporting.vw_pin_value_long.sql @@ -1,76 +1,80 @@ -- View containing values from each stage of assessment by PIN and year -- in long format --- CCAO mailed, CCAO final, and BOR final values for each PIN by year. --- We use ARBITRARY functions here to deduplicate PINs with multiple rows for --- a given stage/pin/year combination. Values are always the same within these --- duplicates. +-- List of types of columns that we will extract when pivoting vw_pin_value +-- from wide to long +{% set cols = [ + "class", "bldg", "land", "tot", "bldg_mv", "land_mv", "tot_mv" +] %} + +-- Pivot vw_pin_value from wide to long, so that we create one row for each +-- assessment stage with values pulled from the column types we defined above WITH stage_values AS ( SELECT - parid, - taxyr, - REGEXP_REPLACE(class, '[^[:alnum:]]', '') AS class, - procname, - ARBITRARY( - CASE - WHEN taxyr < '2020' THEN ovrvalasm2 - WHEN taxyr >= '2020' THEN valasm2 - END - ) AS bldg, - ARBITRARY( - CASE - WHEN taxyr < '2020' THEN ovrvalasm1 - WHEN taxyr >= '2020' THEN valasm1 - END - ) AS land, - ARBITRARY( - CASE - WHEN taxyr < '2020' THEN ovrvalasm3 - WHEN taxyr >= '2020' THEN valasm3 - END - ) AS tot, - ARBITRARY( - CASE - WHEN taxyr < '2020' THEN NULL - WHEN taxyr >= '2020' THEN valapr2 - END - ) AS bldg_mv, - ARBITRARY( - CASE - WHEN taxyr < '2020' THEN NULL - WHEN taxyr >= '2020' THEN valapr1 - END - ) AS land_mv, - ARBITRARY( - CASE - WHEN taxyr < '2020' THEN NULL - WHEN taxyr >= '2020' THEN valapr3 - END - ) AS tot_mv - FROM {{ source('iasworld', 'asmt_all') }} - WHERE procname IN ('CCAOVALUE', 'CCAOFINAL', 'BORVALUE') - AND rolltype != 'RR' - AND deactivat IS NULL - AND valclass IS NULL - GROUP BY parid, taxyr, procname, REGEXP_REPLACE(class, '[^[:alnum:]]', '') + t1.pin, + t1.year, + t2.class, + t2.stage_name, + t2.stage_num, + t2.bldg, + t2.land, + t2.tot, + t2.bldg_mv, + t2.land_mv, + t2.tot_mv + FROM {{ ref("default.vw_pin_value") }} AS t1 + CROSS JOIN + UNNEST( + ARRAY[ + 'PRE-MAILED', + 'MAILED', + 'ASSESSOR PRE-CERTIFIED', + 'ASSESSOR CERTIFIED', + -- This is a slightly different stage name from the name that + -- we use in vw_pin_value ('BOARD CERTIFIED'). At some point + -- we may want to align these names, but for now we maintain + -- the difference for legacy compatibility + 'BOR CERTIFIED' + ], + ARRAY[0.5, 1, 1.5, 2, 3], + {% for col in cols %} + ARRAY[ + pre_mailed_{{ col }}, + mailed_{{ col }}, + pre_certified_{{ col }}, + certified_{{ col }}, + board_{{ col }} + ] + {% if not loop.last %},{% endif %} + {% endfor %} + ) + AS t2 ( + stage_name, + stage_num, + {% for col in cols %} + {{ col }}{% if not loop.last %},{% endif %} + {% endfor %} + ) + -- Since we're enumerating the valid stage names by hand, rather than + -- pulling them from the values that are present in the underlying + -- vw_pin_value view, we need some way of determining when a PIN does not + -- have a value for a particular stage in a given year. Checking for a null + -- class is one way of doing that, since it means the `pre_{stage}_class` + -- column is null, which should only be possible in cases where that stage + -- doesn't exist for the PIN/year. Note that we test this assumption with + -- a data test (`default_vw_pin_value_class_is_null_when_values_are_null`) + -- to ensure that it doesn't change in the future + WHERE t2.class IS NOT NULL ) SELECT - svls.parid AS pin, - svls.taxyr AS year, + svls.pin, + svls.year, svls.class, groups.reporting_class_code AS major_class, groups.modeling_group AS property_group, - CASE - WHEN svls.procname = 'CCAOVALUE' THEN 'MAILED' - WHEN svls.procname = 'CCAOFINAL' THEN 'ASSESSOR CERTIFIED' - WHEN svls.procname = 'BORVALUE' THEN 'BOR CERTIFIED' - END AS stage_name, - CASE - WHEN svls.procname = 'CCAOVALUE' THEN 1 - WHEN svls.procname = 'CCAOFINAL' THEN 2 - WHEN svls.procname = 'BORVALUE' THEN 3 - END AS stage_num, + svls.stage_name, + svls.stage_num, svls.bldg, svls.land, svls.tot, diff --git a/dbt/models/reporting/schema.yml b/dbt/models/reporting/schema.yml index d149ea157..f7a666bf0 100644 --- a/dbt/models/reporting/schema.yml +++ b/dbt/models/reporting/schema.yml @@ -274,6 +274,9 @@ models: name: reporting_vw_pin_value_long_mailed_class_no_hyphens column_name: class values: "2-99" + - not_null: + name: reporting_vw_pin_value_long_stage_name_not_null + column_name: stage_name - not_null: name: reporting_vw_pin_value_long_tot_mv_not_null column_name: tot_mv diff --git a/dbt/models/shared_columns.md b/dbt/models/shared_columns.md index 1d479e3e0..fb606fd0c 100644 --- a/dbt/models/shared_columns.md +++ b/dbt/models/shared_columns.md @@ -386,6 +386,117 @@ However, this value is post-Desk Review and so may not perfectly match outputs from the model {% enddocs %} +## pre_certified_bldg + +{% docs shared_column_pre_certified_bldg %} +Provisional certified assessed/market value of building from year specified by +column prefix (or year of observation if not prefixed). + +Provisional certified values are not final, and are only present in the +data for the current assessment year up until the moment when appeals are +finalized. At that point the `pre_certified` values disappear and `certified` +values replace them +{% enddocs %} + +## pre_certified_class + +{% docs shared_column_pre_certified_class %} +Provisional stage-level property type and/or use at the time of CCAO +certification. + +Designates the property type, such as vacant, residential, multi-family, +agricultural, commercial or industrial. The classification determines the +percentage of fair cash value at which a property is assessed for taxing +purposes. See `ccao.class_dict` for more information. + +Provisional certified values are not final, and are only present in the +data for the current assessment year up until the moment when appeals are +finalized. At that point the `pre_certified` values disappear and `certified` +values replace them +{% enddocs %} + +## pre_certified_land + +{% docs shared_column_pre_certified_land %} +Provisional certified assessed/market value of land from year specified by +column prefix (or year of observation if not prefixed). + +Provisional certified values are not final, and are only present in the +data for the current assessment year up until the moment when appeals are +finalized. At that point the `pre_certified` values disappear and `certified` +values replace them +{% enddocs %} + +## pre_certified_tot + +{% docs shared_column_pre_certified_tot %} +Provisional certified total assessed/market value from year specified by column +prefix (or year of observation if not prefixed). + +This is the value after the first round of appeals at the Assessor's Office. + +Provisional certified values are not final, and are only present in the +data for the current assessment year up until the moment when appeals are +finalized. At that point the `pre_certified` values disappear and `certified` +values replace them +{% enddocs %} + +## pre_mailed_bldg + +{% docs shared_column_pre_mailed_bldg %} +Provisional mailed assessed/market value of building from year specified by +column prefix (or year of observation if not prefixed). + +Provisional mailed values are not final, and are only present in the +data for the current assessment year up until the moment when values go out to +mail. At that point the `pre_mailed` values disappear and `mailed` values +replace them +{% enddocs %} + +## pre_mailed_class + +{% docs shared_column_pre_mailed_class %} +Provisional stage-level property type and/or use at the time of CCAO mailing. + +Designates the property type, such as vacant, residential, multi-family, +agricultural, commercial or industrial. The classification determines the +percentage of fair cash value at which a property is assessed for taxing +purposes. See `ccao.class_dict` for more information. + +Provisional mailed values are not final, and are only present in the +data for the current assessment year up until the moment when values go out to +mail. At that point the `pre_mailed` values disappear and `mailed` values +replace them +{% enddocs %} + +## pre_mailed_land + +{% docs shared_column_pre_mailed_land %} +Provisional mailed assessed/market value of land from year specified by column +prefix (or year of observation if not prefixed). + +Provisional mailed values are not final, and are only present in the +data for the current assessment year up until the moment when values go out to +mail. At that point the `pre_mailed` values disappear and `mailed` values +replace them +{% enddocs %} + +## pre_mailed_tot + +{% docs shared_column_pre_mailed_tot %} +Provisional mailed total assessed/market value from year specified by column +prefix (or year of observation if not prefixed). + +This the pre-appeal value that is initially mailed to taxpayers. +However, this value is post-Desk Review and so may not perfectly match +outputs from the model. + +Provisional mailed values are not final, and are only present in the +data for the current assessment year up until the moment when values go out to +mail. At that point the `pre_mailed` values disappear and `mailed` values +replace them +{% enddocs %} + # Characteristics ## char_age