├── .github └── workflows │ └── test.yml ├── .gitignore ├── LICENSE ├── Makefile ├── README.md ├── data └── route_types.txt ├── sql ├── constraints.sql ├── drop_constraints.sql ├── drop_indices.sql ├── drop_notnull.sql ├── drop_triggers.sql ├── indices.sql ├── notnull.sql ├── schema.sql ├── shape_geoms_populate.sql ├── stop_time_update_distance.sql └── triggers.sql ├── src ├── load.sh └── load_feed_info.sh └── tests ├── constraints.sql ├── data ├── 281.zip └── 433.zip ├── schema.sql ├── table-agency.sql ├── table-attributions.sql ├── table-calendar.sql ├── table-calendar_dates.sql ├── table-fare_attributes.sql ├── table-fare_rules.sql ├── table-feed_info.sql ├── table-frequencies.sql ├── table-levels.sql ├── table-pathways.sql ├── table-routes.sql ├── table-shape_geoms.sql ├── table-shapes.sql ├── table-stop_times.sql ├── table-stops.sql ├── table-transfers.sql ├── table-translations.sql ├── table-trips.sql └── validity ├── calendar.sql ├── exists.sql ├── fares.sql ├── frequencies_trip_fkey.sql ├── routes.sql ├── stop_geometry.sql ├── stop_times.sql ├── transfers.sql └── trips_route_id_fkey.sql /.github/workflows/test.yml: -------------------------------------------------------------------------------- 1 | name: Test gtfs-sql-importer 2 | 3 | on: push 4 | 5 | jobs: 6 | test: 7 | runs-on: ubuntu-latest 8 | 9 | strategy: 10 | matrix: 11 | gtfs: 12 | - "281" 13 | - "433" 14 | postgis: 15 | - "10-2.5" 16 | - "12-3.1" 17 | - "14-3.1" 18 | 19 | services: 20 | database: 21 | image: postgis/postgis:${{ matrix.postgis }} 22 | ports: 23 | - 5432:5432 24 | env: 25 | POSTGRES_USER: postgres 26 | POSTGRES_PASSWORD: password 27 | options: >- 28 | --health-cmd pg_isready 29 | --health-interval 13s 30 | --health-timeout 5s 31 | --health-retries 5 32 | --health-start-period 1s 33 | env: 34 | PGUSER: postgres 35 | PGPASSWORD: password 36 | PGHOST: localhost 37 | PAGER: cat 38 | 39 | steps: 40 | - uses: actions/checkout@v2 41 | - name: Cache pgtap 42 | uses: actions/cache@v2 43 | with: 44 | key: pgtap-1.2.0 45 | path: | 46 | pgtap-1.2.0.zip 47 | pgtap-1.2.0 48 | - name: Download and install pgtap 49 | run: | 50 | wget --no-clobber https://api.pgxn.org/dist/pgtap/1.2.0/pgtap-1.2.0.zip 51 | unzip -u pgtap-1.2.0.zip 52 | make -C pgtap-1.2.0 sql/pgtap.sql 53 | PGOPTIONS=--search_path=tap,public psql -c "CREATE SCHEMA tap" -f pgtap-1.2.0/sql/pgtap.sql 54 | - run: make init drop_constraints drop_notnull 55 | - run: make load 56 | env: 57 | GTFS: tests/data/${{ matrix.gtfs }}.zip 58 | - run: make add_constraints add_notnull || echo "could not add constraints" 59 | name: Try to add constraints 60 | - run: make test 61 | - name: Run validity tests 62 | run: make check 63 | env: 64 | FEED_INDEX: 1 65 | - name: Run some basic queries 66 | run: | 67 | psql -c "SELECT feed_index, feed_file FROM gtfs.feed_info" 68 | psql -c "SELECT feed_index, trip_id, stop_id, stop_sequence, shape_dist_traveled FROM gtfs.stop_times LIMIT 10" 69 | psql -c "SELECT feed_index, shape_id, length FROM gtfs.shape_geoms LIMIT 10" 70 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | *~ 2 | gtfs 3 | 4 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright (c) 2017-2021 Neil Freeman 2 | Copyright (c) 2010 Colin Bick, Robert Damphousse 3 | 4 | Permission is hereby granted, free of charge, to any person obtaining a copy 5 | of this software and associated documentation files (the "Software"), to deal 6 | in the Software without restriction, including without limitation the rights 7 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 8 | copies of the Software, and to permit persons to whom the Software is 9 | furnished to do so, subject to the following conditions: 10 | 11 | The above copyright notice and this permission notice shall be included in 12 | all copies or substantial portions of the Software. 13 | 14 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 15 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 16 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 17 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 18 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 19 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN 20 | THE SOFTWARE. 21 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | SHELL := /bin/bash 2 | 3 | TABLES = stop_times trips routes \ 4 | calendar_dates calendar \ 5 | shapes stops \ 6 | transfers frequencies \ 7 | attributions translations pathways levels \ 8 | fare_attributes fare_rules agency feed_info 9 | 10 | SCHEMA = gtfs 11 | 12 | SRID = 4326 13 | 14 | psql = $(strip psql -v schema=$(SCHEMA)) 15 | 16 | .PHONY: all load vacuum init clean \ 17 | test check truncate \ 18 | drop_constraints add_constraints \ 19 | drop_indices add_indices \ 20 | add_triggers drop_triggers \ 21 | drop_notnull add_notnull \ 22 | $(addprefix load-,$(TABLES)) 23 | 24 | all: 25 | 26 | add_constraints add_indices add_triggers add_notnull: add_%: sql/%.sql 27 | $(psql) -f $< 28 | 29 | drop_indices drop_constraints drop_triggers drop_notnull: drop_%: sql/drop_%.sql 30 | $(psql) -f $< 31 | 32 | load: $(addprefix load-,$(TABLES)) 33 | $(psql) -v schema=$(SCHEMA) -v feed_file=$(GTFS) --set srid=$(SRID) -f sql/shape_geoms_populate.sql 34 | $(psql) -v schema=$(SCHEMA) -v feed_file=$(GTFS) --set srid=$(SRID) -f sql/stop_time_update_distance.sql 35 | @$(psql) -t -A -c "SELECT format('* loaded %s with feed index = %s', feed_file, feed_index) FROM $(SCHEMA).feed_info WHERE feed_file = '$(GTFS)'" 36 | 37 | $(filter-out load-feed_info,$(addprefix load-,$(TABLES))): load-%: load-feed_info | $(GTFS) 38 | $(SHELL) src/load.sh $| $(SCHEMA) $* 39 | 40 | load-feed_info: | $(GTFS) ## Insert row into feed_index, if necessary 41 | $(SHELL) ./src/load_feed_info.sh $| $(SCHEMA) 42 | 43 | vacuum: ; $(psql) -c "VACUUM ANALYZE" 44 | 45 | clean: ## Delete a feed from the DB. Relies on foreign keys for feed_index in each table 46 | ifdef FEED_INDEX 47 | $(psql) -c "DELETE FROM $(SCHEMA).feed_info WHERE feed_index = $(FEED_INDEX)" 48 | else 49 | $(error "make clean" requires FEED_INDEX) 50 | endif 51 | 52 | ifdef FEED_INDEX 53 | check: ; prove -v --exec 'psql -qAt -v schema=$(SCHEMA) -v feed_index=$(FEED_INDEX) -f' $(wildcard tests/validity/*.sql) 54 | endif 55 | 56 | test: ; prove -f --exec 'psql -qAt -v schema=$(SCHEMA) -f' $(wildcard tests/*.sql) 57 | 58 | truncate: 59 | for t in $(TABLES); do \ 60 | echo "TRUNCATE TABLE $(SCHEMA).$$t RESTART IDENTITY CASCADE;"; done \ 61 | | $(psql) -1 62 | 63 | init: sql/schema.sql 64 | $(psql) -v ON_ERROR_STOP=on -f $< 65 | $(psql) -v ON_ERROR_STOP=on -c "\copy $(SCHEMA).route_types FROM 'data/route_types.txt'" 66 | $(psql) -v ON_ERROR_STOP=on -f sql/indices.sql 67 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # About 2 | 3 | Import GTFS data into a PostgreSQL database. Includes all the constraints in the GTFS spec with some basic tools for dealing with improper data 4 | 5 | ## Requirements 6 | 7 | * Postgresql database (10+) with a PostGIS (2.2+) extension 8 | 9 | ## Links 10 | 11 | * [GTFS (General Transit Feed Specification)](https://gtfs.org/reference/static) 12 | * [Transitfeeds](http://transitfeeds.com) (index and archive of GTFS data sets) 13 | * [Transit.land](http://transit.land) A community-edited service with an achive of GTFS. 14 | 15 | ## Initial import 16 | 17 | This importer uses a Makefile to organize a series of SQL commands. The file `src/load.sh` is a shell script that does the heavy lifting of loading the contents of a GTFS zip file into a PostgreSQL database. 18 | 19 | Before importing data, set up database and make sure to provide relevant variables: 20 | ``` 21 | export PGDATABASE=mydbname 22 | export PGUSER=mydbuser 23 | export PGHOST=mydbhost 24 | export PGPORT=mydbport 25 | make init 26 | ``` 27 | This will create the a new schema with the necessary tables, as well as useful indices and foreign keys. 28 | 29 | ### Schema 30 | 31 | By default, your GTFS data will be loaded into a schema named `gtfs`. You can always rename it when you're done. Setting the `SCHEMA` variable when running make tasks will also address a different schema 32 | 33 | ## Connecting to the database 34 | 35 | Use the standard [Postgres environment variables](https://www.postgresql.org/docs/current/static/libpq-envars.html) to specify your connection parameters. For example: 36 | ```` 37 | export PGDATABASE=mydbname PGHOST=example.com PGUSER=username 38 | make load GTFS=gtfs.zip 39 | ```` 40 | 41 | ## Importing 42 | 43 | To import the GTFS dataset in file named `gtfs.zip`. Note that we first drop foreign key and not null constraints. This is necessary because the tables will be loaded in parallel (`-j` option) in arbitrary order: 44 | ```` 45 | make drop_constraints 46 | make -j load GTFS=gtfs.zip 47 | make add_constraints 48 | ```` 49 | 50 | ### Feed indexes 51 | 52 | GTFS data is regularly updated, and it's reasonable to want to include multiple iterations in the same database. This tool includes a `feed_index` column in each table. This index is part of the primary key of each table. 53 | 54 | ### Extra columns 55 | 56 | The loading script checks for extra columns in a GTFS table and adds them to database as `text` columns. You may wish to alter or remove these columns. 57 | 58 | ## Big datasets 59 | 60 | For large feeds, you may find that loading is faster without indices. Don't forget to add them back, or your queries will be very slow: 61 | ```bash 62 | make drop_indices drop_constraints 63 | make load GTFS=gtfs.zip 64 | make add_indices add_constraints 65 | ``` 66 | 67 | ## Troubleshooting common errors in GTFS data 68 | 69 | Most GTFS data has errors in it, so you may encounter an error when trying to add constraints back. Common errors include missing `service_id`s. 70 | 71 | The `check` task will run the scripts in `tests/validity`, which perform several queries looking for rows that violate foreign key constraints and bad geometries in the `shapes` table. These tests require `prove`, a very common perl testing program and [pgTAP](https://pgtap.org), a Postgresql testing suite. Install it in a new `tap` schema with: 72 | ```bash 73 | wget https://api.pgxn.org/dist/pgtap/1.2.0/pgtap-1.2.0.zip 74 | unzip pgtap-1.2.0.zip 75 | make -C pgtap-1.2.0 sql/pgtap.sql 76 | PGOPTIONS=--search_path=tap,public psql -c "CREATE SCHEMA tap" -f pgtap-1.2.0/sql/pgtap.sql 77 | ``` 78 | Then run the check task, giving the index of the feed to check: 79 | ``` 80 | make check FEED_INDEX=1 81 | ``` 82 | 83 | The resulting report will tell you which tables have constraint violations, and what the errors are. You may wish to manually add missing values to your tables. It also checks if all tables are populated (some optional tables may not be). 84 | 85 | If you don't have `prove` available, try another [TAP consumer](http://testanything.org/consumers.html). Failing that, you can run the tests with: 86 | ```bash 87 | find tests -name '*.sql' -print -exec psql -Aqt -v schema=gtfs -f {} \; 88 | ``` 89 | 90 | ### Null data 91 | ``` 92 | ERROR: null value in column "example_id" violates not-null constraint 93 | ``` 94 | This might occur if an "id" column (e.g. `route_id`) is improperly empty. As a workaround, you can drop `NOT NULL` constraints from the database and reload the data: 95 | ```bash 96 | make drop_notnull 97 | make load GTFS=example.zip 98 | ``` 99 | Then edit the database to add a non-empty value and recreate the not-null constraints (`make add_notnull`). 100 | 101 | # License 102 | Released under the MIT (X11) license. See LICENSE in this directory. 103 | -------------------------------------------------------------------------------- /data/route_types.txt: -------------------------------------------------------------------------------- 1 | 0 Street-level Rail (tram, streetcar, light rail) 2 | 1 Underground Rail 3 | 2 Rail (intercity or long-distance) 4 | 3 Bus (short- or long-distance) 5 | 4 Ferry 6 | 5 Cable tram 7 | 6 Aerial lift 8 | 7 Funicular 9 | 11 Trolleybus 10 | 12 Monorail 11 | 100 Railway Service 12 | 101 High Speed Rail Service 13 | 102 Long Distance Trains 14 | 103 Inter Regional Rail Service 15 | 104 Car Transport Rail Service 16 | 105 Sleeper Rail Service 17 | 106 Regional Rail Service 18 | 107 Tourist Railway Service 19 | 108 Rail Shuttle (Within Complex) 20 | 109 Suburban Railway 21 | 110 Replacement Rail Service 22 | 111 Special Rail Service 23 | 112 Lorry Transport Rail Service 24 | 113 All Rail Services 25 | 114 Cross-Country Rail Service 26 | 115 Vehicle Transport Rail Service 27 | 116 Rack and Pinion Railway 28 | 117 Additional Rail Service 29 | 200 Coach Service 30 | 201 International Coach Service 31 | 202 National Coach Service 32 | 203 Shuttle Coach Service 33 | 204 Regional Coach Service 34 | 205 Special Coach Service 35 | 206 Sightseeing Coach Service 36 | 207 Tourist Coach Service 37 | 208 Commuter Coach Service 38 | 209 All Coach Services 39 | 300 Suburban Railway Service 40 | 400 Urban Railway Service 41 | 401 Metro Service 42 | 402 Underground Service 43 | 403 Urban Railway Service 44 | 404 All Urban Railway Services 45 | 405 Monorail 46 | 500 Metro Service 47 | 600 Underground Service 48 | 700 Bus Service 49 | 701 Regional Bus Service 50 | 702 Express Bus Service 51 | 703 Stopping Bus Service 52 | 704 Local Bus Service 53 | 705 Night Bus Service 54 | 706 Post Bus Service 55 | 707 Special Needs Bus 56 | 708 Mobility Bus Service 57 | 709 Mobility Bus for Registered Disabled 58 | 710 Sightseeing Bus 59 | 711 Shuttle Bus 60 | 712 School Bus 61 | 713 School and Public Service Bus 62 | 714 Rail Replacement Bus Service 63 | 715 Demand and Response Bus Service 64 | 716 All Bus Services 65 | 800 Trolleybus Service 66 | 900 Tram Service 67 | 901 City Tram Service 68 | 902 Local Tram Service 69 | 903 Regional Tram Service 70 | 904 Sightseeing Tram Service 71 | 905 Shuttle Tram Service 72 | 906 All Tram Services 73 | 1000 Water Transport Service 74 | 1001 International Car Ferry Service 75 | 1002 National Car Ferry Service 76 | 1003 Regional Car Ferry Service 77 | 1004 Local Car Ferry Service 78 | 1005 International Passenger Ferry Service 79 | 1006 National Passenger Ferry Service 80 | 1007 Regional Passenger Ferry Service 81 | 1008 Local Passenger Ferry Service 82 | 1009 Post Boat Service 83 | 1010 Train Ferry Service 84 | 1011 Road-Link Ferry Service 85 | 1012 Airport-Link Ferry Service 86 | 1013 Car High-Speed Ferry Service 87 | 1014 Passenger High-Speed Ferry Service 88 | 1015 Sightseeing Boat Service 89 | 1016 School Boat 90 | 1017 Cable-Drawn Boat Service 91 | 1018 River Bus Service 92 | 1019 Scheduled Ferry Service 93 | 1020 Shuttle Ferry Service 94 | 1021 All Water Transport Services 95 | 1100 Air Service 96 | 1101 International Air Service 97 | 1102 Domestic Air Service 98 | 1103 Intercontinental Air Service 99 | 1104 Domestic Scheduled Air Service 100 | 1105 Shuttle Air Service 101 | 1106 Intercontinental Charter Air Service 102 | 1107 International Charter Air Service 103 | 1108 Round-Trip Charter Air Service 104 | 1109 Sightseeing Air Service 105 | 1110 Helicopter Air Service 106 | 1111 Domestic Charter Air Service 107 | 1112 Schengen-Area Air Service 108 | 1113 Airship Service 109 | 1114 All Air Services 110 | 1200 Ferry Service 111 | 1300 Telecabin Service 112 | 1301 Telecabin Service 113 | 1302 Cable Car Service 114 | 1303 Elevator Service 115 | 1304 Chair Lift Service 116 | 1305 Drag Lift Service 117 | 1306 Small Telecabin Service 118 | 1307 All Telecabin Services 119 | 1400 Funicular Service 120 | 1401 Funicular Service 121 | 1402 All Funicular Service 122 | 1500 Taxi Service 123 | 1501 Communal Taxi Service 124 | 1502 Water Taxi Service 125 | 1503 Rail Taxi Service 126 | 1504 Bike Taxi Service 127 | 1505 Licensed Taxi Service 128 | 1506 Private Hire Service Vehicle 129 | 1507 All Taxi Services 130 | 1600 Self Drive 131 | 1601 Hire Car 132 | 1602 Hire Van 133 | 1603 Hire Motorbike 134 | 1604 Hire Cycle 135 | 1700 Miscellaneous Service 136 | 1701 Cable Car 137 | 1702 Horse-drawn Carriage 138 | -------------------------------------------------------------------------------- /sql/constraints.sql: -------------------------------------------------------------------------------- 1 | SET search_path to :schema, public; 2 | 3 | ALTER TABLE stops 4 | ADD CONSTRAINT stops_level_id_fkey FOREIGN KEY (feed_index, level_id) REFERENCES levels (feed_index, level_id); 5 | 6 | ALTER TABLE routes 7 | ADD CONSTRAINT route_types_fkey FOREIGN KEY (route_type) REFERENCES route_types (route_type), 8 | ADD CONSTRAINT routes_agency_id_fkey FOREIGN KEY (feed_index, agency_id) REFERENCES agency (feed_index, agency_id); 9 | 10 | ALTER TABLE calendar_dates 11 | ADD CONSTRAINT calendar_dates_service_id_fkey FOREIGN KEY (feed_index, service_id) REFERENCES calendar (feed_index, service_id); 12 | 13 | ALTER TABLE fare_attributes 14 | ADD CONSTRAINT fare_attributes_fkey FOREIGN KEY (feed_index, agency_id) REFERENCES agency (feed_index, agency_id); 15 | 16 | ALTER TABLE fare_rules 17 | ADD CONSTRAINT fare_rules_service_fkey FOREIGN KEY (feed_index, service_id) REFERENCES calendar (feed_index, service_id), 18 | ADD CONSTRAINT fare_rules_fare_id_fkey FOREIGN KEY (feed_index, fare_id) REFERENCES fare_attributes (feed_index, fare_id), 19 | ADD CONSTRAINT fare_rules_route_id_fkey FOREIGN KEY (feed_index, route_id) REFERENCES routes (feed_index, route_id); 20 | 21 | ALTER TABLE trips 22 | ADD CONSTRAINT trips_route_id_fkey FOREIGN KEY (feed_index, route_id) REFERENCES routes (feed_index, route_id), 23 | ADD CONSTRAINT trips_calendar_fkey FOREIGN KEY (feed_index, service_id) REFERENCES calendar (feed_index, service_id); 24 | 25 | ALTER TABLE stop_times 26 | ADD CONSTRAINT stop_times_trips_fkey FOREIGN KEY (feed_index, trip_id) REFERENCES trips (feed_index, trip_id), 27 | ADD CONSTRAINT stop_times_stops_fkey FOREIGN KEY (feed_index, stop_id) REFERENCES stops (feed_index, stop_id); 28 | 29 | ALTER TABLE frequencies 30 | ADD CONSTRAINT frequencies_trip_fkey FOREIGN KEY (feed_index, trip_id) REFERENCES trips (feed_index, trip_id); 31 | 32 | ALTER TABLE transfers 33 | ADD CONSTRAINT transfers_from_stop_fkey FOREIGN KEY (feed_index, from_stop_id) REFERENCES stops (feed_index, stop_id), 34 | ADD CONSTRAINT transfers_to_stop_fkey FOREIGN KEY (feed_index, to_stop_id) REFERENCES stops (feed_index, stop_id), 35 | ADD CONSTRAINT transfers_from_route_fkey FOREIGN KEY (feed_index, from_route_id) REFERENCES routes (feed_index, route_id), 36 | ADD CONSTRAINT transfers_to_route_fkey FOREIGN KEY (feed_index, to_route_id) REFERENCES routes (feed_index, route_id), 37 | ADD CONSTRAINT transfers_service_fkey FOREIGN KEY (feed_index, service_id) REFERENCES calendar (feed_index, service_id); 38 | 39 | ALTER TABLE attributions 40 | ADD CONSTRAINT attributions_trip_id_fkey FOREIGN KEY (feed_index, trip_id) REFERENCES trips (feed_index, trip_id), 41 | ADD CONSTRAINT attributions_route_id_fkey FOREIGN KEY (feed_index, route_id) REFERENCES routes (feed_index, route_id); 42 | -------------------------------------------------------------------------------- /sql/drop_constraints.sql: -------------------------------------------------------------------------------- 1 | SET search_path to :schema, public; 2 | 3 | ALTER TABLE stops 4 | DROP CONSTRAINT stops_level_id_fkey CASCADE; 5 | 6 | ALTER TABLE :schema.routes 7 | DROP CONSTRAINT routes_agency_id_fkey CASCADE, 8 | DROP CONSTRAINT route_types_fkey CASCADE; 9 | 10 | ALTER TABLE :schema.fare_attributes 11 | DROP CONSTRAINT fare_attributes_fkey CASCADE; 12 | 13 | ALTER TABLE :schema.calendar_dates 14 | DROP CONSTRAINT calendar_dates_service_id_fkey CASCADE; 15 | 16 | ALTER TABLE :schema.fare_rules 17 | DROP CONSTRAINT fare_rules_service_fkey CASCADE, 18 | DROP CONSTRAINT fare_rules_route_id_fkey CASCADE, 19 | DROP CONSTRAINT fare_rules_fare_id_fkey CASCADE; 20 | 21 | ALTER TABLE :schema.trips 22 | DROP CONSTRAINT trips_route_id_fkey CASCADE, 23 | DROP CONSTRAINT trips_calendar_fkey CASCADE; 24 | 25 | ALTER TABLE :schema.stop_times 26 | DROP CONSTRAINT stop_times_trips_fkey CASCADE, 27 | DROP CONSTRAINT stop_times_stops_fkey CASCADE; 28 | 29 | ALTER TABLE :schema.frequencies 30 | DROP CONSTRAINT frequencies_trip_fkey CASCADE; 31 | 32 | ALTER TABLE :schema.transfers 33 | DROP CONSTRAINT transfers_from_stop_fkey CASCADE, 34 | DROP CONSTRAINT transfers_to_stop_fkey CASCADE, 35 | DROP CONSTRAINT transfers_from_route_fkey CASCADE, 36 | DROP CONSTRAINT transfers_to_route_fkey CASCADE, 37 | DROP CONSTRAINT transfers_service_fkey CASCADE; 38 | 39 | ALTER TABLE attributions 40 | DROP CONSTRAINT attributions_trip_id_fkey CASCADE, 41 | DROP CONSTRAINT attributions_route_id_fkey CASCADE; 42 | -------------------------------------------------------------------------------- /sql/drop_indices.sql: -------------------------------------------------------------------------------- 1 | SET search_path to :schema, public; 2 | 3 | DROP INDEX stops_geom_idx; 4 | 5 | DROP INDEX calendar_dates_dateidx; 6 | 7 | DROP INDEX shapes_shape_key; 8 | 9 | DROP INDEX stop_times_key; 10 | DROP INDEX arr_time_index; 11 | DROP INDEX dep_time_index; 12 | 13 | DROP INDEX shape_geoms_geom_idx; 14 | -------------------------------------------------------------------------------- /sql/drop_notnull.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO :schema; 2 | 3 | ALTER TABLE agency 4 | ALTER COLUMN agency_name DROP NOT NULL, 5 | ALTER COLUMN agency_timezone DROP NOT NULL, 6 | ALTER COLUMN agency_url DROP NOT NULL; 7 | 8 | ALTER TABLE attributions 9 | ALTER COLUMN organization_name DROP NOT NULL; 10 | 11 | ALTER TABLE calendar 12 | ALTER COLUMN end_date DROP NOT NULL, 13 | ALTER COLUMN monday DROP NOT NULL, 14 | ALTER COLUMN tuesday DROP NOT NULL, 15 | ALTER COLUMN wednesday DROP NOT NULL, 16 | ALTER COLUMN thursday DROP NOT NULL, 17 | ALTER COLUMN friday DROP NOT NULL, 18 | ALTER COLUMN saturday DROP NOT NULL, 19 | ALTER COLUMN sunday DROP NOT NULL, 20 | ALTER COLUMN start_date DROP NOT NULL; 21 | 22 | ALTER TABLE fare_attributes 23 | ALTER COLUMN currency_type DROP NOT NULL, 24 | ALTER COLUMN transfers DROP NOT NULL, 25 | ALTER COLUMN payment_method DROP NOT NULL, 26 | ALTER COLUMN price DROP NOT NULL; 27 | 28 | ALTER TABLE feed_info 29 | ALTER COLUMN feed_publisher_name DROP NOT NULL, 30 | ALTER COLUMN feed_publisher_url DROP NOT NULL, 31 | ALTER COLUMN feed_lang DROP NOT NULL; 32 | 33 | ALTER TABLE frequencies 34 | ALTER COLUMN end_time DROP NOT NULL, 35 | ALTER COLUMN headway_secs DROP NOT NULL; 36 | 37 | ALTER TABLE levels 38 | ALTER COLUMN level_index DROP NOT NULL; 39 | 40 | ALTER TABLE pathways 41 | ALTER COLUMN pathway_mode DROP NOT NULL, 42 | ALTER COLUMN from_stop_id DROP NOT NULL, 43 | ALTER COLUMN to_stop_id DROP NOT NULL, 44 | ALTER COLUMN is_bidirectional DROP NOT NULL; 45 | 46 | ALTER TABLE routes 47 | ALTER COLUMN route_type DROP NOT NULL; 48 | 49 | ALTER TABLE shape_geoms 50 | ALTER COLUMN length DROP NOT NULL, 51 | ALTER COLUMN the_geom DROP NOT NULL; 52 | 53 | ALTER TABLE shapes 54 | ALTER COLUMN shape_pt_lon DROP NOT NULL, 55 | ALTER COLUMN shape_pt_lat DROP NOT NULL; 56 | 57 | ALTER TABLE transfers 58 | ALTER COLUMN transfer_type DROP NOT NULL; 59 | 60 | ALTER TABLE translations 61 | ALTER COLUMN field_name DROP NOT NULL, 62 | ALTER COLUMN translation DROP NOT NULL; 63 | 64 | ALTER TABLE trips 65 | ALTER COLUMN route_id DROP NOT NULL, 66 | ALTER COLUMN service_id DROP NOT NULL; 67 | -------------------------------------------------------------------------------- /sql/drop_triggers.sql: -------------------------------------------------------------------------------- 1 | DROP TRIGGER IF EXISTS :schema.stop_geom_trigger ON :schema.stops; 2 | -------------------------------------------------------------------------------- /sql/indices.sql: -------------------------------------------------------------------------------- 1 | SET search_path to :schema, public; 2 | 3 | CREATE INDEX IF NOT EXISTS calendar_service_id 4 | ON :schema.calendar (feed_index, service_id); 5 | 6 | CREATE INDEX IF NOT EXISTS stop_geom_idx 7 | ON stops USING GIST (the_geom); 8 | 9 | CREATE INDEX IF NOT EXISTS calendar_dates_dateidx 10 | ON :schema.calendar_dates (date); 11 | 12 | CREATE INDEX IF NOT EXISTS shapes_shape_key 13 | ON :schema.shapes (shape_id); 14 | 15 | CREATE INDEX IF NOT EXISTS trips_service_id 16 | ON :schema.trips (feed_index, service_id); 17 | 18 | CREATE INDEX IF NOT EXISTS stop_times_key 19 | ON :schema.stop_times (feed_index, trip_id, stop_id); 20 | 21 | CREATE INDEX IF NOT EXISTS arr_time_index 22 | ON :schema.stop_times (arrival_time_seconds); 23 | 24 | CREATE INDEX IF NOT EXISTS dep_time_index 25 | ON :schema.stop_times (departure_time_seconds); 26 | 27 | CREATE INDEX IF NOT EXISTS shape_geoms_geom_idx 28 | ON shape_geoms USING GIST (the_geom); 29 | -------------------------------------------------------------------------------- /sql/notnull.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO :schema; 2 | 3 | ALTER TABLE agency 4 | ALTER COLUMN agency_name SET NOT NULL, 5 | ALTER COLUMN agency_timezone SET NOT NULL, 6 | ALTER COLUMN agency_url SET NOT NULL; 7 | 8 | ALTER TABLE attributions 9 | ALTER COLUMN organization_name SET NOT NULL; 10 | 11 | ALTER TABLE calendar 12 | ALTER COLUMN end_date SET NOT NULL, 13 | ALTER COLUMN service_id SET NOT NULL, 14 | ALTER COLUMN monday SET NOT NULL, 15 | ALTER COLUMN tuesday SET NOT NULL, 16 | ALTER COLUMN wednesday SET NOT NULL, 17 | ALTER COLUMN thursday SET NOT NULL, 18 | ALTER COLUMN friday SET NOT NULL, 19 | ALTER COLUMN saturday SET NOT NULL, 20 | ALTER COLUMN sunday SET NOT NULL, 21 | ALTER COLUMN start_date SET NOT NULL; 22 | 23 | ALTER TABLE fare_attributes 24 | ALTER COLUMN currency_type SET NOT NULL, 25 | ALTER COLUMN transfers SET NOT NULL, 26 | ALTER COLUMN payment_method SET NOT NULL, 27 | ALTER COLUMN price SET NOT NULL, 28 | ALTER COLUMN fare_id SET NOT NULL; 29 | 30 | ALTER TABLE feed_info 31 | ALTER COLUMN feed_publisher_name SET NOT NULL, 32 | ALTER COLUMN feed_publisher_url SET NOT NULL, 33 | ALTER COLUMN feed_lang SET NOT NULL; 34 | 35 | ALTER TABLE frequencies 36 | ALTER COLUMN trip_id SET NOT NULL, 37 | ALTER COLUMN start_time SET NOT NULL, 38 | ALTER COLUMN end_time SET NOT NULL, 39 | ALTER COLUMN headway_secs SET NOT NULL; 40 | 41 | ALTER TABLE levels 42 | ALTER COLUMN level_index SET NOT NULL, 43 | ALTER COLUMN level_id SET NOT NULL; 44 | 45 | ALTER TABLE pathways 46 | ALTER COLUMN pathway_mode SET NOT NULL, 47 | ALTER COLUMN pathway_id SET NOT NULL, 48 | ALTER COLUMN from_stop_id SET NOT NULL, 49 | ALTER COLUMN to_stop_id SET NOT NULL, 50 | ALTER COLUMN is_bidirectional SET NOT NULL; 51 | 52 | ALTER TABLE routes 53 | ALTER COLUMN route_type SET NOT NULL; 54 | 55 | ALTER TABLE shape_geoms 56 | ALTER COLUMN length SET NOT NULL, 57 | ALTER COLUMN the_geom SET NOT NULL; 58 | 59 | ALTER TABLE shapes 60 | ALTER COLUMN shape_pt_lon SET NOT NULL, 61 | ALTER COLUMN shape_pt_lat SET NOT NULL; 62 | 63 | ALTER TABLE transfers 64 | ALTER COLUMN transfer_type SET NOT NULL; 65 | 66 | ALTER TABLE translations 67 | ALTER COLUMN field_name SET NOT NULL, 68 | ALTER COLUMN translation SET NOT NULL, 69 | ALTER COLUMN field_value SET NOT NULL;; 70 | 71 | ALTER TABLE trips 72 | ALTER COLUMN route_id SET NOT NULL, 73 | ALTER COLUMN service_id SET NOT NULL; 74 | -------------------------------------------------------------------------------- /sql/schema.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | CREATE SCHEMA IF NOT EXISTS :schema; 3 | SET search_path to :schema, public; 4 | 5 | CREATE TABLE feed_info ( 6 | feed_index serial PRIMARY KEY, -- tracks uploads, avoids key collisions 7 | feed_publisher_name text not null, 8 | feed_publisher_url text not null, 9 | feed_lang text not null, 10 | default_lang text default null, 11 | feed_start_date date default null, 12 | feed_end_date date default null, 13 | feed_version text default null, 14 | -- unofficial features 15 | feed_download_date date, 16 | feed_file text, 17 | feed_timezone text default null, 18 | feed_id text default null, 19 | feed_contact_url text default null, 20 | feed_contact_email text default null, 21 | CONSTRAINT feed_file_uniq UNIQUE (feed_file) 22 | ); 23 | 24 | CREATE TABLE agency ( 25 | feed_index integer NOT NULL REFERENCES feed_info (feed_index) ON DELETE CASCADE, 26 | agency_id text default '', 27 | agency_name text not null, 28 | agency_url text not null, 29 | agency_timezone text not null, 30 | -- optional 31 | agency_lang text, 32 | agency_phone text, 33 | agency_fare_url text, 34 | agency_email text, 35 | bikes_policy_url text, 36 | CONSTRAINT agency_pkey PRIMARY KEY (feed_index, agency_id) 37 | ); 38 | 39 | --related to calendar_dates(exception_type) 40 | CREATE TABLE exception_types ( 41 | exception_type int PRIMARY KEY, 42 | description text 43 | ); 44 | 45 | --related to stops(wheelchair_accessible) 46 | CREATE TABLE wheelchair_accessible ( 47 | wheelchair_accessible int PRIMARY KEY, 48 | description text 49 | ); 50 | 51 | --related to stops(wheelchair_boarding) 52 | CREATE TABLE wheelchair_boardings ( 53 | wheelchair_boarding int PRIMARY KEY, 54 | description text 55 | ); 56 | 57 | CREATE TABLE pickup_dropoff_types ( 58 | type_id int PRIMARY KEY, 59 | description text 60 | ); 61 | 62 | CREATE TABLE transfer_types ( 63 | transfer_type int PRIMARY KEY, 64 | description text 65 | ); 66 | 67 | --related to stops(location_type) 68 | CREATE TABLE location_types ( 69 | location_type int PRIMARY KEY, 70 | description text 71 | ); 72 | 73 | -- related to stop_times(timepoint) 74 | CREATE TABLE timepoints ( 75 | timepoint int PRIMARY KEY, 76 | description text 77 | ); 78 | 79 | CREATE TABLE continuous_pickup ( 80 | continuous_pickup int PRIMARY KEY, 81 | description text 82 | ); 83 | 84 | CREATE TABLE continuous_drop_off ( 85 | continuous_drop_off int PRIMARY KEY, 86 | description text 87 | ); 88 | 89 | CREATE TABLE calendar ( 90 | feed_index integer NOT NULL REFERENCES feed_info (feed_index) ON DELETE CASCADE, 91 | service_id text, 92 | monday int not null, 93 | tuesday int not null, 94 | wednesday int not null, 95 | thursday int not null, 96 | friday int not null, 97 | saturday int not null, 98 | sunday int not null, 99 | start_date date not null, 100 | end_date date not null, 101 | CONSTRAINT calendar_pkey PRIMARY KEY (feed_index, service_id) 102 | ); 103 | 104 | CREATE OR REPLACE FUNCTION feed_date_update() 105 | RETURNS TRIGGER AS $$ 106 | BEGIN 107 | UPDATE feed_info fi SET 108 | feed_start_date = CASE WHEN feed_start_date IS NULL THEN start_date ELSE feed_start_date END, 109 | feed_end_date = CASE WHEN feed_end_date IS NULL THEN end_date ELSE feed_end_date END 110 | FROM ( 111 | SELECT feed_index, MIN(start_date) start_date, MAX(end_date) end_date 112 | FROM inserted 113 | GROUP BY 1 114 | ) a 115 | WHERE fi.feed_index = a.feed_index 116 | AND (fi.feed_start_date IS NULL OR fi.feed_end_date IS NULL); 117 | RETURN NULL; 118 | END; 119 | $$ LANGUAGE plpgsql 120 | SET search_path = :schema, public; 121 | 122 | COMMENT ON FUNCTION feed_date_update IS 123 | 'Update start/end dates in feed_info after inserting info calendar_dates. Do not overwrite existing dates'; 124 | 125 | CREATE TRIGGER calendar_trigger AFTER INSERT ON calendar 126 | REFERENCING NEW TABLE AS inserted 127 | FOR EACH STATEMENT EXECUTE PROCEDURE feed_date_update(); 128 | 129 | CREATE TABLE levels ( 130 | feed_index integer NOT NULL REFERENCES feed_info (feed_index) ON DELETE CASCADE, 131 | level_id text not null, 132 | level_index double precision not null, 133 | level_name text, 134 | PRIMARY KEY (feed_index, level_id) 135 | ); 136 | 137 | CREATE TABLE stops ( 138 | feed_index int NOT NULL REFERENCES feed_info (feed_index) ON DELETE CASCADE, 139 | stop_id text not null, 140 | stop_code text, 141 | stop_name text, 142 | stop_desc text, 143 | stop_lat double precision, 144 | stop_lon double precision, 145 | zone_id text, 146 | stop_url text, 147 | stop_street text, 148 | stop_city text, 149 | stop_region text, 150 | stop_postcode text, 151 | stop_country text, 152 | stop_timezone text, 153 | direction text, 154 | position text, 155 | parent_station text, 156 | wheelchair_boarding integer REFERENCES wheelchair_boardings (wheelchair_boarding), 157 | wheelchair_accessible integer REFERENCES wheelchair_accessible (wheelchair_accessible), 158 | -- optional 159 | location_type integer REFERENCES location_types (location_type), 160 | vehicle_type int, 161 | level_id text, 162 | platform_code text, 163 | the_geom geometry(point, 4326), 164 | CONSTRAINT stops_level_id_fkey FOREIGN KEY (feed_index, level_id) 165 | REFERENCES levels (feed_index, level_id), 166 | CONSTRAINT stops_pkey PRIMARY KEY (feed_index, stop_id) 167 | ); 168 | 169 | -- trigger the_geom update with lat or lon inserted 170 | CREATE OR REPLACE FUNCTION stop_geom_update() RETURNS TRIGGER AS $stop_geom$ 171 | BEGIN 172 | NEW.the_geom = ST_SetSRID(ST_MakePoint(NEW.stop_lon, NEW.stop_lat), 4326); 173 | RETURN NEW; 174 | END; 175 | $stop_geom$ LANGUAGE plpgsql; 176 | 177 | CREATE TRIGGER stop_geom_trigger BEFORE INSERT OR UPDATE ON stops 178 | FOR EACH ROW EXECUTE PROCEDURE stop_geom_update(); 179 | 180 | CREATE TABLE route_types ( 181 | route_type int PRIMARY KEY, 182 | description text 183 | ); 184 | 185 | CREATE TABLE routes ( 186 | feed_index int NOT NULL REFERENCES feed_info (feed_index) ON DELETE CASCADE, 187 | route_id text not null, 188 | agency_id text, 189 | route_short_name text default '', 190 | route_long_name text default '', 191 | route_desc text, 192 | route_type int not null, 193 | route_url text, 194 | route_color text, 195 | route_text_color text, 196 | route_sort_order integer default null, 197 | continuous_pickup int default null REFERENCES continuous_pickup (continuous_pickup), 198 | continuous_drop_off int default null REFERENCES continuous_drop_off (continuous_drop_off), 199 | CONSTRAINT routes_agency_id_fkey FOREIGN KEY (feed_index, agency_id) 200 | REFERENCES agency (feed_index, agency_id), 201 | CONSTRAINT route_types_fkey FOREIGN KEY (route_type) 202 | REFERENCES route_types (route_type), 203 | CONSTRAINT routes_pkey PRIMARY KEY (feed_index, route_id) 204 | ); 205 | 206 | CREATE TABLE calendar_dates ( 207 | feed_index int NOT NULL REFERENCES feed_info (feed_index) ON DELETE CASCADE, 208 | service_id text not null, 209 | date date not null, 210 | exception_type int REFERENCES exception_types (exception_type), 211 | CONSTRAINT calendar_dates_service_id_fkey FOREIGN KEY (feed_index, service_id) 212 | REFERENCES calendar (feed_index, service_id), 213 | CONSTRAINT calendar_dates_pkey PRIMARY KEY (feed_index, service_id, date) 214 | ); 215 | 216 | CREATE TABLE payment_methods ( 217 | payment_method int PRIMARY KEY, 218 | description text 219 | ); 220 | 221 | CREATE TABLE fare_attributes ( 222 | feed_index int NOT NULL REFERENCES feed_info (feed_index), 223 | fare_id text not null, 224 | price double precision not null, 225 | currency_type text not null, 226 | payment_method int NOT NULL REFERENCES payment_methods, 227 | transfers int NOT NULL, 228 | transfer_duration int, 229 | -- unofficial features 230 | agency_id text, 231 | CONSTRAINT fare_attributes_fkey FOREIGN KEY (feed_index, agency_id) 232 | REFERENCES agency (feed_index, agency_id), 233 | CONSTRAINT fare_attributes_pkey PRIMARY KEY (feed_index, fare_id) 234 | ); 235 | 236 | CREATE TABLE fare_rules ( 237 | feed_index int NOT NULL REFERENCES feed_info (feed_index) ON DELETE CASCADE, 238 | fare_id text NOT NULL, 239 | route_id text, 240 | origin_id text, 241 | destination_id text, 242 | contains_id text, 243 | -- unofficial features 244 | service_id text, 245 | CONSTRAINT fare_rules_service_fkey FOREIGN KEY (feed_index, service_id) 246 | REFERENCES calendar (feed_index, service_id), 247 | CONSTRAINT fare_rules_fare_id_fkey FOREIGN KEY (feed_index, fare_id) 248 | REFERENCES fare_attributes (feed_index, fare_id), 249 | CONSTRAINT fare_rules_route_id_fkey FOREIGN KEY (feed_index, route_id) 250 | REFERENCES routes (feed_index, route_id), 251 | CONSTRAINT fare_rules_pkey 252 | PRIMARY KEY (feed_index, fare_id, route_id, origin_id, destination_id) 253 | ); 254 | 255 | CREATE TABLE shapes ( 256 | feed_index int NOT NULL REFERENCES feed_info (feed_index) ON DELETE CASCADE, 257 | shape_id text not null, 258 | shape_pt_lat double precision not null, 259 | shape_pt_lon double precision not null, 260 | shape_pt_sequence int not null, 261 | -- optional 262 | shape_dist_traveled double precision, 263 | CONSTRAINT shapes_pk PRIMARY KEY (feed_index, shape_id, shape_pt_sequence) 264 | ); 265 | 266 | -- Create new table to store the shape geometries 267 | CREATE TABLE shape_geoms ( 268 | feed_index int NOT NULL REFERENCES feed_info (feed_index) ON DELETE CASCADE, 269 | shape_id text not null, 270 | length numeric(12, 2) not null, 271 | the_geom geometry(LineString, 4326) not null, 272 | CONSTRAINT shape_geom_pkey PRIMARY KEY (feed_index, shape_id) 273 | ); 274 | 275 | CREATE TABLE trips ( 276 | feed_index int NOT NULL REFERENCES feed_info (feed_index) ON DELETE CASCADE, 277 | route_id text not null, 278 | service_id text not null, 279 | trip_id text not null, 280 | trip_headsign text, 281 | direction_id int, 282 | block_id text, 283 | shape_id text, 284 | trip_short_name text, 285 | wheelchair_accessible int REFERENCES wheelchair_accessible(wheelchair_accessible), 286 | -- unofficial features 287 | direction text, 288 | schd_trip_id text, 289 | trip_type text, 290 | exceptional int, 291 | bikes_allowed int, 292 | CONSTRAINT trips_route_id_fkey FOREIGN KEY (feed_index, route_id) 293 | REFERENCES routes (feed_index, route_id), 294 | CONSTRAINT trips_calendar_fkey FOREIGN KEY (feed_index, service_id) 295 | REFERENCES calendar (feed_index, service_id), 296 | CONSTRAINT trips_pkey PRIMARY KEY (feed_index, trip_id) 297 | ); 298 | 299 | CREATE TABLE stop_times ( 300 | feed_index int NOT NULL REFERENCES feed_info (feed_index) ON DELETE CASCADE, 301 | trip_id text not null, 302 | -- Check that casting to time interval works. 303 | -- Interval used rather than Time because: 304 | -- "For times occurring after midnight on the service day, 305 | -- enter the time as a value greater than 24:00:00" 306 | -- https://developers.google.com/transit/gtfs/reference#stop_timestxt 307 | -- conversion tool: https://github.com/Bus-Data-NYC/nyc-bus-stats/blob/master/sql/util.sql#L48 308 | arrival_time interval CHECK (arrival_time::interval = arrival_time::interval), 309 | departure_time interval CHECK (departure_time::interval = departure_time::interval), 310 | stop_id text, 311 | stop_sequence int not null, 312 | stop_headsign text, 313 | pickup_type int REFERENCES pickup_dropoff_types(type_id), 314 | drop_off_type int REFERENCES pickup_dropoff_types(type_id), 315 | continuous_pickup int default null REFERENCES continuous_pickup (continuous_pickup), 316 | continuous_drop_off int default null REFERENCES continuous_drop_off (continuous_drop_off), 317 | shape_dist_traveled numeric(10, 2), 318 | timepoint int REFERENCES timepoints (timepoint), 319 | 320 | -- unofficial features 321 | -- the following are not in the spec 322 | arrival_time_seconds int default null, 323 | departure_time_seconds int default null, 324 | CONSTRAINT stop_times_trips_fkey FOREIGN KEY (feed_index, trip_id) 325 | REFERENCES trips (feed_index, trip_id), 326 | CONSTRAINT stop_times_stops_fkey FOREIGN KEY (feed_index, stop_id) 327 | REFERENCES stops (feed_index, stop_id), 328 | CONSTRAINT stop_times_pkey PRIMARY KEY (feed_index, trip_id, stop_sequence) 329 | ); 330 | 331 | -- "Safely" locate a point on a (possibly complicated) line by using minimum and maximum distances. 332 | -- Unlike st_LineLocatePoint, this accepts and returns absolute distances, not fractions 333 | CREATE OR REPLACE FUNCTION safe_locate 334 | (route geometry, point geometry, start numeric, finish numeric, length numeric) 335 | RETURNS numeric AS $$ 336 | -- Multiply the fractional distance also the substring by the substring, 337 | -- then add the start distance 338 | SELECT LEAST(length, GREATEST(0, start) + ST_LineLocatePoint( 339 | ST_LineSubstring(route, GREATEST(0, start / length), LEAST(1, finish / length)), 340 | point 341 | )::numeric * ( 342 | -- The absolute distance between start and finish 343 | LEAST(length, finish) - GREATEST(0, start) 344 | )); 345 | $$ LANGUAGE SQL; 346 | 347 | CREATE TABLE frequencies ( 348 | feed_index int NOT NULL REFERENCES feed_info (feed_index) ON DELETE CASCADE, 349 | trip_id text, 350 | start_time text not null CHECK (start_time::interval = start_time::interval), 351 | end_time text not null CHECK (end_time::interval = end_time::interval), 352 | headway_secs int not null, 353 | exact_times int, 354 | start_time_seconds int, 355 | end_time_seconds int, 356 | CONSTRAINT frequencies_trip_fkey FOREIGN KEY (feed_index, trip_id) 357 | REFERENCES trips (feed_index, trip_id), 358 | CONSTRAINT frequencies_pkey PRIMARY KEY (feed_index, trip_id, start_time) 359 | ); 360 | 361 | CREATE TABLE transfers ( 362 | feed_index int NOT NULL REFERENCES feed_info (feed_index) ON DELETE CASCADE, 363 | from_stop_id text not null, 364 | to_stop_id text not null, 365 | transfer_type int not null REFERENCES transfer_types(transfer_type), 366 | min_transfer_time int, 367 | -- Unofficial fields 368 | from_route_id text default null, 369 | to_route_id text default null, 370 | service_id text default null, 371 | CONSTRAINT transfers_from_stop_fkey FOREIGN KEY (feed_index, from_stop_id) 372 | REFERENCES stops (feed_index, stop_id), 373 | CONSTRAINT transfers_to_stop_fkey FOREIGN KEY (feed_index, to_stop_id) 374 | REFERENCES stops (feed_index, stop_id), 375 | CONSTRAINT transfers_from_route_fkey FOREIGN KEY (feed_index, from_route_id) 376 | REFERENCES routes (feed_index, route_id), 377 | CONSTRAINT transfers_to_route_fkey FOREIGN KEY (feed_index, to_route_id) 378 | REFERENCES routes (feed_index, route_id), 379 | CONSTRAINT transfers_service_fkey FOREIGN KEY (feed_index, service_id) 380 | REFERENCES calendar (feed_index, service_id), 381 | CONSTRAINT transfers_pkey PRIMARY KEY (feed_index, from_stop_id, to_stop_id) 382 | ); 383 | 384 | CREATE TABLE pathway_modes ( 385 | pathway_mode integer PRIMARY KEY, 386 | description text 387 | ); 388 | 389 | CREATE TABLE pathways ( 390 | feed_index integer NOT NULL REFERENCES feed_info (feed_index) ON DELETE CASCADE, 391 | pathway_id text not null, 392 | from_stop_id text not null, 393 | to_stop_id text not null, 394 | pathway_mode integer not null REFERENCES pathway_modes (pathway_mode), 395 | is_bidirectional integer not null, 396 | length double precision, 397 | traversal_time integer, 398 | stair_count integer, 399 | max_slope numeric, 400 | min_width double precision, 401 | signposted_as text, 402 | reversed_signposted_as text, 403 | PRIMARY KEY (feed_index, pathway_id) 404 | ); 405 | 406 | CREATE TABLE translations ( 407 | feed_index integer NOT NULL REFERENCES feed_info (feed_index) ON DELETE CASCADE, 408 | table_name text not null, 409 | field_name text not null, 410 | language text not null, 411 | translation text not null, 412 | record_id text, 413 | record_sub_id text, 414 | field_value text, 415 | PRIMARY KEY (feed_index, table_name, field_value, language) 416 | ); 417 | 418 | CREATE TABLE attributions ( 419 | feed_index integer NOT NULL REFERENCES feed_info (feed_index) ON DELETE CASCADE, 420 | attribution_id text, 421 | agency_id text, 422 | route_id text, 423 | trip_id text, 424 | organization_name text not null, 425 | is_producer boolean, 426 | is_operator boolean, 427 | is_authority boolean, 428 | attribution_url text, 429 | attribution_email text, 430 | attribution_phone text, 431 | CONSTRAINT attributions_trip_id_fkey FOREIGN KEY (feed_index, trip_id) 432 | REFERENCES trips (feed_index, trip_id), 433 | CONSTRAINT attributions_route_id_fkey FOREIGN KEY (feed_index, route_id) 434 | REFERENCES routes (feed_index, route_id), 435 | PRIMARY KEY (feed_index, attribution_id) 436 | ); 437 | 438 | insert into exception_types (exception_type, description) values 439 | (1, 'service has been added'), 440 | (2, 'service has been removed'); 441 | 442 | insert into transfer_types (transfer_type, description) VALUES 443 | (0,'Preferred transfer point'), 444 | (1,'Designated transfer point'), 445 | (2,'Transfer possible with min_transfer_time window'), 446 | (3,'Transfers forbidden'); 447 | 448 | insert into location_types(location_type, description) values 449 | (0,'stop'), 450 | (1,'station'), 451 | (2,'station entrance'), 452 | (3,'generic node'), 453 | (4,'boarding area'); 454 | 455 | insert into wheelchair_boardings(wheelchair_boarding, description) values 456 | (0, 'No accessibility information available for the stop'), 457 | (1, 'At least some vehicles at this stop can be boarded by a rider in a wheelchair'), 458 | (2, 'Wheelchair boarding is not possible at this stop'); 459 | 460 | insert into wheelchair_accessible(wheelchair_accessible, description) values 461 | (0, 'No accessibility information available for this trip'), 462 | (1, 'The vehicle being used on this particular trip can accommodate at least one rider in a wheelchair'), 463 | (2, 'No riders in wheelchairs can be accommodated on this trip'); 464 | 465 | insert into pickup_dropoff_types (type_id, description) values 466 | (0,'Regularly Scheduled'), 467 | (1,'Not available'), 468 | (2,'Phone arrangement only'), 469 | (3,'Driver arrangement only'); 470 | 471 | insert into payment_methods (payment_method, description) values 472 | (0,'On Board'), 473 | (1,'Prepay'); 474 | 475 | insert into timepoints (timepoint, description) values 476 | (0, 'Times are considered approximate'), 477 | (1, 'Times are considered exact'); 478 | 479 | insert into continuous_pickup (continuous_pickup, description) values 480 | (0, 'Continuous stopping pickup'), 481 | (1, 'No continuous stopping pickup'), 482 | (2, 'Must phone agency to arrange continuous stopping pickup'), 483 | (3, 'Must coordinate with driver to arrange continuous stopping pickup'); 484 | 485 | insert into continuous_drop_off (continuous_drop_off, description) values 486 | (0, 'Continuous stopping drop-off'), 487 | (1, 'No continuous stopping drop-off'), 488 | (2, 'Must phone agency to arrange continuous stopping drop-off'), 489 | (3, 'Must coordinate with driver to arrange continuous stopping drop-off'); 490 | 491 | insert into pathway_modes (pathway_mode, description) values 492 | (1, 'walkway'), 493 | (2, 'stairs'), 494 | (3, 'moving sidewalk/travelator'), 495 | (4, 'escalator'), 496 | (5, 'elevator'), 497 | (6, 'fare gate (or payment gate)'), 498 | (7, 'exit gate'); 499 | 500 | COMMIT; 501 | -------------------------------------------------------------------------------- /sql/shape_geoms_populate.sql: -------------------------------------------------------------------------------- 1 | /** 2 | Insert geometries into shape_geoms by summarizing the shapes table 3 | Arguments 4 | --------- 5 | :schema: database schema, typically `gtfs` 6 | :feed_file: the feed zip file, should be a unique row in :schema.feed_info 7 | */ 8 | INSERT INTO :schema.shape_geoms (feed_index, shape_id, length, the_geom) 9 | SELECT feed_index, shape_id, ST_Length(the_geom::geography), the_geom 10 | FROM ( 11 | SELECT 12 | feed_index, 13 | shape_id, 14 | ST_SetSRID(ST_MakeLine(ST_MakePoint(shape_pt_lon, shape_pt_lat) ORDER BY shape_pt_sequence), 4326) AS the_geom 15 | FROM :schema.shapes s 16 | JOIN :schema.feed_info USING (feed_index) 17 | WHERE feed_file = :'feed_file' 18 | GROUP BY 1, 2 19 | ) a; 20 | -------------------------------------------------------------------------------- /sql/stop_time_update_distance.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Update the stop_times.shape_dist_traveled column where missing or out-of-order. 3 | Arguments 4 | --------- 5 | :schema: database schema, typically `gtfs` 6 | :feed_file: the feed zip file, should be a unique row in :schema.feed_info 7 | :srid: the spatial reference system to work in. Using a projected system will improve results. 8 | Use a system that employs meters 9 | */ 10 | UPDATE :schema.stop_times s 11 | SET shape_dist_traveled = :schema.safe_locate( 12 | ST_Transform(r.the_geom, :srid), 13 | ST_Transform(p.the_geom, :srid), 14 | lag, 15 | coalesce(lead, r.length), 16 | r.length::numeric 17 | ) 18 | FROM 19 | ( 20 | SELECT 21 | feed_index, 22 | trip_id, 23 | stop_id, 24 | coalesce(lag(shape_dist_traveled) over (trip), 0)::numeric AS lag, 25 | shape_dist_traveled AS dist, 26 | lead(shape_dist_traveled) over (trip)::numeric AS lead 27 | FROM :schema.stop_times 28 | JOIN :schema.feed_info USING (feed_index) 29 | WHERE feed_file = :'feed_file' 30 | WINDOW trip AS (PARTITION BY feed_index, trip_id ORDER BY stop_sequence) 31 | ) AS d 32 | LEFT JOIN :schema.stops AS p USING (feed_index, stop_id) 33 | LEFT JOIN :schema.trips AS t USING (feed_index, trip_id) 34 | LEFT JOIN :schema.shape_geoms AS r USING (feed_index, shape_id) 35 | WHERE 36 | (s.feed_index, s.trip_id, s.stop_id) = (d.feed_index, d.trip_id, d.stop_id) 37 | AND ( 38 | COALESCE(lead, length) > lag 39 | AND (dist > COALESCE(lead, length) OR dist < lag) 40 | ) 41 | OR s.shape_dist_traveled IS NULL; 42 | -------------------------------------------------------------------------------- /sql/triggers.sql: -------------------------------------------------------------------------------- 1 | CREATE TRIGGER stop_geom_trigger BEFORE INSERT OR UPDATE ON :schema.stops 2 | FOR EACH ROW EXECUTE PROCEDURE :schema.stop_geom_update(); 3 | -------------------------------------------------------------------------------- /src/load.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | set -e 3 | # This script takes three arguments: 4 | # - A zip file containing gtfs files 5 | # - schema namem, typically `gtfs` 6 | # - table name, which should refer to a file named table.txt in the zip archive 7 | ZIP=$1 8 | SCHEMA=${2} 9 | TABLE=${3} 10 | 11 | if [[ -z "$(unzip -Z -1 "$ZIP" "${TABLE}.txt")" ]]; then 12 | echo "Skipping ${SCHEMA}.${TABLE}" 1>&2 13 | exit 14 | fi 15 | 16 | # Die if this zip isn't yet registered in feed_info 17 | feed_index=$(psql -At -c "SELECT feed_index FROM ${SCHEMA}.feed_info WHERE feed_file = '${ZIP}'") 18 | if [[ -z "$feed_index" ]]; then 19 | echo "Unable to find '${ZIP}' in ${SCHEMA}.feed_info" 1>&2 20 | exit 1 21 | fi 22 | 23 | export PGOPTIONS="${PGOPTIONS} -c client_min_messages=warning" 24 | 25 | # Remove possible BOM from header 26 | hed=$(unzip -p "$ZIP" "${TABLE}.txt" | head -n 1 | awk '{ sub(/^\xef\xbb\xbf/,"") } { print }') 27 | 28 | # Add unknown custom columns as text fields 29 | echo "$hed" \ 30 | | awk -v schema="$SCHEMA" -v FS=, -v table="$TABLE" '{for (i = 1; i <= NF; i++) print "ALTER TABLE " schema "." table " ADD COLUMN IF NOT EXISTS " $i " TEXT;"}' \ 31 | | psql -q 32 | 33 | # COPY rows from zip file, removing leading spaces and other junk 34 | unzip -p "$ZIP" "${TABLE}.txt" \ 35 | | tail -n +2 \ 36 | | awk -v fi="${feed_index}" '{ sub(/\r$/, ""); sub("^\"\",", ","); gsub(",\"\"", ","); gsub(/,[[:space:]]+/, ","); if (NF > 0) print fi "," $0 }' \ 37 | | psql -c "COPY ${SCHEMA}.${TABLE} (feed_index, ${hed}) FROM STDIN (FORMAT csv, HEADER off)" 38 | -------------------------------------------------------------------------------- /src/load_feed_info.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | # This script takes three arguments: 3 | # A zip file containing gtfs files and a schema name. 4 | # It tries to load the file "feed_info.txt" from the zip file. If that file doesn't exist, it inserts a new row with no metadata 5 | ZIP=$1 6 | SCHEMA=${2} 7 | 8 | feed_index=$(psql -At -c "SELECT feed_index FROM ${SCHEMA}.feed_info WHERE feed_file = '${ZIP}'") 9 | 10 | if [[ -n "$feed_index" ]]; then 11 | echo "Using existing feed_index = $feed_index" 12 | exit 13 | fi 14 | 15 | export PGOPTIONS="${PGOPTIONS} -c client_min_messages=warning" 16 | 17 | if [[ $(unzip -Z -1 "$ZIP" | grep feed_info.txt) ]]; then 18 | 19 | hed=$(unzip -p "$ZIP" feed_info.txt | head -n 1 | awk '{sub(/^\xef\xbb\xbf/,"")}{print}') 20 | 21 | echo "$hed" \ 22 | | awk -v schema=$SCHEMA -v FS=, -v table=feed_info '{for (i = 1; i <= NF; i++) print "ALTER TABLE " schema "." table " ADD COLUMN IF NOT EXISTS " $i " TEXT;"}' \ 23 | | psql -q 24 | 25 | unzip -p "$ZIP" feed_info.txt \ 26 | | awk -v feed_file="$ZIP" '{ sub(/\r$/, ""); sub("^\"\",", ","); gsub(",\"\"", ","); gsub(/,[[:space:]]+/, ","); if (NF > 0) print $0 "," feed_file }' \ 27 | | psql -c "COPY ${SCHEMA}.feed_info (${hed},feed_file) FROM STDIN (FORMAT csv, HEADER on)" 28 | 29 | else 30 | # Start and end dates will be populated after insert to calendar_dates 31 | psql -c "INSERT INTO ${SCHEMA}.feed_info (feed_file) VALUES ('${ZIP}') ON CONFLICT DO NOTHING"; 32 | 33 | fi 34 | -------------------------------------------------------------------------------- /tests/constraints.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | SET search_path to tap, public; 3 | 4 | SELECT plan(30); 5 | 6 | SELECT col_is_fk(:'schema', 'routes', ARRAY['route_type'], 'routes.route_type is a foreign key'); 7 | SELECT col_is_fk(:'schema', 'routes', ARRAY['feed_index', 'agency_id'], 'routes.agency_id is a foreign key'); 8 | SELECT col_is_fk(:'schema', 'routes', ARRAY['continuous_pickup'], 'routes.continuous_pickup is a foreign key'); 9 | SELECT col_is_fk(:'schema', 'routes', ARRAY['continuous_drop_off'], 'routes.continuous_drop_off is a foreign key'); 10 | 11 | SELECT col_is_fk(:'schema', 'calendar_dates', ARRAY['feed_index', 'service_id'], 'calendar_dates.service_id is a foreign key'); 12 | SELECT col_is_fk(:'schema', 'calendar_dates', ARRAY['exception_type'], 'calendar_dates.exception_type is a foreign key'); 13 | 14 | SELECT col_is_fk(:'schema', 'fare_attributes', ARRAY['feed_index', 'agency_id'], 'fare_attributes.agency_id is a foreign key'); 15 | SELECT col_is_fk(:'schema', 'fare_attributes', ARRAY['payment_method'], 'fare_attributes.payment_method is a foreign key'); 16 | 17 | SELECT col_is_fk(:'schema', 'fare_rules', ARRAY['feed_index', 'service_id'], 'fare_rules.service_id is a foreign key'); 18 | SELECT col_is_fk(:'schema', 'fare_rules', ARRAY['feed_index', 'fare_id'], 'fare_rules.fare_id is a foreign key'); 19 | SELECT col_is_fk(:'schema', 'fare_rules', ARRAY['feed_index', 'route_id'], 'fare_rules.route_id is a foreign key'); 20 | 21 | SELECT col_is_fk(:'schema', 'trips', ARRAY['feed_index', 'route_id'], 'trips.route_id is a foreign key'); 22 | SELECT col_is_fk(:'schema', 'trips', ARRAY['feed_index', 'service_id'], 'trips.service_id is a foreign key'); 23 | SELECT col_is_fk(:'schema', 'trips', ARRAY['wheelchair_accessible'], 'trips.wheelchair_accessible is a foreign key'); 24 | 25 | SELECT col_is_fk(:'schema', 'stop_times', ARRAY['feed_index', 'trip_id'], 'stop_times.trip_id is a foreign key'); 26 | SELECT col_is_fk(:'schema', 'stop_times', ARRAY['feed_index', 'stop_id'], 'stop_times.stop_id is a foreign key'); 27 | SELECT col_is_fk(:'schema', 'stop_times', ARRAY['continuous_pickup'], 'stop_times.continuous_pickup is a foreign key'); 28 | SELECT col_is_fk(:'schema', 'stop_times', ARRAY['pickup_type'], 'stop_times.pickup_type is a foreign key'); 29 | SELECT col_is_fk(:'schema', 'stop_times', ARRAY['drop_off_type'], 'stop_times.drop_off_type is a foreign key'); 30 | SELECT col_is_fk(:'schema', 'stop_times', ARRAY['continuous_pickup'], 'stop_times.continuous_pickup is a foreign key'); 31 | SELECT col_is_fk(:'schema', 'stop_times', ARRAY['continuous_drop_off'], 'stop_times.continuous_drop_off is a foreign key'); 32 | 33 | SELECT col_is_fk(:'schema', 'frequencies', ARRAY['feed_index', 'trip_id'], 'frequencies.trip_id is a foreign key'); 34 | 35 | SELECT col_is_fk(:'schema', 'transfers', ARRAY['feed_index', 'from_stop_id'], 'transfers.from_stop_id is a foreign key'); 36 | SELECT col_is_fk(:'schema', 'transfers', ARRAY['feed_index', 'to_stop_id'], 'transfers.to_stop_id is a foreign key'); 37 | SELECT col_is_fk(:'schema', 'transfers', ARRAY['feed_index', 'from_route_id'], 'transfers.from_route_id is a foreign key'); 38 | SELECT col_is_fk(:'schema', 'transfers', ARRAY['feed_index', 'to_route_id'], 'transfers.to_route_id is a foreign key'); 39 | SELECT col_is_fk(:'schema', 'transfers', ARRAY['feed_index', 'service_id'], 'transfers.service_id is a foreign key'); 40 | 41 | SELECT col_is_fk(:'schema', 'stops', ARRAY['feed_index','level_id'], 'stops.level_id is a foreign key'); 42 | 43 | SELECT col_is_fk(:'schema', 'attributions', ARRAY['feed_index','trip_id'], 'attributions.trip_id is a foreign key'); 44 | SELECT col_is_fk(:'schema', 'attributions', ARRAY['feed_index','route_id'], 'attributions.route_id is a foreign key'); 45 | 46 | SELECT * FROM finish(); 47 | ROLLBACK; 48 | -------------------------------------------------------------------------------- /tests/data/281.zip: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/fitnr/gtfs-sql-importer/e42ac3fcb74cd1fdc46966a392482a414f3d4682/tests/data/281.zip -------------------------------------------------------------------------------- /tests/data/433.zip: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/fitnr/gtfs-sql-importer/e42ac3fcb74cd1fdc46966a392482a414f3d4682/tests/data/433.zip -------------------------------------------------------------------------------- /tests/schema.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | SET search_path TO tap, public; 3 | 4 | SELECT plan(114); 5 | 6 | SELECT has_schema(:'schema'); 7 | 8 | SELECT functions_are(:'schema', ARRAY[ 9 | 'feed_date_update', 10 | 'safe_locate', 11 | 'stop_geom_update' 12 | ]); 13 | 14 | SELECT is(md5(p.prosrc), '2065575f11e67e941eda441c4994c629', 'Function safe_locate body should match checksum') 15 | FROM pg_catalog.pg_proc p 16 | JOIN pg_catalog.pg_namespace n ON p.pronamespace = n.oid 17 | WHERE n.nspname = :'schema' 18 | AND proname = 'safe_locate' 19 | AND proargtypes::text = '24724 24724 1700 1700 1700'; 20 | 21 | SELECT is(md5(p.prosrc), '616b269581704c146937a1b8abdcc1c7', 'Function shape_update body should match checksum') 22 | FROM pg_catalog.pg_proc p 23 | JOIN pg_catalog.pg_namespace n ON p.pronamespace = n.oid 24 | WHERE n.nspname = :'schema' 25 | AND proname = 'shape_update' 26 | AND proargtypes::text = ''; 27 | 28 | SELECT is(md5(p.prosrc), 'b1f84dc082d7ec534c8c90d5982a941c', 'Function stop_geom_update body should match checksum') 29 | FROM pg_catalog.pg_proc p 30 | JOIN pg_catalog.pg_namespace n ON p.pronamespace = n.oid 31 | WHERE n.nspname = :'schema' 32 | AND proname = 'stop_geom_update' 33 | AND proargtypes::text = ''; 34 | 35 | SELECT is(md5(p.prosrc), '4b98b092dbb9f88986747b5c155dc39d', 'Function feed_date_update body should match checksum') 36 | FROM pg_catalog.pg_proc p 37 | JOIN pg_catalog.pg_namespace n ON p.pronamespace = n.oid 38 | WHERE n.nspname = :'schema' 39 | AND proname = 'feed_date_update' 40 | AND proargtypes::text = ''; 41 | 42 | SELECT has_trigger(:'schema'::name, 'calendar'::name, 'calendar_trigger'::name); 43 | SELECT has_trigger(:'schema'::name, 'stops'::name, 'stop_geom_trigger'::name); 44 | 45 | SELECT 46 | collect_tap( 47 | has_table(:'schema'::name, tname::name), 48 | has_pk(:'schema', tname, format('Table %s should have a primary key', tname)), 49 | columns_are(:'schema'::name, tname, cols), 50 | 51 | col_type_is(:'schema', tname, cols[1], 'integer', format('Column %s.%s should be type integer', tname, cols[1])), 52 | col_not_null(:'schema', tname, cols[1], format('Column %s.%s should be NOT NULL', tname, cols[1])), 53 | col_hasnt_default(:'schema', tname, cols[1], format('Column %s.%s should not have a default', tname, cols[1])), 54 | 55 | col_type_is(:'schema', tname, cols[2], 'text', format('Column %s.%s should be type text', tname, cols[2])), 56 | col_is_null(:'schema', tname, cols[2], format('Column %s.%s should be NOT NULL', tname, cols[2])), 57 | col_hasnt_default(:'schema', tname, cols[2], format('Column %s.%s should not have a default', tname, cols[2])) 58 | ) 59 | FROM (VALUES 60 | ('continuous_pickup'::name, ARRAY['continuous_pickup', 'description']::name[]), 61 | ('continuous_drop_off'::name, ARRAY['continuous_drop_off', 'description']::name[]), 62 | ('exception_types', ARRAY['exception_type', 'description']), 63 | ('location_types', ARRAY['location_type', 'description']), 64 | ('pathway_modes', ARRAY['pathway_mode', 'description']), 65 | ('payment_methods', ARRAY['payment_method', 'description']), 66 | ('pickup_dropoff_types', ARRAY['type_id', 'description']), 67 | ('route_types', ARRAY['route_type','description']), 68 | ('transfer_types', ARRAY['transfer_type','description']), 69 | ('wheelchair_accessible', ARRAY['wheelchair_accessible', 'description']), 70 | ('wheelchair_boardings', ARRAY['wheelchair_boarding', 'description']), 71 | ('timepoints', ARRAY['timepoint', 'description']) 72 | ) a (tname, cols); 73 | 74 | SELECT * FROM finish(); 75 | ROLLBACK; 76 | -------------------------------------------------------------------------------- /tests/table-agency.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | SET search_path TO tap, public; 3 | SELECT plan(22); 4 | SELECT has_table(:'schema', 'agency', 'table agency exists'); 5 | SELECT has_pk(:'schema', 'agency', 'table agency has primary key'); 6 | SELECT has_column(:'schema', 'agency', 'feed_index', 'table agency has column feed_index'); 7 | SELECT col_type_is(:'schema', 'agency', 'feed_index', 'integer', 'column agency.feed_index is integer'); 8 | SELECT has_column(:'schema', 'agency', 'agency_id', 'table agency has column agency_id'); 9 | SELECT col_type_is(:'schema', 'agency', 'agency_id', 'text', 'column agency.agency_id is text'); 10 | SELECT has_column(:'schema', 'agency', 'agency_name', 'table agency has column agency_name'); 11 | SELECT col_type_is(:'schema', 'agency', 'agency_name', 'text', 'column agency.agency_name is text'); 12 | SELECT has_column(:'schema', 'agency', 'agency_url', 'table agency has column agency_url'); 13 | SELECT col_type_is(:'schema', 'agency', 'agency_url', 'text', 'column agency.agency_url is text'); 14 | SELECT has_column(:'schema', 'agency', 'agency_timezone', 'table agency has column agency_timezone'); 15 | SELECT col_type_is(:'schema', 'agency', 'agency_timezone', 'text', 'column agency.agency_timezone is text'); 16 | SELECT has_column(:'schema', 'agency', 'agency_lang', 'table agency has column agency_lang'); 17 | SELECT col_type_is(:'schema', 'agency', 'agency_lang', 'text', 'column agency.agency_lang is text'); 18 | SELECT has_column(:'schema', 'agency', 'agency_phone', 'table agency has column agency_phone'); 19 | SELECT col_type_is(:'schema', 'agency', 'agency_phone', 'text', 'column agency.agency_phone is text'); 20 | SELECT has_column(:'schema', 'agency', 'agency_fare_url', 'table agency has column agency_fare_url'); 21 | SELECT col_type_is(:'schema', 'agency', 'agency_fare_url', 'text', 'column agency.agency_fare_url is text'); 22 | SELECT has_column(:'schema', 'agency', 'agency_email', 'table agency has column agency_email'); 23 | SELECT col_type_is(:'schema', 'agency', 'agency_email', 'text', 'column agency.agency_email is text'); 24 | SELECT has_column(:'schema', 'agency', 'bikes_policy_url', 'table agency has column bikes_policy_url'); 25 | SELECT col_type_is(:'schema', 'agency', 'bikes_policy_url', 'text', 'column agency.bikes_policy_url is text'); 26 | SELECT * FROM finish(); 27 | ROLLBACK; 28 | -------------------------------------------------------------------------------- /tests/table-attributions.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | SET search_path TO tap, public; 3 | SELECT plan(51); 4 | 5 | SELECT has_table( 6 | :'schema', 'attributions', 7 | 'Should have table gtfs.attributions' 8 | ); 9 | 10 | SELECT has_pk( 11 | :'schema', 'attributions', 12 | 'Table gtfs.attributions should have a primary key' 13 | ); 14 | 15 | SELECT columns_are(:'schema'::name, 'attributions'::name, ARRAY[ 16 | 'feed_index'::name, 17 | 'attribution_id'::name, 18 | 'agency_id'::name, 19 | 'route_id'::name, 20 | 'trip_id'::name, 21 | 'organization_name'::name, 22 | 'is_producer'::name, 23 | 'is_operator'::name, 24 | 'is_authority'::name, 25 | 'attribution_url'::name, 26 | 'attribution_email'::name, 27 | 'attribution_phone'::name 28 | ]); 29 | 30 | SELECT has_column( :'schema', 'attributions', 'feed_index', 'Column gtfs.attributions.feed_index should exist'); 31 | SELECT col_type_is( :'schema', 'attributions', 'feed_index', 'integer', 'Column gtfs.attributions.feed_index should be type integer'); 32 | SELECT col_not_null( :'schema', 'attributions', 'feed_index', 'Column gtfs.attributions.feed_index should be NOT NULL'); 33 | SELECT col_hasnt_default(:'schema', 'attributions', 'feed_index', 'Column gtfs.attributions.feed_index should not have a default'); 34 | 35 | SELECT has_column( :'schema', 'attributions', 'attribution_id', 'Column gtfs.attributions.attribution_id should exist'); 36 | SELECT col_type_is( :'schema', 'attributions', 'attribution_id', 'text', 'Column gtfs.attributions.attribution_id should be type text'); 37 | SELECT col_not_null( :'schema', 'attributions', 'attribution_id', 'Column gtfs.attributions.attribution_id should be NOT NULL'); 38 | SELECT col_hasnt_default(:'schema', 'attributions', 'attribution_id', 'Column gtfs.attributions.attribution_id should not have a default'); 39 | 40 | SELECT has_column( :'schema', 'attributions', 'agency_id', 'Column gtfs.attributions.agency_id should exist'); 41 | SELECT col_type_is( :'schema', 'attributions', 'agency_id', 'text', 'Column gtfs.attributions.agency_id should be type text'); 42 | SELECT col_is_null( :'schema', 'attributions', 'agency_id', 'Column gtfs.attributions.agency_id should allow NULL'); 43 | SELECT col_hasnt_default(:'schema', 'attributions', 'agency_id', 'Column gtfs.attributions.agency_id should not have a default'); 44 | 45 | SELECT has_column( :'schema', 'attributions', 'route_id', 'Column gtfs.attributions.route_id should exist'); 46 | SELECT col_type_is( :'schema', 'attributions', 'route_id', 'text', 'Column gtfs.attributions.route_id should be type text'); 47 | SELECT col_is_null( :'schema', 'attributions', 'route_id', 'Column gtfs.attributions.route_id should allow NULL'); 48 | SELECT col_hasnt_default(:'schema', 'attributions', 'route_id', 'Column gtfs.attributions.route_id should not have a default'); 49 | 50 | SELECT has_column( :'schema', 'attributions', 'trip_id', 'Column gtfs.attributions.trip_id should exist'); 51 | SELECT col_type_is( :'schema', 'attributions', 'trip_id', 'text', 'Column gtfs.attributions.trip_id should be type text'); 52 | SELECT col_is_null( :'schema', 'attributions', 'trip_id', 'Column gtfs.attributions.trip_id should allow NULL'); 53 | SELECT col_hasnt_default(:'schema', 'attributions', 'trip_id', 'Column gtfs.attributions.trip_id should not have a default'); 54 | 55 | SELECT has_column( :'schema', 'attributions', 'organization_name', 'Column gtfs.attributions.organization_name should exist'); 56 | SELECT col_type_is( :'schema', 'attributions', 'organization_name', 'text', 'Column gtfs.attributions.organization_name should be type text'); 57 | SELECT col_not_null( :'schema', 'attributions', 'organization_name', 'Column gtfs.attributions.organization_name should not allow NULL'); 58 | SELECT col_hasnt_default(:'schema', 'attributions', 'organization_name', 'Column gtfs.attributions.organization_name should not have a default'); 59 | 60 | SELECT has_column( :'schema', 'attributions', 'is_producer', 'Column gtfs.attributions.is_producer should exist'); 61 | SELECT col_type_is( :'schema', 'attributions', 'is_producer', 'boolean', 'Column gtfs.attributions.is_producer should be type boolean'); 62 | SELECT col_is_null( :'schema', 'attributions', 'is_producer', 'Column gtfs.attributions.is_producer should allow NULL'); 63 | SELECT col_hasnt_default(:'schema', 'attributions', 'is_producer', 'Column gtfs.attributions.is_producer should not have a default'); 64 | 65 | SELECT has_column( :'schema', 'attributions', 'is_operator', 'Column gtfs.attributions.is_operator should exist'); 66 | SELECT col_type_is( :'schema', 'attributions', 'is_operator', 'boolean', 'Column gtfs.attributions.is_operator should be type boolean'); 67 | SELECT col_is_null( :'schema', 'attributions', 'is_operator', 'Column gtfs.attributions.is_operator should allow NULL'); 68 | SELECT col_hasnt_default(:'schema', 'attributions', 'is_operator', 'Column gtfs.attributions.is_operator should not have a default'); 69 | 70 | SELECT has_column( :'schema', 'attributions', 'is_authority', 'Column gtfs.attributions.is_authority should exist'); 71 | SELECT col_type_is( :'schema', 'attributions', 'is_authority', 'boolean', 'Column gtfs.attributions.is_authority should be type boolean'); 72 | SELECT col_is_null( :'schema', 'attributions', 'is_authority', 'Column gtfs.attributions.is_authority should allow NULL'); 73 | SELECT col_hasnt_default(:'schema', 'attributions', 'is_authority', 'Column gtfs.attributions.is_authority should not have a default'); 74 | 75 | SELECT has_column( :'schema', 'attributions', 'attribution_url', 'Column gtfs.attributions.attribution_url should exist'); 76 | SELECT col_type_is( :'schema', 'attributions', 'attribution_url', 'text', 'Column gtfs.attributions.attribution_url should be type text'); 77 | SELECT col_is_null( :'schema', 'attributions', 'attribution_url', 'Column gtfs.attributions.attribution_url should allow NULL'); 78 | SELECT col_hasnt_default(:'schema', 'attributions', 'attribution_url', 'Column gtfs.attributions.attribution_url should not have a default'); 79 | 80 | SELECT has_column( :'schema', 'attributions', 'attribution_email', 'Column gtfs.attributions.attribution_email should exist'); 81 | SELECT col_type_is( :'schema', 'attributions', 'attribution_email', 'text', 'Column gtfs.attributions.attribution_email should be type text'); 82 | SELECT col_is_null( :'schema', 'attributions', 'attribution_email', 'Column gtfs.attributions.attribution_email should allow NULL'); 83 | SELECT col_hasnt_default(:'schema', 'attributions', 'attribution_email', 'Column gtfs.attributions.attribution_email should not have a default'); 84 | 85 | SELECT has_column( :'schema', 'attributions', 'attribution_phone', 'Column gtfs.attributions.attribution_phone should exist'); 86 | SELECT col_type_is( :'schema', 'attributions', 'attribution_phone', 'text', 'Column gtfs.attributions.attribution_phone should be type text'); 87 | SELECT col_is_null( :'schema', 'attributions', 'attribution_phone', 'Column gtfs.attributions.attribution_phone should allow NULL'); 88 | SELECT col_hasnt_default(:'schema', 'attributions', 'attribution_phone', 'Column gtfs.attributions.attribution_phone should not have a default'); 89 | 90 | SELECT * FROM finish(); 91 | ROLLBACK; 92 | -------------------------------------------------------------------------------- /tests/table-calendar.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, public; 2 | SELECT plan(25); 3 | 4 | SELECT has_table(:'schema', 'calendar', 'table calendar exists'); 5 | SELECT has_pk(:'schema', 'calendar', 'table calendar has primary key'); 6 | SELECT is_indexed(:'schema', 'calendar', ARRAY['feed_index', 'service_id']); 7 | 8 | SELECT has_column(:'schema', 'calendar', 'feed_index', 'table calendar has column feed_index'); 9 | SELECT col_type_is(:'schema', 'calendar', 'feed_index', 'integer', 'column calendar.feed_index is integer'); 10 | SELECT has_column(:'schema', 'calendar', 'service_id', 'table calendar has column service_id'); 11 | SELECT col_type_is(:'schema', 'calendar', 'service_id', 'text', 'column calendar.service_id is text'); 12 | SELECT has_column(:'schema', 'calendar', 'monday', 'table calendar has column monday'); 13 | SELECT col_type_is(:'schema', 'calendar', 'monday', 'integer', 'column calendar.monday is integer'); 14 | SELECT has_column(:'schema', 'calendar', 'tuesday', 'table calendar has column tuesday'); 15 | SELECT col_type_is(:'schema', 'calendar', 'tuesday', 'integer', 'column calendar.tuesday is integer'); 16 | SELECT has_column(:'schema', 'calendar', 'wednesday', 'table calendar has column wednesday'); 17 | SELECT col_type_is(:'schema', 'calendar', 'wednesday', 'integer', 'column calendar.wednesday is integer'); 18 | SELECT has_column(:'schema', 'calendar', 'thursday', 'table calendar has column thursday'); 19 | SELECT col_type_is(:'schema', 'calendar', 'thursday', 'integer', 'column calendar.thursday is integer'); 20 | SELECT has_column(:'schema', 'calendar', 'friday', 'table calendar has column friday'); 21 | SELECT col_type_is(:'schema', 'calendar', 'friday', 'integer', 'column calendar.friday is integer'); 22 | SELECT has_column(:'schema', 'calendar', 'saturday', 'table calendar has column saturday'); 23 | SELECT col_type_is(:'schema', 'calendar', 'saturday', 'integer', 'column calendar.saturday is integer'); 24 | SELECT has_column(:'schema', 'calendar', 'sunday', 'table calendar has column sunday'); 25 | SELECT col_type_is(:'schema', 'calendar', 'sunday', 'integer', 'column calendar.sunday is integer'); 26 | SELECT has_column(:'schema', 'calendar', 'start_date', 'table calendar has column start_date'); 27 | SELECT col_type_is(:'schema', 'calendar', 'start_date', 'date', 'column calendar.start_date is date'); 28 | SELECT has_column(:'schema', 'calendar', 'end_date', 'table calendar has column end_date'); 29 | SELECT col_type_is(:'schema', 'calendar', 'end_date', 'date', 'column calendar.end_date is date'); 30 | SELECT * FROM finish(); 31 | -------------------------------------------------------------------------------- /tests/table-calendar_dates.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, public; 2 | SELECT plan(11); 3 | SELECT has_table(:'schema', 'calendar_dates', 'table calendar_dates exists'); 4 | SELECT has_pk(:'schema', 'calendar_dates', 'table calendar_dates has primary key'); 5 | SELECT is_indexed(:'schema', 'calendar_dates', ARRAY['date']); 6 | SELECT has_column(:'schema', 'calendar_dates', 'feed_index', 'table calendar_dates has column feed_index'); 7 | SELECT col_type_is(:'schema', 'calendar_dates', 'feed_index', 'integer', 'column calendar_dates.feed_index is integer'); 8 | SELECT has_column(:'schema', 'calendar_dates', 'service_id', 'table calendar_dates has column service_id'); 9 | SELECT col_type_is(:'schema', 'calendar_dates', 'service_id', 'text', 'column calendar_dates.service_id is text'); 10 | SELECT has_column(:'schema', 'calendar_dates', 'date', 'table calendar_dates has column date'); 11 | SELECT col_type_is(:'schema', 'calendar_dates', 'date', 'date', 'column calendar_dates.date is date'); 12 | SELECT has_column(:'schema', 'calendar_dates', 'exception_type', 'table calendar_dates has column exception_type'); 13 | SELECT col_type_is(:'schema', 'calendar_dates', 'exception_type', 'integer', 'column calendar_dates.exception_type is integer'); 14 | SELECT * FROM finish(); 15 | -------------------------------------------------------------------------------- /tests/table-fare_attributes.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, public; 2 | SELECT plan(18); 3 | SELECT has_table(:'schema', 'fare_attributes', 'table fare_attributes exists'); 4 | SELECT has_pk(:'schema', 'fare_attributes', 'table fare_attributes has primary key'); 5 | SELECT has_column(:'schema', 'fare_attributes', 'feed_index', 'table fare_attributes has column feed_index'); 6 | SELECT col_type_is(:'schema', 'fare_attributes', 'feed_index', 'integer', 'column fare_attributes.feed_index is integer'); 7 | SELECT has_column(:'schema', 'fare_attributes', 'fare_id', 'table fare_attributes has column fare_id'); 8 | SELECT col_type_is(:'schema', 'fare_attributes', 'fare_id', 'text', 'column fare_attributes.fare_id is text'); 9 | SELECT has_column(:'schema', 'fare_attributes', 'price', 'table fare_attributes has column price'); 10 | SELECT col_type_is(:'schema', 'fare_attributes', 'price', 'double precision', 'column fare_attributes.price is double precision'); 11 | SELECT has_column(:'schema', 'fare_attributes', 'currency_type', 'table fare_attributes has column currency_type'); 12 | SELECT col_type_is(:'schema', 'fare_attributes', 'currency_type', 'text', 'column fare_attributes.currency_type is text'); 13 | SELECT has_column(:'schema', 'fare_attributes', 'payment_method', 'table fare_attributes has column payment_method'); 14 | SELECT col_type_is(:'schema', 'fare_attributes', 'payment_method', 'integer', 'column fare_attributes.payment_method is integer'); 15 | SELECT has_column(:'schema', 'fare_attributes', 'transfers', 'table fare_attributes has column transfers'); 16 | SELECT col_type_is(:'schema', 'fare_attributes', 'transfers', 'integer', 'column fare_attributes.transfers is integer'); 17 | SELECT has_column(:'schema', 'fare_attributes', 'transfer_duration', 'table fare_attributes has column transfer_duration'); 18 | SELECT col_type_is(:'schema', 'fare_attributes', 'transfer_duration', 'integer', 'column fare_attributes.transfer_duration is integer'); 19 | SELECT has_column(:'schema', 'fare_attributes', 'agency_id', 'table fare_attributes has column agency_id'); 20 | SELECT col_type_is(:'schema', 'fare_attributes', 'agency_id', 'text', 'column fare_attributes.agency_id is text'); 21 | SELECT * FROM finish(); 22 | -------------------------------------------------------------------------------- /tests/table-fare_rules.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, public; 2 | SELECT plan(16); 3 | SELECT has_table(:'schema', 'fare_rules', 'table fare_rules exists'); 4 | SELECT has_pk(:'schema', 'fare_rules', 'table fare_rules has primary key'); 5 | SELECT has_column(:'schema', 'fare_rules', 'feed_index', 'table fare_rules has column feed_index'); 6 | SELECT col_type_is(:'schema', 'fare_rules', 'feed_index', 'integer', 'column fare_rules.feed_index is integer'); 7 | SELECT has_column(:'schema', 'fare_rules', 'fare_id', 'table fare_rules has column fare_id'); 8 | SELECT col_type_is(:'schema', 'fare_rules', 'fare_id', 'text', 'column fare_rules.fare_id is text'); 9 | SELECT has_column(:'schema', 'fare_rules', 'route_id', 'table fare_rules has column route_id'); 10 | SELECT col_type_is(:'schema', 'fare_rules', 'route_id', 'text', 'column fare_rules.route_id is text'); 11 | SELECT has_column(:'schema', 'fare_rules', 'origin_id', 'table fare_rules has column origin_id'); 12 | SELECT col_type_is(:'schema', 'fare_rules', 'origin_id', 'text', 'column fare_rules.origin_id is text'); 13 | SELECT has_column(:'schema', 'fare_rules', 'destination_id', 'table fare_rules has column destination_id'); 14 | SELECT col_type_is(:'schema', 'fare_rules', 'destination_id', 'text', 'column fare_rules.destination_id is text'); 15 | SELECT has_column(:'schema', 'fare_rules', 'contains_id', 'table fare_rules has column contains_id'); 16 | SELECT col_type_is(:'schema', 'fare_rules', 'contains_id', 'text', 'column fare_rules.contains_id is text'); 17 | SELECT has_column(:'schema', 'fare_rules', 'service_id', 'table fare_rules has column service_id'); 18 | SELECT col_type_is(:'schema', 'fare_rules', 'service_id', 'text', 'column fare_rules.service_id is text'); 19 | SELECT * FROM finish(); 20 | -------------------------------------------------------------------------------- /tests/table-feed_info.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | SET search_path TO tap, public; 3 | SELECT plan(29); 4 | SELECT has_table(:'schema', 'feed_info', 'table feed_info exists'); 5 | SELECT has_pk(:'schema', 'feed_info', 'table feed_info has primary key'); 6 | SELECT has_column(:'schema', 'feed_info', 'feed_index', 'table feed_info has column feed_index'); 7 | SELECT col_type_is(:'schema', 'feed_info', 'feed_index', 'integer', 'column feed_info.feed_index is integer'); 8 | SELECT has_column(:'schema', 'feed_info', 'feed_publisher_name', 'table feed_info has column feed_publisher_name'); 9 | SELECT col_type_is(:'schema', 'feed_info', 'feed_publisher_name', 'text', 'column feed_info.feed_publisher_name is text'); 10 | SELECT has_column(:'schema', 'feed_info', 'feed_publisher_url', 'table feed_info has column feed_publisher_url'); 11 | SELECT col_type_is(:'schema', 'feed_info', 'feed_publisher_url', 'text', 'column feed_info.feed_publisher_url is text'); 12 | SELECT has_column(:'schema', 'feed_info', 'feed_timezone', 'table feed_info has column feed_timezone'); 13 | SELECT col_type_is(:'schema', 'feed_info', 'feed_timezone', 'text', 'column feed_info.feed_timezone is text'); 14 | SELECT has_column(:'schema', 'feed_info', 'feed_lang', 'table feed_info has column feed_lang'); 15 | SELECT col_type_is(:'schema', 'feed_info', 'feed_lang', 'text', 'column feed_info.feed_lang is text'); 16 | SELECT has_column(:'schema', 'feed_info', 'feed_version', 'table feed_info has column feed_version'); 17 | SELECT col_type_is(:'schema', 'feed_info', 'feed_version', 'text', 'column feed_info.feed_version is text'); 18 | SELECT has_column(:'schema', 'feed_info', 'feed_start_date', 'table feed_info has column feed_start_date'); 19 | SELECT col_type_is(:'schema', 'feed_info', 'feed_start_date', 'date', 'column feed_info.feed_start_date is date'); 20 | SELECT has_column(:'schema', 'feed_info', 'feed_end_date', 'table feed_info has column feed_end_date'); 21 | SELECT col_type_is(:'schema', 'feed_info', 'feed_end_date', 'date', 'column feed_info.feed_end_date is date'); 22 | SELECT has_column(:'schema', 'feed_info', 'feed_id', 'table feed_info has column feed_id'); 23 | SELECT col_type_is(:'schema', 'feed_info', 'feed_id', 'text', 'column feed_info.feed_id is text'); 24 | SELECT has_column(:'schema', 'feed_info', 'feed_contact_url', 'table feed_info has column feed_contact_url'); 25 | SELECT col_type_is(:'schema', 'feed_info', 'feed_contact_url', 'text', 'column feed_info.feed_contact_url is text'); 26 | SELECT has_column(:'schema', 'feed_info', 'feed_contact_email', 'table feed_info has column feed_contact_email'); 27 | SELECT col_type_is(:'schema', 'feed_info', 'feed_contact_email', 'text', 'column feed_info.feed_contact_email is text'); 28 | SELECT has_column(:'schema', 'feed_info', 'feed_download_date', 'table feed_info has column feed_download_date'); 29 | SELECT col_type_is(:'schema', 'feed_info', 'feed_download_date', 'date', 'column feed_info.feed_download_date is date'); 30 | SELECT has_column(:'schema', 'feed_info', 'feed_file', 'table feed_info has column feed_file'); 31 | SELECT col_type_is(:'schema', 'feed_info', 'feed_file', 'text', 'column feed_info.feed_file is text'); 32 | SELECT col_is_unique(:'schema', 'feed_info', 'feed_file', 'column feed_info.feed_file is unique'); 33 | SELECT * FROM finish(); 34 | ROLLBACK; 35 | -------------------------------------------------------------------------------- /tests/table-frequencies.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, public; 2 | SELECT plan(18); 3 | SELECT has_table(:'schema', 'frequencies', 'table frequencies exists'); 4 | SELECT has_pk(:'schema', 'frequencies', 'table frequencies has primary key'); 5 | SELECT has_column(:'schema', 'frequencies', 'feed_index', 'table frequencies has column feed_index'); 6 | SELECT col_type_is(:'schema', 'frequencies', 'feed_index', 'integer', 'column frequencies.feed_index is integer'); 7 | SELECT has_column(:'schema', 'frequencies', 'trip_id', 'table frequencies has column trip_id'); 8 | SELECT col_type_is(:'schema', 'frequencies', 'trip_id', 'text', 'column frequencies.trip_id is text'); 9 | SELECT has_column(:'schema', 'frequencies', 'start_time', 'table frequencies has column start_time'); 10 | SELECT col_type_is(:'schema', 'frequencies', 'start_time', 'text', 'column frequencies.start_time is text'); 11 | SELECT has_column(:'schema', 'frequencies', 'end_time', 'table frequencies has column end_time'); 12 | SELECT col_type_is(:'schema', 'frequencies', 'end_time', 'text', 'column frequencies.end_time is text'); 13 | SELECT has_column(:'schema', 'frequencies', 'headway_secs', 'table frequencies has column headway_secs'); 14 | SELECT col_type_is(:'schema', 'frequencies', 'headway_secs', 'integer', 'column frequencies.headway_secs is integer'); 15 | SELECT has_column(:'schema', 'frequencies', 'exact_times', 'table frequencies has column exact_times'); 16 | SELECT col_type_is(:'schema', 'frequencies', 'exact_times', 'integer', 'column frequencies.exact_times is integer'); 17 | SELECT has_column(:'schema', 'frequencies', 'start_time_seconds', 'table frequencies has column start_time_seconds'); 18 | SELECT col_type_is(:'schema', 'frequencies', 'start_time_seconds', 'integer', 'column frequencies.start_time_seconds is integer'); 19 | SELECT has_column(:'schema', 'frequencies', 'end_time_seconds', 'table frequencies has column end_time_seconds'); 20 | SELECT col_type_is(:'schema', 'frequencies', 'end_time_seconds', 'integer', 'column frequencies.end_time_seconds is integer'); 21 | SELECT * FROM finish(); 22 | -------------------------------------------------------------------------------- /tests/table-levels.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | SET search_path TO tap, public; 3 | SELECT plan(19); 4 | 5 | SELECT has_table(:'schema', 'levels', 'Should have table gtfs.levels'); 6 | 7 | SELECT has_pk( 8 | :'schema', 'levels', 9 | 'Table gtfs.levels should have a primary key' 10 | ); 11 | 12 | SELECT columns_are(:'schema'::name, 'levels'::name, ARRAY[ 13 | 'feed_index'::name, 14 | 'level_id'::name, 15 | 'level_index'::name, 16 | 'level_name'::name 17 | ]); 18 | 19 | SELECT has_column( :'schema', 'levels', 'feed_index', 'Column gtfs.levels.feed_index should exist'); 20 | SELECT col_type_is( :'schema', 'levels', 'feed_index', 'integer', 'Column gtfs.levels.feed_index should be type integer'); 21 | SELECT col_not_null( :'schema', 'levels', 'feed_index', 'Column gtfs.levels.feed_index should be NOT NULL'); 22 | SELECT col_hasnt_default(:'schema', 'levels', 'feed_index', 'Column gtfs.levels.feed_index should not have a default'); 23 | 24 | SELECT has_column( :'schema', 'levels', 'level_id', 'Column gtfs.levels.level_id should exist'); 25 | SELECT col_type_is( :'schema', 'levels', 'level_id', 'text', 'Column gtfs.levels.level_id should be type text'); 26 | SELECT col_not_null( :'schema', 'levels', 'level_id', 'Column gtfs.levels.level_id should be NOT NULL'); 27 | SELECT col_hasnt_default(:'schema', 'levels', 'level_id', 'Column gtfs.levels.level_id should not have a default'); 28 | 29 | SELECT has_column( :'schema', 'levels', 'level_index', 'Column gtfs.levels.level_index should exist'); 30 | SELECT col_type_is( :'schema', 'levels', 'level_index', 'double precision', 'Column gtfs.levels.level_index should be type double precision'); 31 | SELECT col_not_null( :'schema', 'levels', 'level_index', 'Column gtfs.levels.level_index should not allow NULL'); 32 | SELECT col_hasnt_default(:'schema', 'levels', 'level_index', 'Column gtfs.levels.level_index should not have a default'); 33 | 34 | SELECT has_column( :'schema', 'levels', 'level_name', 'Column gtfs.levels.level_name should exist'); 35 | SELECT col_type_is( :'schema', 'levels', 'level_name', 'text', 'Column gtfs.levels.level_name should be type text'); 36 | SELECT col_is_null( :'schema', 'levels', 'level_name', 'Column gtfs.levels.level_name should allow NULL'); 37 | SELECT col_hasnt_default(:'schema', 'levels', 'level_name', 'Column gtfs.levels.level_name should not have a default'); 38 | 39 | SELECT * FROM finish(); 40 | ROLLBACK; 41 | -------------------------------------------------------------------------------- /tests/table-pathways.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | SET search_path TO tap, public; 3 | SELECT plan(55); 4 | 5 | SELECT has_table( 6 | :'schema', 'pathways', 7 | 'Should have table gtfs.pathways' 8 | ); 9 | 10 | SELECT has_pk( 11 | :'schema', 'pathways', 12 | 'Table gtfs.pathways should have a primary key' 13 | ); 14 | 15 | SELECT columns_are(:'schema'::name, 'pathways'::name, ARRAY[ 16 | 'feed_index'::name, 17 | 'pathway_id'::name, 18 | 'from_stop_id'::name, 19 | 'to_stop_id'::name, 20 | 'pathway_mode'::name, 21 | 'is_bidirectional'::name, 22 | 'length'::name, 23 | 'traversal_time'::name, 24 | 'stair_count'::name, 25 | 'max_slope'::name, 26 | 'min_width'::name, 27 | 'signposted_as'::name, 28 | 'reversed_signposted_as'::name 29 | ]); 30 | 31 | SELECT has_column( :'schema', 'pathways', 'feed_index', 'Column gtfs.pathways.feed_index should exist'); 32 | SELECT col_type_is( :'schema', 'pathways', 'feed_index', 'integer', 'Column gtfs.pathways.feed_index should be type integer'); 33 | SELECT col_not_null( :'schema', 'pathways', 'feed_index', 'Column gtfs.pathways.feed_index should be NOT NULL'); 34 | SELECT col_hasnt_default(:'schema', 'pathways', 'feed_index', 'Column gtfs.pathways.feed_index should not have a default'); 35 | 36 | SELECT has_column( :'schema', 'pathways', 'pathway_id', 'Column gtfs.pathways.pathway_id should exist'); 37 | SELECT col_type_is( :'schema', 'pathways', 'pathway_id', 'text', 'Column gtfs.pathways.pathway_id should be type text'); 38 | SELECT col_not_null( :'schema', 'pathways', 'pathway_id', 'Column gtfs.pathways.pathway_id should be NOT NULL'); 39 | SELECT col_hasnt_default(:'schema', 'pathways', 'pathway_id', 'Column gtfs.pathways.pathway_id should not have a default'); 40 | 41 | SELECT has_column( :'schema', 'pathways', 'from_stop_id', 'Column gtfs.pathways.from_stop_id should exist'); 42 | SELECT col_type_is( :'schema', 'pathways', 'from_stop_id', 'text', 'Column gtfs.pathways.from_stop_id should be type text'); 43 | SELECT col_not_null( :'schema', 'pathways', 'from_stop_id', 'Column gtfs.pathways.from_stop_id should not allow NULL'); 44 | SELECT col_hasnt_default(:'schema', 'pathways', 'from_stop_id', 'Column gtfs.pathways.from_stop_id should not have a default'); 45 | 46 | SELECT has_column( :'schema', 'pathways', 'to_stop_id', 'Column gtfs.pathways.to_stop_id should exist'); 47 | SELECT col_type_is( :'schema', 'pathways', 'to_stop_id', 'text', 'Column gtfs.pathways.to_stop_id should be type text'); 48 | SELECT col_not_null( :'schema', 'pathways', 'to_stop_id', 'Column gtfs.pathways.to_stop_id should not allow NULL'); 49 | SELECT col_hasnt_default(:'schema', 'pathways', 'to_stop_id', 'Column gtfs.pathways.to_stop_id should not have a default'); 50 | 51 | SELECT has_column( :'schema', 'pathways', 'pathway_mode', 'Column gtfs.pathways.pathway_mode should exist'); 52 | SELECT col_type_is( :'schema', 'pathways', 'pathway_mode', 'integer', 'Column gtfs.pathways.pathway_mode should be type integer'); 53 | SELECT col_not_null( :'schema', 'pathways', 'pathway_mode', 'Column gtfs.pathways.pathway_mode should not allow NULL'); 54 | SELECT col_hasnt_default(:'schema', 'pathways', 'pathway_mode', 'Column gtfs.pathways.pathway_mode should not have a default'); 55 | 56 | SELECT has_column( :'schema', 'pathways', 'is_bidirectional', 'Column gtfs.pathways.is_bidirectional should exist'); 57 | SELECT col_type_is( :'schema', 'pathways', 'is_bidirectional', 'integer', 'Column gtfs.pathways.is_bidirectional should be type integer'); 58 | SELECT col_not_null( :'schema', 'pathways', 'is_bidirectional', 'Column gtfs.pathways.is_bidirectional should not allow NULL'); 59 | SELECT col_hasnt_default(:'schema', 'pathways', 'is_bidirectional', 'Column gtfs.pathways.is_bidirectional should not have a default'); 60 | 61 | SELECT has_column( :'schema', 'pathways', 'length', 'Column gtfs.pathways.length should exist'); 62 | SELECT col_type_is( :'schema', 'pathways', 'length', 'double precision', 'Column gtfs.pathways.length should be type double precision'); 63 | SELECT col_is_null( :'schema', 'pathways', 'length', 'Column gtfs.pathways.length should allow NULL'); 64 | SELECT col_hasnt_default(:'schema', 'pathways', 'length', 'Column gtfs.pathways.length should not have a default'); 65 | 66 | SELECT has_column( :'schema', 'pathways', 'traversal_time', 'Column gtfs.pathways.traversal_time should exist'); 67 | SELECT col_type_is( :'schema', 'pathways', 'traversal_time', 'integer', 'Column gtfs.pathways.traversal_time should be type integer'); 68 | SELECT col_is_null( :'schema', 'pathways', 'traversal_time', 'Column gtfs.pathways.traversal_time should allow NULL'); 69 | SELECT col_hasnt_default(:'schema', 'pathways', 'traversal_time', 'Column gtfs.pathways.traversal_time should not have a default'); 70 | 71 | SELECT has_column( :'schema', 'pathways', 'stair_count', 'Column gtfs.pathways.stair_count should exist'); 72 | SELECT col_type_is( :'schema', 'pathways', 'stair_count', 'integer', 'Column gtfs.pathways.stair_count should be type integer'); 73 | SELECT col_is_null( :'schema', 'pathways', 'stair_count', 'Column gtfs.pathways.stair_count should allow NULL'); 74 | SELECT col_hasnt_default(:'schema', 'pathways', 'stair_count', 'Column gtfs.pathways.stair_count should not have a default'); 75 | 76 | SELECT has_column( :'schema', 'pathways', 'max_slope', 'Column gtfs.pathways.max_slope should exist'); 77 | SELECT col_type_is( :'schema', 'pathways', 'max_slope', 'numeric', 'Column gtfs.pathways.max_slope should be type numeric'); 78 | SELECT col_is_null( :'schema', 'pathways', 'max_slope', 'Column gtfs.pathways.max_slope should allow NULL'); 79 | SELECT col_hasnt_default(:'schema', 'pathways', 'max_slope', 'Column gtfs.pathways.max_slope should not have a default'); 80 | 81 | SELECT has_column( :'schema', 'pathways', 'min_width', 'Column gtfs.pathways.min_width should exist'); 82 | SELECT col_type_is( :'schema', 'pathways', 'min_width', 'double precision', 'Column gtfs.pathways.min_width should be type double precision'); 83 | SELECT col_is_null( :'schema', 'pathways', 'min_width', 'Column gtfs.pathways.min_width should allow NULL'); 84 | SELECT col_hasnt_default(:'schema', 'pathways', 'min_width', 'Column gtfs.pathways.min_width should not have a default'); 85 | 86 | SELECT has_column( :'schema', 'pathways', 'signposted_as', 'Column gtfs.pathways.signposted_as should exist'); 87 | SELECT col_type_is( :'schema', 'pathways', 'signposted_as', 'text', 'Column gtfs.pathways.signposted_as should be type text'); 88 | SELECT col_is_null( :'schema', 'pathways', 'signposted_as', 'Column gtfs.pathways.signposted_as should allow NULL'); 89 | SELECT col_hasnt_default(:'schema', 'pathways', 'signposted_as', 'Column gtfs.pathways.signposted_as should not have a default'); 90 | 91 | SELECT has_column( :'schema', 'pathways', 'reversed_signposted_as', 'Column gtfs.pathways.reversed_signposted_as should exist'); 92 | SELECT col_type_is( :'schema', 'pathways', 'reversed_signposted_as', 'text', 'Column gtfs.pathways.reversed_signposted_as should be type text'); 93 | SELECT col_is_null( :'schema', 'pathways', 'reversed_signposted_as', 'Column gtfs.pathways.reversed_signposted_as should allow NULL'); 94 | SELECT col_hasnt_default(:'schema', 'pathways', 'reversed_signposted_as', 'Column gtfs.pathways.reversed_signposted_as should not have a default'); 95 | 96 | SELECT * FROM finish(); 97 | ROLLBACK; 98 | -------------------------------------------------------------------------------- /tests/table-routes.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, public; 2 | SELECT plan(24); 3 | SELECT has_table(:'schema', 'routes', 'table routes exists'); 4 | SELECT has_pk(:'schema', 'routes', 'table routes has primary key'); 5 | SELECT has_column(:'schema', 'routes', 'feed_index', 'table routes has column feed_index'); 6 | SELECT col_type_is(:'schema', 'routes', 'feed_index', 'integer', 'column routes.feed_index is integer'); 7 | SELECT has_column(:'schema', 'routes', 'route_id', 'table routes has column route_id'); 8 | SELECT col_type_is(:'schema', 'routes', 'route_id', 'text', 'column routes.route_id is text'); 9 | SELECT has_column(:'schema', 'routes', 'agency_id', 'table routes has column agency_id'); 10 | SELECT col_type_is(:'schema', 'routes', 'agency_id', 'text', 'column routes.agency_id is text'); 11 | SELECT has_column(:'schema', 'routes', 'route_short_name', 'table routes has column route_short_name'); 12 | SELECT col_type_is(:'schema', 'routes', 'route_short_name', 'text', 'column routes.route_short_name is text'); 13 | SELECT has_column(:'schema', 'routes', 'route_long_name', 'table routes has column route_long_name'); 14 | SELECT col_type_is(:'schema', 'routes', 'route_long_name', 'text', 'column routes.route_long_name is text'); 15 | SELECT has_column(:'schema', 'routes', 'route_desc', 'table routes has column route_desc'); 16 | SELECT col_type_is(:'schema', 'routes', 'route_desc', 'text', 'column routes.route_desc is text'); 17 | SELECT has_column(:'schema', 'routes', 'route_type', 'table routes has column route_type'); 18 | SELECT col_type_is(:'schema', 'routes', 'route_type', 'integer', 'column routes.route_type is integer'); 19 | SELECT has_column(:'schema', 'routes', 'route_url', 'table routes has column route_url'); 20 | SELECT col_type_is(:'schema', 'routes', 'route_url', 'text', 'column routes.route_url is text'); 21 | SELECT has_column(:'schema', 'routes', 'route_color', 'table routes has column route_color'); 22 | SELECT col_type_is(:'schema', 'routes', 'route_color', 'text', 'column routes.route_color is text'); 23 | SELECT has_column(:'schema', 'routes', 'route_text_color', 'table routes has column route_text_color'); 24 | SELECT col_type_is(:'schema', 'routes', 'route_text_color', 'text', 'column routes.route_text_color is text'); 25 | SELECT has_column(:'schema', 'routes', 'route_sort_order', 'table routes has column route_sort_order'); 26 | SELECT col_type_is(:'schema', 'routes', 'route_sort_order', 'integer', 'column routes.route_sort_order is integer'); 27 | SELECT * FROM finish(); 28 | -------------------------------------------------------------------------------- /tests/table-shape_geoms.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, public; 2 | SELECT plan(11); 3 | SELECT has_table(:'schema', 'shape_geoms', 'table shape_geoms exists'); 4 | SELECT has_pk(:'schema', 'shape_geoms', 'table shape_geoms has primary key'); 5 | SELECT has_column(:'schema', 'shape_geoms', 'feed_index', 'table shape_geoms has column feed_index'); 6 | SELECT col_type_is(:'schema', 'shape_geoms', 'feed_index', 'integer', 'column shape_geoms.feed_index is integer'); 7 | SELECT has_column(:'schema', 'shape_geoms', 'shape_id', 'table shape_geoms has column shape_id'); 8 | SELECT col_type_is(:'schema', 'shape_geoms', 'shape_id', 'text', 'column shape_geoms.shape_id is text'); 9 | SELECT has_column(:'schema', 'shape_geoms', 'length', 'table shape_geoms has column length'); 10 | SELECT col_type_is(:'schema', 'shape_geoms', 'length', 'numeric(12,2)', 'column shape_geoms.length is numeric(12,2)'); 11 | SELECT has_column(:'schema', 'shape_geoms', 'the_geom', 'table shape_geoms has column the_geom'); 12 | SELECT col_type_is(:'schema', 'shape_geoms', 'the_geom', 'geometry(LineString,4326)', 'column shape_geoms.the_geom is geometry(LineString,4326)'); 13 | SELECT is_indexed(:'schema', 'shape_geoms', ARRAY['the_geom']); 14 | SELECT * FROM finish(); 15 | -------------------------------------------------------------------------------- /tests/table-shapes.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, public; 2 | SELECT plan(15); 3 | SELECT has_table(:'schema', 'shapes', 'table shapes exists'); 4 | SELECT has_pk(:'schema', 'shapes', 'table shapes has primary key'); 5 | SELECT is_indexed(:'schema', 'shapes', ARRAY['shape_id']); 6 | SELECT has_column(:'schema', 'shapes', 'feed_index', 'table shapes has column feed_index'); 7 | SELECT col_type_is(:'schema', 'shapes', 'feed_index', 'integer', 'column shapes.feed_index is integer'); 8 | SELECT has_column(:'schema', 'shapes', 'shape_id', 'table shapes has column shape_id'); 9 | SELECT col_type_is(:'schema', 'shapes', 'shape_id', 'text', 'column shapes.shape_id is text'); 10 | SELECT has_column(:'schema', 'shapes', 'shape_pt_lat', 'table shapes has column shape_pt_lat'); 11 | SELECT col_type_is(:'schema', 'shapes', 'shape_pt_lat', 'double precision', 'column shapes.shape_pt_lat is double precision'); 12 | SELECT has_column(:'schema', 'shapes', 'shape_pt_lon', 'table shapes has column shape_pt_lon'); 13 | SELECT col_type_is(:'schema', 'shapes', 'shape_pt_lon', 'double precision', 'column shapes.shape_pt_lon is double precision'); 14 | SELECT has_column(:'schema', 'shapes', 'shape_pt_sequence', 'table shapes has column shape_pt_sequence'); 15 | SELECT col_type_is(:'schema', 'shapes', 'shape_pt_sequence', 'integer', 'column shapes.shape_pt_sequence is integer'); 16 | SELECT has_column(:'schema', 'shapes', 'shape_dist_traveled', 'table shapes has column shape_dist_traveled'); 17 | SELECT col_type_is(:'schema', 'shapes', 'shape_dist_traveled', 'double precision', 'column shapes.shape_dist_traveled is double precision'); 18 | SELECT * FROM finish(); 19 | -------------------------------------------------------------------------------- /tests/table-stop_times.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, public; 2 | SELECT plan(35); 3 | SELECT has_table(:'schema', 'stop_times', 'table stop_times exists'); 4 | SELECT has_pk(:'schema', 'stop_times', 'table stop_times has primary key'); 5 | SELECT is_indexed(:'schema', 'stop_times', ARRAY['feed_index', 'trip_id', 'stop_id']); 6 | SELECT is_indexed(:'schema', 'stop_times', ARRAY['arrival_time_seconds']); 7 | SELECT is_indexed(:'schema', 'stop_times', ARRAY['departure_time_seconds']); 8 | SELECT has_column(:'schema', 'stop_times', 'feed_index', 'table stop_times has column feed_index'); 9 | SELECT col_type_is(:'schema', 'stop_times', 'feed_index', 'integer', 'column stop_times.feed_index is integer'); 10 | SELECT has_column(:'schema', 'stop_times', 'trip_id', 'table stop_times has column trip_id'); 11 | SELECT col_type_is(:'schema', 'stop_times', 'trip_id', 'text', 'column stop_times.trip_id is text'); 12 | SELECT has_column(:'schema', 'stop_times', 'arrival_time', 'table stop_times has column arrival_time'); 13 | SELECT col_type_is(:'schema', 'stop_times', 'arrival_time', 'interval', 'column stop_times.arrival_time is interval'); 14 | SELECT has_column(:'schema', 'stop_times', 'departure_time', 'table stop_times has column departure_time'); 15 | SELECT col_type_is(:'schema', 'stop_times', 'departure_time', 'interval', 'column stop_times.departure_time is interval'); 16 | SELECT has_column(:'schema', 'stop_times', 'stop_id', 'table stop_times has column stop_id'); 17 | SELECT col_type_is(:'schema', 'stop_times', 'stop_id', 'text', 'column stop_times.stop_id is text'); 18 | SELECT has_column(:'schema', 'stop_times', 'stop_sequence', 'table stop_times has column stop_sequence'); 19 | SELECT col_type_is(:'schema', 'stop_times', 'stop_sequence', 'integer', 'column stop_times.stop_sequence is integer'); 20 | SELECT has_column(:'schema', 'stop_times', 'stop_headsign', 'table stop_times has column stop_headsign'); 21 | SELECT col_type_is(:'schema', 'stop_times', 'stop_headsign', 'text', 'column stop_times.stop_headsign is text'); 22 | SELECT has_column(:'schema', 'stop_times', 'pickup_type', 'table stop_times has column pickup_type'); 23 | SELECT col_type_is(:'schema', 'stop_times', 'pickup_type', 'integer', 'column stop_times.pickup_type is integer'); 24 | SELECT has_column(:'schema', 'stop_times', 'drop_off_type', 'table stop_times has column drop_off_type'); 25 | SELECT col_type_is(:'schema', 'stop_times', 'drop_off_type', 'integer', 'column stop_times.drop_off_type is integer'); 26 | SELECT has_column(:'schema', 'stop_times', 'shape_dist_traveled', 'table stop_times has column shape_dist_traveled'); 27 | SELECT col_type_is(:'schema', 'stop_times', 'shape_dist_traveled', 'numeric(10,2)', 'column stop_times.shape_dist_traveled is numeric(10,2)'); 28 | SELECT has_column(:'schema', 'stop_times', 'timepoint', 'table stop_times has column timepoint'); 29 | SELECT col_type_is(:'schema', 'stop_times', 'timepoint', 'integer', 'column stop_times.timepoint is integer'); 30 | SELECT has_column(:'schema', 'stop_times', 'continuous_drop_off', 'table stop_times has column continuous_drop_off'); 31 | SELECT col_type_is(:'schema', 'stop_times', 'continuous_drop_off', 'integer', 'column stop_times.continuous_drop_off is integer'); 32 | SELECT has_column(:'schema', 'stop_times', 'continuous_pickup', 'table stop_times has column continuous_pickup'); 33 | SELECT col_type_is(:'schema', 'stop_times', 'continuous_pickup', 'integer', 'column stop_times.continuous_pickup is integer'); 34 | SELECT has_column(:'schema', 'stop_times', 'arrival_time_seconds', 'table stop_times has column arrival_time_seconds'); 35 | SELECT col_type_is(:'schema', 'stop_times', 'arrival_time_seconds', 'integer', 'column stop_times.arrival_time_seconds is integer'); 36 | SELECT has_column(:'schema', 'stop_times', 'departure_time_seconds', 'table stop_times has column departure_time_seconds'); 37 | SELECT col_type_is(:'schema', 'stop_times', 'departure_time_seconds', 'integer', 'column stop_times.departure_time_seconds is integer'); 38 | SELECT * FROM finish(); 39 | -------------------------------------------------------------------------------- /tests/table-stops.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, public; 2 | SELECT plan(51); 3 | SELECT has_table(:'schema', 'stops', 'table stops exists'); 4 | SELECT has_pk(:'schema', 'stops', 'table stops has primary key'); 5 | SELECT has_column(:'schema', 'stops', 'feed_index', 'table stops has column feed_index'); 6 | SELECT col_type_is(:'schema', 'stops', 'feed_index', 'integer', 'column stops.feed_index is integer'); 7 | SELECT has_column(:'schema', 'stops', 'stop_id', 'table stops has column stop_id'); 8 | SELECT col_type_is(:'schema', 'stops', 'stop_id', 'text', 'column stops.stop_id is text'); 9 | SELECT has_column(:'schema', 'stops', 'stop_name', 'table stops has column stop_name'); 10 | SELECT col_type_is(:'schema', 'stops', 'stop_name', 'text', 'column stops.stop_name is text'); 11 | SELECT has_column(:'schema', 'stops', 'stop_desc', 'table stops has column stop_desc'); 12 | SELECT col_type_is(:'schema', 'stops', 'stop_desc', 'text', 'column stops.stop_desc is text'); 13 | SELECT has_column(:'schema', 'stops', 'stop_lat', 'table stops has column stop_lat'); 14 | SELECT col_type_is(:'schema', 'stops', 'stop_lat', 'double precision', 'column stops.stop_lat is double precision'); 15 | SELECT has_column(:'schema', 'stops', 'stop_lon', 'table stops has column stop_lon'); 16 | SELECT col_type_is(:'schema', 'stops', 'stop_lon', 'double precision', 'column stops.stop_lon is double precision'); 17 | SELECT has_column(:'schema', 'stops', 'zone_id', 'table stops has column zone_id'); 18 | SELECT col_type_is(:'schema', 'stops', 'zone_id', 'text', 'column stops.zone_id is text'); 19 | SELECT has_column(:'schema', 'stops', 'stop_url', 'table stops has column stop_url'); 20 | SELECT col_type_is(:'schema', 'stops', 'stop_url', 'text', 'column stops.stop_url is text'); 21 | SELECT has_column(:'schema', 'stops', 'stop_code', 'table stops has column stop_code'); 22 | SELECT col_type_is(:'schema', 'stops', 'stop_code', 'text', 'column stops.stop_code is text'); 23 | SELECT has_column(:'schema', 'stops', 'stop_street', 'table stops has column stop_street'); 24 | SELECT col_type_is(:'schema', 'stops', 'stop_street', 'text', 'column stops.stop_street is text'); 25 | SELECT has_column(:'schema', 'stops', 'stop_city', 'table stops has column stop_city'); 26 | SELECT col_type_is(:'schema', 'stops', 'stop_city', 'text', 'column stops.stop_city is text'); 27 | SELECT has_column(:'schema', 'stops', 'stop_region', 'table stops has column stop_region'); 28 | SELECT col_type_is(:'schema', 'stops', 'stop_region', 'text', 'column stops.stop_region is text'); 29 | SELECT has_column(:'schema', 'stops', 'stop_postcode', 'table stops has column stop_postcode'); 30 | SELECT col_type_is(:'schema', 'stops', 'stop_postcode', 'text', 'column stops.stop_postcode is text'); 31 | SELECT has_column(:'schema', 'stops', 'stop_country', 'table stops has column stop_country'); 32 | SELECT col_type_is(:'schema', 'stops', 'stop_country', 'text', 'column stops.stop_country is text'); 33 | SELECT has_column(:'schema', 'stops', 'stop_timezone', 'table stops has column stop_timezone'); 34 | SELECT col_type_is(:'schema', 'stops', 'stop_timezone', 'text', 'column stops.stop_timezone is text'); 35 | SELECT has_column(:'schema', 'stops', 'direction', 'table stops has column direction'); 36 | SELECT col_type_is(:'schema', 'stops', 'direction', 'text', 'column stops.direction is text'); 37 | SELECT has_column(:'schema', 'stops', 'position', 'table stops has column position'); 38 | SELECT col_type_is(:'schema', 'stops', 'position', 'text', 'column stops.position is text'); 39 | SELECT has_column(:'schema', 'stops', 'parent_station', 'table stops has column parent_station'); 40 | SELECT col_type_is(:'schema', 'stops', 'parent_station', 'text', 'column stops.parent_station is text'); 41 | SELECT has_column(:'schema', 'stops', 'wheelchair_boarding', 'table stops has column wheelchair_boarding'); 42 | SELECT col_type_is(:'schema', 'stops', 'wheelchair_boarding', 'integer', 'column stops.wheelchair_boarding is integer'); 43 | SELECT has_column(:'schema', 'stops', 'wheelchair_accessible', 'table stops has column wheelchair_accessible'); 44 | SELECT col_type_is(:'schema', 'stops', 'wheelchair_accessible', 'integer', 'column stops.wheelchair_accessible is integer'); 45 | SELECT has_column(:'schema', 'stops', 'location_type', 'table stops has column location_type'); 46 | SELECT col_type_is(:'schema', 'stops', 'location_type', 'integer', 'column stops.location_type is integer'); 47 | SELECT has_column(:'schema', 'stops', 'vehicle_type', 'table stops has column vehicle_type'); 48 | SELECT col_type_is(:'schema', 'stops', 'vehicle_type', 'integer', 'column stops.vehicle_type is integer'); 49 | SELECT has_column(:'schema', 'stops', 'platform_code', 'table stops has column platform_code'); 50 | SELECT col_type_is(:'schema', 'stops', 'platform_code', 'text', 'column stops.platform_code is text'); 51 | SELECT has_column(:'schema', 'stops', 'the_geom', 'table stops has column the_geom'); 52 | SELECT col_type_is(:'schema', 'stops', 'the_geom', 'geometry(Point,4326)', 'column stops.the_geom is geometry(Point,4326)'); 53 | SELECT is_indexed(:'schema', 'stops', ARRAY['the_geom']); 54 | SELECT * FROM finish(); 55 | -------------------------------------------------------------------------------- /tests/table-transfers.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, public; 2 | SELECT plan(18); 3 | SELECT has_table(:'schema', 'transfers', 'table transfers exists'); 4 | SELECT has_pk(:'schema', 'transfers', 'table transfers has primary key'); 5 | SELECT has_column(:'schema', 'transfers', 'feed_index', 'table transfers has column feed_index'); 6 | SELECT col_type_is(:'schema', 'transfers', 'feed_index', 'integer', 'column transfers.feed_index is integer'); 7 | SELECT has_column(:'schema', 'transfers', 'from_stop_id', 'table transfers has column from_stop_id'); 8 | SELECT col_type_is(:'schema', 'transfers', 'from_stop_id', 'text', 'column transfers.from_stop_id is text'); 9 | SELECT has_column(:'schema', 'transfers', 'to_stop_id', 'table transfers has column to_stop_id'); 10 | SELECT col_type_is(:'schema', 'transfers', 'to_stop_id', 'text', 'column transfers.to_stop_id is text'); 11 | SELECT has_column(:'schema', 'transfers', 'transfer_type', 'table transfers has column transfer_type'); 12 | SELECT col_type_is(:'schema', 'transfers', 'transfer_type', 'integer', 'column transfers.transfer_type is integer'); 13 | SELECT has_column(:'schema', 'transfers', 'min_transfer_time', 'table transfers has column min_transfer_time'); 14 | SELECT col_type_is(:'schema', 'transfers', 'min_transfer_time', 'integer', 'column transfers.min_transfer_time is integer'); 15 | SELECT has_column(:'schema', 'transfers', 'from_route_id', 'table transfers has column from_route_id'); 16 | SELECT col_type_is(:'schema', 'transfers', 'from_route_id', 'text', 'column transfers.from_route_id is text'); 17 | SELECT has_column(:'schema', 'transfers', 'to_route_id', 'table transfers has column to_route_id'); 18 | SELECT col_type_is(:'schema', 'transfers', 'to_route_id', 'text', 'column transfers.to_route_id is text'); 19 | SELECT has_column(:'schema', 'transfers', 'service_id', 'table transfers has column service_id'); 20 | SELECT col_type_is(:'schema', 'transfers', 'service_id', 'text', 'column transfers.service_id is text'); 21 | SELECT * FROM finish(); 22 | -------------------------------------------------------------------------------- /tests/table-translations.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | SET search_path TO tap, public; 3 | SELECT plan(35); 4 | 5 | SELECT has_table( 6 | :'schema', 'translations', 7 | 'Should have table gtfs.translations' 8 | ); 9 | 10 | SELECT has_pk( 11 | :'schema', 'translations', 12 | 'Table gtfs.translations should have a primary key' 13 | ); 14 | 15 | SELECT columns_are(:'schema'::name, 'translations'::name, ARRAY[ 16 | 'feed_index'::name, 17 | 'table_name'::name, 18 | 'field_name'::name, 19 | 'language'::name, 20 | 'translation'::name, 21 | 'record_id'::name, 22 | 'record_sub_id'::name, 23 | 'field_value'::name 24 | ]); 25 | 26 | SELECT has_column( :'schema', 'translations', 'feed_index', 'Column gtfs.translations.feed_index should exist'); 27 | SELECT col_type_is( :'schema', 'translations', 'feed_index', 'integer', 'Column gtfs.translations.feed_index should be type integer'); 28 | SELECT col_not_null( :'schema', 'translations', 'feed_index', 'Column gtfs.translations.feed_index should be NOT NULL'); 29 | SELECT col_hasnt_default(:'schema', 'translations', 'feed_index', 'Column gtfs.translations.feed_index should not have a default'); 30 | 31 | SELECT has_column( :'schema', 'translations', 'table_name', 'Column gtfs.translations.table_name should exist'); 32 | SELECT col_type_is( :'schema', 'translations', 'table_name', 'text', 'Column gtfs.translations.table_name should be type text'); 33 | SELECT col_not_null( :'schema', 'translations', 'table_name', 'Column gtfs.translations.table_name should be NOT NULL'); 34 | SELECT col_hasnt_default(:'schema', 'translations', 'table_name', 'Column gtfs.translations.table_name should not have a default'); 35 | 36 | SELECT has_column( :'schema', 'translations', 'field_name', 'Column gtfs.translations.field_name should exist'); 37 | SELECT col_type_is( :'schema', 'translations', 'field_name', 'text', 'Column gtfs.translations.field_name should be type text'); 38 | SELECT col_not_null( :'schema', 'translations', 'field_name', 'Column gtfs.translations.field_name should not allow NULL'); 39 | SELECT col_hasnt_default(:'schema', 'translations', 'field_name', 'Column gtfs.translations.field_name should not have a default'); 40 | 41 | SELECT has_column( :'schema', 'translations', 'language', 'Column gtfs.translations.language should exist'); 42 | SELECT col_type_is( :'schema', 'translations', 'language', 'text', 'Column gtfs.translations.language should be type text'); 43 | SELECT col_not_null( :'schema', 'translations', 'language', 'Column gtfs.translations.language should be NOT NULL'); 44 | SELECT col_hasnt_default(:'schema', 'translations', 'language', 'Column gtfs.translations.language should not have a default'); 45 | 46 | SELECT has_column( :'schema', 'translations', 'translation', 'Column gtfs.translations.translation should exist'); 47 | SELECT col_type_is( :'schema', 'translations', 'translation', 'text', 'Column gtfs.translations.translation should be type text'); 48 | SELECT col_not_null( :'schema', 'translations', 'translation', 'Column gtfs.translations.translation should not allow NULL'); 49 | SELECT col_hasnt_default(:'schema', 'translations', 'translation', 'Column gtfs.translations.translation should not have a default'); 50 | 51 | SELECT has_column( :'schema', 'translations', 'record_id', 'Column gtfs.translations.record_id should exist'); 52 | SELECT col_type_is( :'schema', 'translations', 'record_id', 'text', 'Column gtfs.translations.record_id should be type text'); 53 | SELECT col_is_null( :'schema', 'translations', 'record_id', 'Column gtfs.translations.record_id should allow NULL'); 54 | SELECT col_hasnt_default(:'schema', 'translations', 'record_id', 'Column gtfs.translations.record_id should not have a default'); 55 | 56 | SELECT has_column( :'schema', 'translations', 'record_sub_id', 'Column gtfs.translations.record_sub_id should exist'); 57 | SELECT col_type_is( :'schema', 'translations', 'record_sub_id', 'text', 'Column gtfs.translations.record_sub_id should be type text'); 58 | SELECT col_is_null( :'schema', 'translations', 'record_sub_id', 'Column gtfs.translations.record_sub_id should allow NULL'); 59 | SELECT col_hasnt_default(:'schema', 'translations', 'record_sub_id', 'Column gtfs.translations.record_sub_id should not have a default'); 60 | 61 | SELECT has_column( :'schema', 'translations', 'field_value', 'Column gtfs.translations.field_value should exist'); 62 | SELECT col_type_is( :'schema', 'translations', 'field_value', 'text', 'Column gtfs.translations.field_value should be type text'); 63 | SELECT col_not_null( :'schema', 'translations', 'field_value', 'Column gtfs.translations.field_value should be NOT NULL'); 64 | SELECT col_hasnt_default(:'schema', 'translations', 'field_value', 'Column gtfs.translations.field_value should not have a default'); 65 | 66 | SELECT * FROM finish(); 67 | ROLLBACK; 68 | -------------------------------------------------------------------------------- /tests/table-trips.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, public; 2 | SELECT plan(33); 3 | SELECT has_table(:'schema', 'trips', 'table trips exists'); 4 | SELECT has_pk(:'schema', 'trips', 'table trips has primary key'); 5 | SELECT is_indexed(:'schema', 'trips', ARRAY['feed_index', 'service_id']); 6 | SELECT has_column(:'schema', 'trips', 'feed_index', 'table trips has column feed_index'); 7 | SELECT col_type_is(:'schema', 'trips', 'feed_index', 'integer', 'column trips.feed_index is integer'); 8 | SELECT has_column(:'schema', 'trips', 'route_id', 'table trips has column route_id'); 9 | SELECT col_type_is(:'schema', 'trips', 'route_id', 'text', 'column trips.route_id is text'); 10 | SELECT has_column(:'schema', 'trips', 'service_id', 'table trips has column service_id'); 11 | SELECT col_type_is(:'schema', 'trips', 'service_id', 'text', 'column trips.service_id is text'); 12 | SELECT has_column(:'schema', 'trips', 'trip_id', 'table trips has column trip_id'); 13 | SELECT col_type_is(:'schema', 'trips', 'trip_id', 'text', 'column trips.trip_id is text'); 14 | SELECT has_column(:'schema', 'trips', 'trip_headsign', 'table trips has column trip_headsign'); 15 | SELECT col_type_is(:'schema', 'trips', 'trip_headsign', 'text', 'column trips.trip_headsign is text'); 16 | SELECT has_column(:'schema', 'trips', 'direction_id', 'table trips has column direction_id'); 17 | SELECT col_type_is(:'schema', 'trips', 'direction_id', 'integer', 'column trips.direction_id is integer'); 18 | SELECT has_column(:'schema', 'trips', 'block_id', 'table trips has column block_id'); 19 | SELECT col_type_is(:'schema', 'trips', 'block_id', 'text', 'column trips.block_id is text'); 20 | SELECT has_column(:'schema', 'trips', 'shape_id', 'table trips has column shape_id'); 21 | SELECT col_type_is(:'schema', 'trips', 'shape_id', 'text', 'column trips.shape_id is text'); 22 | SELECT has_column(:'schema', 'trips', 'trip_short_name', 'table trips has column trip_short_name'); 23 | SELECT col_type_is(:'schema', 'trips', 'trip_short_name', 'text', 'column trips.trip_short_name is text'); 24 | SELECT has_column(:'schema', 'trips', 'wheelchair_accessible', 'table trips has column wheelchair_accessible'); 25 | SELECT col_type_is(:'schema', 'trips', 'wheelchair_accessible', 'integer', 'column trips.wheelchair_accessible is integer'); 26 | SELECT has_column(:'schema', 'trips', 'direction', 'table trips has column direction'); 27 | SELECT col_type_is(:'schema', 'trips', 'direction', 'text', 'column trips.direction is text'); 28 | SELECT has_column(:'schema', 'trips', 'schd_trip_id', 'table trips has column schd_trip_id'); 29 | SELECT col_type_is(:'schema', 'trips', 'schd_trip_id', 'text', 'column trips.schd_trip_id is text'); 30 | SELECT has_column(:'schema', 'trips', 'trip_type', 'table trips has column trip_type'); 31 | SELECT col_type_is(:'schema', 'trips', 'trip_type', 'text', 'column trips.trip_type is text'); 32 | SELECT has_column(:'schema', 'trips', 'exceptional', 'table trips has column exceptional'); 33 | SELECT col_type_is(:'schema', 'trips', 'exceptional', 'integer', 'column trips.exceptional is integer'); 34 | SELECT has_column(:'schema', 'trips', 'bikes_allowed', 'table trips has column bikes_allowed'); 35 | SELECT col_type_is(:'schema', 'trips', 'bikes_allowed', 'integer', 'column trips.bikes_allowed is integer'); 36 | SELECT * FROM finish(); 37 | -------------------------------------------------------------------------------- /tests/validity/calendar.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, :schema, public; 2 | SELECT plan(2); 3 | 4 | SELECT set_eq( 5 | format('SELECT distinct service_id 6 | FROM calendar_dates 7 | LEFT JOIN calendar b USING (feed_index, service_id) 8 | WHERE b.service_id IS NULL 9 | AND feed_index = %s', 10 | :feed_index 11 | ), 12 | ARRAY[]::text[], 13 | 'calendar_dates_service_id_fkey would be valid' 14 | ); 15 | 16 | SELECT set_eq( 17 | format('SELECT distinct service_id 18 | FROM trips a LEFT JOIN calendar b USING (feed_index, service_id) 19 | WHERE b.service_id IS NULL AND feed_index = %s', 20 | :feed_index 21 | ), 22 | ARRAY[]::text[], 23 | 'trips_calendar_fkey would be valid' 24 | ); 25 | 26 | SELECT * FROM finish(); 27 | -------------------------------------------------------------------------------- /tests/validity/exists.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Check that required tables aren't empty for the given feed_index 3 | Arguments 4 | --------- 5 | :schema: typically `gtfs` 6 | :feed_index: A feed index to check 7 | */ 8 | SET search_path TO tap, public; 9 | SELECT plan(20); 10 | 11 | SELECT isnt_empty( 12 | format('SELECT FROM %I.%I WHERE feed_index = %s', :'schema', table_name, :feed_index), 13 | table_name || ' has data for feed_index = ' || :'feed_index' 14 | ) FROM unnest(ARRAY[ 15 | 'feed_info', 16 | 'agency', 17 | 'routes', 18 | 'stops', 19 | 'trips', 20 | 'stop_times' 21 | ]) table_name; 22 | 23 | SELECT collect_tap( 24 | ok(feed_end_date is not null, 'feed_info.feed_end_date exists for feed_index = '|| :'feed_index'), 25 | ok(feed_start_date is not null, 'feed_info.feed_start_date exists for feed_index = ' || :'feed_index') 26 | ) 27 | FROM :schema.feed_info WHERE feed_index = :feed_index; 28 | 29 | -- These tables are optional or only conditionally required 30 | SELECT todo(12); 31 | SELECT isnt_empty( 32 | format('SELECT FROM %I.%I WHERE feed_index = %s', :'schema', table_name, :feed_index), 33 | table_name || ' has data for feed_index = ' || :'feed_index' 34 | ) FROM unnest(ARRAY[ 35 | 'calendar', 36 | 'calendar_dates', 37 | 'fare_attributes', 38 | 'fare_rules', 39 | 'shapes', 40 | 'shape_geoms', 41 | 'frequencies', 42 | 'transfers', 43 | 'pathways', 44 | 'levels', 45 | 'translations', 46 | 'attributions' 47 | ]) table_name; 48 | 49 | SELECT * FROM finish(); 50 | -------------------------------------------------------------------------------- /tests/validity/fares.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, :schema, public; 2 | 3 | SELECT plan(4); 4 | 5 | SELECT set_eq( 6 | format( 7 | 'SELECT distinct agency_id 8 | FROM fare_attributes a LEFT JOIN agency b USING (feed_index, agency_id) 9 | WHERE b.agency_id IS NULL AND feed_index = %s', 10 | :feed_index 11 | ), 12 | ARRAY[]::text[], 13 | 'fare_attributes_fkey would be valid' 14 | ); 15 | 16 | SELECT set_eq( 17 | format('SELECT distinct service_id 18 | FROM fare_rules a LEFT JOIN calendar b USING (feed_index, service_id) 19 | WHERE b.service_id IS NULL AND feed_index = %s', 20 | :feed_index 21 | ), 22 | ARRAY[]::text[], 23 | 'fare_rules_service_fkey would be valid' 24 | ); 25 | 26 | SELECT set_eq( 27 | format('SELECT distinct route_id 28 | FROM fare_rules a 29 | LEFT JOIN routes b USING (feed_index, route_id) 30 | WHERE b.route_id IS NULL 31 | AND feed_index = %s', 32 | :feed_index 33 | ), 34 | ARRAY[]::text[], 35 | 'fare_rules_route_id_fkey would be valid' 36 | ); 37 | 38 | SELECT set_eq( 39 | format( 40 | 'SELECT distinct fare_id 41 | FROM fare_rules a LEFT JOIN fare_attributes b USING (feed_index, fare_id) 42 | WHERE b.fare_id IS NULL AND feed_index = %s', 43 | :feed_index 44 | ), 45 | ARRAY[]::text[], 46 | 'fare_rules_fare_id_fkey would be valid' 47 | ); 48 | 49 | SELECT * FROM finish(); -------------------------------------------------------------------------------- /tests/validity/frequencies_trip_fkey.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, :schema, public; 2 | 3 | SELECT plan(1); 4 | 5 | SELECT set_eq( 6 | format('SELECT distinct trip_id 7 | FROM frequencies a 8 | LEFT JOIN trips b USING (feed_index, trip_id) 9 | WHERE b.trip_id IS NULL 10 | AND feed_index = %s', 11 | :feed_index 12 | ), 13 | ARRAY[]::text[], 14 | 'frequencies_trip_fkey would be valid' 15 | ); 16 | 17 | SELECT * FROM finish(); -------------------------------------------------------------------------------- /tests/validity/routes.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, :schema, public; 2 | 3 | SELECT plan(2); 4 | 5 | SELECT set_eq( 6 | format('SELECT DISTINCT route_type 7 | FROM routes a LEFT JOIN route_types b USING (route_type) 8 | WHERE a.route_type IS NOT NULL AND b.route_type IS NULL AND feed_index = %s', 9 | :feed_index 10 | ), 11 | ARRAY[]::integer[], 12 | 'route_types_fkey would be valid' 13 | ); 14 | 15 | SELECT set_eq( 16 | format('SELECT distinct agency_id 17 | FROM routes a 18 | LEFT JOIN agency b USING (feed_index, agency_id) 19 | WHERE b.agency_id IS NULL 20 | AND feed_index = %s', 21 | :feed_index 22 | ), 23 | ARRAY[]::text[], 'routes_agency_id_fkey would be valid' 24 | ); 25 | 26 | SELECT * FROM finish(); -------------------------------------------------------------------------------- /tests/validity/stop_geometry.sql: -------------------------------------------------------------------------------- 1 | /* 2 | Arguments 3 | --------- 4 | :schema: typically `gtfs` 5 | :feed_index: A feed index to check 6 | */ 7 | SET search_path TO tap, :schema, public; 8 | 9 | SELECT plan(1); 10 | 11 | SELECT set_eq( 12 | format('SELECT DISTINCT trip_id 13 | FROM ( 14 | SELECT 15 | feed_index, 16 | trip_id, 17 | stop_id, 18 | stop_sequence, 19 | coalesce(lag(shape_dist_traveled) over (trip), 0) AS lag, 20 | shape_dist_traveled AS dist, 21 | (lead(shape_dist_traveled) over (trip)) AS lead 22 | FROM stop_times 23 | WHERE feed_index = %s 24 | WINDOW trip AS (PARTITION BY feed_index, trip_id ORDER BY stop_sequence) 25 | ) AS d 26 | LEFT JOIN trips trip USING (feed_index, trip_id) 27 | LEFT JOIN shape_geoms shape USING (feed_index, shape_id) 28 | WHERE COALESCE(lead, length) > lag AND (dist > COALESCE(lead, length) OR dist < lag)', 29 | :feed_index 30 | ), 31 | ARRAY[]::text[], 32 | 'No trips with out-of-order stops' 33 | ); 34 | 35 | SELECT * FROM finish(); 36 | -------------------------------------------------------------------------------- /tests/validity/stop_times.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, :schema, public; 2 | 3 | SELECT plan(2); 4 | 5 | SELECT set_eq( 6 | format('SELECT distinct stop_id 7 | FROM stop_times a 8 | LEFT JOIN stops b USING (feed_index, stop_id) 9 | WHERE b.stop_id IS NULL 10 | AND feed_index = %s', 11 | :feed_index 12 | ), 13 | ARRAY[]::text[], 14 | 'stop_times_stops_fkey would be valid' 15 | ); 16 | 17 | SELECT set_eq( 18 | format('SELECT distinct trip_id 19 | FROM stop_times a 20 | LEFT JOIN trips b USING (feed_index, trip_id) 21 | WHERE b.trip_id IS NULL 22 | AND feed_index = %s', 23 | :feed_index 24 | ), 25 | ARRAY[]::text[], 26 | 'stop_times_trips_fkey would be valid' 27 | ); 28 | 29 | SELECT * from finish(); -------------------------------------------------------------------------------- /tests/validity/transfers.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, :schema, public; 2 | 3 | SELECT plan(4); 4 | 5 | SELECT set_eq( 6 | format('SELECT distinct from_stop_id 7 | FROM transfers a 8 | LEFT JOIN stops b on a.feed_index = b.feed_index and a.from_stop_id::text = b.stop_id::text 9 | WHERE b.stop_id IS NULL 10 | AND a.feed_index = %s', 11 | :feed_index 12 | ), 13 | ARRAY[]::text[], 14 | 'transfers_from_stop_fkey would be valid'); 15 | 16 | SELECT set_eq( 17 | format('SELECT distinct to_stop_id 18 | FROM transfers a 19 | LEFT JOIN stops b on a.feed_index = b.feed_index and a.to_stop_id::text = b.stop_id::text 20 | WHERE b.stop_id IS NULL 21 | AND a.feed_index = %s', 22 | :feed_index 23 | ), 24 | ARRAY[]::text[], 25 | 'transfers_to_stop_fkey would be valid'); 26 | 27 | SELECT set_eq( 28 | format('SELECT distinct from_route_id 29 | FROM transfers a 30 | LEFT JOIN routes b on a.feed_index = b.feed_index and a.from_route_id::text = b.route_id::text 31 | WHERE b.route_id IS NULL 32 | AND a.feed_index = %s', 33 | :feed_index 34 | ), 35 | ARRAY[]::text[], 36 | 'transfers_from_route_fkey would be valid'); 37 | 38 | SELECT set_eq( 39 | format('SELECT distinct to_route_id 40 | FROM transfers a 41 | LEFT JOIN routes b on a.feed_index = b.feed_index and a.to_route_id::text = b.route_id::text 42 | WHERE b.route_id IS NULL 43 | AND a.feed_index = %s', 44 | :feed_index 45 | ), 46 | ARRAY[]::text[], 47 | 'transfers_to_route_fkey would be valid'); 48 | 49 | SELECT * from finish(); 50 | -------------------------------------------------------------------------------- /tests/validity/trips_route_id_fkey.sql: -------------------------------------------------------------------------------- 1 | SET search_path TO tap, :schema, public; 2 | SELECT plan(1); 3 | 4 | SELECT set_eq( 5 | format('SELECT distinct route_id 6 | FROM trips a LEFT JOIN routes b USING (feed_index, route_id) 7 | WHERE b.route_id IS NULL AND feed_index = %s', 8 | :feed_index 9 | ), 10 | ARRAY[]::text[], 11 | 'trips_route_id_fkey would be valid' 12 | ); 13 | 14 | SELECT * from finish(); --------------------------------------------------------------------------------