Thread: many 'OR' in WHERE-condition
Hello, a friend of mine has got a problem: in a SELECT with a condition 'WHERE foo IN (1,2,3,4,...)' with a large list within. The optimizer choose a rewrite to many OR's and a bitmap index scan on the index, no problem, fast. But if the list increase the planner choose an seq-scan. The amount of values in the list is about 200 and the table has about 250.000 rows. How can we avoid the seq-scan? Andreas, thx in advance. -- Andreas Kretschmer Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header) GnuPG-ID: 0x3FFF606C, privat 0x7F4584DA http://wwwkeys.de.pgp.net
A. Kretschmer wrote: > in a SELECT with a condition 'WHERE foo IN (1,2,3,4,...)' with a large ... > But if the list increase the planner choose an seq-scan. The amount of > values in the list is about 200 and the table has about 250.000 rows. > > How can we avoid the seq-scan? Are you sure you'd want to? What plan have you found to be faster with 200 tests? -- Richard Huxton Archonet Ltd
am Fri, dem 20.04.2007, um 12:03:44 +0100 mailte Richard Huxton folgendes: > A. Kretschmer wrote: > >in a SELECT with a condition 'WHERE foo IN (1,2,3,4,...)' with a large > ... > >But if the list increase the planner choose an seq-scan. The amount of > >values in the list is about 200 and the table has about 250.000 rows. > > > >How can we avoid the seq-scan? > > Are you sure you'd want to? What plan have you found to be faster with > 200 tests? It's not my problem - i found it in a forum (german) http://pg-forum.de/showthread.php?t=1332 If the list contains up to 195 entrys -> up to 195 bitmap index scans and BitmapOr -> 7.839ms If the list contains 196 entrys -> seq-scan -> 5591.567ms Andreas -- Andreas Kretschmer Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header) GnuPG-ID: 0x3FFF606C, privat 0x7F4584DA http://wwwkeys.de.pgp.net
A. Kretschmer wrote: > > It's not my problem - i found it in a forum (german) > http://pg-forum.de/showthread.php?t=1332 > > If the list contains up to 195 entrys -> up to 195 bitmap index scans > and BitmapOr -> 7.839ms > > If the list contains 196 entrys -> seq-scan -> 5591.567ms It looks like it's getting the row estimate badly wrong. "Seq Scan on t_datasets_searchindices_rel (cost=0.00..129053.50 rows=159277 width=4) (actual time=0.213..5590.435 rows=325 loops=1) Probably worth increasing the statistics estimate for that column (ALTER TABLE ... ALTER COLUMN ... SET STATISTICS=N) It also looks like it's getting the cost estimates badly wrong. Probably worth asking the original poster to read the tuning guide. -- Richard Huxton Archonet Ltd
am Fri, dem 20.04.2007, um 12:59:01 +0100 mailte Richard Huxton folgendes: > A. Kretschmer wrote: > > > >It's not my problem - i found it in a forum (german) > >http://pg-forum.de/showthread.php?t=1332 > > > >If the list contains up to 195 entrys -> up to 195 bitmap index scans > >and BitmapOr -> 7.839ms > > > >If the list contains 196 entrys -> seq-scan -> 5591.567ms > > It looks like it's getting the row estimate badly wrong. > > "Seq Scan on t_datasets_searchindices_rel (cost=0.00..129053.50 > rows=159277 width=4) (actual time=0.213..5590.435 rows=325 loops=1) Uh oh, i have overlook this. > > Probably worth increasing the statistics estimate for that column (ALTER > TABLE ... ALTER COLUMN ... SET STATISTICS=N) Thx for your hints! Andreas -- Andreas Kretschmer Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header) GnuPG-ID: 0x3FFF606C, privat 0x7F4584DA http://wwwkeys.de.pgp.net