Skip to content

Commit

Permalink
MDL-78016 dml: Add Oracle support for OFFSET ... FETCH clauses
Browse files Browse the repository at this point in the history
Since Oracle 12, these statements (providing the same than the
well-known LIMIT clauses in MySQL and PostgreSQL) are available,

Just let's switch to use them, removing the old complex ROWNUM
based queries needed before to provide limits support.
  • Loading branch information
stronk7 committed May 19, 2023
1 parent 2e1c6fd commit ff8a947
Showing 1 changed file with 18 additions and 46 deletions.
64 changes: 18 additions & 46 deletions lib/dml/oci_native_moodle_database.php
Original file line number Diff line number Diff line change
Expand Up @@ -705,48 +705,6 @@ protected function normalise_value($column, $value) {
return $value;
}

/**
* Transforms the sql and params in order to emulate the LIMIT clause available in other DBs
*
* @param string $sql the SQL select query to execute.
* @param array $params array of sql parameters
* @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set).
* @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set).
* @return array with the transformed sql and params updated
*/
private function get_limit_sql($sql, array $params = null, $limitfrom=0, $limitnum=0) {

list($limitfrom, $limitnum) = $this->normalise_limit_from_num($limitfrom, $limitnum);
// TODO: Add the /*+ FIRST_ROWS */ hint if there isn't another hint

if ($limitfrom and $limitnum) {
$sql = "SELECT oracle_o.*
FROM (SELECT oracle_i.*, rownum AS oracle_rownum
FROM ($sql) oracle_i
WHERE rownum <= :oracle_num_rows
) oracle_o
WHERE oracle_rownum > :oracle_skip_rows";
$params['oracle_num_rows'] = $limitfrom + $limitnum;
$params['oracle_skip_rows'] = $limitfrom;

} else if ($limitfrom and !$limitnum) {
$sql = "SELECT oracle_o.*
FROM (SELECT oracle_i.*, rownum AS oracle_rownum
FROM ($sql) oracle_i
) oracle_o
WHERE oracle_rownum > :oracle_skip_rows";
$params['oracle_skip_rows'] = $limitfrom;

} else if (!$limitfrom and $limitnum) {
$sql = "SELECT *
FROM ($sql)
WHERE rownum <= :oracle_num_rows";
$params['oracle_num_rows'] = $limitnum;
}

return array($sql, $params);
}

/**
* This function will handle all the column values before being inserted/updated to DB for Oracle
* installations. This is because the "special feature" of Oracle where the empty string is
Expand Down Expand Up @@ -1118,9 +1076,16 @@ public function get_record_sql($sql, array $params=null, $strictness=IGNORE_MISS
*/
public function get_recordset_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {

list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
list($limitfrom, $limitnum) = $this->normalise_limit_from_num($limitfrom, $limitnum);

list($rawsql, $params) = $this->get_limit_sql($sql, $params, $limitfrom, $limitnum);
if ($limitfrom) {
$sql .= " OFFSET $limitfrom ROWS";
}
if ($limitnum) {
$sql .= " FETCH NEXT $limitnum ROWS ONLY";
}

list($rawsql, $params, $type) = $this->fix_sql_params($sql, $params);

list($rawsql, $params) = $this->tweak_param_names($rawsql, $params);
$this->query_start($rawsql, $params, SQL_QUERY_SELECT);
Expand Down Expand Up @@ -1155,9 +1120,16 @@ protected function create_recordset($stmt) {
*/
public function get_records_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) {

list($sql, $params, $type) = $this->fix_sql_params($sql, $params);
list($limitfrom, $limitnum) = $this->normalise_limit_from_num($limitfrom, $limitnum);

if ($limitfrom) {
$sql .= " OFFSET $limitfrom ROWS";
}
if ($limitnum) {
$sql .= " FETCH NEXT $limitnum ROWS ONLY";
}

list($rawsql, $params) = $this->get_limit_sql($sql, $params, $limitfrom, $limitnum);
list($rawsql, $params, $type) = $this->fix_sql_params($sql, $params);

list($rawsql, $params) = $this->tweak_param_names($rawsql, $params);
$this->query_start($rawsql, $params, SQL_QUERY_SELECT);
Expand Down

0 comments on commit ff8a947

Please sign in to comment.