Skip to content

Commit

Permalink
Update hexbin and dsra source (#79)
Browse files Browse the repository at this point in the history
* update indexes on all boundaries table including hexbins

* 2 new indicators for building level dsra

* test hexbin aggregation scripts for nhsl layers, area and centroid included

* updated r2 to r1

* update physical exposure indicators

* minor change to ini file

* remove hexbin centroid aggregations

* revised indicators

* removed _area suffix, added global fabric aggregation but commented out until ready

* exposure v1.2 updates

* update mapping

mean_recovery_time,sC_Recovery
mean_interruption_time,sC_Downtime

* Update Create_hexbin_physical_exposure_aggregation_area_proxy.sql

* Update Create_scenario_risk_building_Indicators_ALL_shkmp.sql

* Update Create_scenario_risk_master_tables.sql

* Update Create_scenario_risk_sauid_Indicators_ALL_shkmp.sql

* Update Create_scenario_risk_sauid_Indicators_ALL_shkmp.sql

* eq_Scenario to eqScenario

* Update Create_scenario_risk_sauid_Indicators_ALL_shkmp.sql

* Update Create_all_tables_update.sql

* Update Create_scenario_risk_building_Indicators_ALL_shkmp.sql

* Update Create_scenario_risk_sauid_Indicators_ALL_shkmp.sql

* update MFshld to include RES4,RES5,RES6

* add national hmaps table and view

* update sC_Downtime to sC_Interruption

* displaced res to affected res

* Revert "displaced res to affected res"

This reverts commit b2f660a.

* Revert "Revert "displaced res to affected res""

This reverts commit 90807d4.

* Revert "displaced res to affected res"

This reverts commit b2f660a.

* Revert "update sC_Downtime to sC_Interruption"

This reverts commit e71d413.

* updated typo for RES6 in MFHshld

* Update Create_physical_exposure_sauid_indicators_view_PhysicalExposure_ste.sql

* downtime to interruption

* dsra updates

* remove { } in comments

* global fabric hexbin update

* update for global fabric

* Update DSRA_outputs2postgres_lfs.py (#76)

Co-authored-by: William Chow <[email protected]>
Co-authored-by: Damon Ulmi <[email protected]>
  • Loading branch information
3 people authored Oct 4, 2021
1 parent 494f8b6 commit 2d9c77e
Show file tree
Hide file tree
Showing 16 changed files with 2,604 additions and 667 deletions.
2 changes: 1 addition & 1 deletion scripts/Create_all_tables_update.sql
Original file line number Diff line number Diff line change
Expand Up @@ -16,7 +16,7 @@ ername varchar,
pruid varchar,
prname varchar,
sh_rupname varchar,
sh_rupabbr varchar,
--sh_rupabbr varchar,
sh_mag varchar,
sh_hypolon float,
sh_hypolat float,
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,167 @@

-- test aggregation to hexbin grids area proxy

--5km
DROP VIEW IF EXISTS results_nhsl_hazard_threat.nhsl_hazard_threat_prioritization_hexgrid_5km;
CREATE VIEW results_nhsl_hazard_threat.nhsl_hazard_threat_prioritization_hexgrid_5km AS
SELECT
b.gridid_5,
--SUM("E_AreaKm2" * b.area_ratio) AS "Et_AreaKm2",
--SUM("E_AreaHa" * b.area_ratio) AS "Et_AreaHa",
SUM("Et_BldgNum" * b.area_ratio) AS "Et_BldgNum",
SUM("Et_AssetValue" * b.area_ratio) AS "Et_AssetValue",
SUM("Et_PopNight" * b.area_ratio) AS "Et_PopNight",
SUM(eq_shaking_score_abs * b.area_ratio) AS "eq_shaking_score_abs",
SUM(eq_shaking_score_rel * b.area_ratio) AS "eq_shaking_score_rel",
SUM(fld_priority_score_abs * b.area_ratio) AS "fld_priority_score_abs",
SUM(fld_priority_score_rel * b.area_ratio) AS "fld_priority_score_rel",
SUM(wildfire_priority_score_abs * b.area_ratio) AS "wildfire_priority_score_abs",
SUM(wildfire_priority_score_rel * b.area_ratio) AS "wildfire_priority_score_rel",
SUM(cy_priority_score_abs * b.area_ratio) AS "cy_priority_score_abs",
SUM(cy_priority_score_rel * b.area_ratio) AS "cy_priority_score_rel",
SUM(total_abs_score * b.area_ratio) AS "total_abs_score",
SUM(total_rel_score * b.area_ratio) AS "total_rel_score",
c.geom

FROM results_nhsl_hazard_threat.nhsl_hazard_threat_all_indicators_s_tbl a
LEFT JOIN boundaries."SAUID_HexGrid_5km_intersect" b ON a."Sauid" = b.sauid
LEFT JOIN boundaries."HexGrid_5km" c ON b.gridid_5 = c.gridid_5
GROUP BY b.gridid_5,c.geom;


-- 10km
DROP VIEW IF EXISTS results_nhsl_hazard_threat.nhsl_hazard_threat_prioritization_hexgrid_10km;
CREATE VIEW results_nhsl_hazard_threat.nhsl_hazard_threat_prioritization_hexgrid_10km AS
SELECT
b.gridid_10,
--SUM("E_AreaKm2" * b.area_ratio) AS "Et_AreaKm2",
--SUM("E_AreaHa" * b.area_ratio) AS "Et_AreaHa",
SUM("Et_BldgNum" * b.area_ratio) AS "Et_BldgNum",
SUM("Et_AssetValue" * b.area_ratio) AS "Et_AssetValue",
SUM("Et_PopNight" * b.area_ratio) AS "Et_PopNight",
SUM(eq_shaking_score_abs * b.area_ratio) AS "eq_shaking_score_abs",
SUM(eq_shaking_score_rel * b.area_ratio) AS "eq_shaking_score_rel",
SUM(fld_priority_score_abs * b.area_ratio) AS "fld_priority_score_abs",
SUM(fld_priority_score_rel * b.area_ratio) AS "fld_priority_score_rel",
SUM(wildfire_priority_score_abs * b.area_ratio) AS "wildfire_priority_score_abs",
SUM(wildfire_priority_score_rel * b.area_ratio) AS "wildfire_priority_score_rel",
SUM(cy_priority_score_abs * b.area_ratio) AS "cy_priority_score_abs",
SUM(cy_priority_score_rel * b.area_ratio) AS "cy_priority_score_rel",
SUM(total_abs_score * b.area_ratio) AS "total_abs_score",
SUM(total_rel_score * b.area_ratio) AS "total_rel_score",
c.geom

FROM results_nhsl_hazard_threat.nhsl_hazard_threat_all_indicators_s_tbl a
LEFT JOIN boundaries."SAUID_HexGrid_10km_intersect" b ON a."Sauid" = b.sauid
LEFT JOIN boundaries."HexGrid_10km" c ON b.gridid_10 = c.gridid_10
GROUP BY b.gridid_10,c.geom;

-- 25km
DROP VIEW IF EXISTS results_nhsl_hazard_threat.nhsl_hazard_threat_prioritization_hexgrid_25km;
CREATE VIEW results_nhsl_hazard_threat.nhsl_hazard_threat_prioritization_hexgrid_25km AS
SELECT
b.gridid_25,
--SUM("E_AreaKm2" * b.area_ratio) AS "Et_AreaKm2",
--SUM("E_AreaHa" * b.area_ratio) AS "Et_AreaHa",
SUM("Et_BldgNum" * b.area_ratio) AS "Et_BldgNum",
SUM("Et_AssetValue" * b.area_ratio) AS "Et_AssetValue",
SUM("Et_PopNight" * b.area_ratio) AS "Et_PopNight",
SUM(eq_shaking_score_abs * b.area_ratio) AS "eq_shaking_score_abs",
SUM(eq_shaking_score_rel * b.area_ratio) AS "eq_shaking_score_rel",
SUM(fld_priority_score_abs * b.area_ratio) AS "fld_priority_score_abs",
SUM(fld_priority_score_rel * b.area_ratio) AS "fld_priority_score_rel",
SUM(wildfire_priority_score_abs * b.area_ratio) AS "wildfire_priority_score_abs",
SUM(wildfire_priority_score_rel * b.area_ratio) AS "wildfire_priority_score_rel",
SUM(cy_priority_score_abs * b.area_ratio) AS "cy_priority_score_abs",
SUM(cy_priority_score_rel * b.area_ratio) AS "cy_priority_score_rel",
SUM(total_abs_score * b.area_ratio) AS "total_abs_score",
SUM(total_rel_score * b.area_ratio) AS "total_rel_score",
c.geom

FROM results_nhsl_hazard_threat.nhsl_hazard_threat_all_indicators_s_tbl a
LEFT JOIN boundaries."SAUID_HexGrid_25km_intersect" b ON a."Sauid" = b.sauid
LEFT JOIN boundaries."HexGrid_25km" c ON b.gridid_25 = c.gridid_25
GROUP BY b.gridid_25,c.geom;


-- 50km
DROP VIEW IF EXISTS results_nhsl_hazard_threat.nhsl_hazard_threat_prioritization_hexgrid_50km;
CREATE VIEW results_nhsl_hazard_threat.nhsl_hazard_threat_prioritization_hexgrid_50km AS
SELECT
b.gridid_50,
--SUM("E_AreaKm2" * b.area_ratio) AS "Et_AreaKm2",
--SUM("E_AreaHa" * b.area_ratio) AS "Et_AreaHa",
SUM("Et_BldgNum" * b.area_ratio) AS "Et_BldgNum",
SUM("Et_AssetValue" * b.area_ratio) AS "Et_AssetValue",
SUM("Et_PopNight" * b.area_ratio) AS "Et_PopNight",
SUM(eq_shaking_score_abs * b.area_ratio) AS "eq_shaking_score_abs",
SUM(eq_shaking_score_rel * b.area_ratio) AS "eq_shaking_score_rel",
SUM(fld_priority_score_abs * b.area_ratio) AS "fld_priority_score_abs",
SUM(fld_priority_score_rel * b.area_ratio) AS "fld_priority_score_rel",
SUM(wildfire_priority_score_abs * b.area_ratio) AS "wildfire_priority_score_abs",
SUM(wildfire_priority_score_rel * b.area_ratio) AS "wildfire_priority_score_rel",
SUM(cy_priority_score_abs * b.area_ratio) AS "cy_priority_score_abs",
SUM(cy_priority_score_rel * b.area_ratio) AS "cy_priority_score_rel",
SUM(total_abs_score * b.area_ratio) AS "total_abs_score",
SUM(total_rel_score * b.area_ratio) AS "total_rel_score",
c.geom

FROM results_nhsl_hazard_threat.nhsl_hazard_threat_all_indicators_s_tbl a
LEFT JOIN boundaries."SAUID_HexGrid_50km_intersect" b ON a."Sauid" = b.sauid
LEFT JOIN boundaries."HexGrid_50km" c ON b.gridid_50 = c.gridid_50
GROUP BY b.gridid_50,c.geom;

-- 100km
DROP VIEW IF EXISTS results_nhsl_hazard_threat.nhsl_hazard_threat_prioritization_hexgrid_100km;
CREATE VIEW results_nhsl_hazard_threat.nhsl_hazard_threat_prioritization_hexgrid_100km AS
SELECT
b.gridid_100,
--SUM("E_AreaKm2" * b.area_ratio) AS "Et_AreaKm2",
--SUM("E_AreaHa" * b.area_ratio) AS "Et_AreaHa",
SUM("Et_BldgNum" * b.area_ratio) AS "Et_BldgNum",
SUM("Et_AssetValue" * b.area_ratio) AS "Et_AssetValue",
SUM("Et_PopNight" * b.area_ratio) AS "Et_PopNight",
SUM(eq_shaking_score_abs * b.area_ratio) AS "eq_shaking_score_abs",
SUM(eq_shaking_score_rel * b.area_ratio) AS "eq_shaking_score_rel",
SUM(fld_priority_score_abs * b.area_ratio) AS "fld_priority_score_abs",
SUM(fld_priority_score_rel * b.area_ratio) AS "fld_priority_score_rel",
SUM(wildfire_priority_score_abs * b.area_ratio) AS "wildfire_priority_score_abs",
SUM(wildfire_priority_score_rel * b.area_ratio) AS "wildfire_priority_score_rel",
SUM(cy_priority_score_abs * b.area_ratio) AS "cy_priority_score_abs",
SUM(cy_priority_score_rel * b.area_ratio) AS "cy_priority_score_rel",
SUM(total_abs_score * b.area_ratio) AS "total_abs_score",
SUM(total_rel_score * b.area_ratio) AS "total_rel_score",
c.geom

FROM results_nhsl_hazard_threat.nhsl_hazard_threat_all_indicators_s_tbl a
LEFT JOIN boundaries."SAUID_HexGrid_100km_intersect" b ON a."Sauid" = b.sauid
LEFT JOIN boundaries."HexGrid_100km" c ON b.gridid_100 = c.gridid_100
GROUP BY b.gridid_100,c.geom;


-- global fabric
DROP VIEW IF EXISTS results_nhsl_hazard_threat.nhsl_hazard_threat_prioritization_hexgrid_global_fabric;
CREATE VIEW results_nhsl_hazard_threat.nhsl_hazard_threat_prioritization_hexgrid_global_fabric AS
SELECT
b.gridid,
--SUM("E_AreaKm2" * b.area_ratio) AS "Et_AreaKm2",
--SUM("E_AreaHa" * b.area_ratio) AS "Et_AreaHa",
SUM("Et_BldgNum" * b.area_ratio) AS "Et_BldgNum",
SUM("Et_AssetValue" * b.area_ratio) AS "Et_AssetValue",
SUM("Et_PopNight" * b.area_ratio) AS "Et_PopNight",
SUM(eq_shaking_score_abs * b.area_ratio) AS "eq_shaking_score_abs",
SUM(eq_shaking_score_rel * b.area_ratio) AS "eq_shaking_score_rel",
SUM(fld_priority_score_abs * b.area_ratio) AS "fld_priority_score_abs",
SUM(fld_priority_score_rel * b.area_ratio) AS "fld_priority_score_rel",
SUM(wildfire_priority_score_abs * b.area_ratio) AS "wildfire_priority_score_abs",
SUM(wildfire_priority_score_rel * b.area_ratio) AS "wildfire_priority_score_rel",
SUM(cy_priority_score_abs * b.area_ratio) AS "cy_priority_score_abs",
SUM(cy_priority_score_rel * b.area_ratio) AS "cy_priority_score_rel",
SUM(total_abs_score * b.area_ratio) AS "total_abs_score",
SUM(total_rel_score * b.area_ratio) AS "total_rel_score",
c.geom

FROM results_nhsl_hazard_threat.nhsl_hazard_threat_all_indicators_s_tbl a
LEFT JOIN boundaries."SAUID_HexGrid_GlobalFabric_intersect" b ON a."Sauid" = b.sauid
LEFT JOIN boundaries."HexGrid_GlobalFabric" c ON b.gridid = c.gridid
GROUP BY b.gridid,c.geom;
Loading

0 comments on commit 2d9c77e

Please sign in to comment.