-
Notifications
You must be signed in to change notification settings - Fork 9
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
Bias adjusted precip #3202
Merged
Merged
Bias adjusted precip #3202
Changes from all commits
Commits
Show all changes
11 commits
Select commit
Hold shift + click to select a range
57f843a
Add field to model and materialized view
dgboss f577fcb
observations crud functions
dgboss ac224cd
weather_models crud
dgboss 5a9f932
Bias adjusted prcip
dgboss 65bdbc7
Show bias adjusted precip on front-end
dgboss 3fff2f6
Merge branch 'main' into story/bias-adjusted-precip-final/2816
conbrad 340c53c
Add function description
dgboss 4ec9d03
Move precip model into RegressionModelsV2
dgboss f71c153
Merge branch 'main' into story/bias-adjusted-precip-final/2816
conbrad ea38419
Lint fixes
conbrad d2da018
Fix off by one day error
dgboss File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,68 @@ | ||
"""bias adjusted precip | ||
|
||
Revision ID: f2e027a47a3f | ||
Revises: 5b745fe0bd7a | ||
Create Date: 2023-10-30 11:34:21.603046 | ||
|
||
""" | ||
from alembic import op | ||
import sqlalchemy as sa | ||
|
||
# revision identifiers, used by Alembic. | ||
revision = 'f2e027a47a3f' | ||
down_revision = '5b745fe0bd7a' | ||
branch_labels = None | ||
depends_on = None | ||
|
||
|
||
def upgrade(): | ||
op.add_column('weather_station_model_predictions', sa.Column('bias_adjusted_precip_24h', sa.Float(), nullable=True)) | ||
# Drop morecast_2_materialized view and recreate with the bias_adjusted_precip_24h field | ||
op.execute("DROP MATERIALIZED VIEW morecast_2_materialized_view;") | ||
op.execute(""" | ||
CREATE MATERIALIZED VIEW morecast_2_materialized_view AS | ||
SELECT weather_station_model_predictions.prediction_timestamp, prediction_models.abbreviation, weather_station_model_predictions.station_code, | ||
weather_station_model_predictions.rh_tgl_2, weather_station_model_predictions.tmp_tgl_2, weather_station_model_predictions.bias_adjusted_temperature, | ||
weather_station_model_predictions.bias_adjusted_rh, weather_station_model_predictions.precip_24h, weather_station_model_predictions.wdir_tgl_10, | ||
weather_station_model_predictions.wind_tgl_10, weather_station_model_predictions.bias_adjusted_wind_speed, weather_station_model_predictions.bias_adjusted_wdir, | ||
weather_station_model_predictions.bias_adjusted_precip_24h, weather_station_model_predictions.update_date, | ||
weather_station_model_predictions.prediction_model_run_timestamp_id | ||
FROM weather_station_model_predictions | ||
JOIN prediction_model_run_timestamps | ||
ON weather_station_model_predictions.prediction_model_run_timestamp_id = prediction_model_run_timestamps.id JOIN prediction_models | ||
ON prediction_model_run_timestamps.prediction_model_id = prediction_models.id | ||
JOIN ( | ||
SELECT max(weather_station_model_predictions.prediction_timestamp) AS latest_prediction, weather_station_model_predictions.station_code AS station_code, | ||
date(weather_station_model_predictions.prediction_timestamp) AS unique_day | ||
FROM weather_station_model_predictions | ||
WHERE date_part('hour', weather_station_model_predictions.prediction_timestamp) = 20 | ||
GROUP BY weather_station_model_predictions.station_code, date(weather_station_model_predictions.prediction_timestamp) | ||
) AS latest | ||
ON weather_station_model_predictions.prediction_timestamp = latest.latest_prediction AND weather_station_model_predictions.station_code = latest.station_code | ||
ORDER BY weather_station_model_predictions.update_date DESC;""") | ||
|
||
|
||
def downgrade(): | ||
# Drop morecast_2_materialized view before dropping the column in the table in order to avoid dependency issues | ||
op.execute("DROP MATERIALIZED VIEW morecast_2_materialized_view;") | ||
op.drop_column('weather_station_model_predictions', 'bias_adjusted_precip_24h') | ||
op.execute(""" | ||
CREATE MATERIALIZED VIEW morecast_2_materialized_view AS | ||
SELECT weather_station_model_predictions.prediction_timestamp, prediction_models.abbreviation, weather_station_model_predictions.station_code, | ||
weather_station_model_predictions.rh_tgl_2, weather_station_model_predictions.tmp_tgl_2, weather_station_model_predictions.bias_adjusted_temperature, | ||
weather_station_model_predictions.bias_adjusted_rh, weather_station_model_predictions.precip_24h, weather_station_model_predictions.wdir_tgl_10, | ||
weather_station_model_predictions.wind_tgl_10, weather_station_model_predictions.bias_adjusted_wind_speed, weather_station_model_predictions.bias_adjusted_wdir, | ||
weather_station_model_predictions.update_date | ||
FROM weather_station_model_predictions | ||
JOIN prediction_model_run_timestamps | ||
ON weather_station_model_predictions.prediction_model_run_timestamp_id = prediction_model_run_timestamps.id JOIN prediction_models | ||
ON prediction_model_run_timestamps.prediction_model_id = prediction_models.id | ||
JOIN ( | ||
SELECT max(weather_station_model_predictions.prediction_timestamp) AS latest_prediction, weather_station_model_predictions.station_code AS station_code, | ||
date(weather_station_model_predictions.prediction_timestamp) AS unique_day | ||
FROM weather_station_model_predictions | ||
WHERE date_part('hour', weather_station_model_predictions.prediction_timestamp) = 20 | ||
GROUP BY weather_station_model_predictions.station_code, date(weather_station_model_predictions.prediction_timestamp) | ||
) AS latest | ||
ON weather_station_model_predictions.prediction_timestamp = latest.latest_prediction AND weather_station_model_predictions.station_code = latest.station_code | ||
ORDER BY weather_station_model_predictions.update_date DESC;""") |
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
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
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
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
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
Oops, something went wrong.
Oops, something went wrong.
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
I'm not familiar with this syntax, but is this creating a series of days based on 24 hour intervals, then selecting each weather date based on it's hour being less than the subset of the series, then summing up the precip based on the hourly actuals that fit in that window? (There's probably a better way of expressing this in English)...
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Do we have/need an index on
hourly_actuals.weather_date
for this query?There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Haha, you have the gist of it. I'm glad you asked this question, I think I found an off-by-one day logic error.
I'll add to the comment with a description of what this is doing.
generate_series(\'{}\', \'{}\', '24 hours'::interval)
This gives us a one column table of dates separated by 24 hours between the start and end dates. For example, if start and end dates are 2023-10-31 20:00:00 to 2023-11-03 20:00:00 we would have a table like:
We then join the
HourlyActuals
table so that we can sum hourly precip in a 24 hour period. The join is based on theweather_date
field in theHourlyActuals
table being in a 24 hour range using this odd looking syntax:weather_date <@ tstzrange(day, day + '24 hours', '(]')
Using 2023-10-31 20:00:00 as an example, rows with the following dates would match. The (] syntax means the lower bound is excluded but the upper bound is included.
2023-10-31 21:00:00
2023-10-31 22:00:00
2023-10-31 23:00:00
2023-11-01 00:00:00
2023-11-01 01:00:00
....
2023-11-01 19:00:00
2023-11-01 20:00:00
My off by one error is that right now I am attributing this accumulated precipitation to October 31, but it should actually be for Nov 1 (we need the preceding 24 hour precip).
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
An index on weather_date is a great idea!