training_duration view
This commit is contained in:
parent
6422fff894
commit
a257a08760
27
init.sql
27
init.sql
@ -20,4 +20,29 @@ create table if not exists training_data(
|
||||
constraint fk_training_id foreign key(training_id) references training(id) on delete cascade
|
||||
);
|
||||
create index if not exists idx_training_data_t on training_data(t);
|
||||
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
|
||||
(select td_start.id as id,
|
||||
td_start.t as start_time,
|
||||
td_end.t as end_time,
|
||||
date_trunc('second', (td_end.t - td_start.t)) as duration
|
||||
from (select td_row_n.t, td_row_n.id
|
||||
from (select *,
|
||||
row_number() over (partition by td.training_id order by td.t asc) as row_n
|
||||
from training_data td join training t on (t.id = td.training_id)
|
||||
order by td.t asc) as td_row_n
|
||||
where td_row_n.row_n = 1
|
||||
order by td_row_n.t asc) td_start
|
||||
|
||||
join
|
||||
|
||||
(select td_row_n.t, td_row_n.id
|
||||
from (select *,
|
||||
row_number() over (partition by td.training_id order by td.t desc) as row_n
|
||||
from training_data td join training t on (t.id = td.training_id)
|
||||
order by td.t asc) as td_row_n
|
||||
where td_row_n.row_n = 1) td_end
|
||||
|
||||
on (td_start.id = td_end.id)
|
||||
);
|
Loading…
x
Reference in New Issue
Block a user