]> git.ipfire.org Git - thirdparty/sqlalchemy/sqlalchemy.git/commitdiff
- add postgresql_regconfig argument to PG dialect for match() operator,
authorjonathan vanasco <jonathan@2xlp.com>
Tue, 10 Jun 2014 22:56:27 +0000 (18:56 -0400)
committerMike Bayer <mike_mp@zzzcomputing.com>
Tue, 8 Jul 2014 22:22:54 +0000 (18:22 -0400)
implements PG's to_tsquery('regconfig', 'arg') pattern. fixes #3078

doc/build/changelog/changelog_09.rst
lib/sqlalchemy/dialects/postgresql/base.py
lib/sqlalchemy/sql/default_comparator.py
lib/sqlalchemy/sql/operators.py
test/dialect/postgresql/test_compiler.py

index ac76a875013e9e6afc5b0a5a24367363e53826ae..687281c51d5c9e1bf59f24975dfd35327e740b43 100644 (file)
     :version: 0.9.7
     :released:
 
+    .. change::
+        :tags: feature, postgresql
+        :versions: 1.0.0
+        :pullreq: bitbucket:22
+        :tickets: 3078
+
+        Added kw argument ``postgresql_regconfig`` to the
+        :meth:`.Operators.match` operator, allows the "reg config" argument
+        to be specified to the ``to_tsquery()`` function emitted.
+        Pull request courtesy Jonathan Vanasco.
+
     .. change::
         :tags: feature, postgresql
         :versions: 1.0.0
index 02c1c86db36ab1eeb4971d0467b4c6ef07bcf834..21df75bb8e4615bea51383f89a13482b04f57cbc 100644 (file)
@@ -271,6 +271,47 @@ produces a statement equivalent to::
 
     SELECT CAST('some text' AS TSVECTOR) AS anon_1
 
+Full Text Searches in Postgresql are influenced by a combination of: the
+PostgresSQL setting of ``default_text_search_config``, the ``regconfig`` used to
+build the GIN/GiST indexes, and the ``regconfig`` optionally passed in during a
+query.
+
+When performing a Full Text Search against a column that has a GIN or
+GiST index that is already pre-computed (which is common on full text searches)
+one may need to explicitly pass in a particular PostgresSQL ``regconfig`` value
+to ensure the query-planner utilizes the index and does not re-compute the
+column on demand.
+
+In order to provide for this explicit query planning, or to use different search
+strategies, the ``match`` method accepts a ``postgresql_regconfig`` keyword
+argument.
+
+    select([mytable.c.id]).where(
+        mytable.c.title.match('somestring', postgresql_regconfig='english')
+    )
+
+Emits the equivalent of::
+
+    SELECT mytable.id FROM mytable
+    WHERE mytable.title @@ to_tsquery('english', 'somestring')
+
+One can also specifically pass in a `'regconfig'` value to the ``to_tsvector()``
+command as the initial argument.
+
+    select([mytable.c.id]).where(
+            func.to_tsvector('english', mytable.c.title )\
+            .match('somestring', postgresql_regconfig='english')
+        )
+
+produces a statement equivalent to::
+
+    SELECT mytable.id FROM mytable
+    WHERE to_tsvector('english', mytable.title) @@
+        to_tsquery('english', 'somestring')
+
+It is recommended that you use the ``EXPLAIN ANALYZE...`` tool from PostgresSQL
+to ensure that you are generating queries with SQLAlchemy that take full
+advantage of any indexes you may have created for full text search.
 
 FROM ONLY ...
 ------------------------
@@ -1134,14 +1175,25 @@ class PGCompiler(compiler.SQLCompiler):
 
     def visit_getitem_binary(self, binary, operator, **kw):
         return "%s[%s]" % (
-                self.process(binary.left, **kw),
-                self.process(binary.right, **kw)
-            )
+            self.process(binary.left, **kw),
+            self.process(binary.right, **kw)
+        )
 
     def visit_match_op_binary(self, binary, operator, **kw):
+        if "postgresql_regconfig" in binary.modifiers:
+            regconfig = self.render_literal_value(\
+                binary.modifiers['postgresql_regconfig'],
+                sqltypes.STRINGTYPE)
+            if regconfig:
+                return "%s @@ to_tsquery(%s, %s)" % (
+                    self.process(binary.left, **kw),
+                    regconfig,
+                    self.process(binary.right, **kw)
+                )
         return "%s @@ to_tsquery(%s)" % (
-                        self.process(binary.left, **kw),
-                        self.process(binary.right, **kw))
+            self.process(binary.left, **kw),
+            self.process(binary.right, **kw)
+        )
 
     def visit_ilike_op_binary(self, binary, operator, **kw):
         escape = binary.modifiers.get("escape", None)
