Skip to content
New issue

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

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

Already on GitHub? Sign in to your account

[TECH] Ingérer et extraire les données provenant de GTFS #1

Merged
merged 21 commits into from
Apr 14, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
17 changes: 5 additions & 12 deletions .github/workflows/cd.yml
Original file line number Diff line number Diff line change
Expand Up @@ -4,9 +4,11 @@ permissions:
contents: write

on:
push:
branches:
- main
workflow_run:
workflows: [ci]
branches: [main]
types:
- completed
repository_dispatch:
types: [deploy]
workflow_dispatch:
Expand All @@ -30,15 +32,6 @@ jobs:
- name: Install
run: npm ci

- name: Lint
run: npm run lint

- name: Test
run: npm test

- name: Build
run: npm run build

- name: Semantic Release
id: semantic
uses: cycjimmy/semantic-release-action@v4
Expand Down
50 changes: 50 additions & 0 deletions .github/workflows/ci.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,50 @@
name: ci

on:
push:
branches:
- main
pull_request:
branches:
- main
repository_dispatch:
types: [ci]
workflow_dispatch:

jobs:
ci:
runs-on: ubuntu-latest

services:
postgres:
image: postgres
env:
POSTGRES_PASSWORD: postgres
options: >-
--health-cmd pg_isready
--health-interval 10s
--health-timeout 5s
--health-retries 5
ports:
- 5432:5432

steps:
- name: Checkout
uses: actions/checkout@v4

- name: Setup Node
uses: actions/setup-node@v4
with:
node-version: 20

- name: Install
run: npm ci

- name: Lint
run: npm run lint

- name: Test
run: npm test
env:
NODE_ENV: test
TEST_DATABASE_URL: postgres://postgres:postgres@localhost:5432/idfm_test
95 changes: 95 additions & 0 deletions db/knex-database-connection.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,95 @@
import process from 'node:process';
import pg from 'pg';
import Knex from 'knex';
import * as knexConfigs from './knexfile.js';

/*
By default, node-postgres casts a DATE value (PostgreSQL type) as a Date Object (JS type).
But, when dealing with dates with no time (such as birthdate for example), we want to
deal with a 'YYYY-MM-DD' string.
*/
pg.types.setTypeParser(pg.types.builtins.DATE, value => value);

/*
The method Bookshelf.Model.count(), used with PostgreSQL, can sometimes returns a BIGINT.
This is not the common case (maybe in several years).
Even though, Bookshelf/Knex have decided to return String.
We decided to parse the result of #count() method to force a resulting INTEGER.

Links :
- problem: https://github.com/bookshelf/bookshelf/issues/1275
- solution: https://github.com/brianc/node-pg-types
*/
pg.types.setTypeParser(pg.types.builtins.INT8, value => Number.parseInt(value));

const environment = process.env.NODE_ENV === 'test' ? 'test' : 'production';
const knexConfig = knexConfigs.default[environment];
export const knex = Knex(knexConfig);

const _databaseName = knex.client.database();

const _dbSpecificQueries = {
listTablesQuery: 'SELECT table_name FROM information_schema.tables WHERE table_schema = current_schema() AND table_catalog = ?',
emptyTableQuery: 'TRUNCATE ',
};

export async function listAllTableNames() {
const bindings = [_databaseName];
const query = _dbSpecificQueries.listTablesQuery;

const resultSet = await knex.raw(query, bindings);

const rows = resultSet.rows;
return rows.map(row => row.table_name);
}

export async function emptyAllTables() {
const tableNames = await listAllTableNames();
const tablesToDelete = tableNames.filter(name => !['knex_migrations', 'knex_migrations_lock'].includes(name));

const tables = tablesToDelete.map(tableToDelete => `"${tableToDelete}"`).join();

const query = _dbSpecificQueries.emptyTableQuery;

return knex.raw(`${query}${tables}`);
}

