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
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>
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;
41 protected $mIgnoreErrors = [];
45 public function cascadingDeletes() {
49 public function cleanupTriggers() {
53 public function strictIPs() {
57 public function realTimestamps() {
61 public function implicitGroupby() {
65 public function implicitOrderby() {
69 public function functionalIndexes() {
73 public function unionSupportsOrderAndLimit() {
78 * Usually aborts on failure
79 * @param string $server
81 * @param string $password
82 * @param string $dbName
83 * @throws DBConnectionError
84 * @return bool|DatabaseBase|null
86 public function open( $server, $user, $password, $dbName ) {
87 # Test for driver support, to avoid suppressed fatal error
88 if ( !function_exists( 'sqlsrv_connect' ) ) {
89 throw new DBConnectionError(
91 "Microsoft SQL Server Native (sqlsrv) functions missing.
92 You can download the driver from: http://go.microsoft.com/fwlink/?LinkId=123470\n"
96 global $wgDBport, $wgDBWindowsAuthentication;
98 # e.g. the class is being loaded
99 if ( !strlen( $user ) ) {
104 $this->mServer
= $server;
105 $this->mPort
= $wgDBport;
106 $this->mUser
= $user;
107 $this->mPassword
= $password;
108 $this->mDBname
= $dbName;
110 $connectionInfo = [];
113 $connectionInfo['Database'] = $dbName;
116 // Decide which auth scenerio to use
117 // if we are using Windows auth, don't add credentials to $connectionInfo
118 if ( !$wgDBWindowsAuthentication ) {
119 $connectionInfo['UID'] = $user;
120 $connectionInfo['PWD'] = $password;
123 MediaWiki\
suppressWarnings();
124 $this->mConn
= sqlsrv_connect( $server, $connectionInfo );
125 MediaWiki\restoreWarnings
();
127 if ( $this->mConn
=== false ) {
128 throw new DBConnectionError( $this, $this->lastError() );
131 $this->mOpened
= true;
137 * Closes a database connection, if it is open
138 * Returns success, true if already closed
141 protected function closeConnection() {
142 return sqlsrv_close( $this->mConn
);
146 * @param bool|MssqlResultWrapper|resource $result
147 * @return bool|MssqlResultWrapper
149 protected function resultObject( $result ) {
152 } elseif ( $result instanceof MssqlResultWrapper
) {
154 } elseif ( $result === true ) {
155 // Successful write query
158 return new MssqlResultWrapper( $this, $result );
164 * @return bool|MssqlResult
165 * @throws DBUnexpectedError
167 protected function doQuery( $sql ) {
168 if ( $this->debug() ) {
169 wfDebug( "SQL: [$sql]\n" );
173 // several extensions seem to think that all databases support limits
174 // via LIMIT N after the WHERE clause well, MSSQL uses SELECT TOP N,
175 // so to catch any of those extensions we'll do a quick check for a
176 // LIMIT clause and pass $sql through $this->LimitToTopN() which parses
177 // the limit clause and passes the result to $this->limitResult();
178 if ( preg_match( '/\bLIMIT\s*/i', $sql ) ) {
179 // massage LIMIT -> TopN
180 $sql = $this->LimitToTopN( $sql );
183 // MSSQL doesn't have EXTRACT(epoch FROM XXX)
184 if ( preg_match( '#\bEXTRACT\s*?\(\s*?EPOCH\s+FROM\b#i', $sql, $matches ) ) {
185 // This is same as UNIX_TIMESTAMP, we need to calc # of seconds from 1970
186 $sql = str_replace( $matches[0], "DATEDIFF(s,CONVERT(datetime,'1/1/1970'),", $sql );
191 // SQLSRV_CURSOR_STATIC is slower than SQLSRV_CURSOR_CLIENT_BUFFERED (one of the two is
192 // needed if we want to be able to seek around the result set), however CLIENT_BUFFERED
193 // has a bug in the sqlsrv driver where wchar_t types (such as nvarchar) that are empty
194 // strings make php throw a fatal error "Severe error translating Unicode"
195 if ( $this->mScrollableCursor
) {
196 $scrollArr = [ 'Scrollable' => SQLSRV_CURSOR_STATIC
];
201 if ( $this->mPrepareStatements
) {
202 // we do prepare + execute so we can get its field metadata for later usage if desired
203 $stmt = sqlsrv_prepare( $this->mConn
, $sql, [], $scrollArr );
204 $success = sqlsrv_execute( $stmt );
206 $stmt = sqlsrv_query( $this->mConn
, $sql, [], $scrollArr );
207 $success = (bool)$stmt;
210 // make a copy so that anything we add below does not get reflected in future queries
211 $ignoreErrors = $this->mIgnoreErrors
;
213 if ( $this->mIgnoreDupKeyErrors
) {
214 // ignore duplicate key errors
215 // this emulates INSERT IGNORE in MySQL
216 $ignoreErrors[] = '2601'; // duplicate key error caused by unique index
217 $ignoreErrors[] = '2627'; // duplicate key error caused by primary key
218 $ignoreErrors[] = '3621'; // generic "the statement has been terminated" error
221 if ( $success === false ) {
222 $errors = sqlsrv_errors();
225 foreach ( $errors as $err ) {
226 if ( !in_array( $err['code'], $ignoreErrors ) ) {
232 if ( $success === false ) {
236 // remember number of rows affected
237 $this->mAffectedRows
= sqlsrv_rows_affected( $stmt );
242 public function freeResult( $res ) {
243 if ( $res instanceof ResultWrapper
) {
247 sqlsrv_free_stmt( $res );
251 * @param MssqlResultWrapper $res
254 public function fetchObject( $res ) {
255 // $res is expected to be an instance of MssqlResultWrapper here
256 return $res->fetchObject();
260 * @param MssqlResultWrapper $res
263 public function fetchRow( $res ) {
264 return $res->fetchRow();
271 public function numRows( $res ) {
272 if ( $res instanceof ResultWrapper
) {
276 $ret = sqlsrv_num_rows( $res );
278 if ( $ret === false ) {
279 // we cannot get an amount of rows from this cursor type
280 // has_rows returns bool true/false if the result has rows
281 $ret = (int)sqlsrv_has_rows( $res );
291 public function numFields( $res ) {
292 if ( $res instanceof ResultWrapper
) {
296 return sqlsrv_num_fields( $res );
304 public function fieldName( $res, $n ) {
305 if ( $res instanceof ResultWrapper
) {
309 return sqlsrv_field_metadata( $res )[$n]['Name'];
313 * This must be called after nextSequenceVal
316 public function insertId() {
317 return $this->mInsertId
;
321 * @param MssqlResultWrapper $res
325 public function dataSeek( $res, $row ) {
326 return $res->seek( $row );
332 public function lastError() {
334 $retErrors = sqlsrv_errors( SQLSRV_ERR_ALL
);
335 if ( $retErrors != null ) {
336 foreach ( $retErrors as $arrError ) {
337 $strRet .= $this->formatError( $arrError ) . "\n";
340 $strRet = "No errors found";
350 private function formatError( $err ) {
351 return '[SQLSTATE ' . $err['SQLSTATE'] . '][Error Code ' . $err['code'] . ']' . $err['message'];
357 public function lastErrno() {
358 $err = sqlsrv_errors( SQLSRV_ERR_ALL
);
359 if ( $err !== null && isset( $err[0] ) ) {
360 return $err[0]['code'];
369 public function affectedRows() {
370 return $this->mAffectedRows
;
376 * @param mixed $table Array or string, table name(s) (prefix auto-added)
377 * @param mixed $vars Array or string, field name(s) to be retrieved
378 * @param mixed $conds Array or string, condition(s) for WHERE
379 * @param string $fname Calling function name (use __METHOD__) for logs/profiling
380 * @param array $options Associative array of options (e.g.
381 * array('GROUP BY' => 'page_title')), see Database::makeSelectOptions
382 * code for list of supported stuff
383 * @param array $join_conds Associative array of table join conditions
384 * (optional) (e.g. array( 'page' => array('LEFT JOIN','page_latest=rev_id') )
385 * @return mixed Database result resource (feed to Database::fetchObject
386 * or whatever), or false on failure
387 * @throws DBQueryError
388 * @throws DBUnexpectedError
391 public function select( $table, $vars, $conds = '', $fname = __METHOD__
,
392 $options = [], $join_conds = []
394 $sql = $this->selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
395 if ( isset( $options['EXPLAIN'] ) ) {
397 $this->mScrollableCursor
= false;
398 $this->mPrepareStatements
= false;
399 $this->query( "SET SHOWPLAN_ALL ON" );
400 $ret = $this->query( $sql, $fname );
401 $this->query( "SET SHOWPLAN_ALL OFF" );
402 } catch ( DBQueryError
$dqe ) {
403 if ( isset( $options['FOR COUNT'] ) ) {
404 // likely don't have privs for SHOWPLAN, so run a select count instead
405 $this->query( "SET SHOWPLAN_ALL OFF" );
406 unset( $options['EXPLAIN'] );
407 $ret = $this->select(
409 'COUNT(*) AS EstimateRows',
416 // someone actually wanted the query plan instead of an est row count
417 // let them know of the error
418 $this->mScrollableCursor
= true;
419 $this->mPrepareStatements
= true;
423 $this->mScrollableCursor
= true;
424 $this->mPrepareStatements
= true;
427 return $this->query( $sql, $fname );
433 * @param mixed $table Array or string, table name(s) (prefix auto-added)
434 * @param mixed $vars Array or string, field name(s) to be retrieved
435 * @param mixed $conds Array or string, condition(s) for WHERE
436 * @param string $fname Calling function name (use __METHOD__) for logs/profiling
437 * @param array $options Associative array of options (e.g. array('GROUP BY' => 'page_title')),
438 * see Database::makeSelectOptions code for list of supported stuff
439 * @param array $join_conds Associative array of table join conditions (optional)
440 * (e.g. array( 'page' => array('LEFT JOIN','page_latest=rev_id') )
441 * @return string The SQL text
443 public function selectSQLText( $table, $vars, $conds = '', $fname = __METHOD__
,
444 $options = [], $join_conds = []
446 if ( isset( $options['EXPLAIN'] ) ) {
447 unset( $options['EXPLAIN'] );
450 $sql = parent
::selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
452 // try to rewrite aggregations of bit columns (currently MAX and MIN)
453 if ( strpos( $sql, 'MAX(' ) !== false ||
strpos( $sql, 'MIN(' ) !== false ) {
455 if ( is_array( $table ) ) {
456 foreach ( $table as $t ) {
457 $bitColumns +
= $this->getBitColumns( $this->tableName( $t ) );
460 $bitColumns = $this->getBitColumns( $this->tableName( $table ) );
463 foreach ( $bitColumns as $col => $info ) {
465 "MAX({$col})" => "MAX(CAST({$col} AS tinyint))",
466 "MIN({$col})" => "MIN(CAST({$col} AS tinyint))",
468 $sql = str_replace( array_keys( $replace ), array_values( $replace ), $sql );
475 public function deleteJoin( $delTable, $joinTable, $delVar, $joinVar, $conds,
478 $this->mScrollableCursor
= false;
480 parent
::deleteJoin( $delTable, $joinTable, $delVar, $joinVar, $conds, $fname );
481 } catch ( Exception
$e ) {
482 $this->mScrollableCursor
= true;
485 $this->mScrollableCursor
= true;
488 public function delete( $table, $conds, $fname = __METHOD__
) {
489 $this->mScrollableCursor
= false;
491 parent
::delete( $table, $conds, $fname );
492 } catch ( Exception
$e ) {
493 $this->mScrollableCursor
= true;
496 $this->mScrollableCursor
= true;
500 * Estimate rows in dataset
501 * Returns estimated count, based on SHOWPLAN_ALL output
502 * This is not necessarily an accurate estimate, so use sparingly
503 * Returns -1 if count cannot be found
504 * Takes same arguments as Database::select()
505 * @param string $table
506 * @param string $vars
507 * @param string $conds
508 * @param string $fname
509 * @param array $options
512 public function estimateRowCount( $table, $vars = '*', $conds = '',
513 $fname = __METHOD__
, $options = []
515 // http://msdn2.microsoft.com/en-us/library/aa259203.aspx
516 $options['EXPLAIN'] = true;
517 $options['FOR COUNT'] = true;
518 $res = $this->select( $table, $vars, $conds, $fname, $options );
522 $row = $this->fetchRow( $res );
524 if ( isset( $row['EstimateRows'] ) ) {
525 $rows = (int)$row['EstimateRows'];
533 * Returns information about an index
534 * If errors are explicitly ignored, returns NULL on failure
535 * @param string $table
536 * @param string $index
537 * @param string $fname
538 * @return array|bool|null
540 public function indexInfo( $table, $index, $fname = __METHOD__
) {
541 # This does not return the same info as MYSQL would, but that's OK
542 # because MediaWiki never uses the returned value except to check for
543 # the existance of indexes.
544 $sql = "sp_helpindex '" . $this->tableName( $table ) . "'";
545 $res = $this->query( $sql, $fname );
552 foreach ( $res as $row ) {
553 if ( $row->index_name
== $index ) {
554 $row->Non_unique
= !stristr( $row->index_description
, "unique" );
555 $cols = explode( ", ", $row->index_keys
);
556 foreach ( $cols as $col ) {
557 $row->Column_name
= trim( $col );
558 $result[] = clone $row;
560 } elseif ( $index == 'PRIMARY' && stristr( $row->index_description
, 'PRIMARY' ) ) {
561 $row->Non_unique
= 0;
562 $cols = explode( ", ", $row->index_keys
);
563 foreach ( $cols as $col ) {
564 $row->Column_name
= trim( $col );
565 $result[] = clone $row;
570 return empty( $result ) ?
false : $result;
574 * INSERT wrapper, inserts an array into a table
576 * $arrToInsert may be a single associative array, or an array of these with numeric keys, for
579 * Usually aborts on failure
580 * If errors are explicitly ignored, returns success
581 * @param string $table
582 * @param array $arrToInsert
583 * @param string $fname
584 * @param array $options
588 public function insert( $table, $arrToInsert, $fname = __METHOD__
, $options = [] ) {
589 # No rows to insert, easy just return now
590 if ( !count( $arrToInsert ) ) {
594 if ( !is_array( $options ) ) {
595 $options = [ $options ];
598 $table = $this->tableName( $table );
600 if ( !( isset( $arrToInsert[0] ) && is_array( $arrToInsert[0] ) ) ) { // Not multi row
601 $arrToInsert = [ 0 => $arrToInsert ]; // make everything multi row compatible
604 // We know the table we're inserting into, get its identity column
606 // strip matching square brackets and the db/schema from table name
607 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
608 $tableRaw = array_pop( $tableRawArr );
609 $res = $this->doQuery(
610 "SELECT NAME AS idColumn FROM SYS.IDENTITY_COLUMNS " .
611 "WHERE OBJECT_NAME(OBJECT_ID)='{$tableRaw}'"
613 if ( $res && sqlsrv_has_rows( $res ) ) {
614 // There is an identity for this table.
615 $identityArr = sqlsrv_fetch_array( $res, SQLSRV_FETCH_ASSOC
);
616 $identity = array_pop( $identityArr );
618 sqlsrv_free_stmt( $res );
620 // Determine binary/varbinary fields so we can encode data as a hex string like 0xABCDEF
621 $binaryColumns = $this->getBinaryColumns( $table );
623 // INSERT IGNORE is not supported by SQL Server
624 // remove IGNORE from options list and set ignore flag to true
625 if ( in_array( 'IGNORE', $options ) ) {
626 $options = array_diff( $options, [ 'IGNORE' ] );
627 $this->mIgnoreDupKeyErrors
= true;
630 foreach ( $arrToInsert as $a ) {
631 // start out with empty identity column, this is so we can return
632 // it as a result of the insert logic
635 $identityClause = '';
637 // if we have an identity column
640 foreach ( $a as $k => $v ) {
641 if ( $k == $identity ) {
642 if ( !is_null( $v ) ) {
643 // there is a value being passed to us,
644 // we need to turn on and off inserted identity
645 $sqlPre = "SET IDENTITY_INSERT $table ON;";
646 $sqlPost = ";SET IDENTITY_INSERT $table OFF;";
648 // we can't insert NULL into an identity column,
649 // so remove the column from the insert.
655 // we want to output an identity column as result
656 $identityClause = "OUTPUT INSERTED.$identity ";
659 $keys = array_keys( $a );
661 // Build the actual query
662 $sql = $sqlPre . 'INSERT ' . implode( ' ', $options ) .
663 " INTO $table (" . implode( ',', $keys ) . ") $identityClause VALUES (";
666 foreach ( $a as $key => $value ) {
667 if ( isset( $binaryColumns[$key] ) ) {
668 $value = new MssqlBlob( $value );
675 if ( is_null( $value ) ) {
677 } elseif ( is_array( $value ) ||
is_object( $value ) ) {
678 if ( is_object( $value ) && $value instanceof Blob
) {
679 $sql .= $this->addQuotes( $value );
681 $sql .= $this->addQuotes( serialize( $value ) );
684 $sql .= $this->addQuotes( $value );
687 $sql .= ')' . $sqlPost;
690 $this->mScrollableCursor
= false;
692 $ret = $this->query( $sql );
693 } catch ( Exception
$e ) {
694 $this->mScrollableCursor
= true;
695 $this->mIgnoreDupKeyErrors
= false;
698 $this->mScrollableCursor
= true;
700 if ( !is_null( $identity ) ) {
701 // then we want to get the identity column value we were assigned and save it off
702 $row = $ret->fetchObject();
703 if ( is_object( $row ) ) {
704 $this->mInsertId
= $row->$identity;
706 // it seems that mAffectedRows is -1 sometimes when OUTPUT INSERTED.identity is used
707 // if we got an identity back, we know for sure a row was affected, so adjust that here
708 if ( $this->mAffectedRows
== -1 ) {
709 $this->mAffectedRows
= 1;
714 $this->mIgnoreDupKeyErrors
= false;
719 * INSERT SELECT wrapper
720 * $varMap must be an associative array of the form array( 'dest1' => 'source1', ...)
721 * Source items may be literals rather than field names, but strings should
722 * be quoted with Database::addQuotes().
723 * @param string $destTable
724 * @param array|string $srcTable May be an array of tables.
725 * @param array $varMap
726 * @param array $conds May be "*" to copy the whole table.
727 * @param string $fname
728 * @param array $insertOptions
729 * @param array $selectOptions
730 * @return null|ResultWrapper
733 public function insertSelect( $destTable, $srcTable, $varMap, $conds, $fname = __METHOD__
,
734 $insertOptions = [], $selectOptions = []
736 $this->mScrollableCursor
= false;
738 $ret = parent
::insertSelect(
747 } catch ( Exception
$e ) {
748 $this->mScrollableCursor
= true;
751 $this->mScrollableCursor
= true;
757 * UPDATE wrapper. Takes a condition array and a SET array.
759 * @param string $table Name of the table to UPDATE. This will be passed through
760 * DatabaseBase::tableName().
762 * @param array $values An array of values to SET. For each array element,
763 * the key gives the field name, and the value gives the data
764 * to set that field to. The data will be quoted by
765 * DatabaseBase::addQuotes().
767 * @param array $conds An array of conditions (WHERE). See
768 * DatabaseBase::select() for the details of the format of
769 * condition arrays. Use '*' to update all rows.
771 * @param string $fname The function name of the caller (from __METHOD__),
772 * for logging and profiling.
774 * @param array $options An array of UPDATE options, can be:
775 * - IGNORE: Ignore unique key conflicts
776 * - LOW_PRIORITY: MySQL-specific, see MySQL manual.
778 * @throws DBUnexpectedError
780 * @throws MWException
782 function update( $table, $values, $conds, $fname = __METHOD__
, $options = [] ) {
783 $table = $this->tableName( $table );
784 $binaryColumns = $this->getBinaryColumns( $table );
786 $opts = $this->makeUpdateOptions( $options );
787 $sql = "UPDATE $opts $table SET " . $this->makeList( $values, LIST_SET
, $binaryColumns );
789 if ( $conds !== [] && $conds !== '*' ) {
790 $sql .= " WHERE " . $this->makeList( $conds, LIST_AND
, $binaryColumns );
793 $this->mScrollableCursor
= false;
795 $ret = $this->query( $sql );
796 } catch ( Exception
$e ) {
797 $this->mScrollableCursor
= true;
800 $this->mScrollableCursor
= true;
805 * Makes an encoded list of strings from an array
806 * @param array $a Containing the data
807 * @param int $mode Constant
808 * - LIST_COMMA: comma separated, no field names
809 * - LIST_AND: ANDed WHERE clause (without the WHERE). See
810 * the documentation for $conds in DatabaseBase::select().
811 * - LIST_OR: ORed WHERE clause (without the WHERE)
812 * - LIST_SET: comma separated with field names, like a SET clause
813 * - LIST_NAMES: comma separated field names
814 * @param array $binaryColumns Contains a list of column names that are binary types
815 * This is a custom parameter only present for MS SQL.
817 * @throws MWException|DBUnexpectedError
820 public function makeList( $a, $mode = LIST_COMMA
, $binaryColumns = [] ) {
821 if ( !is_array( $a ) ) {
822 throw new DBUnexpectedError( $this,
823 'DatabaseBase::makeList called with incorrect parameters' );
826 if ( $mode != LIST_NAMES
) {
827 // In MS SQL, values need to be specially encoded when they are
828 // inserted into binary fields. Perform this necessary encoding
829 // for the specified set of columns.
830 foreach ( array_keys( $a ) as $field ) {
831 if ( !isset( $binaryColumns[$field] ) ) {
835 if ( is_array( $a[$field] ) ) {
836 foreach ( $a[$field] as &$v ) {
837 $v = new MssqlBlob( $v );
841 $a[$field] = new MssqlBlob( $a[$field] );
846 return parent
::makeList( $a, $mode );
850 * @param string $table
851 * @param string $field
852 * @return int Returns the size of a text field, or -1 for "unlimited"
854 public function textFieldSize( $table, $field ) {
855 $table = $this->tableName( $table );
856 $sql = "SELECT CHARACTER_MAXIMUM_LENGTH,DATA_TYPE FROM INFORMATION_SCHEMA.Columns
857 WHERE TABLE_NAME = '$table' AND COLUMN_NAME = '$field'";
858 $res = $this->query( $sql );
859 $row = $this->fetchRow( $res );
861 if ( strtolower( $row['DATA_TYPE'] ) != 'text' ) {
862 $size = $row['CHARACTER_MAXIMUM_LENGTH'];
869 * Construct a LIMIT query with optional offset
870 * This is used for query pages
872 * @param string $sql SQL query we will append the limit too
873 * @param int $limit The SQL limit
874 * @param bool|int $offset The SQL offset (default false)
875 * @return array|string
876 * @throws DBUnexpectedError
878 public function limitResult( $sql, $limit, $offset = false ) {
879 if ( $offset === false ||
$offset == 0 ) {
880 if ( strpos( $sql, "SELECT" ) === false ) {
881 return "TOP {$limit} " . $sql;
883 return preg_replace( '/\bSELECT(\s+DISTINCT)?\b/Dsi',
884 'SELECT$1 TOP ' . $limit, $sql, 1 );
887 // This one is fun, we need to pull out the select list as well as any ORDER BY clause
888 $select = $orderby = [];
889 $s1 = preg_match( '#SELECT\s+(.+?)\s+FROM#Dis', $sql, $select );
890 $s2 = preg_match( '#(ORDER BY\s+.+?)(\s*FOR XML .*)?$#Dis', $sql, $orderby );
891 $overOrder = $postOrder = '';
892 $first = $offset +
1;
893 $last = $offset +
$limit;
894 $sub1 = 'sub_' . $this->mSubqueryId
;
895 $sub2 = 'sub_' . ( $this->mSubqueryId +
1 );
896 $this->mSubqueryId +
= 2;
899 throw new DBUnexpectedError( $this, "Attempting to LIMIT a non-SELECT query\n" );
903 $overOrder = 'ORDER BY (SELECT 1)';
905 if ( !isset( $orderby[2] ) ||
!$orderby[2] ) {
906 // don't need to strip it out if we're using a FOR XML clause
907 $sql = str_replace( $orderby[1], '', $sql );
909 $overOrder = $orderby[1];
910 $postOrder = ' ' . $overOrder;
912 $sql = "SELECT {$select[1]}
914 SELECT ROW_NUMBER() OVER({$overOrder}) AS rowNumber, *
915 FROM ({$sql}) {$sub1}
917 WHERE rowNumber BETWEEN {$first} AND {$last}{$postOrder}";
924 * If there is a limit clause, parse it, strip it, and pass the remaining
925 * SQL through limitResult() with the appropriate parameters. Not the
926 * prettiest solution, but better than building a whole new parser. This
927 * exists becase there are still too many extensions that don't use dynamic
931 * @return array|mixed|string
933 public function LimitToTopN( $sql ) {
934 // Matches: LIMIT {[offset,] row_count | row_count OFFSET offset}
935 $pattern = '/\bLIMIT\s+((([0-9]+)\s*,\s*)?([0-9]+)(\s+OFFSET\s+([0-9]+))?)/i';
936 if ( preg_match( $pattern, $sql, $matches ) ) {
937 $row_count = $matches[4];
938 $offset = $matches[3] ?
: $matches[6] ?
: false;
940 // strip the matching LIMIT clause out
941 $sql = str_replace( $matches[0], '', $sql );
943 return $this->limitResult( $sql, $row_count, $offset );
950 * @return string Wikitext of a link to the server software's web site
952 public function getSoftwareLink() {
953 return "[{{int:version-db-mssql-url}} MS SQL Server]";
957 * @return string Version information from the database
959 public function getServerVersion() {
960 $server_info = sqlsrv_server_info( $this->mConn
);
962 if ( isset( $server_info['SQLServerVersion'] ) ) {
963 $version = $server_info['SQLServerVersion'];
970 * @param string $table
971 * @param string $fname
974 public function tableExists( $table, $fname = __METHOD__
) {
975 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
977 if ( $db !== false ) {
979 wfDebug( "Attempting to call tableExists on a remote table" );
983 if ( $schema === false ) {
984 global $wgDBmwschema;
985 $schema = $wgDBmwschema;
988 $res = $this->query( "SELECT 1 FROM INFORMATION_SCHEMA.TABLES
989 WHERE TABLE_TYPE = 'BASE TABLE'
990 AND TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table'" );
992 if ( $res->numRows() ) {
1000 * Query whether a given column exists in the mediawiki schema
1001 * @param string $table
1002 * @param string $field
1003 * @param string $fname
1006 public function fieldExists( $table, $field, $fname = __METHOD__
) {
1007 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
1009 if ( $db !== false ) {
1011 wfDebug( "Attempting to call fieldExists on a remote table" );
1015 $res = $this->query( "SELECT 1 FROM INFORMATION_SCHEMA.COLUMNS
1016 WHERE TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
1018 if ( $res->numRows() ) {
1025 public function fieldInfo( $table, $field ) {
1026 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
1028 if ( $db !== false ) {
1030 wfDebug( "Attempting to call fieldInfo on a remote table" );
1034 $res = $this->query( "SELECT * FROM INFORMATION_SCHEMA.COLUMNS
1035 WHERE TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
1037 $meta = $res->fetchRow();
1039 return new MssqlField( $meta );
1046 * Begin a transaction, committing any previously open transaction
1047 * @param string $fname
1049 protected function doBegin( $fname = __METHOD__
) {
1050 sqlsrv_begin_transaction( $this->mConn
);
1051 $this->mTrxLevel
= 1;
1056 * @param string $fname
1058 protected function doCommit( $fname = __METHOD__
) {
1059 sqlsrv_commit( $this->mConn
);
1060 $this->mTrxLevel
= 0;
1064 * Rollback a transaction.
1065 * No-op on non-transactional databases.
1066 * @param string $fname
1068 protected function doRollback( $fname = __METHOD__
) {
1069 sqlsrv_rollback( $this->mConn
);
1070 $this->mTrxLevel
= 0;
1074 * Escapes a identifier for use inm SQL.
1075 * Throws an exception if it is invalid.
1076 * Reference: http://msdn.microsoft.com/en-us/library/aa224033%28v=SQL.80%29.aspx
1077 * @param string $identifier
1078 * @throws MWException
1081 private function escapeIdentifier( $identifier ) {
1082 if ( strlen( $identifier ) == 0 ) {
1083 throw new MWException( "An identifier must not be empty" );
1085 if ( strlen( $identifier ) > 128 ) {
1086 throw new MWException( "The identifier '$identifier' is too long (max. 128)" );
1088 if ( ( strpos( $identifier, '[' ) !== false )
1089 ||
( strpos( $identifier, ']' ) !== false )
1091 // It may be allowed if you quoted with double quotation marks, but
1092 // that would break if QUOTED_IDENTIFIER is OFF
1093 throw new MWException( "Square brackets are not allowed in '$identifier'" );
1096 return "[$identifier]";
1103 public function strencode( $s ) {
1104 // Should not be called by us
1106 return str_replace( "'", "''", $s );
1110 * @param string|Blob $s
1113 public function addQuotes( $s ) {
1114 if ( $s instanceof MssqlBlob
) {
1116 } elseif ( $s instanceof Blob
) {
1117 // this shouldn't really ever be called, but it's here if needed
1118 // (and will quite possibly make the SQL error out)
1119 $blob = new MssqlBlob( $s->fetch() );
1120 return $blob->fetch();
1122 if ( is_bool( $s ) ) {
1125 return parent
::addQuotes( $s );
1133 public function addIdentifierQuotes( $s ) {
1134 // http://msdn.microsoft.com/en-us/library/aa223962.aspx
1135 return '[' . $s . ']';
1139 * @param string $name
1142 public function isQuotedIdentifier( $name ) {
1143 return strlen( $name ) && $name[0] == '[' && substr( $name, -1, 1 ) == ']';
1147 * MS SQL supports more pattern operators than other databases (ex: [,],^)
1152 protected function escapeLikeInternal( $s ) {
1153 return addcslashes( $s, '\%_[]^' );
1157 * MS SQL requires specifying the escape character used in a LIKE query
1158 * or using Square brackets to surround characters that are to be escaped
1159 * http://msdn.microsoft.com/en-us/library/ms179859.aspx
1160 * Here we take the Specify-Escape-Character approach since it's less
1161 * invasive, renders a query that is closer to other DB's and better at
1162 * handling square bracket escaping
1164 * @return string Fully built LIKE statement
1166 public function buildLike() {
1167 $params = func_get_args();
1168 if ( count( $params ) > 0 && is_array( $params[0] ) ) {
1169 $params = $params[0];
1172 return parent
::buildLike( $params ) . " ESCAPE '\' ";
1179 public function selectDB( $db ) {
1181 $this->mDBname
= $db;
1182 $this->query( "USE $db" );
1184 } catch ( Exception
$e ) {
1190 * @param array $options An associative array of options to be turned into
1191 * an SQL query, valid keys are listed in the function.
1194 public function makeSelectOptions( $options ) {
1199 foreach ( $options as $key => $option ) {
1200 if ( is_numeric( $key ) ) {
1201 $noKeyOptions[$option] = true;
1205 $tailOpts .= $this->makeGroupByWithHaving( $options );
1207 $tailOpts .= $this->makeOrderBy( $options );
1209 if ( isset( $noKeyOptions['DISTINCT'] ) ||
isset( $noKeyOptions['DISTINCTROW'] ) ) {
1210 $startOpts .= 'DISTINCT';
1213 if ( isset( $noKeyOptions['FOR XML'] ) ) {
1214 // used in group concat field emulation
1215 $tailOpts .= " FOR XML PATH('')";
1218 // we want this to be compatible with the output of parent::makeSelectOptions()
1219 return [ $startOpts, '', $tailOpts, '' ];
1223 * Get the type of the DBMS, as it appears in $wgDBtype.
1226 public function getType() {
1231 * @param array $stringList
1234 public function buildConcat( $stringList ) {
1235 return implode( ' + ', $stringList );
1239 * Build a GROUP_CONCAT or equivalent statement for a query.
1240 * MS SQL doesn't have GROUP_CONCAT so we emulate it with other stuff (and boy is it nasty)
1242 * This is useful for combining a field for several rows into a single string.
1243 * NULL values will not appear in the output, duplicated values will appear,
1244 * and the resulting delimiter-separated values have no defined sort order.
1245 * Code using the results may need to use the PHP unique() or sort() methods.
1247 * @param string $delim Glue to bind the results together
1248 * @param string|array $table Table name
1249 * @param string $field Field name
1250 * @param string|array $conds Conditions
1251 * @param string|array $join_conds Join conditions
1252 * @return string SQL text
1255 public function buildGroupConcatField( $delim, $table, $field, $conds = '',
1258 $gcsq = 'gcsq_' . $this->mSubqueryId
;
1259 $this->mSubqueryId++
;
1261 $delimLen = strlen( $delim );
1262 $fld = "{$field} + {$this->addQuotes( $delim )}";
1263 $sql = "(SELECT LEFT({$field}, LEN({$field}) - {$delimLen}) FROM ("
1264 . $this->selectSQLText( $table, $fld, $conds, null, [ 'FOR XML' ], $join_conds )
1265 . ") {$gcsq} ({$field}))";
1273 public function getSearchEngine() {
1274 return "SearchMssql";
1278 * Returns an associative array for fields that are of type varbinary, binary, or image
1279 * $table can be either a raw table name or passed through tableName() first
1280 * @param string $table
1283 private function getBinaryColumns( $table ) {
1284 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
1285 $tableRaw = array_pop( $tableRawArr );
1287 if ( $this->mBinaryColumnCache
=== null ) {
1288 $this->populateColumnCaches();
1291 return isset( $this->mBinaryColumnCache
[$tableRaw] )
1292 ?
$this->mBinaryColumnCache
[$tableRaw]
1297 * @param string $table
1300 private function getBitColumns( $table ) {
1301 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
1302 $tableRaw = array_pop( $tableRawArr );
1304 if ( $this->mBitColumnCache
=== null ) {
1305 $this->populateColumnCaches();
1308 return isset( $this->mBitColumnCache
[$tableRaw] )
1309 ?
$this->mBitColumnCache
[$tableRaw]
1313 private function populateColumnCaches() {
1314 $res = $this->select( 'INFORMATION_SCHEMA.COLUMNS', '*',
1316 'TABLE_CATALOG' => $this->mDBname
,
1317 'TABLE_SCHEMA' => $this->mSchema
,
1318 'DATA_TYPE' => [ 'varbinary', 'binary', 'image', 'bit' ]
1321 $this->mBinaryColumnCache
= [];
1322 $this->mBitColumnCache
= [];
1323 foreach ( $res as $row ) {
1324 if ( $row->DATA_TYPE
== 'bit' ) {
1325 $this->mBitColumnCache
[$row->TABLE_NAME
][$row->COLUMN_NAME
] = $row;
1327 $this->mBinaryColumnCache
[$row->TABLE_NAME
][$row->COLUMN_NAME
] = $row;
1333 * @param string $name
1334 * @param string $format
1337 function tableName( $name, $format = 'quoted' ) {
1338 # Replace reserved words with better ones
1341 return $this->realTableName( 'mwuser', $format );
1343 return $this->realTableName( $name, $format );
1348 * call this instead of tableName() in the updater when renaming tables
1349 * @param string $name
1350 * @param string $format One of quoted, raw, or split
1353 function realTableName( $name, $format = 'quoted' ) {
1354 $table = parent
::tableName( $name, $format );
1355 if ( $format == 'split' ) {
1356 // Used internally, we want the schema split off from the table name and returned
1357 // as a list with 3 elements (database, schema, table)
1358 $table = explode( '.', $table );
1359 while ( count( $table ) < 3 ) {
1360 array_unshift( $table, false );
1368 * @param string $tableName
1369 * @param string $fName
1370 * @return bool|ResultWrapper
1373 public function dropTable( $tableName, $fName = __METHOD__
) {
1374 if ( !$this->tableExists( $tableName, $fName ) ) {
1378 // parent function incorrectly appends CASCADE, which we don't want
1379 $sql = "DROP TABLE " . $this->tableName( $tableName );
1381 return $this->query( $sql, $fName );
1385 * Called in the installer and updater.
1386 * Probably doesn't need to be called anywhere else in the codebase.
1387 * @param bool|null $value
1390 public function prepareStatements( $value = null ) {
1391 return wfSetVar( $this->mPrepareStatements
, $value );
1395 * Called in the installer and updater.
1396 * Probably doesn't need to be called anywhere else in the codebase.
1397 * @param bool|null $value
1400 public function scrollableCursor( $value = null ) {
1401 return wfSetVar( $this->mScrollableCursor
, $value );
1405 * Called in the installer and updater.
1406 * Probably doesn't need to be called anywhere else in the codebase.
1407 * @param array|null $value
1408 * @return array|null
1410 public function ignoreErrors( array $value = null ) {
1411 return wfSetVar( $this->mIgnoreErrors
, $value );
1413 } // end DatabaseMssql class
1420 class MssqlField
implements Field
{
1421 private $name, $tableName, $default, $max_length, $nullable, $type;
1423 function __construct( $info ) {
1424 $this->name
= $info['COLUMN_NAME'];
1425 $this->tableName
= $info['TABLE_NAME'];
1426 $this->default = $info['COLUMN_DEFAULT'];
1427 $this->max_length
= $info['CHARACTER_MAXIMUM_LENGTH'];
1428 $this->nullable
= !( strtolower( $info['IS_NULLABLE'] ) == 'no' );
1429 $this->type
= $info['DATA_TYPE'];
1436 function tableName() {
1437 return $this->tableName
;
1440 function defaultValue() {
1441 return $this->default;
1444 function maxLength() {
1445 return $this->max_length
;
1448 function isNullable() {
1449 return $this->nullable
;
1457 class MssqlBlob
extends Blob
{
1458 public function __construct( $data ) {
1459 if ( $data instanceof MssqlBlob
) {
1461 } elseif ( $data instanceof Blob
) {
1462 $this->mData
= $data->fetch();
1463 } elseif ( is_array( $data ) && is_object( $data ) ) {
1464 $this->mData
= serialize( $data );
1466 $this->mData
= $data;
1471 * Returns an unquoted hex representation of a binary string
1472 * for insertion into varbinary-type fields
1475 public function fetch() {
1476 if ( $this->mData
=== null ) {
1481 $dataLength = strlen( $this->mData
);
1482 for ( $i = 0; $i < $dataLength; $i++
) {
1483 $ret .= bin2hex( pack( 'C', ord( $this->mData
[$i] ) ) );
1490 class MssqlResultWrapper
extends ResultWrapper
{
1491 private $mSeekTo = null;
1494 * @return stdClass|bool
1496 public function fetchObject() {
1497 $res = $this->result
;
1499 if ( $this->mSeekTo
!== null ) {
1500 $result = sqlsrv_fetch_object( $res, 'stdClass', [],
1501 SQLSRV_SCROLL_ABSOLUTE
, $this->mSeekTo
);
1502 $this->mSeekTo
= null;
1504 $result = sqlsrv_fetch_object( $res );
1507 // MediaWiki expects us to return boolean false when there are no more rows instead of null
1508 if ( $result === null ) {
1516 * @return array|bool
1518 public function fetchRow() {
1519 $res = $this->result
;
1521 if ( $this->mSeekTo
!== null ) {
1522 $result = sqlsrv_fetch_array( $res, SQLSRV_FETCH_BOTH
,
1523 SQLSRV_SCROLL_ABSOLUTE
, $this->mSeekTo
);
1524 $this->mSeekTo
= null;
1526 $result = sqlsrv_fetch_array( $res );
1529 // MediaWiki expects us to return boolean false when there are no more rows instead of null
1530 if ( $result === null ) {
1541 public function seek( $row ) {
1542 $res = $this->result
;
1545 $numRows = $this->db
->numRows( $res );
1546 $row = intval( $row );
1548 if ( $numRows === 0 ) {
1550 } elseif ( $row < 0 ||
$row > $numRows - 1 ) {
1554 // Unlike MySQL, the seek actually happens on the next access
1555 $this->mSeekTo
= $row;