Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add compatibility with Microsoft SQL Server #323

Open
wants to merge 3 commits into
base: master
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
Expand Up @@ -25,23 +25,23 @@
@Entity
@NamedNativeQuery(name = "ErrorLogByrtfeedID",
query = // Retrieve the remaining columns, title and severity from Error and FinalResult tables on matching errorIds.
"SELECT rowIdentifier, ? AS rtFeedID, errorId AS id, " +
"SELECT rowIdentifier, ? AS rtFeedID, Error.errorId AS id, " +
"Error.title, Error.severity, iterationId, occurrence, loggingTime " +
"FROM Error " +
"INNER JOIN " +
// Retrieve the other required column errorId on matching iterationId from MessageLog and UniqueRowIdResult tables.
"(SELECT rowIdentifier, errorId, iterationId, " +
"(SELECT rowIdentifier, MessageLog.errorId, MessageLog.iterationId, " +
"occurrence, loggingTime " +
"FROM MessageLog " +
"INNER JOIN " +
// Retrieve ROWNUM here.
"(SELECT ROWNUM() AS rowIdentifier, " +
"(SELECT ROW_NUMBER() OVER(ORDER BY IterationID) AS rowIdentifier, " +
"IterationID AS iterationId, " +
"feedTimestamp AS occurrence, " +
"IterationTimestamp AS loggingTime " +
"FROM " +
// Retrieve unique IteraionID and IterationTimestamp to get ROWNUM in sequential order.
"(SELECT DISTINCT errorLog.IterationID, errorLog.IterationTimestamp, errorLog.feedTimestamp " +
"(SELECT errorLog.IterationID, errorLog.IterationTimestamp, errorLog.feedTimestamp " +
"FROM " +
"(SELECT GtfsRtFeedIDIteration.IterationID, " +
"GtfsRtFeedIDIteration.IterationTimestamp, " +
Expand All @@ -54,8 +54,7 @@
"ON MessageLog.iterationID = GtfsRtFeedIDIteration.IterationID " +
"AND IterationTimestamp >= ? AND IterationTimestamp <= ? " +
") errorLog " +
"ORDER BY IterationID " +
") " +
"GROUP BY errorLog.IterationID, errorLog.IterationTimestamp, errorLog.feedTimestamp) t" +
") UniqueRowIdResult " +
"ON MessageLog.iterationId = UniqueRowIdResult.iterationId " +
") FinalResult " +
Expand Down
Expand Up @@ -24,24 +24,24 @@
@XmlRootElement
@Entity
@NamedNativeQuery(name = "ErrorSummaryByrtfeedID",
query = "SELECT ? AS rtFeedID, errorID AS id, " +
query = "SELECT ? AS rtFeedID, Error.errorID AS id, " +
"title, severity, totalCount, lastTime, " +
"lastFeedTime, lastIterationId, lastRowId " +
"FROM Error " +
"INNER JOIN " +
"(SELECT errorID, MAX(rowIdentifier) AS lastRowId, " +
"count(*) AS totalCount, MAX(iterationId) AS lastIterationId, " +
"(SELECT MessageLog.errorID, MAX(rowIdentifier) AS lastRowId, " +
"count(*) AS totalCount, MAX(MessageLog.iterationId) AS lastIterationId, " +
"MAX(iterationTimestamp) AS lastTime, " +
"MAX(feedTimestamp) AS lastFeedTime " +
"FROM MessageLog " +
"INNER JOIN " +
// Retrieve rowIdentifier for each of unique (iterationId, iterationTimestamp)
"(SELECT ROWNUM() AS rowIdentifier, " +
"(SELECT ROW_NUMBER() OVER(ORDER BY iterationID) AS rowIdentifier, " +
"IterationID AS iterationId, " +
"IterationTimestamp AS iterationTimestamp, feedTimestamp " +
"FROM " +
// Retrieve unique IterationID and IterationTimestamp, so that we can get ROWNUM in sequence
"(SELECT DISTINCT errorLog.IterationID, errorLog.IterationTimestamp, " +
"(SELECT errorLog.IterationID, errorLog.IterationTimestamp, " +
"errorLog.feedTimestamp " +
"FROM " +
"(SELECT GtfsRtFeedIDIteration.IterationID, " +
Expand All @@ -55,8 +55,7 @@
"ON MessageLog.iterationID = GtfsRtFeedIDIteration.IterationID " +
"AND IterationTimestamp >= ? AND IterationTimestamp <= ? " +
") errorLog " +
"ORDER BY iterationId " +
") " +
"GROUP BY errorLog.IterationID, errorLog.IterationTimestamp, errorLog.feedTimestamp) t" +
") UniqueRowIdResult " +
"ON MessageLog.iterationID = UniqueRowIdResult.iterationId " +
"GROUP BY errorId " +
Expand Down
Expand Up @@ -31,7 +31,7 @@
"INNER JOIN " +
"(SELECT errorID, count(*) AS totalCount, " +
"MAX(IterationTimestamp) AS IterationTimestamp, " +
"MAX(IterationID) AS lastIterationId " +
"MAX(MessageLog.IterationID) AS lastIterationId " +
"FROM MessageLog " +
"INNER JOIN " +
"(SELECT IterationID, IterationTimestamp " +
Expand Down
Expand Up @@ -25,21 +25,20 @@
@XmlRootElement
@Entity
@NamedNativeQuery(name = "IterationIdErrors",
query = "SELECT ROWNUM() AS rowId, occurrenceId, " +
"errorId, title, occurrencePrefix, occurrenceSuffix " +
query = "SELECT ROW_NUMBER() OVER(ORDER BY occurrenceId) AS rowId, occurrenceId, " +
"Error.errorId, title, occurrencePrefix, occurrenceSuffix " +
"FROM Error " +
"INNER JOIN " +
"(SELECT messageId, errorId, prefix AS occurrencePrefix, occurrenceId " +
"(SELECT Occurrence.messageId, prefix AS occurrencePrefix, occurrenceId " +
"FROM " +
"Occurrence " +
"INNER JOIN " +
"(SELECT messageId, errorId " +
"(SELECT MessageLog.messageId, MessageLog.errorId " +
"FROM MessageLog " +
"WHERE iterationId = ?) MessageLogIteration " +
"ON Occurrence.messageId = MessageLogIteration.messageId " +
"WHERE messageId = ? ) OccurrenceList " +
"ON Error.errorId = OccurrenceList.errorId " +
"ORDER BY occurrenceId ",
"WHERE Occurrence.messageId = ? ) OccurrenceList " +
"ON Error.errorId = OccurrenceList.errorId ",
resultClass = ViewIterationErrorsModel.class)
public class ViewIterationErrorsModel {

Expand Down
83 changes: 52 additions & 31 deletions gtfs-realtime-validator-lib/src/test/resources/testSQLScript.sql
@@ -1,48 +1,69 @@

-- Insert records into GtfsFeed table
INSERT INTO GtfsFeed -- Columns (feedId, agency, fileCheckSum, errorCount, fileLocation, feedUrl, downloadTimestamp)
SET IDENTITY_INSERT GtfsFeed ON;


INSERT INTO GtfsFeed (feedId, agency ,fileChecksum ,errorCount ,fileLocation ,feedUrl ,downloadTimestamp)
-- Columns (feedId, agency, fileCheckSum, errorCount, fileLocation, feedUrl, downloadTimestamp)
-- We ensures that record is not inserted if already exists, to avoid primary key constraint violation
SELECT * FROM (VALUES(-1, 'America/New_York', NULL, 0, 'dummy', 'dummy', 1))
WHERE NOT EXISTS (SELECT * FROM GtfsFeed WHERE feedId = -1);
(SELECT * FROM (SELECT -1 a, 'America/New_York' b, NULL c, 0 d,
'dummy' e, 'dummy' f, 1 g)t WHERE NOT EXISTS
(SELECT * FROM GtfsFeed WHERE feedId = -1));

SET IDENTITY_INSERT GtfsFeed OFF;
-- Insert records into GtfsRtFeed table
INSERT INTO GtfsRtFeed -- Columns (rtFeedId, rtFeedUrl, gtfsFeedId)
SET IDENTITY_INSERT GtfsRtFeed ON;

INSERT INTO GtfsRtFeed (rtFeedId, feedURL, gtfsFeedID)
-- Columns (rtFeedId, rtFeedUrl, gtfsFeedId)
-- We ensures that record is not inserted if already exists, to avoid primary key constraint violation
SELECT * FROM (VALUES( -1, 'dummy', -1))
WHERE NOT EXISTS (SELECT * FROM GtfsRtFeed WHERE rtFeedId = -1);
(SELECT * FROM (SELECT -1 a, 'dummy' b, -1 c)t
WHERE NOT EXISTS (SELECT * FROM GtfsRtFeed WHERE rtFeedId = -1));
SET IDENTITY_INSERT GtfsRtFeed OFF;


SET IDENTITY_INSERT GtfsRtFeedIteration ON;

-- Insert records into GtfsRtFeedIteration
INSERT INTO GtfsRtFeedIteration -- Columns (iterationId, feedHash, feedTimestamp, feedProtoBuf, iterationTimestamp, rtFeedId)
INSERT INTO GtfsRtFeedIteration (iterationId, feedHash, feedTimestamp, feedProtoBuf, iterationTimestamp, rtFeedId)
-- Columns (iterationId, feedHash, feedTimestamp, feedProtoBuf, iterationTimestamp, rtFeedId)
-- We ensures that record is not inserted if already exists, to avoid primary key constraint violation
SELECT * FROM (VALUES( -2, NULL, 1, NULL, 1, -1))
WHERE NOT EXISTS (SELECT * FROM GtfsRtFeedIteration WHERE IterationId = -2);
(SELECT * FROM (SELECT -2 a, NULL b, 1 c, NULL d, 1 e, -1 f) t
WHERE NOT EXISTS (SELECT * FROM GtfsRtFeedIteration WHERE IterationId = -2));


INSERT INTO GtfsRtFeedIteration
SELECT * FROM (VALUES( -1, NULL, 2, NULL, 2, -1))
WHERE NOT EXISTS (SELECT * FROM GtfsRtFeedIteration WHERE IterationId = -1);
INSERT INTO GtfsRtFeedIteration (IterationID, feedHash, feedTimestamp, feedProtobuf, IterationTimestamp, rtFeedID)
(SELECT * FROM (SELECT -1 a, NULL b, 2 c, NULL d, 2 e, -1 f) t
WHERE NOT EXISTS (SELECT * FROM GtfsRtFeedIteration WHERE IterationId = -1));

SET IDENTITY_INSERT GtfsRtFeedIteration OFF;
-- Insert records into MessageLog table
INSERT INTO MessageLog -- Columns (messageId, errorDetails, iterationId, errorId)
SET IDENTITY_INSERT MessageLog ON;
INSERT INTO MessageLog (messageId, errorDetails, iterationId, errorId)
-- Columns (messageId, errorDetails, iterationId, errorId)
-- We ensures that record is not inserted if already exists, to avoid primary key constraint violation
SELECT * FROM (VALUES( -6, NULL, -2, 'W002'))
WHERE NOT EXISTS (SELECT * FROM MessageLog WHERE messageId = -6);
(SELECT * FROM (SELECT -6 a, NULL b, -2 c, 'W002' d) t
WHERE NOT EXISTS (SELECT * FROM MessageLog WHERE messageId = -6));

INSERT INTO MessageLog (messageId, errorDetails, iterationId, errorId)
(SELECT * FROM (SELECT -5 a, NULL b, -2 c, 'W001' d) t
WHERE NOT EXISTS (SELECT * FROM MessageLog WHERE messageId = -5));

INSERT INTO MessageLog (messageId, errorDetails, iterationId, errorId)
(SELECT * FROM (SELECT -4 a, NULL b, -2 c, 'E002' d) t
WHERE NOT EXISTS (SELECT * FROM MessageLog WHERE messageId = -4));

INSERT INTO MessageLog (messageId, errorDetails, iterationId, errorId)
(SELECT * FROM (SELECT -3 a, NULL b, -2 c, 'W002' d) t
WHERE NOT EXISTS (SELECT * FROM MessageLog WHERE messageId = -3));

INSERT INTO MessageLog
SELECT * FROM (VALUES( -5, NULL, -2, 'W001'))
WHERE NOT EXISTS (SELECT * FROM MessageLog WHERE messageId = -5);
INSERT INTO MessageLog (messageId, errorDetails, iterationId, errorId)
(SELECT * FROM (SELECT -2 a, NULL b, -2 c, 'W001' d) t
WHERE NOT EXISTS (SELECT * FROM MessageLog WHERE messageId = -2));

INSERT INTO MessageLog
SELECT * FROM (VALUES( -4, NULL, -2, 'E002'))
WHERE NOT EXISTS (SELECT * FROM MessageLog WHERE messageId = -4);
INSERT INTO MessageLog (messageId, errorDetails, iterationId, errorId)
(SELECT * FROM (SELECT -1 a, NULL b, -2 c, 'E002' d) t
WHERE NOT EXISTS (SELECT * FROM MessageLog WHERE messageId = -1));

INSERT INTO MessageLog
SELECT * FROM (VALUES( -3, NULL, -1, 'W002'))
WHERE NOT EXISTS (SELECT * FROM MessageLog WHERE messageId = -3);

INSERT INTO MessageLog
SELECT * FROM (VALUES( -2, NULL, -1, 'W001'))
WHERE NOT EXISTS (SELECT * FROM MessageLog WHERE messageId = -2);

INSERT INTO MessageLog
SELECT * FROM (VALUES( -1, NULL, -1, 'E002'))
WHERE NOT EXISTS (SELECT * FROM MessageLog WHERE messageId = -1);
SET IDENTITY_INSERT MessageLog OFF;
8 changes: 8 additions & 0 deletions gtfs-realtime-validator-webapp/pom.xml
Expand Up @@ -152,6 +152,14 @@
<artifactId>gtfs-realtime-validator-lib</artifactId>
<version>1.0.0-SNAPSHOT</version>
</dependency>
<!-- https://mvnrepository.com/artifact/com.microsoft.sqlserver/mssql-jdbc -->
<dependency>
<groupId>com.microsoft.sqlserver</groupId>
<artifactId>mssql-jdbc</artifactId>
<version>6.2.2.jre8</version>
<scope>test</scope>
</dependency>

</dependencies>

<build>
Expand Down
@@ -1,17 +1,18 @@
<?xml version="1.0" encoding="UTF-8"?>
<!DOCTYPE hibernate-configuration PUBLIC "-//Hibernate/Hibernate Configuration DTD 3.0//EN" "http://hibernate.sourceforge.net/hibernate-configuration-3.0.dtd">
<!DOCTYPE hibernate-configuration PUBLIC "-//Hibernate/Hibernate Configuration DTD 3.0//EN" "http://www.hibernate.org/dtd/hibernate-configuration-3.0.dtd">
<hibernate-configuration>
<session-factory>
<property name="hibernate.dialect">org.hibernate.dialect.HSQLDialect</property>
<property name="hibernate.connection.driver_class">org.hsqldb.jdbcDriver</property>
<property name="hibernate.connection.url">jdbc:hsqldb:file:gtfsrthsql;hsqldb.log_data=false</property>
<property name="hibernate.dialect">org.hibernate.dialect.SQLServer2012Dialect</property>
<property name="hibernate.connection.driver_class">com.microsoft.sqlserver.jdbc.SQLServerDriver</property>
<property name="hibernate.connection.url">jdbc:sqlserver://cutr-db2.forest.usf.edu:1433;databaseName=gtfs-realtime-validator</property>
<property name="hibernate.c3p0.min_size">1</property>
<property name="hibernate.c3p0.max_size">1</property>
<property name="hibernate.c3p0.timeout">1800</property>
<property name="hibernate.c3p0.max_statements">50</property>
<property name="hibernate.connection.username">sa</property>
<property name="hibernate.connection.password"></property>
<property name="hibernate.connection.username"usergoeshere</property>
<property name="hibernate.connection.password">passwordgoeshere</property>
<property name="hibernate.hbm2ddl.auto">update</property>
<property name="show_sql">true</property>
<mapping class="edu.usf.cutr.gtfsrtvalidator.lib.model.GtfsFeedIterationModel"/>
<mapping class="edu.usf.cutr.gtfsrtvalidator.lib.model.GtfsFeedModel"/>
<mapping class="edu.usf.cutr.gtfsrtvalidator.lib.model.GtfsRtFeedIterationModel"/>
Expand Down
Expand Up @@ -69,15 +69,16 @@ protected void setUp() {
String createQuery = new String(encoded, "UTF-8");

String[] createStatements = createQuery.split(";");

Class.forName("com.microsoft.sqlserver.jdbc.SQLServerDriver");
Connection con = DriverManager.getConnection("jdbc:sqlserver://my.sqlserver.com:1433;databaseName=gtfs-realtime-validator",
"testuser", "testpassword");
for (String createStatement : createStatements) {
Class.forName("org.hsqldb.jdbcDriver");
Connection con = DriverManager.getConnection("jdbc:hsqldb:file:gtfsrthsql", "sa", "");
stmt = con.createStatement();
System.out.println(createStatement);
stmt.execute(createStatement);
stmt.close();
con.close();
}
con.close();
} catch (Exception e) {
System.err.println(e.getClass().getName() + ": " + e.getMessage());
System.exit(0);
Expand Down Expand Up @@ -176,28 +177,27 @@ public void testViewErrorLogModel() {
staticResult.add(viewErrorLogModel);

viewErrorLogModel = new ViewErrorLogModel();
viewErrorLogModel.setRowId(2);
viewErrorLogModel.setRowId(1);
viewErrorLogModel.setGtfsRtId(gtfsRtId);
viewErrorLogModel.setIterationId(-1);
viewErrorLogModel.setOccurrence(2);
viewErrorLogModel.setLoggingTime(2);
viewErrorLogModel.setId("W001");
viewErrorLogModel.setSeverity("WARNING");
viewErrorLogModel.setTitle("Timestamp not populated");
viewErrorLogModel.setIterationId(-2);
viewErrorLogModel.setOccurrence(1);
viewErrorLogModel.setLoggingTime(1);
viewErrorLogModel.setId("E002");
viewErrorLogModel.setSeverity("ERROR");
viewErrorLogModel.setTitle("Unsorted stop_sequence");
viewErrorLogModel.setFormattedTimestamp(gtfsRtFeed.getDateFormat(viewErrorLogModel.getOccurrence(), gtfsRtId));
viewErrorLogModel.setTimeZone(GtfsRtFeed.agencyTimezone);

staticResult.add(viewErrorLogModel);

viewErrorLogModel = new ViewErrorLogModel();
viewErrorLogModel.setRowId(2);
viewErrorLogModel.setGtfsRtId(gtfsRtId);
viewErrorLogModel.setIterationId(-1);
viewErrorLogModel.setOccurrence(2);
viewErrorLogModel.setLoggingTime(2);
viewErrorLogModel.setId("W002");
viewErrorLogModel.setId("W001");
viewErrorLogModel.setSeverity("WARNING");
viewErrorLogModel.setTitle("Vehicle_id not populated");
viewErrorLogModel.setTitle("Timestamp not populated");
viewErrorLogModel.setFormattedTimestamp(gtfsRtFeed.getDateFormat(viewErrorLogModel.getOccurrence(), gtfsRtId));
viewErrorLogModel.setTimeZone(GtfsRtFeed.agencyTimezone);

Expand All @@ -209,23 +209,23 @@ public void testViewErrorLogModel() {
viewErrorLogModel.setIterationId(-2);
viewErrorLogModel.setOccurrence(1);
viewErrorLogModel.setLoggingTime(1);
viewErrorLogModel.setId("E002");
viewErrorLogModel.setSeverity("ERROR");
viewErrorLogModel.setTitle("Unsorted stop_sequence");
viewErrorLogModel.setId("W001");
viewErrorLogModel.setSeverity("WARNING");
viewErrorLogModel.setTitle("Timestamp not populated");
viewErrorLogModel.setFormattedTimestamp(gtfsRtFeed.getDateFormat(viewErrorLogModel.getOccurrence(), gtfsRtId));
viewErrorLogModel.setTimeZone(GtfsRtFeed.agencyTimezone);

staticResult.add(viewErrorLogModel);

viewErrorLogModel = new ViewErrorLogModel();
viewErrorLogModel.setRowId(1);
viewErrorLogModel.setRowId(2);
viewErrorLogModel.setGtfsRtId(gtfsRtId);
viewErrorLogModel.setIterationId(-2);
viewErrorLogModel.setOccurrence(1);
viewErrorLogModel.setLoggingTime(1);
viewErrorLogModel.setId("W001");
viewErrorLogModel.setIterationId(-1);
viewErrorLogModel.setOccurrence(2);
viewErrorLogModel.setLoggingTime(2);
viewErrorLogModel.setId("W002");
viewErrorLogModel.setSeverity("WARNING");
viewErrorLogModel.setTitle("Timestamp not populated");
viewErrorLogModel.setTitle("Vehicle_id not populated");
viewErrorLogModel.setFormattedTimestamp(gtfsRtFeed.getDateFormat(viewErrorLogModel.getOccurrence(), gtfsRtId));
viewErrorLogModel.setTimeZone(GtfsRtFeed.agencyTimezone);

Expand Down