Commit df50f44a authored by Benjamin Eberlei's avatar Benjamin Eberlei

[DBAL-78] Add support for native sql list support in positional queries...

[DBAL-78] Add support for native sql list support in positional queries through the introduction of two new constants:

* Doctrine\DBAL\Connection::PARAM_STR_ARRAY
* Doctrine\DBAL\Connection::PARAM_INT_ARRAY

Replacement of arrays only works in conjunction with the Doctrine\DBAL\Connection::executeQuery() and executeUpdate() methods.
You need to pass the param constants into the third parameter called $types.
parent 37186d98
......@@ -62,6 +62,27 @@ class Connection implements DriverConnection
* Constant for transaction isolation level SERIALIZABLE.
*/
const TRANSACTION_SERIALIZABLE = 4;
/**
* Represents an array of ints to be expanded by Doctrine SQL parsing.
*
* @var int
*/
const PARAM_INT_ARRAY = 101;
/**
* Represents an array of strings to be expanded by Doctrine SQL parsing.
*
* @var int
*/
const PARAM_STR_ARRAY = 102;
/**
* Offset by which PARAM_* constants are detected as arrays of the param type.
*
* @var int
*/
const ARRAY_PARAM_OFFSET = 100;
/**
* The wrapped driver connection.
......@@ -566,6 +587,8 @@ class Connection implements DriverConnection
}
if ($params) {
list($query, $params, $types) = SQLParserUtils::expandListParameters($query, $params, $types);
$stmt = $this->_conn->prepare($query);
if ($types) {
$this->_bindTypedValues($stmt, $params, $types);
......@@ -645,6 +668,8 @@ class Connection implements DriverConnection
}
if ($params) {
list($query, $params, $types) = SQLParserUtils::expandListParameters($query, $params, $types);
$stmt = $this->_conn->prepare($query);
if ($types) {
$this->_bindTypedValues($stmt, $params, $types);
......
<?php
/*
* THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS
* "AS IS" AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT
* LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR
* A PARTICULAR PURPOSE ARE DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT
* OWNER OR CONTRIBUTORS BE LIABLE FOR ANY DIRECT, INDIRECT, INCIDENTAL,
* SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES (INCLUDING, BUT NOT
* LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; LOSS OF USE,
* DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON ANY
* THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT
* (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE
* OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
*
* This software consists of voluntary contributions made by many individuals
* and is licensed under the LGPL. For more information, see
* <http://www.doctrine-project.org>.
*/
namespace Doctrine\DBAL;
use Doctrine\DBAL\Connection;
class SQLParserUtils
{
static public function getPlaceholderPositions($statement, $isPositional = true)
{
$match = ($isPositional) ? '?' : ':';
if (strpos($statement, $match) === false) {
return array();
}
$count = 1;
$inLiteral = false; // a valid query never starts with quotes
$stmtLen = strlen($statement);
$paramMap = array();
for ($i = 0; $i < $stmtLen; $i++) {
if ($statement[$i] == $match && !$inLiteral) {
// real positional parameter detected
if ($isPositional) {
$paramMap[$count] = $i;
} else {
$name = "";
// TODO: Something faster/better to match this than regex?
for ($j = $i; ($j < $stmtLen && preg_match('(([:a-zA-Z0-9]{1}))', $statement[$j])); $j++) {
$name .= $statement[$j];
}
$paramMap[$name][] = $i; // named parameters can be duplicated!
$i = $j;
}
++$count;
} else if ($statement[$i] == "'" || $statement[$i] == '"') {
$inLiteral = ! $inLiteral; // switch state!
}
}
return $paramMap;
}
/**
* @param string $query
* @param array $params
* @param array $types
*/
static public function expandListParameters($query, $params, $types)
{
$isPositional = false;
$arrayPositions = array();
foreach ($types AS $name => $type) {
if ($type === Connection::PARAM_INT_ARRAY || $type == Connection::PARAM_STR_ARRAY) {
$arrayPositions[$name] = false;
$isPositional = (is_numeric($name));
}
}
if (!$arrayPositions) {
return array($query, $params, $types);
}
ksort($params);
ksort($types);
$paramPos = self::getPlaceholderPositions($query, $isPositional);
if ($isPositional) {
$paramOffset = 0;
$queryOffset = 0;
foreach ($paramPos AS $needle => $needlePos) {
if (!isset($arrayPositions[$needle])) {
continue;
}
$needle += $paramOffset;
$needlePos += $queryOffset;
$len = count($params[$needle]);
$params = array_merge(
array_slice($params, 0, $needle-1),
$params[$needle],
array_slice($params, $needle)
);
array_unshift($params, -1); // temporary to shift keys
unset($params[0]);
$types = array_merge(
array_slice($types, 0, $needle-1),
array_fill(0, $len, $types[$needle] - Connection::ARRAY_PARAM_OFFSET), // array needles are at PDO::PARAM_* + 100
array_slice($types, $needle)
);
array_unshift($types, -1);
unset($types[0]);
$expandStr = implode(", ", array_fill(0, $len, "?"));
$query = substr($query, 0, $needlePos) . $expandStr . substr($query, $needlePos + 1);
$paramOffset += ($len -1);
$queryOffset += (strlen($expandStr) - 1);
}
} else {
throw new DBALException("Array parameters are not supported for named placeholders.");
}
return array($query, $params, $types);
}
}
\ No newline at end of file
......@@ -59,6 +59,7 @@ class AllTests
// Connection test
$suite->addTestSuite('Doctrine\Tests\DBAL\ConnectionTest');
$suite->addTestSuite('Doctrine\Tests\DBAL\SQLParserUtilsTest');
// Events and Listeners
$suite->addTestSuite('Doctrine\Tests\DBAL\Events\OracleSessionInitTest');
......
......@@ -3,6 +3,7 @@
namespace Doctrine\Tests\DBAL\Functional;
use Doctrine\DBAL\Types\Type;
use Doctrine\DBAL\Connection;
use PDO;
require_once __DIR__ . '/../../TestInit.php';
......@@ -219,4 +220,28 @@ class DataAccessTest extends \Doctrine\Tests\DbalFunctionalTestCase
$this->assertEquals(1, $stmt->fetchColumn());
}
/**
* @group DBAL-78
*/
public function testNativeArrayListSupport()
{
for ($i = 100; $i < 110; $i++) {
$this->_conn->insert('fetch_table', array('test_int' => $i, 'test_string' => 'foo' . $i, 'test_datetime' => '2010-01-01 10:10:10'));
}
$stmt = $this->_conn->executeQuery('SELECT test_int FROM fetch_table WHERE test_int IN (?)',
array(1 => array(100, 101, 102, 103, 104)), array(1 => Connection::PARAM_INT_ARRAY));
$data = $stmt->fetchAll(PDO::FETCH_NUM);
$this->assertEquals(5, count($data));
$this->assertEquals(array(array(100), array(101), array(102), array(103), array(104)), $data);
$stmt = $this->_conn->executeQuery('SELECT test_int FROM fetch_table WHERE test_string IN (?)',
array(1 => array('foo100', 'foo101', 'foo102', 'foo103', 'foo104')), array(1 => Connection::PARAM_STR_ARRAY));
$data = $stmt->fetchAll(PDO::FETCH_NUM);
$this->assertEquals(5, count($data));
$this->assertEquals(array(array(100), array(101), array(102), array(103), array(104)), $data);
}
}
\ No newline at end of file
<?php
namespace Doctrine\Tests\DBAL;
use Doctrine\DBAL\Connection;
use Doctrine\DBAL\SQLParserUtils;
require_once __DIR__ . '/../TestInit.php';
/**
* @group DBAL-78
*/
class SQLParserUtilsTest extends \Doctrine\Tests\DbalTestCase
{
static public function dataGetPlaceholderPositions()
{
return array(
// none
array('SELECT * FROM Foo', true, array()),
array('SELECT * FROM Foo', false, array()),
// Positionals
array('SELECT ?', true, array(1 => 7)),
array('SELECT * FROM Foo WHERE bar IN (?, ?, ?)', true, array(1 => 32, 2 => 35, 3 => 38)),
array('SELECT ? FROM ?', true, array(1 => 7, 2 => 14)),
array('SELECT "?" FROM foo', true, array()),
array("SELECT '?' FROM foo", true, array()),
array('SELECT "?" FROM foo WHERE bar = ?', true, array(1 => 32)),
array("SELECT '?' FROM foo WHERE bar = ?", true, array(1 => 32)),
// named
array('SELECT :foo FROM :bar', false, array(':foo' => array(7), ':bar' => array(17))),
array('SELECT * FROM Foo WHERE bar IN (:name1, :name2)', false, array(':name1' => array(32), ':name2' => array(40))),
array('SELECT ":foo" FROM Foo WHERE bar IN (:name1, :name2)', false, array(':name1' => array(37), ':name2' => array(45))),
array("SELECT ':foo' FROM Foo WHERE bar IN (:name1, :name2)", false, array(':name1' => array(37), ':name2' => array(45))),
);
}
/**
* @dataProvider dataGetPlaceholderPositions
* @param type $query
* @param type $isPositional
* @param type $expectedParamPos
*/
public function testGetPlaceholderPositions($query, $isPositional, $expectedParamPos)
{
$actualParamPos = SQLParserUtils::getPlaceholderPositions($query, $isPositional);
$this->assertEquals($expectedParamPos, $actualParamPos);
}
static public function dataExpandListParameters()
{
return array(
// Positional: Very simple with one needle
array(
"SELECT * FROM Foo WHERE foo IN (?)",
array(1 => array(1, 2, 3)),
array(1 => Connection::PARAM_INT_ARRAY),
'SELECT * FROM Foo WHERE foo IN (?, ?, ?)',
array(1 => 1, 2 => 2, 3 => 3),
array(1 => \PDO::PARAM_INT, 2 => \PDO::PARAM_INT, 3 => \PDO::PARAM_INT)
),
// Positional: One non-list before d one after list-needle
array(
"SELECT * FROM Foo WHERE foo = ? AND bar IN (?)",
array(1 => "string", 2 => array(1, 2, 3)),
array(1 => \PDO::PARAM_STR, 2 => Connection::PARAM_INT_ARRAY),
'SELECT * FROM Foo WHERE foo = ? AND bar IN (?, ?, ?)',
array(1 => "string", 2 => 1, 3 => 2, 4 => 3),
array(1 => \PDO::PARAM_STR, 2 => \PDO::PARAM_INT, 3 => \PDO::PARAM_INT, 4 => \PDO::PARAM_INT)
),
// Positional: One non-list before d one after list-needle, parameters and types reversed.
array(
"SELECT * FROM Foo WHERE foo = ? AND bar IN (?)",
array(2 => array(1, 2, 3), 1 => "string"),
array(2 => Connection::PARAM_INT_ARRAY, 1 => \PDO::PARAM_STR),
'SELECT * FROM Foo WHERE foo = ? AND bar IN (?, ?, ?)',
array(1 => "string", 2 => 1, 3 => 2, 4 => 3),
array(1 => \PDO::PARAM_STR, 2 => \PDO::PARAM_INT, 3 => \PDO::PARAM_INT, 4 => \PDO::PARAM_INT)
),
// Positional: One non-list after list-needle
array(
"SELECT * FROM Foo WHERE bar IN (?) AND baz = ?",
array(1 => array(1, 2, 3), 3 => "foo"),
array(1 => Connection::PARAM_INT_ARRAY, 3 => \PDO::PARAM_STR),
'SELECT * FROM Foo WHERE bar IN (?, ?, ?) AND baz = ?',
array(1 => 1, 2 => 2, 3 => 3, 4 => "foo"),
array(1 => \PDO::PARAM_INT, 2 => \PDO::PARAM_INT, 3 => \PDO::PARAM_INT, 4 => \PDO::PARAM_STR)
),
// Positional: One non-list before and one after list-needle
array(
"SELECT * FROM Foo WHERE foo = ? AND bar IN (?) AND baz = ?",
array(1 => 1, 2 => array(1, 2, 3), 3 => 4),
array(1 => \PDO::PARAM_INT, 2 => Connection::PARAM_INT_ARRAY, 3 => \PDO::PARAM_INT),
'SELECT * FROM Foo WHERE foo = ? AND bar IN (?, ?, ?) AND baz = ?',
array(1 => 1, 2 => 1, 3 => 2, 4 => 3, 5 => 4),
array(1 => \PDO::PARAM_INT, 2 => \PDO::PARAM_INT, 3 => \PDO::PARAM_INT, 4 => \PDO::PARAM_INT, 5 => \PDO::PARAM_INT)
),
// Positional: Two lists
array(
"SELECT * FROM Foo WHERE foo IN (?, ?)",
array(1 => array(1, 2, 3), 2 => array(4, 5)),
array(1 => Connection::PARAM_INT_ARRAY, 2 => Connection::PARAM_INT_ARRAY),
'SELECT * FROM Foo WHERE foo IN (?, ?, ?, ?, ?)',
array(1 => 1, 2 => 2, 3 => 3, 4 => 4, 5 => 5),
array(1 => \PDO::PARAM_INT, 2 => \PDO::PARAM_INT, 3 => \PDO::PARAM_INT, 4 => \PDO::PARAM_INT, 5 => \PDO::PARAM_INT)
),
);
}
/**
* @dataProvider dataExpandListParameters
* @param type $q
* @param type $p
* @param type $t
* @param type $expectedQuery
* @param type $expectedParams
* @param type $expectedTypes
*/
public function testExpandListParameters($q, $p, $t, $expectedQuery, $expectedParams, $expectedTypes)
{
list($query, $params, $types) = SQLParserUtils::expandListParameters($q, $p, $t);
$this->assertEquals($expectedQuery, $query, "Query was not rewritten correctly.");
$this->assertEquals($expectedParams, $params, "Params dont match");
$this->assertEquals($expectedTypes, $types, "Types dont match");
}
}
\ No newline at end of file
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment