Re: best db schema for time series data?

Поиск
Список
Период
Сортировка
От Harald Fuchs
Тема Re: best db schema for time series data?
Дата
Msg-id 86zkt9qllo.fsf@mgm.protecting.net
обсуждение исходный текст
Ответ на best db schema for time series data?  (Louis-David Mitterrand <vindex+lists-pgsql-performance@apartia.org>)
Ответы Re: best db schema for time series data?
Список pgsql-performance
In article <4CE2688B.2050000@tweakers.net>,
Arjen van der Meijden <acmmailing@tweakers.net> writes:

> On 16-11-2010 11:50, Louis-David Mitterrand wrote:
>> I have to collect lots of prices from web sites and keep track of their
>> changes. What is the best option?
>>
>> 1) one 'price' row per price change:
>>
>> create table price (
>> id_price primary key,
>> id_product integer references product,
>> price integer
>> );
>>
>> 2) a single 'price' row containing all the changes:
>>
>> create table price (
>> id_price primary key,
>> id_product integer references product,
>> price integer[] -- prices are 'pushed' on this array as they change
>> );
>>
>> Which is bound to give the best performance, knowing I will often need
>> to access the latest and next-to-latest prices?

> If you mostly need the last few prices, I'd definitaly go with the
> first aproach, its much cleaner. Besides, you can store a date/time
> per price, so you know when it changed. With the array-approach that's
> a bit harder to do.

I'd probably use a variant of this:

  CREATE TABLE prices (
    pid int NOT NULL REFERENCES products,
    validTil timestamp(0) NULL,
    price int NOT NULL,
    UNIQUE (pid, validTil)
  );

The current price of a product is always the row with validTil IS NULL.
The lookup should be pretty fast because it can use the index of the
UNIQUE constraint.

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

Предыдущее
От: Alvaro Herrera
Дата:
Сообщение: Re: autovacuum blocks the operations of other manual vacuum
Следующее
От: Chris Browne
Дата:
Сообщение: Re: best db schema for time series data?