[FIX] res.partner: current name_search() implementation tends to skip a few valid...
authorOlivier Dony <odo@openerp.com>
Thu, 5 Sep 2013 17:02:51 +0000 (19:02 +0200)
committerOlivier Dony <odo@openerp.com>
Thu, 5 Sep 2013 17:02:51 +0000 (19:02 +0200)
The main reason for the semi-random behavior
observed during auto-completion is the
missing ORDER BY clause in the pre-filtering
SQL query.

The ORDER BY clause is expensive but inevitable
if we want to apply a correct LIMIT, otherwise
we would return random `limit` results among
all the possible matches.

The current SQL query seems convoluted due
to the duplicated CASE clause but it
performs slightly better than the equivalent
CTE-based (WITH...) query, so it was preferred.

There is still a chance of returning too
few results due to double limit application,
as further discussed in bug 1203727

lp bug: https://launchpad.net/bugs/1203727 fixed

bzr revid: odo@openerp.com-20130905170251-x47w1zrm43d0k9wb

openerp/addons/base/res/res_partner.py

index af7fcfa..cefe158 100644 (file)
@@ -593,21 +593,31 @@ class res_partner(osv.osv, format_address):
             if operator in ('=ilike', '=like'):
                 operator = operator[1:]
             query_args = {'name': search_name}
-            limit_str = ''
+            # TODO: simplify this in trunk with `display_name`, once it is stored
+            # Perf note: a CTE expression (WITH ...) seems to have an even higher cost
+            #            than this query with duplicated CASE expressions. The bulk of
+            #            the cost is the ORDER BY, and it is inevitable if we want
+            #            relevant results for the next step, otherwise we'd return
+            #            a random selection of `limit` results.
+            query = ('''SELECT partner.id FROM res_partner partner
+                                          LEFT JOIN res_partner company
+                                               ON partner.parent_id = company.id
+                        WHERE partner.email ''' + operator + ''' %(name)s OR
+                              CASE
+                                   WHEN company.id IS NULL OR partner.is_company
+                                       THEN partner.name
+                                   ELSE company.name || ', ' || partner.name
+                              END ''' + operator + ''' %(name)s
+                        ORDER BY
+                              CASE
+                                   WHEN company.id IS NULL OR partner.is_company
+                                       THEN partner.name
+                                   ELSE company.name || ', ' || partner.name
+                              END''')
             if limit:
-                limit_str = ' limit %(limit)s'
+                query += ' limit %(limit)s'
                 query_args['limit'] = limit
-            # TODO: simplify this in trunk with _rec_name='display_name', once display_name
-            # becomes a stored field
-            cr.execute('''SELECT partner.id FROM res_partner partner
-                          LEFT JOIN res_partner company ON partner.parent_id = company.id
-                          WHERE partner.email ''' + operator +''' %(name)s OR
-                             CASE WHEN company.id IS NULL OR partner.is_company 
-                                      THEN partner.name
-                                  ELSE
-                                      company.name || ', ' || partner.name
-                             END
-                          ''' + operator + ' %(name)s ' + limit_str, query_args)
+            cr.execute(query, query_args)
             ids = map(lambda x: x[0], cr.fetchall())
             ids = self.search(cr, uid, [('id', 'in', ids)] + args, limit=limit, context=context)
             if ids: