Fix use of RawMessage in Status::getMessage()
[mediawiki.git] / includes / db / DatabaseMssql.php
blobce34537aeed3e12d8b516766618af92998456c04
1 <?php
2 /**
3 * This is the MS SQL Server Native database abstraction layer.
5 * This program is free software; you can redistribute it and/or modify
6 * it under the terms of the GNU General Public License as published by
7 * the Free Software Foundation; either version 2 of the License, or
8 * (at your option) any later version.
10 * This program is distributed in the hope that it will be useful,
11 * but WITHOUT ANY WARRANTY; without even the implied warranty of
12 * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
13 * GNU General Public License for more details.
15 * You should have received a copy of the GNU General Public License along
16 * with this program; if not, write to the Free Software Foundation, Inc.,
17 * 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.
18 * http://www.gnu.org/copyleft/gpl.html
20 * @file
21 * @ingroup Database
22 * @author Joel Penner <a-joelpe at microsoft dot com>
23 * @author Chris Pucci <a-cpucci at microsoft dot com>
24 * @author Ryan Biesemeyer <v-ryanbi at microsoft dot com>
25 * @author Ryan Schmidt <skizzerz at gmail dot com>
28 /**
29 * @ingroup Database
31 class DatabaseMssql extends Database {
32 protected $mInsertId = null;
33 protected $mLastResult = null;
34 protected $mAffectedRows = null;
35 protected $mSubqueryId = 0;
36 protected $mScrollableCursor = true;
37 protected $mPrepareStatements = true;
38 protected $mBinaryColumnCache = null;
39 protected $mBitColumnCache = null;
40 protected $mIgnoreDupKeyErrors = false;
42 protected $mPort;
44 public function cascadingDeletes() {
45 return true;
48 public function cleanupTriggers() {
49 return false;
52 public function strictIPs() {
53 return false;
56 public function realTimestamps() {
57 return false;
60 public function implicitGroupby() {
61 return false;
64 public function implicitOrderby() {
65 return false;
68 public function functionalIndexes() {
69 return true;
72 public function unionSupportsOrderAndLimit() {
73 return false;
76 /**
77 * Usually aborts on failure
78 * @param string $server
79 * @param string $user
80 * @param string $password
81 * @param string $dbName
82 * @throws DBConnectionError
83 * @return bool|DatabaseBase|null
85 public function open( $server, $user, $password, $dbName ) {
86 # Test for driver support, to avoid suppressed fatal error
87 if ( !function_exists( 'sqlsrv_connect' ) ) {
88 throw new DBConnectionError(
89 $this,
90 "Microsoft SQL Server Native (sqlsrv) functions missing.
91 You can download the driver from: http://go.microsoft.com/fwlink/?LinkId=123470\n"
95 global $wgDBport, $wgDBWindowsAuthentication;
97 # e.g. the class is being loaded
98 if ( !strlen( $user ) ) {
99 return null;
102 $this->close();
103 $this->mServer = $server;
104 $this->mPort = $wgDBport;
105 $this->mUser = $user;
106 $this->mPassword = $password;
107 $this->mDBname = $dbName;
109 $connectionInfo = [];
111 if ( $dbName ) {
112 $connectionInfo['Database'] = $dbName;
115 // Decide which auth scenerio to use
116 // if we are using Windows auth, don't add credentials to $connectionInfo
117 if ( !$wgDBWindowsAuthentication ) {
118 $connectionInfo['UID'] = $user;
119 $connectionInfo['PWD'] = $password;
122 MediaWiki\suppressWarnings();
123 $this->mConn = sqlsrv_connect( $server, $connectionInfo );
124 MediaWiki\restoreWarnings();
126 if ( $this->mConn === false ) {
127 throw new DBConnectionError( $this, $this->lastError() );
130 $this->mOpened = true;
132 return $this->mConn;
136 * Closes a database connection, if it is open
137 * Returns success, true if already closed
138 * @return bool
140 protected function closeConnection() {
141 return sqlsrv_close( $this->mConn );
145 * @param bool|MssqlResultWrapper|resource $result
146 * @return bool|MssqlResultWrapper
148 protected function resultObject( $result ) {
149 if ( !$result ) {
150 return false;
151 } elseif ( $result instanceof MssqlResultWrapper ) {
152 return $result;
153 } elseif ( $result === true ) {
154 // Successful write query
155 return $result;
156 } else {
157 return new MssqlResultWrapper( $this, $result );
162 * @param string $sql
163 * @return bool|MssqlResult
164 * @throws DBUnexpectedError
166 protected function doQuery( $sql ) {
167 if ( $this->debug() ) {
168 wfDebug( "SQL: [$sql]\n" );
170 $this->offset = 0;
172 // several extensions seem to think that all databases support limits
173 // via LIMIT N after the WHERE clause well, MSSQL uses SELECT TOP N,
174 // so to catch any of those extensions we'll do a quick check for a
175 // LIMIT clause and pass $sql through $this->LimitToTopN() which parses
176 // the limit clause and passes the result to $this->limitResult();
177 if ( preg_match( '/\bLIMIT\s*/i', $sql ) ) {
178 // massage LIMIT -> TopN
179 $sql = $this->LimitToTopN( $sql );
182 // MSSQL doesn't have EXTRACT(epoch FROM XXX)
183 if ( preg_match( '#\bEXTRACT\s*?\(\s*?EPOCH\s+FROM\b#i', $sql, $matches ) ) {
184 // This is same as UNIX_TIMESTAMP, we need to calc # of seconds from 1970
185 $sql = str_replace( $matches[0], "DATEDIFF(s,CONVERT(datetime,'1/1/1970'),", $sql );
188 // perform query
190 // SQLSRV_CURSOR_STATIC is slower than SQLSRV_CURSOR_CLIENT_BUFFERED (one of the two is
191 // needed if we want to be able to seek around the result set), however CLIENT_BUFFERED
192 // has a bug in the sqlsrv driver where wchar_t types (such as nvarchar) that are empty
193 // strings make php throw a fatal error "Severe error translating Unicode"
194 if ( $this->mScrollableCursor ) {
195 $scrollArr = [ 'Scrollable' => SQLSRV_CURSOR_STATIC ];
196 } else {
197 $scrollArr = [];
200 if ( $this->mPrepareStatements ) {
201 // we do prepare + execute so we can get its field metadata for later usage if desired
202 $stmt = sqlsrv_prepare( $this->mConn, $sql, [], $scrollArr );
203 $success = sqlsrv_execute( $stmt );
204 } else {
205 $stmt = sqlsrv_query( $this->mConn, $sql, [], $scrollArr );
206 $success = (bool)$stmt;
209 if ( $this->mIgnoreDupKeyErrors ) {
210 // ignore duplicate key errors, but nothing else
211 // this emulates INSERT IGNORE in MySQL
212 if ( $success === false ) {
213 $errors = sqlsrv_errors( SQLSRV_ERR_ERRORS );
214 $success = true;
216 foreach ( $errors as $err ) {
217 if ( $err['SQLSTATE'] == '23000' && $err['code'] == '2601' ) {
218 continue; // duplicate key error caused by unique index
219 } elseif ( $err['SQLSTATE'] == '23000' && $err['code'] == '2627' ) {
220 continue; // duplicate key error caused by primary key
221 } elseif ( $err['SQLSTATE'] == '01000' && $err['code'] == '3621' ) {
222 continue; // generic "the statement has been terminated" error
225 $success = false; // getting here means we got an error we weren't expecting
226 break;
229 if ( $success ) {
230 $this->mAffectedRows = 0;
231 return $stmt;
236 if ( $success === false ) {
237 return false;
239 // remember number of rows affected
240 $this->mAffectedRows = sqlsrv_rows_affected( $stmt );
242 return $stmt;
245 public function freeResult( $res ) {
246 if ( $res instanceof ResultWrapper ) {
247 $res = $res->result;
250 sqlsrv_free_stmt( $res );
254 * @param MssqlResultWrapper $res
255 * @return stdClass
257 public function fetchObject( $res ) {
258 // $res is expected to be an instance of MssqlResultWrapper here
259 return $res->fetchObject();
263 * @param MssqlResultWrapper $res
264 * @return array
266 public function fetchRow( $res ) {
267 return $res->fetchRow();
271 * @param mixed $res
272 * @return int
274 public function numRows( $res ) {
275 if ( $res instanceof ResultWrapper ) {
276 $res = $res->result;
279 return sqlsrv_num_rows( $res );
283 * @param mixed $res
284 * @return int
286 public function numFields( $res ) {
287 if ( $res instanceof ResultWrapper ) {
288 $res = $res->result;
291 return sqlsrv_num_fields( $res );
295 * @param mixed $res
296 * @param int $n
297 * @return int
299 public function fieldName( $res, $n ) {
300 if ( $res instanceof ResultWrapper ) {
301 $res = $res->result;
304 return sqlsrv_field_metadata( $res )[$n]['Name'];
308 * This must be called after nextSequenceVal
309 * @return int|null
311 public function insertId() {
312 return $this->mInsertId;
316 * @param MssqlResultWrapper $res
317 * @param int $row
318 * @return bool
320 public function dataSeek( $res, $row ) {
321 return $res->seek( $row );
325 * @return string
327 public function lastError() {
328 $strRet = '';
329 $retErrors = sqlsrv_errors( SQLSRV_ERR_ALL );
330 if ( $retErrors != null ) {
331 foreach ( $retErrors as $arrError ) {
332 $strRet .= $this->formatError( $arrError ) . "\n";
334 } else {
335 $strRet = "No errors found";
338 return $strRet;
342 * @param array $err
343 * @return string
345 private function formatError( $err ) {
346 return '[SQLSTATE ' . $err['SQLSTATE'] . '][Error Code ' . $err['code'] . ']' . $err['message'];
350 * @return string
352 public function lastErrno() {
353 $err = sqlsrv_errors( SQLSRV_ERR_ALL );
354 if ( $err !== null && isset( $err[0] ) ) {
355 return $err[0]['code'];
356 } else {
357 return 0;
362 * @return int
364 public function affectedRows() {
365 return $this->mAffectedRows;
369 * SELECT wrapper
371 * @param mixed $table Array or string, table name(s) (prefix auto-added)
372 * @param mixed $vars Array or string, field name(s) to be retrieved
373 * @param mixed $conds Array or string, condition(s) for WHERE
374 * @param string $fname Calling function name (use __METHOD__) for logs/profiling
375 * @param array $options Associative array of options (e.g.
376 * array('GROUP BY' => 'page_title')), see Database::makeSelectOptions
377 * code for list of supported stuff
378 * @param array $join_conds Associative array of table join conditions
379 * (optional) (e.g. array( 'page' => array('LEFT JOIN','page_latest=rev_id') )
380 * @return mixed Database result resource (feed to Database::fetchObject
381 * or whatever), or false on failure
382 * @throws DBQueryError
383 * @throws DBUnexpectedError
384 * @throws Exception
386 public function select( $table, $vars, $conds = '', $fname = __METHOD__,
387 $options = [], $join_conds = []
389 $sql = $this->selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
390 if ( isset( $options['EXPLAIN'] ) ) {
391 try {
392 $this->mScrollableCursor = false;
393 $this->mPrepareStatements = false;
394 $this->query( "SET SHOWPLAN_ALL ON" );
395 $ret = $this->query( $sql, $fname );
396 $this->query( "SET SHOWPLAN_ALL OFF" );
397 } catch ( DBQueryError $dqe ) {
398 if ( isset( $options['FOR COUNT'] ) ) {
399 // likely don't have privs for SHOWPLAN, so run a select count instead
400 $this->query( "SET SHOWPLAN_ALL OFF" );
401 unset( $options['EXPLAIN'] );
402 $ret = $this->select(
403 $table,
404 'COUNT(*) AS EstimateRows',
405 $conds,
406 $fname,
407 $options,
408 $join_conds
410 } else {
411 // someone actually wanted the query plan instead of an est row count
412 // let them know of the error
413 $this->mScrollableCursor = true;
414 $this->mPrepareStatements = true;
415 throw $dqe;
418 $this->mScrollableCursor = true;
419 $this->mPrepareStatements = true;
420 return $ret;
422 return $this->query( $sql, $fname );
426 * SELECT wrapper
428 * @param mixed $table Array or string, table name(s) (prefix auto-added)
429 * @param mixed $vars Array or string, field name(s) to be retrieved
430 * @param mixed $conds Array or string, condition(s) for WHERE
431 * @param string $fname Calling function name (use __METHOD__) for logs/profiling
432 * @param array $options Associative array of options (e.g. array('GROUP BY' => 'page_title')),
433 * see Database::makeSelectOptions code for list of supported stuff
434 * @param array $join_conds Associative array of table join conditions (optional)
435 * (e.g. array( 'page' => array('LEFT JOIN','page_latest=rev_id') )
436 * @return string The SQL text
438 public function selectSQLText( $table, $vars, $conds = '', $fname = __METHOD__,
439 $options = [], $join_conds = []
441 if ( isset( $options['EXPLAIN'] ) ) {
442 unset( $options['EXPLAIN'] );
445 $sql = parent::selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
447 // try to rewrite aggregations of bit columns (currently MAX and MIN)
448 if ( strpos( $sql, 'MAX(' ) !== false || strpos( $sql, 'MIN(' ) !== false ) {
449 $bitColumns = [];
450 if ( is_array( $table ) ) {
451 foreach ( $table as $t ) {
452 $bitColumns += $this->getBitColumns( $this->tableName( $t ) );
454 } else {
455 $bitColumns = $this->getBitColumns( $this->tableName( $table ) );
458 foreach ( $bitColumns as $col => $info ) {
459 $replace = [
460 "MAX({$col})" => "MAX(CAST({$col} AS tinyint))",
461 "MIN({$col})" => "MIN(CAST({$col} AS tinyint))",
463 $sql = str_replace( array_keys( $replace ), array_values( $replace ), $sql );
467 return $sql;
470 public function deleteJoin( $delTable, $joinTable, $delVar, $joinVar, $conds,
471 $fname = __METHOD__
473 $this->mScrollableCursor = false;
474 try {
475 parent::deleteJoin( $delTable, $joinTable, $delVar, $joinVar, $conds, $fname );
476 } catch ( Exception $e ) {
477 $this->mScrollableCursor = true;
478 throw $e;
480 $this->mScrollableCursor = true;
483 public function delete( $table, $conds, $fname = __METHOD__ ) {
484 $this->mScrollableCursor = false;
485 try {
486 parent::delete( $table, $conds, $fname );
487 } catch ( Exception $e ) {
488 $this->mScrollableCursor = true;
489 throw $e;
491 $this->mScrollableCursor = true;
495 * Estimate rows in dataset
496 * Returns estimated count, based on SHOWPLAN_ALL output
497 * This is not necessarily an accurate estimate, so use sparingly
498 * Returns -1 if count cannot be found
499 * Takes same arguments as Database::select()
500 * @param string $table
501 * @param string $vars
502 * @param string $conds
503 * @param string $fname
504 * @param array $options
505 * @return int
507 public function estimateRowCount( $table, $vars = '*', $conds = '',
508 $fname = __METHOD__, $options = []
510 // http://msdn2.microsoft.com/en-us/library/aa259203.aspx
511 $options['EXPLAIN'] = true;
512 $options['FOR COUNT'] = true;
513 $res = $this->select( $table, $vars, $conds, $fname, $options );
515 $rows = -1;
516 if ( $res ) {
517 $row = $this->fetchRow( $res );
519 if ( isset( $row['EstimateRows'] ) ) {
520 $rows = (int)$row['EstimateRows'];
524 return $rows;
528 * Returns information about an index
529 * If errors are explicitly ignored, returns NULL on failure
530 * @param string $table
531 * @param string $index
532 * @param string $fname
533 * @return array|bool|null
535 public function indexInfo( $table, $index, $fname = __METHOD__ ) {
536 # This does not return the same info as MYSQL would, but that's OK
537 # because MediaWiki never uses the returned value except to check for
538 # the existance of indexes.
539 $sql = "sp_helpindex '" . $table . "'";
540 $res = $this->query( $sql, $fname );
541 if ( !$res ) {
542 return null;
545 $result = [];
546 foreach ( $res as $row ) {
547 if ( $row->index_name == $index ) {
548 $row->Non_unique = !stristr( $row->index_description, "unique" );
549 $cols = explode( ", ", $row->index_keys );
550 foreach ( $cols as $col ) {
551 $row->Column_name = trim( $col );
552 $result[] = clone $row;
554 } elseif ( $index == 'PRIMARY' && stristr( $row->index_description, 'PRIMARY' ) ) {
555 $row->Non_unique = 0;
556 $cols = explode( ", ", $row->index_keys );
557 foreach ( $cols as $col ) {
558 $row->Column_name = trim( $col );
559 $result[] = clone $row;
564 return empty( $result ) ? false : $result;
568 * INSERT wrapper, inserts an array into a table
570 * $arrToInsert may be a single associative array, or an array of these with numeric keys, for
571 * multi-row insert.
573 * Usually aborts on failure
574 * If errors are explicitly ignored, returns success
575 * @param string $table
576 * @param array $arrToInsert
577 * @param string $fname
578 * @param array $options
579 * @return bool
580 * @throws Exception
582 public function insert( $table, $arrToInsert, $fname = __METHOD__, $options = [] ) {
583 # No rows to insert, easy just return now
584 if ( !count( $arrToInsert ) ) {
585 return true;
588 if ( !is_array( $options ) ) {
589 $options = [ $options ];
592 $table = $this->tableName( $table );
594 if ( !( isset( $arrToInsert[0] ) && is_array( $arrToInsert[0] ) ) ) { // Not multi row
595 $arrToInsert = [ 0 => $arrToInsert ]; // make everything multi row compatible
598 // We know the table we're inserting into, get its identity column
599 $identity = null;
600 // strip matching square brackets and the db/schema from table name
601 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
602 $tableRaw = array_pop( $tableRawArr );
603 $res = $this->doQuery(
604 "SELECT NAME AS idColumn FROM SYS.IDENTITY_COLUMNS " .
605 "WHERE OBJECT_NAME(OBJECT_ID)='{$tableRaw}'"
607 if ( $res && sqlsrv_has_rows( $res ) ) {
608 // There is an identity for this table.
609 $identityArr = sqlsrv_fetch_array( $res, SQLSRV_FETCH_ASSOC );
610 $identity = array_pop( $identityArr );
612 sqlsrv_free_stmt( $res );
614 // Determine binary/varbinary fields so we can encode data as a hex string like 0xABCDEF
615 $binaryColumns = $this->getBinaryColumns( $table );
617 // INSERT IGNORE is not supported by SQL Server
618 // remove IGNORE from options list and set ignore flag to true
619 if ( in_array( 'IGNORE', $options ) ) {
620 $options = array_diff( $options, [ 'IGNORE' ] );
621 $this->mIgnoreDupKeyErrors = true;
624 foreach ( $arrToInsert as $a ) {
625 // start out with empty identity column, this is so we can return
626 // it as a result of the insert logic
627 $sqlPre = '';
628 $sqlPost = '';
629 $identityClause = '';
631 // if we have an identity column
632 if ( $identity ) {
633 // iterate through
634 foreach ( $a as $k => $v ) {
635 if ( $k == $identity ) {
636 if ( !is_null( $v ) ) {
637 // there is a value being passed to us,
638 // we need to turn on and off inserted identity
639 $sqlPre = "SET IDENTITY_INSERT $table ON;";
640 $sqlPost = ";SET IDENTITY_INSERT $table OFF;";
641 } else {
642 // we can't insert NULL into an identity column,
643 // so remove the column from the insert.
644 unset( $a[$k] );
649 // we want to output an identity column as result
650 $identityClause = "OUTPUT INSERTED.$identity ";
653 $keys = array_keys( $a );
655 // Build the actual query
656 $sql = $sqlPre . 'INSERT ' . implode( ' ', $options ) .
657 " INTO $table (" . implode( ',', $keys ) . ") $identityClause VALUES (";
659 $first = true;
660 foreach ( $a as $key => $value ) {
661 if ( isset( $binaryColumns[$key] ) ) {
662 $value = new MssqlBlob( $value );
664 if ( $first ) {
665 $first = false;
666 } else {
667 $sql .= ',';
669 if ( is_null( $value ) ) {
670 $sql .= 'null';
671 } elseif ( is_array( $value ) || is_object( $value ) ) {
672 if ( is_object( $value ) && $value instanceof Blob ) {
673 $sql .= $this->addQuotes( $value );
674 } else {
675 $sql .= $this->addQuotes( serialize( $value ) );
677 } else {
678 $sql .= $this->addQuotes( $value );
681 $sql .= ')' . $sqlPost;
683 // Run the query
684 $this->mScrollableCursor = false;
685 try {
686 $ret = $this->query( $sql );
687 } catch ( Exception $e ) {
688 $this->mScrollableCursor = true;
689 $this->mIgnoreDupKeyErrors = false;
690 throw $e;
692 $this->mScrollableCursor = true;
694 if ( !is_null( $identity ) ) {
695 // then we want to get the identity column value we were assigned and save it off
696 $row = $ret->fetchObject();
697 if ( is_object( $row ) ) {
698 $this->mInsertId = $row->$identity;
702 $this->mIgnoreDupKeyErrors = false;
703 return $ret;
707 * INSERT SELECT wrapper
708 * $varMap must be an associative array of the form array( 'dest1' => 'source1', ...)
709 * Source items may be literals rather than field names, but strings should
710 * be quoted with Database::addQuotes().
711 * @param string $destTable
712 * @param array|string $srcTable May be an array of tables.
713 * @param array $varMap
714 * @param array $conds May be "*" to copy the whole table.
715 * @param string $fname
716 * @param array $insertOptions
717 * @param array $selectOptions
718 * @return null|ResultWrapper
719 * @throws Exception
721 public function insertSelect( $destTable, $srcTable, $varMap, $conds, $fname = __METHOD__,
722 $insertOptions = [], $selectOptions = []
724 $this->mScrollableCursor = false;
725 try {
726 $ret = parent::insertSelect(
727 $destTable,
728 $srcTable,
729 $varMap,
730 $conds,
731 $fname,
732 $insertOptions,
733 $selectOptions
735 } catch ( Exception $e ) {
736 $this->mScrollableCursor = true;
737 throw $e;
739 $this->mScrollableCursor = true;
741 return $ret;
745 * UPDATE wrapper. Takes a condition array and a SET array.
747 * @param string $table Name of the table to UPDATE. This will be passed through
748 * DatabaseBase::tableName().
750 * @param array $values An array of values to SET. For each array element,
751 * the key gives the field name, and the value gives the data
752 * to set that field to. The data will be quoted by
753 * DatabaseBase::addQuotes().
755 * @param array $conds An array of conditions (WHERE). See
756 * DatabaseBase::select() for the details of the format of
757 * condition arrays. Use '*' to update all rows.
759 * @param string $fname The function name of the caller (from __METHOD__),
760 * for logging and profiling.
762 * @param array $options An array of UPDATE options, can be:
763 * - IGNORE: Ignore unique key conflicts
764 * - LOW_PRIORITY: MySQL-specific, see MySQL manual.
765 * @return bool
766 * @throws DBUnexpectedError
767 * @throws Exception
768 * @throws MWException
770 function update( $table, $values, $conds, $fname = __METHOD__, $options = [] ) {
771 $table = $this->tableName( $table );
772 $binaryColumns = $this->getBinaryColumns( $table );
774 $opts = $this->makeUpdateOptions( $options );
775 $sql = "UPDATE $opts $table SET " . $this->makeList( $values, LIST_SET, $binaryColumns );
777 if ( $conds !== [] && $conds !== '*' ) {
778 $sql .= " WHERE " . $this->makeList( $conds, LIST_AND, $binaryColumns );
781 $this->mScrollableCursor = false;
782 try {
783 $ret = $this->query( $sql );
784 } catch ( Exception $e ) {
785 $this->mScrollableCursor = true;
786 throw $e;
788 $this->mScrollableCursor = true;
789 return true;
793 * Makes an encoded list of strings from an array
794 * @param array $a Containing the data
795 * @param int $mode Constant
796 * - LIST_COMMA: comma separated, no field names
797 * - LIST_AND: ANDed WHERE clause (without the WHERE). See
798 * the documentation for $conds in DatabaseBase::select().
799 * - LIST_OR: ORed WHERE clause (without the WHERE)
800 * - LIST_SET: comma separated with field names, like a SET clause
801 * - LIST_NAMES: comma separated field names
802 * @param array $binaryColumns Contains a list of column names that are binary types
803 * This is a custom parameter only present for MS SQL.
805 * @throws MWException|DBUnexpectedError
806 * @return string
808 public function makeList( $a, $mode = LIST_COMMA, $binaryColumns = [] ) {
809 if ( !is_array( $a ) ) {
810 throw new DBUnexpectedError( $this,
811 'DatabaseBase::makeList called with incorrect parameters' );
814 if ( $mode != LIST_NAMES ) {
815 // In MS SQL, values need to be specially encoded when they are
816 // inserted into binary fields. Perform this necessary encoding
817 // for the specified set of columns.
818 foreach ( array_keys( $a ) as $field ) {
819 if ( !isset( $binaryColumns[$field] ) ) {
820 continue;
823 if ( is_array( $a[$field] ) ) {
824 foreach ( $a[$field] as &$v ) {
825 $v = new MssqlBlob( $v );
827 unset( $v );
828 } else {
829 $a[$field] = new MssqlBlob( $a[$field] );
834 return parent::makeList( $a, $mode );
838 * @param string $table
839 * @param string $field
840 * @return int Returns the size of a text field, or -1 for "unlimited"
842 public function textFieldSize( $table, $field ) {
843 $table = $this->tableName( $table );
844 $sql = "SELECT CHARACTER_MAXIMUM_LENGTH,DATA_TYPE FROM INFORMATION_SCHEMA.Columns
845 WHERE TABLE_NAME = '$table' AND COLUMN_NAME = '$field'";
846 $res = $this->query( $sql );
847 $row = $this->fetchRow( $res );
848 $size = -1;
849 if ( strtolower( $row['DATA_TYPE'] ) != 'text' ) {
850 $size = $row['CHARACTER_MAXIMUM_LENGTH'];
853 return $size;
857 * Construct a LIMIT query with optional offset
858 * This is used for query pages
860 * @param string $sql SQL query we will append the limit too
861 * @param int $limit The SQL limit
862 * @param bool|int $offset The SQL offset (default false)
863 * @return array|string
864 * @throws DBUnexpectedError
866 public function limitResult( $sql, $limit, $offset = false ) {
867 if ( $offset === false || $offset == 0 ) {
868 if ( strpos( $sql, "SELECT" ) === false ) {
869 return "TOP {$limit} " . $sql;
870 } else {
871 return preg_replace( '/\bSELECT(\s+DISTINCT)?\b/Dsi',
872 'SELECT$1 TOP ' . $limit, $sql, 1 );
874 } else {
875 // This one is fun, we need to pull out the select list as well as any ORDER BY clause
876 $select = $orderby = [];
877 $s1 = preg_match( '#SELECT\s+(.+?)\s+FROM#Dis', $sql, $select );
878 $s2 = preg_match( '#(ORDER BY\s+.+?)(\s*FOR XML .*)?$#Dis', $sql, $orderby );
879 $overOrder = $postOrder = '';
880 $first = $offset + 1;
881 $last = $offset + $limit;
882 $sub1 = 'sub_' . $this->mSubqueryId;
883 $sub2 = 'sub_' . ( $this->mSubqueryId + 1 );
884 $this->mSubqueryId += 2;
885 if ( !$s1 ) {
886 // wat
887 throw new DBUnexpectedError( $this, "Attempting to LIMIT a non-SELECT query\n" );
889 if ( !$s2 ) {
890 // no ORDER BY
891 $overOrder = 'ORDER BY (SELECT 1)';
892 } else {
893 if ( !isset( $orderby[2] ) || !$orderby[2] ) {
894 // don't need to strip it out if we're using a FOR XML clause
895 $sql = str_replace( $orderby[1], '', $sql );
897 $overOrder = $orderby[1];
898 $postOrder = ' ' . $overOrder;
900 $sql = "SELECT {$select[1]}
901 FROM (
902 SELECT ROW_NUMBER() OVER({$overOrder}) AS rowNumber, *
903 FROM ({$sql}) {$sub1}
904 ) {$sub2}
905 WHERE rowNumber BETWEEN {$first} AND {$last}{$postOrder}";
907 return $sql;
912 * If there is a limit clause, parse it, strip it, and pass the remaining
913 * SQL through limitResult() with the appropriate parameters. Not the
914 * prettiest solution, but better than building a whole new parser. This
915 * exists becase there are still too many extensions that don't use dynamic
916 * sql generation.
918 * @param string $sql
919 * @return array|mixed|string
921 public function LimitToTopN( $sql ) {
922 // Matches: LIMIT {[offset,] row_count | row_count OFFSET offset}
923 $pattern = '/\bLIMIT\s+((([0-9]+)\s*,\s*)?([0-9]+)(\s+OFFSET\s+([0-9]+))?)/i';
924 if ( preg_match( $pattern, $sql, $matches ) ) {
925 $row_count = $matches[4];
926 $offset = $matches[3] ?: $matches[6] ?: false;
928 // strip the matching LIMIT clause out
929 $sql = str_replace( $matches[0], '', $sql );
931 return $this->limitResult( $sql, $row_count, $offset );
934 return $sql;
938 * @return string Wikitext of a link to the server software's web site
940 public function getSoftwareLink() {
941 return "[{{int:version-db-mssql-url}} MS SQL Server]";
945 * @return string Version information from the database
947 public function getServerVersion() {
948 $server_info = sqlsrv_server_info( $this->mConn );
949 $version = 'Error';
950 if ( isset( $server_info['SQLServerVersion'] ) ) {
951 $version = $server_info['SQLServerVersion'];
954 return $version;
958 * @param string $table
959 * @param string $fname
960 * @return bool
962 public function tableExists( $table, $fname = __METHOD__ ) {
963 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
965 if ( $db !== false ) {
966 // remote database
967 wfDebug( "Attempting to call tableExists on a remote table" );
968 return false;
971 if ( $schema === false ) {
972 global $wgDBmwschema;
973 $schema = $wgDBmwschema;
976 $res = $this->query( "SELECT 1 FROM INFORMATION_SCHEMA.TABLES
977 WHERE TABLE_TYPE = 'BASE TABLE'
978 AND TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table'" );
980 if ( $res->numRows() ) {
981 return true;
982 } else {
983 return false;
988 * Query whether a given column exists in the mediawiki schema
989 * @param string $table
990 * @param string $field
991 * @param string $fname
992 * @return bool
994 public function fieldExists( $table, $field, $fname = __METHOD__ ) {
995 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
997 if ( $db !== false ) {
998 // remote database
999 wfDebug( "Attempting to call fieldExists on a remote table" );
1000 return false;
1003 $res = $this->query( "SELECT 1 FROM INFORMATION_SCHEMA.COLUMNS
1004 WHERE TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
1006 if ( $res->numRows() ) {
1007 return true;
1008 } else {
1009 return false;
1013 public function fieldInfo( $table, $field ) {
1014 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
1016 if ( $db !== false ) {
1017 // remote database
1018 wfDebug( "Attempting to call fieldInfo on a remote table" );
1019 return false;
1022 $res = $this->query( "SELECT * FROM INFORMATION_SCHEMA.COLUMNS
1023 WHERE TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
1025 $meta = $res->fetchRow();
1026 if ( $meta ) {
1027 return new MssqlField( $meta );
1030 return false;
1034 * Begin a transaction, committing any previously open transaction
1035 * @param string $fname
1037 protected function doBegin( $fname = __METHOD__ ) {
1038 sqlsrv_begin_transaction( $this->mConn );
1039 $this->mTrxLevel = 1;
1043 * End a transaction
1044 * @param string $fname
1046 protected function doCommit( $fname = __METHOD__ ) {
1047 sqlsrv_commit( $this->mConn );
1048 $this->mTrxLevel = 0;
1052 * Rollback a transaction.
1053 * No-op on non-transactional databases.
1054 * @param string $fname
1056 protected function doRollback( $fname = __METHOD__ ) {
1057 sqlsrv_rollback( $this->mConn );
1058 $this->mTrxLevel = 0;
1062 * Escapes a identifier for use inm SQL.
1063 * Throws an exception if it is invalid.
1064 * Reference: http://msdn.microsoft.com/en-us/library/aa224033%28v=SQL.80%29.aspx
1065 * @param string $identifier
1066 * @throws MWException
1067 * @return string
1069 private function escapeIdentifier( $identifier ) {
1070 if ( strlen( $identifier ) == 0 ) {
1071 throw new MWException( "An identifier must not be empty" );
1073 if ( strlen( $identifier ) > 128 ) {
1074 throw new MWException( "The identifier '$identifier' is too long (max. 128)" );
1076 if ( ( strpos( $identifier, '[' ) !== false )
1077 || ( strpos( $identifier, ']' ) !== false )
1079 // It may be allowed if you quoted with double quotation marks, but
1080 // that would break if QUOTED_IDENTIFIER is OFF
1081 throw new MWException( "Square brackets are not allowed in '$identifier'" );
1084 return "[$identifier]";
1088 * @param string $s
1089 * @return string
1091 public function strencode( $s ) {
1092 // Should not be called by us
1094 return str_replace( "'", "''", $s );
1098 * @param string|Blob $s
1099 * @return string
1101 public function addQuotes( $s ) {
1102 if ( $s instanceof MssqlBlob ) {
1103 return $s->fetch();
1104 } elseif ( $s instanceof Blob ) {
1105 // this shouldn't really ever be called, but it's here if needed
1106 // (and will quite possibly make the SQL error out)
1107 $blob = new MssqlBlob( $s->fetch() );
1108 return $blob->fetch();
1109 } else {
1110 if ( is_bool( $s ) ) {
1111 $s = $s ? 1 : 0;
1113 return parent::addQuotes( $s );
1118 * @param string $s
1119 * @return string
1121 public function addIdentifierQuotes( $s ) {
1122 // http://msdn.microsoft.com/en-us/library/aa223962.aspx
1123 return '[' . $s . ']';
1127 * @param string $name
1128 * @return bool
1130 public function isQuotedIdentifier( $name ) {
1131 return strlen( $name ) && $name[0] == '[' && substr( $name, -1, 1 ) == ']';
1135 * @param string $db
1136 * @return bool
1138 public function selectDB( $db ) {
1139 try {
1140 $this->mDBname = $db;
1141 $this->query( "USE $db" );
1142 return true;
1143 } catch ( Exception $e ) {
1144 return false;
1149 * @param array $options An associative array of options to be turned into
1150 * an SQL query, valid keys are listed in the function.
1151 * @return array
1153 public function makeSelectOptions( $options ) {
1154 $tailOpts = '';
1155 $startOpts = '';
1157 $noKeyOptions = [];
1158 foreach ( $options as $key => $option ) {
1159 if ( is_numeric( $key ) ) {
1160 $noKeyOptions[$option] = true;
1164 $tailOpts .= $this->makeGroupByWithHaving( $options );
1166 $tailOpts .= $this->makeOrderBy( $options );
1168 if ( isset( $noKeyOptions['DISTINCT'] ) || isset( $noKeyOptions['DISTINCTROW'] ) ) {
1169 $startOpts .= 'DISTINCT';
1172 if ( isset( $noKeyOptions['FOR XML'] ) ) {
1173 // used in group concat field emulation
1174 $tailOpts .= " FOR XML PATH('')";
1177 // we want this to be compatible with the output of parent::makeSelectOptions()
1178 return [ $startOpts, '', $tailOpts, '' ];
1182 * Get the type of the DBMS, as it appears in $wgDBtype.
1183 * @return string
1185 public function getType() {
1186 return 'mssql';
1190 * @param array $stringList
1191 * @return string
1193 public function buildConcat( $stringList ) {
1194 return implode( ' + ', $stringList );
1198 * Build a GROUP_CONCAT or equivalent statement for a query.
1199 * MS SQL doesn't have GROUP_CONCAT so we emulate it with other stuff (and boy is it nasty)
1201 * This is useful for combining a field for several rows into a single string.
1202 * NULL values will not appear in the output, duplicated values will appear,
1203 * and the resulting delimiter-separated values have no defined sort order.
1204 * Code using the results may need to use the PHP unique() or sort() methods.
1206 * @param string $delim Glue to bind the results together
1207 * @param string|array $table Table name
1208 * @param string $field Field name
1209 * @param string|array $conds Conditions
1210 * @param string|array $join_conds Join conditions
1211 * @return string SQL text
1212 * @since 1.23
1214 public function buildGroupConcatField( $delim, $table, $field, $conds = '',
1215 $join_conds = []
1217 $gcsq = 'gcsq_' . $this->mSubqueryId;
1218 $this->mSubqueryId++;
1220 $delimLen = strlen( $delim );
1221 $fld = "{$field} + {$this->addQuotes( $delim )}";
1222 $sql = "(SELECT LEFT({$field}, LEN({$field}) - {$delimLen}) FROM ("
1223 . $this->selectSQLText( $table, $fld, $conds, null, [ 'FOR XML' ], $join_conds )
1224 . ") {$gcsq} ({$field}))";
1226 return $sql;
1230 * @return string
1232 public function getSearchEngine() {
1233 return "SearchMssql";
1237 * Returns an associative array for fields that are of type varbinary, binary, or image
1238 * $table can be either a raw table name or passed through tableName() first
1239 * @param string $table
1240 * @return array
1242 private function getBinaryColumns( $table ) {
1243 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
1244 $tableRaw = array_pop( $tableRawArr );
1246 if ( $this->mBinaryColumnCache === null ) {
1247 $this->populateColumnCaches();
1250 return isset( $this->mBinaryColumnCache[$tableRaw] )
1251 ? $this->mBinaryColumnCache[$tableRaw]
1252 : [];
1256 * @param string $table
1257 * @return array
1259 private function getBitColumns( $table ) {
1260 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
1261 $tableRaw = array_pop( $tableRawArr );
1263 if ( $this->mBitColumnCache === null ) {
1264 $this->populateColumnCaches();
1267 return isset( $this->mBitColumnCache[$tableRaw] )
1268 ? $this->mBitColumnCache[$tableRaw]
1269 : [];
1272 private function populateColumnCaches() {
1273 $res = $this->select( 'INFORMATION_SCHEMA.COLUMNS', '*',
1275 'TABLE_CATALOG' => $this->mDBname,
1276 'TABLE_SCHEMA' => $this->mSchema,
1277 'DATA_TYPE' => [ 'varbinary', 'binary', 'image', 'bit' ]
1278 ] );
1280 $this->mBinaryColumnCache = [];
1281 $this->mBitColumnCache = [];
1282 foreach ( $res as $row ) {
1283 if ( $row->DATA_TYPE == 'bit' ) {
1284 $this->mBitColumnCache[$row->TABLE_NAME][$row->COLUMN_NAME] = $row;
1285 } else {
1286 $this->mBinaryColumnCache[$row->TABLE_NAME][$row->COLUMN_NAME] = $row;
1292 * @param string $name
1293 * @param string $format
1294 * @return string
1296 function tableName( $name, $format = 'quoted' ) {
1297 # Replace reserved words with better ones
1298 switch ( $name ) {
1299 case 'user':
1300 return $this->realTableName( 'mwuser', $format );
1301 default:
1302 return $this->realTableName( $name, $format );
1307 * call this instead of tableName() in the updater when renaming tables
1308 * @param string $name
1309 * @param string $format One of quoted, raw, or split
1310 * @return string
1312 function realTableName( $name, $format = 'quoted' ) {
1313 $table = parent::tableName( $name, $format );
1314 if ( $format == 'split' ) {
1315 // Used internally, we want the schema split off from the table name and returned
1316 // as a list with 3 elements (database, schema, table)
1317 $table = explode( '.', $table );
1318 while ( count( $table ) < 3 ) {
1319 array_unshift( $table, false );
1322 return $table;
1326 * Called in the installer and updater.
1327 * Probably doesn't need to be called anywhere else in the codebase.
1328 * @param bool|null $value
1329 * @return bool|null
1331 public function prepareStatements( $value = null ) {
1332 return wfSetVar( $this->mPrepareStatements, $value );
1336 * Called in the installer and updater.
1337 * Probably doesn't need to be called anywhere else in the codebase.
1338 * @param bool|null $value
1339 * @return bool|null
1341 public function scrollableCursor( $value = null ) {
1342 return wfSetVar( $this->mScrollableCursor, $value );
1344 } // end DatabaseMssql class
1347 * Utility class.
1349 * @ingroup Database
1351 class MssqlField implements Field {
1352 private $name, $tableName, $default, $max_length, $nullable, $type;
1354 function __construct( $info ) {
1355 $this->name = $info['COLUMN_NAME'];
1356 $this->tableName = $info['TABLE_NAME'];
1357 $this->default = $info['COLUMN_DEFAULT'];
1358 $this->max_length = $info['CHARACTER_MAXIMUM_LENGTH'];
1359 $this->nullable = !( strtolower( $info['IS_NULLABLE'] ) == 'no' );
1360 $this->type = $info['DATA_TYPE'];
1363 function name() {
1364 return $this->name;
1367 function tableName() {
1368 return $this->tableName;
1371 function defaultValue() {
1372 return $this->default;
1375 function maxLength() {
1376 return $this->max_length;
1379 function isNullable() {
1380 return $this->nullable;
1383 function type() {
1384 return $this->type;
1388 class MssqlBlob extends Blob {
1389 public function __construct( $data ) {
1390 if ( $data instanceof MssqlBlob ) {
1391 return $data;
1392 } elseif ( $data instanceof Blob ) {
1393 $this->mData = $data->fetch();
1394 } elseif ( is_array( $data ) && is_object( $data ) ) {
1395 $this->mData = serialize( $data );
1396 } else {
1397 $this->mData = $data;
1402 * Returns an unquoted hex representation of a binary string
1403 * for insertion into varbinary-type fields
1404 * @return string
1406 public function fetch() {
1407 if ( $this->mData === null ) {
1408 return 'null';
1411 $ret = '0x';
1412 $dataLength = strlen( $this->mData );
1413 for ( $i = 0; $i < $dataLength; $i++ ) {
1414 $ret .= bin2hex( pack( 'C', ord( $this->mData[$i] ) ) );
1417 return $ret;
1421 class MssqlResultWrapper extends ResultWrapper {
1422 private $mSeekTo = null;
1425 * @return stdClass|bool
1427 public function fetchObject() {
1428 $res = $this->result;
1430 if ( $this->mSeekTo !== null ) {
1431 $result = sqlsrv_fetch_object( $res, 'stdClass', [],
1432 SQLSRV_SCROLL_ABSOLUTE, $this->mSeekTo );
1433 $this->mSeekTo = null;
1434 } else {
1435 $result = sqlsrv_fetch_object( $res );
1438 // MediaWiki expects us to return boolean false when there are no more rows instead of null
1439 if ( $result === null ) {
1440 return false;
1443 return $result;
1447 * @return array|bool
1449 public function fetchRow() {
1450 $res = $this->result;
1452 if ( $this->mSeekTo !== null ) {
1453 $result = sqlsrv_fetch_array( $res, SQLSRV_FETCH_BOTH,
1454 SQLSRV_SCROLL_ABSOLUTE, $this->mSeekTo );
1455 $this->mSeekTo = null;
1456 } else {
1457 $result = sqlsrv_fetch_array( $res );
1460 // MediaWiki expects us to return boolean false when there are no more rows instead of null
1461 if ( $result === null ) {
1462 return false;
1465 return $result;
1469 * @param int $row
1470 * @return bool
1472 public function seek( $row ) {
1473 $res = $this->result;
1475 // check bounds
1476 $numRows = $this->db->numRows( $res );
1477 $row = intval( $row );
1479 if ( $numRows === 0 ) {
1480 return false;
1481 } elseif ( $row < 0 || $row > $numRows - 1 ) {
1482 return false;
1485 // Unlike MySQL, the seek actually happens on the next access
1486 $this->mSeekTo = $row;
1487 return true;