Hello,
I have recently upgraded to PostgreSQL 9.2.0 and one of my queries is now
giving incorrectly sorted results due, I believe, to the new index-only scan in
9.2.0. The below table is a table of currency FX rates by date.
template1=# \d fx0;
Table "public.fx0"
Column | Type | Modifiers
---------+----------------------+-----------
date | date | not null
fromcur | character varying(3) | not null
fx | numeric(16,8) | not null
tocur | character varying(3) | not null
Indexes:
"pk_fx0" PRIMARY KEY, btree (date, fromcur, tocur)
This query correctly sorts the chosen two currencies by date;
> SELECT * FROM fx0 WHERE fromcur IN ('AUD','JPY') ORDER BY date desc;
date | fromcur | fx | tocur
------------+---------+------------+-------
2012-09-14 | JPY | 0.01276592 | USD
2012-09-14 | AUD | 1.05741440 | USD
2012-09-13 | JPY | 0.01291478 | USD
2012-09-13 | AUD | 1.04486224 | USD
2012-09-12 | AUD | 1.04491173 | USD
2012-09-12 | JPY | 0.01284250 | USD
2012-09-11 | JPY | 0.01285457 | USD
2012-09-11 | AUD | 1.04324956 | USD
<...snip...>
template1=# explain select * FROM fx0 where fromcur IN ('AUD','JPY') ORDER BY
date desc;
QUERY PLAN
------------------------------------------------------------------
Sort (cost=21139.98..21181.31 rows=16530 width=19)
Sort Key: date
-> Seq Scan on fx0 (cost=0.00..19981.83 rows=16530 width=19)
Filter: ((fromcur)::text = ANY ('{AUD,JPY}'::text[]))
(4 rows)
Now I will add a simple condition that date >='2012-09-11'. The output should
exactly match the (truncated) results above:
template1=# select * FROM fx0 where fromcur IN ('AUD','JPY') and date
>='2012-09-11' ORDER BY date desc;
date | fromcur | fx | tocur
------------+---------+------------+-------
2012-09-14 | JPY | 0.01276592 | USD
2012-09-13 | JPY | 0.01291478 | USD
2012-09-12 | JPY | 0.01284250 | USD
2012-09-11 | JPY | 0.01285457 | USD
2012-09-14 | AUD | 1.05741440 | USD
2012-09-13 | AUD | 1.04486224 | USD
2012-09-12 | AUD | 1.04491173 | USD
2012-09-11 | AUD | 1.04324956 | USD
(8 rows)
Note however that the table was NOT sorted by date, but by fromcur
(descending), then date. Let's look at the explain:
template1=# explain select * FROM fx0 where fromcur IN ('AUD','JPY') and date
>='2012-09-11' ORDER BY date desc;
QUERY PLAN
------------------------------------------------------------------------------------------------
Index Scan Backward using pk_fx0 on fx0 (cost=0.00..40.54 rows=12 width=19)
Index Cond: ((date >= '2012-09-11'::date) AND ((fromcur)::text = ANY
('{AUD,JPY}'::text[])))
(2 rows)
The first (correct) query used a Seq Scan, and the second (incorrect) a Index
Scan, leading me to believe there's a problem with the Index Scan in this query
and/or table design.
Please let me know if I can provide any other information.
Regards,
Robert McGehee
PS. I analyzed, vacuumed, reindexed, clustered this table, and even made a a
brand new copy, but the problem persists.
--
Sent via pgsql-bugs mailing list ([email protected])
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-bugs