Re: window function to sort times series data?

Поиск
Список
Период
Сортировка
От A. Kretschmer
Тема Re: window function to sort times series data?
Дата
Msg-id 20100324150441.GC15442@a-kretschmer.de
обсуждение исходный текст
Ответ на Re: window function to sort times series data?  (Louis-David Mitterrand <vindex+lists-pgsql-sql@apartia.org>)
Ответы Re: window function to sort times series data?  (Andreas Kretschmer <akretschmer@spamfence.net>)
Список pgsql-sql
In response to Louis-David Mitterrand :
> On Wed, Mar 24, 2010 at 03:29:36PM +0100, A. Kretschmer wrote:
> > In response to Louis-David Mitterrand :
> > > Hi,
> > > 
> > > I have time series data: price(id_price int, price int, created_on timestamp)
> > > 
> > > I'd like to select the latest price before, say, 2010-03-10 and the
> > > latest price after that date.
> > 
> > test=*# select * from price ;
> >  id_price | price |     created_on
> > ----------+-------+---------------------
> >         1 |    10 | 2010-01-01 00:00:00
> >         1 |    12 | 2010-02-01 00:00:00
> >         1 |     8 | 2010-03-01 00:00:00
> >         1 |    15 | 2010-03-10 00:00:00
> >         1 |    13 | 2010-03-20 00:00:00
> > (5 rows)
> > 
> > test=*# select * from (
> >   select distinct on(id_price) id_price, price, created_on from price where created_on < '2010-02-20'::date order
byid_price, created_on desc
 
> > ) foo union all select * from (
> >   select distinct on(id_price) id_price, price, created_on from price where created_on > '2010-02-20'::date order
byid_price, created_on asc
 
> > ) bar order by id_price,created_on ;
> >  id_price | price |     created_on
> > ----------+-------+---------------------
> >         1 |    12 | 2010-02-01 00:00:00
> >         1 |     8 | 2010-03-01 00:00:00
> > (2 rows)
> > 
> > That's okay for you?
> 
> Yes, that works, but I forgot in my specs (!) that I'd like the two
> prices (pre and post 2010-03-10) to be returned on the same row and only
> if a post-2010-03-10 price exists.

Well:

test=*# select * from price ;id_price | price |     created_on
----------+-------+---------------------       1 |    10 | 2010-01-01 00:00:00       1 |    12 | 2010-02-01 00:00:00
  1 |     8 | 2010-03-01 00:00:00       1 |    15 | 2010-03-10 00:00:00       1 |    13 | 2010-03-20 00:00:00
 
(5 rows)

test=*# select id_price, sum(case when pre_post='pre' then price else 0
end) as pre, sum(case when pre_post='post' then price else 0 end) as
post, max(case when pre_post='pre' then created_on else null end) as
date_pre, max(case when pre_post='post' then created_on else null end)
as date_post from (select * from (select distinct on(id_price)
'pre'::text as pre_post, id_price, price, created_on from price where
created_on < '2010-02-20'::date order by id_price, created_on desc) foo
union all select * from (select distinct on(id_price) 'post'::text,
id_price, price, created_on from price where created_on >
'2010-02-20'::date order by id_price,created_on asc) bar order by
id_price, created_on) foo group by id_price;id_price | pre | post |      date_pre       |      date_post
----------+-----+------+---------------------+---------------------       1 |  12 |    8 | 2010-02-01 00:00:00 |
2010-03-0100:00:00
 
(1 row)


You can filter that result for rows where date_post is not null.


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 по дате отправления:

Предыдущее
От: Louis-David Mitterrand
Дата:
Сообщение: Re: window function to sort times series data?
Следующее
От: Andreas Kretschmer
Дата:
Сообщение: Re: window function to sort times series data?