473,750 Members | 2,308 Online
Bytes | Software Development & Data Engineering Community
+ Post

Home Posts Topics Members FAQ

select ... where <column>='' 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 |
---------------------------+---------------------------+------------+------------------+
101011010100000 0007482877 | 101011010100000 0001090647 | KONTO_NR |
1000000000 |
101011010100000 0007482878 | 101011010100000 0001090647 | KZ_READ | N
|
101011010100000 0007482879 | 101011010100000 0001090647 | READ_DATE | |
101011010100000 0007482880 | 101011010100000 0001090647 | ENTAX_NR |
200000000000000 0 |
101011010100000 0007482881 | 101011010100000 0001090647 | DOC_SOURCE | 400
|
101011010100000 0007482882 | 101011010100000 0001090647 | 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='KON TO_NR' and
param_value='';

this produced:

QUERY PLAN
------------------------------------------------------------------------------------------
Seq Scan on document_params (cost=0.00..241 600.27 rows=152073 width=95)
Filter: (((param_name): :text = 'KONTO_NR'::tex t) AND
((param_value): :text = ''::text))
(2 rows)

There's a multicolumn index (param_value,pa ram_name) on document_params .
To be sure the index works I changed the select to

explain select * from document_params where param_name='KON TO_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..591 783.84
rows=152073 width=95)
Index Cond: ((param_name):: text = 'KONTO_NR'::tex t)
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

Nov 23 '05 #1
5 2359
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/

---------------------------(end of broadcast)---------------------------
TIP 2: you can get off all lists at once with the unregister command
(send "unregister YourEmailAddres sHere" to ma*******@postg resql.org)

Nov 23 '05 #2
Silvio Matthes <si************ @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 counterproducti ve.

regards, tom lane

---------------------------(end of broadcast)---------------------------
TIP 5: Have you checked our extensive FAQ?

http://www.postgresql.org/docs/faqs/FAQ.html

Nov 23 '05 #3
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 counterproducti ve.
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,coun t(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='KUN DEN_NR'
and param_value='';

also did a seqscan.

And

explain select count(*) from document_params where param_name='KON TO_NR'
and param_value='te st';

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='KUN DEN_NR'
and param_value=''? !?

Disabling seqscan gives:

explain select count(*) from document_params where param_name='KUN DEN_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..638 934.84
rows=160694 width=0)
Index Cond: (((param_value) ::text = ''::text) AND
((param_name):: text = 'KUNDEN_NR'::te xt))

Postmaster is using the multicolumn index (param_value,pa ram_name), but
not in the expected time...
as always, any help would be highly appreciated.
Ciao,

Silvio Matthes


Tom Lane <tg*@sss.pgh.pa .us>
Gesendet von: pg************* ****@postgresql .org
24.08.2004 17:35

An
Silvio Matthes <si************ @xcom.de>
Kopie
pg***********@p ostgresql.org
Thema
Re: [GENERAL] select ... where <column>='' does a seqscan [auf Viren
geprueft]


Silvio Matthes <si************ @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 counterproducti ve.

regards, tom lane

---------------------------(end of broadcast)---------------------------
TIP 5: Have you checked our extensive FAQ?

http://www.postgresql.org/docs/faqs/FAQ.html
Nov 23 '05 #4
Silvio Matthes <si************ @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='KUN DEN_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

---------------------------(end of broadcast)---------------------------
TIP 1: subscribe and unsubscribe commands go to ma*******@postg resql.org

Nov 23 '05 #5
>> 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='KUN DEN_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 <tg*@sss.pgh.pa .us>
24.08.2004 18:52

