Commit de6c0bd2 authored by Steve Müller's avatar Steve Müller

Merge pull request #818 from zeroedin-bill/sqlserverlimitfix-2

Rebuild SQLServerPlatform::doModifyLimitQuery again to use a CTE
parents 069280e5 f6150972
......@@ -1182,77 +1182,110 @@ class SQLServerPlatform extends AbstractPlatform
$start = $offset + 1;
$end = $offset + $limit;
$orderBy = stristr($query, 'ORDER BY');
//Remove ORDER BY from $query (including nested parentheses in order by list).
$query = preg_replace('/\s+ORDER\s+BY\s+([^()]+|\((?:(?:(?>[^()]+)|(?R))*)\))+/i', '', $query);
// We'll find a SELECT or SELECT distinct and prepend TOP n to it
// 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';
$replacePattern = sprintf('$1%s $2', "TOP $end");
$query = preg_replace($selectPattern, $replacePattern, $query);
if (stristr($query, "ORDER BY")) {
// Inner order by is not valid in SQL Server for our purposes
// unless it's in a TOP N subquery.
$query = $this->scrubInnerOrderBy($query);
}
$format = 'SELECT * FROM (%s) AS doctrine_tbl WHERE doctrine_rownum BETWEEN %d AND %d ORDER BY doctrine_rownum';
// Build a new limited query around the original, using a CTE
return sprintf(
"WITH dctrn_cte AS (%s) "
. "SELECT * FROM ("
. "SELECT *, ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS doctrine_rownum FROM dctrn_cte"
. ") AS doctrine_tbl "
. "WHERE doctrine_rownum BETWEEN %d AND %d ORDER BY doctrine_rownum ASC",
$query,
$start,
$end
);
}
// Pattern to match "main" SELECT ... FROM clause (including nested parentheses in select list).
$selectFromPattern = '/^(\s*SELECT\s+(?:(.*)(?![^(]*\))))\sFROM\s/i';
/**
* Remove ORDER BY clauses in subqueries - they're not supported by SQL Server.
* Caveat: will leave ORDER BY in TOP N subqueries.
*
* @param $query
* @return string
*/
private function scrubInnerOrderBy($query)
{
$count = substr_count(strtoupper($query), "ORDER BY");
$offset = 0;
if ( ! $orderBy) {
//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
);
while ($count-- > 0) {
$qLen = strlen($query);
$orderByPos = stripos($query, " ORDER BY", $offset);
$parenCount = 0;
$currentPosition = $orderByPos;
return sprintf($format, $query, $start, $end);
}
while ($parenCount >= 0 && $currentPosition < $qLen) {
if ($query[$currentPosition] === '(') {
$parenCount++;
} elseif ($query[$currentPosition] === ')') {
$parenCount--;
}
//Clear ORDER BY
$orderBy = preg_replace('/ORDER\s+BY\s+(.*)/i', '$1', $orderBy);
$orderByParts = explode(',', $orderBy);
$orderByColumns = array();
$currentPosition++;
}
//Split ORDER BY into parts
foreach ($orderByParts as &$part) {
if ($this->isOrderByInTopNSubquery($query, $orderByPos)) {
// If the order by clause is in a TOP N subquery, do not remove
// it and continue iteration from the current position.
$offset = $currentPosition;
continue;
}
if (preg_match('/(([^\s]*)\.)?([^\.\s]*)\s*(ASC|DESC)?/i', trim($part), $matches)) {
$orderByColumns[] = array(
'column' => $matches[3],
'hasTable' => ( ! empty($matches[2])),
'sort' => isset($matches[4]) ? $matches[4] : null,
'table' => empty($matches[2]) ? '[^\.\s]*' : $matches[2]
);
if ($currentPosition < $qLen - 1) {
$query = substr($query, 0, $orderByPos) . substr($query, $currentPosition - 1);
$offset = $orderByPos;
}
}
return $query;
}
$isWrapped = (preg_match('/SELECT DISTINCT .* FROM \(.*\) dctrn_result/', $query)) ? true : false;
$overColumns = array();
//Find alias for each column used in ORDER BY
if ( ! empty($orderByColumns)) {
foreach ($orderByColumns as $column) {
$pattern = sprintf('/%s\.%s\s+(?:AS\s+)?([^,\s)]+)/i', $column['table'], $column['column']);
if ($isWrapped) {
$overColumn = preg_match($pattern, $query, $matches)
? $matches[1] : '';
} else {
$overColumn = preg_match($pattern, $query, $matches)
? ($column['hasTable'] ? $column['table'] . '.' : '') . $column['column']
: $column['column'];
}
/**
* Check an ORDER BY clause to see if it is in a TOP N query or subquery.
*
* @param string $query The query
* @param int $currentPosition Start position of ORDER BY clause
* @return bool true if ORDER BY is in a TOP N query, false otherwise
*/
private function isOrderByInTopNSubquery($query, $currentPosition)
{
// Grab query text on the same nesting level as the ORDER BY clause we're examining.
$subQueryBuffer = '';
$parenCount = 0;
// If $parenCount goes negative, we've exited the subquery we're examining.
// If $currentPosition goes negative, we've reached the beginning of the query.
while ($parenCount >= 0 && $currentPosition >= 0) {
if ($query[$currentPosition] === '(') {
$parenCount--;
} elseif ($query[$currentPosition] === ')') {
$parenCount++;
}
if (isset($column['sort'])) {
$overColumn .= ' ' . $column['sort'];
}
// Only yank query text on the same nesting level as the ORDER BY clause.
$subQueryBuffer = ($parenCount === 0 ? $query[$currentPosition] : " ") . $subQueryBuffer;
$overColumns[] = $overColumn;
}
$currentPosition--;
}
//Replace only first occurrence of FROM with $over to prevent changing FROM also in subqueries.
$over = 'ORDER BY ' . implode(', ', $overColumns);
$query = preg_replace($selectFromPattern, "$1, ROW_NUMBER() OVER ($over) AS doctrine_rownum FROM ", $query, 1);
if (preg_match('/SELECT\s+(DISTINCT\s+)?TOP\s/i', $subQueryBuffer)) {
return true;
}
return sprintf($format, $query, $start, $end);
return false;
}
/**
......
......@@ -269,4 +269,98 @@ class SQLServer2012PlatformTest extends AbstractSQLServerPlatformTestCase
$this->assertEquals($sql, $expected);
}
/**
* @throws \Doctrine\DBAL\DBALException
*/
public function testModifyLimitSubqueryWithJoinAndSubqueryOrderedByColumnFromBaseTable()
{
$querySql = "SELECT DISTINCT id_0, name_1 "
. "FROM ("
. "SELECT t1.id AS id_0, t2.name AS name_1 "
. "FROM table_parent t1 "
. "LEFT JOIN join_table t2 ON t1.id = t2.table_id"
. ") dctrn_result "
. "ORDER BY id_0 ASC";
$alteredSql = "SELECT DISTINCT id_0, name_1 "
. "FROM ("
. "SELECT t1.id AS id_0, t2.name AS name_1 "
. "FROM table_parent t1 "
. "LEFT JOIN join_table t2 ON t1.id = t2.table_id"
. ") dctrn_result "
. "ORDER BY id_0 ASC OFFSET 0 ROWS FETCH NEXT 5 ROWS ONLY";
$sql = $this->_platform->modifyLimitQuery($querySql, 5);
$this->assertEquals($alteredSql, $sql);
}
/**
* @throws \Doctrine\DBAL\DBALException
*/
public function testModifyLimitSubqueryWithJoinAndSubqueryOrderedByColumnFromJoinTable()
{
$querySql = "SELECT DISTINCT id_0, name_1 "
. "FROM ("
. "SELECT t1.id AS id_0, t2.name AS name_1 "
. "FROM table_parent t1 "
. "LEFT JOIN join_table t2 ON t1.id = t2.table_id"
. ") dctrn_result "
. "ORDER BY name_1 ASC";
$alteredSql = "SELECT DISTINCT id_0, name_1 "
. "FROM ("
. "SELECT t1.id AS id_0, t2.name AS name_1 "
. "FROM table_parent t1 "
. "LEFT JOIN join_table t2 ON t1.id = t2.table_id"
. ") dctrn_result "
. "ORDER BY name_1 ASC OFFSET 0 ROWS FETCH NEXT 5 ROWS ONLY";
$sql = $this->_platform->modifyLimitQuery($querySql, 5);
$this->assertEquals($alteredSql, $sql);
}
/**
* @throws \Doctrine\DBAL\DBALException
*/
public function testModifyLimitSubqueryWithJoinAndSubqueryOrderedByColumnsFromBothTables()
{
$querySql = "SELECT DISTINCT id_0, name_1, foo_2 "
. "FROM ("
. "SELECT t1.id AS id_0, t2.name AS name_1, t2.foo AS foo_2 "
. "FROM table_parent t1 "
. "LEFT JOIN join_table t2 ON t1.id = t2.table_id"
. ") dctrn_result "
. "ORDER BY name_1 ASC, foo_2 DESC";
$alteredSql = "SELECT DISTINCT id_0, name_1, foo_2 "
. "FROM ("
. "SELECT t1.id AS id_0, t2.name AS name_1, t2.foo AS foo_2 "
. "FROM table_parent t1 "
. "LEFT JOIN join_table t2 ON t1.id = t2.table_id"
. ") dctrn_result "
. "ORDER BY name_1 ASC, foo_2 DESC OFFSET 0 ROWS FETCH NEXT 5 ROWS ONLY";
$sql = $this->_platform->modifyLimitQuery($querySql, 5);
$this->assertEquals($alteredSql, $sql);
}
public function testModifyLimitSubquerySimple()
{
$querySql = "SELECT DISTINCT id_0 FROM "
. "(SELECT k0_.id AS id_0, k0_.field AS field_1 "
. "FROM key_table k0_ WHERE (k0_.where_field IN (1))) dctrn_result";
$alteredSql = "SELECT DISTINCT id_0 FROM (SELECT k0_.id AS id_0, k0_.field AS field_1 "
. "FROM key_table k0_ WHERE (k0_.where_field IN (1))) dctrn_result ORDER BY 1 OFFSET 0 ROWS FETCH NEXT 20 ROWS ONLY";
$sql = $this->_platform->modifyLimitQuery($querySql, 20);
$this->assertEquals($alteredSql, $sql);
}
public function testModifyLimitQueryWithTopNSubQueryWithOrderBy()
{
$querySql = 'SELECT * FROM test t WHERE t.id = (SELECT TOP 1 t2.id FROM test t2 ORDER BY t2.data DESC)';
$expectedSql = 'SELECT * FROM test t WHERE t.id = (SELECT TOP 1 t2.id FROM test t2 ORDER BY t2.data DESC) ORDER BY (SELECT 0) OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY';
$sql = $this->_platform->modifyLimitQuery($querySql, 10);
$this->assertEquals($expectedSql, $sql);
$querySql = 'SELECT * FROM test t WHERE t.id = (SELECT TOP 1 t2.id FROM test t2 ORDER BY t2.data DESC) ORDER BY t.data2 DESC';
$expectedSql = 'SELECT * FROM test t WHERE t.id = (SELECT TOP 1 t2.id FROM test t2 ORDER BY t2.data DESC) ORDER BY t.data2 DESC OFFSET 0 ROWS FETCH NEXT 10 ROWS ONLY';
$sql = $this->_platform->modifyLimitQuery($querySql, 10);
$this->assertEquals($expectedSql, $sql);
}
}
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