* changed display function for length to Linker::formatRevisionSize
[mediawiki.git] / includes / db / DatabaseMssql.php
blobd8452f9749553e435e5a0ceed560e40f1ee3fa03
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->addQuotes( $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->addQuotes( $value );
461 } else {
462 $sql .= $this->addQuotes( 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 * Return the next in a sequence, save the value for retrieval via insertId()
515 function nextSequenceValue( $seqName ) {
516 if ( !$this->tableExists( 'sequence_' . $seqName ) ) {
517 sqlsrv_query( $this->mConn, "CREATE TABLE [sequence_$seqName] (id INT NOT NULL IDENTITY PRIMARY KEY, junk varchar(10) NULL)" );
519 sqlsrv_query( $this->mConn, "INSERT INTO [sequence_$seqName] (junk) VALUES ('')" );
520 $ret = sqlsrv_query( $this->mConn, "SELECT TOP 1 id FROM [sequence_$seqName] ORDER BY id DESC" );
521 $row = sqlsrv_fetch_array( $ret, SQLSRV_FETCH_ASSOC );// KEEP ASSOC THERE, weird weird bug dealing with the return value if you don't
523 sqlsrv_free_stmt( $ret );
524 $this->mInsertId = $row['id'];
525 return $row['id'];
529 * Return the current value of a sequence. Assumes it has ben nextval'ed in this session.
531 function currentSequenceValue( $seqName ) {
532 $ret = sqlsrv_query( $this->mConn, "SELECT TOP 1 id FROM [sequence_$seqName] ORDER BY id DESC" );
533 if ( $ret !== false ) {
534 $row = sqlsrv_fetch_array( $ret );
535 sqlsrv_free_stmt( $ret );
536 return $row['id'];
537 } else {
538 return $this->nextSequenceValue( $seqName );
543 # REPLACE query wrapper
544 # MSSQL simulates this with a DELETE followed by INSERT
545 # $row is the row to insert, an associative array
546 # $uniqueIndexes is an array of indexes. Each element may be either a
547 # field name or an array of field names
549 # It may be more efficient to leave off unique indexes which are unlikely to collide.
550 # However if you do this, you run the risk of encountering errors which wouldn't have
551 # occurred in MySQL
552 function replace( $table, $uniqueIndexes, $rows, $fname = 'DatabaseMssql::replace' ) {
553 $table = $this->tableName( $table );
555 if ( count( $rows ) == 0 ) {
556 return;
559 # Single row case
560 if ( !is_array( reset( $rows ) ) ) {
561 $rows = array( $rows );
564 foreach ( $rows as $row ) {
565 # Delete rows which collide
566 if ( $uniqueIndexes ) {
567 $sql = "DELETE FROM $table WHERE ";
568 $first = true;
569 foreach ( $uniqueIndexes as $index ) {
570 if ( $first ) {
571 $first = false;
572 $sql .= "(";
573 } else {
574 $sql .= ') OR (';
576 if ( is_array( $index ) ) {
577 $first2 = true;
578 foreach ( $index as $col ) {
579 if ( $first2 ) {
580 $first2 = false;
581 } else {
582 $sql .= ' AND ';
584 $sql .= $col . '=' . $this->addQuotes( $row[$col] );
586 } else {
587 $sql .= $index . '=' . $this->addQuotes( $row[$index] );
590 $sql .= ')';
591 $this->query( $sql, $fname );
594 # Now insert the row
595 $sql = "INSERT INTO $table (" . $this->makeList( array_keys( $row ), LIST_NAMES ) . ') VALUES (' .
596 $this->makeList( $row, LIST_COMMA ) . ')';
597 $this->query( $sql, $fname );
601 # DELETE where the condition is a join
602 function deleteJoin( $delTable, $joinTable, $delVar, $joinVar, $conds, $fname = "DatabaseMssql::deleteJoin" ) {
603 if ( !$conds ) {
604 throw new DBUnexpectedError( $this, 'DatabaseMssql::deleteJoin() called with empty $conds' );
607 $delTable = $this->tableName( $delTable );
608 $joinTable = $this->tableName( $joinTable );
609 $sql = "DELETE FROM $delTable WHERE $delVar IN (SELECT $joinVar FROM $joinTable ";
610 if ( $conds != '*' ) {
611 $sql .= 'WHERE ' . $this->makeList( $conds, LIST_AND );
613 $sql .= ')';
615 $this->query( $sql, $fname );
618 # Returns the size of a text field, or -1 for "unlimited"
619 function textFieldSize( $table, $field ) {
620 $table = $this->tableName( $table );
621 $sql = "SELECT CHARACTER_MAXIMUM_LENGTH,DATA_TYPE FROM INFORMATION_SCHEMA.Columns
622 WHERE TABLE_NAME = '$table' AND COLUMN_NAME = '$field'";
623 $res = $this->query( $sql );
624 $row = $this->fetchRow( $res );
625 $size = -1;
626 if ( strtolower( $row['DATA_TYPE'] ) != 'text' ) {
627 $size = $row['CHARACTER_MAXIMUM_LENGTH'];
629 return $size;
633 * Construct a LIMIT query with optional offset
634 * This is used for query pages
635 * $sql string SQL query we will append the limit too
636 * $limit integer the SQL limit
637 * $offset integer the SQL offset (default false)
639 function limitResult( $sql, $limit, $offset = false ) {
640 if ( $offset === false || $offset == 0 ) {
641 if ( strpos( $sql, "SELECT" ) === false ) {
642 return "TOP {$limit} " . $sql;
643 } else {
644 return preg_replace( '/\bSELECT(\s*DISTINCT)?\b/Dsi', 'SELECT$1 TOP ' . $limit, $sql, 1 );
646 } else {
647 $sql = '
648 SELECT * FROM (
649 SELECT sub2.*, ROW_NUMBER() OVER(ORDER BY sub2.line2) AS line3 FROM (
650 SELECT 1 AS line2, sub1.* FROM (' . $sql . ') AS sub1
651 ) as sub2
652 ) AS sub3
653 WHERE line3 BETWEEN ' . ( $offset + 1 ) . ' AND ' . ( $offset + $limit );
654 return $sql;
658 // If there is a limit clause, parse it, strip it, and pass the remaining sql through limitResult()
659 // with the appropriate parameters. Not the prettiest solution, but better than building a whole new parser.
660 // This exists becase there are still too many extensions that don't use dynamic sql generation.
661 function LimitToTopN( $sql ) {
662 // Matches: LIMIT {[offset,] row_count | row_count OFFSET offset}
663 $pattern = '/\bLIMIT\s+((([0-9]+)\s*,\s*)?([0-9]+)(\s+OFFSET\s+([0-9]+))?)/i';
664 if ( preg_match( $pattern, $sql, $matches ) ) {
665 // row_count = $matches[4]
666 $row_count = $matches[4];
667 // offset = $matches[3] OR $matches[6]
668 $offset = $matches[3] or
669 $offset = $matches[6] or
670 $offset = false;
672 // strip the matching LIMIT clause out
673 $sql = str_replace( $matches[0], '', $sql );
674 return $this->limitResult( $sql, $row_count, $offset );
676 return $sql;
679 // MSSQL does support this, but documentation is too thin to make a generalized
680 // function for this. Apparently UPDATE TOP (N) works, but the sort order
681 // may not be what we're expecting so the top n results may be a random selection.
682 // TODO: Implement properly.
683 function limitResultForUpdate( $sql, $num ) {
684 return $sql;
687 function timestamp( $ts = 0 ) {
688 return wfTimestamp( TS_ISO_8601, $ts );
692 * @return string wikitext of a link to the server software's web site
694 public static function getSoftwareLink() {
695 return "[http://www.microsoft.com/sql/ MS SQL Server]";
699 * @return string Version information from the database
701 function getServerVersion() {
702 $server_info = sqlsrv_server_info( $this->mConn );
703 $version = 'Error';
704 if ( isset( $server_info['SQLServerVersion'] ) ) {
705 $version = $server_info['SQLServerVersion'];
707 return $version;
710 function tableExists ( $table, $schema = false ) {
711 $res = sqlsrv_query( $this->mConn, "SELECT * FROM information_schema.tables
712 WHERE table_type='BASE TABLE' AND table_name = '$table'" );
713 if ( $res === false ) {
714 print( "Error in tableExists query: " . $this->getErrors() );
715 return false;
717 if ( sqlsrv_fetch( $res ) ) {
718 return true;
719 } else {
720 return false;
725 * Query whether a given column exists in the mediawiki schema
727 function fieldExists( $table, $field, $fname = 'DatabaseMssql::fieldExists' ) {
728 $table = $this->tableName( $table );
729 $res = sqlsrv_query( $this->mConn, "SELECT DATA_TYPE FROM INFORMATION_SCHEMA.Columns
730 WHERE TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
731 if ( $res === false ) {
732 print( "Error in fieldExists query: " . $this->getErrors() );
733 return false;
735 if ( sqlsrv_fetch( $res ) ) {
736 return true;
737 } else {
738 return false;
742 function fieldInfo( $table, $field ) {
743 $table = $this->tableName( $table );
744 $res = sqlsrv_query( $this->mConn, "SELECT * FROM INFORMATION_SCHEMA.Columns
745 WHERE TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
746 if ( $res === false ) {
747 print( "Error in fieldInfo query: " . $this->getErrors() );
748 return false;
750 $meta = $this->fetchRow( $res );
751 if ( $meta ) {
752 return new MssqlField( $meta );
754 return false;
758 * Begin a transaction, committing any previously open transaction
760 function begin( $fname = 'DatabaseMssql::begin' ) {
761 sqlsrv_begin_transaction( $this->mConn );
762 $this->mTrxLevel = 1;
766 * End a transaction
768 function commit( $fname = 'DatabaseMssql::commit' ) {
769 sqlsrv_commit( $this->mConn );
770 $this->mTrxLevel = 0;
774 * Rollback a transaction.
775 * No-op on non-transactional databases.
777 function rollback( $fname = 'DatabaseMssql::rollback' ) {
778 sqlsrv_rollback( $this->mConn );
779 $this->mTrxLevel = 0;
782 function setup_database() {
783 global $wgDBuser;
785 // Make sure that we can write to the correct schema
786 $ctest = "mediawiki_test_table";
787 if ( $this->tableExists( $ctest ) ) {
788 $this->doQuery( "DROP TABLE $ctest" );
790 $SQL = "CREATE TABLE $ctest (a int)";
791 $res = $this->doQuery( $SQL );
792 if ( !$res ) {
793 print "<b>FAILED</b>. Make sure that the user " . htmlspecialchars( $wgDBuser ) . " can write to the database</li>\n";
794 die();
796 $this->doQuery( "DROP TABLE $ctest" );
798 $res = $this->sourceFile( "../maintenance/mssql/tables.sql" );
799 if ( $res !== true ) {
800 echo " <b>FAILED</b></li>";
801 die( htmlspecialchars( $res ) );
804 # Avoid the non-standard "REPLACE INTO" syntax
805 $f = fopen( "../maintenance/interwiki.sql", 'r' );
806 if ( $f == false ) {
807 die( "<li>Could not find the interwiki.sql file" );
809 # We simply assume it is already empty as we have just created it
810 $SQL = "INSERT INTO interwiki(iw_prefix,iw_url,iw_local) VALUES ";
811 while ( ! feof( $f ) ) {
812 $line = fgets( $f, 1024 );
813 $matches = array();
814 if ( !preg_match( '/^\s*(\(.+?),(\d)\)/', $line, $matches ) ) {
815 continue;
817 $this->query( "$SQL $matches[1],$matches[2])" );
819 print " (table interwiki successfully populated)...\n";
821 $this->commit();
825 * Escapes a identifier for use inm SQL.
826 * Throws an exception if it is invalid.
827 * Reference: http://msdn.microsoft.com/en-us/library/aa224033%28v=SQL.80%29.aspx
829 private function escapeIdentifier( $identifier ) {
830 if ( strlen( $identifier ) == 0 ) {
831 throw new MWException( "An identifier must not be empty" );
833 if ( strlen( $identifier ) > 128 ) {
834 throw new MWException( "The identifier '$identifier' is too long (max. 128)" );
836 if ( ( strpos( $identifier, '[' ) !== false ) || ( strpos( $identifier, ']' ) !== false ) ) {
837 // It may be allowed if you quoted with double quotation marks, but that would break if QUOTED_IDENTIFIER is OFF
838 throw new MWException( "You can't use square brackers in the identifier '$identifier'" );
840 return "[$identifier]";
844 * Initial setup.
845 * Precondition: This object is connected as the superuser.
846 * Creates the database, schema, user and login.
848 function initial_setup( $dbName, $newUser, $loginPassword ) {
849 $dbName = $this->escapeIdentifier( $dbName );
851 // It is not clear what can be used as a login,
852 // From http://msdn.microsoft.com/en-us/library/ms173463.aspx
853 // a sysname may be the same as an identifier.
854 $newUser = $this->escapeIdentifier( $newUser );
855 $loginPassword = $this->addQuotes( $loginPassword );
857 $this->doQuery("CREATE DATABASE $dbName;");
858 $this->doQuery("USE $dbName;");
859 $this->doQuery("CREATE SCHEMA $dbName;");
860 $this->doQuery("
861 CREATE
862 LOGIN $newUser
863 WITH
864 PASSWORD=$loginPassword
867 $this->doQuery("
868 CREATE
869 USER $newUser
871 LOGIN $newUser
872 WITH
873 DEFAULT_SCHEMA=$dbName
876 $this->doQuery("
877 GRANT
878 BACKUP DATABASE,
879 BACKUP LOG,
880 CREATE DEFAULT,
881 CREATE FUNCTION,
882 CREATE PROCEDURE,
883 CREATE RULE,
884 CREATE TABLE,
885 CREATE VIEW,
886 CREATE FULLTEXT CATALOG
888 DATABASE::$dbName
889 TO $newUser
892 $this->doQuery("
893 GRANT
894 CONTROL
896 SCHEMA::$dbName
897 TO $newUser
904 function encodeBlob( $b ) {
905 // we can't have zero's and such, this is a simple encoding to make sure we don't barf
906 return base64_encode( $b );
909 function decodeBlob( $b ) {
910 // we can't have zero's and such, this is a simple encoding to make sure we don't barf
911 return base64_decode( $b );
915 * @private
917 function tableNamesWithUseIndexOrJOIN( $tables, $use_index = array(), $join_conds = array() ) {
918 $ret = array();
919 $retJOIN = array();
920 $use_index_safe = is_array( $use_index ) ? $use_index : array();
921 $join_conds_safe = is_array( $join_conds ) ? $join_conds : array();
922 foreach ( $tables as $table ) {
923 // Is there a JOIN and INDEX clause for this table?
924 if ( isset( $join_conds_safe[$table] ) && isset( $use_index_safe[$table] ) ) {
925 $tableClause = $join_conds_safe[$table][0] . ' ' . $this->tableName( $table );
926 $tableClause .= ' ' . $this->useIndexClause( implode( ',', (array)$use_index_safe[$table] ) );
927 $tableClause .= ' ON (' . $this->makeList( (array)$join_conds_safe[$table][1], LIST_AND ) . ')';
928 $retJOIN[] = $tableClause;
929 // Is there an INDEX clause?
930 } else if ( isset( $use_index_safe[$table] ) ) {
931 $tableClause = $this->tableName( $table );
932 $tableClause .= ' ' . $this->useIndexClause( implode( ',', (array)$use_index_safe[$table] ) );
933 $ret[] = $tableClause;
934 // Is there a JOIN clause?
935 } else if ( isset( $join_conds_safe[$table] ) ) {
936 $tableClause = $join_conds_safe[$table][0] . ' ' . $this->tableName( $table );
937 $tableClause .= ' ON (' . $this->makeList( (array)$join_conds_safe[$table][1], LIST_AND ) . ')';
938 $retJOIN[] = $tableClause;
939 } else {
940 $tableClause = $this->tableName( $table );
941 $ret[] = $tableClause;
944 // We can't separate explicit JOIN clauses with ',', use ' ' for those
945 $straightJoins = !empty( $ret ) ? implode( ',', $ret ) : "";
946 $otherJoins = !empty( $retJOIN ) ? implode( ' ', $retJOIN ) : "";
947 // Compile our final table clause
948 return implode( ' ', array( $straightJoins, $otherJoins ) );
951 function strencode( $s ) { # Should not be called by us
952 return str_replace( "'", "''", $s );
955 function addQuotes( $s ) {
956 if ( $s instanceof Blob ) {
957 return "'" . $s->fetch( $s ) . "'";
958 } else {
959 return parent::addQuotes( $s );
963 public function addIdentifierQuotes( $s ) {
964 // http://msdn.microsoft.com/en-us/library/aa223962.aspx
965 return '[' . $s . ']';
968 public function isQuotedIdentifier( $name ) {
969 return $name[0] == '[' && substr( $name, -1, 1 ) == ']';
972 function selectDB( $db ) {
973 return ( $this->query( "SET DATABASE $db" ) !== false );
977 * @private
979 * @param $options Array: an associative array of options to be turned into
980 * an SQL query, valid keys are listed in the function.
981 * @return Array
983 function makeSelectOptions( $options ) {
984 $tailOpts = '';
985 $startOpts = '';
987 $noKeyOptions = array();
988 foreach ( $options as $key => $option ) {
989 if ( is_numeric( $key ) ) {
990 $noKeyOptions[$option] = true;
994 if ( isset( $options['GROUP BY'] ) ) {
995 $tailOpts .= " GROUP BY {$options['GROUP BY']}";
997 if ( isset( $options['HAVING'] ) ) {
998 $tailOpts .= " HAVING {$options['GROUP BY']}";
1000 if ( isset( $options['ORDER BY'] ) ) {
1001 $tailOpts .= " ORDER BY {$options['ORDER BY']}";
1004 if ( isset( $noKeyOptions['DISTINCT'] ) && isset( $noKeyOptions['DISTINCTROW'] ) ) {
1005 $startOpts .= 'DISTINCT';
1008 // we want this to be compatible with the output of parent::makeSelectOptions()
1009 return array( $startOpts, '' , $tailOpts, '' );
1013 * Get the type of the DBMS, as it appears in $wgDBtype.
1015 function getType(){
1016 return 'mssql';
1019 function buildConcat( $stringList ) {
1020 return implode( ' + ', $stringList );
1023 public function getSearchEngine() {
1024 return "SearchMssql";
1028 * Since MSSQL doesn't recognize the infinity keyword, set date manually.
1029 * @todo Remove magic date
1031 public function getInfinity() {
1032 return '3000-01-31 00:00:00.000';
1035 } // end DatabaseMssql class
1038 * Utility class.
1040 * @ingroup Database
1042 class MssqlField implements Field {
1043 private $name, $tablename, $default, $max_length, $nullable, $type;
1044 function __construct ( $info ) {
1045 $this->name = $info['COLUMN_NAME'];
1046 $this->tablename = $info['TABLE_NAME'];
1047 $this->default = $info['COLUMN_DEFAULT'];
1048 $this->max_length = $info['CHARACTER_MAXIMUM_LENGTH'];
1049 $this->nullable = !( strtolower( $info['IS_NULLABLE'] ) == 'no' );
1050 $this->type = $info['DATA_TYPE'];
1053 function name() {
1054 return $this->name;
1057 function tableName() {
1058 return $this->tableName;
1061 function defaultValue() {
1062 return $this->default;
1065 function maxLength() {
1066 return $this->max_length;
1069 function isNullable() {
1070 return $this->nullable;
1073 function type() {
1074 return $this->type;
1079 * The MSSQL PHP driver doesn't support sqlsrv_num_rows, so we recall all rows into an array and maintain our
1080 * own cursor index into that array...This is similar to the way the Oracle driver handles this same issue
1082 * @ingroup Database
1084 class MssqlResult {
1086 public function __construct( $queryresult = false ) {
1087 $this->mCursor = 0;
1088 $this->mRows = array();
1089 $this->mNumFields = sqlsrv_num_fields( $queryresult );
1090 $this->mFieldMeta = sqlsrv_field_metadata( $queryresult );
1092 $rows = sqlsrv_fetch_array( $queryresult, SQLSRV_FETCH_ASSOC );
1094 foreach( $rows as $row ) {
1095 if ( $row !== null ) {
1096 foreach ( $row as $k => $v ) {
1097 if ( is_object( $v ) && method_exists( $v, 'format' ) ) {// DateTime Object
1098 $row[$k] = $v->format( "Y-m-d\TH:i:s\Z" );
1101 $this->mRows[] = $row;// read results into memory, cursors are not supported
1104 $this->mRowCount = count( $this->mRows );
1105 sqlsrv_free_stmt( $queryresult );
1108 private function array_to_obj( $array, &$obj ) {
1109 foreach ( $array as $key => $value ) {
1110 if ( is_array( $value ) ) {
1111 $obj->$key = new stdClass();
1112 $this->array_to_obj( $value, $obj->$key );
1113 } else {
1114 if ( !empty( $key ) ) {
1115 $obj->$key = $value;
1119 return $obj;
1122 public function fetch( $mode = SQLSRV_FETCH_BOTH, $object_class = 'stdClass' ) {
1123 if ( $this->mCursor >= $this->mRowCount || $this->mRowCount == 0 ) {
1124 return false;
1126 $arrNum = array();
1127 if ( $mode == SQLSRV_FETCH_NUMERIC || $mode == SQLSRV_FETCH_BOTH ) {
1128 foreach ( $this->mRows[$this->mCursor] as $value ) {
1129 $arrNum[] = $value;
1132 switch( $mode ) {
1133 case SQLSRV_FETCH_ASSOC:
1134 $ret = $this->mRows[$this->mCursor];
1135 break;
1136 case SQLSRV_FETCH_NUMERIC:
1137 $ret = $arrNum;
1138 break;
1139 case 'OBJECT':
1140 $o = new $object_class;
1141 $ret = $this->array_to_obj( $this->mRows[$this->mCursor], $o );
1142 break;
1143 case SQLSRV_FETCH_BOTH:
1144 default:
1145 $ret = $this->mRows[$this->mCursor] + $arrNum;
1146 break;
1149 $this->mCursor++;
1150 return $ret;
1153 public function get( $pos, $fld ) {
1154 return $this->mRows[$pos][$fld];
1157 public function numrows() {
1158 return $this->mRowCount;
1161 public function seek( $iRow ) {
1162 $this->mCursor = min( $iRow, $this->mRowCount );
1165 public function numfields() {
1166 return $this->mNumFields;
1169 public function fieldname( $nr ) {
1170 $arrKeys = array_keys( $this->mRows[0] );
1171 return $arrKeys[$nr];
1174 public function fieldtype( $nr ) {
1175 $i = 0;
1176 $intType = -1;
1177 foreach ( $this->mFieldMeta as $meta ) {
1178 if ( $nr == $i ) {
1179 $intType = $meta['Type'];
1180 break;
1182 $i++;
1184 // http://msdn.microsoft.com/en-us/library/cc296183.aspx contains type table
1185 switch( $intType ) {
1186 case SQLSRV_SQLTYPE_BIGINT: $strType = 'bigint'; break;
1187 case SQLSRV_SQLTYPE_BINARY: $strType = 'binary'; break;
1188 case SQLSRV_SQLTYPE_BIT: $strType = 'bit'; break;
1189 case SQLSRV_SQLTYPE_CHAR: $strType = 'char'; break;
1190 case SQLSRV_SQLTYPE_DATETIME: $strType = 'datetime'; break;
1191 case SQLSRV_SQLTYPE_DECIMAL/*($precision, $scale)*/: $strType = 'decimal'; break;
1192 case SQLSRV_SQLTYPE_FLOAT: $strType = 'float'; break;
1193 case SQLSRV_SQLTYPE_IMAGE: $strType = 'image'; break;
1194 case SQLSRV_SQLTYPE_INT: $strType = 'int'; break;
1195 case SQLSRV_SQLTYPE_MONEY: $strType = 'money'; break;
1196 case SQLSRV_SQLTYPE_NCHAR/*($charCount)*/: $strType = 'nchar'; break;
1197 case SQLSRV_SQLTYPE_NUMERIC/*($precision, $scale)*/: $strType = 'numeric'; break;
1198 case SQLSRV_SQLTYPE_NVARCHAR/*($charCount)*/: $strType = 'nvarchar'; break;
1199 // case SQLSRV_SQLTYPE_NVARCHAR('max'): $strType = 'nvarchar(MAX)'; break;
1200 case SQLSRV_SQLTYPE_NTEXT: $strType = 'ntext'; break;
1201 case SQLSRV_SQLTYPE_REAL: $strType = 'real'; break;
1202 case SQLSRV_SQLTYPE_SMALLDATETIME: $strType = 'smalldatetime'; break;
1203 case SQLSRV_SQLTYPE_SMALLINT: $strType = 'smallint'; break;
1204 case SQLSRV_SQLTYPE_SMALLMONEY: $strType = 'smallmoney'; break;
1205 case SQLSRV_SQLTYPE_TEXT: $strType = 'text'; break;
1206 case SQLSRV_SQLTYPE_TIMESTAMP: $strType = 'timestamp'; break;
1207 case SQLSRV_SQLTYPE_TINYINT: $strType = 'tinyint'; break;
1208 case SQLSRV_SQLTYPE_UNIQUEIDENTIFIER: $strType = 'uniqueidentifier'; break;
1209 case SQLSRV_SQLTYPE_UDT: $strType = 'UDT'; break;
1210 case SQLSRV_SQLTYPE_VARBINARY/*($byteCount)*/: $strType = 'varbinary'; break;
1211 // case SQLSRV_SQLTYPE_VARBINARY('max'): $strType = 'varbinary(MAX)'; break;
1212 case SQLSRV_SQLTYPE_VARCHAR/*($charCount)*/: $strType = 'varchar'; break;
1213 // case SQLSRV_SQLTYPE_VARCHAR('max'): $strType = 'varchar(MAX)'; break;
1214 case SQLSRV_SQLTYPE_XML: $strType = 'xml'; break;
1215 default: $strType = $intType;
1217 return $strType;
1220 public function free() {
1221 unset( $this->mRows );
1222 return;