Skip to content

Commit eef9da4

Browse files
MOVES4.0.1 with movesdb20240104
2 parents e3d994c + bd714a5 commit eef9da4

40 files changed

+893
-145
lines changed

CITATION.cff

+2-2
Original file line numberDiff line numberDiff line change
@@ -9,5 +9,5 @@ identifiers:
99
value: "Office of Transportation and Air Quality. US Environmental Protection Agency. Ann Arbor, MI."
1010
description: "Publisher"
1111
url: "https://www.epa.gov/moves"
12-
version: 4.0.0
13-
date-released: 2023-08-30
12+
version: 4.0.1
13+
date-released: 2024-01-18

MOVESConfiguration.txt

+1-1
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,5 @@
11
defaultServerName = localhost
2-
defaultDatabaseName = movesdb20230615
2+
defaultDatabaseName = movesdb20240104
33
executionServerName = localhost
44
executionDatabaseName = MOVESExecution
55
outputServerName = 127.0.0.1

amazon/movesamazon.jar

20.9 KB
Binary file not shown.

build.xml

+2-2
Original file line numberDiff line numberDiff line change
@@ -132,8 +132,8 @@
132132
<echo message=" to this file in -Dinput. Use -Doutput= to specify the output" />
133133
<echo message=" file path; file types can be .xls(x), .txt, or .csv. For help," />
134134
<echo message=" see database\NEIQA\NEIQAInstructions.pdf" />
135-
<echo message=" ant onroadNEIQA -Dinput=&quot;cXXXXXyYYYY_in,cZZZZZyYYYY_in&quot; -Doutput=PSC_QA_Report.xlsx" />
136-
<echo message=" ant onroadNEIQA -Dinput=db_list.txt -Doutput=PSC_QA_Report.xlsx" />
135+
<echo message=" ant onroadNEIQA -Dinput=&quot;cXXXXXyYYYY_ZZZZZZZZ,cAAAAAyYYYY_ZZZZZZZZ&quot; -Doutput=QA_Report.xlsx" />
136+
<echo message=" ant onroadNEIQA -Dinput=db_list.txt -Doutput=QA_Report.xlsx" />
137137
<echo message="nonroadNEIQA - run the nonroad NEI QA scripts. Usage has the same arguments" />
138138
<echo message=" as the onroadNEIQA command. " />
139139
<echo message="-------------------------------------------------------------------------------"/>

database/AgeDistributionImporter.sql

