I am working with a GPS datasets of people's mobility for Beijing city. In my raw GPS table trajectories
is the sequence of GPS for all users:
CREATE TABLE trajectories
(
user_id integer,
session_id bigint NOT NULL,
"timestamp" timestamp with time zone NOT NULL,
lat double precision NOT NULL,
lon double precision NOT NULL,
alt double precision,
CONSTRAINT trajectories_pkey PRIMARY KEY (session_id, "timestamp")
);
SELECT * FROM trajectories ORDER BY user_id, timestamp LIMIT 10;
user_id | session_id | timestamp | lat | lon | alt
---------+----------------+------------------------+-----------+------------+-----
1 | 20081023025304 | 2008-10-23 02:53:04+01 | 39.984702 | 116.318417 | 492
1 | 20081023025304 | 2008-10-23 02:53:10+01 | 39.984683 | 116.31845 | 492
1 | 20081023025304 | 2008-10-23 02:53:15+01 | 39.984686 | 116.318417 | 492
1 | 20081023025304 | 2008-10-23 02:53:20+01 | 39.984688 | 116.318385 | 492
1 | 20081023025304 | 2008-10-23 02:53:25+01 | 39.984655 | 116.318263 | 492
1 | 20081023025304 | 2008-10-23 02:53:30+01 | 39.984611 | 116.318026 | 493
1 | 20081023025304 | 2008-10-23 02:53:35+01 | 39.984608 | 116.317761 | 493
1 | 20081023025304 | 2008-10-23 02:53:40+01 | 39.984563 | 116.317517 | 496
1 | 20081023025304 | 2008-10-23 02:53:45+01 | 39.984539 | 116.317294 | 500
1 | 20081023025304 | 2008-10-23 02:53:50+01 | 39.984606 | 116.317065 | 505
(10 rows)
The SELECT query above shows the sequence of GPS points for user 1
, from the starting point for the current trip (session_id=20081023025304
). I want to use the raw data in this table to insert calculated trip metrics into a new table I defined as:
CREATE TABLE trip_metrics(
user_id INT,
session_id BIGINT,
lat_start DOUBLE PRECISION,
lat_end DOUBLE PRECISION,
lon_start DOUBLE PRECISION,
lon_end DOUBLE PRECISION,
trip_starttime timestamp,
trip_endtime timestamp,
trip_duration DOUBLE PRECISION,
trip_distance DOUBLE PRECISION,
PRIMARY KEY (user_id, session_id, trip_starttime)
);
The point of this trip_metrics
TABLE is to store results for analysis, so that lat_start, lon_start
take the values of lat, lon
of starting position (in the given example: 39.984702, 116.318417
), trip_starttimestamp
takes starting time (in this case 2008-10-23 02:53:04+01
) and so the lat_end, lon_end, trip_endtime
respectively.
And finally using lat_start/end, lon_start/end
to compute the distance covered by this user in this trip. The final result should be like:
+---------+----------------+-----------+-----------+------------+------------+------------------------+------------------------+---------------+---------------+
| user_id | session_id | lat_start | lat_end | lon_start | lon_end | trip_starttime | trip_endtime | trip_duration | trip_distance |
+---------+----------------+-----------+-----------+------------+------------+------------------------+------------------------+---------------+---------------+
| 1 | 20081023025304 | 39.984702 | 39.984606 | 116.318417 | 116.317065 | 2008-10-23 02:53:04+01 | 2008-10-23 02:53:50+01 | | |
+---------+----------------+-----------+-----------+------------+------------+------------------------+------------------------+---------------+---------------+
With the values of trip_duration
and trip_distance
calculated (of course the value of trip_duration
would be trip_endtime - trip_starttime
).
I have been stuck in my research for a couple of days thinking about how to do this in PostgrSQL
database filtering only trips within Beijing city latitude (39.85 - 40.05)
and longitude (116.25 - 116.5)
as some trips spanned beyond the city. I created a db-fiddle here containing GPS points of 2 trips for this user (10 points each).
I would appreciate any guide to work around this to make a progress in my current research.
EDIT
Come across this function to calculate distance using haversine formula. I created this function but I'm not sure how to use it to get trip_distance
value.
CREATE OR REPLACE FUNCTION distance(
lat1 double precision,
lon1 double precision,
lat2 double precision,
lon2 double precision)
RETURNS double precision AS
$BODY$
DECLARE
R integer = 6371e3; -- Meters
rad double precision = 0.01745329252;
φ1 double precision = lat1 * rad;
φ2 double precision = lat2 * rad;
Δφ double precision = (lat2-lat1) * rad;
Δλ double precision = (lon2-lon1) * rad;
a double precision = sin(Δφ/2) * sin(Δφ/2) + cos(φ1) * cos(φ2) * sin(Δλ/2) * sin(Δλ/2);
c double precision = 2 * atan2(sqrt(a), sqrt(1-a));
BEGIN
RETURN R * c;
END
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
To compute distances more easily you have to install the PostGIS extension
, as you already suggest in your tags:
CREATE EXTENSION postgis;
The function ST_Distance
is what you're looking for, e.g (quick&dirty):
WITH j AS (
SELECT user_id, session_id,
max(timestamp ORDER BY timestamp),
min(timestamp ORDER BY timestamp)
FROM trajectories t
GROUP BY user_id,session_id
)
SELECT
s.user_id,s.session_id,
lat_start,lon_start,
lat_end,lon_end,
trip_starttime,
trip_endtime,
age(trip_endtime,trip_starttime),
ST_Distance(
ST_MakePoint(lon_start,lat_start)::geography,
ST_MakePoint(lon_end,lat_end)::geography) AS trip_distance
FROM
(SELECT
j.user_id, j.session_id,
t.timestamp AS trip_starttime,
lat AS lat_start, lon AS lon_start FROM j
JOIN trajectories t ON t.timestamp = j.min
AND t.session_id = j.session_id AND t.user_id = j.user_id) s,
(SELECT
j.user_id, j.session_id,
t.timestamp AS trip_endtime,
lat AS lat_end,lon AS lon_end FROM j
JOIN trajectories t ON t.timestamp = j.max
AND t.session_id = j.session_id AND t.user_id = j.user_id) e
WHERE s.user_id = e.user_id AND s.session_id = e.session_id;
user_id | session_id | lat_start | lon_start | lat_end | lon_end | trip_starttime | trip_endtime | age | trip_distance
---------+----------------+-----------+-----------+-----------+------------+------------------------+------------------------+----------+------------------
1 | 20081023025304 | 39.984702 | 16.318417 | 39.984606 | 116.317065 | 2008-10-23 03:53:04+02 | 2008-10-23 03:53:50+02 | 00:00:46 | 8012597.30391588
On a side note: Storing longitude and latitude in separated columns is almost always a bad idea. If possible store them into a geometry or geography column. It might seem necessary at first, but PostGIS offers a ton of really kickass functions
!
Further reading: