Re: index over timestamp not being used

Поиск
Список
Период
Сортировка
От Tom Lane
Тема Re: index over timestamp not being used
Дата
Msg-id 14907.1185305095@sss.pgh.pa.us
обсуждение исходный текст
Ответ на index over timestamp not being used  (Arnau <arnaulist@andromeiberica.com>)
Ответы Re: index over timestamp not being used  (Arnau <arnaulist@andromeiberica.com>)
Список pgsql-performance
Arnau <arnaulist@andromeiberica.com> writes:
> timestamp_in          | timestamp without time zone | default now()

> SELECT ...
> FROM
>   transactions t
>   LEFT OUTER JOIN statistics s ON t.transaction_id = s.transaction_id
> WHERE
>   t.timestamp_in >= to_timestamp('20070101', 'YYYYMMDD')
> GROUP BY date, t.type_id;

to_timestamp() produces timestamp *with* timezone, so your WHERE query
is effectively
    t.timestamp_in::timestamptz >= to_timestamp('20070101', 'YYYYMMDD')
which doesn't match the index.

The first question you should ask yourself is whether you picked the
right datatype for the column.  IMHO timestamp with tz is the more
appropriate choice in the majority of cases.

If you do want to stick with timestamp without tz, you'll need to cast
the result of to_timestamp to that.

Alternatively, do you really need to_timestamp at all?  The standard
timestamp input routine won't have any problem with that format:
    t.timestamp_in >= '20070101'

            regards, tom lane

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

Предыдущее
От: "Campbell, Lance"
Дата:
Сообщение: Re: Table Statistics with pgAdmin III
Следующее
От: Arnau
Дата:
Сообщение: Re: index over timestamp not being used