Re: how to calculate differences of timestamps? - Mailing list pgsql-sql

From Tim Landscheidt
Subject Re: how to calculate differences of timestamps?
Date
Msg-id m3k48uzoxj.fsf@passepartout.tim-landscheidt.de
Whole thread Raw
In response to how to calculate differences of timestamps?  (Andreas <maps.on@gmx.net>)
List pgsql-sql
(anonymous) wrote:

> How could I calculate differences of timestamps in a log-table?

> Table log ( user_id integer, login boolean, ts timestamp )

> So login = true would be a login-event and login = false a logout.
> Is there a way to find the matching login/logout to
> calculate the difference?

This is similar to the question Dianna asked some time ago:

| SELECT user_id,
|        prev_ts AS login_ts,
|        ts AS logout_ts
|        FROM (SELECT user_id,
|                     LAG(login) OVER (PARTITION BY user_id ORDER BY ts) AS prev_login,
|                     LAG(ts) OVER (PARTITION BY user_id ORDER BY ts) AS prev_ts,
|                     login,
|                     ts FROM log) AS SubQuery
|        WHERE prev_login AND NOT login;

> Or is there a better table "design" to do this?

That depends on your requirements and your application de-
sign. The query above requires a full table scan which may
kill performance in some circumstances.
 Of course, any design has to deal with the possibility of
an event not having been logged, multiple logins, etc. The
query above just forms pairs based on temporal proximity.

Tim



pgsql-sql by date:

Previous
From: Andreas
Date:
Subject: how to calculate differences of timestamps?
Next
From: Steve Crawford
Date:
Subject: Re: how to calculate differences of timestamps?