Re: how to calculate differences of timestamps?
От | Steve Crawford |
---|---|
Тема | Re: how to calculate differences of timestamps? |
Дата | |
Msg-id | 4E81F506.6010604@pinpointresearch.com обсуждение исходный текст |
Ответ на | how to calculate differences of timestamps? (Andreas <maps.on@gmx.net>) |
Список | pgsql-sql |
On 09/26/2011 06:31 PM, Andreas 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? > > Or is there a better table "design" to do this? > One way is a sub_select: select o.user_id, o.ts as logout_time, (select max(i.ts) from log i where i.user_id= o.user_id and i.ts < o.ts and login ) as login_time from log where not login ; This will give you login/logout time pairs. Just replace the "," with a "-" if you are interested in login duration. Depending on the frequency and duration of logins and the number of users you may have to play with indexes though an index on ts will probably suffice for most cases. Cheers, Steve
В списке pgsql-sql по дате отправления: