Skip to content
Browse files

Merge branch 'MDL-27071_24' of git://github.com/stronk7/moodle into M…

…OODLE_24_STABLE
  • Loading branch information...
2 parents 49b18ef + f530a1f commit 3fb4ce7d58d9a9ea8a6316e62061bbb6bd86cf76 @danpoltawski danpoltawski committed Apr 29, 2013
Showing with 87 additions and 0 deletions.
  1. +66 −0 lib/dml/oci_native_moodle_database.php
  2. +21 −0 lib/dml/tests/dml_test.php
View
66 lib/dml/oci_native_moodle_database.php
@@ -1571,6 +1571,72 @@ public function sql_concat_join($separator="' '", $elements=array()) {
}
/**
+ * Constructs 'IN()' or '=' sql fragment
+ *
+ * Method overriding {@link moodle_database::get_in_or_equal} to be able to get
+ * more than 1000 elements working, to avoid ORA-01795. We use a pivoting technique
+ * to be able to transform the params into virtual rows, so the original IN()
+ * expression gets transformed into a subquery. Once more, be noted that we shouldn't
+ * be using ever get_in_or_equal() with such number of parameters (proper subquery and/or
+ * chunking should be used instead).
+ *
+ * @param mixed $items A single value or array of values for the expression.
+ * @param int $type Parameter bounding type : SQL_PARAMS_QM or SQL_PARAMS_NAMED.
+ * @param string $prefix Named parameter placeholder prefix (a unique counter value is appended to each parameter name).
+ * @param bool $equal True means we want to equate to the constructed expression, false means we don't want to equate to it.
+ * @param mixed $onemptyitems This defines the behavior when the array of items provided is empty. Defaults to false,
+ * meaning throw exceptions. Other values will become part of the returned SQL fragment.
+ * @throws coding_exception | dml_exception
+ * @return array A list containing the constructed sql fragment and an array of parameters.
+ */
+ public function get_in_or_equal($items, $type=SQL_PARAMS_QM, $prefix='param', $equal=true, $onemptyitems=false) {
+ list($sql, $params) = parent::get_in_or_equal($items, $type, $prefix, $equal, $onemptyitems);
+
+ // Less than 1000 elements, nothing to do.
+ if (count($params) < 1000) {
+ return array($sql, $params); // Return unmodified.
+ }
+
+ // Extract the interesting parts of the sql to rewrite.
+ if (preg_match('!(^.*IN \()([^\)]*)(.*)$!', $sql, $matches) === false) {
+ return array($sql, $params); // Return unmodified.
+ }
+
+ $instart = $matches[1];
+ $insql = $matches[2];
+ $inend = $matches[3];
+ $newsql = '';
+
+ // Some basic verification about the matching going ok.
+ $insqlarr = explode(',', $insql);
+ if (count($insqlarr) !== count($params)) {
+ return array($sql, $params); // Return unmodified.
+ }
+
+ // Arrived here, we need to chunk and pivot the params, building a new sql (params remain the same).
+ $addunionclause = false;
+ while ($chunk = array_splice($insqlarr, 0, 125)) { // Each chunk will handle up to 125 (+125 +1) elements (DECODE max is 255).
+ $chunksize = count($chunk);
+ if ($addunionclause) {
+ $newsql .= "\n UNION ALL";
+ }
+ $newsql .= "\n SELECT DECODE(pivot";
+ $counter = 1;
+ foreach ($chunk as $element) {
+ $newsql .= ",\n {$counter}, " . trim($element);
+ $counter++;
+ }
+ $newsql .= ")";
+ $newsql .= "\n FROM dual";
+ $newsql .= "\n CROSS JOIN (SELECT LEVEL AS pivot FROM dual CONNECT BY LEVEL <= {$chunksize})";
+ $addunionclause = true;
+ }
+
+ // Rebuild the complete IN() clause and return it.
+ return array($instart . $newsql . $inend, $params);
+ }
+
+ /**
* Returns the SQL for returning searching one string for the location of another.
*/
public function sql_position($needle, $haystack) {
View
21 lib/dml/tests/dml_test.php
@@ -4199,6 +4199,27 @@ public function test_get_records_sql_complicated() {
$DB->insert_record($tablename, array('course' => 7, 'content' => 'xx', 'name'=>'1abc'));
$this->assertEquals(count($DB->get_records_sql($sql, array(1))), 1);
$this->assertEquals(count($DB->get_records_sql($sql, array("1"))), 1);
+
+ // Test get_in_or_equal() with a big number of elements. Note that ideally
+ // we should be detecting and warning about any use over, say, 200 elements
+ // and recommend to change code to use subqueries and/or chunks instead.
+ $currentcount = $DB->count_records($tablename);
+ $numelements = 10000; // Verify that we can handle 10000 elements (crazy!)
+ $values = range(1, $numelements);
+
+ list($insql, $inparams) = $DB->get_in_or_equal($values, SQL_PARAMS_QM); // With QM params.
+ $sql = "SELECT *
+ FROM {{$tablename}}
+ WHERE id $insql";
+ $results = $DB->get_records_sql($sql, $inparams);
+ $this->assertEquals($currentcount, count($results));
+
+ list($insql, $inparams) = $DB->get_in_or_equal($values, SQL_PARAMS_NAMED); // With NAMED params.
+ $sql = "SELECT *
+ FROM {{$tablename}}
+ WHERE id $insql";
+ $results = $DB->get_records_sql($sql, $inparams);
+ $this->assertEquals($currentcount, count($results));
}
function test_onelevel_commit() {

0 comments on commit 3fb4ce7

Please sign in to comment.
Something went wrong with that request. Please try again.