From 82c20e6615aff1caec4b8cae422e6d6f043f1e5e Mon Sep 17 00:00:00 2001
From: Angie Byron <webchick@24967.no-reply.drupal.org>
Date: Sun, 13 Dec 2009 18:10:43 +0000
Subject: [PATCH] #654662 by c960657 and Crell: Allow escaping wildcard
 characters in LIKE queries.

---
 includes/database/database.inc              | 56 ++++++++++++++++++++
 includes/database/pgsql/database.inc        |  5 +-
 includes/database/query.inc                 |  3 +-
 modules/simpletest/tests/database_test.test | 57 +++++++++++++++++++++
 4 files changed, 118 insertions(+), 3 deletions(-)

diff --git a/includes/database/database.inc b/includes/database/database.inc
index 4b1cff0f6420..fb324eded31c 100644
--- a/includes/database/database.inc
+++ b/includes/database/database.inc
@@ -819,6 +819,34 @@ public function escapeTable($table) {
     return preg_replace('/[^A-Za-z0-9_]+/', '', $table);
   }
 
+  /**
+   * Escape characters that work as wildcard characters in a LIKE pattern.
+   *
+   * The wildcard characters "%" and "_" as well as backslash are prefixed with
+   * a backslash. Use this to do a seach for a verbatim string without any
+   * wildcard behavior.
+   *
+   * For example, the following does a case-insensitive query for all rows whose
+   * name starts with $prefix:
+   * @code
+   * $result = db_query(
+   *   'SELECT * FROM person WHERE name LIKE :pattern',
+   *   array(':pattern' => db_like($prefix) . '%')
+   * );
+   * @endcode
+   *
+   * Backslash is defined as escape character for LIKE patterns in
+   * DatabaseCondition::mapConditionOperator().
+   *
+   * @param $string
+   *   The string to escape.
+   * @return
+   *   The escaped string.
+   */
+  public function escapeLike($string) {
+    return addcslashes($string, '\%_');
+  }
+
   /**
    * Determine if there is an active transaction open.
    *
@@ -2234,6 +2262,34 @@ function db_escape_table($table) {
   return Database::getConnection()->escapeTable($table);
 }
 
+/**
+ * Escape characters that work as wildcard characters in a LIKE pattern.
+ *
+ * The wildcard characters "%" and "_" as well as backslash are prefixed with
+ * a backslash. Use this to do a seach for a verbatim string without any
+ * wildcard behavior.
+ *
+ * For example, the following does a case-insensitive query for all rows whose
+ * name starts with $prefix:
+ * @code
+ * $result = db_query(
+ *   'SELECT * FROM person WHERE name LIKE :pattern',
+ *   array(':pattern' => db_like($prefix) . '%')
+ * );
+ * @endcode
+ *
+ * Backslash is defined as escape character for LIKE patterns in
+ * DatabaseCondition::mapConditionOperator().
+ *
+ * @param $string
+ *   The string to escape.
+ * @return
+ *   The escaped string.
+ */
+function db_like($string) {
+  return Database::getConnection()->escapeLike($string);
+}
+
 /**
  * Retrieve the name of the currently active database driver, such as
  * "mysql" or "pgsql".
diff --git a/includes/database/pgsql/database.inc b/includes/database/pgsql/database.inc
index 6772471b6b81..8b60b957b697 100644
--- a/includes/database/pgsql/database.inc
+++ b/includes/database/pgsql/database.inc
@@ -120,8 +120,9 @@ public function databaseType() {
   public function mapConditionOperator($operator) {
     static $specials = array(
       // In PostgreSQL, 'LIKE' is case-sensitive. For case-insensitive LIKE
-      // statements, we need to use ILIKE instead.
-      'LIKE' => array('operator' => 'ILIKE'),
+      // statements, we need to use ILIKE instead. Use backslash for escaping
+      // wildcard characters.
+      'LIKE' => array('operator' => 'ILIKE', 'postfix' => " ESCAPE '\\\\'"),
     );
 
     return isset($specials[$operator]) ? $specials[$operator] : NULL;
diff --git a/includes/database/query.inc b/includes/database/query.inc
index 50c106c0d69b..0061abe0f3b7 100644
--- a/includes/database/query.inc
+++ b/includes/database/query.inc
@@ -1330,13 +1330,14 @@ protected function mapConditionOperator($operator) {
       'NOT IN' => array('delimiter' => ', ', 'prefix' => ' (', 'postfix' => ')'),
       'IS NULL' => array('use_value' => FALSE),
       'IS NOT NULL' => array('use_value' => FALSE),
+      // Use backslash for escaping wildcard characters.
+      'LIKE' => array('postfix' => " ESCAPE '\\\\'"),
       // These ones are here for performance reasons.
       '=' => array(),
       '<' => array(),
       '>' => array(),
       '>=' => array(),
       '<=' => array(),
-      'LIKE' => array(),
     );
     if (isset($specials[$operator])) {
       $return = $specials[$operator];
diff --git a/modules/simpletest/tests/database_test.test b/modules/simpletest/tests/database_test.test
index f74ed1d9ad5e..3862f16c03a3 100644
--- a/modules/simpletest/tests/database_test.test
+++ b/modules/simpletest/tests/database_test.test
@@ -2643,6 +2643,63 @@ class DatabaseAnsiSyntaxTestCase extends DatabaseTestCase {
     ));
     $this->assertIdentical($result->fetchField(), 'The age of John is 25.', t('Field ANSI Concat works.'));
   }
+
+  /**
+   * Test escaping of LIKE wildcards.
+   */
+  function testLikeEscape() {
+    db_insert('test')
+      ->fields(array(
+        'name' => 'Ring_',
+      ))
+      ->execute();
+
+    // Match both "Ringo" and "Ring_".
+    $num_matches = db_select('test', 't')
+      ->condition('name', 'Ring_', 'LIKE')
+      ->countQuery()
+      ->execute()
+      ->fetchField();
+    $this->assertIdentical($num_matches, '2', t('Found 2 records.'));
+    // Match only "Ring_" using a LIKE expression with no wildcards.
+    $num_matches = db_select('test', 't')
+      ->condition('name', db_like('Ring_'), 'LIKE')
+      ->countQuery()
+      ->execute()
+      ->fetchField();
+    $this->assertIdentical($num_matches, '1', t('Found 1 record.'));
+  }
+
+  /**
+   * Test LIKE query containing a backslash.
+   */
+  function testLikeBackslash() {
+    db_insert('test')
+      ->fields(array('name'))
+      ->values(array(
+        'name' => 'abcde\f',
+      ))
+      ->values(array(
+        'name' => 'abc%\_',
+      ))
+      ->execute();
+
+    // Match both rows using a LIKE expression with two wildcards and a verbatim
+    // backslash.
+    $num_matches = db_select('test', 't')
+      ->condition('name', 'abc%\\\\_', 'LIKE')
+      ->countQuery()
+      ->execute()
+      ->fetchField();
+    $this->assertIdentical($num_matches, '2', t('Found 2 records.'));
+    // Match only the former using a LIKE expression with no wildcards.
+    $num_matches = db_select('test', 't')
+      ->condition('name', db_like('abc%\_'), 'LIKE')
+      ->countQuery()
+      ->execute()
+      ->fetchField();
+    $this->assertIdentical($num_matches, '1', t('Found 1 record.'));
+  }
 }
 
 /**
-- 
GitLab