diff --git a/README b/README.md similarity index 65% rename from README rename to README.md index 4cc3865..015c233 100644 --- a/README +++ b/README.md @@ -1,5 +1,5 @@ -GTFS MySQL IMPORT SCRIPT -Author: Tom Lee (thomas.j.lee@gmail.com) +##GTFS MySQL IMPORT SCRIPT +_Author: Tom Lee (thomas.j.lee@gmail.com)_ This is a simple set of scripts that will import a GTFS dataset into a lightweight MySQL database. The work is based on Washington, DC's @@ -11,12 +11,13 @@ In addition to the GTFS fields, a number of columns have been created to assist in the conversion of GTFS's string-based date/time representations to more useful Unix timestamp-style second counts. -DEAD-SIMPLE USAGE: +####DEAD-SIMPLE USAGE: 1. Create a database, e.g. CREATE DATABASE gtfs 2. Run table creation scripts against the database: + cat sql/*.sql | mysql -p -u USERNAME -h HOST -D gtfs 3. Edit settings.py with your mysql details. @@ -25,10 +26,23 @@ DEAD-SIMPLE USAGE: 5. Run the import script: + python load_gtfs.py 6. Run the time index creation script: + python build_indices.py -7. Build something neat \ No newline at end of file +7. Build something neat + +####EVEN MORE SIMPLE USAGE: + 1. Put your GTFS files into the gtfs/ folder + 2. At the bottom of _sql_better/load.sql_, comment out LOAD DATA statements for those tables/gtfs files you don't want to include. + 3. + + + cd gtfs + cat ../sql_better/load.sql | mysql -u username -ppassword --local-infile gtfs + + 4. Build something neat \ No newline at end of file diff --git a/sql/agency.sql b/sql/agency.sql index 9561c66..695d270 100644 --- a/sql/agency.sql +++ b/sql/agency.sql @@ -1,8 +1,12 @@ DROP TABLE IF EXISTS `agency`; CREATE TABLE `agency` ( - agency_id VARCHAR(11) PRIMARY KEY, - agency_name VARCHAR(255), - agency_url VARCHAR(255), - agency_timezone VARCHAR(50) -); \ No newline at end of file + agency_id VARCHAR(10) PRIMARY KEY, + agency_name VARCHAR(255) NOT NULL, + agency_url VARCHAR(255) NOT NULL, + agency_timezone VARCHAR(50) NOT NULL, + agency_lang CHAR(2), + agency_phone VARCHAR(32), + agency_fare_url VARCHAR(255), + agency_email VARCHAR(255) +); diff --git a/sql/calendar.sql b/sql/calendar.sql index 5b1d34c..af9d5db 100644 --- a/sql/calendar.sql +++ b/sql/calendar.sql @@ -1,19 +1,15 @@ DROP TABLE IF EXISTS `calendar`; CREATE TABLE `calendar` ( - service_id VARCHAR(50), - service_name VARCHAR(50), - monday TINYINT(1), - tuesday TINYINT(1), - wednesday TINYINT(1), - thursday TINYINT(1), - friday TINYINT(1), - saturday TINYINT(1), - sunday TINYINT(1), - start_date VARCHAR(8), - end_date VARCHAR(8),start_date_timestamp INT(11), - end_date_timestamp INT(11), - KEY `service_id` (service_id), - KEY `start_date_timestamp` (start_date_timestamp), - KEY `end_date_timestamp` (end_date_timestamp) + service_id INTEGER(10) PRIMARY KEY, + monday TINYINT(1) NOT NULL, + tuesday TINYINT(1) NOT NULL, + wednesday TINYINT(1) NOT NULL, + thursday TINYINT(1) NOT NULL, + friday TINYINT(1) NOT NULL, + saturday TINYINT(1) NOT NULL, + sunday TINYINT(1) NOT NULL, + start_date VARCHAR(8) NOT NULL, + end_date VARCHAR(8) NOT NULL, + KEY `service_id` (service_id) ); diff --git a/sql/calendar_dates.sql b/sql/calendar_dates.sql index f41ccab..d603c31 100644 --- a/sql/calendar_dates.sql +++ b/sql/calendar_dates.sql @@ -1,11 +1,15 @@ DROP TABLE IF EXISTS `calendar_dates`; CREATE TABLE `calendar_dates` ( - `date` VARCHAR(8), - date_timestamp INT(11), - exception_type INT(2), - service_id VARCHAR(10), - KEY `service_id` (service_id), - KEY `date_timestamp` (date), - KEY `exception_type` (exception_type) + service_id INTEGER(10) NOT NULL, + `date` VARCHAR(8) NOT NULL, + exception_type TINYINT(1) NOT NULL, + + CHECK (exception_type = 1 || exception_type = 2), + + PRIMARY KEY (service_id, `date`, exception_type), + + FOREIGN KEY (service_id) + REFERENCES calendar(service_id) + ON UPDATE CASCADE ON DELETE CASCADE ); diff --git a/sql/fare_attributes.sql b/sql/fare_attributes.sql new file mode 100644 index 0000000..03c5fa8 --- /dev/null +++ b/sql/fare_attributes.sql @@ -0,0 +1,13 @@ +DROP TABLE IF EXISTS `fare_attributes`; + +CREATE TABLE `fare_attributes` ( + fare_id VARCHAR(255) PRIMARY KEY, + price DECIMAL (4,2) NOT NULL, + currency_type VARCHAR(3) NOT NULL, + payment_method TINYINT(1) NOT NULL, + transfers TINYINT(1) NOT NULL, + transfer_duration INTEGER(5) UNSIGNED, + + CHECK (payment_method = 0 || payment_method = 1), + CHECK (transfers >= 0 && transfers <= 2) +); diff --git a/sql/fare_rules.sql b/sql/fare_rules.sql new file mode 100644 index 0000000..8acc4a9 --- /dev/null +++ b/sql/fare_rules.sql @@ -0,0 +1,13 @@ +DROP TABLE IF EXISTS `fare_rules`; + +CREATE TABLE `fare_rules` ( + fare_id VARCHAR(255) NOT NULL, + route_id VARCHAR(10), + origin_id VARCHAR(10), + destination_id VARCHAR(10), + contains_id VARCHAR(10), + + FOREIGN KEY (fare_id) + REFERENCES fare_attributes(fare_id) + ON UPDATE CASCADE ON DELETE CASCADE +); diff --git a/sql/feed_info.sql b/sql/feed_info.sql new file mode 100644 index 0000000..76894e3 --- /dev/null +++ b/sql/feed_info.sql @@ -0,0 +1,12 @@ +DROP TABLE IF EXISTS `feed_info`; + +CREATE TABLE `feed_info` ( + feed_publisher_name VARCHAR(255) NOT NULL, + feed_publisher_url VARCHAR(255) NOT NULL, + feed_lang CHAR(2) NOT NULL, + feed_start_date VARCHAR(8), + feed_end_date VARCHAR(8), + feed_version VARCHAR(255), + + CONSTRAINT uc_feedPub UNIQUE (feed_publisher_name, feed_publisher_url, feed_lang, feed_start_date, feed_end_date, feed_version) +); diff --git a/sql/frequencies.sql b/sql/frequencies.sql new file mode 100644 index 0000000..4d5ee06 --- /dev/null +++ b/sql/frequencies.sql @@ -0,0 +1,17 @@ +DROP TABLE IF EXISTS `frequencies`; + +CREATE TABLE `frequencies` ( + trip_id INTEGER(10) NOT NULL, + start_time TIME NOT NULL, + end_time TIME NOT NULL, + headway_secs INTEGER(5) UNSIGNED NOT NULL, + exact_times TINYINT(1) DEFAULT 0, + + CHECK (exact_times = 0 || exact_times = 1), + + FOREIGN KEY (trip_id) + REFERENCES trips(trip_id) + ON UPDATE CASCADE ON DELETE CASCADE, + + CONSTRAINT uc_tripFreq UNIQUE (trip_id, start_time, end_time) +); diff --git a/sql/routes.sql b/sql/routes.sql index bec5f50..6975426 100644 --- a/sql/routes.sql +++ b/sql/routes.sql @@ -1,16 +1,21 @@ DROP TABLE IF EXISTS `routes`; CREATE TABLE `routes` ( - route_id INT(11) PRIMARY KEY, - agency_id VARCHAR(11), - route_short_name VARCHAR(50), - route_long_name VARCHAR(255), - route_service_name VARCHAR(255), - route_type INT(2), - route_text_color VARCHAR(255), - route_color VARCHAR(255), - route_url VARCHAR(255), - route_desc VARCHAR(1000), + route_id VARCHAR(10) PRIMARY KEY, + agency_id VARCHAR(10), + route_short_name VARCHAR(50) NOT NULL, + route_long_name VARCHAR(255) NOT NULL, + route_desc VARCHAR(255), + route_type TINYINT(1) NOT NULL, + route_url VARCHAR(255), + route_color CHAR(6) DEFAULT 'FFFFFF', + route_text_color CHAR(6) DEFAULT '000000', KEY `agency_id` (agency_id), - KEY `route_type` (route_type) + KEY `route_type` (route_type), + + CHECK (route_type >=0 && route_type <= 7), + + FOREIGN KEY (agency_id) + REFERENCES agency(agency_id) + ON UPDATE CASCADE ON DELETE CASCADE ); diff --git a/sql/shapes.sql b/sql/shapes.sql index f23ba7c..106b28e 100644 --- a/sql/shapes.sql +++ b/sql/shapes.sql @@ -1,11 +1,10 @@ DROP TABLE IF EXISTS `shapes`; CREATE TABLE `shapes` ( - shape_id INT(11), - shape_code VARCHAR(8), - shape_pt_lat DECIMAL(8,6), - shape_pt_lon DECIMAL(8,6), - shape_pt_sequence INT(11), - shape_dist_traveled DECIMAL(8,6), + shape_id VARCHAR(10) NOT NULL, + shape_pt_lat DECIMAL(9,6) NOT NULL, + shape_pt_lon DECIMAL(9,6) NOT NULL, + shape_pt_sequence INTEGER(5) NOT NULL, + shape_dist_traveled DECIMAL(7,4), PRIMARY KEY (shape_id, shape_pt_sequence) -); \ No newline at end of file +); diff --git a/sql/stop_times.sql b/sql/stop_times.sql index a4d0146..c1ce5b0 100644 --- a/sql/stop_times.sql +++ b/sql/stop_times.sql @@ -1,24 +1,31 @@ DROP TABLE IF EXISTS `stop_times`; CREATE TABLE `stop_times` ( - trip_id VARCHAR(20), - arrival_time VARCHAR(8), - arrival_time_seconds INT(11), - departure_time VARCHAR(8), - departure_time_seconds INT(11), - stop_id INT(11), - stop_sequence INT(11), - stop_headsign VARCHAR(50), - pickup_type INT(2), - drop_off_type INT(2), - timepoint INT(2), - shape_dist_traveled VARCHAR(50), - stop_times_url VARCHAR(255), + trip_id INTEGER(10) NOT NULL, + arrival_time TIME NOT NULL, + departure_time TIME NOT NULL, + stop_id VARCHAR(10) NOT NULL, + stop_sequence INTEGER(10), + stop_headsign VARCHAR(255), + pickup_type INTEGER(2) DEFAULT 0, + drop_off_type INTEGER(2) DEFAULT 0, + shape_dist_traveled DECIMAL(7,4), + timepoint TINYINT(1) DEFAULT 1, KEY `trip_id` (trip_id), - KEY `arrival_time_seconds` (arrival_time_seconds), - KEY `departure_time_seconds` (departure_time_seconds), KEY `stop_id` (stop_id), KEY `stop_sequence` (stop_sequence), KEY `pickup_type` (pickup_type), - KEY `drop_off_type` (drop_off_type) + KEY `drop_off_type` (drop_off_type), + + CHECK (pickup_type >= 0 && pickup_type <= 3), + CHECK (drop_off_type >= 0 && drop_off_type <= 3), + CHECK (timepoint = 0 || timepoint = 1), + + FOREIGN KEY (trip_id) + REFERENCES trips(trip_id) + ON UPDATE CASCADE ON DELETE CASCADE, + + FOREIGN KEY (stop_id) + REFERENCES stops(stop_id) + ON UPDATE CASCADE ON DELETE CASCADE ); diff --git a/sql/stops.sql b/sql/stops.sql index 805f0bc..33623b5 100644 --- a/sql/stops.sql +++ b/sql/stops.sql @@ -1,24 +1,21 @@ DROP TABLE IF EXISTS `stops`; CREATE TABLE `stops` ( - stop_id INT(11) PRIMARY KEY, - stop_code VARCHAR(50), - stop_name VARCHAR(255), + stop_id VARCHAR(10) PRIMARY KEY, + stop_code INTEGER(10) UNIQUE, + stop_name VARCHAR(255) NOT NULL, stop_desc VARCHAR(255), - stop_lat DECIMAL(8,6), - stop_lon DECIMAL(8,6), - agency_id VARCHAR(8), - stop_jurisdiction VARCHAR(8), - zone_id INT(11), - stop_url VARCHAR(255), - location_type INT(2), - parent_station INT(11), - position VARCHAR(255), - direction VARCHAR(255), - wheelchair_boarding INT(2), - KEY `zone_id` (zone_id), - KEY `stop_lat` (stop_lat), - KEY `stop_lon` (stop_lon), - KEY `location_type` (location_type), - KEY `parent_station` (parent_station) + stop_lat DECIMAL(9,6) NOT NULL, + stop_lon DECIMAL(9,6) NOT NULL, + zone_id INTEGER(10), + stop_url VARCHAR(255), + location_type TINYINT(1) DEFAULT 0, + parent_station TINYINT(1) DEFAULT 0, + stop_timezone VARCHAR(50), + wheelchair_boarding TINYINT(1) DEFAULT 0, + + CHECK (location_type = 0 || location_type = 1), + CHECK (wheelchair_boarding = 0 || wheelchair_boarding = 1 || wheelchair_boarding = 2), + + CONSTRAINT uc_location UNIQUE (stop_lat, stop_lon) ); diff --git a/sql/transfers.sql b/sql/transfers.sql new file mode 100644 index 0000000..26888b9 --- /dev/null +++ b/sql/transfers.sql @@ -0,0 +1,17 @@ +DROP TABLE IF EXISTS `transfers`; + +CREATE TABLE `transfers` ( + from_stop_id VARCHAR(10) NOT NULL, + to_stop_id VARCHAR(10) NOT NULL, + transfer_type TINYINT(1) DEFAULT 0, + min_transfer_time INTEGER(5) UNSIGNED, + CHECK (transfer_type >= 0 && transfer_type <= 3), + + FOREIGN KEY (from_stop_id) + REFERENCES stops(stop_id) + ON UPDATE CASCADE ON DELETE CASCADE, + + FOREIGN KEY (to_stop_id) + REFERENCES stops(stop_id) + ON UPDATE CASCADE ON DELETE CASCADE +); diff --git a/sql/trips.sql b/sql/trips.sql index e88e779..930020a 100644 --- a/sql/trips.sql +++ b/sql/trips.sql @@ -1,21 +1,31 @@ DROP TABLE IF EXISTS `trips`; CREATE TABLE `trips` ( - route_id INT(11), - service_id VARCHAR(10), - trip_id VARCHAR(20) PRIMARY KEY, + route_id VARCHAR(10) NOT NULL, + service_id INTEGER(10) NOT NULL, + trip_id INTEGER(10) PRIMARY KEY, trip_headsign VARCHAR(255), - route_short_name VARCHAR(255), + trip_short_name VARCHAR(50), direction_id TINYINT(1), - direction_name VARCHAR(255), - block_id INT(11), - shape_id INT(11), - shape_code VARCHAR(50), - trip_type VARCHAR(8), - wheelchair_accessible INT(2), + block_id INTEGER(10), + shape_id VARCHAR(10), + wheelchair_accessible TINYINT(1), + bikes_allowed TINYINT(2), + KEY `route_id` (route_id), KEY `service_id` (service_id), KEY `direction_id` (direction_id), KEY `block_id` (block_id), - KEY `shape_id` (shape_id) + + CHECK (direction_id = 0 || direction_id = 1), + CHECK (wheelchair_accessible >= 0 && wheelchair_accessible <= 2), + CHECK (bikes_allowed >= 0 && bikes_allowed <= 2), + + FOREIGN KEY (route_id) + REFERENCES routes(route_id) + ON UPDATE CASCADE ON DELETE CASCADE, + + FOREIGN KEY (service_id) + REFERENCES calendar(service_id) + ON UPDATE CASCADE ON DELETE CASCADE ); diff --git a/sql_better/load.sql b/sql_better/load.sql index efbee05..fbd5029 100644 --- a/sql_better/load.sql +++ b/sql_better/load.sql @@ -1,6 +1,7 @@ -/* +/* Script contributed by Michael Perkins +updated on 10/16/16 by Timothy Baumgartner example usage: cat load.sql | mysql -u root @@ -8,113 +9,251 @@ cat load.sql | mysql -u root */ -CREATE DATABASE IF NOT EXISTS wmata_gtfs; +DROP DATABASE IF EXISTS gtfs; -USE wmata_gtfs +CREATE DATABASE gtfs; + +USE gtfs; -DROP TABLE IF EXISTS agency; CREATE TABLE `agency` ( - agency_id int(11) PRIMARY KEY, - agency_name VARCHAR(255), - agency_url VARCHAR(255), - agency_timezone VARCHAR(50) + agency_id VARCHAR(10) PRIMARY KEY, + agency_name VARCHAR(255) NOT NULL, + agency_url VARCHAR(255) NOT NULL, + agency_timezone VARCHAR(50) NOT NULL, + agency_lang CHAR(2), + agency_phone VARCHAR(32), + agency_fare_url VARCHAR(255), + agency_email VARCHAR(255) ); -DROP TABLE IF EXISTS calendar; +CREATE TABLE `routes` ( + route_id VARCHAR(10) PRIMARY KEY, + agency_id VARCHAR(10), + route_short_name VARCHAR(50) NOT NULL, + route_long_name VARCHAR(255) NOT NULL, + route_desc VARCHAR(255), + route_type TINYINT(1) NOT NULL, + route_url VARCHAR(255), + route_color CHAR(6) DEFAULT 'FFFFFF', + route_text_color CHAR(6) DEFAULT '000000', + KEY `agency_id` (agency_id), + KEY `route_type` (route_type), + + CHECK (route_type >=0 && route_type <= 7), + + FOREIGN KEY (agency_id) + REFERENCES agency(agency_id) + ON UPDATE CASCADE ON DELETE CASCADE +); CREATE TABLE `calendar` ( - service_id INT(11), - monday TINYINT(1), - tuesday TINYINT(1), - wednesday TINYINT(1), - thursday TINYINT(1), - friday TINYINT(1), - saturday TINYINT(1), - sunday TINYINT(1), - start_date VARCHAR(8), - end_date VARCHAR(8), + service_id INTEGER(10) PRIMARY KEY, + monday TINYINT(1) NOT NULL, + tuesday TINYINT(1) NOT NULL, + wednesday TINYINT(1) NOT NULL, + thursday TINYINT(1) NOT NULL, + friday TINYINT(1) NOT NULL, + saturday TINYINT(1) NOT NULL, + sunday TINYINT(1) NOT NULL, + start_date VARCHAR(8) NOT NULL, + end_date VARCHAR(8) NOT NULL, KEY `service_id` (service_id) ); -DROP TABLE IF EXISTS calendar_dates; - CREATE TABLE `calendar_dates` ( - service_id INT(11), - `date` VARCHAR(8), - exception_type INT(2), - KEY `service_id` (service_id), - KEY `exception_type` (exception_type) + service_id INTEGER(10) NOT NULL, + `date` VARCHAR(8) NOT NULL, + exception_type TINYINT(1) NOT NULL, + + CHECK (exception_type = 1 || exception_type = 2), + + PRIMARY KEY (service_id, `date`, exception_type), + + FOREIGN KEY (service_id) + REFERENCES calendar(service_id) + ON UPDATE CASCADE ON DELETE CASCADE ); -DROP TABLE IF EXISTS routes; +CREATE TABLE `fare_attributes` ( + fare_id VARCHAR(255) PRIMARY KEY, + price DECIMAL (4,2) NOT NULL, + currency_type VARCHAR(3) NOT NULL, + payment_method TINYINT(1) NOT NULL, + transfers TINYINT(1) NOT NULL, + transfer_duration INTEGER(5) UNSIGNED, -CREATE TABLE `routes` ( - route_id INT(11) PRIMARY KEY, - agency_id INT(11), - route_short_name VARCHAR(50), - route_long_name VARCHAR(255), - route_type INT(2), - KEY `agency_id` (agency_id), - KEY `route_type` (route_type) + CHECK (payment_method = 0 || payment_method = 1), + CHECK (transfers >= 0 && transfers <= 2) ); -DROP TABLE IF EXISTS stop_times; +CREATE TABLE `fare_rules` ( + fare_id VARCHAR(255) NOT NULL, + route_id VARCHAR(10), + origin_id VARCHAR(10), + destination_id VARCHAR(10), + contains_id VARCHAR(10), -CREATE TABLE `stop_times` ( - trip_id INT(11), - arrival_time VARCHAR(8), - departure_time VARCHAR(8), - stop_id INT(11), - stop_sequence INT(11), - pickup_type INT(2), - drop_off_type INT(2), - KEY `trip_id` (trip_id), - KEY `stop_id` (stop_id), - KEY `stop_sequence` (stop_sequence), - KEY `pickup_type` (pickup_type), - KEY `drop_off_type` (drop_off_type) + FOREIGN KEY (fare_id) + REFERENCES fare_attributes(fare_id) + ON UPDATE CASCADE ON DELETE CASCADE ); -DROP TABLE IF EXISTS stops; +CREATE TABLE `feed_info` ( + feed_publisher_name VARCHAR(255) NOT NULL, + feed_publisher_url VARCHAR(255) NOT NULL, + feed_lang CHAR(2) NOT NULL, + feed_start_date VARCHAR(8), + feed_end_date VARCHAR(8), + feed_version VARCHAR(255), + + CONSTRAINT uc_feedPub UNIQUE (feed_publisher_name, feed_publisher_url, feed_lang, feed_start_date, feed_end_date, feed_version) +); + +CREATE TABLE `shapes` ( + shape_id VARCHAR(10) NOT NULL, + shape_pt_lat DECIMAL(9,6) NOT NULL, + shape_pt_lon DECIMAL(9,6) NOT NULL, + shape_pt_sequence INTEGER(5) NOT NULL, + shape_dist_traveled DECIMAL(7,4), + PRIMARY KEY (shape_id, shape_pt_sequence) +); CREATE TABLE `stops` ( - stop_id INT(11) PRIMARY KEY, - stop_name VARCHAR(255), + stop_id VARCHAR(10) PRIMARY KEY, + stop_code INTEGER(10) UNIQUE, + stop_name VARCHAR(255) NOT NULL, stop_desc VARCHAR(255), - stop_lat DECIMAL(8,6), - stop_lon DECIMAL(8,6), - zone_id INT(11), - KEY `zone_id` (zone_id), - KEY `stop_lat` (stop_lat), - KEY `stop_lon` (stop_lon) + stop_lat DECIMAL(9,6) NOT NULL, + stop_lon DECIMAL(9,6) NOT NULL, + zone_id INTEGER(10), + stop_url VARCHAR(255), + location_type TINYINT(1) DEFAULT 0, + parent_station TINYINT(1) DEFAULT 0, + stop_timezone VARCHAR(50), + wheelchair_boarding TINYINT(1) DEFAULT 0, + + CHECK (location_type = 0 || location_type = 1), + CHECK (wheelchair_boarding = 0 || wheelchair_boarding = 1 || wheelchair_boarding = 2), + + CONSTRAINT uc_location UNIQUE (stop_lat, stop_lon) ); -DROP TABLE IF EXISTS trips; +CREATE TABLE `transfers` ( + from_stop_id VARCHAR(10) NOT NULL, + to_stop_id VARCHAR(10) NOT NULL, + transfer_type TINYINT(1) DEFAULT 0, + min_transfer_time INTEGER(5) UNSIGNED, + CHECK (transfer_type >= 0 && transfer_type <= 3), + + FOREIGN KEY (from_stop_id) + REFERENCES stops(stop_id) + ON UPDATE CASCADE ON DELETE CASCADE, + + FOREIGN KEY (to_stop_id) + REFERENCES stops(stop_id) + ON UPDATE CASCADE ON DELETE CASCADE +); CREATE TABLE `trips` ( - route_id INT(11), - service_id INT(11), - trip_id INT(11) PRIMARY KEY, + route_id VARCHAR(10) NOT NULL, + service_id INTEGER(10) NOT NULL, + trip_id INTEGER(10) PRIMARY KEY, trip_headsign VARCHAR(255), + trip_short_name VARCHAR(50), direction_id TINYINT(1), - block_id INT(11), + block_id INTEGER(10), + shape_id VARCHAR(10), + wheelchair_accessible TINYINT(1), + bikes_allowed TINYINT(2), + KEY `route_id` (route_id), KEY `service_id` (service_id), KEY `direction_id` (direction_id), - KEY `block_id` (block_id) + KEY `block_id` (block_id), + + CHECK (direction_id = 0 || direction_id = 1), + CHECK (wheelchair_accessible >= 0 && wheelchair_accessible <= 2), + CHECK (bikes_allowed >= 0 && bikes_allowed <= 2), + + FOREIGN KEY (route_id) + REFERENCES routes(route_id) + ON UPDATE CASCADE ON DELETE CASCADE, + + FOREIGN KEY (service_id) + REFERENCES calendar(service_id) + ON UPDATE CASCADE ON DELETE CASCADE +); + +CREATE TABLE `frequencies` ( + trip_id INTEGER(10) NOT NULL, + start_time TIME NOT NULL, + end_time TIME NOT NULL, + headway_secs INTEGER(5) UNSIGNED NOT NULL, + exact_times TINYINT(1) DEFAULT 0, + + CHECK (exact_times = 0 || exact_times = 1), + + FOREIGN KEY (trip_id) + REFERENCES trips(trip_id) + ON UPDATE CASCADE ON DELETE CASCADE, + + CONSTRAINT uc_tripFreq UNIQUE (trip_id, start_time, end_time) +); + +CREATE TABLE `stop_times` ( + trip_id INTEGER(10) NOT NULL, + arrival_time TIME NOT NULL, + departure_time TIME NOT NULL, + stop_id VARCHAR(10) NOT NULL, + stop_sequence INTEGER(10), + stop_headsign VARCHAR(255), + pickup_type INTEGER(2) DEFAULT 0, + drop_off_type INTEGER(2) DEFAULT 0, + shape_dist_traveled DECIMAL(7,4), + timepoint TINYINT(1) DEFAULT 1, + KEY `trip_id` (trip_id), + KEY `stop_id` (stop_id), + KEY `stop_sequence` (stop_sequence), + KEY `pickup_type` (pickup_type), + KEY `drop_off_type` (drop_off_type), + + CHECK (pickup_type >= 0 && pickup_type <= 3), + CHECK (drop_off_type >= 0 && drop_off_type <= 3), + CHECK (timepoint = 0 || timepoint = 1), + + FOREIGN KEY (trip_id) + REFERENCES trips(trip_id) + ON UPDATE CASCADE ON DELETE CASCADE, + + FOREIGN KEY (stop_id) + REFERENCES stops(stop_id) + ON UPDATE CASCADE ON DELETE CASCADE ); + LOAD DATA LOCAL INFILE 'agency.txt' INTO TABLE agency FIELDS TERMINATED BY ',' IGNORE 1 LINES; +LOAD DATA LOCAL INFILE 'routes.txt' INTO TABLE routes FIELDS TERMINATED BY ',' IGNORE 1 LINES; + LOAD DATA LOCAL INFILE 'calendar.txt' INTO TABLE calendar FIELDS TERMINATED BY ',' IGNORE 1 LINES; LOAD DATA LOCAL INFILE 'calendar_dates.txt' INTO TABLE calendar_dates FIELDS TERMINATED BY ',' IGNORE 1 LINES; -LOAD DATA LOCAL INFILE 'routes.txt' INTO TABLE routes FIELDS TERMINATED BY ',' IGNORE 1 LINES; +LOAD DATA LOCAL INFILE 'fare_attributes.txt' INTO TABLE fare_attributes FIELDS TERMINATED BY ',' IGNORE 1 LINES; -LOAD DATA LOCAL INFILE 'stop_times.txt' INTO TABLE stop_times FIELDS TERMINATED BY ',' IGNORE 1 LINES; +LOAD DATA LOCAL INFILE 'fare_rules.txt' INTO TABLE fare_rules FIELDS TERMINATED BY ',' IGNORE 1 LINES; + +LOAD DATA LOCAL INFILE 'feed_info.txt' INTO TABLE feed_info FIELDS TERMINATED BY ',' IGNORE 1 LINES; + +LOAD DATA LOCAL INFILE 'shapes.txt' INTO TABLE shapes FIELDS TERMINATED BY ',' IGNORE 1 LINES; LOAD DATA LOCAL INFILE 'stops.txt' INTO TABLE stops FIELDS TERMINATED BY ',' IGNORE 1 LINES; -LOAD DATA LOCAL INFILE 'trips.txt' INTO TABLE trips FIELDS TERMINATED BY ',' IGNORE 1 LINES; \ No newline at end of file +LOAD DATA LOCAL INFILE 'transfers.txt' INTO TABLE transfers FIELDS TERMINATED BY ',' IGNORE 1 LINES; + +LOAD DATA LOCAL INFILE 'trips.txt' INTO TABLE trips FIELDS TERMINATED BY ',' IGNORE 1 LINES; + +LOAD DATA LOCAL INFILE 'frequencies.txt' INTO TABLE frequencies FIELDS TERMINATED BY ',' IGNORE 1 LINES; + +LOAD DATA LOCAL INFILE 'stop_times.txt' INTO TABLE stop_times FIELDS TERMINATED BY ',' IGNORE 1 LINES;