diff --git a/lib/dml/mssql_native_moodle_database.php b/lib/dml/mssql_native_moodle_database.php index 96df8997718c1..ba6dcf6c668f0 100644 --- a/lib/dml/mssql_native_moodle_database.php +++ b/lib/dml/mssql_native_moodle_database.php @@ -40,6 +40,11 @@ class mssql_native_moodle_database extends moodle_database { protected $mssql = null; protected $last_error_reporting; // To handle mssql driver default verbosity protected $collation; // current DB collation cache + /** + * Does the used db version support ANSI way of limiting (2012 and higher) + * @var bool + */ + protected $supportsoffsetfetch; /** * Detects if all needed PHP stuff installed. @@ -229,6 +234,10 @@ public function connect($dbhost, $dbuser, $dbpass, $dbname, $prefix, array $dbop $this->free_result($result); + $serverinfo = $this->get_server_info(); + // Fetch/offset is supported staring from SQL Server 2012. + $this->supportsoffsetfetch = $serverinfo['version'] > '11'; + // Connection stabilised and configured, going to instantiate the temptables controller $this->temptables = new mssql_native_moodle_temptables($this); @@ -737,13 +746,28 @@ public function get_recordset_sql($sql, array $params=null, $limitfrom=0, $limit list($limitfrom, $limitnum) = $this->normalise_limit_from_num($limitfrom, $limitnum); if ($limitfrom or $limitnum) { - if ($limitnum >= 1) { // Only apply TOP clause if we have any limitnum (limitfrom offset is handled later) - $fetch = $limitfrom + $limitnum; - if (PHP_INT_MAX - $limitnum < $limitfrom) { // Check PHP_INT_MAX overflow - $fetch = PHP_INT_MAX; + if (!$this->supportsoffsetfetch) { + if ($limitnum >= 1) { // Only apply TOP clause if we have any limitnum (limitfrom offset is handled later). + $fetch = $limitfrom + $limitnum; + if (PHP_INT_MAX - $limitnum < $limitfrom) { // Check PHP_INT_MAX overflow. + $fetch = PHP_INT_MAX; + } + $sql = preg_replace('/^([\s(])*SELECT([\s]+(DISTINCT|ALL))?(?!\s*TOP\s*\()/i', + "\\1SELECT\\2 TOP $fetch", $sql); + } + } else { + $sql = (substr($sql, -1) === ';') ? substr($sql, 0, -1) : $sql; + // We need order by to use FETCH/OFFSET. + // Ordering by first column shouldn't break anything if there was no order in the first place. + if (!strpos(strtoupper($sql), "ORDER BY")) { + $sql .= " ORDER BY 1"; + } + + $sql .= " OFFSET ".$limitfrom." ROWS "; + + if ($limitnum > 0) { + $sql .= " FETCH NEXT ".$limitnum." ROWS ONLY"; } - $sql = preg_replace('/^([\s(])*SELECT([\s]+(DISTINCT|ALL))?(?!\s*TOP\s*\()/i', - "\\1SELECT\\2 TOP $fetch", $sql); } } @@ -754,7 +778,7 @@ public function get_recordset_sql($sql, array $params=null, $limitfrom=0, $limit $result = mssql_query($rawsql, $this->mssql); $this->query_end($result); - if ($limitfrom) { // Skip $limitfrom records + if ($limitfrom && !$this->supportsoffsetfetch) { // Skip $limitfrom records. if (!@mssql_data_seek($result, $limitfrom)) { // Nothing, most probably seek past the end. mssql_free_result($result);