From 2ec45c15bca664770f6fb200231797c7d69eeb42 Mon Sep 17 00:00:00 2001 From: etwas Date: Sun, 13 Apr 2025 13:39:47 +0200 Subject: [PATCH] feat: add db schema and sqlc config file --- schema.sql | 375 +++++++++++++++++++++++++++++++++++++++++++++++++++++ sqlc.yml | 10 ++ 2 files changed, 385 insertions(+) create mode 100644 schema.sql create mode 100644 sqlc.yml diff --git a/schema.sql b/schema.sql new file mode 100644 index 0000000..e4b8ef1 --- /dev/null +++ b/schema.sql @@ -0,0 +1,375 @@ +create table if not exists stat_locations +( + id text not null + primary key, + latitude double precision, + longitude double precision +); + +alter table stat_locations + owner to rhea; + +create index if not exists stat_locations_latitude_longitude_index + on stat_locations (latitude, longitude); + +grant select on stat_locations to grafana; + +create table if not exists stat_services +( + id text not null + primary key, + bus boolean, + taxi boolean, + tram boolean, + ferry boolean, + subway boolean, + national boolean, + regional boolean, + suburban boolean, + regionalexp boolean, + nationalexp boolean +); + +alter table stat_services + owner to rhea; + +grant select on stat_services to grafana; + +create table if not exists stops +( + id text not null + primary key, + name text, + location_id text + references stat_locations, + service_id text + references stat_services +); + +alter table stops + owner to rhea; + +create index if not exists stops_name_index + on stops (name); + +create index if not exists stops_location_id_index + on stops (location_id); + +grant select on stops to grafana; + +create table if not exists operators +( + id text not null + primary key, + name text +); + +alter table operators + owner to rhea; + +grant select on operators to grafana; + +create table if not exists trips +( + id text not null + primary key, + line_id text, + line_fahrtnr text, + line_name text, + line_admincode text, + line_productname text, + line_mode text, + line_product text, + operator text + references operators, + origin text + references stops, + destination text + references stops, + loadfactor text, + realtimedataupdatedat timestamp with time zone +); + +alter table trips + owner to rhea; + +create table if not exists locations +( + tripid text + constraint locations_trips_id_fk + references trips + on update cascade, + latitude double precision, + longitude double precision, + realtimedataupdatedat timestamp with time zone +); + +alter table locations + owner to rhea; + +create index if not exists locations_tripid_index + on locations (tripid); + +create index if not exists locations_realtimedataupdatedat_index + on locations (realtimedataupdatedat); + +grant select on locations to grafana; + +create index if not exists trips_realtimedataupdatedat_index + on trips (realtimedataupdatedat); + +create index if not exists trips_line_product_index + on trips (line_product); + +grant select on trips to grafana; + +create table if not exists trip_meta +( + id text + references trips + on update cascade, + departure timestamp with time zone, + planneddeparture timestamp with time zone, + departuredelay integer, + arrival timestamp with time zone, + plannedarrival timestamp with time zone, + arrivaldelay integer, + reachable boolean, + direction text, + arrivalplatform text, + plannedarrivalplatform text, + departureplatform text, + planneddepartureplatform text, + arrivalprognosistype text, + departureprognosistype text, + cancelled text, + realtimedataupdatedat timestamp with time zone +); + +alter table trip_meta + owner to rhea; + +create index if not exists trip_meta_id_index + on trip_meta (id); + +create index if not exists trip_meta_realtimedataupdatedat_index + on trip_meta (realtimedataupdatedat); + +create index if not exists trip_meta_planneddeparture_index + on trip_meta (planneddeparture); + +grant select on trip_meta to grafana; + +create table if not exists remarks +( + remhash text not null + constraint remarks_pk + primary key, + content text, + type text, + code text, + summary text +); + +alter table remarks + owner to rhea; + +create index if not exists remarks_code_index + on remarks (code); + +grant select on remarks to grafana; + +create table if not exists stopovers +( + id text + references trips + on update cascade, + stop text + references stops, + departure timestamp with time zone, + planneddeparture timestamp with time zone, + departuredelay integer, + arrival timestamp with time zone, + plannedarrival timestamp with time zone, + arrivaldelay integer, + reachable boolean, + direction text, + arrivalplatform text, + plannedarrivalplatform text, + departureplatform text, + planneddepartureplatform text, + arrivalprognosistype text, + departureprognosistype text, + cancelled text, + realtimedataupdatedat timestamp with time zone, + nextstop boolean default false +); + +alter table stopovers + owner to rhea; + +create index if not exists stopovers_id_index + on stopovers (id); + +create index if not exists stopovers_realtimedataupdatedat_index + on stopovers (realtimedataupdatedat); + +create index if not exists stopovers_stop_index + on stopovers (stop); + +create index if not exists stopovers_nextstop_index + on stopovers (nextstop); + +create index if not exists stopovers_arrivaldelay_index + on stopovers (arrivaldelay); + +create index if not exists stopovers_arrival_index + on stopovers (arrival); + +create index if not exists stopovers_departure_index + on stopovers (departure); + +grant select on stopovers to grafana; + +create table if not exists polylines +( + polyline jsonb, + linehash text not null + primary key +); + +alter table polylines + owner to rhea; + +grant select on polylines to grafana; + +create table if not exists polylines_trips +( + trip text + references trips + on update cascade, + polyline text + references polylines +); + +alter table polylines_trips + owner to rhea; + +grant select on polylines_trips to grafana; + +create table if not exists polyline_connections +( + origin text + references stops, + destination text + references stops, + path jsonb, + hash text, + unique (hash, origin, destination) +); + +alter table polyline_connections + owner to rhea; + +grant select on polyline_connections to grafana; + +create table if not exists polyline_linehash_connections +( + hash text not null + primary key + references polylines, + connections text[] +); + +alter table polyline_linehash_connections + owner to rhea; + +grant select on polyline_linehash_connections to grafana; + +create table if not exists spatial_ref_sys +( + srid integer not null + primary key + constraint spatial_ref_sys_srid_check + check ((srid > 0) AND (srid <= 998999)), + auth_name varchar(256), + auth_srid integer, + srtext varchar(2048), + proj4text varchar(2048) +); + +alter table spatial_ref_sys + owner to rhea; + +grant select on spatial_ref_sys to grafana; + +create table if not exists remarks_trips +( + tripid text + constraint remarks_trips_trips_id_fk + references trips + on update cascade, + remhash text + constraint remarks_trips_remarks_remhash_fk + references remarks, + constraint remarks_trips_pk + unique (remhash, tripid) +); + +alter table remarks_trips + owner to rhea; + +grant select on remarks_trips to grafana; + +create table if not exists stop_remarks +( + remhash text not null + constraint new_stop_remarks_pkey + primary key, + content text, + type text, + code text, + summary text +); + +alter table stop_remarks + owner to rhea; + +create index if not exists stop_remarks_code_index + on stop_remarks (code); + +grant select on stop_remarks to grafana; + +create table if not exists stop_remarks_trips +( + tripid text + references trips + on update cascade, + stopid text + references stops, + remhash text + references stop_remarks +); + +alter table stop_remarks_trips + owner to rhea; + +create unique index if not exists stop_remarks_trips_pk + on stop_remarks_trips (remhash, tripid, stopid); + +grant select on stop_remarks_trips to grafana; + +create table if not exists hash_hafas_tid +( + thash text, + tripid text, + constraint hash_hafas_tid_pk + unique (thash, tripid) +); + +alter table hash_hafas_tid + owner to rhea; + +grant select on hash_hafas_tid to grafana; + +SELECT * FROM trips WHERE line_name LIKE 'RE%' ORDER BY realtimedataupdatedat ASC LIMIT 100; \ No newline at end of file diff --git a/sqlc.yml b/sqlc.yml new file mode 100644 index 0000000..d0e78d7 --- /dev/null +++ b/sqlc.yml @@ -0,0 +1,10 @@ +version: "2" +sql: + - engine: "postgresql" + queries: "query.sql" + schema: "schema.sql" + gen: + go: + package: "bahndb_rest" + out: "queries" + sql_package: "pgx/v5" \ No newline at end of file