Re: Window function sort order help

Поиск
Список
Период
Сортировка
От Tim Landscheidt
Тема Re: Window function sort order help
Дата
Msg-id m3aaa4nisy.fsf@passepartout.tim-landscheidt.de
обсуждение исходный текст
Ответ на Window function sort order help  (Dianna Harter <dharter@mynewplace.com>)
Ответы Re: Window function sort order help  (Dianna Harter <dharter@mynewplace.com>)
Список pgsql-sql
Dianna Harter <dharter@mynewplace.com> wrote:

> Having trouble getting a window function to sort correctly.

> Given this data

> consumer_id | move_date  |     history_timestamp
> -------------+------------+----------------------------
>        12345| 2008-01-05 | 2007-12-11 06:02:26.842171
>        12345| 2008-02-29 | 2008-02-05 07:22:38.04067
>        12345| 2008-02-29 | 2008-07-11 09:03:42.44044
>        23456| 2009-01-01 | 2008-11-12 07:33:32.656658 <--
>        23456| 2009-01-28 | 2008-11-14 01:57:40.264335
>        23456| 2009-01-01 | 2008-12-04 17:14:20.279999 <--
>        23456| 2009-01-01 | 2008-12-31 00:33:37.204968
>        23456| 2009-01-01 | 2011-06-08 04:16:41.646521
>        34567| 2010-05-07 | 2010-06-08 05:14:43.842172

> I'm trying to get the timestamp when the consumer last changed their move_date.  (Notice consumer_id 23456 set their
move_dateto 2009-01-01 then changed and then changed it back.  In the end, I want the timestamp from when they changed
itto 2009-01-01 the second time.)
 

> My thought was to do an intermediary step to find the timestamp for each time it switched.  From there I can grab the
max(timestamp)for each consumer.
 

> [...]

> Any suggestions to get the order by to occur first then the partition by or maybe there another approach that I could
use?

If I understand the question correctly, try:

| SELECT DISTINCT ON (consumer_id) consumer_id, move_date, history_timestamp
|        FROM (SELECT consumer_id, move_date, history_timestamp,
|                     LAG(move_date) OVER (PARTITION BY consumer_id ORDER BY consumer_id, history_timestamp) AS
previous_move_date
|                     FROM consumer_hist) AS SubQuery
|        WHERE move_date IS DISTINCT FROM previous_move_date
|        ORDER BY consumer_id, history_timestamp DESC;

Tim



В списке pgsql-sql по дате отправления:

Предыдущее
От: Frank Bax
Дата:
Сообщение: Re: Clever way to check overlapping time intervals ?
Следующее
От: Leif Biberg Kristensen
Дата:
Сообщение: Passing function parameters to regexp_replace