Thread: select ... where ='' does a seqscan [auf Viren geprueft]
Hello,
I'm new to the list and did not find a suitable answer to my question so here it is:
I try to select the rows of a table where the content of a varchar-column is empty ('') and PostgresQL is doing a seqscan.
I've tried this on a PostgresQL-Serverversion 7.3.4 and 8.0 beta1.
To understand my example better, here's the layout of the content of this table:
I have a table document. For each document there are a couple of parameters in table document_param (name-value-pairs).
The table now holds 7 million rows, so a seqscan is quite expensive.
Now some values are empty (as in this example is the param_value of READ_DATE).
document_param_id | document_id | param_name | param_value |
---------------------------+---------------------------+------------+------------------+
1010110101000000007482877 | 1010110101000000001090647 | KONTO_NR | 1000000000 |
1010110101000000007482878 | 1010110101000000001090647 | KZ_READ | N |
1010110101000000007482879 | 1010110101000000001090647 | READ_DATE | |
1010110101000000007482880 | 1010110101000000001090647 | ENTAX_NR | 2000000000000000 |
1010110101000000007482881 | 1010110101000000001090647 | DOC_SOURCE | 400 |
1010110101000000007482882 | 1010110101000000001090647 | KUNDEN_NR | 1000000 |
I want to get all rows where for example the 'KONTO_NR' is empty.
I tried this with:
explain select * from document_params where param_name='KONTO_NR' and param_value='';
this produced:
QUERY PLAN
------------------------------------------------------------------------------------------
Seq Scan on document_params (cost=0.00..241600.27 rows=152073 width=95)
Filter: (((param_name)::text = 'KONTO_NR'::text) AND ((param_value)::text = ''::text))
(2 rows)
There's a multicolumn index (param_value,param_name) on document_params. To be sure the index works I changed the select to
explain select * from document_params where param_name='KONTO_NR' and param_value=' ';
(looking for a space in param_value), and viola, the index is used. But not if I'm looking for ''.
Following a reply to an similar question where NULL-values where wanted, I made a partial index:
create index idx_empty on document_params(param_name) where param_value='';
But PostgresQL does not use it.
When I disable seqscan (set enable_seqscan=false), an explain returns this:
QUERY PLAN
--------------------------------------------------------------------------------------------
Index Scan using idx_empty on document_params (cost=0.00..591783.84 rows=152073 width=95)
Index Cond: ((param_name)::text = 'KONTO_NR'::text)
Filter: ((param_value)::text = ''::text)
So using the index does need more time than a sequential scan?
How can I get the rows with empty values from the table without doing a seqscan?
Any help would be highly appreciated.
Ciao,
Silvio Matthes
Am Dienstag, 24. August 2004 11:59 schrieb Silvio Matthes: > So using the index does need more time than a sequential scan? It's possible. If you want to prove the opposite, please post the output of EXPLAIN ANALYZE in both cases. -- Peter Eisentraut http://developer.postgresql.org/~petere/
Silvio Matthes <silvio.matthes@xcom.de> writes: > I try to select the rows of a table where the content of a varchar-column > is empty ('') and PostgresQL is doing a seqscan. If there are a very large number of rows with param_value='', it's entirely possible that using an index to find them is counterproductive. regards, tom lane
Hello Tom,
>> I try to select the rows of a table where the content of a varchar-column
>> is empty ('') and PostgresQL is doing a seqscan.
>If there are a very large number of rows with param_value='', it's
>entirely possible that using an index to find them is counterproductive.
That's right. I did some research on my database, that's what I found.
select count(*) from document_params;
count
---------
7302418
select param_name,count(param_name) from document_params where param_value='' group by param_name;
param_name | count
------------+---------
READ_DATE | 1064944
ENTAX_NR | 85853
KONTO_NR | 6672
KUNDEN_NR | 7
So it's ok not using an index for
select count(*) from document_params where param_value='';
But
explain select count(*) from document_params where param_name='KUNDEN_NR' and param_value='';
also did a seqscan.
And
explain select count(*) from document_params where param_name='KONTO_NR' and param_value='test';
did an indexscan!
So at the moment it seems to me, that the multicolumn index is not working in the expected way.
The ''-value is not the problem. The problem is that there are a million rows with ''-value.
But in my opinion with the multicolumn index in mind the server should do a index scan, because there are only 7 rows with param_name='KUNDEN_NR' and param_value=''?!?
Disabling seqscan gives:
explain select count(*) from document_params where param_name='KUNDEN_NR' and param_value='';
QUERY PLAN
-----------------------------------------------------------------------------------------------------
Aggregate (cost=639336.57..639336.57 rows=1 width=0)
-> Index Scan using dp_idx_6 on document_params (cost=0.00..638934.84 rows=160694 width=0)
Index Cond: (((param_value)::text = ''::text) AND ((param_name)::text = 'KUNDEN_NR'::text))
Postmaster is using the multicolumn index (param_value,param_name), but not in the expected time...
as always, any help would be highly appreciated.
Ciao,
Silvio Matthes
Tom Lane <tgl@sss.pgh.pa.us> Gesendet von: pgsql-general-owner@postgresql.org 24.08.2004 17:35 |
|
Silvio Matthes <silvio.matthes@xcom.de> writes:
> I try to select the rows of a table where the content of a varchar-column
> is empty ('') and PostgresQL is doing a seqscan.
If there are a very large number of rows with param_value='', it's
entirely possible that using an index to find them is counterproductive.
regards, tom lane
---------------------------(end of broadcast)---------------------------
TIP 5: Have you checked our extensive FAQ?
http://www.postgresql.org/docs/faqs/FAQ.html
Silvio Matthes <silvio.matthes@xcom.de> writes: > But in my opinion with the multicolumn index in mind the server should do > a index scan, because there are only 7 rows with param_name='KUNDEN_NR' > and param_value=''?!? We do not have any cross-column statistics at the moment, so the planner is unable to recognize the potential win here. Note the poor estimate of the number of matching rows in your EXPLAIN result. I think though that it might help to put param_name first in the multicolumn index. regards, tom lane
>> But in my opinion with the multicolumn index in mind the server should do
>> a index scan, because there are only 7 rows with param_name='KUNDEN_NR'
>> and param_value=''?!?
>We do not have any cross-column statistics at the moment, so the planner
>is unable to recognize the potential win here. Note the poor estimate
>of the number of matching rows in your EXPLAIN result.
So would using the index in this case improve the performance?
In short tests it seems so. But I'm running into issues that postmaster seems to cache the results.
Is there a way to switch of caching the results (even stopping and restarting the service on win32 did not bring the desired result...)?
Is it planned to put this feature (cross-column statistics) in postgresQL in the future? What version could it be?
>I think though that it might help to put param_name first in the
>multicolumn index.
it helps, but not much, the performance-gain of the multicolumn index is 20%-80%. the planner still wants a seqscan, so we're talking about 50-60s. If forced to indexscan, the time drops to 70-180ms!
Is it possible to force the planner to use an index on a per-statement-base, so without using the set enable_seqscan-command?
Kind Regards,
Silvio Matthes
Tom Lane <tgl@sss.pgh.pa.us> 24.08.2004 18:52 |
|
Silvio Matthes <silvio.matthes@xcom.de> writes:
> But in my opinion with the multicolumn index in mind the server should do
> a index scan, because there are only 7 rows with param_name='KUNDEN_NR'
> and param_value=''?!?
We do not have any cross-column statistics at the moment, so the planner
is unable to recognize the potential win here. Note the poor estimate
of the number of matching rows in your EXPLAIN result.
I think though that it might help to put param_name first in the
multicolumn index.
regards, tom lane