* OracleInstaller now also supports installation with (requested by Tim):
[mediawiki.git] / includes / db / DatabaseMssql.php
blob015f5a0546bc331749f3306d1e6d64999acd6543
1 <?php
2 /**
3 * This is the MS SQL Server Native database abstraction layer.
5 * @file
6 * @ingroup Database
7 * @author Joel Penner <a-joelpe at microsoft dot com>
8 * @author Chris Pucci <a-cpucci at microsoft dot com>
9 * @author Ryan Biesemeyer <v-ryanbi at microsoft dot com>
12 /**
13 * @ingroup Database
15 class DatabaseMssql extends DatabaseBase {
16 var $mInsertId = NULL;
17 var $mLastResult = NULL;
18 var $mAffectedRows = NULL;
20 var $mPort;
22 function cascadingDeletes() {
23 return true;
25 function cleanupTriggers() {
26 return true;
28 function strictIPs() {
29 return true;
31 function realTimestamps() {
32 return true;
34 function implicitGroupby() {
35 return false;
37 function implicitOrderby() {
38 return false;
40 function functionalIndexes() {
41 return true;
43 function unionSupportsOrderAndLimit() {
44 return false;
47 /**
48 * Usually aborts on failure
50 function open( $server, $user, $password, $dbName ) {
51 # Test for driver support, to avoid suppressed fatal error
52 if ( !function_exists( 'sqlsrv_connect' ) ) {
53 throw new DBConnectionError( $this, "MS Sql Server Native (sqlsrv) functions missing. You can download the driver from: http://go.microsoft.com/fwlink/?LinkId=123470\n" );
56 global $wgDBport;
58 if ( !strlen( $user ) ) { # e.g. the class is being loaded
59 return;
62 $this->close();
63 $this->mServer = $server;
64 $this->mPort = $wgDBport;
65 $this->mUser = $user;
66 $this->mPassword = $password;
67 $this->mDBname = $dbName;
69 $connectionInfo = array();
71 if( $dbName ) {
72 $connectionInfo['Database'] = $dbName;
75 // Start NT Auth Hack
76 // Quick and dirty work around to provide NT Auth designation support.
77 // Current solution requires installer to know to input 'ntauth' for both username and password
78 // to trigger connection via NT Auth. - ugly, ugly, ugly
79 // TO-DO: Make this better and add NT Auth choice to MW installer when SQL Server option is chosen.
80 $ntAuthUserTest = strtolower( $user );
81 $ntAuthPassTest = strtolower( $password );
83 // Decide which auth scenerio to use
84 if( $ntAuthPassTest == 'ntauth' && $ntAuthUserTest == 'ntauth' ){
85 // Don't add credentials to $connectionInfo
86 } else {
87 $connectionInfo['UID'] = $user;
88 $connectionInfo['PWD'] = $password;
90 // End NT Auth Hack
92 wfSuppressWarnings();
93 $this->mConn = sqlsrv_connect( $server, $connectionInfo );
94 wfRestoreWarnings();
96 if ( $this->mConn === false ) {
97 wfDebug( "DB connection error\n" );
98 wfDebug( "Server: $server, Database: $dbName, User: $user, Password: " . substr( $password, 0, 3 ) . "...\n" );
99 wfDebug( $this->lastError() . "\n" );
100 return false;
103 $this->mOpened = true;
104 return $this->mConn;
108 * Closes a database connection, if it is open
109 * Returns success, true if already closed
111 function close() {
112 $this->mOpened = false;
113 if ( $this->mConn ) {
114 return sqlsrv_close( $this->mConn );
115 } else {
116 return true;
120 function doQuery( $sql ) {
121 wfDebug( "SQL: [$sql]\n" );
122 $this->offset = 0;
124 // several extensions seem to think that all databases support limits via LIMIT N after the WHERE clause
125 // well, MSSQL uses SELECT TOP N, so to catch any of those extensions we'll do a quick check for a LIMIT
126 // clause and pass $sql through $this->LimitToTopN() which parses the limit clause and passes the result to
127 // $this->limitResult();
128 if ( preg_match( '/\bLIMIT\s*/i', $sql ) ) {
129 // massage LIMIT -> TopN
130 $sql = $this->LimitToTopN( $sql ) ;
133 // MSSQL doesn't have EXTRACT(epoch FROM XXX)
134 if ( preg_match('#\bEXTRACT\s*?\(\s*?EPOCH\s+FROM\b#i', $sql, $matches ) ) {
135 // This is same as UNIX_TIMESTAMP, we need to calc # of seconds from 1970
136 $sql = str_replace( $matches[0], "DATEDIFF(s,CONVERT(datetime,'1/1/1970'),", $sql );
139 // perform query
140 $stmt = sqlsrv_query( $this->mConn, $sql );
141 if ( $stmt == false ) {
142 $message = "A database error has occurred. Did you forget to run maintenance/update.php after upgrading? See: http://www.mediawiki.org/wiki/Manual:Upgrading#Run_the_update_script\n" .
143 "Query: " . htmlentities( $sql ) . "\n" .
144 "Function: " . __METHOD__ . "\n";
145 // process each error (our driver will give us an array of errors unlike other providers)
146 foreach ( sqlsrv_errors() as $error ) {
147 $message .= $message . "ERROR[" . $error['code'] . "] " . $error['message'] . "\n";
150 throw new DBUnexpectedError( $this, $message );
152 // remember number of rows affected
153 $this->mAffectedRows = sqlsrv_rows_affected( $stmt );
155 // if it is a SELECT statement, or an insert with a request to output something we want to return a row.
156 if ( ( preg_match( '#\bSELECT\s#i', $sql ) ) ||
157 ( preg_match( '#\bINSERT\s#i', $sql ) && preg_match( '#\bOUTPUT\s+INSERTED\b#i', $sql ) ) ) {
158 // this is essentially a rowset, but Mediawiki calls these 'result'
159 // the rowset owns freeing the statement
160 $res = new MssqlResult( $stmt );
161 } else {
162 // otherwise we simply return it was successful, failure throws an exception
163 $res = true;
165 return $res;
168 function freeResult( $res ) {
169 if ( $res instanceof ResultWrapper ) {
170 $res = $res->result;
172 $res->free();
175 function fetchObject( $res ) {
176 if ( $res instanceof ResultWrapper ) {
177 $res = $res->result;
179 $row = $res->fetch( 'OBJECT' );
180 return $row;
183 function getErrors() {
184 $strRet = '';
185 $retErrors = sqlsrv_errors( SQLSRV_ERR_ALL );
186 if ( $retErrors != null ) {
187 foreach ( $retErrors as $arrError ) {
188 $strRet .= "SQLState: " . $arrError[ 'SQLSTATE'] . "\n";
189 $strRet .= "Error Code: " . $arrError[ 'code'] . "\n";
190 $strRet .= "Message: " . $arrError[ 'message'] . "\n";
192 } else {
193 $strRet = "No errors found";
195 return $strRet;
198 function fetchRow( $res ) {
199 if ( $res instanceof ResultWrapper ) {
200 $res = $res->result;
202 $row = $res->fetch( SQLSRV_FETCH_BOTH );
203 return $row;
206 function numRows( $res ) {
207 if ( $res instanceof ResultWrapper ) {
208 $res = $res->result;
210 return ( $res ) ? $res->numrows() : 0;
213 function numFields( $res ) {
214 if ( $res instanceof ResultWrapper ) {
215 $res = $res->result;
217 return ( $res ) ? $res->numfields() : 0;
220 function fieldName( $res, $n ) {
221 if ( $res instanceof ResultWrapper ) {
222 $res = $res->result;
224 return ( $res ) ? $res->fieldname( $n ) : 0;
228 * This must be called after nextSequenceVal
230 function insertId() {
231 return $this->mInsertId;
234 function dataSeek( $res, $row ) {
235 if ( $res instanceof ResultWrapper ) {
236 $res = $res->result;
238 return ( $res ) ? $res->seek( $row ) : false;
241 function lastError() {
242 if ( $this->mConn ) {
243 return $this->getErrors();
244 } else {
245 return "No database connection";
249 function lastErrno() {
250 $err = sqlsrv_errors( SQLSRV_ERR_ALL );
251 if ( $err[0] ) {
252 return $err[0]['code'];
253 } else {
254 return 0;
258 function affectedRows() {
259 return $this->mAffectedRows;
263 * SELECT wrapper
265 * @param $table Mixed: array or string, table name(s) (prefix auto-added)
266 * @param $vars Mixed: array or string, field name(s) to be retrieved
267 * @param $conds Mixed: array or string, condition(s) for WHERE
268 * @param $fname String: calling function name (use __METHOD__) for logs/profiling
269 * @param $options Array: associative array of options (e.g. array('GROUP BY' => 'page_title')),
270 * see Database::makeSelectOptions code for list of supported stuff
271 * @param $join_conds Array: Associative array of table join conditions (optional)
272 * (e.g. array( 'page' => array('LEFT JOIN','page_latest=rev_id') )
273 * @return Mixed: database result resource (feed to Database::fetchObject or whatever), or false on failure
275 function select( $table, $vars, $conds = '', $fname = 'DatabaseMssql::select', $options = array(), $join_conds = array() )
277 $sql = $this->selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
278 if ( isset( $options['EXPLAIN'] ) ) {
279 sqlsrv_query( $this->mConn, "SET SHOWPLAN_ALL ON;" );
280 $ret = $this->query( $sql, $fname );
281 sqlsrv_query( $this->mConn, "SET SHOWPLAN_ALL OFF;" );
282 return $ret;
284 return $this->query( $sql, $fname );
288 * SELECT wrapper
290 * @param $table Mixed: Array or string, table name(s) (prefix auto-added)
291 * @param $vars Mixed: Array or string, field name(s) to be retrieved
292 * @param $conds Mixed: Array or string, condition(s) for WHERE
293 * @param $fname String: Calling function name (use __METHOD__) for logs/profiling
294 * @param $options Array: Associative array of options (e.g. array('GROUP BY' => 'page_title')),
295 * see Database::makeSelectOptions code for list of supported stuff
296 * @param $join_conds Array: Associative array of table join conditions (optional)
297 * (e.g. array( 'page' => array('LEFT JOIN','page_latest=rev_id') )
298 * @return string, the SQL text
300 function selectSQLText( $table, $vars, $conds = '', $fname = 'DatabaseMssql::select', $options = array(), $join_conds = array() ) {
301 if ( isset( $options['EXPLAIN'] ) ) {
302 unset( $options['EXPLAIN'] );
304 return parent::selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
308 * Estimate rows in dataset
309 * Returns estimated count, based on SHOWPLAN_ALL output
310 * This is not necessarily an accurate estimate, so use sparingly
311 * Returns -1 if count cannot be found
312 * Takes same arguments as Database::select()
314 function estimateRowCount( $table, $vars = '*', $conds = '', $fname = 'DatabaseMssql::estimateRowCount', $options = array() ) {
315 $options['EXPLAIN'] = true;// http://msdn2.microsoft.com/en-us/library/aa259203.aspx
316 $res = $this->select( $table, $vars, $conds, $fname, $options );
318 $rows = -1;
319 if ( $res ) {
320 $row = $this->fetchRow( $res );
321 if ( isset( $row['EstimateRows'] ) ) $rows = $row['EstimateRows'];
323 return $rows;
327 * Returns information about an index
328 * If errors are explicitly ignored, returns NULL on failure
330 function indexInfo( $table, $index, $fname = 'DatabaseMssql::indexExists' ) {
331 # This does not return the same info as MYSQL would, but that's OK because MediaWiki never uses the
332 # returned value except to check for the existance of indexes.
333 $sql = "sp_helpindex '" . $table . "'";
334 $res = $this->query( $sql, $fname );
335 if ( !$res ) {
336 return NULL;
339 $result = array();
340 foreach ( $res as $row ) {
341 if ( $row->index_name == $index ) {
342 $row->Non_unique = !stristr( $row->index_description, "unique" );
343 $cols = explode( ", ", $row->index_keys );
344 foreach ( $cols as $col ) {
345 $row->Column_name = trim( $col );
346 $result[] = clone $row;
348 } else if ( $index == 'PRIMARY' && stristr( $row->index_description, 'PRIMARY' ) ) {
349 $row->Non_unique = 0;
350 $cols = explode( ", ", $row->index_keys );
351 foreach ( $cols as $col ) {
352 $row->Column_name = trim( $col );
353 $result[] = clone $row;
357 return empty( $result ) ? false : $result;
361 * INSERT wrapper, inserts an array into a table
363 * $arrToInsert may be a single associative array, or an array of these with numeric keys, for
364 * multi-row insert.
366 * Usually aborts on failure
367 * If errors are explicitly ignored, returns success
369 function insert( $table, $arrToInsert, $fname = 'DatabaseMssql::insert', $options = array() ) {
370 # No rows to insert, easy just return now
371 if ( !count( $arrToInsert ) ) {
372 return true;
375 if ( !is_array( $options ) ) {
376 $options = array( $options );
379 $table = $this->tableName( $table );
381 if ( !( isset( $arrToInsert[0] ) && is_array( $arrToInsert[0] ) ) ) {// Not multi row
382 $arrToInsert = array( 0 => $arrToInsert );// make everything multi row compatible
385 $allOk = true;
387 // We know the table we're inserting into, get its identity column
388 $identity = null;
389 $tableRaw = preg_replace( '#\[([^\]]*)\]#', '$1', $table ); // strip matching square brackets from table name
390 $res = $this->doQuery( "SELECT NAME AS idColumn FROM SYS.IDENTITY_COLUMNS WHERE OBJECT_NAME(OBJECT_ID)='{$tableRaw}'" );
391 if( $res && $res->numrows() ){
392 // There is an identity for this table.
393 $identity = array_pop( $res->fetch( SQLSRV_FETCH_ASSOC ) );
395 unset( $res );
397 foreach ( $arrToInsert as $a ) {
398 // start out with empty identity column, this is so we can return it as a result of the insert logic
399 $sqlPre = '';
400 $sqlPost = '';
401 $identityClause = '';
403 // if we have an identity column
404 if( $identity ) {
405 // iterate through
406 foreach ($a as $k => $v ) {
407 if ( $k == $identity ) {
408 if( !is_null($v) ){
409 // there is a value being passed to us, we need to turn on and off inserted identity
410 $sqlPre = "SET IDENTITY_INSERT $table ON;" ;
411 $sqlPost = ";SET IDENTITY_INSERT $table OFF;";
413 } else {
414 // we can't insert NULL into an identity column, so remove the column from the insert.
415 unset( $a[$k] );
419 $identityClause = "OUTPUT INSERTED.$identity "; // we want to output an identity column as result
422 $keys = array_keys( $a );
424 // INSERT IGNORE is not supported by SQL Server
425 // remove IGNORE from options list and set ignore flag to true
426 $ignoreClause = false;
427 foreach ( $options as $k => $v ) {
428 if ( strtoupper( $v ) == "IGNORE" ) {
429 unset( $options[$k] );
430 $ignoreClause = true;
434 // translate MySQL INSERT IGNORE to something SQL Server can use
435 // example:
436 // MySQL: INSERT IGNORE INTO user_groups (ug_user,ug_group) VALUES ('1','sysop')
437 // MSSQL: IF NOT EXISTS (SELECT * FROM user_groups WHERE ug_user = '1') INSERT INTO user_groups (ug_user,ug_group) VALUES ('1','sysop')
438 if ( $ignoreClause ) {
439 $prival = $a[$keys[0]];
440 $sqlPre .= "IF NOT EXISTS (SELECT * FROM $table WHERE $keys[0] = '$prival')";
443 // Build the actual query
444 $sql = $sqlPre . 'INSERT ' . implode( ' ', $options ) .
445 " INTO $table (" . implode( ',', $keys ) . ") $identityClause VALUES (";
447 $first = true;
448 foreach ( $a as $value ) {
449 if ( $first ) {
450 $first = false;
451 } else {
452 $sql .= ',';
454 if ( is_string( $value ) ) {
455 $sql .= $this->addIdentifierQuotes( $value );
456 } elseif ( is_null( $value ) ) {
457 $sql .= 'null';
458 } elseif ( is_array( $value ) || is_object( $value ) ) {
459 if ( is_object( $value ) && strtolower( get_class( $value ) ) == 'blob' ) {
460 $sql .= $this->addIdentifierQuotes( $value->fetch() );
461 } else {
462 $sql .= $this->addIdentifierQuotes( serialize( $value ) );
464 } else {
465 $sql .= $value;
468 $sql .= ')' . $sqlPost;
470 // Run the query
471 $ret = sqlsrv_query( $this->mConn, $sql );
473 if ( $ret === false ) {
474 throw new DBQueryError( $this, $this->getErrors(), $this->lastErrno(), $sql, $fname );
475 } elseif ( $ret != NULL ) {
476 // remember number of rows affected
477 $this->mAffectedRows = sqlsrv_rows_affected( $ret );
478 if ( !is_null($identity) ) {
479 // then we want to get the identity column value we were assigned and save it off
480 $row = sqlsrv_fetch_object( $ret );
481 $this->mInsertId = $row->$identity;
483 sqlsrv_free_stmt( $ret );
484 continue;
486 $allOk = false;
488 return $allOk;
492 * INSERT SELECT wrapper
493 * $varMap must be an associative array of the form array( 'dest1' => 'source1', ...)
494 * Source items may be literals rather than field names, but strings should be quoted with Database::addQuotes()
495 * $conds may be "*" to copy the whole table
496 * srcTable may be an array of tables.
498 function insertSelect( $destTable, $srcTable, $varMap, $conds, $fname = 'DatabaseMssql::insertSelect',
499 $insertOptions = array(), $selectOptions = array() ) {
500 $ret = parent::insertSelect( $destTable, $srcTable, $varMap, $conds, $fname, $insertOptions, $selectOptions );
502 if ( $ret === false ) {
503 throw new DBQueryError( $this, $this->getErrors(), $this->lastErrno(), /*$sql*/ '', $fname );
504 } elseif ( $ret != NULL ) {
505 // remember number of rows affected
506 $this->mAffectedRows = sqlsrv_rows_affected( $ret );
507 return $ret;
509 return NULL;
513 * Format a table name ready for use in constructing an SQL query
515 * This does two important things: it brackets table names which as necessary,
516 * and it adds a table prefix if there is one.
518 * All functions of this object which require a table name call this function
519 * themselves. Pass the canonical name to such functions. This is only needed
520 * when calling query() directly.
522 * @param $name String: database table name
524 function tableName( $name ) {
525 global $wgSharedDB;
526 # Skip quoted literals
527 if ( $name != '' && $name { 0 } != '[' ) {
528 if ( $this->mTablePrefix !== '' && strpos( '.', $name ) === false ) {
529 $name = "{$this->mTablePrefix}$name";
531 if ( isset( $wgSharedDB ) && "{$this->mTablePrefix}user" == $name ) {
532 $name = "[$wgSharedDB].[$name]";
533 } else {
534 # Standard quoting
535 if ( $name != '' ) $name = "[$name]";
538 return $name;
542 * Return the next in a sequence, save the value for retrieval via insertId()
544 function nextSequenceValue( $seqName ) {
545 if ( !$this->tableExists( 'sequence_' . $seqName ) ) {
546 sqlsrv_query( $this->mConn, "CREATE TABLE [sequence_$seqName] (id INT NOT NULL IDENTITY PRIMARY KEY, junk varchar(10) NULL)" );
548 sqlsrv_query( $this->mConn, "INSERT INTO [sequence_$seqName] (junk) VALUES ('')" );
549 $ret = sqlsrv_query( $this->mConn, "SELECT TOP 1 id FROM [sequence_$seqName] ORDER BY id DESC" );
550 $row = sqlsrv_fetch_array( $ret, SQLSRV_FETCH_ASSOC );// KEEP ASSOC THERE, weird weird bug dealing with the return value if you don't
552 sqlsrv_free_stmt( $ret );
553 $this->mInsertId = $row['id'];
554 return $row['id'];
558 * Return the current value of a sequence. Assumes it has ben nextval'ed in this session.
560 function currentSequenceValue( $seqName ) {
561 $ret = sqlsrv_query( $this->mConn, "SELECT TOP 1 id FROM [sequence_$seqName] ORDER BY id DESC" );
562 if ( $ret !== false ) {
563 $row = sqlsrv_fetch_array( $ret );
564 sqlsrv_free_stmt( $ret );
565 return $row['id'];
566 } else {
567 return $this->nextSequenceValue( $seqName );
572 # REPLACE query wrapper
573 # MSSQL simulates this with a DELETE followed by INSERT
574 # $row is the row to insert, an associative array
575 # $uniqueIndexes is an array of indexes. Each element may be either a
576 # field name or an array of field names
578 # It may be more efficient to leave off unique indexes which are unlikely to collide.
579 # However if you do this, you run the risk of encountering errors which wouldn't have
580 # occurred in MySQL
581 function replace( $table, $uniqueIndexes, $rows, $fname = 'DatabaseMssql::replace' ) {
582 $table = $this->tableName( $table );
584 if ( count( $rows ) == 0 ) {
585 return;
588 # Single row case
589 if ( !is_array( reset( $rows ) ) ) {
590 $rows = array( $rows );
593 foreach ( $rows as $row ) {
594 # Delete rows which collide
595 if ( $uniqueIndexes ) {
596 $sql = "DELETE FROM $table WHERE ";
597 $first = true;
598 foreach ( $uniqueIndexes as $index ) {
599 if ( $first ) {
600 $first = false;
601 $sql .= "(";
602 } else {
603 $sql .= ') OR (';
605 if ( is_array( $index ) ) {
606 $first2 = true;
607 foreach ( $index as $col ) {
608 if ( $first2 ) {
609 $first2 = false;
610 } else {
611 $sql .= ' AND ';
613 $sql .= $col . '=' . $this->addQuotes( $row[$col] );
615 } else {
616 $sql .= $index . '=' . $this->addQuotes( $row[$index] );
619 $sql .= ')';
620 $this->query( $sql, $fname );
623 # Now insert the row
624 $sql = "INSERT INTO $table (" . $this->makeList( array_keys( $row ), LIST_NAMES ) . ') VALUES (' .
625 $this->makeList( $row, LIST_COMMA ) . ')';
626 $this->query( $sql, $fname );
630 # DELETE where the condition is a join
631 function deleteJoin( $delTable, $joinTable, $delVar, $joinVar, $conds, $fname = "DatabaseMssql::deleteJoin" ) {
632 if ( !$conds ) {
633 throw new DBUnexpectedError( $this, 'DatabaseMssql::deleteJoin() called with empty $conds' );
636 $delTable = $this->tableName( $delTable );
637 $joinTable = $this->tableName( $joinTable );
638 $sql = "DELETE FROM $delTable WHERE $delVar IN (SELECT $joinVar FROM $joinTable ";
639 if ( $conds != '*' ) {
640 $sql .= 'WHERE ' . $this->makeList( $conds, LIST_AND );
642 $sql .= ')';
644 $this->query( $sql, $fname );
647 # Returns the size of a text field, or -1 for "unlimited"
648 function textFieldSize( $table, $field ) {
649 $table = $this->tableName( $table );
650 $sql = "SELECT CHARACTER_MAXIMUM_LENGTH,DATA_TYPE FROM INFORMATION_SCHEMA.Columns
651 WHERE TABLE_NAME = '$table' AND COLUMN_NAME = '$field'";
652 $res = $this->query( $sql );
653 $row = $this->fetchRow( $res );
654 $size = -1;
655 if ( strtolower( $row['DATA_TYPE'] ) != 'text' ) {
656 $size = $row['CHARACTER_MAXIMUM_LENGTH'];
658 return $size;
662 * Construct a LIMIT query with optional offset
663 * This is used for query pages
664 * $sql string SQL query we will append the limit too
665 * $limit integer the SQL limit
666 * $offset integer the SQL offset (default false)
668 function limitResult( $sql, $limit, $offset = false ) {
669 if ( $offset === false || $offset == 0 ) {
670 if ( strpos( $sql, "SELECT" ) === false ) {
671 return "TOP {$limit} " . $sql;
672 } else {
673 return preg_replace( '/\bSELECT(\s*DISTINCT)?\b/Dsi', 'SELECT$1 TOP ' . $limit, $sql, 1 );
675 } else {
676 $sql = '
677 SELECT * FROM (
678 SELECT sub2.*, ROW_NUMBER() OVER(ORDER BY sub2.line2) AS line3 FROM (
679 SELECT 1 AS line2, sub1.* FROM (' . $sql . ') AS sub1
680 ) as sub2
681 ) AS sub3
682 WHERE line3 BETWEEN ' . ( $offset + 1 ) . ' AND ' . ( $offset + $limit );
683 return $sql;
687 // If there is a limit clause, parse it, strip it, and pass the remaining sql through limitResult()
688 // with the appropriate parameters. Not the prettiest solution, but better than building a whole new parser.
689 // This exists becase there are still too many extensions that don't use dynamic sql generation.
690 function LimitToTopN( $sql ) {
691 // Matches: LIMIT {[offset,] row_count | row_count OFFSET offset}
692 $pattern = '/\bLIMIT\s+((([0-9]+)\s*,\s*)?([0-9]+)(\s+OFFSET\s+([0-9]+))?)/i';
693 if ( preg_match( $pattern, $sql, $matches ) ) {
694 // row_count = $matches[4]
695 $row_count = $matches[4];
696 // offset = $matches[3] OR $matches[6]
697 $offset = $matches[3] or
698 $offset = $matches[6] or
699 $offset = false;
701 // strip the matching LIMIT clause out
702 $sql = str_replace( $matches[0], '', $sql );
703 return $this->limitResult( $sql, $row_count, $offset );
705 return $sql;
708 // MSSQL does support this, but documentation is too thin to make a generalized
709 // function for this. Apparently UPDATE TOP (N) works, but the sort order
710 // may not be what we're expecting so the top n results may be a random selection.
711 // TODO: Implement properly.
712 function limitResultForUpdate( $sql, $num ) {
713 return $sql;
716 function timestamp( $ts = 0 ) {
717 return wfTimestamp( TS_ISO_8601, $ts );
721 * @return string wikitext of a link to the server software's web site
723 public static function getSoftwareLink() {
724 return "[http://www.microsoft.com/sql/ MS SQL Server]";
728 * @return string Version information from the database
730 function getServerVersion() {
731 $server_info = sqlsrv_server_info( $this->mConn );
732 $version = 'Error';
733 if ( isset( $server_info['SQLServerVersion'] ) ) {
734 $version = $server_info['SQLServerVersion'];
736 return $version;
739 function tableExists ( $table, $schema = false ) {
740 $res = sqlsrv_query( $this->mConn, "SELECT * FROM information_schema.tables
741 WHERE table_type='BASE TABLE' AND table_name = '$table'" );
742 if ( $res === false ) {
743 print( "Error in tableExists query: " . $this->getErrors() );
744 return false;
746 if ( sqlsrv_fetch( $res ) ) {
747 return true;
748 } else {
749 return false;
754 * Query whether a given column exists in the mediawiki schema
756 function fieldExists( $table, $field, $fname = 'DatabaseMssql::fieldExists' ) {
757 $table = $this->tableName( $table );
758 $res = sqlsrv_query( $this->mConn, "SELECT DATA_TYPE FROM INFORMATION_SCHEMA.Columns
759 WHERE TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
760 if ( $res === false ) {
761 print( "Error in fieldExists query: " . $this->getErrors() );
762 return false;
764 if ( sqlsrv_fetch( $res ) ) {
765 return true;
766 } else {
767 return false;
771 function fieldInfo( $table, $field ) {
772 $table = $this->tableName( $table );
773 $res = sqlsrv_query( $this->mConn, "SELECT * FROM INFORMATION_SCHEMA.Columns
774 WHERE TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
775 if ( $res === false ) {
776 print( "Error in fieldInfo query: " . $this->getErrors() );
777 return false;
779 $meta = $this->fetchRow( $res );
780 if ( $meta ) {
781 return new MssqlField( $meta );
783 return false;
787 * Begin a transaction, committing any previously open transaction
789 function begin( $fname = 'DatabaseMssql::begin' ) {
790 sqlsrv_begin_transaction( $this->mConn );
791 $this->mTrxLevel = 1;
795 * End a transaction
797 function commit( $fname = 'DatabaseMssql::commit' ) {
798 sqlsrv_commit( $this->mConn );
799 $this->mTrxLevel = 0;
803 * Rollback a transaction.
804 * No-op on non-transactional databases.
806 function rollback( $fname = 'DatabaseMssql::rollback' ) {
807 sqlsrv_rollback( $this->mConn );
808 $this->mTrxLevel = 0;
811 function setup_database() {
812 global $wgDBuser;
814 // Make sure that we can write to the correct schema
815 $ctest = "mediawiki_test_table";
816 if ( $this->tableExists( $ctest ) ) {
817 $this->doQuery( "DROP TABLE $ctest" );
819 $SQL = "CREATE TABLE $ctest (a int)";
820 $res = $this->doQuery( $SQL );
821 if ( !$res ) {
822 print "<b>FAILED</b>. Make sure that the user " . htmlspecialchars( $wgDBuser ) . " can write to the database</li>\n";
823 die();
825 $this->doQuery( "DROP TABLE $ctest" );
827 $res = $this->sourceFile( "../maintenance/mssql/tables.sql" );
828 if ( $res !== true ) {
829 echo " <b>FAILED</b></li>";
830 die( htmlspecialchars( $res ) );
833 # Avoid the non-standard "REPLACE INTO" syntax
834 $f = fopen( "../maintenance/interwiki.sql", 'r' );
835 if ( $f == false ) {
836 die( "<li>Could not find the interwiki.sql file" );
838 # We simply assume it is already empty as we have just created it
839 $SQL = "INSERT INTO interwiki(iw_prefix,iw_url,iw_local) VALUES ";
840 while ( ! feof( $f ) ) {
841 $line = fgets( $f, 1024 );
842 $matches = array();
843 if ( !preg_match( '/^\s*(\(.+?),(\d)\)/', $line, $matches ) ) {
844 continue;
846 $this->query( "$SQL $matches[1],$matches[2])" );
848 print " (table interwiki successfully populated)...\n";
850 $this->commit();
854 * Escapes a identifier for use inm SQL.
855 * Throws an exception if it is invalid.
856 * Reference: http://msdn.microsoft.com/en-us/library/aa224033%28v=SQL.80%29.aspx
858 private function escapeIdentifier( $identifier ) {
859 if ( strlen( $identifier ) == 0 ) {
860 throw new MWException( "An identifier must not be empty" );
862 if ( strlen( $identifier ) > 128 ) {
863 throw new MWException( "The identifier '$identifier' is too long (max. 128)" );
865 if ( ( strpos( $identifier, '[' ) !== false ) || ( strpos( $identifier, ']' ) !== false ) ) {
866 // It may be allowed if you quoted with double quotation marks, but that would break if QUOTED_IDENTIFIER is OFF
867 throw new MWException( "You can't use square brackers in the identifier '$identifier'" );
869 return "[$identifier]";
873 * Initial setup.
874 * Precondition: This object is connected as the superuser.
875 * Creates the database, schema, user and login.
877 function initial_setup( $dbName, $newUser, $loginPassword ) {
878 $dbName = $this->escapeIdentifier( $dbName );
880 // It is not clear what can be used as a login,
881 // From http://msdn.microsoft.com/en-us/library/ms173463.aspx
882 // a sysname may be the same as an identifier.
883 $newUser = $this->escapeIdentifier( $newUser );
884 $loginPassword = $this->addQuotes( $loginPassword );
886 $this->doQuery("CREATE DATABASE $dbName;");
887 $this->doQuery("USE $dbName;");
888 $this->doQuery("CREATE SCHEMA $dbName;");
889 $this->doQuery("
890 CREATE
891 LOGIN $newUser
892 WITH
893 PASSWORD=$loginPassword
896 $this->doQuery("
897 CREATE
898 USER $newUser
900 LOGIN $newUser
901 WITH
902 DEFAULT_SCHEMA=$dbName
905 $this->doQuery("
906 GRANT
907 BACKUP DATABASE,
908 BACKUP LOG,
909 CREATE DEFAULT,
910 CREATE FUNCTION,
911 CREATE PROCEDURE,
912 CREATE RULE,
913 CREATE TABLE,
914 CREATE VIEW,
915 CREATE FULLTEXT CATALOG
917 DATABASE::$dbName
918 TO $newUser
921 $this->doQuery("
922 GRANT
923 CONTROL
925 SCHEMA::$dbName
926 TO $newUser
933 function encodeBlob( $b ) {
934 // we can't have zero's and such, this is a simple encoding to make sure we don't barf
935 return base64_encode( $b );
938 function decodeBlob( $b ) {
939 // we can't have zero's and such, this is a simple encoding to make sure we don't barf
940 return base64_decode( $b );
944 * @private
946 function tableNamesWithUseIndexOrJOIN( $tables, $use_index = array(), $join_conds = array() ) {
947 $ret = array();
948 $retJOIN = array();
949 $use_index_safe = is_array( $use_index ) ? $use_index : array();
950 $join_conds_safe = is_array( $join_conds ) ? $join_conds : array();
951 foreach ( $tables as $table ) {
952 // Is there a JOIN and INDEX clause for this table?
953 if ( isset( $join_conds_safe[$table] ) && isset( $use_index_safe[$table] ) ) {
954 $tableClause = $join_conds_safe[$table][0] . ' ' . $this->tableName( $table );
955 $tableClause .= ' ' . $this->useIndexClause( implode( ',', (array)$use_index_safe[$table] ) );
956 $tableClause .= ' ON (' . $this->makeList( (array)$join_conds_safe[$table][1], LIST_AND ) . ')';
957 $retJOIN[] = $tableClause;
958 // Is there an INDEX clause?
959 } else if ( isset( $use_index_safe[$table] ) ) {
960 $tableClause = $this->tableName( $table );
961 $tableClause .= ' ' . $this->useIndexClause( implode( ',', (array)$use_index_safe[$table] ) );
962 $ret[] = $tableClause;
963 // Is there a JOIN clause?
964 } else if ( isset( $join_conds_safe[$table] ) ) {
965 $tableClause = $join_conds_safe[$table][0] . ' ' . $this->tableName( $table );
966 $tableClause .= ' ON (' . $this->makeList( (array)$join_conds_safe[$table][1], LIST_AND ) . ')';
967 $retJOIN[] = $tableClause;
968 } else {
969 $tableClause = $this->tableName( $table );
970 $ret[] = $tableClause;
973 // We can't separate explicit JOIN clauses with ',', use ' ' for those
974 $straightJoins = !empty( $ret ) ? implode( ',', $ret ) : "";
975 $otherJoins = !empty( $retJOIN ) ? implode( ' ', $retJOIN ) : "";
976 // Compile our final table clause
977 return implode( ' ', array( $straightJoins, $otherJoins ) );
980 function strencode( $s ) { # Should not be called by us
981 return str_replace( "'", "''", $s );
984 function addQuotes( $s ) {
985 if ( $s instanceof Blob ) {
986 return "'" . $s->fetch( $s ) . "'";
987 } else {
988 return parent::addQuotes( $s );
992 function selectDB( $db ) {
993 return ( $this->query( "SET DATABASE $db" ) !== false );
997 * @private
999 * @param $options Array: an associative array of options to be turned into
1000 * an SQL query, valid keys are listed in the function.
1001 * @return Array
1003 function makeSelectOptions( $options ) {
1004 $tailOpts = '';
1005 $startOpts = '';
1007 $noKeyOptions = array();
1008 foreach ( $options as $key => $option ) {
1009 if ( is_numeric( $key ) ) {
1010 $noKeyOptions[$option] = true;
1014 if ( isset( $options['GROUP BY'] ) ) {
1015 $tailOpts .= " GROUP BY {$options['GROUP BY']}";
1017 if ( isset( $options['HAVING'] ) ) {
1018 $tailOpts .= " HAVING {$options['GROUP BY']}";
1020 if ( isset( $options['ORDER BY'] ) ) {
1021 $tailOpts .= " ORDER BY {$options['ORDER BY']}";
1024 if ( isset( $noKeyOptions['DISTINCT'] ) && isset( $noKeyOptions['DISTINCTROW'] ) ) {
1025 $startOpts .= 'DISTINCT';
1028 // we want this to be compatible with the output of parent::makeSelectOptions()
1029 return array( $startOpts, '' , $tailOpts, '' );
1033 * Get the type of the DBMS, as it appears in $wgDBtype.
1035 function getType(){
1036 return 'mssql';
1039 function buildConcat( $stringList ) {
1040 return implode( ' + ', $stringList );
1043 public function getSearchEngine() {
1044 return "SearchMssql";
1048 * Since MSSQL doesn't recognize the infinity keyword, set date manually.
1049 * @todo Remove magic date
1051 public function getInfinity() {
1052 return '3000-01-31 00:00:00.000';
1055 } // end DatabaseMssql class
1058 * Utility class.
1060 * @ingroup Database
1062 class MssqlField implements Field {
1063 private $name, $tablename, $default, $max_length, $nullable, $type;
1064 function __construct ( $info ) {
1065 $this->name = $info['COLUMN_NAME'];
1066 $this->tablename = $info['TABLE_NAME'];
1067 $this->default = $info['COLUMN_DEFAULT'];
1068 $this->max_length = $info['CHARACTER_MAXIMUM_LENGTH'];
1069 $this->nullable = ( strtolower( $info['IS_NULLABLE'] ) == 'no' ) ? false:true;
1070 $this->type = $info['DATA_TYPE'];
1073 function name() {
1074 return $this->name;
1077 function tableName() {
1078 return $this->tableName;
1081 function defaultValue() {
1082 return $this->default;
1085 function maxLength() {
1086 return $this->max_length;
1089 function isNullable() {
1090 return $this->nullable;
1093 function type() {
1094 return $this->type;
1099 * The MSSQL PHP driver doesn't support sqlsrv_num_rows, so we recall all rows into an array and maintain our
1100 * own cursor index into that array...This is similar to the way the Oracle driver handles this same issue
1102 * @ingroup Database
1104 class MssqlResult {
1106 public function __construct( $queryresult = false ) {
1107 $this->mCursor = 0;
1108 $this->mRows = array();
1109 $this->mNumFields = sqlsrv_num_fields( $queryresult );
1110 $this->mFieldMeta = sqlsrv_field_metadata( $queryresult );
1112 $rows = sqlsrv_fetch_array( $queryresult, SQLSRV_FETCH_ASSOC );
1114 foreach( $rows as $row ) {
1115 if ( $row !== null ) {
1116 foreach ( $row as $k => $v ) {
1117 if ( is_object( $v ) && method_exists( $v, 'format' ) ) {// DateTime Object
1118 $row[$k] = $v->format( "Y-m-d\TH:i:s\Z" );
1121 $this->mRows[] = $row;// read results into memory, cursors are not supported
1124 $this->mRowCount = count( $this->mRows );
1125 sqlsrv_free_stmt( $queryresult );
1128 private function array_to_obj( $array, &$obj ) {
1129 foreach ( $array as $key => $value ) {
1130 if ( is_array( $value ) ) {
1131 $obj->$key = new stdClass();
1132 $this->array_to_obj( $value, $obj->$key );
1133 } else {
1134 if ( !empty( $key ) ) {
1135 $obj->$key = $value;
1139 return $obj;
1142 public function fetch( $mode = SQLSRV_FETCH_BOTH, $object_class = 'stdClass' ) {
1143 if ( $this->mCursor >= $this->mRowCount || $this->mRowCount == 0 ) {
1144 return false;
1146 $arrNum = array();
1147 if ( $mode == SQLSRV_FETCH_NUMERIC || $mode == SQLSRV_FETCH_BOTH ) {
1148 foreach ( $this->mRows[$this->mCursor] as $value ) {
1149 $arrNum[] = $value;
1152 switch( $mode ) {
1153 case SQLSRV_FETCH_ASSOC:
1154 $ret = $this->mRows[$this->mCursor];
1155 break;
1156 case SQLSRV_FETCH_NUMERIC:
1157 $ret = $arrNum;
1158 break;
1159 case 'OBJECT':
1160 $o = new $object_class;
1161 $ret = $this->array_to_obj( $this->mRows[$this->mCursor], $o );
1162 break;
1163 case SQLSRV_FETCH_BOTH:
1164 default:
1165 $ret = $this->mRows[$this->mCursor] + $arrNum;
1166 break;
1169 $this->mCursor++;
1170 return $ret;
1173 public function get( $pos, $fld ) {
1174 return $this->mRows[$pos][$fld];
1177 public function numrows() {
1178 return $this->mRowCount;
1181 public function seek( $iRow ) {
1182 $this->mCursor = min( $iRow, $this->mRowCount );
1185 public function numfields() {
1186 return $this->mNumFields;
1189 public function fieldname( $nr ) {
1190 $arrKeys = array_keys( $this->mRows[0] );
1191 return $arrKeys[$nr];
1194 public function fieldtype( $nr ) {
1195 $i = 0;
1196 $intType = -1;
1197 foreach ( $this->mFieldMeta as $meta ) {
1198 if ( $nr == $i ) {
1199 $intType = $meta['Type'];
1200 break;
1202 $i++;
1204 // http://msdn.microsoft.com/en-us/library/cc296183.aspx contains type table
1205 switch( $intType ) {
1206 case SQLSRV_SQLTYPE_BIGINT: $strType = 'bigint'; break;
1207 case SQLSRV_SQLTYPE_BINARY: $strType = 'binary'; break;
1208 case SQLSRV_SQLTYPE_BIT: $strType = 'bit'; break;
1209 case SQLSRV_SQLTYPE_CHAR: $strType = 'char'; break;
1210 case SQLSRV_SQLTYPE_DATETIME: $strType = 'datetime'; break;
1211 case SQLSRV_SQLTYPE_DECIMAL/*($precision, $scale)*/: $strType = 'decimal'; break;
1212 case SQLSRV_SQLTYPE_FLOAT: $strType = 'float'; break;
1213 case SQLSRV_SQLTYPE_IMAGE: $strType = 'image'; break;
1214 case SQLSRV_SQLTYPE_INT: $strType = 'int'; break;
1215 case SQLSRV_SQLTYPE_MONEY: $strType = 'money'; break;
1216 case SQLSRV_SQLTYPE_NCHAR/*($charCount)*/: $strType = 'nchar'; break;
1217 case SQLSRV_SQLTYPE_NUMERIC/*($precision, $scale)*/: $strType = 'numeric'; break;
1218 case SQLSRV_SQLTYPE_NVARCHAR/*($charCount)*/: $strType = 'nvarchar'; break;
1219 // case SQLSRV_SQLTYPE_NVARCHAR('max'): $strType = 'nvarchar(MAX)'; break;
1220 case SQLSRV_SQLTYPE_NTEXT: $strType = 'ntext'; break;
1221 case SQLSRV_SQLTYPE_REAL: $strType = 'real'; break;
1222 case SQLSRV_SQLTYPE_SMALLDATETIME: $strType = 'smalldatetime'; break;
1223 case SQLSRV_SQLTYPE_SMALLINT: $strType = 'smallint'; break;
1224 case SQLSRV_SQLTYPE_SMALLMONEY: $strType = 'smallmoney'; break;
1225 case SQLSRV_SQLTYPE_TEXT: $strType = 'text'; break;
1226 case SQLSRV_SQLTYPE_TIMESTAMP: $strType = 'timestamp'; break;
1227 case SQLSRV_SQLTYPE_TINYINT: $strType = 'tinyint'; break;
1228 case SQLSRV_SQLTYPE_UNIQUEIDENTIFIER: $strType = 'uniqueidentifier'; break;
1229 case SQLSRV_SQLTYPE_UDT: $strType = 'UDT'; break;
1230 case SQLSRV_SQLTYPE_VARBINARY/*($byteCount)*/: $strType = 'varbinary'; break;
1231 // case SQLSRV_SQLTYPE_VARBINARY('max'): $strType = 'varbinary(MAX)'; break;
1232 case SQLSRV_SQLTYPE_VARCHAR/*($charCount)*/: $strType = 'varchar'; break;
1233 // case SQLSRV_SQLTYPE_VARCHAR('max'): $strType = 'varchar(MAX)'; break;
1234 case SQLSRV_SQLTYPE_XML: $strType = 'xml'; break;
1235 default: $strType = $intType;
1237 return $strType;
1240 public function free() {
1241 unset( $this->mRows );
1242 return;