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)
Ответы: Re: index over timestamp not being used  (Arnau)
Список: pgsql-performance

Скрыть дерево обсуждения

index over timestamp not being used  (Arnau, )
 Re: index over timestamp not being used  (Tom Lane, )
  Re: index over timestamp not being used  (Arnau, )
   Re: index over timestamp not being used  (Tom Lane, )
    Re: index over timestamp not being used  (Mario Weilguni, )
     Re: index over timestamp not being used  (Ansgar -59cobalt- Wiechers, )

Arnau <> 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 по дате сообщения:

От: Tom Lane
Дата:
Сообщение: Re: index over timestamp not being used
От: "Merlin Moncure"
Дата:
Сообщение: Re: 8.2 -> 8.3 performance numbers