Breakdown: Input Form Usage for Comparison and Dynamic visuals
A few people have been curious about how I implemented the use of Input fields within my GoodViz-ESG submission so I figured it may prove useful if I gave a breakdown!
My Targets
What I wanted to achieve was a more dynamic user experience, whereby the user could alter the content displayed within a subset of visualisation objects as opposed to making global selections with conventional filtering.
The main things I wanted to accomplish were:
- A comparison of user input values vs the top 100 companies for specific measures
- Dynamically changing visualisations
The Challenges
- Astrato's Input Form at the time only allowed for records to be inserted into a given table and these records needed to be entered as free text.
- There was also no variable support
Comments
-
Solution 1: Comparisons
The first thing I knew I needed to start off with were some tables to capture the input values. I wanted to keep my user input values separate from the original data so I created a simple table with an auto incrementing key field:
CREATE OR REPLACE TABLE WB_COMPANY ( WB_ID int autoincrement start 1 increment 1 not null ,WB_COMPANYNAME VARCHAR(16777216) );
After inserting a couple of test records I can see the sequence is working as expected, time to move on!
+-------+----------------+ | WB_ID | WB_COMPANYNAME | +-------+----------------+ | 1 | TAYLOR PLC | | 2 | ASTRATO | +-------+----------------+
In my case, there were only a handful of specific ESG measures that I was interested in for comparisons so following the same approach I constructed a few more tables:
--- ENERGY CREATE OR REPLACE TABLE WB_ENERGY_MEASURE ( WB_ID int autoincrement start 1 increment 1 not null ,WB_MEASUREVALUE FLOAT ); --- WATER CREATE OR REPLACE TABLE WB_WATER_MEASURE ( WB_ID int autoincrement start 1 increment 1 not null ,WB_MEASUREVALUE FLOAT ); --- WASTE CREATE OR REPLACE TABLE WB_WASTE_MEASURE ( WB_ID int autoincrement start 1 increment 1 not null ,WB_MEASUREVALUE FLOAT ); --- ENVIRONMENTAL CREATE OR REPLACE TABLE WB_ENV_MEASURE ( WB_ID int autoincrement start 1 increment 1 not null ,WB_MEASUREVALUE FLOAT ); --- GHG CREATE OR REPLACE TABLE WB_GHG_MEASURE ( WB_ID int autoincrement start 1 increment 1 not null ,WB_MEASUREVALUE FLOAT ); --- E_PILLAR CREATE OR REPLACE TABLE WB_E_PILLAR_MEASURE ( WB_ID int autoincrement start 1 increment 1 not null ,WB_MEASUREVALUE FLOAT ); --- E_PILLAR_TRANSPARENCY CREATE OR REPLACE TABLE WB_E_PILLAR_TRANSPARENCY_MEASURE ( WB_ID int autoincrement start 1 increment 1 not null ,WB_MEASUREVALUE FLOAT );
Alright, so at this stage I had my tables, I could insert values, all good so far!
Next up was wrangling my freshly created tables together for ease of use within Astrato.
To accomplish this I scribbled up a view: WB_COMPARISON_MEASURES_VW which utilised Snowflakes Qualify clause against the WB_ID of each of the tables so as to leave me with only the most recent record from each.
Knowing I would only be returning a single row from each of my tables I introduced an ID column with a constant value of 1 to facilitate joining everything together:
CREATE OR REPLACE VIEW WB_COMPARISON_MEASURES_VW AS SELECT WATER.ID, WB_COMPANYNAME, E_PILLAR_MEASURE, E_PILLAR_TRANSPARENCY_MEASURE, WATER_MEASURE, ENERGY_MEASURE, WASTE_MEASURE, ENV_MEASURE, GHG_MEASURE FROM (SELECT 1 AS ID, WB_COMPANYNAME FROM WB_COMPANY qualify row_number() over (order by WB_ID desc) = 1) COMP ,(SELECT 1 AS ID, NVL(WB_MEASUREVALUE,0) AS WATER_MEASURE FROM WB_WATER_MEASURE qualify row_number() over (order by WB_ID desc) = 1) WATER ,(SELECT 1 AS ID, NVL(WB_MEASUREVALUE,0) AS ENERGY_MEASURE FROM WB_ENERGY_MEASURE qualify row_number() over (order by WB_ID desc) = 1) ENERGY ,(SELECT 1 AS ID, NVL(WB_MEASUREVALUE,0) AS WASTE_MEASURE FROM WB_WASTE_MEASURE qualify row_number() over (order by WB_ID desc) = 1) WASTE ,(SELECT 1 AS ID, NVL(WB_MEASUREVALUE,0) AS ENV_MEASURE FROM WB_ENV_MEASURE qualify row_number() over (order by WB_ID desc) = 1) ENV ,(SELECT 1 AS ID, NVL(WB_MEASUREVALUE,0) AS GHG_MEASURE FROM WB_GHG_MEASURE qualify row_number() over (order by WB_ID desc) = 1) GHG ,(SELECT 1 AS ID, NVL(WB_MEASUREVALUE,0) AS E_PILLAR_MEASURE FROM WB_E_PILLAR_MEASURE qualify row_number() over (order by WB_ID desc) = 1) EP ,(SELECT 1 AS ID, NVL(WB_MEASUREVALUE,0) AS E_PILLAR_TRANSPARENCY_MEASURE FROM WB_E_PILLAR_TRANSPARENCY_MEASURE qualify row_number() over (order by WB_ID desc) = 1) EPT WHERE COMP.ID = WATER.ID AND COMP.ID = ENERGY.ID AND COMP.ID = WASTE.ID AND COMP.ID = ENV.ID AND COMP.ID = GHG.ID AND COMP.ID = EP.ID AND COMP.ID = EPT.ID ;
Looking alright:
+----+----------------+------------------+-------------------------------+---------------+----------------+---------------+-------------+ | ID | WB_COMPANYNAME | E_PILLAR_MEASURE | E_PILLAR_TRANSPARENCY_MEASURE | WATER_MEASURE | ENERGY_MEASURE | WASTE_MEASURE | ENV_MEASURE | +----+----------------+------------------+-------------------------------+---------------+----------------+---------------+-------------+ | 1 | ASTRATO | 0 | 0 | 0 | 0 | 0 | 0 | +----+----------------+------------------+-------------------------------+---------------+----------------+---------------+-------------+
OK, so at this point I have my 7 orphan tables for capturing inputs, plus a view that pulls everything together.
Next on the chopping block was to ready the data so the comparison was achievable. This was nice and simple and only required me to union the SCORES_ESG_SAMPLE data that was provided by Gaialens with my new WB_COMPARISON_MEASURES_VW plus the addition of a new "SOURCE" column so I can identify what rows came from where.
CREATE OR REPLACE VIEW SCORES_ESG_SAMPLE_VW AS SELECT 'ESG' AS SOURCE ,"companyname" ,"symbol" ,"country" ,"sector" ,"industry" ,"sub_industry" ,"fiscalyear" ,"E_pillar_score_adjusted" ,"E_pillar_transparency_score" ,"energy_production_and_consumption" ,"environmental_impacts" ,"ghg_emissions" ,"waste_management" ,"water_management" ,"bitumns_and_lignit_surface_coal_mng_rev_div_total_rev_ipctl" ,"bitumns_undergrnd_coal_mining_rev_div_total_revenue_ipctl" ,"coal_mining_revenue_div_total_revenue_ipctl" ,"coal_power_generation_div_total_power_generation_ipctl" ,"coal_power_generation_revenue_div_total_revenue_ipctl" ,"company_no_revenue_from_fossil_fuels_flag_ipctl" ,"electricity_generation_score_ipctl" ... FROM SCORES_ESG_SAMPLE_TABLE UNION SELECT 'WB' AS SOURCE ,WB_COMPANYNAME AS "companyname" ,NULL AS "symbol" ,NULL AS "country" ,NULL AS "sector" ,NULL AS "industry" ,NULL AS "sub_industry" ,NULL AS "fiscalyear" ,E_PILLAR_MEASURE AS "E_pillar_score_adjusted" ,E_PILLAR_TRANSPARENCY_MEASURE AS "E_pillar_transparency_score" ,ENERGY_MEASURE AS "energy_production_and_consumption" ,ENV_MEASURE AS "environmental_impacts" ,GHG_MEASURE AS "ghg_emissions" ,WASTE_MEASURE AS "waste_management" ,WATER_MEASURE AS "water_management" ,0"bitumns_and_lignit_surface_coal_mng_rev_div_total_rev_ipctl" ,0"bitumns_undergrnd_coal_mining_rev_div_total_revenue_ipctl" ,0"coal_mining_revenue_div_total_revenue_ipctl" ,0"coal_power_generation_div_total_power_generation_ipctl" ,0"coal_power_generation_revenue_div_total_revenue_ipctl" ,0"company_no_revenue_from_fossil_fuels_flag_ipctl" ,0"electricity_generation_score_ipctl" ... FROM WB_COMPARISON_MEASURES_VW ;
With the data prep done it was time to shift over to a bit of dashboard design!
Using a Vertical bar chart I plotted the following fields and applied categorical conditional colouring based on the "SOURCE" field so the Input Company is easily discernible:
- Dimension 1: SCORES_ESG_SAMPLE_VW."companyname"
- Dimension 2: SCORES_ESG_SAMPLE_VW.SOURCE
- Measure: AVG(SCORES_ESG_SAMPLE_VW."ghg_emissions")
2 -
Solution 2: Dynamic Visuals
For this I started off by creating a small table that would hold the ESG Measure names as rows, along with a user defined Category and an image URL which came as an afterthought!
CREATE OR REPLACE TABLE ESG_CATEGORIES ( MEASURENAME VARCHAR(16777216) ,CATEGORY VARCHAR(16777216) ,CATEGORY_URL VARCHAR(16777216) ); INSERT INTO ESG_CATEGORIES (MEASURENAME, CATEGORY) WITH INSERTS AS ( SELECT REPLACE(INITCAP(REPLACE('energy_production_and_consumption','_',' ')),'And','and') AS MEASURENAME, 'Energy' AS MEASURE_CATEGORY UNION SELECT REPLACE(INITCAP(REPLACE('environmental_impacts','_',' ')),'And','and') AS MEASURENAME, 'Environmental' AS MEASURE_CATEGORY UNION SELECT REPLACE(INITCAP(REPLACE('ghg_emissions','_',' ')),'And','and') AS MEASURENAME, 'GHG' AS MEASURE_CATEGORY UNION ... ) SELECT I.* FROM INSERTS I; UPDATE ESG_CATEGORIES C SET C.CATEGORY_URL = U.CATEGORY_URL FROM (SELECT 'GHG' AS CATEGORY, 'https://i.postimg.cc/W4DmhSBK/Factory.png' AS CATEGORY_URL FROM DUAL UNION SELECT 'WATER' AS CATEGORY, 'https://i.postimg.cc/yx8y6nnD/Water.png' AS CATEGORY_URL FROM DUAL UNION SELECT 'WASTE' AS CATEGORY, 'https://i.postimg.cc/pT8CrkwC/Waste.png' AS CATEGORY_URL FROM DUAL UNION SELECT 'ENERGY' AS CATEGORY, 'https://i.postimg.cc/d39rzfC7/Energy.png' AS CATEGORY_URL FROM DUAL UNION SELECT 'ENVIRONMENTAL' AS CATEGORY, 'https://i.postimg.cc/0j1CgmH4/Environment.png' AS CATEGORY_URL FROM DUAL ) U WHERE UPPER(C.CATEGORY) = U.CATEGORY;
As with the comparison scenario, I needed somewhere to store my user inputs:
CREATE OR REPLACE TABLE WB_CATEGORY ( WB_ID int autoincrement start 1 increment 1 not null ,CATEGORY_INPUT VARCHAR(16777216) );
And a view that would both limit to just a single record and handle the inputs in case of garbage. In the event an input written to the WB_CATEGORY table that does not match an existing ESG_CATEGORIES.CATEGORY, the input would be ignored and the view would continue to return the previous "valid" record:
CREATE OR REPLACE VIEW CATEGORY_INPUT_VW AS SELECT 1 AS ID ,CASE WHEN TRIM(UPPER(W.CATEGORY_INPUT)) = 'GHG' THEN 'GHG' ELSE TRIM(INITCAP(W.CATEGORY_INPUT)) END AS CATEGORY_INPUT FROM CATEGORY_WB W ,ESG_CATEGORIES C WHERE TRIM(UPPER(W.CATEGORY_INPUT)) = UPPER(C.CATEGORY) qualify row_number() over (order by W.WB_ID desc) = 1 ;
Lastly on the Snowflake side I created a view to transpose the ESG Measures and their scores from the view SCORES_ESG_SAMPLE_VIEW.
CREATE OR REPLACE VIEW TRANSPOSED_SAMPLE_SCORES AS SELECT SOURCE, COMPANYNAME, SYMBOL, MEASURE, CASE WHEN MEASUREVALUE = 999 THEN NULL ELSE MEASUREVALUE END as MEASUREVALUE FROM ( SELECT SOURCE, "companyname" as COMPANYNAME, "symbol" as SYMBOL, MEASURE, MEASUREVALUE FROM (SELECT SOURCE ,"companyname" ,"symbol" ,NVL("E_pillar_score_adjusted",999) AS "E Pillar Score Adjusted" ,NVL("E_pillar_transparency_score",999) AS "E Pillar Transparency Score" ,NVL("energy_production_and_consumption",999) AS "Energy Production and Consumption" ,NVL("environmental_impacts",999) AS "Environmental Impacts" ,NVL("ghg_emissions",999) AS "Ghg Emissions" ,NVL("waste_management",999) AS "Waste Management" ,NVL("water_management",999) AS "Water Management" ,NVL("bitumns_and_lignit_surface_coal_mng_rev_div_total_rev_ipctl",999) AS "Bitumns and Lignit Surface Coal Mng Rev Div Total Rev Ipctl" ,NVL("bitumns_undergrnd_coal_mining_rev_div_total_revenue_ipctl",999) AS "Bitumns Undergrnd Coal Mining Rev Div Total Revenue Ipctl" ,NVL("coal_mining_revenue_div_total_revenue_ipctl",999) AS "Coal Mining Revenue Div Total Revenue Ipctl" ,NVL("coal_power_generation_div_total_power_generation_ipctl",999) AS "Coal Power Generation Div Total Power Generation Ipctl" ,NVL("coal_power_generation_revenue_div_total_revenue_ipctl",999) AS "Coal Power Generation Revenue Div Total Revenue Ipctl" ,NVL("company_no_revenue_from_fossil_fuels_flag_ipctl",999) AS "Company No Revenue From Fossil Fuels Flag Ipctl" ,NVL("electricity_generation_score_ipctl",999) AS "Electricity Generation Score Ipctl" ,NVL("energy_consumption_from_non_renewable_sources_pct_ipctl",999) AS "Energy Consumption From Non Renewable Sources Pct Ipctl" ,NVL("energy_mix_fossil_fuel_score_ipctl",999) AS "Energy Mix Fossil Fuel Score Ipctl" ,NVL("energy_production_from_non_renewable_sources_pct_ipctl",999) AS "Energy Production From Non Renewable Sources Pct Ipctl" ,NVL("fuel_efficiency_transport_score_ipctl",999) AS "Fuel Efficiency Transport Score Ipctl" ,NVL("metallurgical_coal_mining_revenue_div_total_revenue_ipctl",999) AS "Metallurgical Coal Mining Revenue Div Total Revenue Ipctl" ,NVL("thermal_coal_mining_revenue_div_total_revenue_ipctl",999) AS "Thermal Coal Mining Revenue Div Total Revenue Ipctl" ,NVL("transmission_distribution_electric_utilities_score_ipctl",999) AS "Transmission Distribution Electric Utilities Score Ipctl" ,NVL("undefined_coal_mining_revenue_div_total_revenue_ipctl",999) AS "Undefined Coal Mining Revenue Div Total Revenue Ipctl" ,NVL("biodiversity_score_ipctl",999) AS "Biodiversity Score Ipctl" ,NVL("building_materials_construction_realestate_score_ipctl",999) AS "Building Materials Construction Realestate Score Ipctl" ,NVL("climate_strategy_score_ipctl",999) AS "Climate Strategy Score Ipctl" ,NVL("company_no_revenue_from_chemical_production_flag_ipctl",999) AS "Company No Revenue From Chemical Production Flag Ipctl" ,NVL("environmental_policy_management_systems_score_ipctl",999) AS "Environmental Policy Management Systems Score Ipctl" ,NVL("environmental_reporting_score_ipctl",999) AS "Environmental Reporting Score Ipctl" ,NVL("environment_related_offenses_total_ipctl",999) AS "Environment Related Offenses Total Ipctl" ,NVL("genetically_modified_organisms_score_ipctl",999) AS "Genetically Modified Organisms Score Ipctl" ,NVL("impact_ratio_lwp_direct_cost_ipctl",999) AS "Impact Ratio Lwp Direct Cost Ipctl" ,NVL("impact_ratio_lwp_indirect_cost_ipctl",999) AS "Impact Ratio Lwp Indirect Cost Ipctl" ,NVL("impact_ratio_natural_resources_direct_cost_ipctl",999) AS "Impact Ratio Natural Resources Direct Cost Ipctl" ,NVL("impact_ratio_natural_resources_indirect_cost_ipctl",999) AS "Impact Ratio Natural Resources Indirect Cost Ipctl" ,NVL("intensity_acid_emissions_to_water_ipctl",999) AS "Intensity Acid Emissions To Water Ipctl" ,NVL("intensity_metal_emissions_to_water_ipctl",999) AS "Intensity Metal Emissions To Water Ipctl" ,NVL("intensity_nutrients_and_organic_pollutants_direct_quantity_ipct",999) AS "Intensity Nutrients and Organic Pollutants Direct Quantity Ipct" ,NVL("intensity_ozone_depleting_substances_direct_quantity_ipctl",999) AS "Intensity Ozone Depleting Substances Direct Quantity Ipctl" ,NVL("intensity_pesticides_and_fertilizer_ipctl",999) AS "Intensity Pesticides and Fertilizer Ipctl" ,NVL("intensity_total_emissions_of_air_pollutants_ipctl",999) AS "Intensity Total Emissions Of Air Pollutants Ipctl" ,NVL("intensity_total_emissions_of_inorganic_pollutants_ipctl",999) AS "Intensity Total Emissions Of Inorganic Pollutants Ipctl" ,NVL("operational_eco_efficiency_score_ipctl",999) AS "Operational Eco Efficiency Score Ipctl" ,NVL("raw_material_sourcing_score_ipctl",999) AS "Raw Material Sourcing Score Ipctl" ,NVL("resource_conservation_resource_efficiency_score_ipctl",999) AS "Resource Conservation Resource Efficiency Score Ipctl" ,NVL("revenue_from_high_impact_climate_sectors_pct_ipctl",999) AS "Revenue From High Impact Climate Sectors Pct Ipctl" ,NVL("sfdr_sustainable_agricultural_practices_score_ipctl",999) AS "Sfdr Sustainable Agricultural Practices Score Ipctl" ,NVL("sustainable_forestry_practices_score_ipctl",999) AS "Sustainable Forestry Practices Score Ipctl" ,NVL("impact_ratio_air_pollutants_direct_cost_ipctl",999) AS "Impact Ratio Air Pollutants Direct Cost Ipctl" ,NVL("impact_ratio_air_pollutants_indirect_cost_ipctl",999) AS "Impact Ratio Air Pollutants Indirect Cost Ipctl" ,NVL("impact_ratio_ghg_direct_cost_ipctl",999) AS "Impact Ratio Ghg Direct Cost Ipctl" ,NVL("impact_ratio_ghg_indirect_cost_ipctl",999) AS "Impact Ratio Ghg Indirect Cost Ipctl" ,NVL("intensity_co2_emissions_all_fossil_fuel_reserves_ipctl",999) AS "Intensity Co2 Emissions All Fossil Fuel Reserves Ipctl" ,NVL("intensity_ghg_direct_ipctl",999) AS "Intensity Ghg Direct Ipctl" ,NVL("intensity_ghg_emissions_all_fossil_fuel_power_generation_ipctl",999) AS "Intensity Ghg Emissions All Fossil Fuel Power Generation Ipctl" ,NVL("intensity_ghg_first_tier_indirect_ipctl",999) AS "Intensity Ghg First Tier Indirect Ipctl" ,NVL("intensity_ghg_scope_1_ipctl",999) AS "Intensity Ghg Scope 1 Ipctl" ,NVL("intensity_ghg_scope_2_ipctl",999) AS "Intensity Ghg Scope 2 Ipctl" ,NVL("intensity_ghg_scope_3_downstream_ipctl",999) AS "Intensity Ghg Scope 3 Downstream Ipctl" ,NVL("intensity_ghg_scope_3_upstream_ipctl",999) AS "Intensity Ghg Scope 3 Upstream Ipctl" ,NVL("low_carbon_strategy_score_ipctl",999) AS "Low Carbon Strategy Score Ipctl" ,NVL("co_processing_score_ipctl",999) AS "Co Processing Score Ipctl" ,NVL("impact_ratio_waste_direct_cost_ipctl",999) AS "Impact Ratio Waste Direct Cost Ipctl" ,NVL("impact_ratio_waste_indirect_cost_ipctl",999) AS "Impact Ratio Waste Indirect Cost Ipctl" ,NVL("intensity_waste_direct_incineration_ipctl",999) AS "Intensity Waste Direct Incineration Ipctl" ,NVL("intensity_waste_direct_landfill_ipctl",999) AS "Intensity Waste Direct Landfill Ipctl" ,NVL("intensity_waste_direct_nuclear_ipctl",999) AS "Intensity Waste Direct Nuclear Ipctl" ,NVL("intensity_waste_direct_recycled_ipctl",999) AS "Intensity Waste Direct Recycled Ipctl" ,NVL("intensity_waste_hazardous_less_nuclear_ipctl",999) AS "Intensity Waste Hazardous Less Nuclear Ipctl" ,NVL("intensity_waste_incineration_indirect_ipctl",999) AS "Intensity Waste Incineration Indirect Ipctl" ,NVL("intensity_waste_landfill_indirect_ipctl",999) AS "Intensity Waste Landfill Indirect Ipctl" ,NVL("intensity_waste_nonrecycled_ipctl",999) AS "Intensity Waste Nonrecycled Ipctl" ,NVL("intensity_waste_nuclear_ipctl",999) AS "Intensity Waste Nuclear Ipctl" ,NVL("mineral_waste_management_mining_score_ipctl",999) AS "Mineral Waste Management Mining Score Ipctl" ,NVL("packaging_score_ipctl",999) AS "Packaging Score Ipctl" ,NVL("recycling_strategy_building_materials_score_ipctl",999) AS "Recycling Strategy Building Materials Score Ipctl" ,NVL("assets_in_high_water_stress_areas_flag_ipctl",999) AS "Assets In High Water Stress Areas Flag Ipctl" ,NVL("impact_ratio_water_direct_cost_ipctl",999) AS "Impact Ratio Water Direct Cost Ipctl" ,NVL("impact_ratio_water_indirect_cost_ipctl",999) AS "Impact Ratio Water Indirect Cost Ipctl" ,NVL("intensity_water_direct_cooling_ipctl",999) AS "Intensity Water Direct Cooling Ipctl" ,NVL("intensity_water_direct_process_ipctl",999) AS "Intensity Water Direct Process Ipctl" ,NVL("intensity_water_indirect_cooling_ipctl",999) AS "Intensity Water Indirect Cooling Ipctl" ,NVL("intensity_water_indirect_process_ipctl",999) AS "Intensity Water Indirect Process Ipctl" ,NVL("intensity_water_purchased_ipctl",999) AS "Intensity Water Purchased Ipctl" ,NVL("water_operations_water_utilities_score_ipctl",999) AS "Water Operations Water Utilities Score Ipctl" ,NVL("water_related_risks_score_ipctl",999) AS "Water Related Risks Score Ipctl" ,NVL("water_stress_score_ipctl",999) AS "Water Stress Score Ipctl" FROM SCORES_ESG_SAMPLE_VIEW )A UNPIVOT ( MEASUREVALUE FOR MEASURE IN ("E Pillar Score Adjusted","E Pillar Transparency Score","Energy Production and Consumption","Environmental Impacts","Ghg Emissions","Waste Management","Water Management","Bitumns and Lignit Surface Coal Mng Rev Div Total Rev Ipctl","Bitumns Undergrnd Coal Mining Rev Div Total Revenue Ipctl","Coal Mining Revenue Div Total Revenue Ipctl","Coal Power Generation Div Total Power Generation Ipctl","Coal Power Generation Revenue Div Total Revenue Ipctl","Company No Revenue From Fossil Fuels Flag Ipctl","Electricity Generation Score Ipctl","Energy Consumption From Non Renewable Sources Pct Ipctl","Energy Mix Fossil Fuel Score Ipctl","Energy Production From Non Renewable Sources Pct Ipctl","Fuel Efficiency Transport Score Ipctl","Metallurgical Coal Mining Revenue Div Total Revenue Ipctl","Thermal Coal Mining Revenue Div Total Revenue Ipctl","Transmission Distribution Electric Utilities Score Ipctl","Undefined Coal Mining Revenue Div Total Revenue Ipctl","Biodiversity Score Ipctl","Building Materials Construction Realestate Score Ipctl","Climate Strategy Score Ipctl","Company No Revenue From Chemical Production Flag Ipctl","Environmental Policy Management Systems Score Ipctl","Environmental Reporting Score Ipctl","Environment Related Offenses Total Ipctl","Genetically Modified Organisms Score Ipctl","Impact Ratio Lwp Direct Cost Ipctl","Impact Ratio Lwp Indirect Cost Ipctl","Impact Ratio Natural Resources Direct Cost Ipctl","Impact Ratio Natural Resources Indirect Cost Ipctl","Intensity Acid Emissions To Water Ipctl","Intensity Metal Emissions To Water Ipctl","Intensity Nutrients and Organic Pollutants Direct Quantity Ipct","Intensity Ozone Depleting Substances Direct Quantity Ipctl","Intensity Pesticides and Fertilizer Ipctl","Intensity Total Emissions Of Air Pollutants Ipctl","Intensity Total Emissions Of Inorganic Pollutants Ipctl","Operational Eco Efficiency Score Ipctl","Raw Material Sourcing Score Ipctl","Resource Conservation Resource Efficiency Score Ipctl","Revenue From High Impact Climate Sectors Pct Ipctl","Sfdr Sustainable Agricultural Practices Score Ipctl","Sustainable Forestry Practices Score Ipctl","Impact Ratio Air Pollutants Direct Cost Ipctl","Impact Ratio Air Pollutants Indirect Cost Ipctl","Impact Ratio Ghg Direct Cost Ipctl","Impact Ratio Ghg Indirect Cost Ipctl","Intensity Co2 Emissions All Fossil Fuel Reserves Ipctl","Intensity Ghg Direct Ipctl","Intensity Ghg Emissions All Fossil Fuel Power Generation Ipctl","Intensity Ghg First Tier Indirect Ipctl","Intensity Ghg Scope 1 Ipctl","Intensity Ghg Scope 2 Ipctl","Intensity Ghg Scope 3 Downstream Ipctl","Intensity Ghg Scope 3 Upstream Ipctl","Low Carbon Strategy Score Ipctl","Co Processing Score Ipctl","Impact Ratio Waste Direct Cost Ipctl","Impact Ratio Waste Indirect Cost Ipctl","Intensity Waste Direct Incineration Ipctl","Intensity Waste Direct Landfill Ipctl","Intensity Waste Direct Nuclear Ipctl","Intensity Waste Direct Recycled Ipctl","Intensity Waste Hazardous Less Nuclear Ipctl","Intensity Waste Incineration Indirect Ipctl","Intensity Waste Landfill Indirect Ipctl","Intensity Waste Nonrecycled Ipctl","Intensity Waste Nuclear Ipctl","Mineral Waste Management Mining Score Ipctl","Packaging Score Ipctl","Recycling Strategy Building Materials Score Ipctl","Assets In High Water Stress Areas Flag Ipctl","Impact Ratio Water Direct Cost Ipctl","Impact Ratio Water Indirect Cost Ipctl","Intensity Water Direct Cooling Ipctl","Intensity Water Direct Process Ipctl","Intensity Water Indirect Cooling Ipctl","Intensity Water Indirect Process Ipctl","Intensity Water Purchased Ipctl","Water Operations Water Utilities Score Ipctl","Water Related Risks Score Ipctl","Water Stress Score Ipctl" )) ) ;
Shimmying back over to Astrato and after adding my new tables/views to the model:
All that was left was to set a filter on the visualisations that I want to control with the user input I simply set a condition of CATEGORY_INPUT_VW.ID = 1 this then forces an inner join between CATEGORY_INPUT_VW.CATEGORY_INPUT and ESG_CATEGORIES.CATEGORY which reduces to a subset of ESG Measures.
The result of this was a collection of charts and tables that are responsive to the user input Category to control the displayed measure names, whilst also remaining subjected to any other filters that can be applied within the sheet.
Hopefully this is of some use to others and I am sure the approach can be improved or built upon further!
If we get some new features such as picklists for Input Forms and the ability to apply conditional colouring based on colour codes held in a table I will most definitely be revisiting this myself.
5