Re: Getting current and average on a single row

Поиск
Список
Период
Сортировка
От Mark Morgan Lloyd
Тема Re: Getting current and average on a single row
Дата
Msg-id icjijd$87e$1@pye-srv-01.telemetry.co.uk
обсуждение исходный текст
Ответ на Getting current and average on a single row  (Mark Morgan Lloyd <markMLl.pgsql-general@telemetry.co.uk>)
Список pgsql-general
Adrian Klaver wrote:
> On Wednesday 24 November 2010 1:08:27 am Mark Morgan Lloyd wrote:
>> What is best practice when extracting both current and average from a
>> table? Demonstration table here contains data from a cheap weather station.
>>
>> I can obviously get the current reading like this:
>>
>> select temp_out, dewpoint
>> from weather
>> where datetime between (now() - '10 minutes'::interval) and now()
>> order by datetime desc
>> limit 1;
>>
>> and I can get averages like this:
>>
>> select avg(temp_out) as avg_temp_out, avg(dewpoint) as avg_dewpoint
>> from weather
>> where datetime between (now() - '45 minutes'::interval) and now();
>>
>> In both cases there are a dozen or so columns in total. How are these
>> best merged to yield a single row? Some form of join, or window functions?
>
> I am not seeing a dozen columns, maybe rows?

I'd only put in a couple of columns as an example, but I was also making
the point that it would be nice to avoid having to type in an excessive
number of column names.

> I quick and dirty solution(testing needed):
>
> select
> temp_out,dewpoint,atbl.avg_temp_out,atbl.avg_dewpoint
> from
> (select avg(temp_out) as avg_temp_out, avg(dewpoint) as avg_dewpoint
> from weather
> where datetime between (now() - '45 minutes'::interval) and now()) as atbl,
> weather
> order by datetime desc limit 1;

Has to be a bit more complex than that to make sure that the current
reading really is current:

select
ctbl.temp_out,ctbl.dewpoint,
atbl.avg_temp_out,atbl.avg_dewpoint
from (
   select avg(temp_out) as avg_temp_out, avg(dewpoint) as avg_dewpoint
   from weather
   where datetime between (now() - '45 minutes'::interval) and now()
) as atbl, (
   select * from weather
   where datetime between (now() - '8 minutes'::interval) and now()
   order by datetime desc limit 1
) as ctbl;

explain prices that as Nested Loop  (cost=8.30..16.62 rows=1 width=84).
I think it's more elegant than the SQL I'm currently using

select * from (
   select * from weather
   where datetime between (now() - '10 minutes'::interval) and now()
   order by datetime desc
   limit 1
) as foo left outer join (
   select datetime, avg(temp_out) as avg_temp_out, avg(dewpoint) as
avg_dewpoint
   from weather
   where datetime between (now() - '45 minutes'::interval) and now()
   group by datetime
) as bar using (datetime);

but I note that explain prices that as Nested Loop Left Join
(cost=0.02..16.63 rows=1 width=215).

Does that mean that the query using the nested join will, on average, be
more efficient?

--
Mark Morgan Lloyd
markMLl .AT. telemetry.co .DOT. uk

[Opinions above are the author's, not those of his employers or colleagues]

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

Предыдущее
От: Stuart McGraw
Дата:
Сообщение: Re: alter table add column - specify where the column will go?
Следующее
От: Tom Lane
Дата:
Сообщение: Re: alter table add column - specify where the column will go?