feat(nix): update queries, schemas and sqlc config
This commit is contained in:
parent
6f8e3baabd
commit
42ccbb5008
3 changed files with 65 additions and 35 deletions
87
query.sql
87
query.sql
|
|
@ -1,34 +1,38 @@
|
||||||
-- name: GetStationsByName :many
|
-- name: GetStationsByName :many
|
||||||
SELECT s.id,
|
SELECT s.id as "id",
|
||||||
s.name,
|
s.name as "name",
|
||||||
sl.latitude,
|
sl.latitude as "latitude",
|
||||||
sl.longitude,
|
sl.longitude as "longitude",
|
||||||
bus,
|
bus as "bus",
|
||||||
taxi,
|
taxi as "taxi",
|
||||||
tram,
|
tram as "tram",
|
||||||
ferry,
|
ferry as "ferry",
|
||||||
subway,
|
subway as "subway",
|
||||||
national,
|
national as "national",
|
||||||
regional,
|
regional as "regional",
|
||||||
suburban,
|
suburban as "suburban",
|
||||||
regionalexp,
|
regionalexp as "regionalexp",
|
||||||
nationalexp
|
nationalexp as "nationalexp"
|
||||||
FROM stops s
|
FROM stops s
|
||||||
JOIN public.stat_locations sl
|
JOIN public.stat_locations sl
|
||||||
on sl.id = s.location_id
|
on sl.id = s.location_id
|
||||||
JOIN public.stat_services ss
|
JOIN public.stat_services ss
|
||||||
on ss.id = s.service_id
|
on ss.id = s.service_id
|
||||||
|
JOIN public.station_rank sr
|
||||||
|
on sr.stop = s.id
|
||||||
WHERE s.id
|
WHERE s.id
|
||||||
in (SELECT id
|
in (SELECT id
|
||||||
FROM stops s2
|
FROM stops s2
|
||||||
WHERE s2.name LIKE $1
|
WHERE s2.name ILIKE ALL (@search_params::text[])
|
||||||
);
|
)
|
||||||
|
AND CASE WHEN sqlc.narg(long_distance)::bool THEN (ss.national = sqlc.narg(long_distance)::bool OR ss.nationalexp = sqlc.narg(long_distance)::bool) ELSE TRUE END
|
||||||
|
ORDER BY sr.count DESC;
|
||||||
|
|
||||||
-- name: GetStationById :one
|
-- name: GetStationById :one
|
||||||
SELECT s.id,
|
SELECT s.id as "id",
|
||||||
s.name,
|
s.name as "name",
|
||||||
sl.latitude,
|
sl.latitude as "latitude",
|
||||||
sl.longitude,
|
sl.longitude as "longitude",
|
||||||
bus,
|
bus,
|
||||||
taxi,
|
taxi,
|
||||||
tram,
|
tram,
|
||||||
|
|
@ -44,31 +48,48 @@ FROM stops s
|
||||||
on sl.id = s.location_id
|
on sl.id = s.location_id
|
||||||
JOIN public.stat_services ss
|
JOIN public.stat_services ss
|
||||||
on ss.id = s.service_id
|
on ss.id = s.service_id
|
||||||
WHERE s.id = $1;
|
WHERE s.id = @stop_id;
|
||||||
|
|
||||||
-- name: GetDeparturesById :many
|
-- name: GetDeparturesById :many
|
||||||
SELECT DISTINCT (t.id) as "id",
|
SELECT DISTINCT (t.id) as "id",
|
||||||
t.line_name as "lineName",
|
t.line_name as "lineName",
|
||||||
t.line_productname as "lineProductName",
|
t.line_productname as "lineProductName",
|
||||||
so.departuredelay as "departureDelay",
|
so.departuredelay as "departureDelay",
|
||||||
sd.id as "directionId",
|
jsonb_build_object('id', sd.id, 'name', sd.name) as "direction",
|
||||||
sd.name as "directionName",
|
ARRAY((SELECT jsonb_build_object('stop', row('id', sd.id, 'name', sd.name),
|
||||||
|
'arrival', so2.arrival,
|
||||||
|
'plannedArrival', so2.plannedarrival,
|
||||||
|
'arrivalDelay', so2.arrivaldelay,
|
||||||
|
'arrivalPlatform', so2.arrivalplatform,
|
||||||
|
'plannedArrivalPlatform', so2.plannedarrivalplatform,
|
||||||
|
'cancelled', so2.cancelled)
|
||||||
|
FROM stopovers so2
|
||||||
|
JOIN public.stops s2
|
||||||
|
ON so2.stop = s2.id
|
||||||
|
WHERE so2.id = t.id
|
||||||
|
AND so2.plannedarrival > so.planneddeparture
|
||||||
|
AND (so2.stop, so2.realtimedataupdatedat) IN (SELECT DISTINCT (stop), max(realtimedataupdatedat)
|
||||||
|
FROM stopovers so3
|
||||||
|
WHERE (so3.id = t.id
|
||||||
|
AND so3.realtimedataupdatedat <= @rt_updated_at)
|
||||||
|
GROUP BY so3.stop)))
|
||||||
|
AS "stopovers",
|
||||||
so.departure as "departure",
|
so.departure as "departure",
|
||||||
so.planneddeparture as "plannedDeparture",
|
so.planneddeparture as "plannedDeparture",
|
||||||
so.departureplatform as "departurePlattform",
|
so.departureplatform as "departurePlatform",
|
||||||
so.planneddepartureplatform as "plannedDeparturePlattform",
|
so.planneddepartureplatform as "plannedDeparturePlatform",
|
||||||
|
so.cancelled as "cancelled",
|
||||||
so.realtimedataupdatedat as "realtimeDataUpdatedAt"
|
so.realtimedataupdatedat as "realtimeDataUpdatedAt"
|
||||||
FROM stopovers so
|
FROM stopovers so
|
||||||
JOIN trips t ON so.id = t.id
|
JOIN trips t ON so.id = t.id
|
||||||
JOIN public.trip_meta tm on t.id = tm.id
|
JOIN public.trip_meta tm on t.id = tm.id
|
||||||
JOIN public.stops sd on t.destination = sd.id
|
JOIN public.stops sd on t.destination = sd.id
|
||||||
WHERE so.stop = $1
|
WHERE so.stop = @stop_id
|
||||||
AND (so.id, so.realtimedataupdatedat) IN (SELECT DISTINCT (id), max(realtimedataupdatedat)
|
AND (so.id, so.realtimedataupdatedat) IN (SELECT DISTINCT (id), max(realtimedataupdatedat)
|
||||||
FROM stopovers so2
|
FROM stopovers so3
|
||||||
WHERE so2.stop = $1
|
WHERE so3.stop = @stop_id
|
||||||
AND (so2.departure > $2)
|
AND (so3.departure > @departure_from)
|
||||||
AND (so2.departure < $3)
|
AND (so3.departure < @departure_to)
|
||||||
AND (so2.realtimedataupdatedat <= $4)
|
AND (so3.realtimedataupdatedat <= @rt_updated_at)
|
||||||
GROUP BY so2.id
|
GROUP BY so3.id)
|
||||||
LIMIT 50)
|
|
||||||
ORDER BY so.departure ASC;
|
ORDER BY so.departure ASC;
|
||||||
|
|
|
||||||
10
schema.sql
10
schema.sql
|
|
@ -372,4 +372,12 @@ alter table hash_hafas_tid
|
||||||
|
|
||||||
grant select on hash_hafas_tid to grafana;
|
grant select on hash_hafas_tid to grafana;
|
||||||
|
|
||||||
SELECT * FROM trips WHERE line_name LIKE 'RE%' ORDER BY realtimedataupdatedat ASC LIMIT 100;
|
create table public.station_rank
|
||||||
|
(
|
||||||
|
stop text not null
|
||||||
|
constraint station_rank_pk
|
||||||
|
primary key
|
||||||
|
constraint station_rank_stops_id_fk
|
||||||
|
references public.stops,
|
||||||
|
count bigint
|
||||||
|
);
|
||||||
|
|
|
||||||
3
sqlc.yml
3
sqlc.yml
|
|
@ -7,4 +7,5 @@ sql:
|
||||||
go:
|
go:
|
||||||
package: "bahndb_rest"
|
package: "bahndb_rest"
|
||||||
out: "queries"
|
out: "queries"
|
||||||
sql_package: "pgx/v5"
|
sql_package: "pgx/v5"
|
||||||
|
emit_json_tags: true
|
||||||
Loading…
Reference in a new issue