Re: need help with some aggregation magic
От | Kevin Crain |
---|---|
Тема | Re: need help with some aggregation magic |
Дата | |
Msg-id | BANLkTimX4Pb6OxQdVmQFm4CYuqaCgS3K=w@mail.gmail.com обсуждение исходный текст |
Ответ на | need help with some aggregation magic (Andreas <maps.on@gmx.net>) |
Список | pgsql-sql |
Try this: select user_id, project_id, date_trunc, sum(sum) FROM (select user_id, project_id, date_trunc('day', ts), SUM(duration) FROM (select user_id, project_id, a.ts, ((SELECT MIN(b.ts) FROM log b WHERE b.ts>a.ts AND (date_trunc('day',a.ts)=date_trunc('day',b.ts)))-a.ts) AS duration from log a order by user_id, project_id, ts) AS foo group by user_id, project_id, ts) AS day_set group by user_id, project_id, date_trunc order by user_id, project_id, date_trunc; -Kevin Crain On Thu, Jun 9, 2011 at 6:43 AM, Andreas <maps.on@gmx.net> wrote: > hi, > I have a log-table that stores events of users and projects like this > ( user_id integer, project_id integer, ts timestamp, event_type integer ) > > I need an aggregated list of worktime per user, per project, per day. > > The users can switch projects during the day so I can't work this out with > min(ts) and max(ts). > > Is there a clever way to get this with SQL ? > > -- > Sent via pgsql-sql mailing list (pgsql-sql@postgresql.org) > To make changes to your subscription: > http://www.postgresql.org/mailpref/pgsql-sql >
В списке pgsql-sql по дате отправления: