Skip to content

Commit

Permalink
Fix get hydro op chars and tmp opr inputs from db (#1153)
Browse files Browse the repository at this point in the history
* Update how hydro op chars are selected from the database to only 
select horizons on periods when the project is operational
* Update how tmp opr inputs are selected from the database to only 
select timepoints when the project is operational
  • Loading branch information
Janie115 authored Sep 23, 2024
1 parent d2089ef commit 598b742
Show file tree
Hide file tree
Showing 2 changed files with 88 additions and 54 deletions.
32 changes: 32 additions & 0 deletions db/db_schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6242,6 +6242,38 @@ FROM inputs_temporal
USING (temporal_scenario_id, stage_id, timepoint)
;

-- This view shows the possible operational horizons for each project based
-- based on its operational periods (see project_operational_periods), its
-- balancing type, and the periods-horizons mapping for that balancing type
-- (see periods_horizons). It also includes the operational type and the
-- hydro_operational_chars_scenario_id, since these are useful to slice out
-- operational types of interest (namely hydro) and join the hydro inputs,
-- which are indexed by project-horizon.
DROP VIEW IF EXISTS project_operational_horizons;
CREATE VIEW project_operational_horizons AS
SELECT project_portfolio_scenario_id,
project_operational_chars_scenario_id,
project_specified_capacity_scenario_id,
project_new_cost_scenario_id,
temporal_scenario_id,
operational_type,
hydro_operational_chars_scenario_id,
stage_id,
project,
horizon
-- Get all projects in the portfolio (with their opchars)
FROM project_portfolio_opchars
-- Add all the periods horizons for the matching balancing type
LEFT OUTER JOIN
periods_horizons
ON (project_portfolio_opchars.balancing_type_project
= periods_horizons.balancing_type_horizon)
-- Only select horizons from the actual operational periods
INNER JOIN
project_operational_periods
USING (temporal_scenario_id, project, period)
;

-- This view shows the possible operational timepoints for each project based
-- based on its operational periods (see project_operational_periods), and
-- the timepoints in the temporal subscenario (see inputs_temporal). It also
Expand Down
110 changes: 56 additions & 54 deletions gridpath/project/operations/operational_types/common_functions.py
Original file line number Diff line number Diff line change
Expand Up @@ -587,36 +587,40 @@ def get_prj_tmp_opr_inputs_from_db(
# use one of them, so filtering with OR is not 100% correct.

sql = f"""
SELECT project, timepoint, {data_column}
--limit to portfolio projects
FROM (
SELECT project from inputs_project_portfolios
SELECT project, prj_tbl.timepoint, {data_column}
FROM
(SELECT project, stage_id, timepoint
FROM project_operational_timepoints
WHERE project_portfolio_scenario_id = {subscenarios.PROJECT_PORTFOLIO_SCENARIO_ID}
) as portfolio_projects
--limit to optype and get var profile opchar id
JOIN (
AND project_operational_chars_scenario_id = {subscenarios.PROJECT_OPERATIONAL_CHARS_SCENARIO_ID}
AND temporal_scenario_id = {subscenarios.TEMPORAL_SCENARIO_ID}
AND (project_specified_capacity_scenario_id = {subscenarios.PROJECT_SPECIFIED_CAPACITY_SCENARIO_ID}
OR project_new_cost_scenario_id = {subscenarios.PROJECT_NEW_COST_SCENARIO_ID})
AND stage_id = {stage}
) as prj_tbl
INNER JOIN (
SELECT project, {subscenario_id_column}
FROM inputs_project_operational_chars
WHERE project_operational_chars_scenario_id = {subscenarios.PROJECT_OPERATIONAL_CHARS_SCENARIO_ID}
AND operational_type = '{op_type}'
) as op_type_projects_with_btype_and_opchar_id
) AS op_type_projects_with_btype_and_opchar_id
USING (project)
-- Get the data
LEFT OUTER JOIN
{table}
USING ({subscenario_id_column}, project, stage_id, timepoint)
JOIN (
SELECT project, {subscenario_id_column}, timepoint, {data_column}
FROM {table}
WHERE weather_iteration = {weather_iteration}
SELECT timepoint
FROM inputs_temporal
WHERE temporal_scenario_id = {subscenarios.TEMPORAL_SCENARIO_ID}
AND subproblem_id = {subproblem}
AND stage_id = {stage}
) as tmp_tbl
ON (
prj_tbl.timepoint = tmp_tbl.timepoint
)
USING (project, {subscenario_id_column})
-- Limit to the current temporal scenario ID
WHERE (timepoint) IN (
SELECT timepoint
FROM inputs_temporal
WHERE temporal_scenario_id = {subscenarios.TEMPORAL_SCENARIO_ID}
AND subproblem_id = {subproblem}
);
"""
WHERE weather_iteration = {weather_iteration}
;
"""

prj_tmp_data = c.execute(sql)

Expand Down Expand Up @@ -797,43 +801,41 @@ def get_hydro_inputs_from_database(

# TODO: figure out if this still works after hydro update in ra toolkit
sql = f"""
SELECT project, prj_tbl.horizon, average_power_fraction, min_power_fraction,
max_power_fraction
FROM (
SELECT project, balancing_type_project, horizon, average_power_fraction,
min_power_fraction, max_power_fraction
FROM inputs_project_hydro_operational_chars
-- Portfolio projects only
WHERE project in (
SELECT project
FROM inputs_project_portfolios
SELECT project, prj_tbl.horizon, average_power_fraction, min_power_fraction,
max_power_fraction
FROM
(SELECT project, stage_id, horizon
FROM project_operational_horizons
WHERE project_portfolio_scenario_id = {subscenarios.PROJECT_PORTFOLIO_SCENARIO_ID}
)
-- Get the right opchar
AND (project, hydro_operational_chars_scenario_id) in (
AND project_operational_chars_scenario_id = {subscenarios.PROJECT_OPERATIONAL_CHARS_SCENARIO_ID}
AND temporal_scenario_id = {subscenarios.TEMPORAL_SCENARIO_ID}
AND (project_specified_capacity_scenario_id = {subscenarios.PROJECT_SPECIFIED_CAPACITY_SCENARIO_ID}
OR project_new_cost_scenario_id = {subscenarios.PROJECT_NEW_COST_SCENARIO_ID})
AND stage_id = {stage}
) as prj_tbl
INNER JOIN (
SELECT project, hydro_operational_chars_scenario_id
FROM inputs_project_operational_chars
WHERE project_operational_chars_scenario_id
= {subscenarios.PROJECT_OPERATIONAL_CHARS_SCENARIO_ID}
WHERE project_operational_chars_scenario_id = {subscenarios.PROJECT_OPERATIONAL_CHARS_SCENARIO_ID}
AND operational_type = '{op_type}'
) AS hydro_char
USING (project)
LEFT OUTER JOIN
inputs_project_hydro_operational_chars
USING (hydro_operational_chars_scenario_id, project, stage_id, horizon)
JOIN (
SELECT DISTINCT balancing_type_horizon, horizon
FROM inputs_temporal_horizon_timepoints
WHERE temporal_scenario_id = {subscenarios.TEMPORAL_SCENARIO_ID}
AND subproblem_id = {subproblem}
AND stage_id = {stage}
) as hrz_tbl
ON (
balancing_type_project = balancing_type_horizon
AND prj_tbl.horizon = hrz_tbl.horizon
)
-- Get the relevant stage
AND stage_id = {stage}
-- Get the right iteration
AND hydro_iteration = {hydro_iteration}
) as prj_tbl
-- Limit to bt-horizons from this temporal scenario ID
JOIN (
SELECT DISTINCT balancing_type_horizon, horizon
FROM inputs_temporal_horizon_timepoints
WHERE temporal_scenario_id = {subscenarios.TEMPORAL_SCENARIO_ID}
AND subproblem_id = {subproblem}
AND stage_id = {stage}
) as hrz_tbl
ON (
balancing_type_project = balancing_type_horizon
AND prj_tbl.horizon = hrz_tbl.horizon
)
;
WHERE hydro_iteration = {hydro_iteration}
;
"""

hydro_chars = c.execute(sql)
Expand Down

0 comments on commit 598b742

Please sign in to comment.