|
| 1 | +-- Nonroad Post Processing Script (updated 1/2/2024): |
| 2 | +-- Emission factors in grams per operating hour by SCC and Model Year |
| 3 | +-- |
| 4 | +-- MOVES-Nonroad Output Guidance: |
| 5 | +-- SCC and Model Year must be selected and present in the results. |
| 6 | +-- This script will run faster if engine tech and HP class |
| 7 | +-- are not selected, and if there is only one sector, year, |
| 8 | +-- month, and day in the output. |
| 9 | +-- |
| 10 | +-- When prompted to save, specify one of the following file types: .xlsx, .xls, or .txt |
| 11 | +-- The raw output of this script is also stored in the output database in a table called: |
| 12 | +-- EmissionFactors_per_operatinghour_by_SCC_and_ModelYear |
| 13 | +-- |
| 14 | +-- WARNING: |
| 15 | +-- This script may take a long time to complete depending on |
| 16 | +-- the size of the output database. A confirmation notice will |
| 17 | +-- alert you when this action has completed. |
| 18 | + |
| 19 | +flush tables; |
| 20 | + |
| 21 | +-- Set up indexing for setting NULL values to 0 |
| 22 | +set @exist := (select count(*) from information_schema.statistics where table_schema = DATABASE() and table_name = 'movesoutput' and index_name = 'index_state'); |
| 23 | +set @sqlstmt := if( @exist > 0, 'select ''INFO: index_state already exists.''', 'create index index_state on movesoutput ( stateID )'); |
| 24 | +PREPARE stmt FROM @sqlstmt; |
| 25 | +EXECUTE stmt; |
| 26 | + |
| 27 | +set @exist := (select count(*) from information_schema.statistics where table_schema = DATABASE() and table_name = 'movesactivityoutput' and index_name = 'index_state'); |
| 28 | +set @sqlstmt := if( @exist > 0, 'select ''INFO: index_state already exists.''', 'create index index_state on movesactivityoutput ( stateID )'); |
| 29 | +PREPARE stmt FROM @sqlstmt; |
| 30 | +EXECUTE stmt; |
| 31 | + |
| 32 | +set @exist := (select count(*) from information_schema.statistics where table_schema = DATABASE() and table_name = 'movesoutput' and index_name = 'index_county'); |
| 33 | +set @sqlstmt := if( @exist > 0, 'select ''INFO: index_county already exists.''', 'create index index_county on movesoutput ( countyID )'); |
| 34 | +PREPARE stmt FROM @sqlstmt; |
| 35 | +EXECUTE stmt; |
| 36 | + |
| 37 | +set @exist := (select count(*) from information_schema.statistics where table_schema = DATABASE() and table_name = 'movesactivityoutput' and index_name = 'index_county'); |
| 38 | +set @sqlstmt := if( @exist > 0, 'select ''INFO: index_county already exists.''', 'create index index_county on movesactivityoutput ( countyID )'); |
| 39 | +PREPARE stmt FROM @sqlstmt; |
| 40 | +EXECUTE stmt; |
| 41 | + |
| 42 | +-- Convert NULLs to 0 to improve joins |
| 43 | +UPDATE movesoutput SET stateID = 0 WHERE stateID IS NULL; |
| 44 | +UPDATE movesoutput SET countyID = 0 WHERE countyID IS NULL; |
| 45 | +UPDATE movesactivityoutput SET stateID = 0 WHERE stateID IS NULL; |
| 46 | +UPDATE movesactivityoutput SET countyID = 0 WHERE countyID IS NULL; |
| 47 | + |
| 48 | +-- Set up indexing for everything else |
| 49 | +set @exist := (select count(*) from information_schema.statistics where table_schema = DATABASE() and table_name = 'movesoutput' and index_name = 'index1'); |
| 50 | +set @sqlstmt := if( @exist > 0, 'select ''INFO: Index already exists.''', 'create index index1 on movesoutput ( MOVESRunID )'); |
| 51 | +PREPARE stmt FROM @sqlstmt; |
| 52 | +EXECUTE stmt; |
| 53 | + |
| 54 | +set @exist := (select count(*) from information_schema.statistics where table_schema = DATABASE() and table_name = 'movesoutput' and index_name = 'index104'); |
| 55 | +set @sqlstmt := if( @exist > 0, 'select ''INFO: Index already exists.''', 'create index index104 on movesoutput ( MOVESRunID,yearID,monthID,dayID,stateID,countyID,scc,modelYearID,pollutantID,processID )'); |
| 56 | +PREPARE stmt FROM @sqlstmt; |
| 57 | +EXECUTE stmt; |
| 58 | + |
| 59 | +set @exist := (select count(*) from information_schema.statistics where table_schema = DATABASE() and table_name = 'movesactivityoutput' and index_name = 'index10'); |
| 60 | +set @sqlstmt := if( @exist > 0, 'select ''INFO: Index already exists.''', 'create index index10 on movesactivityoutput ( activitytypeid )'); |
| 61 | +PREPARE stmt FROM @sqlstmt; |
| 62 | +EXECUTE stmt; |
| 63 | + |
| 64 | +-- Get time units |
| 65 | +set @timeUnits := (select timeUnits from movesrun limit 1); |
| 66 | + |
| 67 | +-- Get hours of activity |
| 68 | +drop table if exists hours; |
| 69 | +create table hours |
| 70 | +select |
| 71 | + MOVESRunID, |
| 72 | + yearID, |
| 73 | + monthID, |
| 74 | + dayID, |
| 75 | + stateID, |
| 76 | + countyID, |
| 77 | + SCC, |
| 78 | + fuelTypeID, |
| 79 | + modelYearID, |
| 80 | + engTechID, |
| 81 | + hpID, |
| 82 | + activity as hours |
| 83 | +from movesactivityoutput |
| 84 | +where activitytypeid = 2; |
| 85 | + |
| 86 | +create index index1 on hours (MOVESRunID,yearID,monthID,dayID,stateID,countyID,SCC,modelYearID); |
| 87 | + |
| 88 | + |
| 89 | +-- Set up unit conversions table |
| 90 | +drop table if exists units; |
| 91 | +create table units (fromUnit char(5), factor double, description text); |
| 92 | +insert into units values |
| 93 | +('ton', 907185, 'From U.S. tons to grams'), |
| 94 | +('lb', 453.592, 'From lbm to grams'), |
| 95 | +('kg', 1000, 'From kg to grams'), |
| 96 | +('g', 1, 'From grams to grams'); |
| 97 | + |
| 98 | + |
| 99 | +-- Get inventories by SCC |
| 100 | +drop table if exists temp1; |
| 101 | +create table temp1 |
| 102 | +select |
| 103 | + MOVESRunID, |
| 104 | + yearID, |
| 105 | + monthID, |
| 106 | + dayID, |
| 107 | + stateID, |
| 108 | + countyID, |
| 109 | + scc, |
| 110 | + modelYearID, |
| 111 | + pollutantID, |
| 112 | + processID, |
| 113 | + units.factor * sum(emissionQuant) as emissionQuant |
| 114 | +from movesoutput m |
| 115 | +left join movesrun using (movesrunid) |
| 116 | +left join units on (movesrun.massUnits = units.fromUnit) |
| 117 | +group by MOVESRunID,yearID,monthID,dayID,stateID,countyID,scc,modelYearID,pollutantID,processID; |
| 118 | + |
| 119 | +create index index1 on temp1 (MOVESRunID,yearID,monthID,dayID,stateID,countyID,scc,modelYearID); |
| 120 | +create index index2 on temp1 (scc); |
| 121 | + |
| 122 | + |
| 123 | +-- Get hours by SCC and ModelYearID |
| 124 | +drop table if exists temp2; |
| 125 | +create table temp2 |
| 126 | +select |
| 127 | + MOVESRunID, |
| 128 | + yearID, |
| 129 | + monthID, |
| 130 | + dayID, |
| 131 | + stateID, |
| 132 | + countyID, |
| 133 | + scc, |
| 134 | + modelYearID, |
| 135 | + sum(hours) as hours |
| 136 | +from hours |
| 137 | +group by MOVESRunID,yearID,monthID,dayID,stateID,countyID,scc,modelYearID; |
| 138 | + |
| 139 | +create index index1 on temp2 (MOVESRunID,yearID,monthID,dayID,stateID,countyID,scc,modelYearID); |
| 140 | + |
| 141 | + |
| 142 | +-- Join temp1 and temp2 and calculate the emission rate for the resulting output table |
| 143 | +drop table if exists EmissionFactors_per_operatinghour_by_SCC_and_ModelYear; |
| 144 | +create table EmissionFactors_per_operatinghour_by_SCC_and_ModelYear |
| 145 | +select |
| 146 | + b1.MOVESRunID, |
| 147 | + b1.yearID, |
| 148 | + b1.monthID, |
| 149 | + b1.dayID, |
| 150 | + b1.stateID, |
| 151 | + b1.countyID, |
| 152 | + b1.scc, |
| 153 | + s.description as sccDescription, |
| 154 | + s.fuelTypeID, |
| 155 | + b1.modelYearID, |
| 156 | + b1.pollutantID, |
| 157 | + b1.processID, |
| 158 | + b1.emissionQuant, |
| 159 | + b2.hours, |
| 160 | + IF(b2.hours != 0, b1.emissionQuant / b2.hours, NULL) as emissionRate, |
| 161 | + 'g/hr' as emissionRateUnits |
| 162 | +from temp1 b1 |
| 163 | +inner join temp2 b2 USING (MOVESRunID,yearID,monthID,dayID,stateID,countyID,scc,modelYearID) |
| 164 | +left join ##defaultdb##.nrscc s on (b1.scc=s.scc); |
| 165 | + |
| 166 | +-- Drop intermediate tables and the primary indexes |
| 167 | +drop table if exists hours; |
| 168 | +drop table if exists temp1; |
| 169 | +drop table if exists temp2; |
| 170 | +drop table if exists units; |
| 171 | + |
| 172 | +set @exist := (select count(*) from information_schema.statistics where table_schema = DATABASE() and table_name = 'movesoutput' and index_name = 'index1'); |
| 173 | +set @sqlstmt := if( @exist = 0, 'select ''INFO: index1 does not exist.''', 'drop index index1 on movesoutput'); |
| 174 | +PREPARE stmt FROM @sqlstmt; |
| 175 | +EXECUTE stmt; |
| 176 | + |
| 177 | +set @exist := (select count(*) from information_schema.statistics where table_schema = DATABASE() and table_name = 'movesoutput' and index_name = 'index104'); |
| 178 | +set @sqlstmt := if( @exist = 0, 'select ''INFO: index104 does not exist.''', 'drop index index104 on movesoutput'); |
| 179 | +PREPARE stmt FROM @sqlstmt; |
| 180 | +EXECUTE stmt; |
| 181 | + |
| 182 | +set @exist := (select count(*) from information_schema.statistics where table_schema = DATABASE() and table_name = 'movesactivityoutput' and index_name = 'index10'); |
| 183 | +set @sqlstmt := if( @exist = 0, 'select ''INFO: index10 does not exist.''', 'drop index index10 on movesactivityoutput'); |
| 184 | +PREPARE stmt FROM @sqlstmt; |
| 185 | +EXECUTE stmt; |
| 186 | + |
| 187 | +-- Revert 0s to NULLs |
| 188 | +UPDATE movesoutput SET stateID = NULL WHERE stateID = 0; |
| 189 | +UPDATE movesoutput SET countyID = NULL WHERE countyID = 0; |
| 190 | +UPDATE movesactivityoutput SET stateID = NULL WHERE stateID = 0; |
| 191 | +UPDATE movesactivityoutput SET countyID = NULL WHERE countyID = 0; |
| 192 | + |
| 193 | +-- drop the rest of the indexes |
| 194 | +set @exist := (select count(*) from information_schema.statistics where table_schema = DATABASE() and table_name = 'movesoutput' and index_name = 'index_state'); |
| 195 | +set @sqlstmt := if( @exist = 0, 'select ''INFO: index_state does not exist.''', 'drop index index_state on movesoutput'); |
| 196 | +PREPARE stmt FROM @sqlstmt; |
| 197 | +EXECUTE stmt; |
| 198 | + |
| 199 | +set @exist := (select count(*) from information_schema.statistics where table_schema = DATABASE() and table_name = 'movesactivityoutput' and index_name = 'index_state'); |
| 200 | +set @sqlstmt := if( @exist = 0, 'select ''INFO: index_state does not exist.''', 'drop index index_state on movesactivityoutput'); |
| 201 | +PREPARE stmt FROM @sqlstmt; |
| 202 | +EXECUTE stmt; |
| 203 | + |
| 204 | +set @exist := (select count(*) from information_schema.statistics where table_schema = DATABASE() and table_name = 'movesoutput' and index_name = 'index_county'); |
| 205 | +set @sqlstmt := if( @exist = 0, 'select ''INFO: index_county does not exist.''', 'drop index index_county on movesoutput'); |
| 206 | +PREPARE stmt FROM @sqlstmt; |
| 207 | +EXECUTE stmt; |
| 208 | + |
| 209 | +set @exist := (select count(*) from information_schema.statistics where table_schema = DATABASE() and table_name = 'movesactivityoutput' and index_name = 'index_county'); |
| 210 | +set @sqlstmt := if( @exist = 0, 'select ''INFO: index_county does not exist.''', 'drop index index_county on movesactivityoutput'); |
| 211 | +PREPARE stmt FROM @sqlstmt; |
| 212 | +EXECUTE stmt; |
0 commit comments