From: | David Johnston <polobo(at)yahoo(dot)com> |
---|---|
To: | pgsql-sql(at)postgresql(dot)org |
Subject: | Re: Table results format - should I use crosstab? If so, how? |
Date: | 2014-03-19 15:47:50 |
Message-ID: | 1395244070835-5796803.post@n5.nabble.com |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-sql |
Jennifer Mackown wrote
> Hi,
> I have a problem with getting a table to display in the way I want it to.
> It's one of those things that looks so simple I should be able to do it in
> 5 minutes, but I've been working on it all afternoon and I'm getting
> nowhere!!
> What I have is the following:
> Date Firstday Lastday2014/03/12 1
> 12014/03/18 1 02014/03/19 0
> 12014/03/21 1 1
>
> And what I need to see is this:
> Firstday Lastday2014/03/12 2013/03/122014/03/18
> 2013/03/192014/03/21 2013/03/21
WITH data (dt, isfirst, islast) AS ( --setup data
VALUES ('2014-03-12'::date, true, true), ('2013-03-18', true, false),
('2013-03-19', false, true), ('2013-03-21', true, true)
)
, explode AS ( --need to convert columns to rows; use UNION ALL to do this
SELECT dt, 1 AS pos FROM data WHERE isfirst --all start rows
UNION ALL
SELECT dt, 2 AS pos FROM data WHERE islast --all end rows
)
, ordered AS ( --need to arrange the rows so start comes before end
SELECT * FROM explode ORDER BY dt ASC, pos
)
SELECT firstday, lastday FROM ( --then for each end row in the pair get the
immediately prior row as its start
SELECT pos, dt AS lastday, lag(dt) OVER () AS firstday
FROM ordered
) calc WHERE pos = 2 ORDER BY firstday DESC --and only display the end rows
;
This directly solves the problem, however:
1) Start & End dates must be defined in pairs (none missing and no extra
dates in between)
2) There can be no overlapping ranges
Ideally you would have some kind of identifier attached to every start date
and a corresponding identifier on the matching end date. Partitioning on
that identifier and taking the first and last date found would be the most
stable method.
David J.
--
View this message in context: http://postgresql.1045698.n5.nabble.com/Table-results-format-should-I-use-crosstab-If-so-how-tp5796797p5796803.html
Sent from the PostgreSQL - sql mailing list archive at Nabble.com.
From | Date | Subject | |
---|---|---|---|
Next Message | hari.fuchs | 2014-03-19 17:56:58 | Re: Table results format - should I use crosstab? If so, how? |
Previous Message | Jennifer Mackown | 2014-03-19 14:58:57 | Table results format - should I use crosstab? If so, how? |