training_duration with the "distinct on" paradigm
This improves performance against the previous "partition by" approach
This commit is contained in:
parent
64c4938c88
commit
2d802b67d5
46
init.sql
46
init.sql
@ -24,30 +24,28 @@ create index if not exists idx_training_data_training_id on training_data(traini
|
|||||||
create index if not exists idx_training_data_geog on training_data using GIST(geog);
|
create index if not exists idx_training_data_geog on training_data using GIST(geog);
|
||||||
|
|
||||||
create or replace view training_duration as
|
create or replace view training_duration as
|
||||||
(select td_start.id as id,
|
(
|
||||||
td_start.geog as start_location,
|
select
|
||||||
td_end.geog as end_location,
|
td_start.training_id as training_id,
|
||||||
td_start.t as start_time,
|
td_start.t as start_time,
|
||||||
td_end.t as end_time,
|
td_end.t as end_time,
|
||||||
date_trunc('second', (td_end.t - td_start.t)) as duration
|
resolve_geo_location(td_start.geog) AS start_location,
|
||||||
from (select td_row_n.t, td_row_n.id, td_row_n.geog
|
resolve_geo_location(td_end.geog) AS end_location,
|
||||||
from (select *,
|
td_start.geog as start_location_point,
|
||||||
row_number() over (partition by td.training_id order by td.t asc) as row_n
|
td_end.geog as end_location_point,
|
||||||
from training_data td join training t on (t.id = td.training_id)
|
date_trunc('second'::text, td_end.t - td_start.t) AS duration
|
||||||
order by td.t asc) as td_row_n
|
from
|
||||||
where td_row_n.row_n = 1
|
(
|
||||||
order by td_row_n.t asc) td_start
|
select distinct on (td2.training_id) *
|
||||||
|
from training_data td2 order by td2.training_id, t asc
|
||||||
join
|
) td_start
|
||||||
|
join
|
||||||
(select td_row_n.t, td_row_n.id, td_row_n.geog
|
(
|
||||||
from (select *,
|
select distinct on (td2.training_id) *
|
||||||
row_number() over (partition by td.training_id order by td.t desc) as row_n
|
from training_data td2 order by td2.training_id, t desc
|
||||||
from training_data td join training t on (t.id = td.training_id)
|
) td_end
|
||||||
order by td.t asc) as td_row_n
|
on (td_start.training_id = td_end.training_id)
|
||||||
where td_row_n.row_n = 1) td_end
|
order by td_start.t asc
|
||||||
|
|
||||||
on (td_start.id = td_end.id)
|
|
||||||
);
|
);
|
||||||
|
|
||||||
create or replace view training_info as
|
create or replace view training_info as
|
||||||
|
Loading…
x
Reference in New Issue
Block a user