diff --git a/sql/bound.sql b/sql/bound.sql deleted file mode 100644 index c0b58df..0000000 --- a/sql/bound.sql +++ /dev/null @@ -1,3 +0,0 @@ -SELECT MAX(ST_x(the_geom)) AS toprx, MAX(ST_y(the_geom)) AS topry, MIN(ST_x(the_geom)) AS botlx, MIN(ST_y(the_geom)) AS botly -FROM points -WHERE user_id = 1 \ No newline at end of file diff --git a/sql/co2_by_track.sql b/sql/co2_by_track.sql deleted file mode 100644 index 302b0cb..0000000 --- a/sql/co2_by_track.sql +++ /dev/null @@ -1,54 +0,0 @@ -WITH RECURSIVE segments AS ( - SELECT ST_Makeline(pts.the_geom_webmercator) AS the_geom_webmercator, - ST_Length(ST_Makeline(pts.the_geom_webmercator))/1000 AS distance, - transport_modes.factor, - transport_mode, - (MAX(timestamp)-MIN(timestamp)) AS time, - pts.track_id, - pts.path_id AS id, - pts.user_id - FROM (SELECT * FROM points ORDER BY track_id, path_id, timestamp ASC) AS pts - JOIN paths ON pts.path_id=paths.cartodb_id - JOIN transport_modes ON paths.transport_mode = transport_modes.name - GROUP BY pts.path_id, pts.track_id, factor, pts.user_id, transport_mode -), starts AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='StartTrack' -), ends AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='EndTrack' -), tracks AS ( - SELECT - segments.track_id AS id, - SUM(distance*factor) AS carbon, - SUM(distance) AS distance, - SUM(segments.time) AS time, - starts.location_id AS start_id, - ends.location_id AS end_id, - starts.location_name AS start_name, - ends.location_name AS end_name, - starts.date AS start_date, - ends.date AS end_date, - user_id - FROM segments - JOIN starts ON starts.track_id=segments.track_id - JOIN ends ON ends.track_id=segments.track_id - GROUP BY segments.track_id, user_id, start_date, end_date, start_id, end_id, start_name, end_name -), tracks_interval AS ( - SELECT MAX(tracks.carbon)/20 AS interval, MAX(tracks.carbon) AS max - FROM tracks - WHERE tracks.user_id = 1 -), numbers ( n ) AS ( - SELECT cast(0 as double precision) UNION ALL - SELECT n + tracks_interval.interval FROM numbers,tracks_interval WHERE n+tracks_interval.interval < tracks_interval.max -), filtered_tracks AS ( - SELECT tracks.distance, tracks.carbon, interval - FROM tracks, tracks_interval - WHERE tracks.user_id = 1 - AND tracks.start_date >= '2012-06-12T00:00:00.000Z' AND tracks.start_date <= '2012-06-14T23:59:000.999Z' - AND extract(hour from tracks.start_date) >= 4 AND extract(hour from tracks.start_date) <= 5 -) - -SELECT COALESCE(SUM(distance), 0) AS distance, numbers.n - FROM filtered_tracks - RIGHT OUTER JOIN numbers ON ((filtered_tracks.carbon=0 AND numbers.n=0) OR (filtered_tracks.carbon > 0 AND filtered_tracks.carbon <= numbers.n AND numbers.n=filtered_tracks.interval) OR (filtered_tracks.carbon > numbers.n-filtered_tracks.interval AND filtered_tracks.carbon > filtered_tracks.interval AND filtered_tracks.carbon <= numbers.n)) - GROUP BY numbers.n - ORDER BY numbers.n \ No newline at end of file diff --git a/sql/distance_by_day.sql b/sql/distance_by_day.sql deleted file mode 100644 index 51a7c1f..0000000 --- a/sql/distance_by_day.sql +++ /dev/null @@ -1,64 +0,0 @@ -WITH RECURSIVE segments AS ( - SELECT ST_Makeline(pts.the_geom_webmercator) AS the_geom_webmercator, - ST_Length(ST_Makeline(pts.the_geom_webmercator))/1000 AS distance, - transport_modes.factor, - transport_mode, - (MAX(timestamp)-MIN(timestamp)) AS time, - pts.track_id, - pts.path_id AS id, - pts.user_id - FROM (SELECT * FROM points ORDER BY track_id, path_id, timestamp ASC) AS pts - JOIN paths ON pts.path_id=paths.cartodb_id - JOIN transport_modes ON paths.transport_mode = transport_modes.name - GROUP BY pts.path_id, pts.track_id, factor, pts.user_id, transport_mode -), starts AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='StartTrack' -), ends AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='EndTrack' -), tracks AS ( - SELECT - segments.track_id AS id, - SUM(distance*factor) AS carbon, - SUM(distance) AS distance, - SUM(segments.time) AS time, - starts.location_id AS start_id, - ends.location_id AS end_id, - starts.location_name AS start_name, - ends.location_name AS end_name, - starts.date AS start_date, - ends.date AS end_date, - user_id - FROM segments - JOIN starts ON starts.track_id=segments.track_id - JOIN ends ON ends.track_id=segments.track_id - GROUP BY segments.track_id, user_id, start_date, end_date, start_id, end_id, start_name, end_name -), filtered_tracks AS ( - SELECT tracks.distance, start_date - FROM tracks - WHERE - tracks.user_id = 1 - AND (tracks.carbon >= 0 AND tracks.carbon <= 4000) - AND (tracks.distance >= 0 AND tracks.distance <= 30) - AND (extract(hour from tracks.start_date) >= 9 AND extract(hour from tracks.start_date) <= 20) - AND (tracks.start_name='Casa') - AND (tracks.end_name='StartupLisboa') - AND tracks.id IN - (SELECT segments.track_id FROM segments WHERE segments.transport_mode='Walk') -), tracks_interval AS ( - SELECT MAX(start_date) AS max, MIN(start_date) AS min - FROM tracks - WHERE tracks.user_id = 1 -), numbers ( n ) AS ( - SELECT 1 UNION ALL - SELECT 1 + n FROM numbers WHERE n < 1000 -), dates AS ( - SELECT date_trunc('day', tracks_interval.max) - interval '1 day' * (n-1) AS date - FROM numbers, tracks_interval - WHERE date_trunc('day', tracks_interval.max) - interval '1 day' * (n-1) >= date_trunc('day', tracks_interval.min) -) - -SELECT dates.date AS day, SUM(COALESCE(distance, 0)) AS distance -FROM dates - LEFT OUTER JOIN filtered_tracks ON date_trunc('day', start_date) = date -GROUP BY date -ORDER BY date \ No newline at end of file diff --git a/sql/distance_by_timeofday.sql b/sql/distance_by_timeofday.sql deleted file mode 100644 index dcb83f8..0000000 --- a/sql/distance_by_timeofday.sql +++ /dev/null @@ -1,56 +0,0 @@ -WITH RECURSIVE segments AS ( - SELECT ST_Makeline(pts.the_geom_webmercator) AS the_geom_webmercator, - ST_Length(ST_Makeline(pts.the_geom_webmercator))/1000 AS distance, - transport_modes.factor, - transport_mode, - (MAX(timestamp)-MIN(timestamp)) AS time, - pts.track_id, - pts.path_id AS id, - pts.user_id - FROM (SELECT * FROM points ORDER BY track_id, path_id, timestamp ASC) AS pts - JOIN paths ON pts.path_id=paths.cartodb_id - JOIN transport_modes ON paths.transport_mode = transport_modes.name - GROUP BY pts.path_id, pts.track_id, factor, pts.user_id, transport_mode -), starts AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='StartTrack' -), ends AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='EndTrack' -), tracks AS ( - SELECT - segments.track_id AS id, - SUM(distance*factor) AS carbon, - SUM(distance) AS distance, - SUM(segments.time) AS time, - starts.location_id AS start_id, - ends.location_id AS end_id, - starts.location_name AS start_name, - ends.location_name AS end_name, - starts.date AS start_date, - ends.date AS end_date, - user_id - FROM segments - JOIN starts ON starts.track_id=segments.track_id - JOIN ends ON ends.track_id=segments.track_id - GROUP BY segments.track_id, user_id, start_date, end_date, start_id, end_id, start_name, end_name -), hours ( h ) AS ( - SELECT 0 UNION ALL - SELECT h + 1 FROM hours WHERE h < 24 -), filtered_segments AS ( - SELECT ST_Length(ST_Makeline(points.the_geom_webmercator))/1000 AS distance, - points.track_id, - extract(hour from timestamp) AS hour - FROM points - WHERE points.track_id IN( - SELECT id - FROM tracks - WHERE - tracks.user_id = 1 - AND tracks.id IN - (SELECT track_id FROM segments WHERE transport_mode='Run') - ) - GROUP BY points.track_id, hour -) -SELECT COALESCE(SUM(filtered_segments.distance),0) AS distance, hours.h -FROM filtered_segments RIGHT OUTER JOIN hours ON hours.h=filtered_segments.hour -GROUP BY hours.h -ORDER BY hours.h \ No newline at end of file diff --git a/sql/heatmap.sql b/sql/heatmap.sql deleted file mode 100644 index b85996b..0000000 --- a/sql/heatmap.sql +++ /dev/null @@ -1,48 +0,0 @@ -WITH segments AS ( - SELECT ST_Makeline(pts.the_geom_webmercator) AS the_geom_webmercator, - ST_Length(ST_Makeline(pts.the_geom_webmercator))/1000 AS distance, - transport_modes.factor, - transport_mode, - (MAX(timestamp)-MIN(timestamp)) AS time, - pts.track_id, - pts.path_id AS id, - pts.user_id - FROM (SELECT * FROM points ORDER BY track_id, path_id, timestamp ASC) AS pts - JOIN paths ON pts.path_id=paths.cartodb_id - JOIN transport_modes ON paths.transport_mode = transport_modes.name - GROUP BY pts.path_id, pts.track_id, factor, pts.user_id, transport_mode -), starts AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='StartTrack' -), ends AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='EndTrack' -), tracks AS ( - SELECT - segments.track_id AS id, - SUM(distance*factor) AS carbon, - SUM(distance) AS distance, - SUM(segments.time) AS time, - starts.location_id AS start_id, - ends.location_id AS end_id, - starts.date AS start_date, - ends.date AS end_date, - starts.location_name AS start_name, - ends.location_name AS end_name, - user_id - FROM segments - JOIN starts ON starts.track_id=segments.track_id - JOIN ends ON ends.track_id=segments.track_id - GROUP BY segments.track_id, user_id, start_date, end_date, start_id, end_id, start_name, end_name -) - -SELECT ST_x(geom) AS lng, ST_y(geom) AS lat, count(geom) AS count -FROM ( - SELECT ST_SnapToGrid(points.the_geom,0.0001) AS geom FROM points - WHERE points.track_id IN ( - SELECT tracks.id - FROM tracks - WHERE tracks.user_id = 1 - AND tracks.carbon >= 6000 - AND tracks.id IN - (SELECT segments.track_id FROM segments WHERE segments.transport_mode='Walk') - ) -) AS foo GROUP BY lng, lat \ No newline at end of file diff --git a/sql/locations.sql b/sql/locations.sql deleted file mode 100644 index 7f42b01..0000000 --- a/sql/locations.sql +++ /dev/null @@ -1,56 +0,0 @@ -WITH segments AS ( - SELECT ST_Makeline(pts.the_geom_webmercator) AS the_geom_webmercator, - ST_Length(ST_Makeline(pts.the_geom_webmercator))/1000 AS distance, - transport_modes.factor, - transport_mode, - (MAX(timestamp)-MIN(timestamp)) AS time, - pts.track_id, - pts.path_id AS id, - pts.user_id - FROM (SELECT * FROM points ORDER BY track_id, path_id, timestamp ASC) AS pts - JOIN paths ON pts.path_id=paths.cartodb_id - JOIN transport_modes ON paths.transport_mode = transport_modes.name - GROUP BY pts.path_id, pts.track_id, factor, pts.user_id, transport_mode -), starts AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='StartTrack' -), ends AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='EndTrack' -), tracks AS ( - SELECT - segments.track_id AS id, - SUM(distance*factor) AS carbon, - SUM(distance) AS distance, - SUM(segments.time) AS time, - starts.location_id AS start_id, - ends.location_id AS end_id, - starts.date AS start_date, - ends.date AS end_date, - starts.location_name AS start_name, - ends.location_name AS end_name, - user_id - FROM segments - JOIN starts ON starts.track_id=segments.track_id - JOIN ends ON ends.track_id=segments.track_id - GROUP BY segments.track_id, user_id, start_date, end_date, start_id, end_id, start_name, end_name -) -SELECT tracks.start_name, 0 AS cnt, locations.the_geom -FROM tracks JOIN locations ON locations.cartodb_id=start_id -WHERE - tracks.id IN ( - SELECT id FROM tracks - WHERE tracks.user_id = 1 - AND (tracks.end_name='Pq Quinta das Conchas') - ) -GROUP BY locations.cartodb_id -ORDER BY cnt DESC -UNION -SELECT tracks.end_name, COUNT(*) AS cnt, locations.the_geom -FROM tracks JOIN locations ON locations.cartodb_id=end_id -WHERE - tracks.id IN ( - SELECT id FROM tracks - WHERE tracks.user_id = 1 - AND (tracks.end_name='Pq Quinta das Conchas') - ) -GROUP BY locations.cartodb_id -ORDER BY cnt DESC \ No newline at end of file diff --git a/sql/locations_relationships.sql b/sql/locations_relationships.sql deleted file mode 100644 index c72f546..0000000 --- a/sql/locations_relationships.sql +++ /dev/null @@ -1,43 +0,0 @@ -WITH segments AS ( - SELECT ST_Makeline(pts.the_geom_webmercator) AS the_geom_webmercator, - ST_Length(ST_Makeline(pts.the_geom_webmercator))/1000 AS distance, - transport_modes.factor, - transport_mode, - (MAX(timestamp)-MIN(timestamp)) AS time, - pts.track_id, - pts.path_id AS id, - pts.user_id - FROM (SELECT * FROM points ORDER BY track_id, path_id, timestamp ASC) AS pts - JOIN paths ON pts.path_id=paths.cartodb_id - JOIN transport_modes ON paths.transport_mode = transport_modes.name - GROUP BY pts.path_id, pts.track_id, factor, pts.user_id, transport_mode -), starts AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='StartTrack' -), ends AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='EndTrack' -), tracks AS ( - SELECT - segments.track_id AS id, - SUM(distance*factor) AS carbon, - SUM(distance) AS distance, - SUM(segments.time) AS time, - starts.location_id AS start_id, - ends.location_id AS end_id, - starts.date AS start_date, - ends.date AS end_date, - starts.location_name AS start_name, - ends.location_name AS end_name, - user_id - FROM segments - JOIN starts ON starts.track_id=segments.track_id - JOIN ends ON ends.track_id=segments.track_id - GROUP BY segments.track_id, user_id, start_date, end_date, start_id, end_id, start_name, end_name -) - -SELECT tracks.start_name, tracks.end_name, COUNT(*) AS cnt -FROM tracks -WHERE - tracks.user_id = 1 -GROUP BY tracks.start_name, tracks.end_name -HAVING COUNT(*) > 1 -ORDER BY start_name, end_name \ No newline at end of file diff --git a/sql/segments.sql b/sql/segments.sql deleted file mode 100644 index e69de29..0000000 diff --git a/sql/time_by_transportmode.sql b/sql/time_by_transportmode.sql deleted file mode 100644 index 1d204ee..0000000 --- a/sql/time_by_transportmode.sql +++ /dev/null @@ -1,41 +0,0 @@ -WITH segments AS ( - SELECT ST_Makeline(pts.the_geom_webmercator) AS the_geom_webmercator, - ST_Length(ST_Makeline(pts.the_geom_webmercator))/1000 AS distance, - transport_modes.factor, - transport_mode, - (MAX(timestamp)-MIN(timestamp)) AS time, - pts.track_id, - pts.path_id AS id, - pts.user_id - FROM (SELECT * FROM points ORDER BY track_id, path_id, timestamp ASC) AS pts - JOIN paths ON pts.path_id=paths.cartodb_id - JOIN transport_modes ON paths.transport_mode = transport_modes.name - GROUP BY pts.path_id, pts.track_id, factor, pts.user_id, transport_mode -), starts AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='StartTrack' -), ends AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='EndTrack' -), tracks AS ( - SELECT - segments.track_id AS id, - SUM(distance*factor) AS carbon, - SUM(distance) AS distance, - SUM(segments.time) AS time, - starts.location_id AS start_id, - ends.location_id AS end_id, - starts.date AS start_date, - ends.date AS end_date, - starts.location_name AS start_name, - ends.location_name AS end_name, - user_id - FROM segments - JOIN starts ON starts.track_id=segments.track_id - JOIN ends ON ends.track_id=segments.track_id - GROUP BY segments.track_id, user_id, start_date, end_date, start_id, end_id, start_name, end_name -) -SELECT segments.transport_mode, SUM(EXTRACT(EPOCH FROM segments.time)/60) AS time -FROM tracks JOIN segments ON tracks.id=segments.track_id -WHERE - tracks.user_id = 1 - AND (tracks.start_name='Casa') -GROUP BY segments.transport_mode \ No newline at end of file diff --git a/sql/tracks.sql b/sql/tracks.sql deleted file mode 100644 index 1cbd4b2..0000000 --- a/sql/tracks.sql +++ /dev/null @@ -1,44 +0,0 @@ -WITH segments AS ( - SELECT ST_Makeline(pts.the_geom_webmercator) AS the_geom_webmercator, - ST_Length(ST_Makeline(pts.the_geom_webmercator))/1000 AS distance, - transport_modes.factor, - transport_mode, - (MAX(timestamp)-MIN(timestamp)) AS time, - MIN(timestamp) AS start, - MAX(timestamp) AS end, - pts.track_id, - pts.path_id AS id, - pts.user_id - FROM (SELECT * FROM points ORDER BY track_id, path_id, timestamp ASC) AS pts - JOIN paths ON pts.path_id=paths.cartodb_id - JOIN transport_modes ON paths.transport_mode = transport_modes.name - GROUP BY pts.path_id, pts.track_id, factor, pts.user_id, transport_mode -), starts AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='StartTrack' -), ends AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name, FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='EndTrack' -), tracks AS ( - SELECT - segments.track_id AS id, - SUM(distance*factor) AS carbon, - SUM(distance) AS distance, - SUM(segments.time) AS time, - (extract(hour from MIN(segments.start) + SUM(segments.time)/2) + extract(minute from MIN(segments.start) + SUM(segments.time)/2)/60) AS hour, - starts.location_id AS start_id, - ends.location_id AS end_id, - starts.date AS start_date, - ends.date AS end_date, - starts.location_name AS start_name, - ends.location_name AS end_name, - user_id - FROM segments - JOIN starts ON starts.track_id=segments.track_id - JOIN ends ON ends.track_id=segments.track_id - GROUP BY segments.track_id, user_id, start_date, end_date, start_id, end_id, start_name, end_name -) - -SELECT tracks.distance, tracks.carbon, extract(epoch from tracks.time) AS time -FROM tracks -WHERE tracks.user_id = 1 -GROUP BY tracks.distance, tracks.carbon, tracks.time -HAVING MAX(tracks.time) = tracks.time \ No newline at end of file diff --git a/sql/tracks_by_distance.sql b/sql/tracks_by_distance.sql deleted file mode 100644 index f506466..0000000 --- a/sql/tracks_by_distance.sql +++ /dev/null @@ -1,54 +0,0 @@ -WITH RECURSIVE segments AS ( - SELECT ST_Makeline(pts.the_geom_webmercator) AS the_geom_webmercator, - ST_Length(ST_Makeline(pts.the_geom_webmercator))/1000 AS distance, - transport_modes.factor, - transport_mode, - (MAX(timestamp)-MIN(timestamp)) AS time, - pts.track_id, - pts.path_id AS id, - pts.user_id - FROM (SELECT * FROM points ORDER BY track_id, path_id, timestamp ASC) AS pts - JOIN paths ON pts.path_id=paths.cartodb_id - JOIN transport_modes ON paths.transport_mode = transport_modes.name - GROUP BY pts.path_id, pts.track_id, factor, pts.user_id, transport_mode -), starts AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='StartTrack' -), ends AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='EndTrack' -), tracks AS ( - SELECT - segments.track_id AS id, - SUM(distance*factor) AS carbon, - SUM(distance) AS distance, - SUM(segments.time) AS time, - starts.location_id AS start_id, - ends.location_id AS end_id, - starts.location_name AS start_name, - ends.location_name AS end_name, - starts.date AS start_date, - ends.date AS end_date, - user_id - FROM segments - JOIN starts ON starts.track_id=segments.track_id - JOIN ends ON ends.track_id=segments.track_id - GROUP BY segments.track_id, user_id, start_date, end_date, start_id, end_id, start_name, end_name -), tracks_interval AS ( - SELECT MAX(tracks.distance)/20 AS interval, MAX(tracks.distance) AS max - FROM tracks - WHERE tracks.user_id = 1 -), numbers ( n ) AS ( - SELECT cast(0 as double precision) UNION ALL - SELECT n + tracks_interval.interval FROM numbers,tracks_interval WHERE n+tracks_interval.interval < tracks_interval.max -), filtered_tracks AS ( - SELECT tracks.distance, interval - FROM tracks, tracks_interval - WHERE - tracks.user_id = 1 - AND tracks.start_name='Casa' AND tracks.end_name='Casa' -) - -SELECT COUNT(filtered_tracks.*), numbers.n - FROM filtered_tracks - RIGHT OUTER JOIN numbers ON (filtered_tracks.distance >= numbers.n AND filtered_tracks.distance < numbers.n+filtered_tracks.interval) - GROUP BY numbers.n - ORDER BY numbers.n \ No newline at end of file diff --git a/sql/tracks_by_duration.sql b/sql/tracks_by_duration.sql deleted file mode 100644 index c63e187..0000000 --- a/sql/tracks_by_duration.sql +++ /dev/null @@ -1,54 +0,0 @@ -WITH RECURSIVE segments AS ( - SELECT ST_Makeline(pts.the_geom_webmercator) AS the_geom_webmercator, - ST_Length(ST_Makeline(pts.the_geom_webmercator))/1000 AS distance, - transport_modes.factor, - transport_mode, - (MAX(timestamp)-MIN(timestamp)) AS time, - pts.track_id, - pts.path_id AS id, - pts.user_id - FROM (SELECT * FROM points ORDER BY track_id, path_id, timestamp ASC) AS pts - JOIN paths ON pts.path_id=paths.cartodb_id - JOIN transport_modes ON paths.transport_mode = transport_modes.name - GROUP BY pts.path_id, pts.track_id, factor, pts.user_id, transport_mode -), starts AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='StartTrack' -), ends AS ( - SELECT events.date AS date, events.track_id, events.location_id AS location_id, locations.name AS location_name FROM events JOIN locations ON events.location_id=locations.cartodb_id WHERE events.type='EndTrack' -), tracks AS ( - SELECT - segments.track_id AS id, - SUM(distance*factor) AS carbon, - SUM(distance) AS distance, - SUM(segments.time) AS time, - starts.location_id AS start_id, - ends.location_id AS end_id, - starts.location_name AS start_name, - ends.location_name AS end_name, - starts.date AS start_date, - ends.date AS end_date, - user_id - FROM segments - JOIN starts ON starts.track_id=segments.track_id - JOIN ends ON ends.track_id=segments.track_id - GROUP BY segments.track_id, user_id, start_date, end_date, start_id, end_id, start_name, end_name -), tracks_interval AS ( - SELECT MAX(extract(epoch from tracks.time))/20 AS interval, MAX(extract(epoch from tracks.time)) AS max - FROM tracks - WHERE tracks.user_id = 1 -), numbers ( n ) AS ( - SELECT cast(0 as double precision) UNION ALL - SELECT n + tracks_interval.interval FROM numbers,tracks_interval WHERE n+tracks_interval.interval < tracks_interval.max -), filtered_tracks AS ( - SELECT extract(epoch from tracks.time) AS duration, interval - FROM tracks, tracks_interval - WHERE - tracks.user_id = 1 - AND tracks.start_name='Casa' AND tracks.end_name='Casa' -) - -SELECT COUNT(filtered_tracks.*), numbers.n - FROM filtered_tracks - RIGHT OUTER JOIN numbers ON (filtered_tracks.duration >= numbers.n AND filtered_tracks.duration < numbers.n+filtered_tracks.interval) - GROUP BY numbers.n - ORDER BY numbers.n \ No newline at end of file