index 20f13f70fa084d3e0f8b1c20c03ca735bb188ef4..4386eb52c27e914ed3ba9afe8d6a6629ed9019fc 100644 (file)
@@ -213,7 +213,7 @@ class _DefaultColumnComparator(operators.ColumnOperators):
         """See :meth:`.ColumnOperators.match`."""
         return self._boolean_compare(expr, operators.match_op,
                               self._check_literal(expr, operators.match_op,
-                              other))
+                              other), **kw)
 
     def _distinct_impl(self, expr, op, **kw):
         """See :meth:`.ColumnOperators.distinct`."""
index 9ad30e49e2850f3e973d04754f2058ba033f1c56..55700a3822f4e1788fef22ae0fbf742e1aff31ac 100644 (file)
@@ -758,8 +758,8 @@ def notcontains_op(a, b, escape=None):
     return ~a.contains(b, escape=escape)
 
 
-def match_op(a, b):
-    return a.match(b)
+def match_op(a, b, **kw):
+    return a.match(b, **kw)
 
 
 def comma_op(a, b):
index c8138938522eddb4c7ada7d438444fc777e18497..76166b6dd261b50e7dde39800d6258b0768dfa4c 100644 (file)
@@ -695,3 +695,84 @@ class DistinctOnTest(fixtures.TestBase, AssertsCompiledSQL):
             "FROM t, (SELECT t.id AS id, t.a AS a, "
             "t.b AS b FROM t) AS sq WHERE t.id = sq.id"
             )
+
+class FullTextSearchTest(fixtures.TestBase, AssertsCompiledSQL):
+    """Tests for full text searching
+    """
+    __dialect__ = postgresql.dialect()
+
+    def setup(self):
+        self.table = Table('t', MetaData(),
+                Column('id', Integer, primary_key=True),
+                Column('title', String),
+                Column('body', String),
+            )
+        self.table_alt = table('mytable',
+                column('id', Integer),
+                column('title', String(128)),
+                column('body', String(128)))
+
+    def _raise_query(self, q):
+        """
+            useful for debugging. just do...
+            self._raise_query(q)
+        """
+        c = q.compile(dialect=postgresql.dialect())
+        raise ValueError(c)
+
+    def test_match_basic(self):
+        s = select([self.table_alt.c.id])\
+            .where(self.table_alt.c.title.match('somestring'))
+        self.assert_compile(s,
+            'SELECT mytable.id '
+            'FROM mytable '
+            'WHERE mytable.title @@ to_tsquery(%(title_1)s)')
+
+    def test_match_regconfig(self):
+        s = select([self.table_alt.c.id])\
+            .where(
+                self.table_alt.c.title.match('somestring',
+                    postgresql_regconfig='english')
+            )
+        self.assert_compile(s,
+            'SELECT mytable.id '
+            'FROM mytable '
+            """WHERE mytable.title @@ to_tsquery('english', %(title_1)s)""")
+
+    def test_match_tsvector(self):
+        s = select([self.table_alt.c.id])\
+            .where(
+                func.to_tsvector( self.table_alt.c.title )\
+                .match('somestring')
+            )
+        self.assert_compile(s,
+            'SELECT mytable.id '
+            'FROM mytable '
+            'WHERE to_tsvector(mytable.title) @@ to_tsquery(%(to_tsvector_1)s)')
+
+    def test_match_tsvectorconfig(self):
+        s = select([self.table_alt.c.id])\
+            .where(
+                func.to_tsvector( 'english', self.table_alt.c.title )\
+                .match('somestring')
+            )
+        self.assert_compile(s,
+            'SELECT mytable.id '
+            'FROM mytable '
+            'WHERE to_tsvector(%(to_tsvector_1)s, mytable.title) @@ '
+                'to_tsquery(%(to_tsvector_2)s)'
+            )
+
+    def test_match_tsvectorconfig_regconfig(self):
+        s = select([self.table_alt.c.id])\
+            .where(\
+                func.to_tsvector( 'english', self.table_alt.c.title )\
+                .match('somestring', postgresql_regconfig='english')
+            )
+        self.assert_compile(s,
+            'SELECT mytable.id '
+            'FROM mytable '
+            'WHERE to_tsvector(%(to_tsvector_1)s, mytable.title) @@ '
+                """to_tsquery('english', %(to_tsvector_2)s)"""
+            )
+