Re: Help Need some hindsight - Mailing list pgsql-sql

From A. Kretschmer
Subject Re: Help Need some hindsight
Date
Msg-id 20100804114808.GB5435@a-kretschmer.de
Whole thread Raw
In response to Help Need some hindsight  (Andreas <maps.on@gmx.net>)
List pgsql-sql
In response to Andreas :
>  Hi,
> I need to display log events (again).
> The log is simply like this
> log ( log_id serial primary key, create_ts timestamp default 
> localtimestamp, object_id, state_id, ....... )
> 
> It records the state of objects and when and what happend to to change 
> this state.
> 
> I'd like to get a list that shows the current state at any point of time 
> and the state of the last event before regarding the current object_id.
> The tricky bit is that both states should appear in the same row for 
> every row.
> 
> Help?


something like:

test=*# select * from log;id |             ts             | object_id | state_id
----+----------------------------+-----------+---------- 1 | 2010-08-04 13:24:19.648437 |         1 |        1 2 |
2010-08-0413:24:26.957629 |         1 |        2 3 | 2010-08-04 13:24:38.883519 |         1 |        3 4 | 2010-08-04
13:24:43.60719 |         1 |        2 5 | 2010-08-04 13:24:51.123276 |         1 |        4
 
(5 rows)

test=*#
test=*#
test=*# 
select max(case when row_number=1 then id else null end) as current_state_id,       max(case when row_number=2 then id
elsenull end) as last_state_id,       max(case when row_number=1 then state_id else null end) as current_state,
max(casewhen row_number=2 then state_id else null end) as last_state 
 
from ((select 1 as row_number, * from log where object_id=1 and ts < '2010-08-04 13:24:38.883520' order by ts desc
limit1) union all     (select 2, * fromlog where object_id=1 and ts < '2010-08-04 13:24:38.883520' order by ts desc
limit1 offset 1)) foo ;current_state_id | last_state_id | current_state | last_state
 
------------------+---------------+---------------+------------               3 |             2 |             3 |
  2
 
(1 row)

As you can see, the where-condition contains a timestamp that isn't in the table, it's after the id=3.

Maybe there are other, better solutions...


HTH, Andreas
-- 
Andreas Kretschmer
Kontakt:  Heynitz: 035242/47150,   D1: 0160/7141639 (mehr: -> Header)
GnuPG: 0x31720C99, 1006 CCB4 A326 1D42 6431  2EB0 389D 1DC2 3172 0C99


pgsql-sql by date:

Previous
From: Frank Bax
Date:
Subject: Re: What does PostgreSQL do when time goes backward?
Next
From: Kenneth Marshall
Date:
Subject: Re: What does PostgreSQL do when time goes backward?