MDL-57698 sqlsrv: Query temp tables with no lock

This commit is contained in:
John Okely 2017-07-05 14:24:17 +08:00 committed by John Okely
parent b1fc170b21
commit b540fd1a80

View File

@ -50,6 +50,31 @@ class sqlsrv_native_moodle_database extends moodle_database {
/** @var array list of open recordsets */
protected $recordsets = array();
/** @var array list of reserve words in MSSQL / Transact from http://msdn2.microsoft.com/en-us/library/ms189822.aspx */
protected $reservewords = [
"add", "all", "alter", "and", "any", "as", "asc", "authorization", "avg", "backup", "begin", "between", "break",
"browse", "bulk", "by", "cascade", "case", "check", "checkpoint", "close", "clustered", "coalesce", "collate", "column",
"commit", "committed", "compute", "confirm", "constraint", "contains", "containstable", "continue", "controlrow",
"convert", "count", "create", "cross", "current", "current_date", "current_time", "current_timestamp", "current_user",
"cursor", "database", "dbcc", "deallocate", "declare", "default", "delete", "deny", "desc", "disk", "distinct",
"distributed", "double", "drop", "dummy", "dump", "else", "end", "errlvl", "errorexit", "escape", "except", "exec",
"execute", "exists", "exit", "external", "fetch", "file", "fillfactor", "floppy", "for", "foreign", "freetext",
"freetexttable", "from", "full", "function", "goto", "grant", "group", "having", "holdlock", "identity",
"identity_insert", "identitycol", "if", "in", "index", "inner", "insert", "intersect", "into", "is", "isolation",
"join", "key", "kill", "left", "level", "like", "lineno", "load", "max", "merge", "min", "mirrorexit", "national",
"nocheck", "nonclustered", "not", "null", "nullif", "of", "off", "offsets", "on", "once", "only", "open",
"opendatasource", "openquery", "openrowset", "openxml", "option", "or", "order", "outer", "over", "percent", "perm",
"permanent", "pipe", "pivot", "plan", "precision", "prepare", "primary", "print", "privileges", "proc", "procedure",
"processexit", "public", "raiserror", "read", "readtext", "reconfigure", "references", "repeatable", "replication",
"restore", "restrict", "return", "revert", "revoke", "right", "rollback", "rowcount", "rowguidcol", "rule", "save",
"schema", "securityaudit", "select", "semantickeyphrasetable", "semanticsimilaritydetailstable",
"semanticsimilaritytable", "serializable", "session_user", "set", "setuser", "shutdown", "some", "statistics", "sum",
"system_user", "table", "tablesample", "tape", "temp", "temporary", "textsize", "then", "to", "top", "tran",
"transaction", "trigger", "truncate", "try_convert", "tsequal", "uncommitted", "union", "unique", "unpivot", "update",
"updatetext", "use", "user", "values", "varying", "view", "waitfor", "when", "where", "while", "with", "within group",
"work", "writetext"
];
/**
* Constructor - instantiates the database, specifying if it's external (connect to other systems) or no (Moodle DB)
* note this has effect to decide if prefix checks must be performed or no
@ -858,6 +883,10 @@ class sqlsrv_native_moodle_database extends moodle_database {
}
}
}
// Add WITH (NOLOCK) to any temp tables.
$sql = $this->add_no_lock_to_temp_tables($sql);
$result = $this->do_query($sql, $params, SQL_QUERY_SELECT, false, $needscrollable);
if ($needscrollable) { // Skip $limitfrom records.
@ -866,6 +895,34 @@ class sqlsrv_native_moodle_database extends moodle_database {
return $this->create_recordset($result);
}
/**
* Use NOLOCK on any temp tables. Since it's a temp table and uncommitted reads are low risk anyway.
*
* @param string $sql the SQL select query to execute.
* @return string The SQL, with WITH (NOLOCK) added to all temp tables
*/
protected function add_no_lock_to_temp_tables($sql) {
return preg_replace_callback('/(\{([a-z][a-z0-9_]*)\})(\s+(\w+))?/', function($matches) {
$table = $matches[1]; // With the braces, so we can put it back in the query.
$name = $matches[2]; // Without the braces, so we can check if it's a temptable.
$tail = isset($matches[3]) ? $matches[3] : ''; // Catch the next word afterwards so that we can check if it's an alias.
$replacement = $matches[0]; // The table and the word following it, so we can replace it back if no changes are needed.
if ($this->temptables && $this->temptables->is_temptable($name)) {
if (!empty($tail)) {
if (in_array(strtolower(trim($tail)), $this->reservewords)) {
// If the table is followed by a reserve word, it's not an alias so put the WITH (NOLOCK) in between.
return $table . ' WITH (NOLOCK)' . $tail;
}
}
// If the table is not followed by a reserve word, put the WITH (NOLOCK) after the whole match.
return $replacement . ' WITH (NOLOCK)';
} else {
return $replacement;
}
}, $sql);
}
/**
* Create a record set and initialize with first row
*