Skip to content

Commit

Permalink
Merge pull request #2372 from morozov/sql-server-limit
Browse files Browse the repository at this point in the history
Handle arbitrary whitespaces when parsing SQL in order to apply LIMIT for MS SQL Server
  • Loading branch information
Ocramius authored Sep 9, 2016
2 parents a3577e4 + 81dd0b7 commit ec8fc16
Show file tree
Hide file tree
Showing 3 changed files with 23 additions and 3 deletions.
4 changes: 2 additions & 2 deletions lib/Doctrine/DBAL/Platforms/SQLServer2012Platform.php
Original file line number Diff line number Diff line change
Expand Up @@ -117,7 +117,7 @@ protected function doModifyLimitQuery($query, $limit, $offset = null)
// Find the position of the last instance of ORDER BY and ensure it is not within a parenthetical statement
// but can be in a newline
$matches = array();
$matchesCount = preg_match_all("/[\\s]+order by /i", $query, $matches, PREG_OFFSET_CAPTURE);
$matchesCount = preg_match_all("/[\\s]+order\\s+by\\s/im", $query, $matches, PREG_OFFSET_CAPTURE);
$orderByPos = false;
if ($matchesCount > 0) {
$orderByPos = $matches[0][($matchesCount - 1)][1];
Expand All @@ -126,7 +126,7 @@ protected function doModifyLimitQuery($query, $limit, $offset = null)
if ($orderByPos === false
|| substr_count($query, "(", $orderByPos) - substr_count($query, ")", $orderByPos)
) {
if (stripos($query, 'SELECT DISTINCT') === 0) {
if (preg_match('/^SELECT\s+DISTINCT/im', $query)) {
// SQL Server won't let us order by a non-selected column in a DISTINCT query,
// so we have to do this madness. This says, order by the first column in the
// result. SQL Server's docs say that a nonordered query's result order is non-
Expand Down
2 changes: 1 addition & 1 deletion lib/Doctrine/DBAL/Platforms/SQLServerPlatform.php
Original file line number Diff line number Diff line change
Expand Up @@ -1192,7 +1192,7 @@ protected function doModifyLimitQuery($query, $limit, $offset = null)
// Even if the TOP n is very large, the use of a CTE will
// allow the SQL Server query planner to optimize it so it doesn't
// actually scan the entire range covered by the TOP clause.
$selectPattern = '/^(\s*SELECT\s+(?:DISTINCT\s+)?)(.*)$/i';
$selectPattern = '/^(\s*SELECT\s+(?:DISTINCT\s+)?)(.*)$/im';
$replacePattern = sprintf('$1%s $2', "TOP $end");
$query = preg_replace($selectPattern, $replacePattern, $query);

Expand Down
20 changes: 20 additions & 0 deletions tests/Doctrine/Tests/DBAL/Functional/ModifyLimitQueryTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -124,6 +124,26 @@ public function testModifyLimitQueryFromSubSelect()
$this->assertLimitResult(array(2, 1), $sql, 2, 2);
}

public function testModifyLimitQueryLineBreaks()
{
$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));

$sql = <<<SQL
SELECT
*
FROM
modify_limit_table
ORDER
BY
test_int
ASC
SQL;

$this->assertLimitResult(array(2), $sql, 1, 1);
}

public function assertLimitResult($expectedResults, $sql, $limit, $offset, $deterministic = true)
{
$p = $this->_conn->getDatabasePlatform();
Expand Down

0 comments on commit ec8fc16

Please sign in to comment.