export async function listTablesByDependencyOrderDesc() {
// See this link : https://stackoverflow.com/questions/51279588/sort-tables-in-order-of-dependency-postgres
const resultSet = await knex.raw('with recursive fk_tree as ( '
+ 'select t.oid as reloid, '
+ 't.relname as table_name, '
+ 's.nspname as schema_name, '
+ 'null::name as referenced_table_name, '
+ 'null::name as referenced_schema_name, '
+ '1 as level '
+ 'from pg_class t '
+ 'join pg_namespace s on s.oid = t.relnamespace '
+ 'where relkind = \'r\' '
+ 'and not exists (select * '
+ 'from pg_constraint '
+ 'where contype = \'f\' '
+ 'and conrelid = t.oid) '
+ 'and s.nspname = \'public\' '
+ 'union all '
+ 'select ref.oid, '
+ 'ref.relname, '
+ 'rs.nspname, '
+ 'p.table_name, '
+ 'p.schema_name, '
+ 'p.level + 1 '
+ 'from pg_class ref '
+ 'join pg_namespace rs on rs.oid = ref.relnamespace '
+ 'join pg_constraint c on c.contype = \'f\' and c.conrelid = ref.oid '
+ 'join fk_tree p on p.reloid = c.confrelid ), all_tables as ( '
+ 'select schema_name, table_name, level, row_number() over (partition by schema_name, table_name order by level desc) as '
+ 'last_table_row from fk_tree ) '
+ 'select table_name '
+ 'from all_tables at where last_table_row = 1 order by level DESC;');

return resultSet.rows.map(row => row.table_name);
}

export async function disconnect() {
return knex.destroy();
}
48 changes: 48 additions & 0 deletions db/knexfile.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,48 @@
import process from 'node:process';
import * as url from 'node:url';
import { config } from 'dotenv';

const __dirname = url.fileURLToPath(new URL('.', import.meta.url));

config({ path: `${__dirname}/../.env` });

function localPostgresEnv(databaseUrl, knexAsyncStacktraceEnabled) {
return {
client: 'postgresql',
connection: databaseUrl,
pool: {
min: 1,
max: 4,
},
migrations: {
tableName: 'knex_migrations',
directory: './migrations',
stub: './migration-template.js',
loadExtensions: ['.js'],
},
asyncStackTraces: knexAsyncStacktraceEnabled !== 'false',
};
}

const environments = {
development: localPostgresEnv(process.env.DATABASE_URL, process.env.KNEX_ASYNC_STACKTRACE_ENABLED),

test: localPostgresEnv(process.env.TEST_DATABASE_URL, process.env.KNEX_ASYNC_STACKTRACE_ENABLED),

production: {
client: 'postgresql',
connection: process.env.DATABASE_URL,
pool: {
min: Number.parseInt(process.env.DATABASE_CONNECTION_POOL_MIN_SIZE, 10) || 1,
max: Number.parseInt(process.env.DATABASE_CONNECTION_POOL_MAX_SIZE, 10) || 4,
},
migrations: {
tableName: 'knex_migrations',
directory: './migrations',
loadExtensions: ['.js'],
},
asyncStackTraces: process.env.KNEX_ASYNC_STACKTRACE_ENABLED !== 'false',
},
};

export default environments;
21 changes: 21 additions & 0 deletions db/migration-template.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
const TABLE_NAME = 'example';

/**
* @param { import("knex").Knex } knex
* @returns { Promise<void> }
*/
export async function up(knex) {
await knex.schema.createTable(TABLE_NAME, (table) => {
// TODO Replace following line by actual up migration
table.increments('id').notNullable();
});
}

