From: | Michael Fuhr <mike(at)fuhr(dot)org> |
---|---|
To: | Dave Held <dave(dot)held(at)arrayservicesgrp(dot)com> |
Cc: | pgsql-performance(at)postgresql(dot)org |
Subject: | Re: Sort and index |
Date: | 2005-04-18 17:10:13 |
Message-ID: | 20050418171013.GA34421@winnie.fuhr.org |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-performance |
On Mon, Apr 18, 2005 at 10:44:43AM -0500, Dave Held wrote:
> >
> > I thought that an index can be used for sorting.
> > I'm a little confused about the following result:
> >
> > create index OperationsName on Operations(cOperationName);
> > explain SELECT * FROM Operations ORDER BY cOperationName;
> > QUERY PLAN
> > --------------------------------------------------------------
> > ---------
> > Sort (cost=185.37..189.20 rows=1532 width=498)
> > Sort Key: coperationname
> > -> Seq Scan on operations (cost=0.00..104.32 rows=1532 width=498)
> > (3 rows)
> >
> > Is this supposed to be so?
>
> Since you are fetching the entire table, you are touching all the rows.
> If the query were to fetch the rows in index order, it would be seeking
> all over the table's tracks. By fetching in sequence order, it has a
> much better chance of fetching rows in a way that minimizes head seeks.
> Since disk I/O is generally 10-100x slower than RAM, the in-memory sort
> can be surprisingly slow and still beat indexed disk access. Of course,
> this is only true if the table can fit and be sorted entirely in memory
> (which, with 1500 rows, probably can).
Out of curiosity, what are the results of the following queries?
(Queries run twice to make sure time differences aren't due to
caching.)
SET enable_seqscan TO on;
SET enable_indexscan TO off;
EXPLAIN ANALYZE SELECT * FROM Operations ORDER BY cOperationName;
EXPLAIN ANALYZE SELECT * FROM Operations ORDER BY cOperationName;
SET enable_seqscan TO off;
SET enable_indexscan TO on;
EXPLAIN ANALYZE SELECT * FROM Operations ORDER BY cOperationName;
EXPLAIN ANALYZE SELECT * FROM Operations ORDER BY cOperationName;
SELECT version();
With 1500 rows of random data, I consistently see better performance
with an index scan (about twice as fast as a sequence scan), and
the planner uses an index scan if it has a choice (i.e., when
enable_seqscan and enable_indexscan are both on). But my test case
and postgresql.conf settings might be different enough from yours
to account for different behavior.
--
Michael Fuhr
http://www.fuhr.org/~mfuhr/
From | Date | Subject | |
---|---|---|---|
Next Message | John A Meinel | 2005-04-18 17:16:14 | Re: How to improve db performance with $7K? |
Previous Message | Alex Turner | 2005-04-18 16:56:48 | Re: How to improve db performance with $7K? |