"Zaremba, Don" <dzaremba@ellacoya.com> writes:
> This does a full sequential scan
> select id from details where begin_time > to_timestamp('03/08/25
> 18:30');
to_timestamp('foo') is not a constant, so the planner doesn't know how
much of the table this is going to select. In the absence of that
knowledge, its default guess favors a seqscan.
> This uses the index
> select id from details where begin_time > '03/08/25 18:30';
Here the planner can consult pg_stats to get a pretty good idea how
much of the table will be scanned; if the percentage is small enough
it will pick an indexscan.
There are various ways to deal with this --- one thing you might
consider is making a wrapper function for to_timestamp that is
marked "immutable", so that it will be constant-folded on sight.
That has potential gotchas if you want to put the query in a function
though. Another tack is to make the query into a range query:
where begin_time > ... AND begin_time < 'infinity';
See the archives for more discussion.
regards, tom lane