Permalink
Browse files

Updated doModifyLimitQuery in SQLServerPlatform to handle subqueries …

…with Ordering
  • Loading branch information...
1 parent f3374cb commit 88c1975dda492f3dd93cddea71ebacb40ed7efa5 Norbert Orzechowicz committed Jan 22, 2013
@@ -668,32 +668,60 @@ public function getBooleanTypeDeclarationSQL(array $field)
/**
* {@inheritDoc}
- *
- * @link http://lists.bestpractical.com/pipermail/rt-devel/2005-June/007339.html
*/
protected function doModifyLimitQuery($query, $limit, $offset = null)
{
if ($limit > 0) {
- if ($offset == 0) {
- $query = preg_replace('/^(SELECT\s(DISTINCT\s)?)/i', '\1TOP ' . $limit . ' ', $query);
+ $orderby = stristr($query, 'ORDER BY');
+ //Remove ORDER BY from $query
+ $query = preg_replace('/\s*ORDER\s*BY([^\)]*)/', '', $query);
+ $over = 'ORDER BY';
+
+ if ( ! $orderby) {
+ $over .= ' (SELECT 0)';
} else {
- $orderby = stristr($query, 'ORDER BY');
+ //Clear ORDER BY
+ $orderby = preg_replace('/ORDER BY\s?([^\)]*)(.*)/', '$1', $orderby);
+ $orderbyParts = explode(',', $orderby);
+ $orderbyColumns = array();
+
+ //Split ORDER BY into parts
+ foreach ($orderbyParts as &$part) {
+ $part = trim($part);
+ if (preg_match('/([^\s]*\.)?([^\.\s]*)\s*(ASC|DESC)?/i', $part, $matches)) {
+ $orderbyColumns[] = array(
+ 'table' => empty($matches[1])
+ ? '[^\.\s]*'
+ : rtrim($matches[1], '.'),
+ 'column' => $matches[2],
+ 'sort' => isset($matches[3]) ? $matches[3] : null
+ );
+ }
+ }
- if ( ! $orderby) {
- $over = 'ORDER BY (SELECT 0)';
- } else {
- $over = preg_replace('/\"[^,]*\".\"([^,]*)\"/i', '"inner_tbl"."$1"', $orderby);
+ //Find alias for each colum used in ORDER BY
+ if (count($orderbyColumns)) {
+ foreach ($orderbyColumns as $column) {
+ if (preg_match('/' . $column['table'] . '\.(' . $column['column'] . ')\s?(AS)?\s?([^,\s\)]*)/i', $query, $matches)) {
+ $over .= ' ' . $matches[3];
+ $over .= isset($column['sort']) ? ' ' . $column['sort'] . ',' : ',';
+ } else {
+ $over .= ' ' . $column['column'];
+ $over .= isset($column['sort']) ? ' ' . $column['sort'] . ',' : ',';
+ }
+ }
+
+ $over = rtrim($over, ',');
}
+ }
- // Remove ORDER BY clause from $query
- $query = preg_replace('/\s+ORDER BY(.*)/', '', $query);
- $query = preg_replace('/\sFROM/i', ", ROW_NUMBER() OVER ($over) AS doctrine_rownum FROM", $query);
+ //Replace only first occurrence of FROM with $over to prevent changing FROM also in subqueries.
+ $query = preg_replace('/\sFROM/i', ", ROW_NUMBER() OVER ($over) AS doctrine_rownum FROM", $query, 1);
- $start = $offset + 1;
- $end = $offset + $limit;
+ $start = $offset + 1;
+ $end = $offset + $limit;
- $query = "SELECT * FROM ($query) AS doctrine_tbl WHERE doctrine_rownum BETWEEN $start AND $end";
- }
+ $query = "SELECT * FROM ($query) AS doctrine_tbl WHERE doctrine_rownum BETWEEN $start AND $end";
}
return $query;
@@ -142,13 +142,13 @@ public function getGenerateForeignKeySql()
public function testModifyLimitQuery()
{
$sql = $this->_platform->modifyLimitQuery('SELECT * FROM user', 10, 0);
- $this->assertEquals('SELECT TOP 10 * FROM user', $sql);
+ $this->assertEquals('SELECT * FROM (SELECT *, ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS doctrine_rownum FROM user) AS doctrine_tbl WHERE doctrine_rownum BETWEEN 1 AND 10', $sql);
}
public function testModifyLimitQueryWithEmptyOffset()
{
$sql = $this->_platform->modifyLimitQuery('SELECT * FROM user', 10);
- $this->assertEquals('SELECT TOP 10 * FROM user', $sql);
+ $this->assertEquals('SELECT * FROM (SELECT *, ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS doctrine_rownum FROM user) AS doctrine_tbl WHERE doctrine_rownum BETWEEN 1 AND 10', $sql);
}
public function testModifyLimitQueryWithOffset()
@@ -160,13 +160,40 @@ public function testModifyLimitQueryWithOffset()
public function testModifyLimitQueryWithAscOrderBy()
{
$sql = $this->_platform->modifyLimitQuery('SELECT * FROM user ORDER BY username ASC', 10);
- $this->assertEquals('SELECT TOP 10 * FROM user ORDER BY username ASC', $sql);
+ $this->assertEquals('SELECT * FROM (SELECT *, ROW_NUMBER() OVER (ORDER BY username ASC) AS doctrine_rownum FROM user) AS doctrine_tbl WHERE doctrine_rownum BETWEEN 1 AND 10', $sql);
}
public function testModifyLimitQueryWithDescOrderBy()
{
$sql = $this->_platform->modifyLimitQuery('SELECT * FROM user ORDER BY username DESC', 10);
- $this->assertEquals('SELECT TOP 10 * FROM user ORDER BY username DESC', $sql);
+ $this->assertEquals('SELECT * FROM (SELECT *, ROW_NUMBER() OVER (ORDER BY username DESC) AS doctrine_rownum FROM user) AS doctrine_tbl WHERE doctrine_rownum BETWEEN 1 AND 10', $sql);
+ }
+
+ public function testModifyLimitQueryWithMultipleOrderBy()
+ {
+ $sql = $this->_platform->modifyLimitQuery('SELECT * FROM user ORDER BY username DESC, usereamil ASC', 10);
+ $this->assertEquals('SELECT * FROM (SELECT *, ROW_NUMBER() OVER (ORDER BY username DESC, usereamil ASC) AS doctrine_rownum FROM user) AS doctrine_tbl WHERE doctrine_rownum BETWEEN 1 AND 10', $sql);
+ }
+
+ public function testModifyLimitQueryWithSubSelect()
+ {
+ $sql = $this->_platform->modifyLimitQuery('SELECT * FROM (SELECT u.id as uid, u.name as uname) dctrn_result', 10);
+ $this->assertEquals('SELECT * FROM (SELECT *, ROW_NUMBER() OVER (ORDER BY (SELECT 0)) AS doctrine_rownum FROM (SELECT u.id as uid, u.name as uname) dctrn_result) AS doctrine_tbl WHERE doctrine_rownum BETWEEN 1 AND 10', $sql);
+ }
+
+ public function testModifyLimitQueryWithSubSelectAndOrder()
+ {
+ $sql = $this->_platform->modifyLimitQuery('SELECT * FROM (SELECT u.id as uid, u.name as uname ORDER BY u.name DESC) dctrn_result', 10);
+ $this->assertEquals('SELECT * FROM (SELECT *, ROW_NUMBER() OVER (ORDER BY uname DESC) AS doctrine_rownum FROM (SELECT u.id as uid, u.name as uname) dctrn_result) AS doctrine_tbl WHERE doctrine_rownum BETWEEN 1 AND 10', $sql);
+ }
+
+ public function testModifyLimitQueryWithSubSelectAndMultipleOrder()
+ {
+ $sql = $this->_platform->modifyLimitQuery('SELECT * FROM (SELECT u.id as uid, u.name as uname ORDER BY u.name DESC, id ASC) dctrn_result', 10, 5);
+ $this->assertEquals('SELECT * FROM (SELECT *, ROW_NUMBER() OVER (ORDER BY uname DESC, uid ASC) AS doctrine_rownum FROM (SELECT u.id as uid, u.name as uname) dctrn_result) AS doctrine_tbl WHERE doctrine_rownum BETWEEN 6 AND 15', $sql);
+
+ $sql = $this->_platform->modifyLimitQuery('SELECT * FROM (SELECT u.id uid, u.name uname ORDER BY u.name DESC, id ASC) dctrn_result', 10, 5);
+ $this->assertEquals('SELECT * FROM (SELECT *, ROW_NUMBER() OVER (ORDER BY uname DESC, uid ASC) AS doctrine_rownum FROM (SELECT u.id uid, u.name uname) dctrn_result) AS doctrine_tbl WHERE doctrine_rownum BETWEEN 6 AND 15', $sql);
}
/**

0 comments on commit 88c1975

Please sign in to comment.