--- /dev/null
+.. change::
+ :tags: usecase, mysql
+ :tickets: 6132
+
+ Added new construct :class:`_mysql.match`, which provides for the full
+ range of MySQL's MATCH operator including multiple column support and
+ modifiers. Pull request courtesy Anton Kovalevich.
+
+ .. seealso::
+
+ :class:`_mysql.match`
.. automodule:: sqlalchemy.dialects.mysql.base
+MySQL SQL Constructs
+--------------------
+
+.. currentmodule:: sqlalchemy.dialects.mysql
+
+.. autoclass:: match
+ :members:
+
MySQL Data Types
----------------
from .base import YEAR
from .dml import Insert
from .dml import insert
+from .expression import match
from ...util import compat
if compat.py3k:
"dialect",
"insert",
"Insert",
+ "match",
)
select(...).with_hint(some_table, "USE INDEX xyz")
+* MATCH operator support::
+
+ from sqlalchemy.dialects.mysql import match
+ select(...).where(match(col1, col2, against="some expr").in_boolean_mode())
+
+ .. seealso::
+
+ :class:`_mysql.match`
+
.. _mysql_insert_on_duplicate_key_update:
INSERT...ON DUPLICATE KEY UPDATE (Upsert)
from array import array as _array
from collections import defaultdict
+from itertools import compress
import re
from sqlalchemy import literal_column
self.process(binary.right, **kw),
)
- def visit_match_op_binary(self, binary, operator, **kw):
- return "MATCH (%s) AGAINST (%s IN BOOLEAN MODE)" % (
- self.process(binary.left, **kw),
- self.process(binary.right, **kw),
+ _match_valid_flag_combinations = frozenset(
+ (
+ # (boolean_mode, natural_language, query_expansion)
+ (False, False, False),
+ (True, False, False),
+ (False, True, False),
+ (False, False, True),
+ (False, True, True),
)
+ )
+
+ _match_flag_expressions = (
+ "IN BOOLEAN MODE",
+ "IN NATURAL LANGUAGE MODE",
+ "WITH QUERY EXPANSION",
+ )
+
+ def visit_mysql_match(self, element, **kw):
+ return self.visit_match_op_binary(element, element.operator, **kw)
+
+ def visit_match_op_binary(self, binary, operator, **kw):
+ """
+ Note that `mysql_boolean_mode` is enabled by default because of
+ backward compatibility
+ """
+
+ modifiers = binary.modifiers
+
+ boolean_mode = modifiers.get("mysql_boolean_mode", True)
+ natural_language = modifiers.get("mysql_natural_language", False)
+ query_expansion = modifiers.get("mysql_query_expansion", False)
+
+ flag_combination = (boolean_mode, natural_language, query_expansion)
+
+ if flag_combination not in self._match_valid_flag_combinations:
+ flags = (
+ "in_boolean_mode=%s" % boolean_mode,
+ "in_natural_language_mode=%s" % natural_language,
+ "with_query_expansion=%s" % query_expansion,
+ )
+
+ flags = ", ".join(flags)
+
+ raise exc.CompileError("Invalid MySQL match flags: %s" % flags)
+
+ match_clause = binary.left
+ match_clause = self.process(match_clause, **kw)
+ against_clause = self.process(binary.right, **kw)
+
+ if any(flag_combination):
+ flag_expressions = compress(
+ self._match_flag_expressions,
+ flag_combination,
+ )
+
+ against_clause = [against_clause]
+ against_clause.extend(flag_expressions)
+
+ against_clause = " ".join(against_clause)
+
+ return "MATCH (%s) AGAINST (%s)" % (match_clause, against_clause)
def get_from_hint_text(self, table, text):
return text
--- /dev/null
+from ... import exc
+from ... import util
+from ...sql import coercions
+from ...sql import elements
+from ...sql import operators
+from ...sql import roles
+from ...sql.base import _generative
+from ...sql.base import Generative
+
+
+class match(Generative, elements.BinaryExpression):
+ """Produce a ``MATCH (X, Y) AGAINST ('TEXT')`` clause.
+
+ E.g.::
+
+ from sqlalchemy import desc
+ from sqlalchemy.dialects.mysql import match
+
+ match_expr = match(
+ users_table.c.firstname,
+ users_table.c.lastname,
+ against="Firstname Lastname",
+ )
+
+ stmt = (
+ select(users_table)
+ .where(match_expr.in_boolean_mode())
+ .order_by(desc(match_expr))
+ )
+
+ Would produce SQL resembling::
+
+ SELECT id, firstname, lastname
+ FROM user
+ WHERE MATCH(firstname, lastname) AGAINST (:param_1 IN BOOLEAN MODE)
+ ORDER BY MATCH(firstname, lastname) AGAINST (:param_2) DESC
+
+ The :func:`_mysql.match` function is a standalone version of the
+ :meth:`_sql.ColumnElement.match` method available on all
+ SQL expressions, as when :meth:`_expression.ColumnElement.match` is
+ used, but allows to pass multiple columns
+
+ :param cols: column expressions to match against
+
+ :param against: expression to be compared towards
+
+ :param in_boolean_mode: boolean, set "boolean mode" to true
+
+ :param in_natural_language_mode: boolean , set "natural language" to true
+
+ :param with_query_expansion: boolean, set "query expansion" to true
+
+ .. versionadded:: 1.4.19
+
+ .. seealso::
+
+ :meth:`_expression.ColumnElement.match`
+
+ """
+
+ __visit_name__ = "mysql_match"
+
+ inherit_cache = True
+
+ def __init__(self, *cols, **kw):
+ if not cols:
+ raise exc.ArgumentError("columns are required")
+
+ against = kw.pop("against", None)
+
+ if not against:
+ raise exc.ArgumentError("against is required")
+ against = coercions.expect(
+ roles.ExpressionElementRole,
+ against,
+ )
+
+ left = elements.BooleanClauseList._construct_raw(
+ operators.comma_op,
+ clauses=cols,
+ )
+ left.group = False
+
+ flags = util.immutabledict(
+ {
+ "mysql_boolean_mode": kw.pop("in_boolean_mode", False),
+ "mysql_natural_language": kw.pop(
+ "in_natural_language_mode", False
+ ),
+ "mysql_query_expansion": kw.pop("with_query_expansion", False),
+ }
+ )
+
+ if kw:
+ raise exc.ArgumentError("unknown arguments: %s" % (", ".join(kw)))
+
+ super(match, self).__init__(
+ left, against, operators.match_op, modifiers=flags
+ )
+
+ @_generative
+ def in_boolean_mode(self):
+ """Apply the "IN BOOLEAN MODE" modifier to the MATCH expression.
+
+ :return: a new :class:`_mysql.match` instance with modifications
+ applied.
+ """
+
+ self.modifiers = self.modifiers.union({"mysql_boolean_mode": True})
+
+ @_generative
+ def in_natural_language_mode(self):
+ """Apply the "IN NATURAL LANGUAGE MODE" modifier to the MATCH
+ expression.
+
+ :return: a new :class:`_mysql.match` instance with modifications
+ applied.
+ """
+
+ self.modifiers = self.modifiers.union({"mysql_natural_language": True})
+
+ @_generative
+ def with_query_expansion(self):
+ """Apply the "WITH QUERY EXPANSION" modifier to the MATCH expression.
+
+ :return: a new :class:`_mysql.match` instance with modifications
+ applied.
+ """
+
+ self.modifiers = self.modifiers.union({"mysql_query_expansion": True})
* PostgreSQL - renders ``x @@ to_tsquery(y)``
* MySQL - renders ``MATCH (x) AGAINST (y IN BOOLEAN MODE)``
+
+ .. seealso::
+
+ :class:`_mysql.match` - MySQL specific construct with
+ additional features.
+
* Oracle - renders ``CONTAINS(x, y)``
* other backends may provide special implementations.
* Backends without any special implementation will emit
from sqlalchemy import VARCHAR
from sqlalchemy.dialects.mysql import base as mysql
from sqlalchemy.dialects.mysql import insert
+from sqlalchemy.dialects.mysql import match
from sqlalchemy.sql import column
from sqlalchemy.sql import table
from sqlalchemy.sql.expression import literal_column
dialect=mysql.dialect(),
)
- def test_match(self):
- matchtable = table("matchtable", column("title", String))
- self.assert_compile(
- matchtable.c.title.match("somstr"),
- "MATCH (matchtable.title) AGAINST (%s IN BOOLEAN MODE)",
- )
-
- def test_match_compile_kw(self):
- expr = literal("x").match(literal("y"))
- self.assert_compile(
- expr,
- "MATCH ('x') AGAINST ('y' IN BOOLEAN MODE)",
- literal_binds=True,
- )
-
def test_concat_compile_kw(self):
expr = literal("x", type_=String) + literal("y", type_=String)
self.assert_compile(expr, "concat('x', 'y')", literal_binds=True)
"REGEXP_REPLACE(mytable.myid, CONCAT('(?', %s, ')', %s), %s)",
checkpositional=("ig", "pattern", "replacement"),
)
+
+
+class MatchExpressionTest(fixtures.TestBase, AssertsCompiledSQL):
+
+ __dialect__ = mysql.dialect()
+
+ match_table = table(
+ "user",
+ column("firstname", String),
+ column("lastname", String),
+ )
+
+ @testing.combinations(
+ (
+ lambda title: title.match("somstr", mysql_boolean_mode=False),
+ "MATCH (matchtable.title) AGAINST (%s)",
+ ),
+ (
+ lambda title: title.match(
+ "somstr",
+ mysql_boolean_mode=False,
+ mysql_natural_language=True,
+ ),
+ "MATCH (matchtable.title) AGAINST (%s IN NATURAL LANGUAGE MODE)",
+ ),
+ (
+ lambda title: title.match(
+ "somstr",
+ mysql_boolean_mode=False,
+ mysql_query_expansion=True,
+ ),
+ "MATCH (matchtable.title) AGAINST (%s WITH QUERY EXPANSION)",
+ ),
+ (
+ lambda title: title.match(
+ "somstr",
+ mysql_boolean_mode=False,
+ mysql_natural_language=True,
+ mysql_query_expansion=True,
+ ),
+ "MATCH (matchtable.title) AGAINST "
+ "(%s IN NATURAL LANGUAGE MODE WITH QUERY EXPANSION)",
+ ),
+ )
+ def test_match_expression_single_col(self, case, expected):
+ matchtable = table("matchtable", column("title", String))
+ title = matchtable.c.title
+
+ expr = case(title)
+ self.assert_compile(expr, expected)
+
+ @testing.combinations(
+ (
+ lambda expr: expr,
+ "MATCH (user.firstname, user.lastname) AGAINST (%s)",
+ ),
+ (
+ lambda expr: expr.in_boolean_mode(),
+ "MATCH (user.firstname, user.lastname) AGAINST "
+ "(%s IN BOOLEAN MODE)",
+ ),
+ (
+ lambda expr: expr.in_natural_language_mode(),
+ "MATCH (user.firstname, user.lastname) AGAINST "
+ "(%s IN NATURAL LANGUAGE MODE)",
+ ),
+ (
+ lambda expr: expr.with_query_expansion(),
+ "MATCH (user.firstname, user.lastname) AGAINST "
+ "(%s WITH QUERY EXPANSION)",
+ ),
+ (
+ lambda expr: (
+ expr.in_natural_language_mode().with_query_expansion()
+ ),
+ "MATCH (user.firstname, user.lastname) AGAINST "
+ "(%s IN NATURAL LANGUAGE MODE WITH QUERY EXPANSION)",
+ ),
+ )
+ def test_match_expression_multiple_cols(self, case, expected):
+ firstname = self.match_table.c.firstname
+ lastname = self.match_table.c.lastname
+
+ expr = match(firstname, lastname, against="Firstname Lastname")
+
+ expr = case(expr)
+ self.assert_compile(expr, expected)
+
+ def test_cols_required(self):
+ assert_raises_message(
+ exc.ArgumentError,
+ "columns are required",
+ match,
+ against="Firstname Lastname",
+ )
+
+ @testing.combinations(
+ (True, False, True), (True, True, False), (True, True, True)
+ )
+ def test_invalid_combinations(
+ self, boolean_mode, natural_language, query_expansion
+ ):
+ firstname = self.match_table.c.firstname
+ lastname = self.match_table.c.lastname
+
+ assert_raises_message(
+ exc.ArgumentError,
+ "columns are required",
+ match,
+ against="Firstname Lastname",
+ )
+
+ expr = match(
+ firstname,
+ lastname,
+ against="Firstname Lastname",
+ in_boolean_mode=boolean_mode,
+ in_natural_language_mode=natural_language,
+ with_query_expansion=query_expansion,
+ )
+ msg = (
+ "Invalid MySQL match flags: "
+ "in_boolean_mode=%s, "
+ "in_natural_language_mode=%s, "
+ "with_query_expansion=%s"
+ ) % (boolean_mode, natural_language, query_expansion)
+
+ assert_raises_message(
+ exc.CompileError,
+ msg,
+ expr.compile,
+ dialect=self.__dialect__,
+ )
+
+ def test_match_operator(self):
+ matchtable = table("matchtable", column("title", String))
+ self.assert_compile(
+ matchtable.c.title.match("somstr"),
+ "MATCH (matchtable.title) AGAINST (%s IN BOOLEAN MODE)",
+ )
+
+ def test_literal_binds(self):
+ expr = literal("x").match(literal("y"))
+ self.assert_compile(
+ expr,
+ "MATCH ('x') AGAINST ('y' IN BOOLEAN MODE)",
+ literal_binds=True,
+ )