Обсуждение: any way to make query use index?
I am working through our application looking for ways to eliminate seq
scans in our database. I am looking for some help with this query.
SELECT rev_desc FROM rev_code_desc WHERE rev_code = lpad('0300', 4, '0')
Is there anyway to make postgres use an index on this query?
Here is the table definition:
CREATE TABLE rev_code_desc
(
rev_code character(4) NOT NULL,
rev_desc text,
user_id character varying(12),
live_rec boolean DEFAULT true,
CONSTRAINT rev_code_desc_pkey PRIMARY KEY (rev_code)
)
Right now, I can't seem to get it to use an index for this type of
query. Of course, in our application it is SELECT rev_desc FROM
rev_code_desc WHERE rev_code = lpad(<program variable>, 4, '0').
Thanks for any help,
Chris
PG 8.1.3
"Chris Hoover" <revoohc@gmail.com> writes:
> SELECT rev_desc FROM rev_code_desc WHERE rev_code = lpad('0300', 4, '0')
> Is there anyway to make postgres use an index on this query?
> Here is the table definition:
> CREATE TABLE rev_code_desc
> (
> rev_code character(4) NOT NULL,
Since rev_code is char(n), you need to cast the other thing to char(n)
as well:
SELECT rev_desc FROM rev_code_desc WHERE rev_code = lpad('0300', 4, '0')::char(4)
lpad() is declared to return text, which means that your original query
resolves as ... WHERE rev_code::text = lpad('0300', 4, '0'), which
means that the index on rev_code is useless (since it has bpchar
semantics not text semantics).
If changing the queries seems impractical, you could add an index on
rev_code::text, or reconsider the choice of column type.
regards, tom lane
On Nov 15, 2007 11:25 AM, Tom Lane <tgl@sss.pgh.pa.us> wrote: > > Here is the table definition: > > CREATE TABLE rev_code_desc > > ( > > rev_code character(4) NOT NULL, > If changing the queries seems impractical, you could add an index on > rev_code::text, or reconsider the choice of column type. > > regards, tom lane > how would you create this index? create index rev_code_text_idx on rev_code_desc(rev_code::text) fails complaining "ERROR: syntax error at or near "::"" Thanks Chris
"Chris Hoover" <revoohc@gmail.com> writes:
> On Nov 15, 2007 11:25 AM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
>> If changing the queries seems impractical, you could add an index on
>> rev_code::text, or reconsider the choice of column type.
> how would you create this index? create index rev_code_text_idx on
> rev_code_desc(rev_code::text) fails complaining "ERROR: syntax error
> at or near "::""
You need more parentheses --- read the docs about expression indexes.
regards, tom lane