Commit c4d4c5f2 authored by Benjamin Eberlei's avatar Benjamin Eberlei

Merge pull request #512 from deeky666/DBAL-713

Fix modifying limit/offset for statements with subqueries on SQL Server
parents 14333d9c 9f3cb437
......@@ -1145,9 +1145,17 @@ class SQLServerPlatform extends AbstractPlatform
$query = preg_replace('/\s+ORDER\s+BY\s+([^\)]*)/', '', $query); //Remove ORDER BY from $query
$format = 'SELECT * FROM (%s) AS doctrine_tbl WHERE doctrine_rownum BETWEEN %d AND %d';
// Pattern to match "main" SELECT ... FROM clause (including nested parentheses in select list).
$selectFromPattern = '/^(\s*SELECT\s+(?:\((?>[^()]+)|(?:R)*\)|[^(])+)\sFROM\s/i';
if ( ! $orderBy) {
//Replace only first occurrence of FROM with OVER to prevent changing FROM also in subqueries.
$query = preg_replace('/\sFROM\s/i', ', ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS doctrine_rownum FROM ', $query, 1);
//Replace only "main" FROM with OVER to prevent changing FROM also in subqueries.
$query = preg_replace(
$selectFromPattern,
'$1, ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS doctrine_rownum FROM ',
$query,
1
);
return sprintf($format, $query, $start, $end);
}
......@@ -1197,7 +1205,7 @@ class SQLServerPlatform extends AbstractPlatform
//Replace only first occurrence of FROM with $over to prevent changing FROM also in subqueries.
$over = 'ORDER BY ' . implode(', ', $overColumns);
$query = preg_replace('/\sFROM\s/i', ", ROW_NUMBER() OVER ($over) AS doctrine_rownum FROM ", $query, 1);
$query = preg_replace($selectFromPattern, "$1, ROW_NUMBER() OVER ($over) AS doctrine_rownum FROM ", $query, 1);
return sprintf($format, $query, $start, $end);
}
......
......@@ -102,6 +102,20 @@ class ModifyLimitQueryTest extends \Doctrine\Tests\DbalFunctionalTestCase
$this->assertLimitResult(array(2), $sql, 1, 1);
}
public function testModifyLimitQuerySubSelect()
{
$this->_conn->insert('modify_limit_table', array('test_int' => 1));
$this->_conn->insert('modify_limit_table', array('test_int' => 2));
$this->_conn->insert('modify_limit_table', array('test_int' => 3));
$this->_conn->insert('modify_limit_table', array('test_int' => 4));
$sql = "SELECT *, (SELECT COUNT(*) FROM modify_limit_table) AS cnt FROM modify_limit_table";
$this->assertLimitResult(array(4, 3, 2, 1), $sql, 10, 0, false);
$this->assertLimitResult(array(4, 3), $sql, 2, 0, false);
$this->assertLimitResult(array(2, 1), $sql, 2, 2, false);
}
public function assertLimitResult($expectedResults, $sql, $limit, $offset, $deterministic = true)
{
$p = $this->_conn->getDatabasePlatform();
......
......@@ -256,6 +256,74 @@ abstract class AbstractSQLServerPlatformTestCase extends AbstractPlatformTestCas
$this->assertEquals($expected, $actual);
}
/**
* @group DBAL-713
*/
public function testModifyLimitQueryWithSubSelectInSelectList()
{
$sql = $this->_platform->modifyLimitQuery(
"SELECT " .
"u.id, " .
"(u.foo/2) foodiv, " .
"CONCAT(u.bar, u.baz) barbaz, " .
"(SELECT (SELECT COUNT(*) FROM login l WHERE l.profile_id = p.id) FROM profile p WHERE p.user_id = u.id) login_count " .
"FROM user u " .
"WHERE u.status = 'disabled'",
10
);
$this->assertEquals(
"SELECT * FROM (" .
"SELECT " .
"u.id, " .
"(u.foo/2) foodiv, " .
"CONCAT(u.bar, u.baz) barbaz, " .
"(SELECT (SELECT COUNT(*) FROM login l WHERE l.profile_id = p.id) FROM profile p WHERE p.user_id = u.id) login_count, " .
"ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS doctrine_rownum " .
"FROM user u " .
"WHERE u.status = 'disabled'" .
") AS doctrine_tbl WHERE doctrine_rownum BETWEEN 1 AND 10",
$sql
);
}
/**
* @group DBAL-713
*/
public function testModifyLimitQueryWithSubSelectInSelectListAndOrderByClause()
{
if ( ! $this->_platform->supportsLimitOffset()) {
$this->markTestSkipped(sprintf('Platform "%s" does not support offsets in result limiting.', $this->_platform->getName()));
}
$sql = $this->_platform->modifyLimitQuery(
"SELECT " .
"u.id, " .
"(u.foo/2) foodiv, " .
"CONCAT(u.bar, u.baz) barbaz, " .
"(SELECT (SELECT COUNT(*) FROM login l WHERE l.profile_id = p.id) FROM profile p WHERE p.user_id = u.id) login_count " .
"FROM user u " .
"WHERE u.status = 'disabled' " .
"ORDER BY u.username DESC",
10,
5
);
$this->assertEquals(
"SELECT * FROM (" .
"SELECT " .
"u.id, " .
"(u.foo/2) foodiv, " .
"CONCAT(u.bar, u.baz) barbaz, " .
"(SELECT (SELECT COUNT(*) FROM login l WHERE l.profile_id = p.id) FROM profile p WHERE p.user_id = u.id) login_count, " .
"ROW_NUMBER() OVER (ORDER BY username DESC) AS doctrine_rownum " .
"FROM user u " .
"WHERE u.status = 'disabled'" .
") AS doctrine_tbl WHERE doctrine_rownum BETWEEN 6 AND 15",
$sql
);
}
/**
* @group DDC-1360
*/
......
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