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 implicitGroupby() {
49 public function implicitOrderby() {
53 public function unionSupportsOrderAndLimit() {
58 * Usually aborts on failure
59 * @param string $server
61 * @param string $password
62 * @param string $dbName
63 * @throws DBConnectionError
64 * @return bool|resource|null
66 public function open( $server, $user, $password, $dbName ) {
67 # Test for driver support, to avoid suppressed fatal error
68 if ( !function_exists( 'sqlsrv_connect' ) ) {
69 throw new DBConnectionError(
71 "Microsoft SQL Server Native (sqlsrv) functions missing.
72 You can download the driver from: http://go.microsoft.com/fwlink/?LinkId=123470\n"
76 global $wgDBport, $wgDBWindowsAuthentication;
78 # e.g. the class is being loaded
79 if ( !strlen( $user ) ) {
84 $this->mServer
= $server;
85 $this->mPort
= $wgDBport;
87 $this->mPassword
= $password;
88 $this->mDBname
= $dbName;
93 $connectionInfo['Database'] = $dbName;
96 // Decide which auth scenerio to use
97 // if we are using Windows auth, don't add credentials to $connectionInfo
98 if ( !$wgDBWindowsAuthentication ) {
99 $connectionInfo['UID'] = $user;
100 $connectionInfo['PWD'] = $password;
103 MediaWiki\
suppressWarnings();
104 $this->mConn
= sqlsrv_connect( $server, $connectionInfo );
105 MediaWiki\restoreWarnings
();
107 if ( $this->mConn
=== false ) {
108 throw new DBConnectionError( $this, $this->lastError() );
111 $this->mOpened
= true;
117 * Closes a database connection, if it is open
118 * Returns success, true if already closed
121 protected function closeConnection() {
122 return sqlsrv_close( $this->mConn
);
126 * @param bool|MssqlResultWrapper|resource $result
127 * @return bool|MssqlResultWrapper
129 protected function resultObject( $result ) {
132 } elseif ( $result instanceof MssqlResultWrapper
) {
134 } elseif ( $result === true ) {
135 // Successful write query
138 return new MssqlResultWrapper( $this, $result );
144 * @return bool|MssqlResult
145 * @throws DBUnexpectedError
147 protected function doQuery( $sql ) {
148 if ( $this->getFlag( DBO_DEBUG
) ) {
149 wfDebug( "SQL: [$sql]\n" );
153 // several extensions seem to think that all databases support limits
154 // via LIMIT N after the WHERE clause well, MSSQL uses SELECT TOP N,
155 // so to catch any of those extensions we'll do a quick check for a
156 // LIMIT clause and pass $sql through $this->LimitToTopN() which parses
157 // the limit clause and passes the result to $this->limitResult();
158 if ( preg_match( '/\bLIMIT\s*/i', $sql ) ) {
159 // massage LIMIT -> TopN
160 $sql = $this->LimitToTopN( $sql );
163 // MSSQL doesn't have EXTRACT(epoch FROM XXX)
164 if ( preg_match( '#\bEXTRACT\s*?\(\s*?EPOCH\s+FROM\b#i', $sql, $matches ) ) {
165 // This is same as UNIX_TIMESTAMP, we need to calc # of seconds from 1970
166 $sql = str_replace( $matches[0], "DATEDIFF(s,CONVERT(datetime,'1/1/1970'),", $sql );
171 // SQLSRV_CURSOR_STATIC is slower than SQLSRV_CURSOR_CLIENT_BUFFERED (one of the two is
172 // needed if we want to be able to seek around the result set), however CLIENT_BUFFERED
173 // has a bug in the sqlsrv driver where wchar_t types (such as nvarchar) that are empty
174 // strings make php throw a fatal error "Severe error translating Unicode"
175 if ( $this->mScrollableCursor
) {
176 $scrollArr = [ 'Scrollable' => SQLSRV_CURSOR_STATIC
];
181 if ( $this->mPrepareStatements
) {
182 // we do prepare + execute so we can get its field metadata for later usage if desired
183 $stmt = sqlsrv_prepare( $this->mConn
, $sql, [], $scrollArr );
184 $success = sqlsrv_execute( $stmt );
186 $stmt = sqlsrv_query( $this->mConn
, $sql, [], $scrollArr );
187 $success = (bool)$stmt;
190 // make a copy so that anything we add below does not get reflected in future queries
191 $ignoreErrors = $this->mIgnoreErrors
;
193 if ( $this->mIgnoreDupKeyErrors
) {
194 // ignore duplicate key errors
195 // this emulates INSERT IGNORE in MySQL
196 $ignoreErrors[] = '2601'; // duplicate key error caused by unique index
197 $ignoreErrors[] = '2627'; // duplicate key error caused by primary key
198 $ignoreErrors[] = '3621'; // generic "the statement has been terminated" error
201 if ( $success === false ) {
202 $errors = sqlsrv_errors();
205 foreach ( $errors as $err ) {
206 if ( !in_array( $err['code'], $ignoreErrors ) ) {
212 if ( $success === false ) {
216 // remember number of rows affected
217 $this->mAffectedRows
= sqlsrv_rows_affected( $stmt );
222 public function freeResult( $res ) {
223 if ( $res instanceof ResultWrapper
) {
227 sqlsrv_free_stmt( $res );
231 * @param MssqlResultWrapper $res
234 public function fetchObject( $res ) {
235 // $res is expected to be an instance of MssqlResultWrapper here
236 return $res->fetchObject();
240 * @param MssqlResultWrapper $res
243 public function fetchRow( $res ) {
244 return $res->fetchRow();
251 public function numRows( $res ) {
252 if ( $res instanceof ResultWrapper
) {
256 $ret = sqlsrv_num_rows( $res );
258 if ( $ret === false ) {
259 // we cannot get an amount of rows from this cursor type
260 // has_rows returns bool true/false if the result has rows
261 $ret = (int)sqlsrv_has_rows( $res );
271 public function numFields( $res ) {
272 if ( $res instanceof ResultWrapper
) {
276 return sqlsrv_num_fields( $res );
284 public function fieldName( $res, $n ) {
285 if ( $res instanceof ResultWrapper
) {
289 return sqlsrv_field_metadata( $res )[$n]['Name'];
293 * This must be called after nextSequenceVal
296 public function insertId() {
297 return $this->mInsertId
;
301 * @param MssqlResultWrapper $res
305 public function dataSeek( $res, $row ) {
306 return $res->seek( $row );
312 public function lastError() {
314 $retErrors = sqlsrv_errors( SQLSRV_ERR_ALL
);
315 if ( $retErrors != null ) {
316 foreach ( $retErrors as $arrError ) {
317 $strRet .= $this->formatError( $arrError ) . "\n";
320 $strRet = "No errors found";
330 private function formatError( $err ) {
331 return '[SQLSTATE ' . $err['SQLSTATE'] . '][Error Code ' . $err['code'] . ']' . $err['message'];
337 public function lastErrno() {
338 $err = sqlsrv_errors( SQLSRV_ERR_ALL
);
339 if ( $err !== null && isset( $err[0] ) ) {
340 return $err[0]['code'];
349 public function affectedRows() {
350 return $this->mAffectedRows
;
356 * @param mixed $table Array or string, table name(s) (prefix auto-added)
357 * @param mixed $vars Array or string, field name(s) to be retrieved
358 * @param mixed $conds Array or string, condition(s) for WHERE
359 * @param string $fname Calling function name (use __METHOD__) for logs/profiling
360 * @param array $options Associative array of options (e.g.
361 * [ 'GROUP BY' => 'page_title' ]), see Database::makeSelectOptions
362 * code for list of supported stuff
363 * @param array $join_conds Associative array of table join conditions
364 * (optional) (e.g. [ 'page' => [ 'LEFT JOIN','page_latest=rev_id' ] ]
365 * @return mixed Database result resource (feed to Database::fetchObject
366 * or whatever), or false on failure
367 * @throws DBQueryError
368 * @throws DBUnexpectedError
371 public function select( $table, $vars, $conds = '', $fname = __METHOD__
,
372 $options = [], $join_conds = []
374 $sql = $this->selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
375 if ( isset( $options['EXPLAIN'] ) ) {
377 $this->mScrollableCursor
= false;
378 $this->mPrepareStatements
= false;
379 $this->query( "SET SHOWPLAN_ALL ON" );
380 $ret = $this->query( $sql, $fname );
381 $this->query( "SET SHOWPLAN_ALL OFF" );
382 } catch ( DBQueryError
$dqe ) {
383 if ( isset( $options['FOR COUNT'] ) ) {
384 // likely don't have privs for SHOWPLAN, so run a select count instead
385 $this->query( "SET SHOWPLAN_ALL OFF" );
386 unset( $options['EXPLAIN'] );
387 $ret = $this->select(
389 'COUNT(*) AS EstimateRows',
396 // someone actually wanted the query plan instead of an est row count
397 // let them know of the error
398 $this->mScrollableCursor
= true;
399 $this->mPrepareStatements
= true;
403 $this->mScrollableCursor
= true;
404 $this->mPrepareStatements
= true;
407 return $this->query( $sql, $fname );
413 * @param mixed $table Array or string, table name(s) (prefix auto-added)
414 * @param mixed $vars Array or string, field name(s) to be retrieved
415 * @param mixed $conds Array or string, condition(s) for WHERE
416 * @param string $fname Calling function name (use __METHOD__) for logs/profiling
417 * @param array $options Associative array of options (e.g. [ 'GROUP BY' => 'page_title' ]),
418 * see Database::makeSelectOptions code for list of supported stuff
419 * @param array $join_conds Associative array of table join conditions (optional)
420 * (e.g. [ 'page' => [ 'LEFT JOIN','page_latest=rev_id' ] ]
421 * @return string The SQL text
423 public function selectSQLText( $table, $vars, $conds = '', $fname = __METHOD__
,
424 $options = [], $join_conds = []
426 if ( isset( $options['EXPLAIN'] ) ) {
427 unset( $options['EXPLAIN'] );
430 $sql = parent
::selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
432 // try to rewrite aggregations of bit columns (currently MAX and MIN)
433 if ( strpos( $sql, 'MAX(' ) !== false ||
strpos( $sql, 'MIN(' ) !== false ) {
435 if ( is_array( $table ) ) {
436 foreach ( $table as $t ) {
437 $bitColumns +
= $this->getBitColumns( $this->tableName( $t ) );
440 $bitColumns = $this->getBitColumns( $this->tableName( $table ) );
443 foreach ( $bitColumns as $col => $info ) {
445 "MAX({$col})" => "MAX(CAST({$col} AS tinyint))",
446 "MIN({$col})" => "MIN(CAST({$col} AS tinyint))",
448 $sql = str_replace( array_keys( $replace ), array_values( $replace ), $sql );
455 public function deleteJoin( $delTable, $joinTable, $delVar, $joinVar, $conds,
458 $this->mScrollableCursor
= false;
460 parent
::deleteJoin( $delTable, $joinTable, $delVar, $joinVar, $conds, $fname );
461 } catch ( Exception
$e ) {
462 $this->mScrollableCursor
= true;
465 $this->mScrollableCursor
= true;
468 public function delete( $table, $conds, $fname = __METHOD__
) {
469 $this->mScrollableCursor
= false;
471 parent
::delete( $table, $conds, $fname );
472 } catch ( Exception
$e ) {
473 $this->mScrollableCursor
= true;
476 $this->mScrollableCursor
= true;
480 * Estimate rows in dataset
481 * Returns estimated count, based on SHOWPLAN_ALL output
482 * This is not necessarily an accurate estimate, so use sparingly
483 * Returns -1 if count cannot be found
484 * Takes same arguments as Database::select()
485 * @param string $table
486 * @param string $vars
487 * @param string $conds
488 * @param string $fname
489 * @param array $options
492 public function estimateRowCount( $table, $vars = '*', $conds = '',
493 $fname = __METHOD__
, $options = []
495 // http://msdn2.microsoft.com/en-us/library/aa259203.aspx
496 $options['EXPLAIN'] = true;
497 $options['FOR COUNT'] = true;
498 $res = $this->select( $table, $vars, $conds, $fname, $options );
502 $row = $this->fetchRow( $res );
504 if ( isset( $row['EstimateRows'] ) ) {
505 $rows = (int)$row['EstimateRows'];
513 * Returns information about an index
514 * If errors are explicitly ignored, returns NULL on failure
515 * @param string $table
516 * @param string $index
517 * @param string $fname
518 * @return array|bool|null
520 public function indexInfo( $table, $index, $fname = __METHOD__
) {
521 # This does not return the same info as MYSQL would, but that's OK
522 # because MediaWiki never uses the returned value except to check for
523 # the existance of indexes.
524 $sql = "sp_helpindex '" . $this->tableName( $table ) . "'";
525 $res = $this->query( $sql, $fname );
532 foreach ( $res as $row ) {
533 if ( $row->index_name
== $index ) {
534 $row->Non_unique
= !stristr( $row->index_description
, "unique" );
535 $cols = explode( ", ", $row->index_keys
);
536 foreach ( $cols as $col ) {
537 $row->Column_name
= trim( $col );
538 $result[] = clone $row;
540 } elseif ( $index == 'PRIMARY' && stristr( $row->index_description
, 'PRIMARY' ) ) {
541 $row->Non_unique
= 0;
542 $cols = explode( ", ", $row->index_keys
);
543 foreach ( $cols as $col ) {
544 $row->Column_name
= trim( $col );
545 $result[] = clone $row;
550 return empty( $result ) ?
false : $result;
554 * INSERT wrapper, inserts an array into a table
556 * $arrToInsert may be a single associative array, or an array of these with numeric keys, for
559 * Usually aborts on failure
560 * If errors are explicitly ignored, returns success
561 * @param string $table
562 * @param array $arrToInsert
563 * @param string $fname
564 * @param array $options
568 public function insert( $table, $arrToInsert, $fname = __METHOD__
, $options = [] ) {
569 # No rows to insert, easy just return now
570 if ( !count( $arrToInsert ) ) {
574 if ( !is_array( $options ) ) {
575 $options = [ $options ];
578 $table = $this->tableName( $table );
580 if ( !( isset( $arrToInsert[0] ) && is_array( $arrToInsert[0] ) ) ) { // Not multi row
581 $arrToInsert = [ 0 => $arrToInsert ]; // make everything multi row compatible
584 // We know the table we're inserting into, get its identity column
586 // strip matching square brackets and the db/schema from table name
587 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
588 $tableRaw = array_pop( $tableRawArr );
589 $res = $this->doQuery(
590 "SELECT NAME AS idColumn FROM SYS.IDENTITY_COLUMNS " .
591 "WHERE OBJECT_NAME(OBJECT_ID)='{$tableRaw}'"
593 if ( $res && sqlsrv_has_rows( $res ) ) {
594 // There is an identity for this table.
595 $identityArr = sqlsrv_fetch_array( $res, SQLSRV_FETCH_ASSOC
);
596 $identity = array_pop( $identityArr );
598 sqlsrv_free_stmt( $res );
600 // Determine binary/varbinary fields so we can encode data as a hex string like 0xABCDEF
601 $binaryColumns = $this->getBinaryColumns( $table );
603 // INSERT IGNORE is not supported by SQL Server
604 // remove IGNORE from options list and set ignore flag to true
605 if ( in_array( 'IGNORE', $options ) ) {
606 $options = array_diff( $options, [ 'IGNORE' ] );
607 $this->mIgnoreDupKeyErrors
= true;
610 foreach ( $arrToInsert as $a ) {
611 // start out with empty identity column, this is so we can return
612 // it as a result of the insert logic
615 $identityClause = '';
617 // if we have an identity column
620 foreach ( $a as $k => $v ) {
621 if ( $k == $identity ) {
622 if ( !is_null( $v ) ) {
623 // there is a value being passed to us,
624 // we need to turn on and off inserted identity
625 $sqlPre = "SET IDENTITY_INSERT $table ON;";
626 $sqlPost = ";SET IDENTITY_INSERT $table OFF;";
628 // we can't insert NULL into an identity column,
629 // so remove the column from the insert.
635 // we want to output an identity column as result
636 $identityClause = "OUTPUT INSERTED.$identity ";
639 $keys = array_keys( $a );
641 // Build the actual query
642 $sql = $sqlPre . 'INSERT ' . implode( ' ', $options ) .
643 " INTO $table (" . implode( ',', $keys ) . ") $identityClause VALUES (";
646 foreach ( $a as $key => $value ) {
647 if ( isset( $binaryColumns[$key] ) ) {
648 $value = new MssqlBlob( $value );
655 if ( is_null( $value ) ) {
657 } elseif ( is_array( $value ) ||
is_object( $value ) ) {
658 if ( is_object( $value ) && $value instanceof Blob
) {
659 $sql .= $this->addQuotes( $value );
661 $sql .= $this->addQuotes( serialize( $value ) );
664 $sql .= $this->addQuotes( $value );
667 $sql .= ')' . $sqlPost;
670 $this->mScrollableCursor
= false;
672 $ret = $this->query( $sql );
673 } catch ( Exception
$e ) {
674 $this->mScrollableCursor
= true;
675 $this->mIgnoreDupKeyErrors
= false;
678 $this->mScrollableCursor
= true;
680 if ( !is_null( $identity ) ) {
681 // then we want to get the identity column value we were assigned and save it off
682 $row = $ret->fetchObject();
683 if ( is_object( $row ) ) {
684 $this->mInsertId
= $row->$identity;
686 // it seems that mAffectedRows is -1 sometimes when OUTPUT INSERTED.identity is used
687 // if we got an identity back, we know for sure a row was affected, so adjust that here
688 if ( $this->mAffectedRows
== -1 ) {
689 $this->mAffectedRows
= 1;
694 $this->mIgnoreDupKeyErrors
= false;
699 * INSERT SELECT wrapper
700 * $varMap must be an associative array of the form [ 'dest1' => 'source1', ... ]
701 * Source items may be literals rather than field names, but strings should
702 * be quoted with Database::addQuotes().
703 * @param string $destTable
704 * @param array|string $srcTable May be an array of tables.
705 * @param array $varMap
706 * @param array $conds May be "*" to copy the whole table.
707 * @param string $fname
708 * @param array $insertOptions
709 * @param array $selectOptions
710 * @return null|ResultWrapper
713 public function nativeInsertSelect( $destTable, $srcTable, $varMap, $conds, $fname = __METHOD__
,
714 $insertOptions = [], $selectOptions = []
716 $this->mScrollableCursor
= false;
718 $ret = parent
::nativeInsertSelect(
727 } catch ( Exception
$e ) {
728 $this->mScrollableCursor
= true;
731 $this->mScrollableCursor
= true;
737 * UPDATE wrapper. Takes a condition array and a SET array.
739 * @param string $table Name of the table to UPDATE. This will be passed through
740 * Database::tableName().
742 * @param array $values An array of values to SET. For each array element,
743 * the key gives the field name, and the value gives the data
744 * to set that field to. The data will be quoted by
745 * Database::addQuotes().
747 * @param array $conds An array of conditions (WHERE). See
748 * Database::select() for the details of the format of
749 * condition arrays. Use '*' to update all rows.
751 * @param string $fname The function name of the caller (from __METHOD__),
752 * for logging and profiling.
754 * @param array $options An array of UPDATE options, can be:
755 * - IGNORE: Ignore unique key conflicts
756 * - LOW_PRIORITY: MySQL-specific, see MySQL manual.
758 * @throws DBUnexpectedError
761 function update( $table, $values, $conds, $fname = __METHOD__
, $options = [] ) {
762 $table = $this->tableName( $table );
763 $binaryColumns = $this->getBinaryColumns( $table );
765 $opts = $this->makeUpdateOptions( $options );
766 $sql = "UPDATE $opts $table SET " . $this->makeList( $values, LIST_SET
, $binaryColumns );
768 if ( $conds !== [] && $conds !== '*' ) {
769 $sql .= " WHERE " . $this->makeList( $conds, LIST_AND
, $binaryColumns );
772 $this->mScrollableCursor
= false;
774 $this->query( $sql );
775 } catch ( Exception
$e ) {
776 $this->mScrollableCursor
= true;
779 $this->mScrollableCursor
= true;
784 * Makes an encoded list of strings from an array
785 * @param array $a Containing the data
786 * @param int $mode Constant
787 * - LIST_COMMA: comma separated, no field names
788 * - LIST_AND: ANDed WHERE clause (without the WHERE). See
789 * the documentation for $conds in Database::select().
790 * - LIST_OR: ORed WHERE clause (without the WHERE)
791 * - LIST_SET: comma separated with field names, like a SET clause
792 * - LIST_NAMES: comma separated field names
793 * @param array $binaryColumns Contains a list of column names that are binary types
794 * This is a custom parameter only present for MS SQL.
796 * @throws DBUnexpectedError
799 public function makeList( $a, $mode = LIST_COMMA
, $binaryColumns = [] ) {
800 if ( !is_array( $a ) ) {
801 throw new DBUnexpectedError( $this, __METHOD__
. ' called with incorrect parameters' );
804 if ( $mode != LIST_NAMES
) {
805 // In MS SQL, values need to be specially encoded when they are
806 // inserted into binary fields. Perform this necessary encoding
807 // for the specified set of columns.
808 foreach ( array_keys( $a ) as $field ) {
809 if ( !isset( $binaryColumns[$field] ) ) {
813 if ( is_array( $a[$field] ) ) {
814 foreach ( $a[$field] as &$v ) {
815 $v = new MssqlBlob( $v );
819 $a[$field] = new MssqlBlob( $a[$field] );
824 return parent
::makeList( $a, $mode );
828 * @param string $table
829 * @param string $field
830 * @return int Returns the size of a text field, or -1 for "unlimited"
832 public function textFieldSize( $table, $field ) {
833 $table = $this->tableName( $table );
834 $sql = "SELECT CHARACTER_MAXIMUM_LENGTH,DATA_TYPE FROM INFORMATION_SCHEMA.Columns
835 WHERE TABLE_NAME = '$table' AND COLUMN_NAME = '$field'";
836 $res = $this->query( $sql );
837 $row = $this->fetchRow( $res );
839 if ( strtolower( $row['DATA_TYPE'] ) != 'text' ) {
840 $size = $row['CHARACTER_MAXIMUM_LENGTH'];
847 * Construct a LIMIT query with optional offset
848 * This is used for query pages
850 * @param string $sql SQL query we will append the limit too
851 * @param int $limit The SQL limit
852 * @param bool|int $offset The SQL offset (default false)
853 * @return array|string
854 * @throws DBUnexpectedError
856 public function limitResult( $sql, $limit, $offset = false ) {
857 if ( $offset === false ||
$offset == 0 ) {
858 if ( strpos( $sql, "SELECT" ) === false ) {
859 return "TOP {$limit} " . $sql;
861 return preg_replace( '/\bSELECT(\s+DISTINCT)?\b/Dsi',
862 'SELECT$1 TOP ' . $limit, $sql, 1 );
865 // This one is fun, we need to pull out the select list as well as any ORDER BY clause
866 $select = $orderby = [];
867 $s1 = preg_match( '#SELECT\s+(.+?)\s+FROM#Dis', $sql, $select );
868 $s2 = preg_match( '#(ORDER BY\s+.+?)(\s*FOR XML .*)?$#Dis', $sql, $orderby );
869 $overOrder = $postOrder = '';
870 $first = $offset +
1;
871 $last = $offset +
$limit;
872 $sub1 = 'sub_' . $this->mSubqueryId
;
873 $sub2 = 'sub_' . ( $this->mSubqueryId +
1 );
874 $this->mSubqueryId +
= 2;
877 throw new DBUnexpectedError( $this, "Attempting to LIMIT a non-SELECT query\n" );
881 $overOrder = 'ORDER BY (SELECT 1)';
883 if ( !isset( $orderby[2] ) ||
!$orderby[2] ) {
884 // don't need to strip it out if we're using a FOR XML clause
885 $sql = str_replace( $orderby[1], '', $sql );
887 $overOrder = $orderby[1];
888 $postOrder = ' ' . $overOrder;
890 $sql = "SELECT {$select[1]}
892 SELECT ROW_NUMBER() OVER({$overOrder}) AS rowNumber, *
893 FROM ({$sql}) {$sub1}
895 WHERE rowNumber BETWEEN {$first} AND {$last}{$postOrder}";
902 * If there is a limit clause, parse it, strip it, and pass the remaining
903 * SQL through limitResult() with the appropriate parameters. Not the
904 * prettiest solution, but better than building a whole new parser. This
905 * exists becase there are still too many extensions that don't use dynamic
909 * @return array|mixed|string
911 public function LimitToTopN( $sql ) {
912 // Matches: LIMIT {[offset,] row_count | row_count OFFSET offset}
913 $pattern = '/\bLIMIT\s+((([0-9]+)\s*,\s*)?([0-9]+)(\s+OFFSET\s+([0-9]+))?)/i';
914 if ( preg_match( $pattern, $sql, $matches ) ) {
915 $row_count = $matches[4];
916 $offset = $matches[3] ?
: $matches[6] ?
: false;
918 // strip the matching LIMIT clause out
919 $sql = str_replace( $matches[0], '', $sql );
921 return $this->limitResult( $sql, $row_count, $offset );
928 * @return string Wikitext of a link to the server software's web site
930 public function getSoftwareLink() {
931 return "[{{int:version-db-mssql-url}} MS SQL Server]";
935 * @return string Version information from the database
937 public function getServerVersion() {
938 $server_info = sqlsrv_server_info( $this->mConn
);
940 if ( isset( $server_info['SQLServerVersion'] ) ) {
941 $version = $server_info['SQLServerVersion'];
948 * @param string $table
949 * @param string $fname
952 public function tableExists( $table, $fname = __METHOD__
) {
953 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
955 if ( $db !== false ) {
957 wfDebug( "Attempting to call tableExists on a remote table" );
961 if ( $schema === false ) {
962 global $wgDBmwschema;
963 $schema = $wgDBmwschema;
966 $res = $this->query( "SELECT 1 FROM INFORMATION_SCHEMA.TABLES
967 WHERE TABLE_TYPE = 'BASE TABLE'
968 AND TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table'" );
970 if ( $res->numRows() ) {
978 * Query whether a given column exists in the mediawiki schema
979 * @param string $table
980 * @param string $field
981 * @param string $fname
984 public function fieldExists( $table, $field, $fname = __METHOD__
) {
985 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
987 if ( $db !== false ) {
989 wfDebug( "Attempting to call fieldExists on a remote table" );
993 $res = $this->query( "SELECT 1 FROM INFORMATION_SCHEMA.COLUMNS
994 WHERE TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
996 if ( $res->numRows() ) {
1003 public function fieldInfo( $table, $field ) {
1004 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
1006 if ( $db !== false ) {
1008 wfDebug( "Attempting to call fieldInfo on a remote table" );
1012 $res = $this->query( "SELECT * FROM INFORMATION_SCHEMA.COLUMNS
1013 WHERE TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
1015 $meta = $res->fetchRow();
1017 return new MssqlField( $meta );
1024 * Begin a transaction, committing any previously open transaction
1025 * @param string $fname
1027 protected function doBegin( $fname = __METHOD__
) {
1028 sqlsrv_begin_transaction( $this->mConn
);
1029 $this->mTrxLevel
= 1;
1034 * @param string $fname
1036 protected function doCommit( $fname = __METHOD__
) {
1037 sqlsrv_commit( $this->mConn
);
1038 $this->mTrxLevel
= 0;
1042 * Rollback a transaction.
1043 * No-op on non-transactional databases.
1044 * @param string $fname
1046 protected function doRollback( $fname = __METHOD__
) {
1047 sqlsrv_rollback( $this->mConn
);
1048 $this->mTrxLevel
= 0;
1052 * Escapes a identifier for use inm SQL.
1053 * Throws an exception if it is invalid.
1054 * Reference: http://msdn.microsoft.com/en-us/library/aa224033%28v=SQL.80%29.aspx
1055 * @param string $identifier
1056 * @throws InvalidArgumentException
1059 private function escapeIdentifier( $identifier ) {
1060 if ( strlen( $identifier ) == 0 ) {
1061 throw new InvalidArgumentException( "An identifier must not be empty" );
1063 if ( strlen( $identifier ) > 128 ) {
1064 throw new InvalidArgumentException( "The identifier '$identifier' is too long (max. 128)" );
1066 if ( ( strpos( $identifier, '[' ) !== false )
1067 ||
( strpos( $identifier, ']' ) !== false )
1069 // It may be allowed if you quoted with double quotation marks, but
1070 // that would break if QUOTED_IDENTIFIER is OFF
1071 throw new InvalidArgumentException( "Square brackets are not allowed in '$identifier'" );
1074 return "[$identifier]";
1081 public function strencode( $s ) {
1082 // Should not be called by us
1084 return str_replace( "'", "''", $s );
1088 * @param string|int|null|bool|Blob $s
1089 * @return string|int
1091 public function addQuotes( $s ) {
1092 if ( $s instanceof MssqlBlob
) {
1094 } elseif ( $s instanceof Blob
) {
1095 // this shouldn't really ever be called, but it's here if needed
1096 // (and will quite possibly make the SQL error out)
1097 $blob = new MssqlBlob( $s->fetch() );
1098 return $blob->fetch();
1100 if ( is_bool( $s ) ) {
1103 return parent
::addQuotes( $s );
1111 public function addIdentifierQuotes( $s ) {
1112 // http://msdn.microsoft.com/en-us/library/aa223962.aspx
1113 return '[' . $s . ']';
1117 * @param string $name
1120 public function isQuotedIdentifier( $name ) {
1121 return strlen( $name ) && $name[0] == '[' && substr( $name, -1, 1 ) == ']';
1125 * MS SQL supports more pattern operators than other databases (ex: [,],^)
1130 protected function escapeLikeInternal( $s ) {
1131 return addcslashes( $s, '\%_[]^' );
1135 * MS SQL requires specifying the escape character used in a LIKE query
1136 * or using Square brackets to surround characters that are to be escaped
1137 * https://msdn.microsoft.com/en-us/library/ms179859.aspx
1138 * Here we take the Specify-Escape-Character approach since it's less
1139 * invasive, renders a query that is closer to other DB's and better at
1140 * handling square bracket escaping
1142 * @return string Fully built LIKE statement
1144 public function buildLike() {
1145 $params = func_get_args();
1146 if ( count( $params ) > 0 && is_array( $params[0] ) ) {
1147 $params = $params[0];
1150 return parent
::buildLike( $params ) . " ESCAPE '\' ";
1157 public function selectDB( $db ) {
1159 $this->mDBname
= $db;
1160 $this->query( "USE $db" );
1162 } catch ( Exception
$e ) {
1168 * @param array $options An associative array of options to be turned into
1169 * an SQL query, valid keys are listed in the function.
1172 public function makeSelectOptions( $options ) {
1177 foreach ( $options as $key => $option ) {
1178 if ( is_numeric( $key ) ) {
1179 $noKeyOptions[$option] = true;
1183 $tailOpts .= $this->makeGroupByWithHaving( $options );
1185 $tailOpts .= $this->makeOrderBy( $options );
1187 if ( isset( $noKeyOptions['DISTINCT'] ) ||
isset( $noKeyOptions['DISTINCTROW'] ) ) {
1188 $startOpts .= 'DISTINCT';
1191 if ( isset( $noKeyOptions['FOR XML'] ) ) {
1192 // used in group concat field emulation
1193 $tailOpts .= " FOR XML PATH('')";
1196 // we want this to be compatible with the output of parent::makeSelectOptions()
1197 return [ $startOpts, '', $tailOpts, '', '' ];
1201 * Get the type of the DBMS, as it appears in $wgDBtype.
1204 public function getType() {
1209 * @param array $stringList
1212 public function buildConcat( $stringList ) {
1213 return implode( ' + ', $stringList );
1217 * Build a GROUP_CONCAT or equivalent statement for a query.
1218 * MS SQL doesn't have GROUP_CONCAT so we emulate it with other stuff (and boy is it nasty)
1220 * This is useful for combining a field for several rows into a single string.
1221 * NULL values will not appear in the output, duplicated values will appear,
1222 * and the resulting delimiter-separated values have no defined sort order.
1223 * Code using the results may need to use the PHP unique() or sort() methods.
1225 * @param string $delim Glue to bind the results together
1226 * @param string|array $table Table name
1227 * @param string $field Field name
1228 * @param string|array $conds Conditions
1229 * @param string|array $join_conds Join conditions
1230 * @return string SQL text
1233 public function buildGroupConcatField( $delim, $table, $field, $conds = '',
1236 $gcsq = 'gcsq_' . $this->mSubqueryId
;
1237 $this->mSubqueryId++
;
1239 $delimLen = strlen( $delim );
1240 $fld = "{$field} + {$this->addQuotes( $delim )}";
1241 $sql = "(SELECT LEFT({$field}, LEN({$field}) - {$delimLen}) FROM ("
1242 . $this->selectSQLText( $table, $fld, $conds, null, [ 'FOR XML' ], $join_conds )
1243 . ") {$gcsq} ({$field}))";
1249 * Returns an associative array for fields that are of type varbinary, binary, or image
1250 * $table can be either a raw table name or passed through tableName() first
1251 * @param string $table
1254 private function getBinaryColumns( $table ) {
1255 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
1256 $tableRaw = array_pop( $tableRawArr );
1258 if ( $this->mBinaryColumnCache
=== null ) {
1259 $this->populateColumnCaches();
1262 return isset( $this->mBinaryColumnCache
[$tableRaw] )
1263 ?
$this->mBinaryColumnCache
[$tableRaw]
1268 * @param string $table
1271 private function getBitColumns( $table ) {
1272 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
1273 $tableRaw = array_pop( $tableRawArr );
1275 if ( $this->mBitColumnCache
=== null ) {
1276 $this->populateColumnCaches();
1279 return isset( $this->mBitColumnCache
[$tableRaw] )
1280 ?
$this->mBitColumnCache
[$tableRaw]
1284 private function populateColumnCaches() {
1285 $res = $this->select( 'INFORMATION_SCHEMA.COLUMNS', '*',
1287 'TABLE_CATALOG' => $this->mDBname
,
1288 'TABLE_SCHEMA' => $this->mSchema
,
1289 'DATA_TYPE' => [ 'varbinary', 'binary', 'image', 'bit' ]
1292 $this->mBinaryColumnCache
= [];
1293 $this->mBitColumnCache
= [];
1294 foreach ( $res as $row ) {
1295 if ( $row->DATA_TYPE
== 'bit' ) {
1296 $this->mBitColumnCache
[$row->TABLE_NAME
][$row->COLUMN_NAME
] = $row;
1298 $this->mBinaryColumnCache
[$row->TABLE_NAME
][$row->COLUMN_NAME
] = $row;
1304 * @param string $name
1305 * @param string $format
1308 function tableName( $name, $format = 'quoted' ) {
1309 # Replace reserved words with better ones
1312 return $this->realTableName( 'mwuser', $format );
1314 return $this->realTableName( $name, $format );
1319 * call this instead of tableName() in the updater when renaming tables
1320 * @param string $name
1321 * @param string $format One of quoted, raw, or split
1324 function realTableName( $name, $format = 'quoted' ) {
1325 $table = parent
::tableName( $name, $format );
1326 if ( $format == 'split' ) {
1327 // Used internally, we want the schema split off from the table name and returned
1328 // as a list with 3 elements (database, schema, table)
1329 $table = explode( '.', $table );
1330 while ( count( $table ) < 3 ) {
1331 array_unshift( $table, false );
1339 * @param string $tableName
1340 * @param string $fName
1341 * @return bool|ResultWrapper
1344 public function dropTable( $tableName, $fName = __METHOD__
) {
1345 if ( !$this->tableExists( $tableName, $fName ) ) {
1349 // parent function incorrectly appends CASCADE, which we don't want
1350 $sql = "DROP TABLE " . $this->tableName( $tableName );
1352 return $this->query( $sql, $fName );
1356 * Called in the installer and updater.
1357 * Probably doesn't need to be called anywhere else in the codebase.
1358 * @param bool|null $value
1361 public function prepareStatements( $value = null ) {
1362 return wfSetVar( $this->mPrepareStatements
, $value );
1366 * Called in the installer and updater.
1367 * Probably doesn't need to be called anywhere else in the codebase.
1368 * @param bool|null $value
1371 public function scrollableCursor( $value = null ) {
1372 return wfSetVar( $this->mScrollableCursor
, $value );
1376 * Called in the installer and updater.
1377 * Probably doesn't need to be called anywhere else in the codebase.
1378 * @param array|null $value
1379 * @return array|null
1381 public function ignoreErrors( array $value = null ) {
1382 return wfSetVar( $this->mIgnoreErrors
, $value );
1384 } // end DatabaseMssql class