mirror of
https://github.com/kamilwylegala/cakephp2-php8.git
synced 2024-11-15 03:18:26 +00:00
Adding new limit/offset pagination for SQLServer 11.
This commit is contained in:
parent
0e09f75a66
commit
e33a9a7846
2 changed files with 38 additions and 23 deletions
|
@ -116,6 +116,8 @@ class Sqlserver extends DboSource {
|
|||
|
||||
const ROW_COUNTER = '_cake_page_rownum_';
|
||||
|
||||
protected $_version;
|
||||
|
||||
/**
|
||||
* Connects to the database using options in the given configuration array.
|
||||
*
|
||||
|
@ -140,7 +142,7 @@ class Sqlserver extends DboSource {
|
|||
throw new MissingConnectionException(array('class' => $e->getMessage()));
|
||||
}
|
||||
|
||||
// $this->_execute("SET DATEFORMAT ymd");
|
||||
$this->_version = $this->_connection->getAttribute(PDO::ATTR_SERVER_VERSION);
|
||||
return $this->connected;
|
||||
}
|
||||
|
||||
|
@ -375,7 +377,7 @@ class Sqlserver extends DboSource {
|
|||
}
|
||||
$rt .= ' ' . $limit;
|
||||
if (is_int($offset) && $offset > 0) {
|
||||
$rt .= ' OFFSET ' . $offset;
|
||||
$rt = ' OFFSET ' . intval($offset) . ' ROWS FETCH FIRST ' . intval($limit) . ' ROWS ONLY';
|
||||
}
|
||||
return $rt;
|
||||
}
|
||||
|
@ -495,24 +497,33 @@ class Sqlserver extends DboSource {
|
|||
$fields = substr($fields, 9);
|
||||
}
|
||||
|
||||
if (preg_match('/offset\s+([0-9]+)/i', $limit, $offset)) {
|
||||
$limit = preg_replace('/\s*offset.*$/i', '', $limit);
|
||||
preg_match('/top\s+([0-9]+)/i', $limit, $limitVal);
|
||||
$offset = intval($offset[1]) + intval($limitVal[1]);
|
||||
// hack order as SQLServer requires an order if there is a limit.
|
||||
if ($limit && !$order) {
|
||||
$order = 'ORDER BY (SELECT NULL)';
|
||||
}
|
||||
|
||||
// For older versions use the subquery version of pagination.
|
||||
if (version_compare($this->_version, '11', '<') && preg_match('/FETCH\sFIRST\s+([0-9]+)/i', $limit, $offset)) {
|
||||
preg_match('/OFFSET\s*(\d+)\s*.*?(\d+)\s*ROWS/', $limit, $limitOffset);
|
||||
|
||||
$limit = 'TOP ' . intval($limitOffset[2]);
|
||||
$page = intval($limitOffset[1] / $limitOffset[2]);
|
||||
$offset = intval($limitOffset[2] * $page);
|
||||
if (!$order) {
|
||||
$order = 'ORDER BY (SELECT NULL)';
|
||||
}
|
||||
|
||||
$rowCounter = self::ROW_COUNTER;
|
||||
$pagination = "
|
||||
return "
|
||||
SELECT {$limit} * FROM (
|
||||
SELECT {$fields}, ROW_NUMBER() OVER ({$order}) AS {$rowCounter}
|
||||
FROM {$table} {$alias} {$joins} {$conditions} {$group}
|
||||
) AS _cake_paging_
|
||||
WHERE _cake_paging_.{$rowCounter} >= {$offset}
|
||||
WHERE _cake_paging_.{$rowCounter} > {$offset}
|
||||
ORDER BY _cake_paging_.{$rowCounter}
|
||||
";
|
||||
return $pagination;
|
||||
} elseif (strpos($limit, 'FETCH') !== false) {
|
||||
return "SELECT {$fields} FROM {$table} {$alias} {$joins} {$conditions} {$group} {$order} {$limit}";
|
||||
} else {
|
||||
return "SELECT {$limit} {$fields} FROM {$table} {$alias} {$joins} {$conditions} {$group} {$order}";
|
||||
}
|
||||
|
|
|
@ -249,7 +249,7 @@ class SqlserverTest extends CakeTestCase {
|
|||
*
|
||||
* @var array
|
||||
*/
|
||||
public $fixtures = array('core.category', 'core.author', 'core.post');
|
||||
public $fixtures = array('core.user', 'core.category', 'core.author', 'core.post');
|
||||
|
||||
/**
|
||||
* Sets up a Dbo class instance for testing
|
||||
|
@ -617,27 +617,31 @@ class SqlserverTest extends CakeTestCase {
|
|||
* @return void
|
||||
*/
|
||||
public function testLimitOffsetHack() {
|
||||
$this->loadFixtures('Author', 'Post');
|
||||
$this->loadFixtures('Author', 'Post', 'User');
|
||||
$query = array(
|
||||
'limit' => 1,
|
||||
'limit' => 2,
|
||||
'page' => 1,
|
||||
'order' => 'Post.title ASC',
|
||||
'order' => 'User.user ASC',
|
||||
);
|
||||
$Post = ClassRegistry::init('Post');
|
||||
$results = $Post->find('all', $query);
|
||||
$User = ClassRegistry::init('User');
|
||||
$results = $User->find('all', $query);
|
||||
|
||||
$this->assertEquals(1, count($results));
|
||||
$this->assertEquals('First Post', $results[0]['Post']['title']);
|
||||
$this->assertEquals(2, count($results));
|
||||
$this->assertEquals('garrett', $results[0]['User']['user']);
|
||||
$this->assertEquals('larry', $results[1]['User']['user']);
|
||||
|
||||
$query = array(
|
||||
'limit' => 1,
|
||||
'limit' => 2,
|
||||
'page' => 2,
|
||||
'order' => 'Post.title ASC',
|
||||
'order' => 'User.user ASC',
|
||||
);
|
||||
$Post = ClassRegistry::init('Post');
|
||||
$results = $Post->find('all', $query);
|
||||
$this->assertEquals(1, count($results));
|
||||
$User = ClassRegistry::init('User');
|
||||
$results = $User->find('all', $query);
|
||||
|
||||
$this->assertEquals(2, count($results));
|
||||
$this->assertFalse(isset($results[0][0]));
|
||||
$this->assertEquals('Second Post', $results[0]['Post']['title']);
|
||||
$this->assertEquals('mariano', $results[0]['User']['user']);
|
||||
$this->assertEquals('nate', $results[1]['User']['user']);
|
||||
}
|
||||
|
||||
}
|
||||
|
|
Loading…
Reference in a new issue