Re: Index usage with functions in where condition

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Jeremy Palmer <JPalmer(at)linz(dot)govt(dot)nz>
Cc: "pgsql-performance(at)postgresql(dot)org" <pgsql-performance(at)postgresql(dot)org>
Subject: Re: Index usage with functions in where condition
Date: 2010-07-09 23:19:50
Message-ID: 2741.1278717590@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

Jeremy Palmer <JPalmer(at)linz(dot)govt(dot)nz> writes:
> This is the query that does not use the indexes:

> SELECT
> coo.nod_id,
> 6400000*radians(sqrt((coo.value1 - -41.0618)^2+((coo.value2 - 175.58461)*cos(radians(-41.0618)))^2)) as distance
> FROM
> crs_coordinate coo
> WHERE
> coo.value1 between -41.0618-degrees(1200.0/6400000.0) and -41.0618+degrees(1200.0/6400000.0) and
> coo.value2 between 175.58461-degrees(1200.0/6400000.0)/(cos(radians(-41.0618))) and 175.58461+degrees(1200.0/6400000.0)/(cos(radians(-41.0618)));

Those expressions yield float8, not numeric, and numeric vs float8 isn't
an indexable operator for reasons we needn't get into here. You should
probably rethink whether numeric is really the best choice of datatype
for your columns, if this is the sort of value you expect to work with
--- you're paying a considerable price in speed and space for
perhaps-illusory precision gains. But if you insist on using numeric
then the solution is to cast the expression results to numeric
explicitly.

BTW I wonder whether you ought not be looking into postgis rather than
rolling-your-own coordinate arithmetic ...

regards, tom lane

In response to

Responses

Browse pgsql-performance by date

  From Date Subject
Next Message Greg Smith 2010-07-09 23:23:53 Re: [Slony1-general] WAL partition overloaded--by autovacuum?
Previous Message Greg Smith 2010-07-09 22:59:13 Re: Need help in performance tuning.