An
Silvio Matthes <si************ @xcom.de>
Kopie
pg***********@p ostgresql.org
Thema
Re: [GENERAL] select ... where <column>='' does a seqscan [auf Viren [auf
Viren geprueft]


Silvio Matthes <si************ @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='KUN DEN_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
Nov 23 '05 #6

This thread has been closed and replies have been disabled. Please start a new discussion.

Similar topics

11
4855
by: Randell D. | last post by:
Folks, I have a table of addresses and a seperate table with contact names - All addresses tie to one or more names - I would like to keep track of the number of names 'belonging' to an address and have thus included a column in my address table called num_of_contacts. Everytime I add a new contact, I would like to increment the num_of_contacts column in the address table. Is this possible?
3
16659
by: Cindi Simonson | last post by:
Hi, I have a form with a combo box containing 4 columns of data. The form also contains 3 print buttons where the goal is to open 3 different reports according to the value in one of the columns of the combo box. Since the bound column property determines which value to look at, how do I change the bound column's value in an onClick event?
2
10173
by: Jasonkimberson | last post by:
I am doing a data pull of HTML from a database that will be put into a drop down menu currently after i pull and populate the information, it converts my < into &lt; whats the work around for this? HTML code
15
3764
by: John Blair | last post by:
Hi, Code attached but the line that gives me an error is MyDataGrid.Columns(2).Visible = False It actually gives me an error for any value instead of 2 even when 9 bound columns of data exist. How do i hide a column? Thanks. MyConnection = New SqlConnection("server=(local);database=pubs;Trusted_Connection=yes") MyCommand = New SqlDataAdapter("select * from Authors",
0
1079
by: Sinan | last post by:
Hi I am using a datagrid with a Select Column and the SelectedIndexChanged event captures the values of the cells in the selected row. It works fine before sorting any column. The problem starts when I sort a column and then select a row, it gives me the data of another row! Not the row I have selected Any idea what is going wrong? Your help is highly appreciated Here is the sort procedure I am using
6
10680
by: Aaron Smith | last post by:
Ok. I have a dataset that has multiple tables in it. In one of the child tables, I have a column that I added to the DataSet (Not in the DataSource). This column does not need to be stored in the data on the datasource. It simply gets the first name and last name of an instructor and displays it in the grid. I have two major problems.... One, it doesn't display in the column until the row is saved, (Even after calling a refresh on the...
3
10403
by: Vivek | last post by:
Hi, Can someone give an example of a query which produces the following warning: SQL0012W Correlation without qualification has occurred for the column "<column>".
2
2572
Bob Ross
by: Bob Ross | last post by:
I have a very starange problem. I am trying to access a value from a datatable by specifying the column on the datarow but it keeps saying "Column 'BitValue' is not cantained in table 'Fields'" But it clearly is. All other columns work fine and I can reference it by number but not by name. FieldsDS = FieldsSqlFactory.ExecuteQuery() FieldsDS.Tables(0).TableName = "Fields" Dim AdditionalField As OrderingSpecificField Dim C As Integer =...
4
6024
by: Luqman | last post by:
I have populated the Child Accounts and Parent Accounts in a Grid View Control, I want to hide the Select Column of Parent Accounts, but not the Child Accounts, is it possible ? I am using VS 2005 ? Best Regards, Luqman
0
8997
marktang
by: marktang | last post by:
ONU (Optical Network Unit) is one of the key components for providing high-speed Internet services. Its primary function is to act as an endpoint device located at the user's premises. However, people are often confused as to whether an ONU can Work As a Router. In this blog post, we’ll explore What is ONU, What Is Router, ONU & Router’s main usage, and What is the difference between ONU and Router. Let’s take a closer look ! Part I. Meaning of...
0
8833
by: Hystou | last post by:
Most computers default to English, but sometimes we require a different language, especially when relocating. Forgot to request a specific language before your computer shipped? No problem! You can effortlessly switch the default language on Windows 10 without reinstalling. I'll walk you through it. First, let's disable language synchronization. With a Microsoft account, language settings sync across devices. To prevent any complications,...
0
9568
Oralloy
by: Oralloy | last post by:
Hello folks, I am unable to find appropriate documentation on the type promotion of bit-fields when using the generalised comparison operator "<=>". The problem is that using the GNU compilers, it seems that the internal comparison operator "<=>" tries to promote arguments from unsigned to signed. This is as boiled down as I can make it. Here is my compilation command: g++-12 -std=c++20 -Wnarrowing bit_field.cpp Here is the code in...
0
9389
jinu1996
by: jinu1996 | last post by:
In today's digital age, having a compelling online presence is paramount for businesses aiming to thrive in a competitive landscape. At the heart of this digital strategy lies an intricately woven tapestry of website design and digital marketing. It's not merely about having a website; it's about crafting an immersive digital experience that captivates audiences and drives business growth. The Art of Business Website Design Your website is...
0
8257
agi2029
by: agi2029 | last post by:
Let's talk about the concept of autonomous AI software engineers and no-code agents. These AIs are designed to manage the entire lifecycle of a software development project—planning, coding, testing, and deployment—without human intervention. Imagine an AI that can take a project description, break it down, write the code, debug it, and then launch it, all on its own.... Now, this would greatly impact the work of software developers. The idea...
0
4709
by: TSSRALBI | last post by:
Hello I'm a network technician in training and I need your help. I am currently learning how to create and manage the different types of VPNs and I have a question about LAN-to-LAN VPNs. The last exercise I practiced was to create a LAN-to-LAN VPN between two Pfsense firewalls, by using IPSEC protocols. I succeeded, with both firewalls in the same network. But I'm wondering if it's possible to do the same thing, with 2 Pfsense firewalls...
0
4881
by: adsilva | last post by:
A Windows Forms form does not have the event Unload, like VB6. What one acts like?
1
3320
by: 6302768590 | last post by:
Hai team i want code for transfer the data from one system to another through IP address by using C# our system has to for every 5mins then we have to update the data what the data is updated we have to send another system
3
2218
bsmnconsultancy
by: bsmnconsultancy | last post by:
In today's digital era, a well-designed website is crucial for businesses looking to succeed. Whether you're a small business owner or a large corporation in Toronto, having a strong online presence can significantly impact your brand's success. BSMN Consultancy, a leader in Website Development in Toronto offers valuable insights into creating effective websites that not only look great but also perform exceptionally well. In this comprehensive...

By using Bytes.com and it's services, you agree to our Privacy Policy and Terms of Use.

To disable or enable advertisements and analytics tracking please visit the manage ads & tracking page.