From 67f36600d16351b68a4a4398acff33399810a529 Mon Sep 17 00:00:00 2001 From: Alex Zorkin Date: Fri, 17 Jan 2025 15:43:57 -0800 Subject: [PATCH 1/5] chore: removed simple migrations --- .../versions/2024-11-28-01-09_b4da565bb711.py | 46 ------------------- .../versions/2024-12-05-02-19_b69a33bbd135.py | 34 -------------- .../versions/2024-12-09-22-33_cd8698fe40e6.py | 34 -------------- .../versions/2024-12-17-11-23_f93546eaec61.py | 33 ------------- .../versions/2024-12-17-12-25_5b374dd97469.py | 36 --------------- .../versions/2025-01-05-18-43_ca7200152130.py | 37 --------------- .../versions/2025-01-16-20-01_98d79870df6b.py | 41 ----------------- 7 files changed, 261 deletions(-) delete mode 100644 backend/lcfs/db/migrations/versions/2024-11-28-01-09_b4da565bb711.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-12-05-02-19_b69a33bbd135.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-12-09-22-33_cd8698fe40e6.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-12-17-11-23_f93546eaec61.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-12-17-12-25_5b374dd97469.py delete mode 100644 backend/lcfs/db/migrations/versions/2025-01-05-18-43_ca7200152130.py delete mode 100644 backend/lcfs/db/migrations/versions/2025-01-16-20-01_98d79870df6b.py diff --git a/backend/lcfs/db/migrations/versions/2024-11-28-01-09_b4da565bb711.py b/backend/lcfs/db/migrations/versions/2024-11-28-01-09_b4da565bb711.py deleted file mode 100644 index 49a0936d1..000000000 --- a/backend/lcfs/db/migrations/versions/2024-11-28-01-09_b4da565bb711.py +++ /dev/null @@ -1,46 +0,0 @@ -"""Add UCI Columns to FS and Export - -Revision ID: b4da565bb711 -Revises: 0775a141d335 -Create Date: 2024-11-28 01:09:21.241693 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "b4da565bb711" -down_revision = "043c52082a3b" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.add_column( - "fuel_export", - sa.Column( - "uci", - sa.Numeric(precision=10, scale=2), - nullable=True, - comment="Additional Carbon Intensity", - ), - ) - op.add_column( - "fuel_supply", - sa.Column( - "uci", - sa.Numeric(precision=10, scale=2), - nullable=True, - comment="Additional Carbon Intensity", - ), - ) - # ### end Alembic commands ### - - -def downgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.drop_column("fuel_supply", "uci") - op.drop_column("fuel_export", "uci") - # ### end Alembic commands ### diff --git a/backend/lcfs/db/migrations/versions/2024-12-05-02-19_b69a33bbd135.py b/backend/lcfs/db/migrations/versions/2024-12-05-02-19_b69a33bbd135.py deleted file mode 100644 index 3f1477892..000000000 --- a/backend/lcfs/db/migrations/versions/2024-12-05-02-19_b69a33bbd135.py +++ /dev/null @@ -1,34 +0,0 @@ -"""Add notifications email to user_profile - -Revision ID: b69a33bbd135 -Revises: 8491890dd688 -Create Date: 2024-12-05 20:48:24.724112 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "b69a33bbd135" -down_revision = "8491890dd688" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # Add notifications_email column to user_profile table - op.add_column( - "user_profile", - sa.Column( - "notifications_email", - sa.String(length=255), - nullable=True, - comment="Email address used for notifications", - ), - ) - - -def downgrade() -> None: - # Remove notifications_email column from user_profile table - op.drop_column("user_profile", "notifications_email") diff --git a/backend/lcfs/db/migrations/versions/2024-12-09-22-33_cd8698fe40e6.py b/backend/lcfs/db/migrations/versions/2024-12-09-22-33_cd8698fe40e6.py deleted file mode 100644 index 8ec2b8223..000000000 --- a/backend/lcfs/db/migrations/versions/2024-12-09-22-33_cd8698fe40e6.py +++ /dev/null @@ -1,34 +0,0 @@ -"""Remove notifications email from user_profile - -Revision ID: cd8698fe40e6 -Revises: 26ab15f8ab18 -Create Date: 2024-12-09 22:33:29.554360 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "cd8698fe40e6" -down_revision = "9206124a098b" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # Remove notifications_email column from user_profile table - op.drop_column("user_profile", "notifications_email") - - -def downgrade() -> None: - # Add notifications_email column to user_profile table - op.add_column( - "user_profile", - sa.Column( - "notifications_email", - sa.String(length=255), - nullable=True, - comment="Email address used for notifications", - ), - ) diff --git a/backend/lcfs/db/migrations/versions/2024-12-17-11-23_f93546eaec61.py b/backend/lcfs/db/migrations/versions/2024-12-17-11-23_f93546eaec61.py deleted file mode 100644 index 4fbabc280..000000000 --- a/backend/lcfs/db/migrations/versions/2024-12-17-11-23_f93546eaec61.py +++ /dev/null @@ -1,33 +0,0 @@ -"""update notification message model - -Revision ID: f93546eaec61 -Revises: 5d729face5ab -Create Date: 2024-12-17 11:23:19.563138 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "f93546eaec61" -down_revision = "5d729face5ab" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.add_column("notification_message", sa.Column("type", sa.Text(), nullable=False)) - op.add_column( - "notification_message", - sa.Column("related_transaction_id", sa.Text(), nullable=False), - ) - # ### end Alembic commands ### - - -def downgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.drop_column("notification_message", "related_transaction_id") - op.drop_column("notification_message", "type") - # ### end Alembic commands ### diff --git a/backend/lcfs/db/migrations/versions/2024-12-17-12-25_5b374dd97469.py b/backend/lcfs/db/migrations/versions/2024-12-17-12-25_5b374dd97469.py deleted file mode 100644 index 3c7475040..000000000 --- a/backend/lcfs/db/migrations/versions/2024-12-17-12-25_5b374dd97469.py +++ /dev/null @@ -1,36 +0,0 @@ -"""Add legacy id to compliance reports - -Revision ID: 5b374dd97469 -Revises: f93546eaec61 -Create Date: 2024-17-13 12:25:32.076684 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "5b374dd97469" -down_revision = "f93546eaec61" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.add_column( - "compliance_report", - sa.Column( - "legacy_id", - sa.Integer(), - nullable=True, - comment="ID from TFRS if this is a transferred application, NULL otherwise", - ), - ) - # ### end Alembic commands ### - - -def downgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.drop_column("compliance_report", "legacy_id") - # ### end Alembic commands ### diff --git a/backend/lcfs/db/migrations/versions/2025-01-05-18-43_ca7200152130.py b/backend/lcfs/db/migrations/versions/2025-01-05-18-43_ca7200152130.py deleted file mode 100644 index c41500e64..000000000 --- a/backend/lcfs/db/migrations/versions/2025-01-05-18-43_ca7200152130.py +++ /dev/null @@ -1,37 +0,0 @@ -"""Add is_legacy to fuel_type - -Revision ID: ca7200152130 -Revises: bfa7bbb1eea3 -Create Date: 2025-01-05 18:43:43.638740 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "ca7200152130" -down_revision = "bfa7bbb1eea3" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.add_column( - "fuel_type", - sa.Column( - "is_legacy", - sa.Boolean(), - server_default=sa.text("FALSE"), - nullable=False, - comment="Indicates if the fuel type is legacy and should not be used for new reports", - ), - ) - # ### end Alembic commands ### - - -def downgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.drop_column("fuel_type", "is_legacy") - # ### end Alembic commands ### diff --git a/backend/lcfs/db/migrations/versions/2025-01-16-20-01_98d79870df6b.py b/backend/lcfs/db/migrations/versions/2025-01-16-20-01_98d79870df6b.py deleted file mode 100644 index 04f340feb..000000000 --- a/backend/lcfs/db/migrations/versions/2025-01-16-20-01_98d79870df6b.py +++ /dev/null @@ -1,41 +0,0 @@ -"""Add TFRS Summary Columns - -Revision ID: 98d79870df6b -Revises: 998929392c8b -Create Date: 2025-01-16 20:01:34.038941 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "98d79870df6b" -down_revision = "998929392c8b" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.add_column( - "compliance_report_summary", - sa.Column("credits_offset_a", sa.Integer(), nullable=True), - ) - op.add_column( - "compliance_report_summary", - sa.Column("credits_offset_b", sa.Integer(), nullable=True), - ) - op.add_column( - "compliance_report_summary", - sa.Column("credits_offset_c", sa.Integer(), nullable=True), - ) - # ### end Alembic commands ### - - -def downgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.drop_column("compliance_report_summary", "credits_offset_c") - op.drop_column("compliance_report_summary", "credits_offset_b") - op.drop_column("compliance_report_summary", "credits_offset_a") - # ### end Alembic commands ### From 9dcd83250e0bc5df029efa40e846350d1b51eb46 Mon Sep 17 00:00:00 2001 From: Alex Zorkin Date: Mon, 20 Jan 2025 14:56:09 -0800 Subject: [PATCH 2/5] feat: squashed all migrations into 3 step process, initial migration, views and triggers, data updates --- .../versions/2024-11-27-17-51_4038ff8d8c49.py | 797 -------- .../versions/2024-11-27-18-05_043c52082a3b.py | 67 - .../versions/2024-12-02-22-52_aeaa26f5cdd5.py | 38 - .../versions/2024-12-04-23-00_8491890dd688.py | 57 - .../versions/2024-12-05-02-20_d4104af84f2b.py | 90 - .../versions/2024-12-06-01-23_26ab15f8ab18.py | 282 --- .../versions/2024-12-06-09-59_9206124a098b.py | 37 - .../versions/2024-12-09-23-31_7ae38a8413ab.py | 95 - .../versions/2024-12-12-21-43_5d729face5ab.py | 35 - .../versions/2024-12-17-23-58_851e09cf8661.py | 62 - .../versions/2024-12-20-05-17_59873cafbcd8.py | 40 - .../versions/2024-12-21-00-18_5fbcb508c1be.py | 40 - .../versions/2024-12-22-23-46_ab04810d4d7c.py | 36 - .../versions/2024-12-24-07-40_d9cdd9fca0ce.py | 600 ------ .../versions/2024-12-30-13-54_9329e38396e1.py | 84 - .../versions/2025-01-03-23-31_e883ad1f0f60.py | 67 - .../versions/2025-01-04-13-24_bfa7bbb1eea3.py | 37 - .../versions/2025-01-06-19-01_94306eca5261.py | 125 -- .../versions/2025-01-06-22-09_fa98709e7952.py | 177 -- .../versions/2025-01-10-00-35_10863452ccd2.py | 68 - .../versions/2025-01-10-13-39_d25e7c47659e.py | 129 -- .../versions/2025-01-13-22-13_f78e53370ed2.py | 238 --- .../versions/2025-01-14-14-03_5163af6ba4a4.py | 70 - .../versions/2025-01-14-18-12_fe03799b4018.py | 61 - .../versions/2025-01-14-23-47_8119d12538df.py | 75 - .../versions/2025-01-15-22-48_5bc0ef48739a.py | 44 - .../versions/2025-01-16-19-35_998929392c8b.py | 51 - ...29.py => 2025-01-20-14-35_ed3b4d40b324.py} | 132 +- .../versions/2025-01-20-14-37_f217cd32474b.py | 1255 ++++++++++++ .../versions/2025-01-20-14-40_ec826b9226df.py | 1681 +++++++++++++++++ .../api/compliance_report/update_service.py | 4 +- frontend/src/assets/locales/en/reports.json | 2 +- 32 files changed, 3002 insertions(+), 3574 deletions(-) delete mode 100644 backend/lcfs/db/migrations/versions/2024-11-27-17-51_4038ff8d8c49.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-11-27-18-05_043c52082a3b.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-12-02-22-52_aeaa26f5cdd5.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-12-04-23-00_8491890dd688.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-12-05-02-20_d4104af84f2b.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-12-06-01-23_26ab15f8ab18.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-12-06-09-59_9206124a098b.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-12-09-23-31_7ae38a8413ab.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-12-12-21-43_5d729face5ab.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-12-17-23-58_851e09cf8661.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-12-20-05-17_59873cafbcd8.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-12-21-00-18_5fbcb508c1be.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-12-22-23-46_ab04810d4d7c.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-12-24-07-40_d9cdd9fca0ce.py delete mode 100644 backend/lcfs/db/migrations/versions/2024-12-30-13-54_9329e38396e1.py delete mode 100644 backend/lcfs/db/migrations/versions/2025-01-03-23-31_e883ad1f0f60.py delete mode 100644 backend/lcfs/db/migrations/versions/2025-01-04-13-24_bfa7bbb1eea3.py delete mode 100644 backend/lcfs/db/migrations/versions/2025-01-06-19-01_94306eca5261.py delete mode 100644 backend/lcfs/db/migrations/versions/2025-01-06-22-09_fa98709e7952.py delete mode 100644 backend/lcfs/db/migrations/versions/2025-01-10-00-35_10863452ccd2.py delete mode 100644 backend/lcfs/db/migrations/versions/2025-01-10-13-39_d25e7c47659e.py delete mode 100644 backend/lcfs/db/migrations/versions/2025-01-13-22-13_f78e53370ed2.py delete mode 100644 backend/lcfs/db/migrations/versions/2025-01-14-14-03_5163af6ba4a4.py delete mode 100644 backend/lcfs/db/migrations/versions/2025-01-14-18-12_fe03799b4018.py delete mode 100644 backend/lcfs/db/migrations/versions/2025-01-14-23-47_8119d12538df.py delete mode 100644 backend/lcfs/db/migrations/versions/2025-01-15-22-48_5bc0ef48739a.py delete mode 100644 backend/lcfs/db/migrations/versions/2025-01-16-19-35_998929392c8b.py rename backend/lcfs/db/migrations/versions/{2024-11-27-17-35_a2240b2b5629.py => 2025-01-20-14-35_ed3b4d40b324.py} (98%) create mode 100644 backend/lcfs/db/migrations/versions/2025-01-20-14-37_f217cd32474b.py create mode 100644 backend/lcfs/db/migrations/versions/2025-01-20-14-40_ec826b9226df.py diff --git a/backend/lcfs/db/migrations/versions/2024-11-27-17-51_4038ff8d8c49.py b/backend/lcfs/db/migrations/versions/2024-11-27-17-51_4038ff8d8c49.py deleted file mode 100644 index ce9205687..000000000 --- a/backend/lcfs/db/migrations/versions/2024-11-27-17-51_4038ff8d8c49.py +++ /dev/null @@ -1,797 +0,0 @@ -"""Consolidated Migration: Materialized Views, Audit Logging Functions, and Triggers - -Revision ID: 4038ff8d8c49 -Revises: a2240b2b5629 -Create Date: 2024-11-02 10:00:00.000000 - -""" - -from alembic import op -import sqlalchemy as sa -from sqlalchemy.dialects import postgresql - -# revision identifiers, used by Alembic. -revision = "4038ff8d8c49" -down_revision = "a2240b2b5629" -branch_labels = None -depends_on = None - - -def upgrade(): - # ---------------------------------------- - # Part 1: Drop Existing Triggers, Functions, and Views - # ---------------------------------------- - drop_existing_triggers_functions_views() - - # ---------------------------------------- - # Part 2: Create Audit Log Functions and Triggers - # ---------------------------------------- - create_audit_log_functions_and_triggers() - - # ---------------------------------------- - # Part 3: Create Materialized Views and Triggers - # ---------------------------------------- - create_materialized_views_and_triggers() - - # ---------------------------------------- - # Part 4: Create Update Organization Balance Function and Trigger - # ---------------------------------------- - create_update_organization_balance_function_and_trigger() - - -def downgrade(): - # ---------------------------------------- - # Part 4 Downgrade: Drop Update Organization Balance Function and Trigger - # ---------------------------------------- - op.execute( - """DROP TRIGGER IF EXISTS update_organization_balance_trigger ON "transaction";""" - ) - op.execute("""DROP FUNCTION IF EXISTS update_organization_balance();""") - - # ---------------------------------------- - # Part 3 Downgrade: Drop Materialized Views and Triggers - # ---------------------------------------- - drop_materialized_views_and_triggers() - - # ---------------------------------------- - # Part 2 Downgrade: Drop Audit Log Functions and Triggers - # ---------------------------------------- - drop_audit_log_functions_and_triggers() - - -# --------------------------- -# Helper Functions -# --------------------------- - - -def drop_existing_triggers_functions_views(): - # Drop existing triggers - op.execute( - """DROP TRIGGER IF EXISTS refresh_transaction_view_after_transfer ON transfer;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_transaction_view_after_initiative_agreement ON initiative_agreement;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_transaction_view_after_admin_adjustment ON admin_adjustment;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_transaction_view_after_transfer_history ON transfer_history;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_transaction_view_after_initiative_agreement_history ON initiative_agreement_history;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_transaction_view_after_admin_adjustment_history ON admin_adjustment_history;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_mv_transaction_count_after_transfer ON transfer;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_mv_transaction_count_after_initiative_agreement ON initiative_agreement;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_mv_transaction_count_after_admin_adjustment ON admin_adjustment;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_mv_director_review_transaction_count_after_transfer ON transfer;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_mv_director_review_transaction_count_after_compliance_report ON compliance_report;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_mv_director_review_transaction_count_after_initiative_agreement ON initiative_agreement;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_mv_director_review_transaction_count_after_admin_adjustment ON admin_adjustment;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_mv_org_compliance_report_count_after_compliance_report ON compliance_report;""" - ) - - # Drop existing functions - op.execute("""DROP FUNCTION IF EXISTS refresh_transaction_aggregate();""") - op.execute("""DROP FUNCTION IF EXISTS refresh_mv_transaction_count();""") - op.execute( - """DROP FUNCTION IF EXISTS refresh_mv_director_review_transaction_count();""" - ) - op.execute("""DROP FUNCTION IF EXISTS refresh_mv_org_compliance_report_count();""") - - # Drop existing materialized views and views - op.execute("""DROP MATERIALIZED VIEW IF EXISTS mv_transaction_aggregate;""") - op.execute("""DROP VIEW IF EXISTS transaction_status_view;""") - op.execute("""DROP MATERIALIZED VIEW IF EXISTS mv_transaction_count;""") - op.execute( - """DROP MATERIALIZED VIEW IF EXISTS mv_director_review_transaction_count;""" - ) - op.execute("""DROP MATERIALIZED VIEW IF EXISTS mv_org_compliance_report_count;""") - - -def create_audit_log_functions_and_triggers(): - # Step 1: Create JSONB_DIFF FUNCTION - op.execute( - """ - CREATE OR REPLACE FUNCTION jsonb_diff( - old_row JSONB, - new_row JSONB - ) RETURNS JSONB AS $$ - BEGIN - RETURN ( - SELECT jsonb_object_agg(key, value) - FROM ( - SELECT key, value - FROM jsonb_each(new_row) - EXCEPT - SELECT key, value - FROM jsonb_each(old_row) - ) diff - ); - END; - $$ LANGUAGE plpgsql; - """ - ) - - # Step 2: Add JSON delta function - op.execute( - """ - CREATE OR REPLACE FUNCTION generate_json_delta( - old_row JSONB, - new_row JSONB - ) RETURNS JSONB AS $$ - BEGIN - RETURN jsonb_diff(old_row, new_row); - END; - $$ LANGUAGE plpgsql; - """ - ) - - # Step 3: Add audit trigger function - op.execute( - """ - CREATE OR REPLACE FUNCTION audit_trigger_func() - RETURNS TRIGGER AS $$ - DECLARE - v_operation TEXT; - v_table_name TEXT := TG_TABLE_NAME; - v_row_id JSONB; - v_old_values JSONB; - v_new_values JSONB; - v_delta JSONB; - v_pk_col TEXT; - BEGIN - SELECT c.column_name INTO v_pk_col - FROM information_schema.table_constraints tc - JOIN information_schema.constraint_column_usage AS ccu USING (constraint_schema, constraint_name) - JOIN information_schema.columns AS c ON c.table_schema = tc.constraint_schema - AND tc.table_name = c.table_name AND ccu.column_name = c.column_name - WHERE tc.constraint_type = 'PRIMARY KEY' AND tc.table_name = TG_TABLE_NAME - LIMIT 1; - - IF (TG_OP = 'INSERT') THEN - v_operation := 'INSERT'; - v_new_values := to_jsonb(NEW); - EXECUTE format('SELECT ($1).%I', v_pk_col) INTO v_row_id USING NEW; - ELSIF (TG_OP = 'UPDATE') THEN - v_operation := 'UPDATE'; - v_old_values := to_jsonb(OLD); - v_new_values := to_jsonb(NEW); - v_delta := generate_json_delta(v_old_values, v_new_values); - EXECUTE format('SELECT ($1).%I', v_pk_col) INTO v_row_id USING NEW; - ELSIF (TG_OP = 'DELETE') THEN - v_operation := 'DELETE'; - v_old_values := to_jsonb(OLD); - EXECUTE format('SELECT ($1).%I', v_pk_col) INTO v_row_id USING OLD; - END IF; - - INSERT INTO audit_log ( - create_user, - update_user, - table_name, - operation, - row_id, - delta, - old_values, - new_values - ) - VALUES ( - current_setting('app.username', true), - current_setting('app.username', true), - v_table_name, - v_operation, - v_row_id, - v_delta, - v_old_values, - v_new_values - ); - - RETURN NULL; - END; - $$ LANGUAGE plpgsql; - """ - ) - - # Step 4: Add audit triggers to relevant tables - op.execute( - """ - DO $$ - DECLARE - r RECORD; - BEGIN - FOR r IN SELECT tablename - FROM pg_tables - WHERE schemaname = 'public' - AND tablename IN ('transaction', 'compliance_report', 'compliance_report_history', - 'compliance_report_status', 'compliance_report_summary', 'compliance_period', - 'initiative_agreement', 'initiative_agreement_status', 'initiative_agreement_history', - 'allocation_agreement', 'allocation_transaction_type', 'custom_fuel_type', 'fuel_code', - 'fuel_code_prefix', 'fuel_code_status', 'fuel_category', 'fuel_instance', 'fuel_type', - 'fuel_export', 'organization', 'organization_address', 'organization_attorney_address', - 'organization_status', 'organization_type', 'transfer', 'transfer_category', 'transfer_history', - 'transfer_status', 'internal_comment', 'user_profile', 'user_role', 'role', 'notification_message', - 'notification_type', 'admin_adjustment', 'admin_adjustment_status', 'admin_adjustment_history', - 'provision_of_the_act', 'supplemental_report', 'final_supply_equipment', 'notional_transfer', - 'fuel_supply', 'additional_carbon_intensity', 'document', 'end_use_type', 'energy_density', - 'energy_effectiveness_ratio', 'transport_mode', 'final_supply_equipment', 'level_of_equipment', - 'user_login_history', 'unit_of_measure', 'target_carbon_intensity') - LOOP - EXECUTE format(' - CREATE TRIGGER audit_%I_insert_update_delete - AFTER INSERT OR UPDATE OR DELETE ON %I - FOR EACH ROW EXECUTE FUNCTION audit_trigger_func();', - r.tablename, r.tablename); - END LOOP; - END $$; - """ - ) - - -def create_materialized_views_and_triggers(): - # Create mv_transaction_aggregate materialized view - op.execute( - """ - CREATE MATERIALIZED VIEW mv_transaction_aggregate AS - SELECT - t.transfer_id AS transaction_id, - 'Transfer' AS transaction_type, - org_from.organization_id AS from_organization_id, - org_from.name AS from_organization, - org_to.organization_id AS to_organization_id, - org_to.name AS to_organization, - t.quantity, - t.price_per_unit, - ts.status::text AS status, - NULL AS compliance_period, - t.from_org_comment AS comment, - tc.category, - ( - SELECT th.create_date - FROM transfer_history th - WHERE th.transfer_id = t.transfer_id AND th.transfer_status_id = 6 - ) AS recorded_date, - NULL AS approved_date, - t.transaction_effective_date, - t.update_date, - t.create_date - FROM transfer t - JOIN organization org_from ON t.from_organization_id = org_from.organization_id - JOIN organization org_to ON t.to_organization_id = org_to.organization_id - JOIN transfer_status ts ON t.current_status_id = ts.transfer_status_id - LEFT JOIN transfer_category tc ON t.transfer_category_id = tc.transfer_category_id - UNION ALL - SELECT - ia.initiative_agreement_id AS transaction_id, - 'InitiativeAgreement' AS transaction_type, - NULL AS from_organization_id, - NULL AS from_organization, - org.organization_id AS to_organization_id, - org.name AS to_organization, - ia.compliance_units AS quantity, - NULL AS price_per_unit, - ias.status::text AS status, - NULL AS compliance_period, - ia.gov_comment AS comment, - NULL AS category, - NULL AS recorded_date, - ( - SELECT iah.create_date - FROM initiative_agreement_history iah - WHERE iah.initiative_agreement_id = ia.initiative_agreement_id AND iah.initiative_agreement_status_id = 3 - ) AS approved_date, - ia.transaction_effective_date, - ia.update_date, - ia.create_date - FROM initiative_agreement ia - JOIN organization org ON ia.to_organization_id = org.organization_id - JOIN initiative_agreement_status ias ON ia.current_status_id = ias.initiative_agreement_status_id - UNION ALL - SELECT - aa.admin_adjustment_id AS transaction_id, - 'AdminAdjustment' AS transaction_type, - NULL AS from_organization_id, - NULL AS from_organization, - org.organization_id AS to_organization_id, - org.name AS to_organization, - aa.compliance_units AS quantity, - NULL AS price_per_unit, - aas.status::text AS status, - NULL AS compliance_period, - aa.gov_comment AS comment, - NULL AS category, - NULL AS recorded_date, - ( - SELECT aah.create_date - FROM admin_adjustment_history aah - WHERE aah.admin_adjustment_id = aa.admin_adjustment_id AND aah.admin_adjustment_status_id = 3 - ) AS approved_date, - aa.transaction_effective_date, - aa.update_date, - aa.create_date - FROM admin_adjustment aa - JOIN organization org ON aa.to_organization_id = org.organization_id - JOIN admin_adjustment_status aas ON aa.current_status_id = aas.admin_adjustment_status_id; - """ - ) - - # Create unique index on mv_transaction_aggregate - op.execute( - """ - CREATE UNIQUE INDEX mv_transaction_aggregate_unique_idx ON mv_transaction_aggregate (transaction_id, transaction_type); - """ - ) - - # Create transaction_status_view - op.execute( - """ - CREATE OR REPLACE VIEW transaction_status_view AS - SELECT - status::text, - create_date, - update_date - FROM initiative_agreement_status - UNION - SELECT - status::text, - create_date, - update_date - FROM admin_adjustment_status - UNION - SELECT - status::text, - create_date, - update_date - FROM transfer_status; - """ - ) - - # Create refresh_transaction_aggregate function - op.execute( - """ - CREATE OR REPLACE FUNCTION refresh_transaction_aggregate() - RETURNS TRIGGER AS $$ - BEGIN - REFRESH MATERIALIZED VIEW CONCURRENTLY mv_transaction_aggregate; - RETURN NULL; - END; - $$ LANGUAGE plpgsql; - """ - ) - - # Create triggers to refresh mv_transaction_aggregate - op.execute( - """ - CREATE TRIGGER refresh_transaction_view_after_transfer - AFTER INSERT OR UPDATE OR DELETE ON transfer - FOR EACH STATEMENT EXECUTE FUNCTION refresh_transaction_aggregate(); - """ - ) - op.execute( - """ - CREATE TRIGGER refresh_transaction_view_after_initiative_agreement - AFTER INSERT OR UPDATE OR DELETE ON initiative_agreement - FOR EACH STATEMENT EXECUTE FUNCTION refresh_transaction_aggregate(); - """ - ) - op.execute( - """ - CREATE TRIGGER refresh_transaction_view_after_admin_adjustment - AFTER INSERT OR UPDATE OR DELETE ON admin_adjustment - FOR EACH STATEMENT EXECUTE FUNCTION refresh_transaction_aggregate(); - """ - ) - op.execute( - """ - CREATE TRIGGER refresh_transaction_view_after_transfer_history - AFTER INSERT OR UPDATE OR DELETE ON transfer_history - FOR EACH STATEMENT EXECUTE FUNCTION refresh_transaction_aggregate(); - """ - ) - op.execute( - """ - CREATE TRIGGER refresh_transaction_view_after_initiative_agreement_history - AFTER INSERT OR UPDATE OR DELETE ON initiative_agreement_history - FOR EACH STATEMENT EXECUTE FUNCTION refresh_transaction_aggregate(); - """ - ) - op.execute( - """ - CREATE TRIGGER refresh_transaction_view_after_admin_adjustment_history - AFTER INSERT OR UPDATE OR DELETE ON admin_adjustment_history - FOR EACH STATEMENT EXECUTE FUNCTION refresh_transaction_aggregate(); - """ - ) - - # Create mv_transaction_count materialized view - op.execute( - """ - CREATE MATERIALIZED VIEW mv_transaction_count AS - SELECT - 'transfers' AS transaction_type, - COUNT(*) FILTER ( - WHERE - t.current_status_id IN (4, 5) -- Submitted, Recommended - ) AS count_in_progress - FROM transfer t - UNION ALL - SELECT - 'initiative_agreements' AS transaction_type, - COUNT(*) FILTER ( - WHERE - ia.current_status_id IN (1, 2) -- Draft, Recommended - ) AS count_in_progress - FROM initiative_agreement ia - UNION ALL - SELECT - 'admin_adjustments' AS transaction_type, - COUNT(*) FILTER ( - WHERE - aa.current_status_id IN (1, 2) -- Draft, Recommended - ) AS count_in_progress - FROM admin_adjustment aa; - """ - ) - - # Create unique index on mv_transaction_count - op.execute( - """ - CREATE UNIQUE INDEX mv_transaction_count_unique_idx ON mv_transaction_count (transaction_type); - """ - ) - - # Create refresh_mv_transaction_count function - op.execute( - """ - CREATE OR REPLACE FUNCTION refresh_mv_transaction_count() - RETURNS TRIGGER AS $$ - BEGIN - REFRESH MATERIALIZED VIEW CONCURRENTLY mv_transaction_count; - RETURN NULL; - END; - $$ LANGUAGE plpgsql; - """ - ) - - # Create triggers to refresh mv_transaction_count - op.execute( - """ - CREATE TRIGGER refresh_mv_transaction_count_after_transfer - AFTER INSERT OR UPDATE OR DELETE ON transfer - FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_transaction_count(); - """ - ) - op.execute( - """ - CREATE TRIGGER refresh_mv_transaction_count_after_initiative_agreement - AFTER INSERT OR UPDATE OR DELETE ON initiative_agreement - FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_transaction_count(); - """ - ) - op.execute( - """ - CREATE TRIGGER refresh_mv_transaction_count_after_admin_adjustment - AFTER INSERT OR UPDATE OR DELETE ON admin_adjustment - FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_transaction_count(); - """ - ) - - # Create mv_director_review_transaction_count materialized view - op.execute( - """ - CREATE MATERIALIZED VIEW mv_director_review_transaction_count AS - SELECT - 'transfers' AS transaction_type, - COUNT(*) FILTER ( - WHERE - t.current_status_id = 5 -- Recommended - ) AS count_for_review - FROM transfer t - UNION ALL - SELECT - 'compliance_reports' AS transaction_type, - COUNT(*) FILTER ( - WHERE - cr.current_status_id = 4 -- Recommended by Manager - ) AS count_for_review - FROM compliance_report cr - UNION ALL - SELECT - 'initiative_agreements' AS transaction_type, - COUNT(*) FILTER ( - WHERE - ia.current_status_id = 2 -- Recommended - ) AS count_for_review - FROM initiative_agreement ia - UNION ALL - SELECT - 'admin_adjustments' AS transaction_type, - COUNT(*) FILTER ( - WHERE - aa.current_status_id = 2 -- Recommended - ) AS count_for_review - FROM admin_adjustment aa; - """ - ) - - # Create unique index on mv_director_review_transaction_count - op.execute( - """ - CREATE UNIQUE INDEX mv_director_review_transaction_count_unique_idx ON mv_director_review_transaction_count (transaction_type); - """ - ) - - # Create refresh_mv_director_review_transaction_count function - op.execute( - """ - CREATE OR REPLACE FUNCTION refresh_mv_director_review_transaction_count() - RETURNS TRIGGER AS $$ - BEGIN - REFRESH MATERIALIZED VIEW CONCURRENTLY mv_director_review_transaction_count; - RETURN NULL; - END; - $$ LANGUAGE plpgsql; - """ - ) - - # Create triggers to refresh mv_director_review_transaction_count - op.execute( - """ - CREATE TRIGGER refresh_mv_director_review_transaction_count_after_transfer - AFTER INSERT OR UPDATE OR DELETE ON transfer - FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_director_review_transaction_count(); - """ - ) - op.execute( - """ - CREATE TRIGGER refresh_mv_director_review_transaction_count_after_compliance_report - AFTER INSERT OR UPDATE OR DELETE ON compliance_report - FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_director_review_transaction_count(); - """ - ) - op.execute( - """ - CREATE TRIGGER refresh_mv_director_review_transaction_count_after_initiative_agreement - AFTER INSERT OR UPDATE OR DELETE ON initiative_agreement - FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_director_review_transaction_count(); - """ - ) - op.execute( - """ - CREATE TRIGGER refresh_mv_director_review_transaction_count_after_admin_adjustment - AFTER INSERT OR UPDATE OR DELETE ON admin_adjustment - FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_director_review_transaction_count(); - """ - ) - - # Create mv_org_compliance_report_count materialized view - op.execute( - """ - CREATE MATERIALIZED VIEW mv_org_compliance_report_count AS - SELECT - organization_id, - COUNT(*) FILTER (WHERE current_status_id = 1) AS count_in_progress, - COUNT(*) FILTER (WHERE current_status_id = 2) AS count_awaiting_gov_review - FROM - compliance_report - GROUP BY - organization_id; - """ - ) - - # Create unique index on mv_org_compliance_report_count - op.execute( - """ - CREATE UNIQUE INDEX mv_org_compliance_report_count_org_id_idx ON mv_org_compliance_report_count (organization_id); - """ - ) - - # Create refresh_mv_org_compliance_report_count function - op.execute( - """ - CREATE OR REPLACE FUNCTION refresh_mv_org_compliance_report_count() - RETURNS TRIGGER AS $$ - BEGIN - REFRESH MATERIALIZED VIEW CONCURRENTLY mv_org_compliance_report_count; - RETURN NULL; - END; - $$ LANGUAGE plpgsql; - """ - ) - - # Create trigger to refresh mv_org_compliance_report_count - op.execute( - """ - CREATE TRIGGER refresh_mv_org_compliance_report_count_after_compliance_report - AFTER INSERT OR UPDATE OR DELETE ON compliance_report - FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_org_compliance_report_count(); - """ - ) - - -def create_update_organization_balance_function_and_trigger(): - # Create update_organization_balance function - op.execute( - """ - CREATE OR REPLACE FUNCTION update_organization_balance() - RETURNS TRIGGER AS $$ - DECLARE - new_total_balance BIGINT; - new_reserved_balance BIGINT; - org_id INT := COALESCE(NEW.organization_id, OLD.organization_id); - BEGIN - -- Calculate new total balance for specific organization_id - SELECT COALESCE(SUM(compliance_units), 0) INTO new_total_balance - FROM "transaction" - WHERE organization_id = org_id - AND transaction_action = 'Adjustment'; - - -- Calculate new reserved balance for specific organization_id - SELECT COALESCE(SUM(compliance_units), 0) INTO new_reserved_balance - FROM "transaction" - WHERE organization_id = org_id - AND transaction_action = 'Reserved'; - - -- Update the organization with the new balances - UPDATE organization - SET total_balance = new_total_balance, - reserved_balance = new_reserved_balance - WHERE organization_id = org_id; - - RETURN NEW; - END; - $$ LANGUAGE plpgsql; - """ - ) - - # Create trigger to update organization balance - op.execute( - """ - CREATE TRIGGER update_organization_balance_trigger - AFTER INSERT OR UPDATE OR DELETE ON "transaction" - FOR EACH ROW EXECUTE FUNCTION update_organization_balance(); - """ - ) - - -def drop_materialized_views_and_triggers(): - # Drop triggers related to materialized views - op.execute( - """DROP TRIGGER IF EXISTS refresh_transaction_view_after_transfer ON transfer;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_transaction_view_after_initiative_agreement ON initiative_agreement;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_transaction_view_after_admin_adjustment ON admin_adjustment;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_transaction_view_after_transfer_history ON transfer_history;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_transaction_view_after_initiative_agreement_history ON initiative_agreement_history;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_transaction_view_after_admin_adjustment_history ON admin_adjustment_history;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_mv_transaction_count_after_transfer ON transfer;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_mv_transaction_count_after_initiative_agreement ON initiative_agreement;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_mv_transaction_count_after_admin_adjustment ON admin_adjustment;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_mv_director_review_transaction_count_after_transfer ON transfer;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_mv_director_review_transaction_count_after_compliance_report ON compliance_report;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_mv_director_review_transaction_count_after_initiative_agreement ON initiative_agreement;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_mv_director_review_transaction_count_after_admin_adjustment ON admin_adjustment;""" - ) - op.execute( - """DROP TRIGGER IF EXISTS refresh_mv_org_compliance_report_count_after_compliance_report ON compliance_report;""" - ) - - # Drop functions related to materialized views - op.execute("""DROP FUNCTION IF EXISTS refresh_transaction_aggregate();""") - op.execute("""DROP FUNCTION IF EXISTS refresh_mv_transaction_count();""") - op.execute( - """DROP FUNCTION IF EXISTS refresh_mv_director_review_transaction_count();""" - ) - op.execute("""DROP FUNCTION IF EXISTS refresh_mv_org_compliance_report_count();""") - - # Drop materialized views and views - op.execute("""DROP MATERIALIZED VIEW IF EXISTS mv_transaction_aggregate;""") - op.execute("""DROP VIEW IF EXISTS transaction_status_view;""") - op.execute("""DROP MATERIALIZED VIEW IF EXISTS mv_transaction_count;""") - op.execute( - """DROP MATERIALIZED VIEW IF EXISTS mv_director_review_transaction_count;""" - ) - op.execute("""DROP MATERIALIZED VIEW IF EXISTS mv_org_compliance_report_count;""") - - -def drop_audit_log_functions_and_triggers(): - # Remove audit triggers - op.execute( - """ - DO $$ - DECLARE - r RECORD; - BEGIN - FOR r IN SELECT tablename - FROM pg_tables - WHERE schemaname = 'public' - AND tablename IN ('transaction', 'compliance_report', 'compliance_report_history', - 'compliance_report_status', 'compliance_report_summary', 'compliance_period', - 'initiative_agreement', 'initiative_agreement_status', 'initiative_agreement_history', - 'allocation_agreement', 'allocation_transaction_type', 'custom_fuel_type', 'fuel_code', - 'fuel_code_prefix', 'fuel_code_status', 'fuel_category', 'fuel_instance', 'fuel_type', - 'fuel_export', 'organization', 'organization_address', 'organization_attorney_address', - 'organization_status', 'organization_type', 'transfer', 'transfer_category', 'transfer_history', - 'transfer_status', 'internal_comment', 'user_profile', 'user_role', 'role', 'notification_message', - 'notification_type', 'admin_adjustment', 'admin_adjustment_status', 'admin_adjustment_history', - 'provision_of_the_act', 'supplemental_report', 'final_supply_equipment', 'notional_transfer', - 'fuel_supply', 'additional_carbon_intensity', 'document', 'end_use_type', 'energy_density', - 'energy_effectiveness_ratio', 'transport_mode', 'final_supply_equipment', 'level_of_equipment', - 'user_login_history', 'unit_of_measure', 'target_carbon_intensity') - LOOP - EXECUTE format(' - DROP TRIGGER IF EXISTS audit_%I_insert_update_delete ON %I;', - r.tablename, r.tablename); - END LOOP; - END $$; - """ - ) - - # Drop audit trigger function - op.execute("DROP FUNCTION IF EXISTS audit_trigger_func;") - - # Drop generate_json_delta function - op.execute("DROP FUNCTION IF EXISTS generate_json_delta;") - - # Drop JSONB_DIFF FUNCTION - op.execute("DROP FUNCTION IF EXISTS jsonb_diff;") diff --git a/backend/lcfs/db/migrations/versions/2024-11-27-18-05_043c52082a3b.py b/backend/lcfs/db/migrations/versions/2024-11-27-18-05_043c52082a3b.py deleted file mode 100644 index c71a8aae3..000000000 --- a/backend/lcfs/db/migrations/versions/2024-11-27-18-05_043c52082a3b.py +++ /dev/null @@ -1,67 +0,0 @@ -"""Add options to the Feedstock Transport mode fuel code - -Revision ID: 043c52082a3b -Revises: None -Create Date: 2024-11-27 18:05:12.015327 - -""" - -from datetime import datetime -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "043c52082a3b" -down_revision = "4038ff8d8c49" -branch_labels = None -depends_on = None - - -def upgrade(): - current_time = datetime.now() - - # Update Marine to Marine-domestic - op.execute( - """ - UPDATE transport_mode - SET transport_mode = 'Marine-domestic', - update_date = '{}', - update_user = 'no-user' - WHERE transport_mode = 'Marine' - """.format( - current_time - ) - ) - - # Insert Marine-international - op.execute( - """ - INSERT INTO transport_mode (transport_mode, create_date, update_date, create_user, update_user) - VALUES ('Marine-international', '{}', '{}', 'no_user', 'no_user') - """.format( - current_time, current_time - ) - ) - - -def downgrade(): - # Revert Marine-domestic back to Marine - op.execute( - """ - UPDATE transport_mode - SET transport_mode = 'Marine', - update_date = '{}', - update_user = 'no_user' - WHERE transport_mode = 'Marine-domestic' - """.format( - datetime.utcnow() - ) - ) - - # Remove Marine-international - op.execute( - """ - DELETE FROM transport_mode - WHERE transport_mode = 'Marine-international' - """ - ) diff --git a/backend/lcfs/db/migrations/versions/2024-12-02-22-52_aeaa26f5cdd5.py b/backend/lcfs/db/migrations/versions/2024-12-02-22-52_aeaa26f5cdd5.py deleted file mode 100644 index 80ab64168..000000000 --- a/backend/lcfs/db/migrations/versions/2024-12-02-22-52_aeaa26f5cdd5.py +++ /dev/null @@ -1,38 +0,0 @@ -"""Replace 'Other' with detailed description in 'level_of_equipment' table - -Revision ID: aeaa26f5cdd5 -Revises: b4da565bb711 -Create Date: 2024-12-02 22:52:12.302543 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "aeaa26f5cdd5" -down_revision = "b4da565bb711" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # Update the 'name' column in the 'level_of_equipment' table - op.execute( - """ - UPDATE level_of_equipment - SET name = 'Other - Additional information provided in notes field' - WHERE name = 'Other' - """ - ) - - -def downgrade() -> None: - # Revert the 'name' column update in the 'level_of_equipment' table - op.execute( - """ - UPDATE level_of_equipment - SET name = 'Other' - WHERE name = 'Other - Additional information provided in notes field' - """ - ) diff --git a/backend/lcfs/db/migrations/versions/2024-12-04-23-00_8491890dd688.py b/backend/lcfs/db/migrations/versions/2024-12-04-23-00_8491890dd688.py deleted file mode 100644 index d12c0a57a..000000000 --- a/backend/lcfs/db/migrations/versions/2024-12-04-23-00_8491890dd688.py +++ /dev/null @@ -1,57 +0,0 @@ -"""Data Fixes - -Revision ID: 8491890dd688 -Revises: aeaa26f5cdd5 -Create Date: 2024-12-04 23:00:10.708533 - -""" - -from alembic import op -from sqlalchemy import update - -from lcfs.db.models import FuelType, AllocationTransactionType -from lcfs.db.models.fuel.FuelType import QuantityUnitsEnum - -# revision identifiers, used by Alembic. -revision = "8491890dd688" -down_revision = "aeaa26f5cdd5" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.execute( - update(FuelType) - .where(FuelType.fuel_type_id == 6) - .values(units=QuantityUnitsEnum.Kilograms) - ) - - op.execute( - update(FuelType).where(FuelType.fuel_type_id == 20).values(fossil_derived=False) - ) - - # Update 'type' and 'description' in allocation_transaction_type where allocation_transaction_type_id = 2 - op.execute( - update(AllocationTransactionType) - .where(AllocationTransactionType.allocation_transaction_type_id == 2) - .values( - type="Allocated to", - description="Fuel allocated to another supplier under an allocation agreement", - ) - ) - - # Update 'type' and 'description' in allocation_transaction_type where allocation_transaction_type_id = 1 - op.execute( - update(AllocationTransactionType) - .where(AllocationTransactionType.allocation_transaction_type_id == 1) - .values( - type="Allocated from", - description="Fuel allocated from another supplier under an allocation agreement", - ) - ) - # ### end Alembic commands ### - - -def downgrade() -> None: - pass diff --git a/backend/lcfs/db/migrations/versions/2024-12-05-02-20_d4104af84f2b.py b/backend/lcfs/db/migrations/versions/2024-12-05-02-20_d4104af84f2b.py deleted file mode 100644 index 2ccc2ba9e..000000000 --- a/backend/lcfs/db/migrations/versions/2024-12-05-02-20_d4104af84f2b.py +++ /dev/null @@ -1,90 +0,0 @@ -"""Update Notification Types and remove data - -Revision ID: d4104af84f2b -Revises: b69a33bbd135 -Create Date: 2024-12-05 02:20:33.898150 - -""" - -import sqlalchemy as sa -from alembic import op -from sqlalchemy.dialects.postgresql import ENUM - -# Revision identifiers, used by Alembic. -revision = "d4104af84f2b" -down_revision = "b69a33bbd135" -branch_labels = None -depends_on = None - - -def upgrade(): - # Remove the notification types added in the previous migration - op.execute("DELETE FROM notification_type;") - - # Alter the `name` column in `notification_type` to be a VARCHAR - with op.batch_alter_table("notification_type") as batch_op: - batch_op.alter_column( - "name", - existing_type=ENUM( - "TRANSFER_PARTNER_UPDATE", - "TRANSFER_DIRECTOR_REVIEW", - "INITIATIVE_APPROVED", - "INITIATIVE_DA_REQUEST", - "SUPPLEMENTAL_REQUESTED", - "DIRECTOR_ASSESSMENT", - name="notification_type_enum_v2", - ), - type_=sa.String(length=255), - existing_nullable=False, - ) - - # Drop the old enum types - op.execute("DROP TYPE IF EXISTS notification_type_enum_v2;") - - -def downgrade(): - # First, remove all existing data that might not match the enum - op.execute("DELETE FROM notification_type;") - - # Re-create the old enum type - notification_type_enum_v2 = ENUM( - "TRANSFER_PARTNER_UPDATE", - "TRANSFER_DIRECTOR_REVIEW", - "INITIATIVE_APPROVED", - "INITIATIVE_DA_REQUEST", - "SUPPLEMENTAL_REQUESTED", - "DIRECTOR_ASSESSMENT", - name="notification_type_enum_v2", - ) - notification_type_enum_v2.create(op.get_bind(), checkfirst=False) - - # Alter the `name` column back to the old enum - with op.batch_alter_table("notification_type") as batch_op: - batch_op.alter_column( - "name", - type_=notification_type_enum_v2, - existing_type=sa.String(length=255), - postgresql_using="name::notification_type_enum_v2", - existing_nullable=False, - ) - - # Re-insert the previous notification types - op.execute( - """ - INSERT INTO notification_type (notification_type_id, name, description, email_content, create_user, update_user) - VALUES - (1, 'TRANSFER_PARTNER_UPDATE', 'Transfer partner update notification', 'Email content for transfer partner update', 'system', 'system'), - (2, 'TRANSFER_DIRECTOR_REVIEW', 'Director review notification', 'Email content for director review', 'system', 'system'), - (3, 'INITIATIVE_APPROVED', 'Initiative approved notification', 'Email content for initiative approval', 'system', 'system'), - (4, 'INITIATIVE_DA_REQUEST', 'DA request notification', 'Email content for DA request', 'system', 'system'), - (5, 'SUPPLEMENTAL_REQUESTED', 'Supplemental requested notification', 'Email content for supplemental request', 'system', 'system'), - (6, 'DIRECTOR_ASSESSMENT', 'Director assessment notification', 'Email content for director assessment', 'system', 'system'); - """ - ) - - # Reset the sequence for the id column with correct sequence name - op.execute( - """ - SELECT setval('notification_type_notification_type_id_seq', (SELECT MAX(notification_type_id) FROM notification_type)); - """ - ) diff --git a/backend/lcfs/db/migrations/versions/2024-12-06-01-23_26ab15f8ab18.py b/backend/lcfs/db/migrations/versions/2024-12-06-01-23_26ab15f8ab18.py deleted file mode 100644 index 5a7c88e10..000000000 --- a/backend/lcfs/db/migrations/versions/2024-12-06-01-23_26ab15f8ab18.py +++ /dev/null @@ -1,282 +0,0 @@ -"""update end use table with new values - -Revision ID: 26ab15f8ab18 -Revises: d4104af84f2b -Create Date: 2024-12-06 01:23:21.598991 - -""" - -import sqlalchemy as sa -from alembic import op -from datetime import datetime - -# revision identifiers, used by Alembic. -revision = "26ab15f8ab18" -down_revision = "d4104af84f2b" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - current_time = datetime.now() - - # Update existing end use types 14-21 to new values - updates = [ - (14, 'Aircraft'), - (15, 'Compression-ignition engine- Marine, general'), - (16, 'Compression-ignition engine- Marine, operated within 51 to 75% of load range'), - (17, 'Compression-ignition engine- Marine, operated within 76 to 100% of load range'), - (18, 'Compression-ignition engine- Marine, with methane slip reduction kit- General'), - (19, 'Compression-ignition engine- Marine, with methane slip reduction kit- Operated within 51 to 75% of load range'), - (20, 'Compression-ignition engine- Marine, with methane slip reduction kit- Operated within 76 to 100% of load range'), - (21, 'Compression-ignition engine- Marine, unknown whether kit is installed or average operating load range') - ] - - for end_use_id, type_name in updates: - op.execute( - """ - UPDATE end_use_type - SET type = '{}', - sub_type = NULL, - intended_use = true, - update_date = '{}', - update_user = 'no_user' - WHERE end_use_type_id = {} - """.format(type_name, current_time, end_use_id) - ) - - # Update existing UCI values for IDs 1-9 - uci_updates = [ - (1, 7, 5, None, 0), # Remove end_use_type_id 14 - (2, None, 5, None, 0), # Remove fuel_type_id and end_use_type_id - (3, 7, 5, 15, 27.3), # Update with new end_use_type_id and intensity - (4, 7, 5, 16, 17.8), - (5, 7, 5, 17, 12.2), - (6, 7, 5, 18, 10.6), - (7, 7, 5, 19, 8.4), - (8, 7, 5, 20, 8.0), - (9, 7, 5, 21, 27.3) - ] - - for uci_id, fuel_type_id, uom_id, end_use_type_id, intensity in uci_updates: - if fuel_type_id and end_use_type_id: - op.execute( - """ - UPDATE additional_carbon_intensity - SET fuel_type_id = {}, - uom_id = {}, - end_use_type_id = {}, - intensity = {}, - update_date = '{}', - update_user = 'no_user' - WHERE additional_uci_id = {} - """.format(fuel_type_id, uom_id, end_use_type_id, intensity, current_time, uci_id) - ) - elif fuel_type_id: - op.execute( - """ - UPDATE additional_carbon_intensity - SET fuel_type_id = {}, - uom_id = {}, - end_use_type_id = NULL, - intensity = {}, - update_date = '{}', - update_user = 'no_user' - WHERE additional_uci_id = {} - """.format(fuel_type_id, uom_id, intensity, current_time, uci_id) - ) - else: - op.execute( - """ - UPDATE additional_carbon_intensity - SET fuel_type_id = NULL, - uom_id = {}, - end_use_type_id = NULL, - intensity = {}, - update_date = '{}', - update_user = 'no_user' - WHERE additional_uci_id = {} - """.format(uom_id, intensity, current_time, uci_id) - ) - - # Update existing EER values for IDs 14-24 - eer_updates = [ - (14, 2, 3, 10, 2.8), # Changed to Shore power - (15, 2, 3, 11, 2.4), # Changed to Trolley bus - (16, 2, 3, 2, 1.0), # Changed to Other or unknown - (17, 2, 6, 3, 1.8), # Changed to Fuel cell vehicle - (18, 2, 6, 2, 0.9), # Changed to Other or unknown - (19, 2, 13, None, 0.9), # Changed to default ratio - (20, 3, 3, None, 2.5), # Changed to default ratio - (21, 3, 11, None, 1.0), # Changed to default ratio - (22, 2, 7, 15, 1.0), # Changed to new marine type - (23, 2, 7, 16, 1.0), # Changed to new marine type - (24, 2, 7, 17, 1.0) # Changed to new marine type - ] - - for eer_id, fuel_category_id, fuel_type_id, end_use_type_id, ratio in eer_updates: - if end_use_type_id: - op.execute( - """ - UPDATE energy_effectiveness_ratio - SET fuel_category_id = {}, - fuel_type_id = {}, - end_use_type_id = {}, - ratio = {}, - update_date = '{}', - update_user = 'no_user' - WHERE eer_id = {} - """.format(fuel_category_id, fuel_type_id, end_use_type_id, ratio, current_time, eer_id) - ) - else: - op.execute( - """ - UPDATE energy_effectiveness_ratio - SET fuel_category_id = {}, - fuel_type_id = {}, - end_use_type_id = NULL, - ratio = {}, - update_date = '{}', - update_user = 'no_user' - WHERE eer_id = {} - """.format(fuel_category_id, fuel_type_id, ratio, current_time, eer_id) - ) - - -def downgrade() -> None: - current_time = datetime.now() - - # Restore original end use types 14-21 - original_values = [ - (14, 'Marine', 'General'), - (15, 'Marine', 'Operated within 51 to 75% of load range'), - (16, 'Marine', 'Operated within 76 to 100% of load range'), - (17, 'Marine, w/ methane slip reduction kit', 'General'), - (18, 'Marine, w/ methane slip reduction kit', - 'Operated within 51 to 75% of load range'), - (19, 'Marine, w/ methane slip reduction kit', - 'Operated within 76 to 100% of load range'), - (20, 'Unknown', None), - (21, 'Aircraft', None) - ] - - for end_use_id, type_name, sub_type in original_values: - if sub_type: - op.execute( - """ - UPDATE end_use_type - SET type = '{}', - sub_type = '{}', - update_date = '{}', - update_user = 'no_user' - WHERE end_use_type_id = {} - """.format(type_name, sub_type, current_time, end_use_id) - ) - else: - op.execute( - """ - UPDATE end_use_type - SET type = '{}', - sub_type = NULL, - update_date = '{}', - update_user = 'no_user' - WHERE end_use_type_id = {} - """.format(type_name, current_time, end_use_id) - ) - - # Restore original UCI values - uci_originals = [ - (1, 7, 5, 14, 27.3), - (2, 7, 5, 15, 17.8), - (3, 7, 5, 16, 12.2), - (4, 7, 5, 17, 10.6), - (5, 7, 5, 18, 8.4), - (6, 7, 5, 19, 8.0), - (7, 7, 5, 20, 27.3), - (8, 7, 5, None, 0), - (9, None, 5, None, 0) - ] - - for uci_id, fuel_type_id, uom_id, end_use_type_id, intensity in uci_originals: - if fuel_type_id and end_use_type_id: - op.execute( - """ - UPDATE additional_carbon_intensity - SET fuel_type_id = {}, - uom_id = {}, - end_use_type_id = {}, - intensity = {}, - update_date = '{}', - update_user = 'no_user' - WHERE additional_uci_id = {} - """.format(fuel_type_id, uom_id, end_use_type_id, intensity, current_time, uci_id) - ) - elif fuel_type_id: - op.execute( - """ - UPDATE additional_carbon_intensity - SET fuel_type_id = {}, - uom_id = {}, - end_use_type_id = NULL, - intensity = {}, - update_date = '{}', - update_user = 'no_user' - WHERE additional_uci_id = {} - """.format(fuel_type_id, uom_id, intensity, current_time, uci_id) - ) - else: - op.execute( - """ - UPDATE additional_carbon_intensity - SET fuel_type_id = NULL, - uom_id = {}, - end_use_type_id = NULL, - intensity = {}, - update_date = '{}', - update_user = 'no_user' - WHERE additional_uci_id = {} - """.format(uom_id, intensity, current_time, uci_id) - ) - - # Restore original EER values - eer_originals = [ - (14, 2, 3, 14, 2.5), # Restore to Marine - (15, 2, 3, 10, 2.8), # Restore to Shore power - (16, 2, 3, 11, 2.4), # Restore to Trolley bus - (17, 2, 3, 2, 1.0), # Restore to Other or unknown - (18, 2, 6, 3, 1.8), # Restore to Fuel cell vehicle - (19, 2, 6, 2, 0.9), # Restore to Other or unknown - (20, 2, 7, 12, 1.0), # Restore to Compression-ignition engine - (21, 2, 7, 2, 0.9), # Restore to Other or unknown - (22, 2, 13, None, 0.9), # Restore to default ratio - (23, 3, 3, None, 2.5), # Restore to default ratio - (24, 3, 11, None, 1.0) # Restore to default ratio - ] - - for eer_id, fuel_category_id, fuel_type_id, end_use_type_id, ratio in eer_originals: - if end_use_type_id: - op.execute( - """ - UPDATE energy_effectiveness_ratio - SET fuel_category_id = {}, - fuel_type_id = {}, - end_use_type_id = {}, - ratio = {}, - update_date = '{}', - update_user = 'no_user' - WHERE eer_id = {} - """.format(fuel_category_id, fuel_type_id, end_use_type_id, ratio, current_time, eer_id) - ) - else: - op.execute( - """ - UPDATE energy_effectiveness_ratio - SET fuel_category_id = {}, - fuel_type_id = {}, - end_use_type_id = NULL, - ratio = {}, - update_date = '{}', - update_user = 'no_user' - WHERE eer_id = {} - """.format(fuel_category_id, fuel_type_id, ratio, current_time, eer_id) - ) diff --git a/backend/lcfs/db/migrations/versions/2024-12-06-09-59_9206124a098b.py b/backend/lcfs/db/migrations/versions/2024-12-06-09-59_9206124a098b.py deleted file mode 100644 index d12cf71d4..000000000 --- a/backend/lcfs/db/migrations/versions/2024-12-06-09-59_9206124a098b.py +++ /dev/null @@ -1,37 +0,0 @@ -"""Add Organization name to FSE - -Revision ID: 9206124a098b -Revises: aeaa26f5cdd5 -Create Date: 2024-12-04 09:59:22.876386 - -""" - -from alembic import op -import sqlalchemy as sa - -# revision identifiers, used by Alembic. -revision = "9206124a098b" -down_revision = "26ab15f8ab18" -branch_labels = None -depends_on = None - - -def upgrade(): - # Add the column 'organization_name' to 'final_supply_equipment' table with a default value - op.add_column( - "final_supply_equipment", - sa.Column("organization_name", sa.String(), nullable=False, server_default=""), - ) - - # Update existing rows to have the default value - op.execute( - "UPDATE final_supply_equipment SET organization_name = '' WHERE organization_name IS NULL" - ) - - # Remove the server default to prevent future rows from automatically getting the default value - op.alter_column("final_supply_equipment", "organization_name", server_default=None) - - -def downgrade(): - # Remove the column 'organization_name' from 'final_supply_equipment' table - op.drop_column("final_supply_equipment", "organization_name") diff --git a/backend/lcfs/db/migrations/versions/2024-12-09-23-31_7ae38a8413ab.py b/backend/lcfs/db/migrations/versions/2024-12-09-23-31_7ae38a8413ab.py deleted file mode 100644 index 51856f8c4..000000000 --- a/backend/lcfs/db/migrations/versions/2024-12-09-23-31_7ae38a8413ab.py +++ /dev/null @@ -1,95 +0,0 @@ -"""Update Fuel Types measured in volume to be other-uses - -Revision ID: 7ae38a8413ab -Revises: 26ab15f8ab18 -Create Date: 2024-12-09 19:31:18.199089 - -""" - -import sqlalchemy as sa -from alembic import op -from datetime import datetime - -# revision identifiers, used by Alembic. -revision = "7ae38a8413ab" -down_revision = "cd8698fe40e6" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - current_time = datetime.now() - - # Update the `other_uses_fossil_derived` field for all specified fuel types - op.execute( - f""" - UPDATE fuel_type - SET other_uses_fossil_derived = true, - update_date = '{current_time}', - update_user = 'no_user' - WHERE fuel_type IN ( - 'Alternative jet fuel', - 'Biodiesel', - 'Ethanol', - 'HDRD', - 'Renewable gasoline', - 'Renewable naphtha' - ) - """ - ) - - # Update the `other_uses_fossil_derived` field for all specified fuel types - op.execute( - f""" - UPDATE fuel_type - SET other_uses_fossil_derived = false, - update_date = '{current_time}', - update_user = 'no_user' - WHERE fuel_type IN ( - 'CNG', - 'Electricity', - 'Hydrogen', - 'LNG', - 'Propane' - ) - """ - ) - - -def downgrade() -> None: - current_time = datetime.now() - - # Revert the `other_uses_fossil_derived` field to false for the first set of fuel types - op.execute( - f""" - UPDATE fuel_type - SET other_uses_fossil_derived = false, - update_date = '{current_time}', - update_user = 'no_user' - WHERE fuel_type IN ( - 'Alternative jet fuel', - 'Biodiesel', - 'Ethanol', - 'HDRD', - 'Renewable gasoline', - 'Renewable naphtha' - ) - """ - ) - - # Revert the `other_uses_fossil_derived` field to true for the second set of fuel types - op.execute( - f""" - UPDATE fuel_type - SET other_uses_fossil_derived = true, - update_date = '{current_time}', - update_user = 'no_user' - WHERE fuel_type IN ( - 'CNG', - 'Electricity', - 'Hydrogen', - 'LNG', - 'Propane' - ) - """ - ) diff --git a/backend/lcfs/db/migrations/versions/2024-12-12-21-43_5d729face5ab.py b/backend/lcfs/db/migrations/versions/2024-12-12-21-43_5d729face5ab.py deleted file mode 100644 index 558720d38..000000000 --- a/backend/lcfs/db/migrations/versions/2024-12-12-21-43_5d729face5ab.py +++ /dev/null @@ -1,35 +0,0 @@ -"""Update default_carbon_intensity for 'Other diesel' fuel type - -Revision ID: 5d729face5ab -Revises: 7ae38a8413ab -Create Date: 2024-12-12 21:43:01.414475 -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "5d729face5ab" -down_revision = "7ae38a8413ab" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - op.execute( - """ - UPDATE fuel_type - SET default_carbon_intensity = 100.21 - WHERE fuel_type_id = 20 - """ - ) - - -def downgrade() -> None: - op.execute( - """ - UPDATE fuel_type - SET default_carbon_intensity = 94.38 - WHERE fuel_type_id = 20 - """ - ) diff --git a/backend/lcfs/db/migrations/versions/2024-12-17-23-58_851e09cf8661.py b/backend/lcfs/db/migrations/versions/2024-12-17-23-58_851e09cf8661.py deleted file mode 100644 index e7f10a2c3..000000000 --- a/backend/lcfs/db/migrations/versions/2024-12-17-23-58_851e09cf8661.py +++ /dev/null @@ -1,62 +0,0 @@ -"""Add Default CI to Categories - -Revision ID: 851e09cf8661 -Revises: 5b374dd97469 -Create Date: 2024-12-17 23:58:07.462215 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "851e09cf8661" -down_revision = "5b374dd97469" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.add_column( - "fuel_category", - sa.Column( - "default_carbon_intensity", - sa.Numeric(precision=10, scale=2), - nullable=True, - comment="Default carbon intensity of the fuel category", - ), - ) - - # Populate default values for existing records - op.execute( - """ - UPDATE "fuel_category" SET "default_carbon_intensity" = 88.83 WHERE "description" = 'Jet fuel'; - """ - ) - op.execute( - """ - UPDATE "fuel_category" SET "default_carbon_intensity" = 100.21 WHERE "description" = 'Diesel'; - """ - ) - op.execute( - """ - UPDATE "fuel_category" SET "default_carbon_intensity" = 93.67 WHERE "description" = 'Gasoline'; - """ - ) - - # Now set the column to NOT NULL after populating defaults - op.alter_column( - "fuel_category", - "default_carbon_intensity", - existing_type=sa.Numeric(precision=10, scale=2), - nullable=False, - ) - - # ### end Alembic commands ### - - -def downgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.drop_column("fuel_category", "default_carbon_intensity") - # ### end Alembic commands ### diff --git a/backend/lcfs/db/migrations/versions/2024-12-20-05-17_59873cafbcd8.py b/backend/lcfs/db/migrations/versions/2024-12-20-05-17_59873cafbcd8.py deleted file mode 100644 index 79914e3b0..000000000 --- a/backend/lcfs/db/migrations/versions/2024-12-20-05-17_59873cafbcd8.py +++ /dev/null @@ -1,40 +0,0 @@ -"""update other diesel - -Revision ID: 59873cafbcd8 -Revises: 851e09cf8661 -Create Date: 2024-12-20 05:17:40.638826 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "59873cafbcd8" -down_revision = "851e09cf8661" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.execute( - """ - UPDATE fuel_type - SET fossil_derived = false, other_uses_fossil_derived = false - WHERE fuel_type = 'Other diesel' - """ - ) - # ### end Alembic commands ### - - -def downgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.execute( - """ - UPDATE fuel_type - SET fossil_derived = true, other_uses_fossil_derived = true - WHERE fuel_type = 'Other diesel' - """ - ) - # ### end Alembic commands ### diff --git a/backend/lcfs/db/migrations/versions/2024-12-21-00-18_5fbcb508c1be.py b/backend/lcfs/db/migrations/versions/2024-12-21-00-18_5fbcb508c1be.py deleted file mode 100644 index 2477b1308..000000000 --- a/backend/lcfs/db/migrations/versions/2024-12-21-00-18_5fbcb508c1be.py +++ /dev/null @@ -1,40 +0,0 @@ -"""LNG end use naming change - -Revision ID: 5fbcb508c1be -Revises: 59873cafbcd8 -Create Date: 2024-12-21 00:18:12.324520 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "5fbcb508c1be" -down_revision = "59873cafbcd8" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.execute( - """ - UPDATE end_use_type - SET type = 'Compression-ignition engine- Marine, with methane slip reduction kit- Operated within 26 to 75% of load range' - WHERE end_use_type_id = 19 - """ - ) - # ### end Alembic commands ### - - -def downgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.execute( - """ - UPDATE end_use_type - SET type = 'Compression-ignition engine- Marine, with methane slip reduction kit- Operated within 51 to 75% of load range' - WHERE end_use_type_id = 19 - """ - ) - # ### end Alembic commands ### diff --git a/backend/lcfs/db/migrations/versions/2024-12-22-23-46_ab04810d4d7c.py b/backend/lcfs/db/migrations/versions/2024-12-22-23-46_ab04810d4d7c.py deleted file mode 100644 index 524d59140..000000000 --- a/backend/lcfs/db/migrations/versions/2024-12-22-23-46_ab04810d4d7c.py +++ /dev/null @@ -1,36 +0,0 @@ -"""Add UQ to TCI - -Revision ID: ab04810d4d7c -Revises: 5fbcb508c1be -Create Date: 2024-12-22 23:46:37.505166 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "ab04810d4d7c" -down_revision = "5fbcb508c1be" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.create_unique_constraint( - "uq_target_carbon_intensity_compliance_fuel", - "target_carbon_intensity", - ["compliance_period_id", "fuel_category_id"], - ) - # ### end Alembic commands ### - - -def downgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.drop_constraint( - "uq_target_carbon_intensity_compliance_fuel", - "target_carbon_intensity", - type_="unique", - ) - # ### end Alembic commands ### diff --git a/backend/lcfs/db/migrations/versions/2024-12-24-07-40_d9cdd9fca0ce.py b/backend/lcfs/db/migrations/versions/2024-12-24-07-40_d9cdd9fca0ce.py deleted file mode 100644 index fe90da04f..000000000 --- a/backend/lcfs/db/migrations/versions/2024-12-24-07-40_d9cdd9fca0ce.py +++ /dev/null @@ -1,600 +0,0 @@ -"""move common seeders to migrations - -Revision ID: d9cdd9fca0ce -Revises: 5fbcb508c1be -Create Date: 2024-12-24 07:40:08.332121 -""" -from alembic import op -import sqlalchemy as sa -from datetime import datetime - -# revision identifiers, used by Alembic. -revision = "d9cdd9fca0ce" -down_revision = "ab04810d4d7c" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # 1. Compliance Periods - dates = [(year, f"{year}-01-01", f"{year}-12-31") - for year in range(2010, 2033)] - for i, (year, start_date, end_date) in enumerate(dates, 1): - op.execute(f""" - INSERT INTO compliance_period ( - compliance_period_id, description, display_order, - effective_date, expiration_date, effective_status - ) - VALUES ( - {i}, '{year}', {i}, - '{start_date}', '{end_date}', TRUE - ) - ON CONFLICT (compliance_period_id) DO NOTHING; - """) - - # 2. Organization Types - op.execute(""" - INSERT INTO organization_type (organization_type_id, org_type, description) - VALUES - (1, 'fuel_supplier', 'Fuel Supplier'), - (2, 'electricity_supplier', 'Electricity Supplier'), - (3, 'broker', 'Broker'), - (4, 'utilities', 'Utilities (local or public)') - ON CONFLICT (organization_type_id) DO NOTHING; - """) - - # 3. Organization Statuses - op.execute(""" - INSERT INTO organization_status (organization_status_id, status, description) - VALUES - (1, 'Unregistered', 'Unregistered'), - (2, 'Registered', 'Registered'), - (3, 'Suspended', 'Suspended'), - (4, 'Canceled', 'Canceled') - ON CONFLICT (organization_status_id) DO NOTHING; - """) - - # 4. Roles - op.execute(""" - INSERT INTO role (role_id, name, description, is_government_role, display_order) - VALUES - (1, 'GOVERNMENT', 'Identifies a government user in the system.', TRUE, 1), - (2, 'SUPPLIER', 'Identifies a supplier user in the system.', FALSE, 2), - (3, 'ADMINISTRATOR', 'Can add/edit IDIR users and assign roles, add/edit organizations, BCeID users, and assign roles', TRUE, 3), - (4, 'ANALYST', 'Can make recommendations on transfers, transactions, and compliance reports, manage file submissions, and add/edit fuel codes', TRUE, 4), - (5, 'COMPLIANCE_MANAGER', 'Can make recommendations on compliance reports', TRUE, 5), - (6, 'DIRECTOR', 'Can assess compliance reports and approve transactions', TRUE, 6), - (7, 'MANAGE_USERS', 'Can add/edit BCeID users and assign roles', FALSE, 7), - (8, 'TRANSFER', 'Can create/save transfers and submit files', FALSE, 8), - (9, 'COMPLIANCE_REPORTING', 'Can create/save compliance reports and submit files', FALSE, 9), - (10, 'SIGNING_AUTHORITY', 'Can sign and submit compliance reports to government and transfers to trade partners/government', FALSE, 10), - (11, 'READ_ONLY', 'Can view transactions, compliance reports, and files', FALSE, 11) - ON CONFLICT (role_id) DO NOTHING; - """) - - # 5. Transfer Statuses - op.execute(""" - INSERT INTO transfer_status (transfer_status_id, status, visible_to_transferor, visible_to_transferee, visible_to_government) - VALUES - (1, 'Draft', TRUE, FALSE, FALSE), - (2, 'Deleted', FALSE, FALSE, FALSE), - (3, 'Sent', TRUE, TRUE, FALSE), - (4, 'Submitted', TRUE, TRUE, TRUE), - (5, 'Recommended', TRUE, TRUE, TRUE), - (6, 'Recorded', TRUE, TRUE, TRUE), - (7, 'Refused', TRUE, TRUE, TRUE), - (8, 'Declined', TRUE, TRUE, FALSE), - (9, 'Rescinded', TRUE, TRUE, TRUE) - ON CONFLICT (transfer_status_id) DO NOTHING; - """) - - # 6. Transfer Categories - op.execute(""" - INSERT INTO transfer_category (transfer_category_id, category, effective_status) - VALUES - (1, 'A', TRUE), - (2, 'B', TRUE), - (3, 'C', TRUE), - (4, 'D', TRUE) - ON CONFLICT (transfer_category_id) DO NOTHING; - """) - - # 7. Admin Adjustment Statuses - op.execute(""" - INSERT INTO admin_adjustment_status (admin_adjustment_status_id, status) - VALUES - (1, 'Draft'), - (2, 'Recommended'), - (3, 'Approved'), - (4, 'Deleted') - ON CONFLICT (admin_adjustment_status_id) DO NOTHING; - """) - - # 8. Initiative Agreement Statuses - op.execute(""" - INSERT INTO initiative_agreement_status (initiative_agreement_status_id, status) - VALUES - (1, 'Draft'), - (2, 'Recommended'), - (3, 'Approved'), - (4, 'Deleted') - ON CONFLICT (initiative_agreement_status_id) DO NOTHING; - """) - - # 9. Static Fuel Data - # Expected Use Types - op.execute(""" - INSERT INTO expected_use_type (expected_use_type_id, name, description, effective_status) - VALUES - (1, 'Heating oil', 'Fuel used for heating purposes', TRUE), - (2, 'Other', 'Other type of fuel description', TRUE) - ON CONFLICT (expected_use_type_id) DO NOTHING; - """) - - # Unit of Measures first - op.execute(""" - INSERT INTO unit_of_measure (uom_id, name, description) - VALUES - (1, 'MJ/L', 'Megajoules per litre'), - (2, 'MJ/kWh', 'Megajoules per kilowatt hour'), - (3, 'MJ/m³', 'Megajoules per cubic metre'), - (4, 'MJ/kg', 'Megajoules per kilogram'), - (5, 'gCO²e/MJ', 'grams of carbon dioxide equivalent per megajoule') - ON CONFLICT (uom_id) DO NOTHING; - """) - - # End Use Types - op.execute(""" - INSERT INTO end_use_type (end_use_type_id, type, intended_use) - VALUES - (1, 'Light duty motor vehicles', TRUE), - (2, 'Other or unknown', FALSE), - (3, 'Fuel cell vehicle', FALSE), - (4, 'Battery bus', TRUE), - (5, 'Battery truck', TRUE), - (6, 'Cargo handling equipment', TRUE), - (7, 'Fixed guiderail', TRUE), - (8, 'Ground support equipment', TRUE), - (9, 'Heavy forklift', TRUE), - (10, 'Shore power', TRUE), - (11, 'Trolley bus', TRUE), - (12, 'Compression-ignition engine', FALSE), - (13, 'Other', TRUE), - (14, 'Aircraft', TRUE), - (15, 'Compression-ignition engine- Marine, general', TRUE), - (16, 'Compression-ignition engine- Marine, operated within 51 to 75% of load range', TRUE), - (17, 'Compression-ignition engine- Marine, operated within 76 to 100% of load range', TRUE), - (18, 'Compression-ignition engine- Marine, with methane slip reduction kit- General', TRUE), - (19, 'Compression-ignition engine- Marine, with methane slip reduction kit- Operated within 26 to 75% of load range', TRUE), - (20, 'Compression-ignition engine- Marine, with methane slip reduction kit- Operated within 76 to 100% of load range', TRUE), - (21, 'Compression-ignition engine- Marine, unknown whether kit is installed or average operating load range', TRUE), - (22, 'Unknown engine type', TRUE), - (23, 'Other (i.e. road transportation)', TRUE), - (24, 'Any', TRUE) - ON CONFLICT (end_use_type_id) DO NOTHING; - - """) - - # Provision Acts - op.execute(""" - INSERT INTO provision_of_the_act (provision_of_the_act_id, name, description, effective_status) - VALUES - (1, 'Prescribed carbon intensity - section 19 (a)', 'Prescribed carbon intensity - section 19 (a)', TRUE), - (2, 'Fuel code - section 19 (b) (i)', 'Fuel code - section 19 (b) (i)', TRUE), - (3, 'Default carbon intensity - section 19 (b) (ii)', 'Default carbon intensity - section 19 (b) (ii)', TRUE) - ON CONFLICT (provision_of_the_act_id) DO NOTHING; - """) - - # Fuel Categories - op.execute(""" - INSERT INTO fuel_category (fuel_category_id, category, description, default_carbon_intensity, effective_status) - VALUES - (1, 'Gasoline', 'Gasoline', 93.67, TRUE), - (2, 'Diesel', 'Diesel', 100.21, TRUE), - (3, 'Jet fuel', 'Jet fuel', 88.83, TRUE) - ON CONFLICT (fuel_category_id) DO NOTHING; - """) - - # Fuel Types - op.execute(""" - INSERT INTO fuel_type (fuel_type_id, fuel_type, fossil_derived, other_uses_fossil_derived, - provision_1_id, provision_2_id, default_carbon_intensity, units, unrecognized) - VALUES - (1, 'Biodiesel', FALSE, FALSE, 2, 3, 100.21, 'Litres', FALSE), - (2, 'CNG', FALSE, TRUE, 2, 3, 63.91, 'Cubic_metres', FALSE), - (3, 'Electricity', FALSE, TRUE, 2, 3, 12.14, 'Kilowatt_hour', FALSE), - (4, 'Ethanol', FALSE, FALSE, 2, 3, 93.67, 'Litres', FALSE), - (5, 'HDRD', FALSE, FALSE, 2, 3, 100.21, 'Litres', FALSE), - (6, 'Hydrogen', FALSE, TRUE, 2, 3, 123.96, 'Kilograms', FALSE), - (7, 'LNG', FALSE, TRUE, 2, 3, 90.11, 'Kilograms', FALSE), - (11, 'Alternative jet fuel', FALSE, FALSE, 2, 3, 88.83, 'Litres', FALSE), - (13, 'Propane', FALSE, TRUE, 2, 3, 79.87, 'Litres', FALSE), - (14, 'Renewable gasoline', FALSE, FALSE, 2, 3, 93.67, 'Litres', FALSE), - (15, 'Renewable naphtha', FALSE, FALSE, 2, 3, 93.67, 'Litres', FALSE), - (16, 'Fossil-derived diesel', TRUE, TRUE, 1, NULL, 94.38, 'Litres', FALSE), - (17, 'Fossil-derived gasoline', TRUE, TRUE, 1, NULL, 93.67, 'Litres', FALSE), - (18, 'Fossil-derived jet fuel', TRUE, TRUE, 1, NULL, 88.83, 'Litres', FALSE), - (19, 'Other', FALSE, FALSE, 2, 3, 0, 'Litres', TRUE), - (20, 'Other diesel', FALSE, FALSE, 1, NULL, 100.21, 'Litres', FALSE) - ON CONFLICT (fuel_type_id) DO NOTHING; - """) - - # Energy Effectiveness Ratios - op.execute(""" - INSERT INTO energy_effectiveness_ratio ( - eer_id, fuel_category_id, fuel_type_id, end_use_type_id, ratio, effective_status - ) - VALUES - (1, 1, 2, 24, 0.9, TRUE), - (2, 1, 3, 1, 3.5, TRUE), - (3, 1, 3, 2, 1.0, TRUE), - (4, 1, 6, 3, 2.4, TRUE), - (5, 1, 6, 2, 0.9, TRUE), - (6, 1, 13, 24, 0.9, TRUE), - (7, 2, 2, 24, 0.9, TRUE), - (8, 2, 3, 4, 3.8, TRUE), - (9, 2, 3, 5, 3.2, TRUE), - (10, 2, 3, 6, 2.5, TRUE), - (11, 2, 3, 7, 2.9, TRUE), - (12, 2, 3, 8, 2.5, TRUE), - (13, 2, 3, 9, 3.9, TRUE), - (14, 2, 3, 10, 2.8, TRUE), - (15, 2, 3, 11, 2.4, TRUE), - (16, 2, 3, 2, 1.0, TRUE), - (17, 2, 6, 3, 1.8, TRUE), - (18, 2, 6, 2, 0.9, TRUE), - (19, 2, 13, 24, 0.9, TRUE), - (20, 3, 3, 24, 2.5, TRUE), - (21, 3, 11, 24, 1.0, TRUE), - (22, 2, 7, 15, 1.0, TRUE), - (23, 2, 7, 16, 1.0, TRUE), - (24, 2, 7, 17, 1.0, TRUE), - (25, 2, 7, 18, 1.0, TRUE), - (26, 2, 7, 19, 1.0, TRUE), - (27, 2, 7, 20, 1.0, TRUE), - (28, 2, 7, 21, 1.0, TRUE), - (29, 2, 7, 22, 0.9, TRUE), - (30, 2, 7, 23, 0.9, TRUE), - (31, 2, 1, 24, 1.0, TRUE), - (32, 2, 5, 24, 1.0, TRUE), - (33, 3, 6, 24, 1.0, TRUE), - (34, 1, 14, 24, 1.0, TRUE), - (35, 1, 15, 24, 1.0, TRUE), - (36, 2, 16, 24, 1.0, TRUE), - (37, 1, 17, 24, 1.0, TRUE), - (38, 3, 18, 24, 1.0, TRUE), - (39, 1, 19, 24, 1.0, TRUE), - (40, 2, 19, 24, 1.0, TRUE), - (41, 3, 7, 24, 1.0, TRUE), - (42, 2, 20, 24, 1.0, TRUE), - (43, 1, 4, 24, 1.0, TRUE) - ON CONFLICT (eer_id) DO NOTHING; - """) - - # Now Additional Carbon Intensities - op.execute(""" - INSERT INTO additional_carbon_intensity (additional_uci_id, fuel_type_id, uom_id, end_use_type_id, intensity) - VALUES - (1, 7, 5, NULL, 0), - (2, NULL, 5, NULL, 0), - (3, 7, 5, 15, 27.3), - (4, 7, 5, 16, 17.8), - (5, 7, 5, 17, 12.2), - (6, 7, 5, 18, 10.6), - (7, 7, 5, 19, 8.4), - (8, 7, 5, 20, 8.0), - (9, 7, 5, 21, 27.3), - (10, 7, 5, 22, 27.3), - (11, 7, 5, 23, 0) - ON CONFLICT (additional_uci_id) DO NOTHING; - """) - - # Energy Densities - op.execute(""" - INSERT INTO energy_density (energy_density_id, fuel_type_id, uom_id, density) - VALUES - (1, 17, 1, 34.69), - (2, 4, 1, 23.58), - (3, 14, 1, 34.69), - (4, 15, 1, 34.51), - (5, 16, 1, 38.65), - (6, 1, 1, 35.40), - (7, 5, 1, 37.89), - (9, 18, 1, 37.40), - (10, 11, 1, 36.00), - (11, 3, 2, 3.60), - (12, 6, 2, 141.76), - (13, 13, 1, 25.62), - (14, 2, 3, 38.27), - (15, 7, 4, 53.54), - (16, 20, 1, 36.51) - ON CONFLICT (energy_density_id) DO NOTHING; - """) - - # Target Carbon Intensities - op.execute(""" - INSERT INTO target_carbon_intensity ( - target_carbon_intensity_id, - compliance_period_id, - fuel_category_id, - target_carbon_intensity, - reduction_target_percentage, - effective_status - ) - VALUES - (1, 15, 1, 78.68, 16.0, TRUE), - (2, 16, 1, 76.53, 18.3, TRUE), - (3, 17, 1, 74.37, 20.6, TRUE), - (4, 18, 1, 72.13, 23.0, TRUE), - (5, 19, 1, 69.97, 25.3, TRUE), - (6, 20, 1, 67.72, 27.7, TRUE), - (7, 21, 1, 65.57, 30.0, TRUE), - (8, 15, 2, 79.28, 16.0, TRUE), - (9, 16, 2, 77.11, 18.3, TRUE), - (10, 17, 2, 74.94, 20.6, TRUE), - (11, 18, 2, 72.67, 23.0, TRUE), - (12, 19, 2, 70.50, 25.3, TRUE), - (13, 20, 2, 68.24, 27.7, TRUE), - (14, 21, 2, 66.07, 30.0, TRUE), - (15, 15, 3, 88.83, 0.0, TRUE), - (16, 16, 3, 88.83, 0.0, TRUE), - (17, 17, 3, 87.05, 2.0, TRUE), - (18, 18, 3, 85.28, 4.0, TRUE), - (19, 19, 3, 83.50, 6.0, TRUE), - (20, 20, 3, 81.72, 8.0, TRUE), - (21, 21, 3, 79.95, 10.0, TRUE) - ON CONFLICT (target_carbon_intensity_id) DO NOTHING; - """) - - # Fuel Instances - op.execute(""" - INSERT INTO fuel_instance (fuel_instance_id, fuel_type_id, fuel_category_id) - VALUES - (1, 1, 2), - (2, 2, 1), - (3, 2, 2), - (4, 3, 1), - (5, 3, 2), - (6, 3, 3), - (7, 4, 1), - (8, 5, 2), - (9, 6, 1), - (10, 6, 2), - (11, 6, 3), - (12, 7, 2), - (16, 11, 3), - (18, 13, 1), - (19, 13, 2), - (20, 14, 1), - (21, 15, 1), - (22, 16, 2), - (23, 17, 1), - (24, 18, 3), - (25, 19, 1), - (26, 19, 2), - (27, 19, 3), - (28, 20, 2) - ON CONFLICT (fuel_instance_id) DO NOTHING; - """) - - # Transport Modes - op.execute(""" - INSERT INTO transport_mode (transport_mode_id, transport_mode) - VALUES - (1, 'Truck'), - (2, 'Rail'), - (3, 'Marine-domestic'), - (4, 'Adjacent'), - (5, 'Pipeline') - ON CONFLICT (transport_mode_id) DO NOTHING; - """) - - # Fuel Code Prefixes - op.execute(""" - INSERT INTO fuel_code_prefix (fuel_code_prefix_id, prefix) - VALUES - (1, 'BCLCF'), - (2, 'PROXY') - ON CONFLICT (fuel_code_prefix_id) DO NOTHING; - """) - - # Fuel Code Statuses - op.execute(""" - INSERT INTO fuel_code_status (fuel_code_status_id, status, description, display_order) - VALUES - (1, 'Draft', 'Initial state of the fuel code', 1), - (2, 'Approved', 'Fuel code has been approved', 2), - (3, 'Deleted', 'Fuel code has been deleted', 3) - ON CONFLICT (fuel_code_status_id) DO NOTHING; - """) - - # Level of Equipment - op.execute(""" - INSERT INTO level_of_equipment (level_of_equipment_id, name, display_order) - VALUES - (1, 'Level 3 - Direct current fast charging', 1), - (2, 'Level 2 - High voltage, operating above level 1', 2), - (3, 'Level 1 - Low voltage, operating at 120V AC or less', 3), - (4, 'Other - Additional information provided in notes field', 4) - ON CONFLICT (level_of_equipment_id) DO NOTHING; - """) - - # Fuel Measurement Types - op.execute(""" - INSERT INTO fuel_measurement_type (fuel_measurement_type_id, type, display_order) - VALUES - (1, 'Separate utility meter', 1), - (2, 'Equipment meter (remote access)', 2), - (3, 'Equipment meter (physical access)', 3), - (4, 'No meter or estimated', 4) - ON CONFLICT (fuel_measurement_type_id) DO NOTHING; - """) - - # 10. Compliance Report Statuses - op.execute(""" - INSERT INTO compliance_report_status (compliance_report_status_id, status, effective_status) - VALUES - (1, 'Draft', TRUE), - (2, 'Submitted', TRUE), - (3, 'Recommended_by_analyst', TRUE), - (4, 'Recommended_by_manager', TRUE), - (5, 'Assessed', TRUE), - (6, 'ReAssessed', TRUE) - ON CONFLICT (compliance_report_status_id) DO NOTHING; - """) - - # 11. Allocation Transaction Types - op.execute(""" - INSERT INTO allocation_transaction_type ( - allocation_transaction_type_id, type, description, - display_order, effective_date, effective_status - ) - VALUES - (1, 'Allocated from', 'Fuel allocated from another supplier under an allocation agreement', 1, '2012-01-01', TRUE), - (2, 'Allocated to', 'Fuel allocated to another supplier under an allocation agreement', 2, '2012-01-01', TRUE) - ON CONFLICT (allocation_transaction_type_id) DO NOTHING; - """) - - # 12. End User Types - op.execute(""" - INSERT INTO end_user_type (type_name, intended_use) - VALUES - ('Multi-unit residential building', TRUE), - ('Fleet', TRUE), - ('Public', TRUE), - ('Employee', TRUE) - ON CONFLICT (type_name) DO NOTHING; - """) - - # 13. Notification Types - op.execute(""" - INSERT INTO notification_type (notification_type_id, name, description, email_content, create_user, update_user) - VALUES - (1, 'BCEID__COMPLIANCE_REPORT__DIRECTOR_ASSESSMENT', 'Director assessed a compliance report or supplemental report.', 'Email content', 'system', 'system'), - (2, 'BCEID__INITIATIVE_AGREEMENT__DIRECTOR_APPROVAL', 'Director approved the initiative agreement or transaction', 'Email content', 'system', 'system'), - (3, 'BCEID__TRANSFER__DIRECTOR_DECISION', 'Director recorded or refused a transfer request', 'Email content', 'system', 'system'), - (4, 'BCEID__TRANSFER__PARTNER_ACTIONS', 'A transfer partner took action (proposed, declined, rescinded, or signed & submitted) on a transfer request', 'Email content', 'system', 'system'), - (5, 'IDIR_ANALYST__COMPLIANCE_REPORT__DIRECTOR_DECISION', 'Director assessed compliance report', 'Email content', 'system', 'system'), - (6, 'IDIR_ANALYST__COMPLIANCE_REPORT__MANAGER_RECOMMENDATION', 'Compliance manager recommended action on the compliance report.', 'Email content', 'system', 'system'), - (7, 'IDIR_ANALYST__COMPLIANCE_REPORT__SUBMITTED_FOR_REVIEW', 'Compliance report submitted for government analyst review or returned by compliance manager', 'Email content', 'system', 'system'), - (8, 'IDIR_ANALYST__INITIATIVE_AGREEMENT__RETURNED_TO_ANALYST', 'Director approved/returned the initiative agreement to the analyst', 'Email content', 'system', 'system'), - (9, 'IDIR_ANALYST__TRANSFER__DIRECTOR_RECORDED', 'Director recorded or refused a transfer request', 'Email content', 'system', 'system'), - (10, 'IDIR_ANALYST__TRANSFER__RESCINDED_ACTION', 'A transfer request was rescinded by a transfer partner', 'Email content', 'system', 'system'), - (11, 'IDIR_ANALYST__TRANSFER__SUBMITTED_FOR_REVIEW', 'Transfer request submitted for government analyst review', 'Email content', 'system', 'system'), - (12, 'IDIR_COMPLIANCE_MANAGER__COMPLIANCE_REPORT__ANALYST_RECOMMENDATION', 'Analyst recommendation on the compliance report or returned by the director', 'Email content', 'system', 'system'), - (13, 'IDIR_COMPLIANCE_MANAGER__COMPLIANCE_REPORT__DIRECTOR_ASSESSMENT', 'Director assessed a compliance report', 'Email content', 'system', 'system'), - (14, 'IDIR_COMPLIANCE_MANAGER__COMPLIANCE_REPORT__SUBMITTED_FOR_REVIEW', 'Compliance report submitted for government analyst review', 'Email content', 'system', 'system'), - (15, 'IDIR_DIRECTOR__COMPLIANCE_REPORT__MANAGER_RECOMMENDATION', 'Compliance manager recommended action on the compliance report', 'Email content', 'system', 'system'), - (16, 'IDIR_DIRECTOR__INITIATIVE_AGREEMENT__ANALYST_RECOMMENDATION', 'Analyst recommendation provided for the initiative agreement', 'Email content', 'system', 'system'), - (17, 'IDIR_DIRECTOR__TRANSFER__ANALYST_RECOMMENDATION', 'Analyst recommendation provided for the transfer request', 'Email content', 'system', 'system') - ON CONFLICT (notification_type_id) DO NOTHING; - """) - - # 14. Notification Channels - op.execute(""" - INSERT INTO notification_channel (notification_channel_id, channel_name, enabled, subscribe_by_default) - VALUES - (1, 'EMAIL', TRUE, TRUE), - (2, 'IN_APP', TRUE, FALSE) - ON CONFLICT (notification_channel_id) DO NOTHING; - """) - - # Update sequences - sequence_mappings = { - 'transfer_status': 'transfer_status_id', - 'transfer_category': 'transfer_category_id', - 'role': 'role_id', - 'organization_type': 'organization_type_id', - 'organization_status': 'organization_status_id', - 'initiative_agreement_status': 'initiative_agreement_status_id', - 'compliance_period': 'compliance_period_id', - 'admin_adjustment_status': 'admin_adjustment_status_id', - 'notification_channel': 'notification_channel_id', - 'notification_type': 'notification_type_id', - 'end_user_type': 'end_user_type_id', - 'compliance_report_status': 'compliance_report_status_id', - 'allocation_transaction_type': 'allocation_transaction_type_id', - 'provision_of_the_act': 'provision_of_the_act_id', - 'transport_mode': 'transport_mode_id', - 'fuel_code_prefix': 'fuel_code_prefix_id', - 'fuel_code_status': 'fuel_code_status_id', - 'fuel_category': 'fuel_category_id', - 'fuel_type': 'fuel_type_id', - 'unit_of_measure': 'uom_id', # Both column and sequence use uom_id - 'additional_carbon_intensity': 'additional_uci_id', - 'energy_effectiveness_ratio': 'eer_id', - 'energy_density': 'energy_density_id', - 'target_carbon_intensity': 'target_carbon_intensity_id', - 'fuel_instance': 'fuel_instance_id', - 'level_of_equipment': 'level_of_equipment_id', - 'fuel_measurement_type': 'fuel_measurement_type_id' - } - - for table, id_column in sequence_mappings.items(): - if table == 'unit_of_measure': - # Special case for unit_of_measure table - op.execute(f""" - SELECT setval('unit_of_measure_uom_id_seq', - (SELECT MAX(uom_id) FROM unit_of_measure), true); - """) - else: - op.execute(f""" - SELECT setval('{table}_{id_column}_seq', - (SELECT MAX({id_column}) FROM {table}), true); - """) - - -def downgrade() -> None: - # Clear all seeded data in reverse order of creation, respecting foreign key constraints - table_groups = [ - # Group 1 - Most dependent tables (records with multiple foreign keys) - [ - 'fuel_instance', # Depends on fuel_type and fuel_category - 'target_carbon_intensity', # Depends on compliance_period and fuel_category - 'additional_carbon_intensity', # Depends on fuel_type and end_use_type - 'energy_density', # Depends on fuel_type and uom - 'energy_effectiveness_ratio', # Added here since it depends on end_use_type - 'fuel_code', # If exists, depends on several tables - ], - - # Group 2 - Tables with single foreign key dependencies - [ - 'notification_channel', - 'notification_type', - 'end_user_type', - 'allocation_transaction_type', - 'compliance_report_status', - 'fuel_measurement_type', - 'level_of_equipment', - ], - - # Group 3 - Core reference tables with dependencies - [ - 'fuel_type', # Depends on provision_of_the_act - 'fuel_category', - 'transport_mode', - 'fuel_code_prefix', - 'fuel_code_status', - 'end_use_type', - ], - - # Group 4 - Base reference tables (no dependencies) - [ - 'expected_use_type', - 'unit_of_measure', - 'provision_of_the_act', - 'initiative_agreement_status', - 'admin_adjustment_status', - 'transfer_category', - 'transfer_status', - 'role', - 'organization_status', - 'organization_type', - 'compliance_period' - ] - ] - - # Execute TRUNCATE for each group - for group in table_groups: - tables_list = ', '.join(group) - op.execute(f"TRUNCATE TABLE {tables_list} CASCADE;") diff --git a/backend/lcfs/db/migrations/versions/2024-12-30-13-54_9329e38396e1.py b/backend/lcfs/db/migrations/versions/2024-12-30-13-54_9329e38396e1.py deleted file mode 100644 index 6d00c6db8..000000000 --- a/backend/lcfs/db/migrations/versions/2024-12-30-13-54_9329e38396e1.py +++ /dev/null @@ -1,84 +0,0 @@ -"""add update_count_transfers_in_progress db function and update existing counts - -Revision ID: 9329e38396e1 -Revises: d9cdd9fca0ce -Create Date: 2024-12-30 13:54:09.361644 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "9329e38396e1" -down_revision = "d9cdd9fca0ce" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # Create or replace the trigger function without considering Draft transfers - op.execute( - """ - CREATE OR REPLACE FUNCTION update_count_transfers_in_progress() - RETURNS TRIGGER AS $$ - BEGIN - -- Update count_transfers_in_progress for from_organization_id and to_organization_id - UPDATE organization o - SET count_transfers_in_progress = ( - SELECT COUNT(DISTINCT t.transfer_id) - FROM transfer t - WHERE - t.current_status_id IN (3, 4) - AND (t.from_organization_id = o.organization_id OR t.to_organization_id = o.organization_id) - ) - WHERE o.organization_id = COALESCE(NEW.from_organization_id, OLD.from_organization_id) - OR o.organization_id = COALESCE(NEW.to_organization_id, OLD.to_organization_id); - - RETURN NEW; - END; - $$ LANGUAGE plpgsql; - """ - ) - - # Create the trigger - op.execute( - """ - CREATE TRIGGER update_count_transfers_in_progress_trigger - AFTER INSERT OR UPDATE OR DELETE ON transfer - FOR EACH ROW - EXECUTE FUNCTION update_count_transfers_in_progress(); - """ - ) - - # Update existing counts for all organizations by aggregating both sent and received transfers without double-counting - op.execute( - """ - UPDATE organization o - SET count_transfers_in_progress = COALESCE(sub.total_transfer_count, 0) - FROM ( - SELECT - org.organization_id, - COUNT(DISTINCT t.transfer_id) AS total_transfer_count - FROM - organization org - LEFT JOIN transfer t ON org.organization_id = t.from_organization_id - OR org.organization_id = t.to_organization_id - WHERE - t.current_status_id IN (3, 4) - GROUP BY - org.organization_id - ) sub - WHERE - o.organization_id = sub.organization_id; - """ - ) - - -def downgrade() -> None: - # Drop the trigger - op.execute( - "DROP TRIGGER IF EXISTS update_count_transfers_in_progress_trigger ON transfer;" - ) - # Drop the trigger function - op.execute("DROP FUNCTION IF EXISTS update_count_transfers_in_progress();") diff --git a/backend/lcfs/db/migrations/versions/2025-01-03-23-31_e883ad1f0f60.py b/backend/lcfs/db/migrations/versions/2025-01-03-23-31_e883ad1f0f60.py deleted file mode 100644 index eab360311..000000000 --- a/backend/lcfs/db/migrations/versions/2025-01-03-23-31_e883ad1f0f60.py +++ /dev/null @@ -1,67 +0,0 @@ -"""Rename Reassessed - -Revision ID: e883ad1f0f60 -Revises: 9329e38396e1 -Create Date: 2025-01-03 23:31:19.098618 - -""" - -import sqlalchemy as sa -from alembic import op -from alembic_postgresql_enum import TableReference - -# revision identifiers, used by Alembic. -revision = "e883ad1f0f60" -down_revision = "9329e38396e1" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.sync_enum_values( - "public", - "compliancereportstatusenum", - [ - "Draft", - "Submitted", - "Recommended_by_analyst", - "Recommended_by_manager", - "Assessed", - "Reassessed", - ], - [ - TableReference( - table_schema="public", - table_name="compliance_report_status", - column_name="status", - ) - ], - enum_values_to_rename=[("ReAssessed", "Reassessed")], - ) - # ### end Alembic commands ### - - -def downgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.sync_enum_values( - "public", - "compliancereportstatusenum", - [ - "Draft", - "Submitted", - "Recommended_by_analyst", - "Recommended_by_manager", - "Assessed", - "ReAssessed", - ], - [ - TableReference( - table_schema="public", - table_name="compliance_report_status", - column_name="status", - ) - ], - enum_values_to_rename=[("Reassessed", "ReAssessed")], - ) - # ### end Alembic commands ### diff --git a/backend/lcfs/db/migrations/versions/2025-01-04-13-24_bfa7bbb1eea3.py b/backend/lcfs/db/migrations/versions/2025-01-04-13-24_bfa7bbb1eea3.py deleted file mode 100644 index 1ce35a7a0..000000000 --- a/backend/lcfs/db/migrations/versions/2025-01-04-13-24_bfa7bbb1eea3.py +++ /dev/null @@ -1,37 +0,0 @@ -"""Update fuel type name - -Revision ID: bfa7bbb1eea3 -Revises: 9329e38396e1 -Create Date: 2025-01-03 13:24:19.525006 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "bfa7bbb1eea3" -down_revision = "e883ad1f0f60" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # Update fuel type name - op.execute(""" - UPDATE fuel_type - SET fuel_type = 'Other diesel fuel', - provision_1_id = 3 -- Change from prescribed (1) to default (3) - WHERE fuel_type = 'Other diesel'; - """) - - -def downgrade() -> None: - # Revert fuel type name update - op.execute(""" - UPDATE fuel_type - SET fuel_type = 'Other diesel', - provision_1_id = 1 -- Change from default (3) to prescribed (1) - WHERE fuel_type = 'Other diesel fuel'; - """) - diff --git a/backend/lcfs/db/migrations/versions/2025-01-06-19-01_94306eca5261.py b/backend/lcfs/db/migrations/versions/2025-01-06-19-01_94306eca5261.py deleted file mode 100644 index 4f9a65214..000000000 --- a/backend/lcfs/db/migrations/versions/2025-01-06-19-01_94306eca5261.py +++ /dev/null @@ -1,125 +0,0 @@ -""" -Add is_legacy to Provisions and insert data - -Revision ID: 94306eca5261 -Revises: ca7200152130 -Create Date: 2025-01-06 19:01:53.418638 -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "94306eca5261" -down_revision = "ca7200152130" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # 1) Add the new column - op.add_column( - "provision_of_the_act", - sa.Column( - "is_legacy", - sa.Boolean(), - server_default=sa.text("FALSE"), - nullable=False, - comment="Indicates if the provision is legacy and should not be used for new reports", - ), - ) - - # 2) Insert or update data to populate is_legacy, etc. - # For demonstration, we'll use bulk_insert here. If your table already - # has data, you might prefer an UPDATE or a combination of both. - provision_of_the_act = sa.Table( - "provision_of_the_act", - sa.MetaData(), - sa.Column("provision_of_the_act_id", sa.Integer, primary_key=True), - sa.Column("name", sa.String), - sa.Column("description", sa.String), - sa.Column("create_user", sa.String), - sa.Column("update_user", sa.String), - sa.Column("display_order", sa.Integer), - sa.Column("effective_date", sa.Date), - sa.Column("effective_status", sa.Boolean), - sa.Column("expiration_date", sa.Date), - sa.Column("is_legacy", sa.Boolean), - ) - - op.bulk_insert( - provision_of_the_act, - [ - { - "name": "Prescribed carbon intensity - Section 6 (5) (a)", - "description": "Prescribed carbon intensity - Section 6 (5) (a)", - "create_user": "no_user", - "update_user": "no_user", - "display_order": None, - "effective_date": None, - "effective_status": True, - "expiration_date": None, - "is_legacy": True, - }, - { - "name": "Prescribed carbon intensity - Section 6 (5) (b)", - "description": "Prescribed carbon intensity - Section 6 (5) (b)", - "create_user": "no_user", - "update_user": "no_user", - "display_order": None, - "effective_date": None, - "effective_status": True, - "expiration_date": None, - "is_legacy": True, - }, - { - "name": "Approved fuel code - Section 6 (5) (c)", - "description": "Approved fuel code - Section 6 (5) (c)", - "create_user": "no_user", - "update_user": "no_user", - "display_order": None, - "effective_date": None, - "effective_status": True, - "expiration_date": None, - "is_legacy": True, - }, - { - "name": "Default Carbon Intensity Value - Section 6 (5) (d) (i)", - "description": "Default Carbon Intensity Value - Section 6 (5) (d) (i)", - "create_user": "no_user", - "update_user": "no_user", - "display_order": None, - "effective_date": None, - "effective_status": True, - "expiration_date": None, - "is_legacy": True, - }, - { - "name": "GHGenius modelled - Section 6 (5) (d) (ii) (A)", - "description": "GHGenius modelled - Section 6 (5) (d) (ii) (A)", - "create_user": "no_user", - "update_user": "no_user", - "display_order": None, - "effective_date": None, - "effective_status": True, - "expiration_date": None, - "is_legacy": True, - }, - { - "name": "Alternative Method - Section 6 (5) (d) (ii) (B)", - "description": "Alternative Method - Section 6 (5) (d) (ii) (B)", - "create_user": "no_user", - "update_user": "no_user", - "display_order": None, - "effective_date": None, - "effective_status": True, - "expiration_date": None, - "is_legacy": True, - }, - ], - ) - - -def downgrade() -> None: - # Remove is_legacy column. (Data removal is optional or up to you.) - op.drop_column("provision_of_the_act", "is_legacy") diff --git a/backend/lcfs/db/migrations/versions/2025-01-06-22-09_fa98709e7952.py b/backend/lcfs/db/migrations/versions/2025-01-06-22-09_fa98709e7952.py deleted file mode 100644 index 2b815de67..000000000 --- a/backend/lcfs/db/migrations/versions/2025-01-06-22-09_fa98709e7952.py +++ /dev/null @@ -1,177 +0,0 @@ -"""Add legacy fuel types - -Revision ID: fa98709e7952 -Revises: 94306eca5261 -Create Date: 2025-01-06 22:09:52.936619 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "fa98709e7952" -down_revision = "94306eca5261" -branch_labels = None -depends_on = None - - -def upgrade(): - op.execute( - """ - INSERT INTO fuel_type ( - fuel_type, - fossil_derived, - other_uses_fossil_derived, - default_carbon_intensity, - units, - unrecognized, - create_user, - update_user, - is_legacy - ) - VALUES - -- 1) Natural gas-based gasoline - ( - 'Natural gas-based gasoline', - FALSE, - TRUE, - 90.07, - 'Litres', - FALSE, - 'no_user', - 'no_user', - TRUE - ), - -- 2) Petroleum-based diesel - ( - 'Petroleum-based diesel', - FALSE, - TRUE, - 94.76, - 'Litres', - FALSE, - 'no_user', - 'no_user', - TRUE - ), - -- 3) Petroleum-based gasoline - ( - 'Petroleum-based gasoline', - FALSE, - TRUE, - 88.14, - 'Litres', - FALSE, - 'no_user', - 'no_user', - TRUE - ); - """ - ) - - op.execute( - """ - INSERT INTO energy_density ( - fuel_type_id, - density, - uom_id, - create_user, - update_user - ) - SELECT - ft.fuel_type_id, - CASE - WHEN ft.fuel_type = 'Natural gas-based gasoline' THEN 34.69 - WHEN ft.fuel_type = 'Petroleum-based diesel' THEN 38.65 - WHEN ft.fuel_type = 'Petroleum-based gasoline' THEN 34.69 - END AS density, - 1 AS uom_id, - 'no_user' AS create_user, - 'no_user' AS update_user - FROM fuel_type ft - WHERE ft.fuel_type IN ( - 'Natural gas-based gasoline', - 'Petroleum-based diesel', - 'Petroleum-based gasoline' - ); - """ - ) - - op.execute( - """ - INSERT INTO energy_effectiveness_ratio ( - fuel_category_id, - fuel_type_id, - end_use_type_id, - ratio, - create_user, - update_user, - effective_date, - effective_status, - expiration_date - ) - SELECT - CASE - WHEN ft.fuel_type = 'Petroleum-based diesel' THEN 2 - ELSE 1 - END AS fuel_category_id, - ft.fuel_type_id, - NULL AS end_use_type_id, - 1.0 AS ratio, - 'no_user' AS create_user, - 'no_user' AS update_user, - CURRENT_DATE AS effective_date, - TRUE AS effective_status, - NULL AS expiration_date - FROM fuel_type ft - WHERE ft.fuel_type IN ( - 'Natural gas-based gasoline', - 'Petroleum-based diesel', - 'Petroleum-based gasoline' - ); - """ - ) - - -def downgrade(): - op.execute( - """ - DELETE FROM energy_effectiveness_ratio - WHERE fuel_type_id IN ( - SELECT fuel_type_id - FROM fuel_type - WHERE fuel_type IN ( - 'Natural gas-based gasoline', - 'Petroleum-based diesel', - 'Petroleum-based gasoline' - ) - ); - """ - ) - - op.execute( - """ - DELETE FROM energy_density - WHERE fuel_type_id IN ( - SELECT fuel_type_id - FROM fuel_type - WHERE fuel_type IN ( - 'Natural gas-based gasoline', - 'Petroleum-based diesel', - 'Petroleum-based gasoline' - ) - ); - """ - ) - - op.execute( - """ - DELETE FROM fuel_type - WHERE fuel_type IN ( - 'Natural gas-based gasoline', - 'Petroleum-based diesel', - 'Petroleum-based gasoline' - ); - """ - ) diff --git a/backend/lcfs/db/migrations/versions/2025-01-10-00-35_10863452ccd2.py b/backend/lcfs/db/migrations/versions/2025-01-10-00-35_10863452ccd2.py deleted file mode 100644 index b1cdca64a..000000000 --- a/backend/lcfs/db/migrations/versions/2025-01-10-00-35_10863452ccd2.py +++ /dev/null @@ -1,68 +0,0 @@ -"""mv for compliance report count for the dashboard - -Revision ID: 10863452ccd2 -Revises: 94306eca5261 -Create Date: 2025-01-10 00:35:24.596718 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "10863452ccd2" -down_revision = "fa98709e7952" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - op.execute( - """ - CREATE MATERIALIZED VIEW mv_compliance_report_count AS - SELECT - CASE current_status_id - WHEN 2 THEN 'Submitted' - WHEN 3 THEN 'Recommended by Analysts' - WHEN 4 THEN 'Recommended by Manager' - END as status, - COUNT(*) as count - FROM compliance_report - WHERE current_status_id IN (2,3,4) - GROUP BY current_status_id; - """ - ) - - op.execute( - """ - CREATE UNIQUE INDEX mv_compliance_report_count_idx - ON mv_compliance_report_count (status); - """ - ) - - op.execute( - """ - CREATE OR REPLACE FUNCTION refresh_mv_compliance_report_count() - RETURNS TRIGGER AS $$ - BEGIN - REFRESH MATERIALIZED VIEW CONCURRENTLY mv_compliance_report_count; - RETURN NULL; - END; - $$ LANGUAGE plpgsql; - """ - ) - - op.execute( - """ - CREATE TRIGGER refresh_mv_compliance_report_count_after_change - AFTER INSERT OR UPDATE OR DELETE ON compliance_report - FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_compliance_report_count(); - """ - ) - - -def downgrade() -> None: - op.execute( - "DROP TRIGGER IF EXISTS refresh_mv_compliance_report_count_after_change ON compliance_report;") - op.execute("DROP FUNCTION IF EXISTS refresh_mv_compliance_report_count();") - op.execute("DROP MATERIALIZED VIEW IF EXISTS mv_compliance_report_count;") diff --git a/backend/lcfs/db/migrations/versions/2025-01-10-13-39_d25e7c47659e.py b/backend/lcfs/db/migrations/versions/2025-01-10-13-39_d25e7c47659e.py deleted file mode 100644 index 839943fc0..000000000 --- a/backend/lcfs/db/migrations/versions/2025-01-10-13-39_d25e7c47659e.py +++ /dev/null @@ -1,129 +0,0 @@ -"""mv update on org balances - -Revision ID: d25e7c47659e -Revises: fa98709e7952 -Create Date: 2025-01-10 13:39:31.688471 -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "d25e7c47659e" -down_revision = "10863452ccd2" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # Create or replace the function with updated logic: - # 1) total_balance now sums: - # - All compliance_units from 'Adjustment' - # - Negative compliance_units from 'Reserved' - # 2) reserved_balance sums only negative compliance_units from 'Reserved' - op.execute( - """ - CREATE OR REPLACE FUNCTION update_organization_balance() - RETURNS TRIGGER AS $$ - DECLARE - new_total_balance BIGINT; - new_reserved_balance BIGINT; - org_id INT := COALESCE(NEW.organization_id, OLD.organization_id); - BEGIN - -- Calculate new total_balance: - -- adjustments + negative reserved units - SELECT COALESCE( - SUM( - CASE - WHEN transaction_action = 'Adjustment' THEN compliance_units - WHEN transaction_action = 'Reserved' AND compliance_units < 0 THEN compliance_units - ELSE 0 - END - ), - 0 - ) - INTO new_total_balance - FROM "transaction" - WHERE organization_id = org_id; - - -- Calculate new reserved_balance from negative compliance_units - SELECT COALESCE(SUM(compliance_units), 0) - INTO new_reserved_balance - FROM "transaction" - WHERE organization_id = org_id - AND transaction_action = 'Reserved' - AND compliance_units < 0; - - UPDATE organization - SET total_balance = new_total_balance, - reserved_balance = new_reserved_balance - WHERE organization_id = org_id; - - RETURN NEW; - END; - $$ LANGUAGE plpgsql; - """ - ) - - op.execute( - """ - DROP TRIGGER IF EXISTS update_organization_balance_trigger ON "transaction"; - """ - ) - op.execute( - """ - CREATE TRIGGER update_organization_balance_trigger - AFTER INSERT OR UPDATE OR DELETE ON "transaction" - FOR EACH ROW EXECUTE FUNCTION update_organization_balance(); - """ - ) - - -def downgrade() -> None: - # Revert to the original logic: - # 1) total_balance sums only 'Adjustment' - # 2) reserved_balance sums all (positive and negative) 'Reserved' - op.execute( - """ - CREATE OR REPLACE FUNCTION update_organization_balance() - RETURNS TRIGGER AS $$ - DECLARE - new_total_balance BIGINT; - new_reserved_balance BIGINT; - org_id INT := COALESCE(NEW.organization_id, OLD.organization_id); - BEGIN - SELECT COALESCE(SUM(compliance_units), 0) - INTO new_total_balance - FROM "transaction" - WHERE organization_id = org_id - AND transaction_action = 'Adjustment'; - - SELECT COALESCE(SUM(compliance_units), 0) - INTO new_reserved_balance - FROM "transaction" - WHERE organization_id = org_id - AND transaction_action = 'Reserved'; - - UPDATE organization - SET total_balance = new_total_balance, - reserved_balance = new_reserved_balance - WHERE organization_id = org_id; - - RETURN NEW; - END; - $$ LANGUAGE plpgsql; - """ - ) - - op.execute( - """ - DROP TRIGGER IF EXISTS update_organization_balance_trigger ON "transaction"; - """ - ) - op.execute( - """ - CREATE TRIGGER update_organization_balance_trigger - AFTER INSERT OR UPDATE OR DELETE ON "transaction" - FOR EACH ROW EXECUTE FUNCTION update_organization_balance(); - """ - ) diff --git a/backend/lcfs/db/migrations/versions/2025-01-13-22-13_f78e53370ed2.py b/backend/lcfs/db/migrations/versions/2025-01-13-22-13_f78e53370ed2.py deleted file mode 100644 index f97aa17c6..000000000 --- a/backend/lcfs/db/migrations/versions/2025-01-13-22-13_f78e53370ed2.py +++ /dev/null @@ -1,238 +0,0 @@ -"""Add CR to Transaction Aggregate - -Revision ID: f78e53370ed2 -Revises: d25e7c47659e -Create Date: 2025-01-13 22:13:48.610890 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "f78e53370ed2" -down_revision = "d25e7c47659e" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - op.execute("DROP MATERIALIZED VIEW mv_transaction_aggregate;") - op.execute( - """ - CREATE MATERIALIZED VIEW mv_transaction_aggregate AS - SELECT - t.transfer_id AS transaction_id, - 'Transfer' AS transaction_type, - NULL AS description, - org_from.organization_id AS from_organization_id, - org_from.name AS from_organization, - org_to.organization_id AS to_organization_id, - org_to.name AS to_organization, - t.quantity, - t.price_per_unit, - ts.status::text AS status, - NULL AS compliance_period, - t.from_org_comment AS COMMENT, - tc.category, - ( - SELECT - th.create_date - FROM - transfer_history th - WHERE - th.transfer_id = t.transfer_id - AND th.transfer_status_id = 6) AS recorded_date, NULL AS approved_date, t.transaction_effective_date, t.update_date, t.create_date - FROM - transfer t - JOIN organization org_from ON t.from_organization_id = org_from.organization_id - JOIN organization org_to ON t.to_organization_id = org_to.organization_id - JOIN transfer_status ts ON t.current_status_id = ts.transfer_status_id - LEFT JOIN transfer_category tc ON t.transfer_category_id = tc.transfer_category_id - UNION ALL - SELECT - ia.initiative_agreement_id AS transaction_id, - 'InitiativeAgreement' AS transaction_type, - NULL AS description, - NULL AS from_organization_id, - NULL AS from_organization, - org.organization_id AS to_organization_id, - org.name AS to_organization, - ia.compliance_units AS quantity, - NULL AS price_per_unit, - ias.status::text AS status, - NULL AS compliance_period, - ia.gov_comment AS COMMENT, - NULL AS category, - NULL AS recorded_date, - ( - SELECT - iah.create_date - FROM - initiative_agreement_history iah - WHERE - iah.initiative_agreement_id = ia.initiative_agreement_id - AND iah.initiative_agreement_status_id = 3) AS approved_date, ia.transaction_effective_date, ia.update_date, ia.create_date - FROM - initiative_agreement ia - JOIN organization org ON ia.to_organization_id = org.organization_id - JOIN initiative_agreement_status ias ON ia.current_status_id = ias.initiative_agreement_status_id - UNION ALL - SELECT - aa.admin_adjustment_id AS transaction_id, - 'AdminAdjustment' AS transaction_type, - NULL AS description, - NULL AS from_organization_id, - NULL AS from_organization, - org.organization_id AS to_organization_id, - org.name AS to_organization, - aa.compliance_units AS quantity, - NULL AS price_per_unit, - aas.status::text AS status, - NULL AS compliance_period, - aa.gov_comment AS COMMENT, - NULL AS category, - NULL AS recorded_date, - ( - SELECT - aah.create_date - FROM - admin_adjustment_history aah - WHERE - aah.admin_adjustment_id = aa.admin_adjustment_id - AND aah.admin_adjustment_status_id = 3) AS approved_date, aa.transaction_effective_date, aa.update_date, aa.create_date - FROM - admin_adjustment aa - JOIN organization org ON aa.to_organization_id = org.organization_id - JOIN admin_adjustment_status aas ON aa.current_status_id = aas.admin_adjustment_status_id - UNION ALL - SELECT - cr.compliance_report_id AS transaction_id, - 'ComplianceReport' AS transaction_type, - cr.nickname AS description, - NULL AS from_organization_id, - NULL AS from_organization, - org.organization_id AS to_organization_id, - org.name AS to_organization, - tr.compliance_units AS quantity, - NULL AS price_per_unit, - crs.status::text AS status, - cp.description AS compliance_period, - NULL AS COMMENT, - NULL AS category, - NULL AS recorded_date, - NULL AS approved_date, - NULL AS transaction_effective_date, - cr.update_date, - cr.create_date - FROM - compliance_report cr - JOIN organization org ON cr.organization_id = org.organization_id - JOIN compliance_report_status crs ON cr.current_status_id = crs.compliance_report_status_id - JOIN compliance_period cp ON cr.compliance_period_id = cp.compliance_period_id - JOIN TRANSACTION tr ON cr.transaction_id = tr.transaction_id - AND cr.transaction_id IS NOT NULL; - """ - ) - - # Create unique index on mv_transaction_aggregate - op.execute( - """ - CREATE UNIQUE INDEX mv_transaction_aggregate_unique_idx ON mv_transaction_aggregate (transaction_id, description, transaction_type); - """ - ) - - -def downgrade() -> None: - op.execute("DROP MATERIALIZED VIEW mv_transaction_aggregate;") - op.execute( - """ - CREATE MATERIALIZED VIEW mv_transaction_aggregate AS - SELECT - t.transfer_id AS transaction_id, - 'Transfer' AS transaction_type, - org_from.organization_id AS from_organization_id, - org_from.name AS from_organization, - org_to.organization_id AS to_organization_id, - org_to.name AS to_organization, - t.quantity, - t.price_per_unit, - ts.status::text AS status, - NULL AS compliance_period, - t.from_org_comment AS comment, - tc.category, - ( - SELECT th.create_date - FROM transfer_history th - WHERE th.transfer_id = t.transfer_id AND th.transfer_status_id = 6 - ) AS recorded_date, - NULL AS approved_date, - t.transaction_effective_date, - t.update_date, - t.create_date - FROM transfer t - JOIN organization org_from ON t.from_organization_id = org_from.organization_id - JOIN organization org_to ON t.to_organization_id = org_to.organization_id - JOIN transfer_status ts ON t.current_status_id = ts.transfer_status_id - LEFT JOIN transfer_category tc ON t.transfer_category_id = tc.transfer_category_id - UNION ALL - SELECT - ia.initiative_agreement_id AS transaction_id, - 'InitiativeAgreement' AS transaction_type, - NULL AS from_organization_id, - NULL AS from_organization, - org.organization_id AS to_organization_id, - org.name AS to_organization, - ia.compliance_units AS quantity, - NULL AS price_per_unit, - ias.status::text AS status, - NULL AS compliance_period, - ia.gov_comment AS comment, - NULL AS category, - NULL AS recorded_date, - ( - SELECT iah.create_date - FROM initiative_agreement_history iah - WHERE iah.initiative_agreement_id = ia.initiative_agreement_id AND iah.initiative_agreement_status_id = 3 - ) AS approved_date, - ia.transaction_effective_date, - ia.update_date, - ia.create_date - FROM initiative_agreement ia - JOIN organization org ON ia.to_organization_id = org.organization_id - JOIN initiative_agreement_status ias ON ia.current_status_id = ias.initiative_agreement_status_id - UNION ALL - SELECT - aa.admin_adjustment_id AS transaction_id, - 'AdminAdjustment' AS transaction_type, - NULL AS from_organization_id, - NULL AS from_organization, - org.organization_id AS to_organization_id, - org.name AS to_organization, - aa.compliance_units AS quantity, - NULL AS price_per_unit, - aas.status::text AS status, - NULL AS compliance_period, - aa.gov_comment AS comment, - NULL AS category, - NULL AS recorded_date, - ( - SELECT aah.create_date - FROM admin_adjustment_history aah - WHERE aah.admin_adjustment_id = aa.admin_adjustment_id AND aah.admin_adjustment_status_id = 3 - ) AS approved_date, - aa.transaction_effective_date, - aa.update_date, - aa.create_date - FROM admin_adjustment aa - JOIN organization org ON aa.to_organization_id = org.organization_id - JOIN admin_adjustment_status aas ON aa.current_status_id = aas.admin_adjustment_status_id; - """ - ) - - # Create unique index on mv_transaction_aggregate - op.execute( - """ - CREATE UNIQUE INDEX mv_transaction_aggregate_unique_idx ON mv_transaction_aggregate (transaction_id, transaction_type); - """ - ) diff --git a/backend/lcfs/db/migrations/versions/2025-01-14-14-03_5163af6ba4a4.py b/backend/lcfs/db/migrations/versions/2025-01-14-14-03_5163af6ba4a4.py deleted file mode 100644 index 4b3841d7a..000000000 --- a/backend/lcfs/db/migrations/versions/2025-01-14-14-03_5163af6ba4a4.py +++ /dev/null @@ -1,70 +0,0 @@ -"""revert org display balance - - -Revision ID: 5163af6ba4a4 -Revises: f78e53370ed2 -Create Date: 2025-01-14 14:03:50.975682 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "5163af6ba4a4" -down_revision = "f78e53370ed2" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # Reapply the original logic for balances: - op.execute( - """ - CREATE OR REPLACE FUNCTION update_organization_balance() - RETURNS TRIGGER AS $$ - DECLARE - new_total_balance BIGINT; - new_reserved_balance BIGINT; - org_id INT := COALESCE(NEW.organization_id, OLD.organization_id); - BEGIN - SELECT COALESCE(SUM(compliance_units), 0) - INTO new_total_balance - FROM "transaction" - WHERE organization_id = org_id - AND transaction_action = 'Adjustment'; - - SELECT COALESCE(SUM(compliance_units), 0) - INTO new_reserved_balance - FROM "transaction" - WHERE organization_id = org_id - AND transaction_action = 'Reserved' - AND compliance_units < 0; - - UPDATE organization - SET total_balance = new_total_balance, - reserved_balance = new_reserved_balance - WHERE organization_id = org_id; - - RETURN NEW; - END; - $$ LANGUAGE plpgsql; - """ - ) - - op.execute( - """ - DROP TRIGGER IF EXISTS update_organization_balance_trigger ON "transaction"; - """ - ) - op.execute( - """ - CREATE TRIGGER update_organization_balance_trigger - AFTER INSERT OR UPDATE OR DELETE ON "transaction" - FOR EACH ROW EXECUTE FUNCTION update_organization_balance(); - """ - ) - - -def downgrade() -> None: - pass diff --git a/backend/lcfs/db/migrations/versions/2025-01-14-18-12_fe03799b4018.py b/backend/lcfs/db/migrations/versions/2025-01-14-18-12_fe03799b4018.py deleted file mode 100644 index 8afe58102..000000000 --- a/backend/lcfs/db/migrations/versions/2025-01-14-18-12_fe03799b4018.py +++ /dev/null @@ -1,61 +0,0 @@ -"""Update other_uses_fossil_derived in fuel_type - -Revision ID: fe03799b4018 -Revises: fa98709e7952 -Create Date: 2025-01-14 18:12:43.683691 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "fe03799b4018" -down_revision = "5163af6ba4a4" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # Set other_uses_fossil_derived to false - op.execute(""" - UPDATE fuel_type - SET other_uses_fossil_derived = false - WHERE fuel_type IN ( - 'CNG', 'Electricity', 'Hydrogen', 'LNG', 'Propane', - 'Natural gas-based gasoline', 'Petroleum-based diesel', - 'Petroleum-based gasoline' - ) - """) - - # Set other_uses_fossil_derived to true - op.execute(""" - UPDATE fuel_type - SET other_uses_fossil_derived = true - WHERE fuel_type IN ( - 'Alternative jet fuel', 'Biodiesel', 'Ethanol', 'HDRD', - 'Other diesel fuel', 'Renewable gasoline', 'Renewable naphtha' - ) - """) - -def downgrade() -> None: - # Revert `other_uses_fossil_derived` to original values for false - op.execute(""" - UPDATE fuel_type - SET other_uses_fossil_derived = true - WHERE fuel_type IN ( - 'CNG', 'Electricity', 'Hydrogen', 'LNG', 'Propane', - 'Natural gas-based gasoline', 'Petroleum-based diesel', - 'Petroleum-based gasoline' - ) - """) - - # Revert `other_uses_fossil_derived` to original values for true - op.execute(""" - UPDATE fuel_type - SET other_uses_fossil_derived = false - WHERE fuel_type IN ( - 'Alternative jet fuel', 'Biodiesel', 'Ethanol', 'HDRD', - 'Other diesel fuel', 'Renewable gasoline', 'Renewable naphtha' - ) - """) diff --git a/backend/lcfs/db/migrations/versions/2025-01-14-23-47_8119d12538df.py b/backend/lcfs/db/migrations/versions/2025-01-14-23-47_8119d12538df.py deleted file mode 100644 index 2a5a46a06..000000000 --- a/backend/lcfs/db/migrations/versions/2025-01-14-23-47_8119d12538df.py +++ /dev/null @@ -1,75 +0,0 @@ -"""mv for fuel code count - -Revision ID: 8119d12538df -Revises: d25e7c47659e -Create Date: 2025-01-14 23:47:28.504150 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "8119d12538df" -down_revision = "fe03799b4018" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.execute( - """ - CREATE MATERIALIZED VIEW mv_fuel_code_count AS - SELECT - CASE fuel_status_id - WHEN 1 THEN 'Draft' - END as status, - COUNT(*) as count - FROM fuel_code - WHERE fuel_status_id = 1 - GROUP BY fuel_status_id; - """ - ) - - op.execute( - """ - CREATE UNIQUE INDEX mv_fuel_code_count_idx - ON mv_fuel_code_count (status); - """ - ) - - op.execute( - """ - CREATE OR REPLACE FUNCTION refresh_mv_fuel_code_count() - RETURNS TRIGGER AS $$ - BEGIN - REFRESH MATERIALIZED VIEW CONCURRENTLY mv_fuel_code_count; - RETURN NULL; - END; - $$ LANGUAGE plpgsql; - """ - ) - - op.execute( - """ - CREATE TRIGGER refresh_mv_fuel_code_count_after_change - AFTER INSERT OR UPDATE OR DELETE ON fuel_code - FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_fuel_code_count(); - """ - ) - - # Refresh the materialized view to include existing fuel codes - op.execute( - "REFRESH MATERIALIZED VIEW CONCURRENTLY mv_fuel_code_count;" - ) - # ### end Alembic commands ### - - -def downgrade() -> None: - # ### commands auto generated by Alembic - please adjust! ### - op.execute( - "DROP TRIGGER IF EXISTS refresh_mv_fuel_code_count_after_change ON fuel_code;") - op.execute("DROP FUNCTION IF EXISTS refresh_mv_fuel_code_count();") - op.execute("DROP MATERIALIZED VIEW IF EXISTS mv_fuel_code_count;") - # ### end Alembic commands ### diff --git a/backend/lcfs/db/migrations/versions/2025-01-15-22-48_5bc0ef48739a.py b/backend/lcfs/db/migrations/versions/2025-01-15-22-48_5bc0ef48739a.py deleted file mode 100644 index 5046cf1f2..000000000 --- a/backend/lcfs/db/migrations/versions/2025-01-15-22-48_5bc0ef48739a.py +++ /dev/null @@ -1,44 +0,0 @@ -"""add truck and marine transport mode - -Revision ID: 5bc0ef48739a -Revises: f78e53370ed2 -Create Date: 2025-01-15 22:48:43.582069 - -""" - -import sqlalchemy as sa -from alembic import op -from datetime import datetime - -# revision identifiers, used by Alembic. -revision = "5bc0ef48739a" -down_revision = "8119d12538df" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - current_time = datetime.now() - - # Insert Truck and Marine transport modes - op.execute( - """ - INSERT INTO transport_mode (transport_mode, create_date, update_date, create_user, update_user) - VALUES - ('Truck', '{}', '{}', 'no_user', 'no_user'), - ('Marine', '{}', '{}', 'no_user', 'no_user') - - """.format( - current_time, current_time, current_time, current_time - ) - ) - - -def downgrade() -> None: - # Remove Truck and Marine transport modes - op.execute( - """ - DELETE FROM transport_mode - WHERE transport_mode IN ('Truck', 'Marine') - """ - ) diff --git a/backend/lcfs/db/migrations/versions/2025-01-16-19-35_998929392c8b.py b/backend/lcfs/db/migrations/versions/2025-01-16-19-35_998929392c8b.py deleted file mode 100644 index 2bb1c4cc3..000000000 --- a/backend/lcfs/db/migrations/versions/2025-01-16-19-35_998929392c8b.py +++ /dev/null @@ -1,51 +0,0 @@ -"""add marine end use - -Revision ID: 998929392c8b -Revises: 5bc0ef48739a -Create Date: 2025-01-07 19:35:00.064999 - -""" - -import sqlalchemy as sa -from alembic import op - -# revision identifiers, used by Alembic. -revision = "998929392c8b" -down_revision = "5bc0ef48739a" -branch_labels = None -depends_on = None - - -def upgrade() -> None: - op.execute( - """ - INSERT INTO end_use_type (end_use_type_id, type, intended_use) - VALUES (25, 'Marine', TRUE) - ON CONFLICT (end_use_type_id) DO NOTHING; - """ - ) - # Energy Effectiveness Ratios - op.execute( - """ - INSERT INTO energy_effectiveness_ratio ( - eer_id, fuel_category_id, fuel_type_id, end_use_type_id, ratio, effective_status - ) - VALUES (44, 2, 3, 25, 2.5, TRUE) - ON CONFLICT (eer_id) DO NOTHING; - """ - ) - - -def downgrade() -> None: - op.execute( - """ - DELETE FROM energy_effectiveness_ratio - WHERE eer_id = 44; - """ - ) - op.execute( - """ - DELETE FROM end_use_type - WHERE end_use_type_id = 25; - """ - ) diff --git a/backend/lcfs/db/migrations/versions/2024-11-27-17-35_a2240b2b5629.py b/backend/lcfs/db/migrations/versions/2025-01-20-14-35_ed3b4d40b324.py similarity index 98% rename from backend/lcfs/db/migrations/versions/2024-11-27-17-35_a2240b2b5629.py rename to backend/lcfs/db/migrations/versions/2025-01-20-14-35_ed3b4d40b324.py index e7e768fa3..cd316578f 100644 --- a/backend/lcfs/db/migrations/versions/2024-11-27-17-35_a2240b2b5629.py +++ b/backend/lcfs/db/migrations/versions/2025-01-20-14-35_ed3b4d40b324.py @@ -1,8 +1,8 @@ -"""initial migration +"""Initial Migration: All base models and enums -Revision ID: a2240b2b5629 +Revision ID: ed3b4d40b324 Revises: -Create Date: 2024-11-27 17:35:34.810640 +Create Date: 2025-01-20 14:35:28.309082 """ @@ -11,7 +11,7 @@ from sqlalchemy.dialects import postgresql # revision identifiers, used by Alembic. -revision = "a2240b2b5629" +revision = "ed3b4d40b324" down_revision = None branch_labels = None depends_on = None @@ -52,15 +52,6 @@ def upgrade() -> None: sa.Enum( "Adjustment", "Reserved", "Released", name="transaction_action_enum" ).create(op.get_bind()) - sa.Enum( - "TRANSFER_PARTNER_UPDATE", - "TRANSFER_DIRECTOR_REVIEW", - "INITIATIVE_APPROVED", - "INITIATIVE_DA_REQUEST", - "SUPPLEMENTAL_REQUESTED", - "DIRECTOR_ASSESSMENT", - name="notification_type_enum", - ).create(op.get_bind()) sa.Enum( "fuel_supplier", "electricity_supplier", @@ -101,7 +92,7 @@ def upgrade() -> None: "Recommended_by_analyst", "Recommended_by_manager", "Assessed", - "ReAssessed", + "Reassessed", name="compliancereportstatusenum", ).create(op.get_bind()) sa.Enum("ANNUAL", "QUARTERLY", name="reportingfrequency").create(op.get_bind()) @@ -408,7 +399,7 @@ def upgrade() -> None: "Recommended_by_analyst", "Recommended_by_manager", "Assessed", - "ReAssessed", + "Reassessed", name="compliancereportstatusenum", create_type=False, ), @@ -492,7 +483,6 @@ def upgrade() -> None: comment="The user who last updated this record in the database.", ), sa.PrimaryKeyConstraint("document_id", name=op.f("pk_document")), - sa.UniqueConstraint("document_id", name=op.f("uq_document_document_id")), comment="Main document table for storing base document information", ) op.create_table( @@ -709,7 +699,13 @@ def upgrade() -> None: "description", sa.Text(), nullable=True, - comment="Description of the fuel categor", + comment="Description of the fuel category", + ), + sa.Column( + "default_carbon_intensity", + sa.Numeric(precision=10, scale=2), + nullable=False, + comment="Default carbon intensity of the fuel category", ), sa.Column( "create_date", @@ -1035,9 +1031,6 @@ def upgrade() -> None: sa.PrimaryKeyConstraint( "internal_comment_id", name=op.f("pk_internal_comment") ), - sa.UniqueConstraint( - "internal_comment_id", name=op.f("uq_internal_comment_internal_comment_id") - ), comment="Stores internal comments with scope and related metadata.", ) op.create_table( @@ -1132,20 +1125,7 @@ def upgrade() -> None: sa.Column( "notification_type_id", sa.Integer(), autoincrement=True, nullable=False ), - sa.Column( - "name", - postgresql.ENUM( - "TRANSFER_PARTNER_UPDATE", - "TRANSFER_DIRECTOR_REVIEW", - "INITIATIVE_APPROVED", - "INITIATIVE_DA_REQUEST", - "SUPPLEMENTAL_REQUESTED", - "DIRECTOR_ASSESSMENT", - name="notification_type_enum", - create_type=False, - ), - nullable=False, - ), + sa.Column("name", sa.String(length=255), nullable=False), sa.Column("description", sa.Text(), nullable=True), sa.Column("email_content", sa.Text(), nullable=True), sa.Column( @@ -1463,6 +1443,13 @@ def upgrade() -> None: nullable=False, comment="Description of the provision. This is the displayed name. e.g. Prescribed Carbon Intensity, Approved Fuel Code.", ), + sa.Column( + "is_legacy", + sa.Boolean(), + server_default=sa.text("FALSE"), + nullable=False, + comment="Indicates if the fuel type is legacy and should not be used for new reports", + ), sa.Column( "create_date", sa.TIMESTAMP(timezone=True), @@ -1655,10 +1642,6 @@ def upgrade() -> None: sa.PrimaryKeyConstraint( "transfer_category_id", name=op.f("pk_transfer_category") ), - sa.UniqueConstraint( - "transfer_category_id", - name=op.f("uq_transfer_category_transfer_category_id"), - ), comment="Transfer Category", ) op.create_table( @@ -1913,6 +1896,13 @@ def upgrade() -> None: nullable=False, comment="Indicates if the fuel type is unrecognized", ), + sa.Column( + "is_legacy", + sa.Boolean(), + server_default=sa.text("FALSE"), + nullable=False, + comment="Indicates if the fuel type is legacy and should not be used for new reports", + ), sa.Column( "create_date", sa.TIMESTAMP(timezone=True), @@ -2193,6 +2183,11 @@ def upgrade() -> None: sa.PrimaryKeyConstraint( "target_carbon_intensity_id", name=op.f("pk_target_carbon_intensity") ), + sa.UniqueConstraint( + "compliance_period_id", + "fuel_category_id", + name="uq_target_carbon_intensity_compliance_fuel", + ), comment="Target carbon intensity values for various fuel categories", ) op.create_table( @@ -2695,9 +2690,6 @@ def upgrade() -> None: name=op.f("fk_transaction_organization_id_organization"), ), sa.PrimaryKeyConstraint("transaction_id", name=op.f("pk_transaction")), - sa.UniqueConstraint( - "transaction_id", name=op.f("uq_transaction_transaction_id") - ), comment="Contains a list of all of the government to organization and Organization to Organization transaction.", ) op.create_table( @@ -2881,9 +2873,6 @@ def upgrade() -> None: sa.PrimaryKeyConstraint( "admin_adjustment_id", name=op.f("pk_admin_adjustment") ), - sa.UniqueConstraint( - "admin_adjustment_id", name=op.f("uq_admin_adjustment_admin_adjustment_id") - ), comment="Goverment to organization compliance units admin_adjustment", ) op.create_table( @@ -2925,6 +2914,12 @@ def upgrade() -> None: nullable=False, comment="UUID that groups all versions of a compliance report", ), + sa.Column( + "legacy_id", + sa.Integer(), + nullable=True, + comment="ID from TFRS if this is a transferred application, NULL otherwise", + ), sa.Column( "version", sa.Integer(), @@ -3247,10 +3242,6 @@ def upgrade() -> None: sa.PrimaryKeyConstraint( "initiative_agreement_id", name=op.f("pk_initiative_agreement") ), - sa.UniqueConstraint( - "initiative_agreement_id", - name=op.f("uq_initiative_agreement_initiative_agreement_id"), - ), comment="Goverment to organization compliance units initiative agreement", ) op.create_table( @@ -3333,11 +3324,13 @@ def upgrade() -> None: sa.Column("is_warning", sa.Boolean(), nullable=True), sa.Column("is_error", sa.Boolean(), nullable=True), sa.Column("is_archived", sa.Boolean(), nullable=True), + sa.Column("type", sa.Text(), nullable=False), sa.Column("message", sa.Text(), nullable=False), sa.Column("related_organization_id", sa.Integer(), nullable=True), sa.Column("origin_user_profile_id", sa.Integer(), nullable=True), sa.Column("related_user_profile_id", sa.Integer(), nullable=True), sa.Column("notification_type_id", sa.Integer(), nullable=True), + sa.Column("related_transaction_id", sa.Text(), nullable=False), sa.Column( "create_date", sa.TIMESTAMP(timezone=True), @@ -3527,7 +3520,6 @@ def upgrade() -> None: name=op.f("fk_transfer_transfer_category_id_transfer_category"), ), sa.PrimaryKeyConstraint("transfer_id", name=op.f("pk_transfer")), - sa.UniqueConstraint("transfer_id", name=op.f("uq_transfer_transfer_id")), comment="Records of tranfer from Organization to Organization", ) op.create_table( @@ -3671,10 +3663,6 @@ def upgrade() -> None: sa.PrimaryKeyConstraint( "admin_adjustment_history_id", name=op.f("pk_admin_adjustment_history") ), - sa.UniqueConstraint( - "admin_adjustment_history_id", - name=op.f("uq_admin_adjustment_history_admin_adjustment_history_id"), - ), comment="History record for admin_adjustment status change.", ) op.create_table( @@ -4147,6 +4135,9 @@ def upgrade() -> None: sa.Column("line_11_fossil_derived_base_fuel_total", sa.Float(), nullable=False), sa.Column("line_21_non_compliance_penalty_payable", sa.Float(), nullable=False), sa.Column("total_non_compliance_penalty_payable", sa.Float(), nullable=False), + sa.Column("credits_offset_a", sa.Integer(), nullable=True), + sa.Column("credits_offset_b", sa.Integer(), nullable=True), + sa.Column("credits_offset_c", sa.Integer(), nullable=True), sa.Column( "create_date", sa.TIMESTAMP(timezone=True), @@ -4298,6 +4289,12 @@ def upgrade() -> None: nullable=True, comment="Any additional notes related to the equipment.", ), + sa.Column( + "organization_name", + sa.Text(), + nullable=True, + comment="External organization name.", + ), sa.Column( "create_date", sa.TIMESTAMP(timezone=True), @@ -4435,6 +4432,12 @@ def upgrade() -> None: nullable=True, comment="CI of fuel for the fuel supply", ), + sa.Column( + "uci", + sa.Numeric(precision=10, scale=2), + nullable=True, + comment="Additional Carbon Intensity", + ), sa.Column( "energy_density", sa.Numeric(precision=10, scale=2), @@ -4638,6 +4641,12 @@ def upgrade() -> None: nullable=True, comment="Energy Effectiveness Ratio", ), + sa.Column( + "uci", + sa.Numeric(precision=10, scale=2), + nullable=True, + comment="Additional Carbon Intensity", + ), sa.Column("energy", sa.BigInteger(), nullable=True, comment="Energy content"), sa.Column( "fuel_type_other", @@ -4847,12 +4856,6 @@ def upgrade() -> None: "initiative_agreement_history_id", name=op.f("pk_initiative_agreement_history"), ), - sa.UniqueConstraint( - "initiative_agreement_history_id", - name=op.f( - "uq_initiative_agreement_history_initiative_agreement_history_id" - ), - ), comment="History record for initiative agreement status change.", ) op.create_table( @@ -5469,7 +5472,7 @@ def downgrade() -> None: "Recommended_by_analyst", "Recommended_by_manager", "Assessed", - "ReAssessed", + "Reassessed", name="compliancereportstatusenum", ).drop(op.get_bind()) sa.Enum("Single port", "Dual port", name="ports_enum").drop(op.get_bind()) @@ -5506,15 +5509,6 @@ def downgrade() -> None: "utilities", name="org_type_enum", ).drop(op.get_bind()) - sa.Enum( - "TRANSFER_PARTNER_UPDATE", - "TRANSFER_DIRECTOR_REVIEW", - "INITIATIVE_APPROVED", - "INITIATIVE_DA_REQUEST", - "SUPPLEMENTAL_REQUESTED", - "DIRECTOR_ASSESSMENT", - name="notification_type_enum", - ).drop(op.get_bind()) sa.Enum("Adjustment", "Reserved", "Released", name="transaction_action_enum").drop( op.get_bind() ) diff --git a/backend/lcfs/db/migrations/versions/2025-01-20-14-37_f217cd32474b.py b/backend/lcfs/db/migrations/versions/2025-01-20-14-37_f217cd32474b.py new file mode 100644 index 000000000..93b4629ee --- /dev/null +++ b/backend/lcfs/db/migrations/versions/2025-01-20-14-37_f217cd32474b.py @@ -0,0 +1,1255 @@ +""" +Consolidated Migration: Materialized Views, Audit Logging, Updated Balances, and More + +Incorporates the original base migration (4038ff8d8c49, dated 2024-11-02) +plus follow-up migrations in chronological order: + +1) 9329e38396e1 (2024-12-30): update_count_transfers_in_progress() +2) 10863452ccd2 (2025-01-10): mv_compliance_report_count +3) d25e7c47659e (2025-01-10): update_organization_balance() changes (overridden later) +4) f78e53370ed2 (2025-01-13): Add CR to mv_transaction_aggregate +5) 5163af6ba4a4 (2025-01-14): Revert org display balance (final version of update_organization_balance()) +6) 8119d12538df (2025-01-14): mv_fuel_code_count + +Revision ID: f217cd32474b +Revises: ed3b4d40b324 +Create Date: 2025-01-20 14:37:57.157152 +""" + +from alembic import op +import sqlalchemy as sa +from sqlalchemy.dialects import postgresql + +# revision identifiers, used by Alembic. +revision = "f217cd32474b" +down_revision = "ed3b4d40b324" +branch_labels = None +depends_on = None + + +def upgrade(): + # ---------------------------------------- + # Part 1: Drop Existing Triggers, Functions, and Views + # ---------------------------------------- + drop_existing_triggers_functions_views() + + # ---------------------------------------- + # Part 2: Create Audit Log Functions and Triggers + # ---------------------------------------- + create_audit_log_functions_and_triggers() + + # ---------------------------------------- + # Part 3: Create Materialized Views and Triggers (Base) + # ---------------------------------------- + create_materialized_views_and_triggers() + + # ---------------------------------------- + # Part 4: Create/Update Organization Balance Function and Trigger (Final) + # (Supersedes older definitions by taking final logic from 5163af6ba4a4) + # ---------------------------------------- + create_update_organization_balance_function_and_trigger() + + # ---------------------------------------- + # Part 5 (2024-12-30, rev 9329e38396e1): add update_count_transfers_in_progress + # ---------------------------------------- + create_update_count_transfers_in_progress() + + # ---------------------------------------- + # Part 6 (2025-01-10, rev 10863452ccd2): Create mv_compliance_report_count + # ---------------------------------------- + create_mv_compliance_report_count() + + # ---------------------------------------- + # Part 7 (2025-01-13, rev f78e53370ed2): Recreate mv_transaction_aggregate with CR support + # ---------------------------------------- + recreate_mv_transaction_aggregate_with_compliance_report() + + # ---------------------------------------- + # Part 8 (2025-01-14, rev 8119d12538df): Create mv_fuel_code_count + # ---------------------------------------- + create_mv_fuel_code_count() + + # End of upgrade + + +def downgrade(): + """ + Rolls back changes in reverse order. + + - Drops mv_fuel_code_count (Part 8). + - Restores older mv_transaction_aggregate definition from before CR was added (Part 7). + - Drops mv_compliance_report_count (Part 6). + - Drops update_count_transfers_in_progress() (Part 5). + - Removes final update_organization_balance (Part 4) but re-creates the older one from the base script. + - Drops all base materialized views/triggers (Part 3). + - Drops audit log triggers/functions (Part 2). + - Leaves the DB with no triggers/functions/views (Part 1). + """ + + # ---------------------------------------- + # Part 8 Downgrade: mv_fuel_code_count + # ---------------------------------------- + op.execute( + "DROP TRIGGER IF EXISTS refresh_mv_fuel_code_count_after_change ON fuel_code;" + ) + op.execute("DROP FUNCTION IF EXISTS refresh_mv_fuel_code_count();") + op.execute("DROP MATERIALIZED VIEW IF EXISTS mv_fuel_code_count;") + + # ---------------------------------------- + # Part 7 Downgrade: revert mv_transaction_aggregate to original base + # ---------------------------------------- + op.execute("DROP MATERIALIZED VIEW IF EXISTS mv_transaction_aggregate;") + op.execute( + """ + CREATE MATERIALIZED VIEW mv_transaction_aggregate AS + SELECT + t.transfer_id AS transaction_id, + 'Transfer' AS transaction_type, + org_from.organization_id AS from_organization_id, + org_from.name AS from_organization, + org_to.organization_id AS to_organization_id, + org_to.name AS to_organization, + t.quantity, + t.price_per_unit, + ts.status::text AS status, + NULL AS compliance_period, + t.from_org_comment AS comment, + tc.category, + ( + SELECT th.create_date + FROM transfer_history th + WHERE th.transfer_id = t.transfer_id AND th.transfer_status_id = 6 + ) AS recorded_date, + NULL AS approved_date, + t.transaction_effective_date, + t.update_date, + t.create_date + FROM transfer t + JOIN organization org_from ON t.from_organization_id = org_from.organization_id + JOIN organization org_to ON t.to_organization_id = org_to.organization_id + JOIN transfer_status ts ON t.current_status_id = ts.transfer_status_id + LEFT JOIN transfer_category tc ON t.transfer_category_id = tc.transfer_category_id + UNION ALL + SELECT + ia.initiative_agreement_id AS transaction_id, + 'InitiativeAgreement' AS transaction_type, + NULL AS from_organization_id, + NULL AS from_organization, + org.organization_id AS to_organization_id, + org.name AS to_organization, + ia.compliance_units AS quantity, + NULL AS price_per_unit, + ias.status::text AS status, + NULL AS compliance_period, + ia.gov_comment AS comment, + NULL AS category, + NULL AS recorded_date, + ( + SELECT iah.create_date + FROM initiative_agreement_history iah + WHERE iah.initiative_agreement_id = ia.initiative_agreement_id + AND iah.initiative_agreement_status_id = 3 + ) AS approved_date, + ia.transaction_effective_date, + ia.update_date, + ia.create_date + FROM initiative_agreement ia + JOIN organization org ON ia.to_organization_id = org.organization_id + JOIN initiative_agreement_status ias ON ia.current_status_id = ias.initiative_agreement_status_id + UNION ALL + SELECT + aa.admin_adjustment_id AS transaction_id, + 'AdminAdjustment' AS transaction_type, + NULL AS from_organization_id, + NULL AS from_organization, + org.organization_id AS to_organization_id, + org.name AS to_organization, + aa.compliance_units AS quantity, + NULL AS price_per_unit, + aas.status::text AS status, + NULL AS compliance_period, + aa.gov_comment AS comment, + NULL AS category, + NULL AS recorded_date, + ( + SELECT aah.create_date + FROM admin_adjustment_history aah + WHERE aah.admin_adjustment_id = aa.admin_adjustment_id + AND aah.admin_adjustment_status_id = 3 + ) AS approved_date, + aa.transaction_effective_date, + aa.update_date, + aa.create_date + FROM admin_adjustment aa + JOIN organization org ON aa.to_organization_id = org.organization_id + JOIN admin_adjustment_status aas ON aa.current_status_id = aas.admin_adjustment_status_id; + """ + ) + op.execute( + """ + CREATE UNIQUE INDEX mv_transaction_aggregate_unique_idx + ON mv_transaction_aggregate (transaction_id, transaction_type); + """ + ) + + # ---------------------------------------- + # Part 6 Downgrade: drop mv_compliance_report_count + # ---------------------------------------- + op.execute( + "DROP TRIGGER IF EXISTS refresh_mv_compliance_report_count_after_change ON compliance_report;" + ) + op.execute("DROP FUNCTION IF EXISTS refresh_mv_compliance_report_count();") + op.execute("DROP MATERIALIZED VIEW IF EXISTS mv_compliance_report_count;") + + # ---------------------------------------- + # Part 5 Downgrade: drop update_count_transfers_in_progress + # ---------------------------------------- + op.execute( + "DROP TRIGGER IF EXISTS update_count_transfers_in_progress_trigger ON transfer;" + ) + op.execute("DROP FUNCTION IF EXISTS update_count_transfers_in_progress();") + + # ---------------------------------------- + # Part 4 Downgrade: revert update_organization_balance to original + # (Matches the base migration’s logic) + # ---------------------------------------- + op.execute( + """DROP TRIGGER IF EXISTS update_organization_balance_trigger ON "transaction";""" + ) + op.execute("""DROP FUNCTION IF EXISTS update_organization_balance();""") + # Recreate the original from the base script + op.execute( + """ + CREATE OR REPLACE FUNCTION update_organization_balance() + RETURNS TRIGGER AS $$ + DECLARE + new_total_balance BIGINT; + new_reserved_balance BIGINT; + org_id INT := COALESCE(NEW.organization_id, OLD.organization_id); + BEGIN + -- Calculate new total balance for specific organization_id + SELECT COALESCE(SUM(compliance_units), 0) INTO new_total_balance + FROM "transaction" + WHERE organization_id = org_id + AND transaction_action = 'Adjustment'; + + -- Calculate new reserved balance for specific organization_id + SELECT COALESCE(SUM(compliance_units), 0) INTO new_reserved_balance + FROM "transaction" + WHERE organization_id = org_id + AND transaction_action = 'Reserved'; + + -- Update the organization with the new balances + UPDATE organization + SET total_balance = new_total_balance, + reserved_balance = new_reserved_balance + WHERE organization_id = org_id; + + RETURN NEW; + END; + $$ LANGUAGE plpgsql; + """ + ) + op.execute( + """ + CREATE TRIGGER update_organization_balance_trigger + AFTER INSERT OR UPDATE OR DELETE ON "transaction" + FOR EACH ROW EXECUTE FUNCTION update_organization_balance(); + """ + ) + + # ---------------------------------------- + # Part 3 Downgrade: Drop Materialized Views and Triggers + # ---------------------------------------- + drop_materialized_views_and_triggers() + + # ---------------------------------------- + # Part 2 Downgrade: Drop Audit Log Functions and Triggers + # ---------------------------------------- + drop_audit_log_functions_and_triggers() + + +# --------------------------------------------------------------------- +# Helper Functions (original base) +# --------------------------------------------------------------------- + + +def drop_existing_triggers_functions_views(): + # (same as original base) + op.execute( + """DROP TRIGGER IF EXISTS refresh_transaction_view_after_transfer ON transfer;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_transaction_view_after_initiative_agreement ON initiative_agreement;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_transaction_view_after_admin_adjustment ON admin_adjustment;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_transaction_view_after_transfer_history ON transfer_history;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_transaction_view_after_initiative_agreement_history ON initiative_agreement_history;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_transaction_view_after_admin_adjustment_history ON admin_adjustment_history;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_mv_transaction_count_after_transfer ON transfer;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_mv_transaction_count_after_initiative_agreement ON initiative_agreement;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_mv_transaction_count_after_admin_adjustment ON admin_adjustment;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_mv_director_review_transaction_count_after_transfer ON transfer;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_mv_director_review_transaction_count_after_compliance_report ON compliance_report;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_mv_director_review_transaction_count_after_initiative_agreement ON initiative_agreement;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_mv_director_review_transaction_count_after_admin_adjustment ON admin_adjustment;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_mv_org_compliance_report_count_after_compliance_report ON compliance_report;""" + ) + + op.execute("""DROP FUNCTION IF EXISTS refresh_transaction_aggregate();""") + op.execute("""DROP FUNCTION IF EXISTS refresh_mv_transaction_count();""") + op.execute( + """DROP FUNCTION IF EXISTS refresh_mv_director_review_transaction_count();""" + ) + op.execute("""DROP FUNCTION IF EXISTS refresh_mv_org_compliance_report_count();""") + + op.execute("""DROP MATERIALIZED VIEW IF EXISTS mv_transaction_aggregate;""") + op.execute("""DROP VIEW IF EXISTS transaction_status_view;""") + op.execute("""DROP MATERIALIZED VIEW IF EXISTS mv_transaction_count;""") + op.execute( + """DROP MATERIALIZED VIEW IF EXISTS mv_director_review_transaction_count;""" + ) + op.execute("""DROP MATERIALIZED VIEW IF EXISTS mv_org_compliance_report_count;""") + + +def create_audit_log_functions_and_triggers(): + # (same as original base) + op.execute( + """ + CREATE OR REPLACE FUNCTION jsonb_diff( + old_row JSONB, + new_row JSONB + ) RETURNS JSONB AS $$ + BEGIN + RETURN ( + SELECT jsonb_object_agg(key, value) + FROM ( + SELECT key, value + FROM jsonb_each(new_row) + EXCEPT + SELECT key, value + FROM jsonb_each(old_row) + ) diff + ); + END; + $$ LANGUAGE plpgsql; + """ + ) + + op.execute( + """ + CREATE OR REPLACE FUNCTION generate_json_delta( + old_row JSONB, + new_row JSONB + ) RETURNS JSONB AS $$ + BEGIN + RETURN jsonb_diff(old_row, new_row); + END; + $$ LANGUAGE plpgsql; + """ + ) + + op.execute( + """ + CREATE OR REPLACE FUNCTION audit_trigger_func() + RETURNS TRIGGER AS $$ + DECLARE + v_operation TEXT; + v_table_name TEXT := TG_TABLE_NAME; + v_row_id JSONB; + v_old_values JSONB; + v_new_values JSONB; + v_delta JSONB; + v_pk_col TEXT; + BEGIN + SELECT c.column_name INTO v_pk_col + FROM information_schema.table_constraints tc + JOIN information_schema.constraint_column_usage AS ccu USING (constraint_schema, constraint_name) + JOIN information_schema.columns AS c ON c.table_schema = tc.constraint_schema + AND tc.table_name = c.table_name AND ccu.column_name = c.column_name + WHERE tc.constraint_type = 'PRIMARY KEY' AND tc.table_name = TG_TABLE_NAME + LIMIT 1; + + IF (TG_OP = 'INSERT') THEN + v_operation := 'INSERT'; + v_new_values := to_jsonb(NEW); + EXECUTE format('SELECT ($1).%I', v_pk_col) INTO v_row_id USING NEW; + ELSIF (TG_OP = 'UPDATE') THEN + v_operation := 'UPDATE'; + v_old_values := to_jsonb(OLD); + v_new_values := to_jsonb(NEW); + v_delta := generate_json_delta(v_old_values, v_new_values); + EXECUTE format('SELECT ($1).%I', v_pk_col) INTO v_row_id USING NEW; + ELSIF (TG_OP = 'DELETE') THEN + v_operation := 'DELETE'; + v_old_values := to_jsonb(OLD); + EXECUTE format('SELECT ($1).%I', v_pk_col) INTO v_row_id USING OLD; + END IF; + + INSERT INTO audit_log ( + create_user, + update_user, + table_name, + operation, + row_id, + delta, + old_values, + new_values + ) + VALUES ( + current_setting('app.username', true), + current_setting('app.username', true), + v_table_name, + v_operation, + v_row_id, + v_delta, + v_old_values, + v_new_values + ); + + RETURN NULL; + END; + $$ LANGUAGE plpgsql; + """ + ) + + # Attach triggers to each relevant table + op.execute( + """ + DO $$ + DECLARE + r RECORD; + BEGIN + FOR r IN SELECT tablename + FROM pg_tables + WHERE schemaname = 'public' + AND tablename IN ( + 'transaction','compliance_report','compliance_report_history','compliance_report_status', + 'compliance_report_summary','compliance_period','initiative_agreement','initiative_agreement_status', + 'initiative_agreement_history','allocation_agreement','allocation_transaction_type','custom_fuel_type', + 'fuel_code','fuel_code_prefix','fuel_code_status','fuel_category','fuel_instance','fuel_type', + 'fuel_export','organization','organization_address','organization_attorney_address','organization_status', + 'organization_type','transfer','transfer_category','transfer_history','transfer_status','internal_comment', + 'user_profile','user_role','role','notification_message','notification_type','admin_adjustment', + 'admin_adjustment_status','admin_adjustment_history','provision_of_the_act','supplemental_report', + 'final_supply_equipment','notional_transfer','fuel_supply','additional_carbon_intensity','document', + 'end_use_type','energy_density','energy_effectiveness_ratio','transport_mode','final_supply_equipment', + 'level_of_equipment','user_login_history','unit_of_measure','target_carbon_intensity' + ) + LOOP + EXECUTE format(' + CREATE TRIGGER audit_%I_insert_update_delete + AFTER INSERT OR UPDATE OR DELETE ON %I + FOR EACH ROW EXECUTE FUNCTION audit_trigger_func();', + r.tablename, r.tablename); + END LOOP; + END $$; + """ + ) + + +def create_materialized_views_and_triggers(): + # (same as original base) + op.execute( + """ + CREATE MATERIALIZED VIEW mv_transaction_aggregate AS + SELECT + t.transfer_id AS transaction_id, + 'Transfer' AS transaction_type, + org_from.organization_id AS from_organization_id, + org_from.name AS from_organization, + org_to.organization_id AS to_organization_id, + org_to.name AS to_organization, + t.quantity, + t.price_per_unit, + ts.status::text AS status, + NULL AS compliance_period, + t.from_org_comment AS comment, + tc.category, + ( + SELECT th.create_date + FROM transfer_history th + WHERE th.transfer_id = t.transfer_id AND th.transfer_status_id = 6 + ) AS recorded_date, + NULL AS approved_date, + t.transaction_effective_date, + t.update_date, + t.create_date + FROM transfer t + JOIN organization org_from ON t.from_organization_id = org_from.organization_id + JOIN organization org_to ON t.to_organization_id = org_to.organization_id + JOIN transfer_status ts ON t.current_status_id = ts.transfer_status_id + LEFT JOIN transfer_category tc ON t.transfer_category_id = tc.transfer_category_id + UNION ALL + SELECT + ia.initiative_agreement_id AS transaction_id, + 'InitiativeAgreement' AS transaction_type, + NULL AS from_organization_id, + NULL AS from_organization, + org.organization_id AS to_organization_id, + org.name AS to_organization, + ia.compliance_units AS quantity, + NULL AS price_per_unit, + ias.status::text AS status, + NULL AS compliance_period, + ia.gov_comment AS comment, + NULL AS category, + NULL AS recorded_date, + ( + SELECT iah.create_date + FROM initiative_agreement_history iah + WHERE iah.initiative_agreement_id = ia.initiative_agreement_id AND iah.initiative_agreement_status_id = 3 + ) AS approved_date, + ia.transaction_effective_date, + ia.update_date, + ia.create_date + FROM initiative_agreement ia + JOIN organization org ON ia.to_organization_id = org.organization_id + JOIN initiative_agreement_status ias ON ia.current_status_id = ias.initiative_agreement_status_id + UNION ALL + SELECT + aa.admin_adjustment_id AS transaction_id, + 'AdminAdjustment' AS transaction_type, + NULL AS from_organization_id, + NULL AS from_organization, + org.organization_id AS to_organization_id, + org.name AS to_organization, + aa.compliance_units AS quantity, + NULL AS price_per_unit, + aas.status::text AS status, + NULL AS compliance_period, + aa.gov_comment AS comment, + NULL AS category, + NULL AS recorded_date, + ( + SELECT aah.create_date + FROM admin_adjustment_history aah + WHERE aah.admin_adjustment_id = aa.admin_adjustment_id AND aah.admin_adjustment_status_id = 3 + ) AS approved_date, + aa.transaction_effective_date, + aa.update_date, + aa.create_date + FROM admin_adjustment aa + JOIN organization org ON aa.to_organization_id = org.organization_id + JOIN admin_adjustment_status aas ON aa.current_status_id = aas.admin_adjustment_status_id; + """ + ) + + op.execute( + """ + CREATE UNIQUE INDEX mv_transaction_aggregate_unique_idx + ON mv_transaction_aggregate (transaction_id, transaction_type); + """ + ) + + op.execute( + """ + CREATE OR REPLACE VIEW transaction_status_view AS + SELECT status::text, create_date, update_date + FROM initiative_agreement_status + UNION + SELECT status::text, create_date, update_date + FROM admin_adjustment_status + UNION + SELECT status::text, create_date, update_date + FROM transfer_status; + """ + ) + + op.execute( + """ + CREATE OR REPLACE FUNCTION refresh_transaction_aggregate() + RETURNS TRIGGER AS $$ + BEGIN + REFRESH MATERIALIZED VIEW CONCURRENTLY mv_transaction_aggregate; + RETURN NULL; + END; + $$ LANGUAGE plpgsql; + """ + ) + + # Triggers for mv_transaction_aggregate + op.execute( + """ + CREATE TRIGGER refresh_transaction_view_after_transfer + AFTER INSERT OR UPDATE OR DELETE ON transfer + FOR EACH STATEMENT EXECUTE FUNCTION refresh_transaction_aggregate(); + """ + ) + op.execute( + """ + CREATE TRIGGER refresh_transaction_view_after_initiative_agreement + AFTER INSERT OR UPDATE OR DELETE ON initiative_agreement + FOR EACH STATEMENT EXECUTE FUNCTION refresh_transaction_aggregate(); + """ + ) + op.execute( + """ + CREATE TRIGGER refresh_transaction_view_after_admin_adjustment + AFTER INSERT OR UPDATE OR DELETE ON admin_adjustment + FOR EACH STATEMENT EXECUTE FUNCTION refresh_transaction_aggregate(); + """ + ) + op.execute( + """ + CREATE TRIGGER refresh_transaction_view_after_transfer_history + AFTER INSERT OR UPDATE OR DELETE ON transfer_history + FOR EACH STATEMENT EXECUTE FUNCTION refresh_transaction_aggregate(); + """ + ) + op.execute( + """ + CREATE TRIGGER refresh_transaction_view_after_initiative_agreement_history + AFTER INSERT OR UPDATE OR DELETE ON initiative_agreement_history + FOR EACH STATEMENT EXECUTE FUNCTION refresh_transaction_aggregate(); + """ + ) + op.execute( + """ + CREATE TRIGGER refresh_transaction_view_after_admin_adjustment_history + AFTER INSERT OR UPDATE OR DELETE ON admin_adjustment_history + FOR EACH STATEMENT EXECUTE FUNCTION refresh_transaction_aggregate(); + """ + ) + + # mv_transaction_count + op.execute( + """ + CREATE MATERIALIZED VIEW mv_transaction_count AS + SELECT + 'transfers' AS transaction_type, + COUNT(*) FILTER ( + WHERE t.current_status_id IN (4,5) + ) AS count_in_progress + FROM transfer t + UNION ALL + SELECT + 'initiative_agreements' AS transaction_type, + COUNT(*) FILTER ( + WHERE ia.current_status_id IN (1,2) + ) AS count_in_progress + FROM initiative_agreement ia + UNION ALL + SELECT + 'admin_adjustments' AS transaction_type, + COUNT(*) FILTER ( + WHERE aa.current_status_id IN (1,2) + ) AS count_in_progress + FROM admin_adjustment aa; + """ + ) + op.execute( + """ + CREATE UNIQUE INDEX mv_transaction_count_unique_idx + ON mv_transaction_count (transaction_type); + """ + ) + op.execute( + """ + CREATE OR REPLACE FUNCTION refresh_mv_transaction_count() + RETURNS TRIGGER AS $$ + BEGIN + REFRESH MATERIALIZED VIEW CONCURRENTLY mv_transaction_count; + RETURN NULL; + END; + $$ LANGUAGE plpgsql; + """ + ) + op.execute( + """ + CREATE TRIGGER refresh_mv_transaction_count_after_transfer + AFTER INSERT OR UPDATE OR DELETE ON transfer + FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_transaction_count(); + """ + ) + op.execute( + """ + CREATE TRIGGER refresh_mv_transaction_count_after_initiative_agreement + AFTER INSERT OR UPDATE OR DELETE ON initiative_agreement + FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_transaction_count(); + """ + ) + op.execute( + """ + CREATE TRIGGER refresh_mv_transaction_count_after_admin_adjustment + AFTER INSERT OR UPDATE OR DELETE ON admin_adjustment + FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_transaction_count(); + """ + ) + + # mv_director_review_transaction_count + op.execute( + """ + CREATE MATERIALIZED VIEW mv_director_review_transaction_count AS + SELECT + 'transfers' AS transaction_type, + COUNT(*) FILTER ( + WHERE t.current_status_id = 5 + ) AS count_for_review + FROM transfer t + UNION ALL + SELECT + 'compliance_reports' AS transaction_type, + COUNT(*) FILTER ( + WHERE cr.current_status_id = 4 + ) AS count_for_review + FROM compliance_report cr + UNION ALL + SELECT + 'initiative_agreements' AS transaction_type, + COUNT(*) FILTER ( + WHERE ia.current_status_id = 2 + ) AS count_for_review + FROM initiative_agreement ia + UNION ALL + SELECT + 'admin_adjustments' AS transaction_type, + COUNT(*) FILTER ( + WHERE aa.current_status_id = 2 + ) AS count_for_review + FROM admin_adjustment aa; + """ + ) + op.execute( + """ + CREATE UNIQUE INDEX mv_director_review_transaction_count_unique_idx + ON mv_director_review_transaction_count (transaction_type); + """ + ) + op.execute( + """ + CREATE OR REPLACE FUNCTION refresh_mv_director_review_transaction_count() + RETURNS TRIGGER AS $$ + BEGIN + REFRESH MATERIALIZED VIEW CONCURRENTLY mv_director_review_transaction_count; + RETURN NULL; + END; + $$ LANGUAGE plpgsql; + """ + ) + op.execute( + """ + CREATE TRIGGER refresh_mv_director_review_transaction_count_after_transfer + AFTER INSERT OR UPDATE OR DELETE ON transfer + FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_director_review_transaction_count(); + """ + ) + op.execute( + """ + CREATE TRIGGER refresh_mv_director_review_transaction_count_after_compliance_report + AFTER INSERT OR UPDATE OR DELETE ON compliance_report + FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_director_review_transaction_count(); + """ + ) + op.execute( + """ + CREATE TRIGGER refresh_mv_director_review_transaction_count_after_initiative_agreement + AFTER INSERT OR UPDATE OR DELETE ON initiative_agreement + FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_director_review_transaction_count(); + """ + ) + op.execute( + """ + CREATE TRIGGER refresh_mv_director_review_transaction_count_after_admin_adjustment + AFTER INSERT OR UPDATE OR DELETE ON admin_adjustment + FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_director_review_transaction_count(); + """ + ) + + # mv_org_compliance_report_count + op.execute( + """ + CREATE MATERIALIZED VIEW mv_org_compliance_report_count AS + SELECT + organization_id, + COUNT(*) FILTER (WHERE current_status_id = 1) AS count_in_progress, + COUNT(*) FILTER (WHERE current_status_id = 2) AS count_awaiting_gov_review + FROM compliance_report + GROUP BY organization_id; + """ + ) + op.execute( + """ + CREATE UNIQUE INDEX mv_org_compliance_report_count_org_id_idx + ON mv_org_compliance_report_count (organization_id); + """ + ) + op.execute( + """ + CREATE OR REPLACE FUNCTION refresh_mv_org_compliance_report_count() + RETURNS TRIGGER AS $$ + BEGIN + REFRESH MATERIALIZED VIEW CONCURRENTLY mv_org_compliance_report_count; + RETURN NULL; + END; + $$ LANGUAGE plpgsql; + """ + ) + op.execute( + """ + CREATE TRIGGER refresh_mv_org_compliance_report_count_after_compliance_report + AFTER INSERT OR UPDATE OR DELETE ON compliance_report + FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_org_compliance_report_count(); + """ + ) + + +def create_update_organization_balance_function_and_trigger(): + """ + Final version of update_organization_balance() from 5163af6ba4a4. + + Summaries: + - total_balance = sum of 'Adjustment' + - reserved_balance = sum of 'Reserved' with compliance_units < 0 + """ + # Drop if exists (in case older version was created above). + op.execute( + """DROP TRIGGER IF EXISTS update_organization_balance_trigger ON "transaction";""" + ) + op.execute("""DROP FUNCTION IF EXISTS update_organization_balance();""") + + op.execute( + """ + CREATE OR REPLACE FUNCTION update_organization_balance() + RETURNS TRIGGER AS $$ + DECLARE + new_total_balance BIGINT; + new_reserved_balance BIGINT; + org_id INT := COALESCE(NEW.organization_id, OLD.organization_id); + BEGIN + SELECT COALESCE(SUM(compliance_units), 0) + INTO new_total_balance + FROM "transaction" + WHERE organization_id = org_id + AND transaction_action = 'Adjustment'; + + SELECT COALESCE(SUM(compliance_units), 0) + INTO new_reserved_balance + FROM "transaction" + WHERE organization_id = org_id + AND transaction_action = 'Reserved' + AND compliance_units < 0; + + UPDATE organization + SET total_balance = new_total_balance, + reserved_balance = new_reserved_balance + WHERE organization_id = org_id; + + RETURN NEW; + END; + $$ LANGUAGE plpgsql; + """ + ) + op.execute( + """ + CREATE TRIGGER update_organization_balance_trigger + AFTER INSERT OR UPDATE OR DELETE ON "transaction" + FOR EACH ROW EXECUTE FUNCTION update_organization_balance(); + """ + ) + + +# --------------------------------------------------------------------- +# Part 5: add update_count_transfers_in_progress (9329e38396e1) +# --------------------------------------------------------------------- +def create_update_count_transfers_in_progress(): + # Create or replace the function + op.execute( + """ + CREATE OR REPLACE FUNCTION update_count_transfers_in_progress() + RETURNS TRIGGER AS $$ + BEGIN + UPDATE organization o + SET count_transfers_in_progress = ( + SELECT COUNT(DISTINCT t.transfer_id) + FROM transfer t + WHERE + t.current_status_id IN (3, 4) -- Sent, Submitted + AND ( + t.from_organization_id = o.organization_id + OR t.to_organization_id = o.organization_id + ) + ) + WHERE o.organization_id = COALESCE(NEW.from_organization_id, OLD.from_organization_id) + OR o.organization_id = COALESCE(NEW.to_organization_id, OLD.to_organization_id); + + RETURN NEW; + END; + $$ LANGUAGE plpgsql; + """ + ) + + # Trigger after insert/update/delete on transfer + op.execute( + """ + CREATE TRIGGER update_count_transfers_in_progress_trigger + AFTER INSERT OR UPDATE OR DELETE ON transfer + FOR EACH ROW + EXECUTE FUNCTION update_count_transfers_in_progress(); + """ + ) + + # Update existing counts + op.execute( + """ + UPDATE organization o + SET count_transfers_in_progress = COALESCE(sub.total_transfer_count, 0) + FROM ( + SELECT + org.organization_id, + COUNT(DISTINCT t.transfer_id) AS total_transfer_count + FROM organization org + LEFT JOIN transfer t + ON org.organization_id = t.from_organization_id + OR org.organization_id = t.to_organization_id + WHERE t.current_status_id IN (3, 4) -- Sent, Submitted + GROUP BY org.organization_id + ) sub + WHERE o.organization_id = sub.organization_id; + """ + ) + + +# --------------------------------------------------------------------- +# Part 6: mv_compliance_report_count (10863452ccd2) +# --------------------------------------------------------------------- +def create_mv_compliance_report_count(): + op.execute( + """ + CREATE MATERIALIZED VIEW mv_compliance_report_count AS + SELECT + CASE current_status_id + WHEN 2 THEN 'Submitted' + WHEN 3 THEN 'Recommended by Analysts' + WHEN 4 THEN 'Recommended by Manager' + END as status, + COUNT(*) as count + FROM compliance_report + WHERE current_status_id IN (2,3,4) + GROUP BY current_status_id; + """ + ) + op.execute( + """ + CREATE UNIQUE INDEX mv_compliance_report_count_idx + ON mv_compliance_report_count (status); + """ + ) + op.execute( + """ + CREATE OR REPLACE FUNCTION refresh_mv_compliance_report_count() + RETURNS TRIGGER AS $$ + BEGIN + REFRESH MATERIALIZED VIEW CONCURRENTLY mv_compliance_report_count; + RETURN NULL; + END; + $$ LANGUAGE plpgsql; + """ + ) + op.execute( + """ + CREATE TRIGGER refresh_mv_compliance_report_count_after_change + AFTER INSERT OR UPDATE OR DELETE ON compliance_report + FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_compliance_report_count(); + """ + ) + + +# --------------------------------------------------------------------- +# Part 7: Re-create mv_transaction_aggregate with CR (f78e53370ed2) +# --------------------------------------------------------------------- +def recreate_mv_transaction_aggregate_with_compliance_report(): + op.execute("DROP MATERIALIZED VIEW mv_transaction_aggregate;") + op.execute( + """ + CREATE MATERIALIZED VIEW mv_transaction_aggregate AS + SELECT + t.transfer_id AS transaction_id, + 'Transfer' AS transaction_type, + NULL AS description, + org_from.organization_id AS from_organization_id, + org_from.name AS from_organization, + org_to.organization_id AS to_organization_id, + org_to.name AS to_organization, + t.quantity, + t.price_per_unit, + ts.status::text AS status, + NULL AS compliance_period, + t.from_org_comment AS comment, + tc.category, + ( + SELECT th.create_date + FROM transfer_history th + WHERE th.transfer_id = t.transfer_id + AND th.transfer_status_id = 6 + ) AS recorded_date, + NULL AS approved_date, + t.transaction_effective_date, + t.update_date, + t.create_date + FROM transfer t + JOIN organization org_from ON t.from_organization_id = org_from.organization_id + JOIN organization org_to ON t.to_organization_id = org_to.organization_id + JOIN transfer_status ts ON t.current_status_id = ts.transfer_status_id + LEFT JOIN transfer_category tc ON t.transfer_category_id = tc.transfer_category_id + + UNION ALL + + SELECT + ia.initiative_agreement_id AS transaction_id, + 'InitiativeAgreement' AS transaction_type, + NULL AS description, + NULL AS from_organization_id, + NULL AS from_organization, + org.organization_id AS to_organization_id, + org.name AS to_organization, + ia.compliance_units AS quantity, + NULL AS price_per_unit, + ias.status::text AS status, + NULL AS compliance_period, + ia.gov_comment AS comment, + NULL AS category, + NULL AS recorded_date, + ( + SELECT iah.create_date + FROM initiative_agreement_history iah + WHERE iah.initiative_agreement_id = ia.initiative_agreement_id + AND iah.initiative_agreement_status_id = 3 + ) AS approved_date, + ia.transaction_effective_date, + ia.update_date, + ia.create_date + FROM initiative_agreement ia + JOIN organization org ON ia.to_organization_id = org.organization_id + JOIN initiative_agreement_status ias ON ia.current_status_id = ias.initiative_agreement_status_id + + UNION ALL + + SELECT + aa.admin_adjustment_id AS transaction_id, + 'AdminAdjustment' AS transaction_type, + NULL AS description, + NULL AS from_organization_id, + NULL AS from_organization, + org.organization_id AS to_organization_id, + org.name AS to_organization, + aa.compliance_units AS quantity, + NULL AS price_per_unit, + aas.status::text AS status, + NULL AS compliance_period, + aa.gov_comment AS comment, + NULL AS category, + NULL AS recorded_date, + ( + SELECT aah.create_date + FROM admin_adjustment_history aah + WHERE aah.admin_adjustment_id = aa.admin_adjustment_id + AND aah.admin_adjustment_status_id = 3 + ) AS approved_date, + aa.transaction_effective_date, + aa.update_date, + aa.create_date + FROM admin_adjustment aa + JOIN organization org ON aa.to_organization_id = org.organization_id + JOIN admin_adjustment_status aas ON aa.current_status_id = aas.admin_adjustment_status_id + + UNION ALL + + SELECT + cr.compliance_report_id AS transaction_id, + 'ComplianceReport' AS transaction_type, + cr.nickname AS description, + NULL AS from_organization_id, + NULL AS from_organization, + org.organization_id AS to_organization_id, + org.name AS to_organization, + tr.compliance_units AS quantity, + NULL AS price_per_unit, + crs.status::text AS status, + cp.description AS compliance_period, + NULL AS comment, + NULL AS category, + NULL AS recorded_date, + NULL AS approved_date, + NULL AS transaction_effective_date, + cr.update_date, + cr.create_date + FROM compliance_report cr + JOIN organization org ON cr.organization_id = org.organization_id + JOIN compliance_report_status crs ON cr.current_status_id = crs.compliance_report_status_id + JOIN compliance_period cp ON cr.compliance_period_id = cp.compliance_period_id + JOIN "transaction" tr ON cr.transaction_id = tr.transaction_id + AND cr.transaction_id IS NOT NULL; + """ + ) + op.execute( + """ + CREATE UNIQUE INDEX mv_transaction_aggregate_unique_idx + ON mv_transaction_aggregate (transaction_id, description, transaction_type); + """ + ) + + +# --------------------------------------------------------------------- +# Part 8: mv_fuel_code_count (8119d12538df) +# --------------------------------------------------------------------- +def create_mv_fuel_code_count(): + op.execute( + """ + CREATE MATERIALIZED VIEW mv_fuel_code_count AS + SELECT + CASE fuel_status_id + WHEN 1 THEN 'Draft' + END as status, + COUNT(*) as count + FROM fuel_code + WHERE fuel_status_id = 1 + GROUP BY fuel_status_id; + """ + ) + op.execute( + """ + CREATE UNIQUE INDEX mv_fuel_code_count_idx + ON mv_fuel_code_count (status); + """ + ) + op.execute( + """ + CREATE OR REPLACE FUNCTION refresh_mv_fuel_code_count() + RETURNS TRIGGER AS $$ + BEGIN + REFRESH MATERIALIZED VIEW CONCURRENTLY mv_fuel_code_count; + RETURN NULL; + END; + $$ LANGUAGE plpgsql; + """ + ) + op.execute( + """ + CREATE TRIGGER refresh_mv_fuel_code_count_after_change + AFTER INSERT OR UPDATE OR DELETE ON fuel_code + FOR EACH STATEMENT EXECUTE FUNCTION refresh_mv_fuel_code_count(); + """ + ) + op.execute("REFRESH MATERIALIZED VIEW CONCURRENTLY mv_fuel_code_count;") + + +def drop_materialized_views_and_triggers(): + # (same as original base) + op.execute( + """DROP TRIGGER IF EXISTS refresh_transaction_view_after_transfer ON transfer;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_transaction_view_after_initiative_agreement ON initiative_agreement;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_transaction_view_after_admin_adjustment ON admin_adjustment;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_transaction_view_after_transfer_history ON transfer_history;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_transaction_view_after_initiative_agreement_history ON initiative_agreement_history;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_transaction_view_after_admin_adjustment_history ON admin_adjustment_history;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_mv_transaction_count_after_transfer ON transfer;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_mv_transaction_count_after_initiative_agreement ON initiative_agreement;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_mv_transaction_count_after_admin_adjustment ON admin_adjustment;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_mv_director_review_transaction_count_after_transfer ON transfer;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_mv_director_review_transaction_count_after_compliance_report ON compliance_report;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_mv_director_review_transaction_count_after_initiative_agreement ON initiative_agreement;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_mv_director_review_transaction_count_after_admin_adjustment ON admin_adjustment;""" + ) + op.execute( + """DROP TRIGGER IF EXISTS refresh_mv_org_compliance_report_count_after_compliance_report ON compliance_report;""" + ) + + op.execute("""DROP FUNCTION IF EXISTS refresh_transaction_aggregate();""") + op.execute("""DROP FUNCTION IF EXISTS refresh_mv_transaction_count();""") + op.execute( + """DROP FUNCTION IF EXISTS refresh_mv_director_review_transaction_count();""" + ) + op.execute("""DROP FUNCTION IF EXISTS refresh_mv_org_compliance_report_count();""") + + op.execute("""DROP MATERIALIZED VIEW IF EXISTS mv_transaction_aggregate;""") + op.execute("""DROP VIEW IF EXISTS transaction_status_view;""") + op.execute("""DROP MATERIALIZED VIEW IF EXISTS mv_transaction_count;""") + op.execute( + """DROP MATERIALIZED VIEW IF EXISTS mv_director_review_transaction_count;""" + ) + op.execute("""DROP MATERIALIZED VIEW IF EXISTS mv_org_compliance_report_count;""") + + +def drop_audit_log_functions_and_triggers(): + # (same as original base) + op.execute( + """ + DO $$ + DECLARE + r RECORD; + BEGIN + FOR r IN SELECT tablename + FROM pg_tables + WHERE schemaname = 'public' + AND tablename IN ( + 'transaction','compliance_report','compliance_report_history','compliance_report_status', + 'compliance_report_summary','compliance_period','initiative_agreement','initiative_agreement_status', + 'initiative_agreement_history','allocation_agreement','allocation_transaction_type','custom_fuel_type', + 'fuel_code','fuel_code_prefix','fuel_code_status','fuel_category','fuel_instance','fuel_type', + 'fuel_export','organization','organization_address','organization_attorney_address','organization_status', + 'organization_type','transfer','transfer_category','transfer_history','transfer_status','internal_comment', + 'user_profile','user_role','role','notification_message','notification_type','admin_adjustment', + 'admin_adjustment_status','admin_adjustment_history','provision_of_the_act','supplemental_report', + 'final_supply_equipment','notional_transfer','fuel_supply','additional_carbon_intensity','document', + 'end_use_type','energy_density','energy_effectiveness_ratio','transport_mode','final_supply_equipment', + 'level_of_equipment','user_login_history','unit_of_measure','target_carbon_intensity' + ) + LOOP + EXECUTE format(' + DROP TRIGGER IF EXISTS audit_%I_insert_update_delete ON %I;', + r.tablename, r.tablename); + END LOOP; + END $$; + """ + ) + op.execute("DROP FUNCTION IF EXISTS audit_trigger_func;") + op.execute("DROP FUNCTION IF EXISTS generate_json_delta;") + op.execute("DROP FUNCTION IF EXISTS jsonb_diff;") diff --git a/backend/lcfs/db/migrations/versions/2025-01-20-14-40_ec826b9226df.py b/backend/lcfs/db/migrations/versions/2025-01-20-14-40_ec826b9226df.py new file mode 100644 index 000000000..33aaf4993 --- /dev/null +++ b/backend/lcfs/db/migrations/versions/2025-01-20-14-40_ec826b9226df.py @@ -0,0 +1,1681 @@ +""" +Consolidated Migration: Squashed data updates from historical migrations + +Combines multiple migration files into one, preserving the chronological order +of their 'upgrade' steps and reversing it for 'downgrade'. Comments mark the +original revision IDs. + +Revision ID: ec826b9226df +Revises: f217cd32474b +Create Date: 2025-01-20 14:40:01.289718 +""" + +from alembic import op +import sqlalchemy as sa +from sqlalchemy.dialects.postgresql import ENUM +from datetime import datetime + +# Single consolidated revision identifier +revision = "ec826b9226df" +down_revision = "f217cd32474b" +branch_labels = None +depends_on = None + + +def upgrade(): + """ + Consolidated UPGRADE logic from all migrations, in ascending date order: + (1) 043c52082a3b (2024-11-27) + (2) aeaa26f5cdd5 (2024-12-02) + (3) 9206124a098b (2024-12-04) + (4) 8491890dd688 (2024-12-04) + (5) d4104af84f2b (2024-12-05) + (6) 26ab15f8ab18 (2024-12-06) + (7) 7ae38a8413ab (2024-12-09) + (8) 5d729face5ab (2024-12-12) + (9) 851e09cf8661 (2024-12-17) + (10) 59873cafbcd8 (2024-12-20) + (11) 5fbcb508c1be (2024-12-21) + (12) ab04810d4d7c (2024-12-22) + (13) d9cdd9fca0ce (2024-12-24) + (14) bfa7bbb1eea3 (2025-01-03) + (15) e883ad1f0f60 (2025-01-03) + (16) 94306eca5261 (2025-01-06) + (17) fa98709e7952 (2025-01-06) + (18) 998929392c8b (2025-01-07) + (19) fe03799b4018 (2025-01-14) + (20) 5bc0ef48739a (2025-01-15) + """ + + # + # (1) 043c52082a3b (2024-11-27): Add 'Marine-domestic' and 'Marine-international' transport modes + # + current_time = datetime.now() + # Update Marine -> Marine-domestic + op.execute( + f""" + UPDATE transport_mode + SET transport_mode = 'Marine-domestic', + update_date = '{current_time}', + update_user = 'no-user' + WHERE transport_mode = 'Marine' + """ + ) + + # Insert Marine-international + op.execute( + f""" + INSERT INTO transport_mode (transport_mode, create_date, update_date, create_user, update_user) + VALUES ('Marine-international', '{current_time}', '{current_time}', 'no_user', 'no_user') + """ + ) + + # + # (2) aeaa26f5cdd5 (2024-12-02): Replace "Other" in level_of_equipment with long description + # + op.execute( + """ + UPDATE level_of_equipment + SET name = 'Other - Additional information provided in notes field' + WHERE name = 'Other' + """ + ) + + # + # (4) 8491890dd688 (2024-12-04): Data fixes for FuelType and AllocationTransactionType + # (Originally used Python model references; replaced with raw SQL.) + # + # - fuel_type_id = 6 -> units=Kilograms + # - fuel_type_id = 20 -> fossil_derived=False + # - allocation_transaction_type_id = 2 -> "Allocated to" + # - allocation_transaction_type_id = 1 -> "Allocated from" + # + op.execute( + """ + UPDATE fuel_type + SET units = 'Kilograms' + WHERE fuel_type_id = 6 + """ + ) + op.execute( + """ + UPDATE fuel_type + SET fossil_derived = false + WHERE fuel_type_id = 20 + """ + ) + op.execute( + """ + UPDATE allocation_transaction_type + SET type = 'Allocated to', + description = 'Fuel allocated to another supplier under an allocation agreement' + WHERE allocation_transaction_type_id = 2 + """ + ) + op.execute( + """ + UPDATE allocation_transaction_type + SET type = 'Allocated from', + description = 'Fuel allocated from another supplier under an allocation agreement' + WHERE allocation_transaction_type_id = 1 + """ + ) + + # + # (5) d4104af84f2b (2024-12-05): Update Notification Types and remove old data/enum + # + # 1) DELETE FROM notification_type + # 2) Convert name column to VARCHAR from old enum + # 3) DROP TYPE notification_type_enum_v2 if exists + # + op.execute("DELETE FROM notification_type;") + + with op.batch_alter_table("notification_type") as batch_op: + batch_op.alter_column( + "name", + existing_type=sa.String(length=255), # in the final script, assume string + type_=sa.String(length=255), + existing_nullable=False, + ) + + op.execute("DROP TYPE IF EXISTS notification_type_enum_v2;") + + # + # (6) 26ab15f8ab18 (2024-12-06): Update end_use_type (IDs 14-21) and adjust additional_carbon_intensity, EER + # + current_time = datetime.now() + updates = [ + (14, "Aircraft"), + (15, "Compression-ignition engine- Marine, general"), + ( + 16, + "Compression-ignition engine- Marine, operated within 51 to 75% of load range", + ), + ( + 17, + "Compression-ignition engine- Marine, operated within 76 to 100% of load range", + ), + ( + 18, + "Compression-ignition engine- Marine, with methane slip reduction kit- General", + ), + ( + 19, + "Compression-ignition engine- Marine, with methane slip reduction kit- Operated within 51 to 75% of load range", + ), + ( + 20, + "Compression-ignition engine- Marine, with methane slip reduction kit- Operated within 76 to 100% of load range", + ), + ( + 21, + "Compression-ignition engine- Marine, unknown whether kit is installed or average operating load range", + ), + ] + for end_use_id, new_type in updates: + op.execute( + f""" + UPDATE end_use_type + SET type = '{new_type}', + sub_type = NULL, + intended_use = true, + update_date = '{current_time}', + update_user = 'no_user' + WHERE end_use_type_id = {end_use_id} + """ + ) + + # Adjust additional_carbon_intensity (IDs 1-9) + uci_updates = [ + (1, 7, 5, None, 0), + (2, None, 5, None, 0), + (3, 7, 5, 15, 27.3), + (4, 7, 5, 16, 17.8), + (5, 7, 5, 17, 12.2), + (6, 7, 5, 18, 10.6), + (7, 7, 5, 19, 8.4), + (8, 7, 5, 20, 8.0), + (9, 7, 5, 21, 27.3), + ] + for uci_id, fuel_type_id, uom_id, end_use_type_id, intensity in uci_updates: + # If 'None' for end_use_type_id or fuel_type_id, set them to NULL + if fuel_type_id and end_use_type_id: + op.execute( + f""" + UPDATE additional_carbon_intensity + SET fuel_type_id = {fuel_type_id}, + uom_id = {uom_id}, + end_use_type_id = {end_use_type_id}, + intensity = {intensity}, + update_date = '{current_time}', + update_user = 'no_user' + WHERE additional_uci_id = {uci_id} + """ + ) + elif fuel_type_id: + op.execute( + f""" + UPDATE additional_carbon_intensity + SET fuel_type_id = {fuel_type_id}, + uom_id = {uom_id}, + end_use_type_id = NULL, + intensity = {intensity}, + update_date = '{current_time}', + update_user = 'no_user' + WHERE additional_uci_id = {uci_id} + """ + ) + else: + op.execute( + f""" + UPDATE additional_carbon_intensity + SET fuel_type_id = NULL, + uom_id = {uom_id}, + end_use_type_id = NULL, + intensity = {intensity}, + update_date = '{current_time}', + update_user = 'no_user' + WHERE additional_uci_id = {uci_id} + """ + ) + + # Adjust EER for IDs 14-24 + eer_updates = [ + (14, 2, 3, 10, 2.8), + (15, 2, 3, 11, 2.4), + (16, 2, 3, 2, 1.0), + (17, 2, 6, 3, 1.8), + (18, 2, 6, 2, 0.9), + (19, 2, 13, None, 0.9), + (20, 3, 3, None, 2.5), + (21, 3, 11, None, 1.0), + (22, 2, 7, 15, 1.0), + (23, 2, 7, 16, 1.0), + (24, 2, 7, 17, 1.0), + ] + for eer_id, fc_id, ft_id, eut_id, ratio in eer_updates: + if eut_id: + op.execute( + f""" + UPDATE energy_effectiveness_ratio + SET fuel_category_id = {fc_id}, + fuel_type_id = {ft_id}, + end_use_type_id = {eut_id}, + ratio = {ratio}, + update_date = '{current_time}', + update_user = 'no_user' + WHERE eer_id = {eer_id} + """ + ) + else: + op.execute( + f""" + UPDATE energy_effectiveness_ratio + SET fuel_category_id = {fc_id}, + fuel_type_id = {ft_id}, + end_use_type_id = NULL, + ratio = {ratio}, + update_date = '{current_time}', + update_user = 'no_user' + WHERE eer_id = {eer_id} + """ + ) + + # + # (7) 7ae38a8413ab (2024-12-09): Mark volume-based fuel types as other_uses_fossil_derived = true, and gas-based as false + # + current_time = datetime.now() + op.execute( + f""" + UPDATE fuel_type + SET other_uses_fossil_derived = true, + update_date = '{current_time}', + update_user = 'no_user' + WHERE fuel_type IN ( + 'Alternative jet fuel', + 'Biodiesel', + 'Ethanol', + 'HDRD', + 'Renewable gasoline', + 'Renewable naphtha' + ) + """ + ) + op.execute( + f""" + UPDATE fuel_type + SET other_uses_fossil_derived = false, + update_date = '{current_time}', + update_user = 'no_user' + WHERE fuel_type IN ( + 'CNG', + 'Electricity', + 'Hydrogen', + 'LNG', + 'Propane' + ) + """ + ) + + # + # (8) 5d729face5ab (2024-12-12): Update default_carbon_intensity for 'Other diesel' (fuel_type_id=20) to 100.21 + # + op.execute( + """ + UPDATE fuel_type + SET default_carbon_intensity = 100.21 + WHERE fuel_type_id = 20 + """ + ) + + # + # (9) 851e09cf8661 (2024-12-17): Add "default_carbon_intensity" column to "fuel_category" and populate + # + op.execute( + """ + UPDATE "fuel_category" + SET "default_carbon_intensity" = 88.83 + WHERE "description" = 'Jet fuel'; + """ + ) + op.execute( + """ + UPDATE "fuel_category" + SET "default_carbon_intensity" = 100.21 + WHERE "description" = 'Diesel'; + """ + ) + op.execute( + """ + UPDATE "fuel_category" + SET "default_carbon_intensity" = 93.67 + WHERE "description" = 'Gasoline'; + """ + ) + op.alter_column( + "fuel_category", + "default_carbon_intensity", + existing_type=sa.Numeric(precision=10, scale=2), + nullable=False, + ) + + # + # (10) 59873cafbcd8 (2024-12-20): Update 'Other diesel' to set fossil_derived = false, other_uses_fossil_derived = false + # + op.execute( + """ + UPDATE fuel_type + SET fossil_derived = false, other_uses_fossil_derived = false + WHERE fuel_type = 'Other diesel' + """ + ) + + # + # (11) 5fbcb508c1be (2024-12-21): Rename an end_use_type for LNG + # + op.execute( + """ + UPDATE end_use_type + SET type = 'Compression-ignition engine- Marine, with methane slip reduction kit- Operated within 26 to 75% of load range' + WHERE end_use_type_id = 19 + """ + ) + + # + # (13) d9cdd9fca0ce (2024-12-24): Move common seeders to migrations + # + # (Full block of reference data insertion) + # + dates = [(year, f"{year}-01-01", f"{year}-12-31") for year in range(2010, 2033)] + for i, (year, start_date, end_date) in enumerate(dates, 1): + op.execute( + f""" + INSERT INTO compliance_period ( + compliance_period_id, description, display_order, + effective_date, expiration_date, effective_status + ) + VALUES ( + {i}, '{year}', {i}, + '{start_date}', '{end_date}', TRUE + ) + ON CONFLICT (compliance_period_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO organization_type (organization_type_id, org_type, description) + VALUES + (1, 'fuel_supplier', 'Fuel Supplier'), + (2, 'electricity_supplier', 'Electricity Supplier'), + (3, 'broker', 'Broker'), + (4, 'utilities', 'Utilities (local or public)') + ON CONFLICT (organization_type_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO organization_status (organization_status_id, status, description) + VALUES + (1, 'Unregistered', 'Unregistered'), + (2, 'Registered', 'Registered'), + (3, 'Suspended', 'Suspended'), + (4, 'Canceled', 'Canceled') + ON CONFLICT (organization_status_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO role (role_id, name, description, is_government_role, display_order) + VALUES + (1, 'GOVERNMENT', 'Identifies a government user in the system.', TRUE, 1), + (2, 'SUPPLIER', 'Identifies a supplier user in the system.', FALSE, 2), + (3, 'ADMINISTRATOR', 'Can add/edit IDIR users and assign roles, add/edit organizations, BCeID users, and assign roles', TRUE, 3), + (4, 'ANALYST', 'Can make recommendations on transfers, transactions, and compliance reports, manage file submissions, and add/edit fuel codes', TRUE, 4), + (5, 'COMPLIANCE_MANAGER', 'Can make recommendations on compliance reports', TRUE, 5), + (6, 'DIRECTOR', 'Can assess compliance reports and approve transactions', TRUE, 6), + (7, 'MANAGE_USERS', 'Can add/edit BCeID users and assign roles', FALSE, 7), + (8, 'TRANSFER', 'Can create/save transfers and submit files', FALSE, 8), + (9, 'COMPLIANCE_REPORTING', 'Can create/save compliance reports and submit files', FALSE, 9), + (10, 'SIGNING_AUTHORITY', 'Can sign and submit compliance reports to government and transfers to trade partners/government', FALSE, 10), + (11, 'READ_ONLY', 'Can view transactions, compliance reports, and files', FALSE, 11) + ON CONFLICT (role_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO transfer_status (transfer_status_id, status, visible_to_transferor, visible_to_transferee, visible_to_government) + VALUES + (1, 'Draft', TRUE, FALSE, FALSE), + (2, 'Deleted', FALSE, FALSE, FALSE), + (3, 'Sent', TRUE, TRUE, FALSE), + (4, 'Submitted', TRUE, TRUE, TRUE), + (5, 'Recommended', TRUE, TRUE, TRUE), + (6, 'Recorded', TRUE, TRUE, TRUE), + (7, 'Refused', TRUE, TRUE, TRUE), + (8, 'Declined', TRUE, TRUE, FALSE), + (9, 'Rescinded', TRUE, TRUE, TRUE) + ON CONFLICT (transfer_status_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO transfer_category (transfer_category_id, category, effective_status) + VALUES + (1, 'A', TRUE), + (2, 'B', TRUE), + (3, 'C', TRUE), + (4, 'D', TRUE) + ON CONFLICT (transfer_category_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO admin_adjustment_status (admin_adjustment_status_id, status) + VALUES + (1, 'Draft'), + (2, 'Recommended'), + (3, 'Approved'), + (4, 'Deleted') + ON CONFLICT (admin_adjustment_status_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO initiative_agreement_status (initiative_agreement_status_id, status) + VALUES + (1, 'Draft'), + (2, 'Recommended'), + (3, 'Approved'), + (4, 'Deleted') + ON CONFLICT (initiative_agreement_status_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO expected_use_type (expected_use_type_id, name, description, effective_status) + VALUES + (1, 'Heating oil', 'Fuel used for heating purposes', TRUE), + (2, 'Other', 'Other type of fuel description', TRUE) + ON CONFLICT (expected_use_type_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO unit_of_measure (uom_id, name, description) + VALUES + (1, 'MJ/L', 'Megajoules per litre'), + (2, 'MJ/kWh', 'Megajoules per kilowatt hour'), + (3, 'MJ/m³', 'Megajoules per cubic metre'), + (4, 'MJ/kg', 'Megajoules per kilogram'), + (5, 'gCO²e/MJ', 'grams of carbon dioxide equivalent per megajoule') + ON CONFLICT (uom_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO end_use_type (end_use_type_id, type, intended_use) + VALUES + (1, 'Light duty motor vehicles', TRUE), + (2, 'Other or unknown', FALSE), + (3, 'Fuel cell vehicle', FALSE), + (4, 'Battery bus', TRUE), + (5, 'Battery truck', TRUE), + (6, 'Cargo handling equipment', TRUE), + (7, 'Fixed guiderail', TRUE), + (8, 'Ground support equipment', TRUE), + (9, 'Heavy forklift', TRUE), + (10, 'Shore power', TRUE), + (11, 'Trolley bus', TRUE), + (12, 'Compression-ignition engine', FALSE), + (13, 'Other', TRUE), + (14, 'Aircraft', TRUE), + (15, 'Compression-ignition engine- Marine, general', TRUE), + (16, 'Compression-ignition engine- Marine, operated within 51 to 75% of load range', TRUE), + (17, 'Compression-ignition engine- Marine, operated within 76 to 100% of load range', TRUE), + (18, 'Compression-ignition engine- Marine, with methane slip reduction kit- General', TRUE), + (19, 'Compression-ignition engine- Marine, with methane slip reduction kit- Operated within 51 to 75% of load range', TRUE), + (20, 'Compression-ignition engine- Marine, with methane slip reduction kit- Operated within 76 to 100% of load range', TRUE), + (21, 'Compression-ignition engine- Marine, unknown whether kit is installed or average operating load range', TRUE), + (22, 'Unknown engine type', TRUE), + (23, 'Other (i.e. road transportation)', TRUE), + (24, 'Any', TRUE) + ON CONFLICT (end_use_type_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO provision_of_the_act (provision_of_the_act_id, name, description, effective_status) + VALUES + (1, 'Prescribed carbon intensity - section 19 (a)', 'Prescribed carbon intensity - section 19 (a)', TRUE), + (2, 'Fuel code - section 19 (b) (i)', 'Fuel code - section 19 (b) (i)', TRUE), + (3, 'Default carbon intensity - section 19 (b) (ii)', 'Default carbon intensity - section 19 (b) (ii)', TRUE) + ON CONFLICT (provision_of_the_act_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO fuel_category (fuel_category_id, category, description, default_carbon_intensity, effective_status) + VALUES + (1, 'Gasoline', 'Gasoline', 93.67, TRUE), + (2, 'Diesel', 'Diesel', 100.21, TRUE), + (3, 'Jet fuel', 'Jet fuel', 88.83, TRUE) + ON CONFLICT (fuel_category_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO fuel_type (fuel_type_id, fuel_type, fossil_derived, other_uses_fossil_derived, + provision_1_id, provision_2_id, default_carbon_intensity, units, unrecognized) + VALUES + (1, 'Biodiesel', FALSE, FALSE, 2, 3, 100.21, 'Litres', FALSE), + (2, 'CNG', FALSE, TRUE, 2, 3, 63.91, 'Cubic_metres', FALSE), + (3, 'Electricity', FALSE, TRUE, 2, 3, 12.14, 'Kilowatt_hour', FALSE), + (4, 'Ethanol', FALSE, FALSE, 2, 3, 93.67, 'Litres', FALSE), + (5, 'HDRD', FALSE, FALSE, 2, 3, 100.21, 'Litres', FALSE), + (6, 'Hydrogen', FALSE, TRUE, 2, 3, 123.96, 'Kilograms', FALSE), + (7, 'LNG', FALSE, TRUE, 2, 3, 90.11, 'Kilograms', FALSE), + (11, 'Alternative jet fuel', FALSE, FALSE, 2, 3, 88.83, 'Litres', FALSE), + (13, 'Propane', FALSE, TRUE, 2, 3, 79.87, 'Litres', FALSE), + (14, 'Renewable gasoline', FALSE, FALSE, 2, 3, 93.67, 'Litres', FALSE), + (15, 'Renewable naphtha', FALSE, FALSE, 2, 3, 93.67, 'Litres', FALSE), + (16, 'Fossil-derived diesel', TRUE, TRUE, 1, NULL, 94.38, 'Litres', FALSE), + (17, 'Fossil-derived gasoline', TRUE, TRUE, 1, NULL, 93.67, 'Litres', FALSE), + (18, 'Fossil-derived jet fuel', TRUE, TRUE, 1, NULL, 88.83, 'Litres', FALSE), + (19, 'Other', FALSE, FALSE, 2, 3, 0, 'Litres', TRUE), + (20, 'Other diesel', FALSE, FALSE, 1, NULL, 100.21, 'Litres', FALSE) + ON CONFLICT (fuel_type_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO energy_effectiveness_ratio ( + eer_id, fuel_category_id, fuel_type_id, end_use_type_id, ratio, effective_status + ) + VALUES + (1, 1, 2, 24, 0.9, TRUE), + (2, 1, 3, 1, 3.5, TRUE), + (3, 1, 3, 2, 1.0, TRUE), + (4, 1, 6, 3, 2.4, TRUE), + (5, 1, 6, 2, 0.9, TRUE), + (6, 1, 13, 24, 0.9, TRUE), + (7, 2, 2, 24, 0.9, TRUE), + (8, 2, 3, 4, 3.8, TRUE), + (9, 2, 3, 5, 3.2, TRUE), + (10, 2, 3, 6, 2.5, TRUE), + (11, 2, 3, 7, 2.9, TRUE), + (12, 2, 3, 8, 2.5, TRUE), + (13, 2, 3, 9, 3.9, TRUE), + (14, 2, 3, 10, 2.8, TRUE), + (15, 2, 3, 11, 2.4, TRUE), + (16, 2, 3, 2, 1.0, TRUE), + (17, 2, 6, 3, 1.8, TRUE), + (18, 2, 6, 2, 0.9, TRUE), + (19, 2, 13, 24, 0.9, TRUE), + (20, 3, 3, 24, 2.5, TRUE), + (21, 3, 11, 24, 1.0, TRUE), + (22, 2, 7, 15, 1.0, TRUE), + (23, 2, 7, 16, 1.0, TRUE), + (24, 2, 7, 17, 1.0, TRUE), + (25, 2, 7, 18, 1.0, TRUE), + (26, 2, 7, 19, 1.0, TRUE), + (27, 2, 7, 20, 1.0, TRUE), + (28, 2, 7, 21, 1.0, TRUE), + (29, 2, 7, 22, 0.9, TRUE), + (30, 2, 7, 23, 0.9, TRUE), + (31, 2, 1, 24, 1.0, TRUE), + (32, 2, 5, 24, 1.0, TRUE), + (33, 3, 6, 24, 1.0, TRUE), + (34, 1, 14, 24, 1.0, TRUE), + (35, 1, 15, 24, 1.0, TRUE), + (36, 2, 16, 24, 1.0, TRUE), + (37, 1, 17, 24, 1.0, TRUE), + (38, 3, 18, 24, 1.0, TRUE), + (39, 1, 19, 24, 1.0, TRUE), + (40, 2, 19, 24, 1.0, TRUE), + (41, 3, 7, 24, 1.0, TRUE), + (42, 2, 20, 24, 1.0, TRUE), + (43, 1, 4, 24, 1.0, TRUE) + ON CONFLICT (eer_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO additional_carbon_intensity (additional_uci_id, fuel_type_id, uom_id, end_use_type_id, intensity) + VALUES + (1, 7, 5, NULL, 0), + (2, NULL, 5, NULL, 0), + (3, 7, 5, 15, 27.3), + (4, 7, 5, 16, 17.8), + (5, 7, 5, 17, 12.2), + (6, 7, 5, 18, 10.6), + (7, 7, 5, 19, 8.4), + (8, 7, 5, 20, 8.0), + (9, 7, 5, 21, 27.3), + (10, 7, 5, 22, 27.3), + (11, 7, 5, 23, 0) + ON CONFLICT (additional_uci_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO energy_density (energy_density_id, fuel_type_id, uom_id, density) + VALUES + (1, 17, 1, 34.69), + (2, 4, 1, 23.58), + (3, 14, 1, 34.69), + (4, 15, 1, 34.51), + (5, 16, 1, 38.65), + (6, 1, 1, 35.40), + (7, 5, 1, 37.89), + (9, 18, 1, 37.40), + (10, 11, 1, 36.00), + (11, 3, 2, 3.60), + (12, 6, 2, 141.76), + (13, 13, 1, 25.62), + (14, 2, 3, 38.27), + (15, 7, 4, 53.54), + (16, 20, 1, 36.51) + ON CONFLICT (energy_density_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO target_carbon_intensity ( + target_carbon_intensity_id, + compliance_period_id, + fuel_category_id, + target_carbon_intensity, + reduction_target_percentage, + effective_status + ) + VALUES + (1, 15, 1, 78.68, 16.0, TRUE), + (2, 16, 1, 76.53, 18.3, TRUE), + (3, 17, 1, 74.37, 20.6, TRUE), + (4, 18, 1, 72.13, 23.0, TRUE), + (5, 19, 1, 69.97, 25.3, TRUE), + (6, 20, 1, 67.72, 27.7, TRUE), + (7, 21, 1, 65.57, 30.0, TRUE), + (8, 15, 2, 79.28, 16.0, TRUE), + (9, 16, 2, 77.11, 18.3, TRUE), + (10, 17, 2, 74.94, 20.6, TRUE), + (11, 18, 2, 72.67, 23.0, TRUE), + (12, 19, 2, 70.50, 25.3, TRUE), + (13, 20, 2, 68.24, 27.7, TRUE), + (14, 21, 2, 66.07, 30.0, TRUE), + (15, 15, 3, 88.83, 0.0, TRUE), + (16, 16, 3, 88.83, 0.0, TRUE), + (17, 17, 3, 87.05, 2.0, TRUE), + (18, 18, 3, 85.28, 4.0, TRUE), + (19, 19, 3, 83.50, 6.0, TRUE), + (20, 20, 3, 81.72, 8.0, TRUE), + (21, 21, 3, 79.95, 10.0, TRUE) + ON CONFLICT (target_carbon_intensity_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO fuel_instance (fuel_instance_id, fuel_type_id, fuel_category_id) + VALUES + (1, 1, 2), + (2, 2, 1), + (3, 2, 2), + (4, 3, 1), + (5, 3, 2), + (6, 3, 3), + (7, 4, 1), + (8, 5, 2), + (9, 6, 1), + (10, 6, 2), + (11, 6, 3), + (12, 7, 2), + (16, 11, 3), + (18, 13, 1), + (19, 13, 2), + (20, 14, 1), + (21, 15, 1), + (22, 16, 2), + (23, 17, 1), + (24, 18, 3), + (25, 19, 1), + (26, 19, 2), + (27, 19, 3), + (28, 20, 2) + ON CONFLICT (fuel_instance_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO transport_mode (transport_mode_id, transport_mode) + VALUES + (1, 'Truck'), + (2, 'Rail'), + (3, 'Marine-domestic'), + (4, 'Adjacent'), + (5, 'Pipeline') + ON CONFLICT (transport_mode_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO fuel_code_prefix (fuel_code_prefix_id, prefix) + VALUES + (1, 'BCLCF'), + (2, 'PROXY') + ON CONFLICT (fuel_code_prefix_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO fuel_code_status (fuel_code_status_id, status, description, display_order) + VALUES + (1, 'Draft', 'Initial state of the fuel code', 1), + (2, 'Approved', 'Fuel code has been approved', 2), + (3, 'Deleted', 'Fuel code has been deleted', 3) + ON CONFLICT (fuel_code_status_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO level_of_equipment (level_of_equipment_id, name, display_order) + VALUES + (1, 'Level 3 - Direct current fast charging', 1), + (2, 'Level 2 - High voltage, operating above level 1', 2), + (3, 'Level 1 - Low voltage, operating at 120V AC or less', 3), + (4, 'Other - Additional information provided in notes field', 4) + ON CONFLICT (level_of_equipment_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO fuel_measurement_type (fuel_measurement_type_id, type, display_order) + VALUES + (1, 'Separate utility meter', 1), + (2, 'Equipment meter (remote access)', 2), + (3, 'Equipment meter (physical access)', 3), + (4, 'No meter or estimated', 4) + ON CONFLICT (fuel_measurement_type_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO compliance_report_status (compliance_report_status_id, status, effective_status) + VALUES + (1, 'Draft', TRUE), + (2, 'Submitted', TRUE), + (3, 'Recommended_by_analyst', TRUE), + (4, 'Recommended_by_manager', TRUE), + (5, 'Assessed', TRUE), + (6, 'Reassessed', TRUE) + ON CONFLICT (compliance_report_status_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO allocation_transaction_type ( + allocation_transaction_type_id, type, description, + display_order, effective_date, effective_status + ) + VALUES + (1, 'Allocated from', 'Fuel allocated from another supplier under an allocation agreement', 1, '2012-01-01', TRUE), + (2, 'Allocated to', 'Fuel allocated to another supplier under an allocation agreement', 2, '2012-01-01', TRUE) + ON CONFLICT (allocation_transaction_type_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO end_user_type (type_name, intended_use) + VALUES + ('Multi-unit residential building', TRUE), + ('Fleet', TRUE), + ('Public', TRUE), + ('Employee', TRUE) + ON CONFLICT (type_name) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO notification_type (notification_type_id, name, description, email_content, create_user, update_user) + VALUES + (1, 'BCEID__COMPLIANCE_REPORT__DIRECTOR_ASSESSMENT', 'Director assessed a compliance report or supplemental report.', 'Email content', 'system', 'system'), + (2, 'BCEID__INITIATIVE_AGREEMENT__DIRECTOR_APPROVAL', 'Director approved the initiative agreement or transaction', 'Email content', 'system', 'system'), + (3, 'BCEID__TRANSFER__DIRECTOR_DECISION', 'Director recorded or refused a transfer request', 'Email content', 'system', 'system'), + (4, 'BCEID__TRANSFER__PARTNER_ACTIONS', 'A transfer partner took action (proposed, declined, rescinded, or signed & submitted) on a transfer request', 'Email content', 'system', 'system'), + (5, 'IDIR_ANALYST__COMPLIANCE_REPORT__DIRECTOR_DECISION', 'Director assessed compliance report', 'Email content', 'system', 'system'), + (6, 'IDIR_ANALYST__COMPLIANCE_REPORT__MANAGER_RECOMMENDATION', 'Compliance manager recommended action on the compliance report.', 'Email content', 'system', 'system'), + (7, 'IDIR_ANALYST__COMPLIANCE_REPORT__SUBMITTED_FOR_REVIEW', 'Compliance report submitted for government analyst review or returned by compliance manager', 'Email content', 'system', 'system'), + (8, 'IDIR_ANALYST__INITIATIVE_AGREEMENT__RETURNED_TO_ANALYST', 'Director approved/returned the initiative agreement to the analyst', 'Email content', 'system', 'system'), + (9, 'IDIR_ANALYST__TRANSFER__DIRECTOR_RECORDED', 'Director recorded or refused a transfer request', 'Email content', 'system', 'system'), + (10, 'IDIR_ANALYST__TRANSFER__RESCINDED_ACTION', 'A transfer request was rescinded by a transfer partner', 'Email content', 'system', 'system'), + (11, 'IDIR_ANALYST__TRANSFER__SUBMITTED_FOR_REVIEW', 'Transfer request submitted for government analyst review', 'Email content', 'system', 'system'), + (12, 'IDIR_COMPLIANCE_MANAGER__COMPLIANCE_REPORT__ANALYST_RECOMMENDATION', 'Analyst recommendation on the compliance report or returned by the director', 'Email content', 'system', 'system'), + (13, 'IDIR_COMPLIANCE_MANAGER__COMPLIANCE_REPORT__DIRECTOR_ASSESSMENT', 'Director assessed a compliance report', 'Email content', 'system', 'system'), + (14, 'IDIR_COMPLIANCE_MANAGER__COMPLIANCE_REPORT__SUBMITTED_FOR_REVIEW', 'Compliance report submitted for government analyst review', 'Email content', 'system', 'system'), + (15, 'IDIR_DIRECTOR__COMPLIANCE_REPORT__MANAGER_RECOMMENDATION', 'Compliance manager recommended action on the compliance report', 'Email content', 'system', 'system'), + (16, 'IDIR_DIRECTOR__INITIATIVE_AGREEMENT__ANALYST_RECOMMENDATION', 'Analyst recommendation provided for the initiative agreement', 'Email content', 'system', 'system'), + (17, 'IDIR_DIRECTOR__TRANSFER__ANALYST_RECOMMENDATION', 'Analyst recommendation provided for the transfer request', 'Email content', 'system', 'system') + ON CONFLICT (notification_type_id) DO NOTHING; + """ + ) + + op.execute( + """ + INSERT INTO notification_channel (notification_channel_id, channel_name, enabled, subscribe_by_default) + VALUES + (1, 'EMAIL', TRUE, TRUE), + (2, 'IN_APP', TRUE, FALSE) + ON CONFLICT (notification_channel_id) DO NOTHING; + """ + ) + + # Update sequences + sequence_mappings = { + "transfer_status": "transfer_status_id", + "transfer_category": "transfer_category_id", + "role": "role_id", + "organization_type": "organization_type_id", + "organization_status": "organization_status_id", + "initiative_agreement_status": "initiative_agreement_status_id", + "compliance_period": "compliance_period_id", + "admin_adjustment_status": "admin_adjustment_status_id", + "notification_channel": "notification_channel_id", + "notification_type": "notification_type_id", + "end_user_type": "end_user_type_id", + "compliance_report_status": "compliance_report_status_id", + "allocation_transaction_type": "allocation_transaction_type_id", + "provision_of_the_act": "provision_of_the_act_id", + "transport_mode": "transport_mode_id", + "fuel_code_prefix": "fuel_code_prefix_id", + "fuel_code_status": "fuel_code_status_id", + "fuel_category": "fuel_category_id", + "fuel_type": "fuel_type_id", + "unit_of_measure": "uom_id", + "additional_carbon_intensity": "additional_uci_id", + "energy_effectiveness_ratio": "eer_id", + "energy_density": "energy_density_id", + "target_carbon_intensity": "target_carbon_intensity_id", + "fuel_instance": "fuel_instance_id", + "level_of_equipment": "level_of_equipment_id", + "fuel_measurement_type": "fuel_measurement_type_id", + } + for table, id_column in sequence_mappings.items(): + if table == "unit_of_measure": + op.execute( + f""" + SELECT setval('unit_of_measure_uom_id_seq', + (SELECT MAX(uom_id) FROM unit_of_measure), true); + """ + ) + else: + op.execute( + f""" + SELECT setval('{table}_{id_column}_seq', + (SELECT MAX({id_column}) FROM {table}), true); + """ + ) + + # + # (14) bfa7bbb1eea3 (2025-01-03): Update 'Other diesel' -> 'Other diesel fuel' + # + op.execute( + """ + UPDATE fuel_type + SET fuel_type = 'Other diesel fuel', + provision_1_id = 3 + WHERE fuel_type = 'Other diesel'; + """ + ) + + # + # (16) 94306eca5261 (2025-01-06): Insert is_legacy to provision_of_the_act + # + # Insert new rows (bulk_insert from the snippet) + # If any of these exact names exist, check for conflict; here we do naive insert + op.execute( + """ + INSERT INTO provision_of_the_act ( + name, description, create_user, update_user, + display_order, effective_date, effective_status, + expiration_date, is_legacy + ) VALUES + ( + 'Prescribed carbon intensity - Section 6 (5) (a)', + 'Prescribed carbon intensity - Section 6 (5) (a)', + 'no_user', 'no_user', + NULL, NULL, TRUE, + NULL, TRUE + ), + ( + 'Prescribed carbon intensity - Section 6 (5) (b)', + 'Prescribed carbon intensity - Section 6 (5) (b)', + 'no_user', 'no_user', + NULL, NULL, TRUE, + NULL, TRUE + ), + ( + 'Approved fuel code - Section 6 (5) (c)', + 'Approved fuel code - Section 6 (5) (c)', + 'no_user', 'no_user', + NULL, NULL, TRUE, + NULL, TRUE + ), + ( + 'Default Carbon Intensity Value - Section 6 (5) (d) (i)', + 'Default Carbon Intensity Value - Section 6 (5) (d) (i)', + 'no_user', 'no_user', + NULL, NULL, TRUE, + NULL, TRUE + ), + ( + 'GHGenius modelled - Section 6 (5) (d) (ii) (A)', + 'GHGenius modelled - Section 6 (5) (d) (ii) (A)', + 'no_user', 'no_user', + NULL, NULL, TRUE, + NULL, TRUE + ), + ( + 'Alternative Method - Section 6 (5) (d) (ii) (B)', + 'Alternative Method - Section 6 (5) (d) (ii) (B)', + 'no_user', 'no_user', + NULL, NULL, TRUE, + NULL, TRUE + ); + """ + ) + + # + # (17) fa98709e7952 (2025-01-06): Add legacy fuel types "Natural gas-based gasoline", "Petroleum-based diesel", "Petroleum-based gasoline" + # + op.execute( + """ + INSERT INTO fuel_type ( + fuel_type, + fossil_derived, + other_uses_fossil_derived, + default_carbon_intensity, + units, + unrecognized, + create_user, + update_user, + is_legacy + ) + VALUES + ( + 'Natural gas-based gasoline', + FALSE, + TRUE, + 90.07, + 'Litres', + FALSE, + 'no_user', + 'no_user', + TRUE + ), + ( + 'Petroleum-based diesel', + FALSE, + TRUE, + 94.76, + 'Litres', + FALSE, + 'no_user', + 'no_user', + TRUE + ), + ( + 'Petroleum-based gasoline', + FALSE, + TRUE, + 88.14, + 'Litres', + FALSE, + 'no_user', + 'no_user', + TRUE + ); + """ + ) + + op.execute( + """ + INSERT INTO energy_density ( + fuel_type_id, + density, + uom_id, + create_user, + update_user + ) + SELECT + ft.fuel_type_id, + CASE + WHEN ft.fuel_type = 'Natural gas-based gasoline' THEN 34.69 + WHEN ft.fuel_type = 'Petroleum-based diesel' THEN 38.65 + WHEN ft.fuel_type = 'Petroleum-based gasoline' THEN 34.69 + END AS density, + 1 AS uom_id, + 'no_user' AS create_user, + 'no_user' AS update_user + FROM fuel_type ft + WHERE ft.fuel_type IN ( + 'Natural gas-based gasoline', + 'Petroleum-based diesel', + 'Petroleum-based gasoline' + ); + """ + ) + + op.execute( + """ + INSERT INTO energy_effectiveness_ratio ( + fuel_category_id, + fuel_type_id, + end_use_type_id, + ratio, + create_user, + update_user, + effective_date, + effective_status, + expiration_date + ) + SELECT + CASE + WHEN ft.fuel_type = 'Petroleum-based diesel' THEN 2 + ELSE 1 + END AS fuel_category_id, + ft.fuel_type_id, + NULL AS end_use_type_id, + 1.0 AS ratio, + 'no_user' AS create_user, + 'no_user' AS update_user, + CURRENT_DATE AS effective_date, + TRUE AS effective_status, + NULL AS expiration_date + FROM fuel_type ft + WHERE ft.fuel_type IN ( + 'Natural gas-based gasoline', + 'Petroleum-based diesel', + 'Petroleum-based gasoline' + ); + """ + ) + + # + # (18) 998929392c8b (2025-01-07): Add marine end use (end_use_type_id=25) plus EER record (eer_id=44) + # + op.execute( + """ + INSERT INTO end_use_type (end_use_type_id, type, intended_use) + VALUES (25, 'Marine', TRUE) + ON CONFLICT (end_use_type_id) DO NOTHING; + """ + ) + op.execute( + """ + INSERT INTO energy_effectiveness_ratio ( + eer_id, fuel_category_id, fuel_type_id, end_use_type_id, ratio, effective_status + ) + VALUES (44, 2, 3, 25, 2.5, TRUE) + ON CONFLICT (eer_id) DO NOTHING; + """ + ) + + # + # (19) fe03799b4018 (2025-01-14): Update other_uses_fossil_derived for certain fuel types + # + op.execute( + """ + UPDATE fuel_type + SET other_uses_fossil_derived = false + WHERE fuel_type IN ( + 'CNG', 'Electricity', 'Hydrogen', 'LNG', 'Propane', + 'Natural gas-based gasoline', 'Petroleum-based diesel', + 'Petroleum-based gasoline' + ) + """ + ) + op.execute( + """ + UPDATE fuel_type + SET other_uses_fossil_derived = true + WHERE fuel_type IN ( + 'Alternative jet fuel', 'Biodiesel', 'Ethanol', 'HDRD', + 'Other diesel fuel', 'Renewable gasoline', 'Renewable naphtha' + ) + """ + ) + + # + # (20) 5bc0ef48739a (2025-01-15): Add Truck and Marine transport mode + # (Though it references 'Marine', we already changed it above. We'll do as-is.) + # + current_time = datetime.now() + op.execute( + f""" + INSERT INTO transport_mode (transport_mode, create_date, update_date, create_user, update_user) + VALUES + ('Truck', '{current_time}', '{current_time}', 'no_user', 'no_user'), + ('Marine', '{current_time}', '{current_time}', 'no_user', 'no_user') + """ + ) + + +def downgrade(): + """ + Consolidated DOWNGRADE logic in reverse chronological order: + + (20) 5bc0ef48739a (2025-01-15) + (19) fe03799b4018 (2025-01-14) + (18) 998929392c8b (2025-01-07) + (17) fa98709e7952 (2025-01-06) + (16) 94306eca5261 (2025-01-06) + (15) e883ad1f0f60 (2025-01-03) + (14) bfa7bbb1eea3 (2025-01-03) + (13) d9cdd9fca0ce (2024-12-24) + (12) ab04810d4d7c (2024-12-22) + (11) 5fbcb508c1be (2024-12-21) + (10) 59873cafbcd8 (2024-12-20) + (9) 851e09cf8661 (2024-12-17) + (8) 5d729face5ab (2024-12-12) + (7) 7ae38a8413ab (2024-12-09) + (6) 26ab15f8ab18 (2024-12-06) + (5) d4104af84f2b (2024-12-05) + (4) 8491890dd688 (2024-12-04) + (3) 9206124a098b (2024-12-04) + (2) aeaa26f5cdd5 (2024-12-02) + (1) 043c52082a3b (2024-11-27) + """ + + # + # (20) 5bc0ef48739a (Downgrade): Remove Truck, Marine transport modes + # + op.execute( + """ + DELETE FROM transport_mode + WHERE transport_mode IN ('Truck', 'Marine') + """ + ) + + # + # (19) fe03799b4018 (Downgrade): Revert the other_uses_fossil_derived changes + # + op.execute( + """ + UPDATE fuel_type + SET other_uses_fossil_derived = true + WHERE fuel_type IN ( + 'CNG', 'Electricity', 'Hydrogen', 'LNG', 'Propane', + 'Natural gas-based gasoline', 'Petroleum-based diesel', + 'Petroleum-based gasoline' + ) + """ + ) + op.execute( + """ + UPDATE fuel_type + SET other_uses_fossil_derived = false + WHERE fuel_type IN ( + 'Alternative jet fuel', 'Biodiesel', 'Ethanol', 'HDRD', + 'Other diesel fuel', 'Renewable gasoline', 'Renewable naphtha' + ) + """ + ) + + # + # (18) 998929392c8b (Downgrade): Remove EER (id=44) + remove end_use_type (id=25) + # + op.execute( + """ + DELETE FROM energy_effectiveness_ratio + WHERE eer_id = 44; + """ + ) + op.execute( + """ + DELETE FROM end_use_type + WHERE end_use_type_id = 25; + """ + ) + + # + # (17) fa98709e7952 (Downgrade): Remove the newly inserted "Natural gas-based gasoline," etc. + # + op.execute( + """ + DELETE FROM energy_effectiveness_ratio + WHERE fuel_type_id IN ( + SELECT fuel_type_id + FROM fuel_type + WHERE fuel_type IN ( + 'Natural gas-based gasoline', + 'Petroleum-based diesel', + 'Petroleum-based gasoline' + ) + ); + """ + ) + op.execute( + """ + DELETE FROM energy_density + WHERE fuel_type_id IN ( + SELECT fuel_type_id + FROM fuel_type + WHERE fuel_type IN ( + 'Natural gas-based gasoline', + 'Petroleum-based diesel', + 'Petroleum-based gasoline' + ) + ); + """ + ) + op.execute( + """ + DELETE FROM fuel_type + WHERE fuel_type IN ( + 'Natural gas-based gasoline', + 'Petroleum-based diesel', + 'Petroleum-based gasoline' + ); + """ + ) + + # + # (16) 94306eca5261 (Downgrade): Drop is_legacy from provision_of_the_act + # + op.drop_column("provision_of_the_act", "is_legacy") + + # + # (14) bfa7bbb1eea3 (Downgrade): Revert fuel_type = 'Other diesel fuel' -> 'Other diesel' + # + op.execute( + """ + UPDATE fuel_type + SET fuel_type = 'Other diesel', + provision_1_id = 1 + WHERE fuel_type = 'Other diesel fuel'; + """ + ) + + # + # (13) d9cdd9fca0ce (Downgrade): Clear all seeded data, in groups + # + table_groups = [ + [ + "fuel_instance", + "target_carbon_intensity", + "additional_carbon_intensity", + "energy_density", + "energy_effectiveness_ratio", + "fuel_code", # if it exists + ], + [ + "notification_channel", + "notification_type", + "end_user_type", + "allocation_transaction_type", + "compliance_report_status", + "fuel_measurement_type", + "level_of_equipment", + ], + [ + "fuel_type", + "fuel_category", + "transport_mode", + "fuel_code_prefix", + "fuel_code_status", + "end_use_type", + ], + [ + "expected_use_type", + "unit_of_measure", + "provision_of_the_act", + "initiative_agreement_status", + "admin_adjustment_status", + "transfer_category", + "transfer_status", + "role", + "organization_status", + "organization_type", + "compliance_period", + ], + ] + for group in table_groups: + tables_list = ", ".join(group) + op.execute(f"TRUNCATE TABLE {tables_list} CASCADE;") + + # + # (12) ab04810d4d7c (Downgrade): Drop unique constraint from target_carbon_intensity + # + op.drop_constraint( + "uq_target_carbon_intensity_compliance_fuel", + "target_carbon_intensity", + type_="unique", + ) + + # + # (11) 5fbcb508c1be (Downgrade): Rename end_use_type_id=19 back + # + op.execute( + """ + UPDATE end_use_type + SET type = 'Compression-ignition engine- Marine, with methane slip reduction kit- Operated within 51 to 75% of load range' + WHERE end_use_type_id = 19 + """ + ) + + # + # (10) 59873cafbcd8 (Downgrade): Restore 'Other diesel' fossil_derived = true, other_uses_fossil_derived = true + # + op.execute( + """ + UPDATE fuel_type + SET fossil_derived = true, other_uses_fossil_derived = true + WHERE fuel_type = 'Other diesel' + """ + ) + + # + # (9) 851e09cf8661 (Downgrade): Drop the default_carbon_intensity column from fuel_category + # + op.drop_column("fuel_category", "default_carbon_intensity") + + # + # (8) 5d729face5ab (Downgrade): Revert default_carbon_intensity of 'Other diesel' (id=20) to 94.38 + # + op.execute( + """ + UPDATE fuel_type + SET default_carbon_intensity = 94.38 + WHERE fuel_type_id = 20 + """ + ) + + # + # (7) 7ae38a8413ab (Downgrade): Revert volume-based fuels to false, gas-based to true + # + current_time = datetime.now() + op.execute( + f""" + UPDATE fuel_type + SET other_uses_fossil_derived = false, + update_date = '{current_time}', + update_user = 'no_user' + WHERE fuel_type IN ( + 'Alternative jet fuel', + 'Biodiesel', + 'Ethanol', + 'HDRD', + 'Renewable gasoline', + 'Renewable naphtha' + ) + """ + ) + op.execute( + f""" + UPDATE fuel_type + SET other_uses_fossil_derived = true, + update_date = '{current_time}', + update_user = 'no_user' + WHERE fuel_type IN ( + 'CNG', + 'Electricity', + 'Hydrogen', + 'LNG', + 'Propane' + ) + """ + ) + + # + # (6) 26ab15f8ab18 (Downgrade): Restore original end_use_type + additional_carbon_intensity + EER + # + current_time = datetime.now() + original_values = [ + (14, "Marine", "General"), + (15, "Marine", "Operated within 51 to 75% of load range"), + (16, "Marine", "Operated within 76 to 100% of load range"), + (17, "Marine, w/ methane slip reduction kit", "General"), + ( + 18, + "Marine, w/ methane slip reduction kit", + "Operated within 51 to 75% of load range", + ), + ( + 19, + "Marine, w/ methane slip reduction kit", + "Operated within 76 to 100% of load range", + ), + (20, "Unknown", None), + (21, "Aircraft", None), + ] + for end_use_id, type_name, sub_type in original_values: + if sub_type: + op.execute( + f""" + UPDATE end_use_type + SET type = '{type_name}', + sub_type = '{sub_type}', + update_date = '{current_time}', + update_user = 'no_user' + WHERE end_use_type_id = {end_use_id} + """ + ) + else: + op.execute( + f""" + UPDATE end_use_type + SET type = '{type_name}', + sub_type = NULL, + update_date = '{current_time}', + update_user = 'no_user' + WHERE end_use_type_id = {end_use_id} + """ + ) + + uci_originals = [ + (1, 7, 5, 14, 27.3), + (2, 7, 5, 15, 17.8), + (3, 7, 5, 16, 12.2), + (4, 7, 5, 17, 10.6), + (5, 7, 5, 18, 8.4), + (6, 7, 5, 19, 8.0), + (7, 7, 5, 20, 27.3), + (8, 7, 5, None, 0), + (9, None, 5, None, 0), + ] + for uci_id, fuel_type_id, uom_id, eut_id, intensity in uci_originals: + if fuel_type_id and eut_id: + op.execute( + f""" + UPDATE additional_carbon_intensity + SET fuel_type_id = {fuel_type_id}, + uom_id = {uom_id}, + end_use_type_id = {eut_id}, + intensity = {intensity}, + update_date = '{current_time}', + update_user = 'no_user' + WHERE additional_uci_id = {uci_id} + """ + ) + elif fuel_type_id: + op.execute( + f""" + UPDATE additional_carbon_intensity + SET fuel_type_id = {fuel_type_id}, + uom_id = {uom_id}, + end_use_type_id = NULL, + intensity = {intensity}, + update_date = '{current_time}', + update_user = 'no_user' + WHERE additional_uci_id = {uci_id} + """ + ) + else: + op.execute( + f""" + UPDATE additional_carbon_intensity + SET fuel_type_id = NULL, + uom_id = {uom_id}, + end_use_type_id = NULL, + intensity = {intensity}, + update_date = '{current_time}', + update_user = 'no_user' + WHERE additional_uci_id = {uci_id} + """ + ) + + eer_originals = [ + (14, 2, 3, 14, 2.5), + (15, 2, 3, 10, 2.8), + (16, 2, 3, 11, 2.4), + (17, 2, 3, 2, 1.0), + (18, 2, 6, 3, 1.8), + (19, 2, 6, 2, 0.9), + (20, 2, 7, 12, 1.0), + (21, 2, 7, 2, 0.9), + (22, 2, 13, None, 0.9), + (23, 3, 3, None, 2.5), + (24, 3, 11, None, 1.0), + ] + for eer_id, fc_id, ft_id, eut_id, ratio in eer_originals: + if eut_id: + op.execute( + f""" + UPDATE energy_effectiveness_ratio + SET fuel_category_id = {fc_id}, + fuel_type_id = {ft_id}, + end_use_type_id = {eut_id}, + ratio = {ratio}, + update_date = '{current_time}', + update_user = 'no_user' + WHERE eer_id = {eer_id} + """ + ) + else: + op.execute( + f""" + UPDATE energy_effectiveness_ratio + SET fuel_category_id = {fc_id}, + fuel_type_id = {ft_id}, + end_use_type_id = NULL, + ratio = {ratio}, + update_date = '{current_time}', + update_user = 'no_user' + WHERE eer_id = {eer_id} + """ + ) + + # + # (5) d4104af84f2b (Downgrade): Restore notification_type table to old enum-based approach + # + op.execute("DELETE FROM notification_type;") + + # Recreate old enum + notification_type_enum_v2 = ENUM( + "TRANSFER_PARTNER_UPDATE", + "TRANSFER_DIRECTOR_REVIEW", + "INITIATIVE_APPROVED", + "INITIATIVE_DA_REQUEST", + "SUPPLEMENTAL_REQUESTED", + "DIRECTOR_ASSESSMENT", + name="notification_type_enum_v2", + ) + notification_type_enum_v2.create(op.get_bind(), checkfirst=False) + + # Convert the name column back to enum + with op.batch_alter_table("notification_type") as batch_op: + batch_op.alter_column( + "name", + type_=notification_type_enum_v2, + postgresql_using="name::notification_type_enum_v2", + existing_type=sa.String(length=255), + existing_nullable=False, + ) + + # Re-insert old data + op.execute( + """ + INSERT INTO notification_type (notification_type_id, name, description, email_content, create_user, update_user) + VALUES + (1, 'TRANSFER_PARTNER_UPDATE', 'Transfer partner update notification', 'Email content for transfer partner update', 'system', 'system'), + (2, 'TRANSFER_DIRECTOR_REVIEW', 'Director review notification', 'Email content for director review', 'system', 'system'), + (3, 'INITIATIVE_APPROVED', 'Initiative approved notification', 'Email content for initiative approval', 'system', 'system'), + (4, 'INITIATIVE_DA_REQUEST', 'DA request notification', 'Email content for DA request', 'system', 'system'), + (5, 'SUPPLEMENTAL_REQUESTED', 'Supplemental requested notification', 'Email content for supplemental request', 'system', 'system'), + (6, 'DIRECTOR_ASSESSMENT', 'Director assessment notification', 'Email content for director assessment', 'system', 'system'); + """ + ) + + op.execute( + """ + SELECT setval('notification_type_notification_type_id_seq', + (SELECT MAX(notification_type_id) FROM notification_type)); + """ + ) + + # + # (4) 8491890dd688 (Downgrade): No direct reversion steps were provided, so pass. + # + # The original only did data updates; no direct reverts specified. + pass + + # + # (3) 9206124a098b (Downgrade): Remove column organization_name from final_supply_equipment + # + op.drop_column("final_supply_equipment", "organization_name") + + # + # (2) aeaa26f5cdd5 (Downgrade): Revert "Other - Additional information..." to "Other" in level_of_equipment + # + op.execute( + """ + UPDATE level_of_equipment + SET name = 'Other' + WHERE name = 'Other - Additional information provided in notes field' + """ + ) + + # + # (1) 043c52082a3b (Downgrade): Revert Marine-domestic -> Marine and remove Marine-international + # + op.execute( + f""" + UPDATE transport_mode + SET transport_mode = 'Marine', + update_date = '{datetime.utcnow()}', + update_user = 'no_user' + WHERE transport_mode = 'Marine-domestic' + """ + ) + op.execute( + """ + DELETE FROM transport_mode + WHERE transport_mode = 'Marine-international' + """ + ) diff --git a/backend/lcfs/web/api/compliance_report/update_service.py b/backend/lcfs/web/api/compliance_report/update_service.py index 47b73ff8a..5f26e330e 100644 --- a/backend/lcfs/web/api/compliance_report/update_service.py +++ b/backend/lcfs/web/api/compliance_report/update_service.py @@ -302,6 +302,6 @@ async def handle_assessed_status(self, report: ComplianceReport): await self.repo.update_compliance_report(report) async def handle_reassessed_status(self, report: ComplianceReport): - """Handle actions when a report is ReAssessed.""" - # Implement logic for ReAssessed status + """Handle actions when a report is Reassessed.""" + # Implement logic for Reassessed status pass diff --git a/frontend/src/assets/locales/en/reports.json b/frontend/src/assets/locales/en/reports.json index a9d80c348..e97a0b5ad 100644 --- a/frontend/src/assets/locales/en/reports.json +++ b/frontend/src/assets/locales/en/reports.json @@ -146,7 +146,7 @@ "Recommended by manager": "Recommended {{createDate}} by {{firstName}} {{lastName}}.", "Assessed": "Assessed {{createDate}} by {{firstName}} {{lastName}}.", "AssessedBy": "Assessed {{createDate}} by the director under the Low Carbon Fuels Act.", - "ReAssessed": "Re-assessed" + "Reassessed": "Re-assessed" }, "internalComments": "Internal comments", "fuelLabels": { From 43e71b0e4ffacb1a52b76c366046773d556f1fb4 Mon Sep 17 00:00:00 2001 From: Alex Zorkin Date: Mon, 20 Jan 2025 15:30:55 -0800 Subject: [PATCH 3/5] fix: filter transactions on assessed only --- .../db/migrations/versions/2025-01-20-14-37_f217cd32474b.py | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/backend/lcfs/db/migrations/versions/2025-01-20-14-37_f217cd32474b.py b/backend/lcfs/db/migrations/versions/2025-01-20-14-37_f217cd32474b.py index 93b4629ee..d832e02de 100644 --- a/backend/lcfs/db/migrations/versions/2025-01-20-14-37_f217cd32474b.py +++ b/backend/lcfs/db/migrations/versions/2025-01-20-14-37_f217cd32474b.py @@ -1102,7 +1102,8 @@ def recreate_mv_transaction_aggregate_with_compliance_report(): JOIN compliance_report_status crs ON cr.current_status_id = crs.compliance_report_status_id JOIN compliance_period cp ON cr.compliance_period_id = cp.compliance_period_id JOIN "transaction" tr ON cr.transaction_id = tr.transaction_id - AND cr.transaction_id IS NOT NULL; + AND cr.transaction_id IS NOT NULL + WHERE crs.status = 'Assessed'; """ ) op.execute( From b4b79669fe2dcd5b54240995932af29f13bac950 Mon Sep 17 00:00:00 2001 From: Alex Zorkin Date: Mon, 20 Jan 2025 15:32:05 -0800 Subject: [PATCH 4/5] fix: reassessed including in transaction cr filter --- .../db/migrations/versions/2025-01-20-14-37_f217cd32474b.py | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/backend/lcfs/db/migrations/versions/2025-01-20-14-37_f217cd32474b.py b/backend/lcfs/db/migrations/versions/2025-01-20-14-37_f217cd32474b.py index d832e02de..85ff84d38 100644 --- a/backend/lcfs/db/migrations/versions/2025-01-20-14-37_f217cd32474b.py +++ b/backend/lcfs/db/migrations/versions/2025-01-20-14-37_f217cd32474b.py @@ -1103,7 +1103,7 @@ def recreate_mv_transaction_aggregate_with_compliance_report(): JOIN compliance_period cp ON cr.compliance_period_id = cp.compliance_period_id JOIN "transaction" tr ON cr.transaction_id = tr.transaction_id AND cr.transaction_id IS NOT NULL - WHERE crs.status = 'Assessed'; + WHERE crs.status IN ('Assessed', 'Reassessed'); """ ) op.execute( From 7270626ebd8e22986865d9bca71081fb1576bb61 Mon Sep 17 00:00:00 2001 From: Arturo Reyes Lopez Date: Tue, 21 Jan 2025 15:58:51 -0700 Subject: [PATCH 5/5] Users component having infinite re-renders affecting pagination --- frontend/src/views/Admin/AdminMenu/components/Users.jsx | 5 +++-- 1 file changed, 3 insertions(+), 2 deletions(-) diff --git a/frontend/src/views/Admin/AdminMenu/components/Users.jsx b/frontend/src/views/Admin/AdminMenu/components/Users.jsx index 82a13c93f..502a6a793 100644 --- a/frontend/src/views/Admin/AdminMenu/components/Users.jsx +++ b/frontend/src/views/Admin/AdminMenu/components/Users.jsx @@ -31,10 +31,11 @@ export const Users = () => { const gridOptions = { overlayNoRowsTemplate: t('admin:usersNotFound') } - const defaultSortModel = [ + const defaultSortModel = useMemo(() => [ { field: 'isActive', direction: 'desc' }, { field: 'firstName', direction: 'asc' } - ] + ], []); + const navigate = useNavigate() const handleNewUserClick = () => {