Re: view of weekly data - Mailing list pgsql-sql

From Greg Stark
Subject Re: view of weekly data
Date
Msg-id 87hd6x15l2.fsf@stark.xeocode.com
Whole thread Raw
In response to view of weekly data  ("Ding Xiangguang" <Xiangguang@singtel.com>)
List pgsql-sql
"Ding Xiangguang" <Xiangguang@singtel.com> writes:

> Hi, friend,
> 
> Suppose there is table of daily transaction data with 5 fields,
> 
> time(date), open(float8), high(float8), low(float8), close(float8)
> 
> Is it possible to create a view of weekly data, i.e. open is the first
> day'open, high is the highest of the week, low is the lowest of the week, close
> is the last day's close.

low and high are easy, they're just min() and max(). so you would get
something like:

select date_trunc('week', time) as startofweek,       min(low) as weeklylow,       max(high) as weeklyhigh from
dailydatagroupby date_trunc('week', time)
 


Unfortunately showing the open and close is much much harder. To get them
efficiently requires a feature set called OLAP that Postgres doesn't have and
isn't likely to get soon.

In Postgres 8.1 (and 8.0?) you could actually write some custom aggregate
functions using RECORD data type to store the earliest and latest time found
so far and the corresponding open and close to get them efficiently. Maybe
someone else would be able to show how to do that, I haven't tried it yet.

The only way to do it in standardish SQL would be with terribly inefficient
subqueries:

select date_trunc('week', time) as startofweek,       min(low) as weeklylow,       max(high) as weeklyhigh,
(selectopen          from dailydata as d         where date_trunc('week',time)=date_trunc('week',dailydata.time)
orderby time asc        limit 1      ) as weeklyopen,      (select close         from dailydata as d         where
date_trunc('week',time)=date_trunc('week',dailydata.time)       order by time desc        limit 1      ) as weeklyclose
fromdailydatagroup by date_trunc('week', time)
 


-- 
greg



pgsql-sql by date:

Previous
From: Axel Straschil
Date:
Subject: ORDER BY with LTREE
Next
From: Greg Stark
Date:
Subject: Re: Tough Problem -- Record Checkouts