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

Add final_model CSV seed #365

Merged
merged 32 commits into from
Apr 11, 2024
Merged

Add final_model CSV seed #365

merged 32 commits into from
Apr 11, 2024

Conversation

dfsnow
Copy link
Member

@dfsnow dfsnow commented Mar 28, 2024

This PR moves the final_model table into dbt as a seed. It also updates the table (and downstream dependencies) such that an individual year can have multiple final models. Finally, it adds the 2024 final model records in final_model.

I played around with using [ephemeral](https://docs.getdbt.com/docs/build/materializations#ephemeral models to accomplish this, but they ended up not being needed.

Testing

Here's proof that the updated table/join results in no changes.

vw_ratio_stats

SELECT old.year, old.cnt_old, new.cnt_new
FROM (
    SELECT year, COUNT(*) AS cnt_old
    FROM "reporting"."vw_ratio_stats"
    GROUP BY year
) old
LEFT JOIN (
    SELECT year, COUNT(*) AS cnt_new
    FROM "z_ci_dfsnow-add-final-model-seed_reporting"."vw_ratio_stats"
    GROUP BY year
) new
ON old.year = new.year
ORDER BY year
year cnt_old cnt_new
2021 205368 205368
2022 300219 300219
2023 231949 231949
2024 3448 57008

And EXCEPT shows no value differences:

SELECT COUNT(*)
FROM (
    SELECT *
    FROM "reporting"."vw_ratio_stats"
    WHERE year <= '2023'
    EXCEPT
    SELECT *
    FROM "z_ci_dfsnow-add-final-model-seed_reporting"."vw_ratio_stats"
    WHERE year <= '2023'
)
count
0

res_report_summary

SELECT old.year, old.cnt_old, new.cnt_new
FROM (
    SELECT year, COUNT(*) AS cnt_old
    FROM "reporting"."res_report_summary"
    GROUP BY year
) old
LEFT JOIN (
    SELECT year, COUNT(*) AS cnt_new
    FROM "z_ci_dfsnow-add-final-model-seed_reporting"."res_report_summary"
    GROUP BY year
) new
ON old.year = new.year
ORDER BY year
year cnt_old cnt_new
2021 8850 8850
2022 13003 13003
2023 10128 10128
2024 268 3220

dbt/dbt_project.yml Outdated Show resolved Hide resolved
Comment on lines 40 to 50
# final_model

{% docs table_final_model %}
Final model `run_id` and information for each year.

This table is manually updated (edit the CSV on S3) once the residential
and condominium models are finalized for each year.

**Primary Key**: `year`, `run_id`
{% enddocs %}

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

This is just moved over to seeds/model/docs.md.

@@ -38,18 +38,45 @@ town_names AS (
FROM {{ source('spatial', 'township') }}
),

final_model_parsed AS (
Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

As an aside, I kind of wish there was some way to parse or process seeds so we wouldn't need to use this CTE. We could just make another model downstream of the seed, but that feels a little messy. Thoughts?

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

We can do some naive parsing at the level of the raw seed by specifying column_types, but that won't help with encoding the triad_name categoricals, and I'm not super confident it would work with the township_code_coverage array field either. I think a transformation model is actually the idiomatic way of doing this in dbt, since dbt encourages explicit data transformations; an ephemeral model on top of the raw seed would be ideal if ephemeral models were supported in dbt-athena (#238), but I think if we renamed the seed model to something like model.final_model_raw and made model.final_model a view on top of that then it would still be pretty clear what's going on.

If we think that this particular parsing of the seed will only be used in a couple places, I'm also fine keeping the code as-is and using a CTE for parsing where necessary. A transformation model is only necessary to the extent that this logic will be widely used, in my opinion.

Copy link
Member Author

@dfsnow dfsnow Apr 11, 2024

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I think it's valuable to have a parsed version available. Added it in 7011d36!

model_values AS (
SELECT
ap.meta_pin AS parid,
CAST(CAST(ap.meta_year AS INT) + 1 AS VARCHAR) AS year,
ap.year,
Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

meta_year is the year of characteristics, year is the actual year of modeling/values.

Comment on lines 98 to 106
AND (
-- If reassessment year, use different models for different towns
(
CONTAINS(fm.townships, 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)
)
Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

This heinous join is the result of the new final_model schema. We need a way to get a model per township in a tri year, then the "final" model everywhere else.

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Even though all the counts match, I can't get the actual values to match exactly for this view for the life of me. The SQL below returns lots of mismatched rows with slightly different values.

SELECT *
FROM "reporting"."res_report_summary"
WHERE year <= '2023'
EXCEPT
SELECT *
FROM "z_ci_dfsnow-add-final-model-seed_reporting"."res_report_summary"
WHERE year <= '2023'

I think it may have something to do with the approx_percentile() function being dependent on the order of the data fed to it, but I'm not sure. Since we're already changing a bunch of stuff in the reporting views, it may not be an issue. @wrridgeway, can you let me know if you have any ideas on this/if I should dive deeper on it?

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

If the differences are only slight, I'm not concerned about it, approx_percentile is not deterministic as I understand it. Let me test using syntax that grabs the values inside of the CTAS real quick to see if things like mean/min/max line up.

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Here's some heinous code to confirm it's not an issue with values differing across the different builds:

WITH town_class AS (
    SELECT
        par.parid,
        par.taxyr,
        town.triad_name AS triad,
        leg.user1 AS township_code,
        CONCAT(leg.user1, SUBSTR(par.nbhd, 3, 3)) AS townnbhd,
        par.class,
        CASE WHEN par.class IN ('299', '399') THEN 'CONDO'
            WHEN par.class IN ('211', '212') THEN 'MF'
            WHEN
                par.class IN (
                    '202', '203', '204', '205', '206', '207',
                    '208', '209', '210', '234', '278', '295'
                )
                THEN 'SF'
        END AS property_group,
        CAST(CAST(par.taxyr AS INT) - 1 AS VARCHAR) AS model_join_year
    FROM iasworld.pardat AS par
    LEFT JOIN iasworld.legdat AS leg
        ON par.parid = leg.parid
        AND par.taxyr = leg.taxyr
    LEFT JOIN spatial.township AS town
        ON leg.user1 = town.township_code
    WHERE par.cur = 'Y'
        AND par.deactivat IS NULL
        AND leg.cur = 'Y'
        AND leg.deactivat IS NULL
),

-- Final model values (Add 1 to model year since '2021' correspond to '2022'
-- mailed values in iasWorld)
model_values_old AS (
    SELECT
        ap.meta_pin AS parid,
        tc.property_group,
        tc.class,
        tc.triad,
        tc.township_code,
        tc.townnbhd,
        tc.taxyr AS year,
        'model' AS assessment_stage,
        ap.pred_pin_final_fmv_round AS total
    FROM model.assessment_pin AS ap
    LEFT JOIN town_class AS tc
        ON ap.meta_pin = tc.parid
        AND ap.meta_year = tc.model_join_year
    INNER JOIN model.final_model AS fm
        ON ap.run_id = fm.run_id
        AND ap.year = CAST(fm.year AS varchar)
        
    WHERE tc.property_group IS NOT NULL
        AND tc.triad IS NOT NULL

),

-- Final model values (Add 1 to model year since '2021' correspond to '2022'
-- mailed values in iasWorld)
model_values_new AS (
    SELECT
        ap.meta_pin AS parid,
        tc.property_group,
        tc.class,
        tc.triad,
        tc.township_code,
        tc.townnbhd,
        tc.taxyr AS year,
        'model' AS assessment_stage,
        ap.pred_pin_final_fmv_round AS total
    FROM model.assessment_pin AS ap
    LEFT JOIN town_class AS tc
        ON ap.meta_pin = tc.parid
        AND ap.meta_year = tc.model_join_year
    INNER JOIN "z_ci_dfsnow-add-final-model-seed_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)
        )
    WHERE tc.property_group IS NOT NULL
        AND tc.triad IS NOT NULL
        AND fm.year != '2024'
)

select
mvo.township_code, mvo.year,
min(mvo.total) as old_min,
min(mvn.total) as new_min,
max(mvo.total) as old_max,
max(mvn.total) as new_max,
avg(mvo.total) as old_avg,
avg(mvn.total) as new_avg
from model_values_old mvo
LEFT JOIN model_values_new mvn
    ON mvo.parid = mvn.parid
    AND mvo.year = mvn.year
group by mvo.township_code, mvo.year
order by mvo.township_code, mvo.year
township_code year old_min new_min old_max new_max old_avg new_avg
10 2022 15000 15000 4760000 4760000 693291.2189 693291.2189
10 2023 18000 18000 940600 940600 445256.1265 445256.1265
11 2022 0 0 650000 650000 272508.4451 272508.4451
11 2023 10 10 650000 650000 261533.9616 261533.9616
12 2022 30 30 730000 730000 153554.264 153554.264
12 2023 3680 3680 1740000 1740000 166666.9488 166666.9488
13 2022 480 480 800000 800000 180661.8648 180661.8648
13 2023 480 480 1370000 1370000 188551.4667 188551.4667
14 2022 7500 7500 590000 590000 126844.4994 126844.4994
14 2023 13746 13746 560000 560000 133519.884 133519.884
15 2022 10000 10000 630000 630000 229951.8672 229951.8672
15 2023 22064 22064 690000 690000 229494.871 229494.871
16 2022 20 20 1400000 1400000 281583.4609 281583.4609
16 2023 20 20 516900 516900 160768.5653 160768.5653
17 2022 20 20 3830000 3830000 455977.365 455977.365
17 2023 20 20 2280600 2280600 243351.5237 243351.5237
18 2022 10000 10000 1110000 1110000 263610.1381 263610.1381
18 2023 70700 70700 422400 422400 214440.0557 214440.0557
19 2022 30000 30000 2140000 2140000 453188.0143 453188.0143
19 2023 33900 33900 2370000 2370000 480643.87 480643.87
20 2022 30 30 1120000 1120000 258809.8879 258809.8879
20 2023 20 20 484200 484200 132780.5386 132780.5386
21 2022 20 20 6160000 6160000 384317.8438 384317.8438
21 2023 20 20 3610000 3610000 407743.6904 407743.6904
22 2022 10 10 2020000 2020000 333492.7646 333492.7646
22 2023 20 20 834700 834700 175539.8301 175539.8301
23 2022 20 20 1.67E+07 1.67E+07 1029317.645 1029317.645
23 2023 20 20 1730200 1730200 322301.1406 322301.1406
24 2022 20 20 2400000 2400000 338021.1736 338021.1736
24 2023 20 20 1687000 1687000 202749.4441 202749.4441
25 2022 50 50 5170000 5170000 597015.3866 597015.3866
25 2023 50 50 972900 972900 287126.6216 287126.6216
26 2022 15000 15000 1120000 1120000 365525.3378 365525.3378
26 2023 104000 104000 452600 452600 247341.4868 247341.4868
27 2022 0 0 2170000 2170000 390699.6299 390699.6299
27 2023 0 0 2760000 2760000 406387.6999 406387.6999
28 2022 7200 7200 4260000 4260000 319471.2634 319471.2634
28 2023 7160 7160 5260000 5260000 340999.3281 340999.3281
29 2022 90 90 2690000 2690000 319296.467 319296.467
29 2023 20 20 1315900 1315900 180592.2975 180592.2975
30 2022 2240 2240 1970000 1970000 291459.3331 291459.3331
30 2023 2480 2480 2290000 2290000 307844.4053 307844.4053
31 2022 50 50 1390000 1390000 243563.1733 243563.1733
31 2023 50 50 1500000 1500000 258503.7078 258503.7078
32 2022 2200 2200 870000 870000 190905.69 190905.69
32 2023 2290 2290 4600000 4600000 210359.4036 210359.4036
33 2022 10 10 2720000 2720000 584373.754 584373.754
33 2023 20 20 2290000 2290000 619751.0155 619751.0155
34 2022 2160 2160 1546600 1546600 364896.4762 364896.4762
34 2023 2230 2230 1390000 1390000 386781.28 386781.28
35 2022 2670 2670 1140000 1140000 277124.0889 277124.0889
35 2023 327 327 354700 354700 181164.7315 181164.7315
36 2022 4000 4000 750000 750000 237671.2834 237671.2834
36 2023 10733 10733 720000 720000 233506.3708 233506.3708
37 2022 3000 3000 830000 830000 128533.7808 128533.7808
37 2023 4180 4180 1330000 1330000 134200.8807 134200.8807
38 2022 20 20 1980000 1980000 315401.6555 315401.6555
38 2023 760 760 796100 796100 187741.4772 187741.4772
39 2022 30 30 1730000 1730000 204654.0277 204654.0277
39 2023 30 30 1590000 1590000 212764.6871 212764.6871
70 2022 0 0 8606900 8606900 202226.8851 202226.8851
70 2023 0 0 755700 755700 178841.3341 178841.3341
71 2022 568 568 2320000 2320000 377286.6489 377286.6489
71 2023 1330 1330 1093200 1093200 190470.1801 190470.1801
72 2022 26 26 1900000 1900000 206104.3928 206104.3928
72 2023 5060 5060 371700 371700 115418.879 115418.879
73 2022 40 40 7586200 7586200 457181.8555 457181.8555
73 2023 10 10 3777200 3777200 291792.9079 291792.9079
74 2022 0 0 2.31E+07 2.31E+07 473806.5927 473806.5927
74 2023 0 0 8309900 8309900 356508.5903 356508.5903
75 2022 700 700 5290000 5290000 283193.2209 283193.2209
75 2023 700 700 1113000 1113000 170951.3368 170951.3368
76 2022 17 17 2.21E+07 2.21E+07 295717.5609 295717.5609
76 2023 0 0 3801600 3801600 239355.7706 239355.7706
77 2022 3 3 6860000 6860000 391541.3889 391541.3889
77 2023 0 0 2827900 2827900 321829.6277 321829.6277

@dfsnow dfsnow marked this pull request as ready for review April 10, 2024 03:14
@dfsnow dfsnow requested a review from a team as a code owner April 10, 2024 03:14
Copy link
Contributor

@jeancochrane jeancochrane left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Nice use of a seed!

dbt/seeds/model/schema.yml Outdated Show resolved Hide resolved
@@ -38,18 +38,45 @@ town_names AS (
FROM {{ source('spatial', 'township') }}
),

final_model_parsed AS (
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

We can do some naive parsing at the level of the raw seed by specifying column_types, but that won't help with encoding the triad_name categoricals, and I'm not super confident it would work with the township_code_coverage array field either. I think a transformation model is actually the idiomatic way of doing this in dbt, since dbt encourages explicit data transformations; an ephemeral model on top of the raw seed would be ideal if ephemeral models were supported in dbt-athena (#238), but I think if we renamed the seed model to something like model.final_model_raw and made model.final_model a view on top of that then it would still be pretty clear what's going on.

If we think that this particular parsing of the seed will only be used in a couple places, I'm also fine keeping the code as-is and using a CTE for parsing where necessary. A transformation model is only necessary to the extent that this logic will be widely used, in my opinion.

@@ -0,0 +1,47 @@
seeds:
- name: model.final_model
Copy link
Contributor

@jeancochrane jeancochrane Apr 10, 2024

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

[Thought, non-blocking] What do we think about adding some tests to this model? In particular, I'm thinking about how the join conditions in this PR depend on the assumption that the combination of township_code_coverage values for final models in a given year cover all triads in that year's township. I'm not 100% confident that our current strategy for testing changed and added models would work for seeds -- we know that models will get tested if the queries that comprise them change, but I'm not sure if we can expect the same behavior for seeds whose data change -- but if we could get it working I think it would be a helpful safeguard for future maintainers who need to modify the model.final_model.csv seed file.

Just an idea for the future, we can do this investigation in a follow-up issue!

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Let's kick this to a follow-up issue. See #376

Co-authored-by: Jean Cochrane <jeancochrane@users.noreply.github.com>
@dfsnow dfsnow force-pushed the dfsnow/add-final-model-seed branch from b2a7b53 to 333de4a Compare April 11, 2024 16:45
@dfsnow dfsnow force-pushed the dfsnow/add-final-model-seed branch from 333de4a to 7011d36 Compare April 11, 2024 16:48
Copy link
Contributor

@jeancochrane jeancochrane left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Looks great, two small suggestions but otherwise this is ready to go!

dbt/seeds/model/docs.md Outdated Show resolved Hide resolved
aws-athena/ctas/model.final_model.sql Show resolved Hide resolved
Co-authored-by: Jean Cochrane <jeancochrane@users.noreply.github.com>
@dfsnow dfsnow force-pushed the dfsnow/add-final-model-seed branch from b773b58 to 0b7a716 Compare April 11, 2024 17:41
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

If the differences are only slight, I'm not concerned about it, approx_percentile is not deterministic as I understand it. Let me test using syntax that grabs the values inside of the CTAS real quick to see if things like mean/min/max line up.

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Here's some heinous code to confirm it's not an issue with values differing across the different builds:

WITH town_class AS (
    SELECT
        par.parid,
        par.taxyr,
        town.triad_name AS triad,
        leg.user1 AS township_code,
        CONCAT(leg.user1, SUBSTR(par.nbhd, 3, 3)) AS townnbhd,
        par.class,
        CASE WHEN par.class IN ('299', '399') THEN 'CONDO'
            WHEN par.class IN ('211', '212') THEN 'MF'
            WHEN
                par.class IN (
                    '202', '203', '204', '205', '206', '207',
                    '208', '209', '210', '234', '278', '295'
                )
                THEN 'SF'
        END AS property_group,
        CAST(CAST(par.taxyr AS INT) - 1 AS VARCHAR) AS model_join_year
    FROM iasworld.pardat AS par
    LEFT JOIN iasworld.legdat AS leg
        ON par.parid = leg.parid
        AND par.taxyr = leg.taxyr
    LEFT JOIN spatial.township AS town
        ON leg.user1 = town.township_code
    WHERE par.cur = 'Y'
        AND par.deactivat IS NULL
        AND leg.cur = 'Y'
        AND leg.deactivat IS NULL
),

-- Final model values (Add 1 to model year since '2021' correspond to '2022'
-- mailed values in iasWorld)
model_values_old AS (
    SELECT
        ap.meta_pin AS parid,
        tc.property_group,
        tc.class,
        tc.triad,
        tc.township_code,
        tc.townnbhd,
        tc.taxyr AS year,
        'model' AS assessment_stage,
        ap.pred_pin_final_fmv_round AS total
    FROM model.assessment_pin AS ap
    LEFT JOIN town_class AS tc
        ON ap.meta_pin = tc.parid
        AND ap.meta_year = tc.model_join_year
    INNER JOIN model.final_model AS fm
        ON ap.run_id = fm.run_id
        AND ap.year = CAST(fm.year AS varchar)
        
    WHERE tc.property_group IS NOT NULL
        AND tc.triad IS NOT NULL

),

-- Final model values (Add 1 to model year since '2021' correspond to '2022'
-- mailed values in iasWorld)
model_values_new AS (
    SELECT
        ap.meta_pin AS parid,
        tc.property_group,
        tc.class,
        tc.triad,
        tc.township_code,
        tc.townnbhd,
        tc.taxyr AS year,
        'model' AS assessment_stage,
        ap.pred_pin_final_fmv_round AS total
    FROM model.assessment_pin AS ap
    LEFT JOIN town_class AS tc
        ON ap.meta_pin = tc.parid
        AND ap.meta_year = tc.model_join_year
    INNER JOIN "z_ci_dfsnow-add-final-model-seed_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)
        )
    WHERE tc.property_group IS NOT NULL
        AND tc.triad IS NOT NULL
        AND fm.year != '2024'
)

select
mvo.township_code, mvo.year,
min(mvo.total) as old_min,
min(mvn.total) as new_min,
max(mvo.total) as old_max,
max(mvn.total) as new_max,
avg(mvo.total) as old_avg,
avg(mvn.total) as new_avg
from model_values_old mvo
LEFT JOIN model_values_new mvn
    ON mvo.parid = mvn.parid
    AND mvo.year = mvn.year
group by mvo.township_code, mvo.year
order by mvo.township_code, mvo.year
township_code year old_min new_min old_max new_max old_avg new_avg
10 2022 15000 15000 4760000 4760000 693291.2189 693291.2189
10 2023 18000 18000 940600 940600 445256.1265 445256.1265
11 2022 0 0 650000 650000 272508.4451 272508.4451
11 2023 10 10 650000 650000 261533.9616 261533.9616
12 2022 30 30 730000 730000 153554.264 153554.264
12 2023 3680 3680 1740000 1740000 166666.9488 166666.9488
13 2022 480 480 800000 800000 180661.8648 180661.8648
13 2023 480 480 1370000 1370000 188551.4667 188551.4667
14 2022 7500 7500 590000 590000 126844.4994 126844.4994
14 2023 13746 13746 560000 560000 133519.884 133519.884
15 2022 10000 10000 630000 630000 229951.8672 229951.8672
15 2023 22064 22064 690000 690000 229494.871 229494.871
16 2022 20 20 1400000 1400000 281583.4609 281583.4609
16 2023 20 20 516900 516900 160768.5653 160768.5653
17 2022 20 20 3830000 3830000 455977.365 455977.365
17 2023 20 20 2280600 2280600 243351.5237 243351.5237
18 2022 10000 10000 1110000 1110000 263610.1381 263610.1381
18 2023 70700 70700 422400 422400 214440.0557 214440.0557
19 2022 30000 30000 2140000 2140000 453188.0143 453188.0143
19 2023 33900 33900 2370000 2370000 480643.87 480643.87
20 2022 30 30 1120000 1120000 258809.8879 258809.8879
20 2023 20 20 484200 484200 132780.5386 132780.5386
21 2022 20 20 6160000 6160000 384317.8438 384317.8438
21 2023 20 20 3610000 3610000 407743.6904 407743.6904
22 2022 10 10 2020000 2020000 333492.7646 333492.7646
22 2023 20 20 834700 834700 175539.8301 175539.8301
23 2022 20 20 1.67E+07 1.67E+07 1029317.645 1029317.645
23 2023 20 20 1730200 1730200 322301.1406 322301.1406
24 2022 20 20 2400000 2400000 338021.1736 338021.1736
24 2023 20 20 1687000 1687000 202749.4441 202749.4441
25 2022 50 50 5170000 5170000 597015.3866 597015.3866
25 2023 50 50 972900 972900 287126.6216 287126.6216
26 2022 15000 15000 1120000 1120000 365525.3378 365525.3378
26 2023 104000 104000 452600 452600 247341.4868 247341.4868
27 2022 0 0 2170000 2170000 390699.6299 390699.6299
27 2023 0 0 2760000 2760000 406387.6999 406387.6999
28 2022 7200 7200 4260000 4260000 319471.2634 319471.2634
28 2023 7160 7160 5260000 5260000 340999.3281 340999.3281
29 2022 90 90 2690000 2690000 319296.467 319296.467
29 2023 20 20 1315900 1315900 180592.2975 180592.2975
30 2022 2240 2240 1970000 1970000 291459.3331 291459.3331
30 2023 2480 2480 2290000 2290000 307844.4053 307844.4053
31 2022 50 50 1390000 1390000 243563.1733 243563.1733
31 2023 50 50 1500000 1500000 258503.7078 258503.7078
32 2022 2200 2200 870000 870000 190905.69 190905.69
32 2023 2290 2290 4600000 4600000 210359.4036 210359.4036
33 2022 10 10 2720000 2720000 584373.754 584373.754
33 2023 20 20 2290000 2290000 619751.0155 619751.0155
34 2022 2160 2160 1546600 1546600 364896.4762 364896.4762
34 2023 2230 2230 1390000 1390000 386781.28 386781.28
35 2022 2670 2670 1140000 1140000 277124.0889 277124.0889
35 2023 327 327 354700 354700 181164.7315 181164.7315
36 2022 4000 4000 750000 750000 237671.2834 237671.2834
36 2023 10733 10733 720000 720000 233506.3708 233506.3708
37 2022 3000 3000 830000 830000 128533.7808 128533.7808
37 2023 4180 4180 1330000 1330000 134200.8807 134200.8807
38 2022 20 20 1980000 1980000 315401.6555 315401.6555
38 2023 760 760 796100 796100 187741.4772 187741.4772
39 2022 30 30 1730000 1730000 204654.0277 204654.0277
39 2023 30 30 1590000 1590000 212764.6871 212764.6871
70 2022 0 0 8606900 8606900 202226.8851 202226.8851
70 2023 0 0 755700 755700 178841.3341 178841.3341
71 2022 568 568 2320000 2320000 377286.6489 377286.6489
71 2023 1330 1330 1093200 1093200 190470.1801 190470.1801
72 2022 26 26 1900000 1900000 206104.3928 206104.3928
72 2023 5060 5060 371700 371700 115418.879 115418.879
73 2022 40 40 7586200 7586200 457181.8555 457181.8555
73 2023 10 10 3777200 3777200 291792.9079 291792.9079
74 2022 0 0 2.31E+07 2.31E+07 473806.5927 473806.5927
74 2023 0 0 8309900 8309900 356508.5903 356508.5903
75 2022 700 700 5290000 5290000 283193.2209 283193.2209
75 2023 700 700 1113000 1113000 170951.3368 170951.3368
76 2022 17 17 2.21E+07 2.21E+07 295717.5609 295717.5609
76 2023 0 0 3801600 3801600 239355.7706 239355.7706
77 2022 3 3 6860000 6860000 391541.3889 391541.3889
77 2023 0 0 2827900 2827900 321829.6277 321829.6277

@dfsnow dfsnow merged commit 739a4ba into master Apr 11, 2024
11 checks passed
@dfsnow dfsnow deleted the dfsnow/add-final-model-seed branch April 11, 2024 20:24
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

3 participants