+7
Original file line numberDiff line numberDiff line change
@@ -67,3 +67,10 @@ select concat('ERROR: Source ',sourceTypeID,', year ',yearID,' ageFraction sum i
6767
from tempNotUnity;
6868

6969
drop table if exists tempNotUnity;
70+
71+
-- Complain about any null values
72+
insert into importTempMessages (message)
73+
SELECT concat('ERROR: Found a NULL ageFraction value for sourceTypeID: ', sourceTypeID)
74+
from SourceTypeAgeDistribution
75+
where ageFraction IS NULL
76+
LIMIT 1;

database/AverageSpeedDistributionImporter.sql

+7
Original file line numberDiff line numberDiff line change
@@ -14,3 +14,10 @@ select concat('ERROR: Source ',sourceTypeID,', road ',roadTypeID,', hour/day ',h
1414
from tempNotUnity;
1515

1616
drop table if exists tempNotUnity;
17+
18+
-- Complain about any null values
19+
insert into importTempMessages (message)
20+
SELECT concat('ERROR: Found a NULL avgSpeedFraction value for sourceTypeID: ', sourceTypeID)
21+
from avgSpeedDistribution
22+
where avgSpeedFraction IS NULL
23+
LIMIT 1;

database/NEIQA/NEIQAInstructions.pdf

-462 KB
Binary file not shown.

database/NEIQA/onroadCDBchecks.sql

+70-9
Original file line numberDiff line numberDiff line change
@@ -602,11 +602,6 @@ Update CDB_Checks as a, tempb as b set a.count = b.table_rows Where a.tableName
602602

603603
-- Present tables
604604
Update CDB_Checks set testDescription = 'Present' where `count` is not null;
605-
606-
Update CDB_Checks set testDescription = 'Table likely to be overwritten',
607-
`status` = 'Warning'
608-
where `count` > 0
609-
and tableName in ('emissionratebyage', 'fuelsupply', 'fuelformulation', 'zonemonthhour');
610605

611606
Update CDB_Checks set testDescription = 'Table no longer used as user input',
612607
`status` = 'Error'
@@ -1623,6 +1618,7 @@ Drop table if exists tempA;
16231618
-- source type, fuel type, and model year are valid (i.e., no diesel motorcycles).
16241619
-- So this table checks for completeness vs. samplevehiclepopulation, which contains this definition
16251620
-- Also, only check for the existence of modelyearids that will appear in the run (according to the year table)
1621+
-- Also, insert a different message if the entire table is empty, so that it can be flagged as a warning instead
16261622
INSERT INTO QA_Checks_Log values ( 1507, 'OK', @hVersion, curDate(), curTime() );
16271623
Insert into CDB_Checks
16281624
( tableName,
@@ -1639,7 +1635,25 @@ INSERT INTO QA_Checks_Log values ( 1507, 'OK', @hVersion, curDate(), curTime() )
16391635
join `year`
16401636
where modelYearID between yearID-30 and yearID) as t1
16411637
left join avft using (sourceTypeID, fuelTypeID, modelYearID)
1642-
where fuelEngFraction is NULL
1638+
join (select count(*) as n from avft) as t2
1639+
where fuelEngFraction is NULL and n > 0
1640+
ORDER BY sourceTypeID, fuelTypeID, modelYearID LIMIT 1;
1641+
1642+
Insert into CDB_Checks
1643+
( tableName,
1644+
checkNumber,
1645+
testDescription
1646+
)
1647+
Select 'avft' as tableName,
1648+
1507 as checkNumber,
1649+
'Table is empty' as testDescription
1650+
from (select distinct sourceTypeID, fuelTypeID, modelYearID
1651+
from ##defaultdb##.samplevehiclepopulation
1652+
join `year`
1653+
where modelYearID between yearID-30 and yearID) as t1
1654+
left join avft using (sourceTypeID, fuelTypeID, modelYearID)
1655+
join (select count(*) as n from avft) as t2
1656+
where fuelEngFraction is NULL and n = 0
16431657
ORDER BY sourceTypeID, fuelTypeID, modelYearID LIMIT 1;
16441658

16451659
-- check no. 1508: check column type definitions for input db mismatches with default db
@@ -2445,6 +2459,18 @@ join (select column_name, column_type, is_nullable, column_key from information_
24452459
where table_schema = '##defaultdb##' and table_name = 'emissionratebyage') t2 using (column_name)
24462460
where t1.column_type <> t2.column_type or t1.is_nullable <> t2.is_nullable or t1.column_key <> t2.column_key;
24472461

2462+
-- check no. 1905: warn that any user-supplied emissionRateByAge table is likely to be overwritten
2463+
INSERT INTO QA_Checks_Log values ( 1905, 'OK', @hVersion, curDate(), curTime() );
2464+
Insert into CDB_Checks
2465+
( TableName,
2466+
CheckNumber,
2467+
TestDescription )
2468+
Select "emissionRateByAge" as tableName,
2469+
1905,
2470+
'Table likely to be overwritten' as testDescription
2471+
from emissionRateByAge
2472+
having count(*) > 0;
2473+
24482474
-- Checks for fuelformulation
24492475
Insert into CDB_Checks (CheckNumber, TableName, TestDescription) values (2000, "fuelFormulation", "Table Check:");
24502476

@@ -2836,6 +2862,18 @@ join (select column_name, column_type, is_nullable, column_key from information_
28362862
where table_schema = '##defaultdb##' and table_name = 'fuelformulation') t2 using (column_name)
28372863
where t1.column_type <> t2.column_type or t1.is_nullable <> t2.is_nullable or t1.column_key <> t2.column_key;
28382864

2865+
-- check no. 2015: warn that any user-supplied fuelformulation table is likely to be overwritten
2866+
INSERT INTO QA_Checks_Log values ( 2015, 'OK', @hVersion, curDate(), curTime() );
2867+
Insert into CDB_Checks
2868+
( TableName,
2869+
CheckNumber,
2870+
TestDescription )
2871+
Select "fuelFormulation" as tableName,
2872+
2015,
2873+
'Table likely to be overwritten' as testDescription
2874+
from fuelFormulation
2875+
having count(*) > 0;
2876+
28392877
-- fuelsupply checks
28402878
Insert into CDB_Checks (CheckNumber, TableName, TestDescription) values (2100, "fuelSupply", "Table Check:");
28412879

@@ -2961,6 +2999,17 @@ join (select column_name, column_type, is_nullable, column_key from information_
29612999
where table_schema = '##defaultdb##' and table_name = 'fuelsupply') t2 using (column_name)
29623000
where t1.column_type <> t2.column_type or t1.is_nullable <> t2.is_nullable or t1.column_key <> t2.column_key;
29633001

3002+
-- check no. 2106: warn that any user-supplied fuelSupply table is likely to be overwritten
3003+
INSERT INTO QA_Checks_Log values ( 2106, 'OK', @hVersion, curDate(), curTime() );
3004+
Insert into CDB_Checks
3005+
( TableName,
3006+
CheckNumber,
3007+
TestDescription )
3008+
Select "fuelSupply" as tableName,
3009+
2106,
3010+
'Table likely to be overwritten' as testDescription
3011+
from fuelSupply
3012+
having count(*) > 0;
29643013

29653014
-- fuelusagefraction
29663015
Insert into CDB_Checks (CheckNumber, TableName, TestDescription) values (2200, "fuelUsageFraction", "Table Check:");
@@ -8040,6 +8089,17 @@ join (select column_name, column_type, is_nullable, column_key from information_
80408089
where table_schema = '##defaultdb##' and table_name = 'zonemonthhour') t2 using (column_name)
80418090
where t1.column_type <> t2.column_type or t1.is_nullable <> t2.is_nullable or t1.column_key <> t2.column_key;
80428091

8092+
-- check no. 5008: warn that any user-supplied zoneMonthHour table is likely to be overwritten
8093+
INSERT INTO QA_Checks_Log values ( 5008, 'OK', @hVersion, curDate(), curTime() );
8094+
Insert into CDB_Checks
8095+
( TableName,
8096+
CheckNumber,
8097+
TestDescription )
8098+
Select "zoneMonthHour" as tableName,
8099+
5008,
8100+
'Table likely to be overwritten' as testDescription
8101+
from zoneMonthHour
8102+
having count(*) > 0;
80438103

80448104
-- zoneRoadType
80458105
Insert into CDB_Checks (CheckNumber, TableName, TestDescription) values (5100, "zoneRoadType", "Table Check:");
@@ -8192,9 +8252,10 @@ Update CDB_Checks set status = 'Error' where checkNumber is not null an
81928252
-- set Status to 'Warning' for select checks (these are typically distribution checks, as well as tables that give warnings
81938253
-- if you supply them: fuelformulation, fuelsupply, and zonemonthhour)
81948254
Update CDB_Checks set status = 'Warning' where checkNumber in
8195-
(1608,1609,1610,1611,1807,2001,2002,2003,2004,2005,2006,2007,2008,2009,2010,2011,2012,2101,
8196-
2102,2103,2104,2406,2507,2508,2808,2809,3605,3804,3805,3906,4506,5001,5002,5003,5004,5005,
8197-
5006);
8255+
(1608,1609,1610,1611,1806,1807,1905,2001,2002,2003,2004,2005,2006,2007,2008,2009,2010,2011,
8256+
2012,2015,2101,2102,2103,2104,2106,2406,2507,2508,2808,2809,3605,3804,3805,3906,4506,5001,
8257+
5002,5003,5004,5005,5006,5008);
8258+
Update CDB_Checks set status = 'Warning' where checkNumber = 1507 and testDescription = 'Table is empty';
81988259

81998260
-- special cases for VMT/starts checks --
82008261
-- mark all VMT row count checks as 'complete' regardless of results
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,212 @@
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

Comments
 (0)