I am admittedly speaking up somewhat late here, and may be completely off base, 
but it seems to me that the "LIKE" operation is almost always going to be a 
loser, performance-wise, when there is an initial wildcard, e.g. "%superman 
re%" will require a sequential scan, while "superman re%" would not (assuming 
proper indexes matching case and type).

I'd suggest tsearch2, possibly, which uses GIST indexes and may perhaps be a 
better match for this sort of problem.

HTH,

Greg Williamson
DBA
GlobeXplorer LLC

-----Original Message-----
From:   [EMAIL PROTECTED] on behalf of Richard Huxton
Sent:   Thu 11/9/2006 1:22 AM
To:     Thomas H.
Cc:     pgsql-general@postgresql.org
Subject:        Re: [GENERAL] planer picks a bad plan (seq-scan instead of 
index)

Thomas H. wrote:
> --------------------
> SELECT * FROM shop.dvds
> LEFT JOIN oldtables.movies ON mov_id = dvd_mov_id
> LEFT JOIN shop.data_soundmedia ON sm_info_ean = dvd_ean
> WHERE (lower(mov_name) LIKE '%superman re%' OR lower(dvd_name) like 
> '%superman re%' OR lower(dvd_edition) LIKE '%superman re%')
> --------------------

Try putting your conditions as part of the join:
SELECT * FROM shop.dvds
LEFT JOIN
   oldtables.movies
ON
   mov_id = dvd_mov_id
   AND (
     lower(mov_name) LIKE '%superman re%'
     OR lower(dvd_name) like '%superman re%'
     OR lower(dvd_edition) LIKE '%superman re%'
   )
LEFT JOIN shop.data_soundmedia ON sm_info_ean = dvd_ean

I'd also be tempted to look at a tsearch2 setup for the word searches.
-- 
   Richard Huxton
   Archonet Ltd

---------------------------(end of broadcast)---------------------------
TIP 9: In versions below 8.0, the planner will ignore your desire to
       choose an index scan if your joining column's datatypes do not
       match


-------------------------------------------------------
Click link below if it is SPAM [EMAIL PROTECTED]
"https://mailscanner.globexplorer.com/dspam/dspam.cgi?signatureID=4552efed289104295495211&[EMAIL
 PROTECTED]&retrain=spam&template=history&history_page=1"
!DSPAM:4552efed289104295495211!
-------------------------------------------------------






---------------------------(end of broadcast)---------------------------
TIP 4: Have you searched our list archives?

               http://archives.postgresql.org/

Reply via email to