/**
* @param { import("knex").Knex } knex
* @returns { Promise<void> }
*/
export async function down(knex) {
// TODO Replace following line by actual down migration
await knex.schema.dropTable(TABLE_NAME);
}
93 changes: 93 additions & 0 deletions db/migrations/20240326115545_add-all-tables.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,93 @@
/**
* @param { import("knex").Knex } knex
* @returns { Promise<void> }
*/
export async function up(knex) {
await knex.schema.createTable('routes', (table) => {
table.text('route_id').primary();
table.text('route_short_name').defaultTo('');
table.text('route_long_name').defaultTo('');
table.text('route_desc').defaultTo('');
table.integer('route_type');
table.text('route_color').notNullable();
table.text('route_text_color').notNullable();
});

await knex.schema.createTable('stops', (table) => {
table.text('stop_id').primary();
table.text('stop_name').notNullable();
table.text('stop_desc').nullable();
table.double('stop_lat').notNullable();
table.double('stop_lon').notNullable();
table.text('zone_id');
table.text('stop_url');
table.text('parent_station');
table.text('platform_code').nullable();
});

await knex.schema.createTable('stop_times', (table) => {
table.text('trip_id').notNullable();
table
.text('arrival_time')
.notNullable();
table.check('??::interval = ??::interval', ['arrival_time', 'arrival_time']);
table
.text('departure_time')
.notNullable();
table.check('??::interval = ??::interval', ['departure_time', 'departure_time']);
table.text('stop_id');
table.integer('stop_sequence').notNullable();
table.integer('pickup_type');
table.integer('drop_off_type');
table.primary(['trip_id', 'stop_sequence']);
table.index(['trip_id', 'stop_id'], 'stop_times_key');
});

await knex.schema.createTable('trips', (table) => {
table.text('route_id').notNullable();
table.text('service_id').notNullable();
table.text('trip_id').notNullable().primary();
table.text('trip_headsign');
table.integer('direction_id');
table.text('block_id');
table.text('shape_id');
table.index('trip_id');
});

await knex.schema.createTable('pathways', (table) => {
table.text('pathway_id').notNullable();
table.text('from_stop_id');
table.text('to_stop_id');
table.text('pathway_mode').notNullable();
table.boolean('is_bidirectional').defaultTo(false);
table.float('length');
table.integer('traversal_time').notNullable();
table.integer('stair_count');
table.float('max_slope');
table.float('min_width');
table.text('signposted_as');
table.text('reversed_signposted_as');
table.primary(['pathway_id']);
});

await knex.schema.createTable('transfers', (table) => {
table.text('from_stop_id').notNullable();
table.text('to_stop_id').notNullable();
table.integer('transfer_type').notNullable();
table.integer('min_transfer_time').notNullable();
table.primary(['from_stop_id', 'to_stop_id']);
});
}

/**
* @param { import("knex").Knex } knex
* @returns { Promise<void> }
*/
export async function down(knex) {
await knex.schema.dropTable('routes');
await knex.schema.dropTable('stops');
await knex.schema.dropTable('stop_times');
await knex.schema.dropTable('trips');
await knex.schema.dropTable('pathways');
await knex.schema.dropTable('transfers');
}
11 changes: 11 additions & 0 deletions db/pgsql-errors.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
const PGSQL_DUPLICATE_DATABASE_ERROR = '42P04';
const PGSQL_NON_EXISTENT_DATABASE_ERROR = '3D000';
const PGSQL_UNIQUE_CONSTRAINT_VIOLATION_ERROR = '23505';
const PGSQL_FOREIGN_KEY_VIOLATION_ERROR = '23503';

export {
PGSQL_DUPLICATE_DATABASE_ERROR,
PGSQL_FOREIGN_KEY_VIOLATION_ERROR,
PGSQL_NON_EXISTENT_DATABASE_ERROR,
PGSQL_UNIQUE_CONSTRAINT_VIOLATION_ERROR,
};
10 changes: 10 additions & 0 deletions docker-compose.yaml
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
version: '3'

services:
postgres:
image: postgres:14.10-alpine
container_name: metro-travel-postgres
ports:
- '${DATABASE_PORT:-5432}:5432'
environment:
POSTGRES_HOST_AUTH_METHOD: trust
2 changes: 2 additions & 0 deletions docs/diary/2024-02-25.md
Original file line number Diff line number Diff line change
Expand Up @@ -45,6 +45,8 @@ qui permet d'afficher la France avec D3.js. Après quelques modifications, j'arr
Après quelques heures, je pense que ce projet est faisable, mes inquiétudes sont sur le fait de relier les stations
entre elles au fur et à mesure que l'utilisateur les essayes.

[EDIT 2023-03-25]: Je découvre que les données d'île-de-France mobilités sont sur un autre site : [PRIM - Plateforme Régionale d'Information Multimodale](https://prim.iledefrance-mobilites.fr/).

## Ressources

- [Travle.earth](https://travle.earth/)
Expand Down
Loading