diff --git a/bcts/other/mv_licence_issued_advertised_lrm.sql b/bcts/other/mv_licence_issued_advertised_lrm.sql new file mode 100644 index 0000000..141144c --- /dev/null +++ b/bcts/other/mv_licence_issued_advertised_lrm.sql @@ -0,0 +1,363 @@ +create materialized view bcts_staging.mv_licence_issued_advertised_lrm as +/* qLicenceIssuedAdvertised_LRM */ + + /* Licence Info */ +with licence as + ( + select + licn_seq_nbr, + case + when + TSO_CODE in ('TBA', 'TPL', 'TPG', 'TSK', 'TSN', 'TCC', 'TKA', 'TKO', 'TOC') + then + 'Interior' + when + TSO_CODE in ('TCH', 'TST', 'TSG') + then + 'Coast' + end as BUSINESS_AREA_REGION_CATEGORY, + case + when + TSO_CODE in ('TBA', 'TPL', 'TPG', 'TSK', 'TSN') + then + 'North Interior' + when + TSO_CODE in ('TCC', 'TKA', 'TKO', 'TOC') + then + 'South Interior' + when + TSO_CODE in ('TCH', 'TST', 'TSG') + then + 'Coast' + end as BUSINESS_AREA_REGION, + (CASE + WHEN TSO_NAME = 'Seaward' THEN 'Seaward-Tlasta' + ELSE TSO_NAME + END) || ' (' || TSO_CODE || ')' AS BUSINESS_AREA, + + Licence_ID, + nav_name as Management_Unit, + District_Name as District, + Licn_Category_ID as Category_ID_LRM, + Category as Category_LRM + from + bcts_staging.v_licence), + /* Total Licence Info -- Info about all blocks in licence */ + total_licence_info as + ( + select + B.LICN_SEQ_NBR, + count(*) as count_all_blocks_in_licence, + Sum(B.BLAL_RW_VOL) AS LRM_RW_VOLUME, + Sum(B.CRUISE_VOL) AS LRM_CRUISE_VOLUME, + Sum(COALESCE(CRUISE_VOL,0) + COALESCE(BLAL_RW_VOL,0)) AS LRM_TOTAL_VOLUME + from + BCTS_STAGING.V_BLOCK B + group by + b.licn_seq_nbr + ), + /* + salvage_all_fire_year + + Volume of blocks within licence that have any SFIRE## activities. + If a block has multiple salvage fire years, the block volume is only + included once in the total; no double-counting. + */ + salvage_all_fire_year as + ( + select + B.LICN_SEQ_NBR, + count(*) as count_blocks_salvage_any_fire_year, + Sum(B.BLAL_RW_VOL) AS LRM_RW_VOLUME_SALVAGE_ALL_FIRE_YEARS, + Sum(B.CRUISE_VOL) AS LRM_CRUISE_VOLUME_SALVAGE_ALL_FIRE_YEARS, + Sum(COALESCE(CRUISE_VOL,0) + COALESCE(BLAL_RW_VOL,0)) AS LRM_TOTAL_VOLUME_SALVAGE_ALL_FIRE_YEARS + from + BCTS_STAGING.V_BLOCK B + INNER JOIN + ( + /* + This distinct clause ensures each block is only counted once + if it has any SFIRE activities. + */ + select distinct + cutb_seq_nbr + + from + BCTS_STAGING.v_block_activity_all + + where + activity_class = 'CSB' + and actt_key_ind like 'SFIRE%' + ) block_with_any_sfire_year + ON + b.cutb_seq_nbr = block_with_any_sfire_year.cutb_seq_nbr + group by + B.TSO_CODE, + B.TSO_NAME, + licn_seq_nbr + ), + + /* + salvage21fire + + Volume within licence that is salvage from a 2021 fire. + Only blocks with SFIRE21 activity are included. + + */ + salvage21fire as + ( + SELECT + B.LICN_SEQ_NBR, + count(*) as count_blocks_salvage_21_fire, + Sum(B.BLAL_RW_VOL) AS LRM_RW_VOLUME_SALVAGE_2021_FIRE, + Sum(B.CRUISE_VOL) AS LRM_CRUISE_VOLUME_SALVAGE_2021_FIRE, + Sum(COALESCE(CRUISE_VOL,0) + COALESCE(BLAL_RW_VOL,0)) AS LRM_TOTAL_VOLUME_SALVAGE_2021_FIRE + FROM + BCTS_STAGING.V_BLOCK B + INNER JOIN + ( + /* + The SFIRE21 activity can be entered multiple times for the same + block. The SFIRE21 activity is meant to be present for + blocks that are salvage from 2021 fires, and absent for those + that are not. Multiple entries of the activity on one block are + meaningless. For the purposes of this query, we assume that + multiple entries are intended to indicate the block is salvage. + This DISTINCT query ensures we only count the block volume once + for each SFIRE21 activity on the block. + */ + select distinct + cutb_seq_nbr + from + BCTS_STAGING.v_block_activity_all + where + activity_class = 'CSB' + and actt_key_ind = 'SFIRE21' + ) block_with_sfire21 + ON + b.cutb_seq_nbr = block_with_sfire21.cutb_seq_nbr + GROUP BY + B.LICN_SEQ_NBR + ), + + salvage22fire as + /* + salvage22fire + + Volume within licence that is salvage from a 2022 fire. + Only blocks with SFIRE22 activity are included. + + */ + ( + SELECT + B.LICN_SEQ_NBR, + count(*) as count_blocks_salvage_22_fire, + Sum(B.BLAL_RW_VOL) AS LRM_RW_VOLUME_SALVAGE_2022_FIRE, + Sum(B.CRUISE_VOL) AS LRM_CRUISE_VOLUME_SALVAGE_2022_FIRE, + Sum(COALESCE(CRUISE_VOL,0) + COALESCE(BLAL_RW_VOL,0)) AS LRM_TOTAL_VOLUME_SALVAGE_2022_FIRE + FROM + bcts_staging.V_BLOCK B + INNER JOIN + ( + /* + The SFIRE22 activity can be entered multiple times for the same + block. The SFIRE22 activity is meant to be present for + blocks that are salvage from 2022 fires, and absent for those + that are not. Multiple entries of the activity on one block are + meaningless. For the purposes of this query, we assume that + multiple entries are intended to indicate the block is salvage. + This DISTINCT query ensures we only count the block volume once + for each SFIRE22 activity on the block. + */ + select distinct + cutb_seq_nbr + from + bcts_staging.v_block_activity_all + where + activity_class = 'CSB' + and actt_key_ind = 'SFIRE22' + ) block_with_sfire22 + ON + b.cutb_seq_nbr = block_with_sfire22.cutb_seq_nbr + GROUP BY + B.LICN_SEQ_NBR + ), + + /* + salvage23fire + + Volume within licence that is salvage from a 2023 fire. + Only blocks with SFIRE23 activity are included. + */ + salvage23fire as + ( + SELECT + B.LICN_SEQ_NBR, + count(*) as count_blocks_salvage_23_fire, + Sum(B.BLAL_RW_VOL) AS LRM_RW_VOLUME_SALVAGE_2023_FIRE, + Sum(B.CRUISE_VOL) AS LRM_CRUISE_VOLUME_SALVAGE_2023_FIRE, + Sum(COALESCE(CRUISE_VOL,0) + COALESCE(BLAL_RW_VOL,0)) AS LRM_TOTAL_VOLUME_SALVAGE_2023_FIRE + FROM + bcts_staging.V_BLOCK B + INNER JOIN + ( + /* + The SFIRE23 activity can be entered multiple times for the same + block. The SFIRE23 activity is meant to be present for + blocks that are salvage from 2023 fires, and absent for those + that are not. Multiple entries of the activity on one block are + meaningless. For the purposes of this query, we assume that + multiple entries are intended to indicate the block is salvage. + This DISTINCT query ensures we only count the block volume once + for each SFIRE23 activity on the block. + */ + select distinct + cutb_seq_nbr + from + bcts_staging.v_block_activity_all + where + activity_class = 'CSB' + and actt_key_ind = 'SFIRE23' + ) block_with_sfire23 + ON + b.cutb_seq_nbr = block_with_sfire23.cutb_seq_nbr + GROUP BY + B.LICN_SEQ_NBR + ), + + /* + salvage24fire + + Volume within licence that is salvage from a 2024 fire. + Only blocks with SFIRE24 activity are included. + + As at 2024-02-13, this activity code has not been deployed; + it is scripted here in anticipation of future deployment. + */ + salvage24fire as + ( + SELECT + B.LICN_SEQ_NBR, + count(*) as count_blocks_salvage_24_fire, + Sum(B.BLAL_RW_VOL) AS LRM_RW_VOLUME_SALVAGE_2024_FIRE, + Sum(B.CRUISE_VOL) AS LRM_CRUISE_VOLUME_SALVAGE_2024_FIRE, + Sum(COALESCE(CRUISE_VOL,0) + COALESCE(BLAL_RW_VOL,0)) AS LRM_TOTAL_VOLUME_SALVAGE_2024_FIRE + FROM + bcts_staging.V_BLOCK B + INNER JOIN + ( + /* + The SFIRE24 activity can be entered multiple times for the same + block. The SFIRE24 activity is meant to be present for + blocks that are salvage from 2024 fires, and absent for those + that are not. Multiple entries of the activity on one block are + meaningless. For the purposes of this query, we assume that + multiple entries are intended to indicate the block is salvage. + This DISTINCT query ensures we only count the block volume once + for each SFIRE24 activity on the block. + */ + select distinct + cutb_seq_nbr + from + bcts_staging.v_block_activity_all + where + activity_class = 'CSB' + and actt_key_ind = 'SFIRE24' + ) block_with_sfire24 + ON + b.cutb_seq_nbr = block_with_sfire24.cutb_seq_nbr + GROUP BY + B.LICN_SEQ_NBR + ), + /* + salvage25fire + + Volume within licence that is salvage from a 2025 fire. + Only blocks with SFIRE25 activity are included. + + As at 2024-02-13, this activity code has not been deployed; + it is scripted here in anticipation of future deployment. + */ + salvage25fire as + ( + SELECT + B.LICN_SEQ_NBR, + count(*) as count_blocks_salvage_25_fire, + Sum(B.BLAL_RW_VOL) AS LRM_RW_VOLUME_SALVAGE_2025_FIRE, + Sum(B.CRUISE_VOL) AS LRM_CRUISE_VOLUME_SALVAGE_2025_FIRE, + Sum(COALESCE(CRUISE_VOL,0) + COALESCE(BLAL_RW_VOL,0)) AS LRM_TOTAL_VOLUME_SALVAGE_2025_FIRE + FROM + bcts_staging.V_BLOCK B + INNER JOIN + ( + /* + The SFIRE25 activity can be entered multiple times for the same + block. The SFIRE25 activity is meant to be present for + blocks that are salvage from 2025 fires, and absent for those + that are not. Multiple entries of the activity on one block are + meaningless. For the purposes of this query, we assume that + multiple entries are intended to indicate the block is salvage. + This DISTINCT query ensures we only count the block volume once + for each SFIRE25 activity on the block. + */ + select distinct + cutb_seq_nbr + from + bcts_staging.v_block_activity_all + where + activity_class = 'CSB' + and actt_key_ind = 'SFIRE25' + ) block_with_sfire25 + ON + b.cutb_seq_nbr = block_with_sfire25.cutb_seq_nbr + GROUP BY + B.LICN_SEQ_NBR + ) + + +select + licence.business_area_region_category, + licence.business_area_region, + licence.business_area, + licence.licence_id, + licence.Management_Unit, + licence.District, + licence.Category_ID_LRM, + total_licence_info.LRM_TOTAL_VOLUME, + total_licence_info.count_all_blocks_in_licence, + salvage_all_fire_year.LRM_TOTAL_VOLUME_SALVAGE_ALL_FIRE_YEARS, + salvage_all_fire_year.count_blocks_salvage_any_fire_year, + salvage21fire.LRM_TOTAL_VOLUME_SALVAGE_2021_FIRE, + salvage21fire.count_blocks_salvage_21_fire, + salvage22fire.LRM_TOTAL_VOLUME_SALVAGE_2022_FIRE, + salvage22fire.count_blocks_salvage_22_fire, + salvage23fire.LRM_TOTAL_VOLUME_SALVAGE_2023_FIRE, + salvage23fire.count_blocks_salvage_23_fire, + salvage24fire.LRM_TOTAL_VOLUME_SALVAGE_2024_FIRE, + salvage24fire.count_blocks_salvage_24_fire, + salvage25fire.LRM_TOTAL_VOLUME_SALVAGE_2025_FIRE, + salvage25fire.count_blocks_salvage_25_fire, + licence.licn_seq_nbr + +from licence +left join total_licence_info +on licence.licn_seq_nbr = total_licence_info.licn_seq_nbr +left join salvage_all_fire_year +on licence.licn_seq_nbr = salvage_all_fire_year.licn_seq_nbr +left join salvage21fire +on licence.licn_seq_nbr = salvage21fire.licn_seq_nbr +left join salvage22fire +on licence.licn_seq_nbr = salvage22fire.licn_seq_nbr +left join salvage23fire +on licence.licn_seq_nbr = salvage23fire.licn_seq_nbr +left join salvage24fire +on licence.licn_seq_nbr = salvage24fire.licn_seq_nbr +left join salvage25fire +on licence.licn_seq_nbr = salvage25fire.licn_seq_nbr + +order by + business_area_region_category desc, + business_area_region, + business_area, + licence_id +; \ No newline at end of file diff --git a/bcts/other/mv_licence_issued_advertised_main.sql b/bcts/other/mv_licence_issued_advertised_main.sql new file mode 100644 index 0000000..1ca4c2c --- /dev/null +++ b/bcts/other/mv_licence_issued_advertised_main.sql @@ -0,0 +1,62 @@ +create materialized view bcts_staging.mv_licence_issued_advertised_main as +SELECT + official.Business_Area_Region_Category, + official.Business_Area_Region, + official.Business_Area, + lrm.Management_Unit, + lrm.District, + Official.X_Axis_Date, + Official.X_Axis_Fiscal, + Official.X_Axis_Quarter, + official.forest_file_id AS Licence, + official.File_Type_Code, + Official.Auction_Count_All_Time_to_Report_Period_End, + Official.First_Auction_Date, + Official.First_Auction_Fiscal, + Official.First_Auction_Quarter, + Official.First_BCTS_Category_Code, + Official.First_Auction_Volume, + Official.First_Auction_Category_A_and_1_Volume, + Official.First_Auction_Category_2_and_4_Volume, + Official.First_Auction_Volume_is_in_Report_Period, + Official.First_Auction_Category_A_and_1_Volume_is_in_Report_Period, + Official.First_Auction_Category_2_and_4_Volume_is_in_Report_Period, + Official.Last_Auction_Date, + Official.Last_Auction_Fiscal, + Official.Last_Auction_Quarter, + Official.Last_Auction_BCTS_Category_Code, + Official.Last_Auction_Volume, + Official.Last_Auction_Category_A_and_1_Volume, + Official.Last_Auction_Category_2_and_4_Volume, + Official.Original_Cat_2_and_4_Readvertised_Cat_A_and_1_Volume, + Official.Original_Cat_A_and_1_Readvertised_Cat_2_and_4_Volume, + Official.Last_Auction_No_Sale_Rationale, + Official.Last_Auction_No_Sale_Volume, + Official.Last_Auction_No_Sale_Category_A_1_Volume, + Official.Last_Auction_No_Sale_Category_2_4_Volume, + Official.Last_Auction_No_Sale, + Official.Last_Auction_No_Sale_Cat_A, + Official.Last_Auction_No_Sale_Cat_2_4, + Official.Issued_Licence_Legal_Effective_Date, + Official.Issued_Licence_Legal_Effective_Fiscal, + Official.Issued_Licence_Legal_Effective_Quarter, + Official.Issued_Licence_BCTS_Category_Code, + Official.Issued_Licence_Volume, + Official.Category_A_and_1_Issued_Volume, + Official.Category_2_and_4_Issued_Volume, + Official.Issued_Licence_Maximum_Value, + Official.Issued_licence_maximum_value_Cat_A, + Official.Issued_licence_maximum_value_Cat_2_4, + Official.Issued_Licence_Client_Number, + Official.Issued_Licence_Client_Name, + official.Issued_in_Report_Period, + Official.Issued_in_Report_Period_Cat_A, + Official.Issued_in_Report_Period_Cat_2_4, + official.Advertised_in_Report_Period, + round(lrm.LRM_Total_Volume_Salvage_All_Fire_Years) AS Total_Volume_Salvage_All_Fire_Year_LRM, + Official.FTA_File_Status, + Official.FTA_File_Status_Date +FROM + bcts_staging.mv_licence_issued_advertised_official AS official + LEFT JOIN bcts_staging.mv_licence_issued_advertised_lrm AS lrm + ON official.forest_file_id = lrm.licence_id \ No newline at end of file diff --git a/bcts/other/v_reporting_date_ranges.sql b/bcts/other/v_reporting_date_ranges.sql new file mode 100644 index 0000000..a8f9f6b --- /dev/null +++ b/bcts/other/v_reporting_date_ranges.sql @@ -0,0 +1,162 @@ +CREATE OR REPLACE VIEW bcts_staging.report_date_ranges AS +SELECT + -- 1. Fiscal year (April 1) to 15th/end of current/last month + CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) < 4 THEN DATE_TRUNC('year', CURRENT_DATE) - INTERVAL '9 months' + ELSE DATE_TRUNC('year', CURRENT_DATE) + INTERVAL '3 months' + END AS start_date, + CASE + WHEN EXTRACT(DAY FROM CURRENT_DATE) > 15 THEN DATE_TRUNC('month', CURRENT_DATE) + INTERVAL '15 days' + ELSE DATE_TRUNC('month', CURRENT_DATE) - INTERVAL '1 day' + END AS end_date, + CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN EXTRACT(YEAR FROM CURRENT_DATE) + ELSE EXTRACT(YEAR FROM CURRENT_DATE) - 1 + END AS fiscal_year, + 'Fiscal Year to Date' AS report_frequency, + 'Y' AS is_report_valid + +UNION ALL + +SELECT + -- 2. Most recent half month + CASE + WHEN EXTRACT(DAY FROM CURRENT_DATE) > 15 THEN DATE_TRUNC('month', CURRENT_DATE) + ELSE DATE_TRUNC('month', CURRENT_DATE) - INTERVAL '1 month' + INTERVAL '15 days' + END AS start_date, + CASE + WHEN EXTRACT(DAY FROM CURRENT_DATE) > 15 THEN DATE_TRUNC('month', CURRENT_DATE) + INTERVAL '15 days' + ELSE DATE_TRUNC('month', CURRENT_DATE) - INTERVAL '1 day' + END AS end_date, + CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN EXTRACT(YEAR FROM CURRENT_DATE) + ELSE EXTRACT(YEAR FROM CURRENT_DATE) - 1 + END AS fiscal_year, + 'Current Half Month' AS report_frequency, + 'Y' AS is_report_valid + +UNION ALL + +SELECT + -- 3. Last finished 3 months + DATE_TRUNC('month', CURRENT_DATE) - INTERVAL '3 months' AS start_date, + DATE_TRUNC('month', CURRENT_DATE) - INTERVAL '1 day' AS end_date, + CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN EXTRACT(YEAR FROM CURRENT_DATE) + ELSE EXTRACT(YEAR FROM CURRENT_DATE) - 1 + END AS fiscal_year, + 'Last 3 Months' AS report_frequency, + 'Y' AS is_report_valid + +UNION ALL + +SELECT + -- 4. Last finished 6 months + DATE_TRUNC('month', CURRENT_DATE) - INTERVAL '6 months' AS start_date, + DATE_TRUNC('month', CURRENT_DATE) - INTERVAL '1 day' AS end_date, + CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN EXTRACT(YEAR FROM CURRENT_DATE) + ELSE EXTRACT(YEAR FROM CURRENT_DATE) - 1 + END AS fiscal_year, + 'Last 6 Months' AS report_frequency, + 'Y' AS is_report_valid + +UNION ALL + +SELECT + -- Q1 (April 1 to June 30) + CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN DATE_TRUNC('year', CURRENT_DATE) + INTERVAL '3 months' + ELSE DATE_TRUNC('year', CURRENT_DATE) - INTERVAL '9 months' + END AS start_date, + CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN DATE_TRUNC('year', CURRENT_DATE) + INTERVAL '6 months' - INTERVAL '1 day' + ELSE DATE_TRUNC('year', CURRENT_DATE) - INTERVAL '6 months' - INTERVAL '1 day' + END AS end_date, + CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN EXTRACT(YEAR FROM CURRENT_DATE) + ELSE EXTRACT(YEAR FROM CURRENT_DATE) - 1 + END AS fiscal_year, + 'Q1 Fiscal Year' AS report_frequency, + CASE + WHEN (CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN DATE_TRUNC('year', CURRENT_DATE) + INTERVAL '6 months' - INTERVAL '1 day' + ELSE DATE_TRUNC('year', CURRENT_DATE) - INTERVAL '6 months' - INTERVAL '1 day' + END) < NOW() THEN 'Y' + ELSE 'N' + END AS is_report_valid + +UNION ALL + +SELECT + -- Q2 (July 1 to September 30) + CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN DATE_TRUNC('year', CURRENT_DATE) + INTERVAL '6 months' + ELSE DATE_TRUNC('year', CURRENT_DATE) - INTERVAL '6 months' + END AS start_date, + CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN DATE_TRUNC('year', CURRENT_DATE) + INTERVAL '9 months' - INTERVAL '1 day' + ELSE DATE_TRUNC('year', CURRENT_DATE) - INTERVAL '3 months' - INTERVAL '1 day' + END AS end_date, + CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN EXTRACT(YEAR FROM CURRENT_DATE) + ELSE EXTRACT(YEAR FROM CURRENT_DATE) - 1 + END fiscal_year, + 'Q2 Fiscal Year' AS report_frequency, + CASE + WHEN ( CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN DATE_TRUNC('year', CURRENT_DATE) + INTERVAL '9 months' - INTERVAL '1 day' + ELSE DATE_TRUNC('year', CURRENT_DATE) - INTERVAL '3 months' - INTERVAL '1 day' + END) < NOW() THEN 'Y' + ELSE 'N' + END AS is_report_valid + +UNION ALL + +SELECT + -- Q3 (October 1 to December 31) + CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN DATE_TRUNC('year', CURRENT_DATE) + INTERVAL '9 months' + ELSE DATE_TRUNC('year', CURRENT_DATE) - INTERVAL '3 months' + END AS start_date, + CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN DATE_TRUNC('year', CURRENT_DATE) + INTERVAL '12 months' - INTERVAL '1 day' + ELSE DATE_TRUNC('year', CURRENT_DATE) - INTERVAL '1 day' + END AS end_date, + CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN EXTRACT(YEAR FROM CURRENT_DATE) + ELSE EXTRACT(YEAR FROM CURRENT_DATE) - 1 + END fiscal_year, + 'Q3 Fiscal Year' AS report_frequency, + CASE + WHEN (CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN DATE_TRUNC('year', CURRENT_DATE) + INTERVAL '12 months' - INTERVAL '1 day' + ELSE DATE_TRUNC('year', CURRENT_DATE) - INTERVAL '1 day' + END) < NOW() THEN 'Y' + ELSE 'N' + END AS is_report_valid + +UNION ALL + +SELECT + -- Q4 (January 1 to March 31) + CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN DATE_TRUNC('year', CURRENT_DATE) + INTERVAL '9 months' + ELSE DATE_TRUNC('year', CURRENT_DATE) + END AS start_date, + CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN DATE_TRUNC('year', CURRENT_DATE) + INTERVAL '1 year' + INTERVAL '3 months' + ELSE DATE_TRUNC('year', CURRENT_DATE) + INTERVAL '3 months' - INTERVAL '1 day' + END AS end_date, + CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN EXTRACT(YEAR FROM CURRENT_DATE) + ELSE EXTRACT(YEAR FROM CURRENT_DATE) - 1 + END fiscal_year, + 'Q4 Fiscal Year' AS report_frequency, + CASE + WHEN (CASE + WHEN EXTRACT(MONTH FROM CURRENT_DATE) >= 4 THEN DATE_TRUNC('year', CURRENT_DATE) + INTERVAL '1 year' + INTERVAL '3 months' + ELSE DATE_TRUNC('year', CURRENT_DATE) + INTERVAL '3 months' - INTERVAL '1 day' + END) < now() THEN 'Y' + ELSE 'N' + END AS is_report_valid; diff --git a/shared/bcts_reports_etl/bcts_performance_report_transformation.py b/shared/bcts_reports_etl/bcts_performance_report_transformation.py index c2bde4f..eda02a5 100644 --- a/shared/bcts_reports_etl/bcts_performance_report_transformation.py +++ b/shared/bcts_reports_etl/bcts_performance_report_transformation.py @@ -157,6 +157,22 @@ def run_get_currently_in_market(current_date_pst): connection.rollback() +def refresh_mat_views(): + + sql_statement = \ + """ + refresh materialized view bcts_staging.mv_licence_issued_advertised_lrm; + refresh materialized view bcts_staging.mv_licence_issued_advertised_main; + + """ + + try: + cursor.execute(sql_statement) + connection.commit() + logging.info(f"SQL script executed successfully.") + except psycopg2.Error as e: + logging.error(f"Error executing the SQL script: {e}") + connection.rollback() if __name__ == "__main__": @@ -164,6 +180,8 @@ def run_get_currently_in_market(current_date_pst): connection = get_connection() cursor = connection.cursor() + + # Fetch the start and end dates for the report periods df = get_reporting_periods(connection, cursor) @@ -195,6 +213,11 @@ def run_get_currently_in_market(current_date_pst): currently_in_market_executed = True + # Refresh materialized views for BCTS Performance Reports + logging.info("Refreshing materialized views...") + refresh_mat_views() + logging.info("Materialized views have been refreshed!") + # Clean up cursor.close()