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 DatabaseBase
{
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;
44 public function cascadingDeletes() {
48 public function cleanupTriggers() {
52 public function strictIPs() {
56 public function realTimestamps() {
60 public function implicitGroupby() {
64 public function implicitOrderby() {
68 public function functionalIndexes() {
72 public function unionSupportsOrderAndLimit() {
77 * Usually aborts on failure
78 * @param string $server
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(
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 ) ) {
103 $this->mServer
= $server;
104 $this->mPort
= $wgDBport;
105 $this->mUser
= $user;
106 $this->mPassword
= $password;
107 $this->mDBname
= $dbName;
109 $connectionInfo = array();
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 wfSuppressWarnings();
123 $this->mConn
= sqlsrv_connect( $server, $connectionInfo );
126 if ( $this->mConn
=== false ) {
127 throw new DBConnectionError( $this, $this->lastError() );
130 $this->mOpened
= true;
136 * Closes a database connection, if it is open
137 * Returns success, true if already closed
140 protected function closeConnection() {
141 return sqlsrv_close( $this->mConn
);
145 * @param bool|MssqlResultWrapper|resource $result
146 * @return bool|MssqlResultWrapper
148 public function resultObject( $result ) {
149 if ( empty( $result ) ) {
151 } elseif ( $result instanceof MssqlResultWrapper
) {
153 } elseif ( $result === true ) {
154 // Successful write query
157 return new MssqlResultWrapper( $this, $result );
163 * @return bool|MssqlResult
164 * @throws DBUnexpectedError
166 protected function doQuery( $sql ) {
167 if ( $this->debug() ) {
168 wfDebug( "SQL: [$sql]\n" );
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 );
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 = array( 'Scrollable' => SQLSRV_CURSOR_STATIC
);
197 $scrollArr = array();
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, array(), $scrollArr );
203 $success = sqlsrv_execute( $stmt );
205 $stmt = sqlsrv_query( $this->mConn
, $sql, array(), $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
);
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
230 $this->mAffectedRows
= 0;
236 if ( $success === false ) {
239 // remember number of rows affected
240 $this->mAffectedRows
= sqlsrv_rows_affected( $stmt );
245 public function freeResult( $res ) {
246 if ( $res instanceof ResultWrapper
) {
250 sqlsrv_free_stmt( $res );
254 * @param MssqlResultWrapper $res
257 public function fetchObject( $res ) {
258 // $res is expected to be an instance of MssqlResultWrapper here
259 return $res->fetchObject();
263 * @param MssqlResultWrapper $res
266 public function fetchRow( $res ) {
267 return $res->fetchRow();
274 public function numRows( $res ) {
275 if ( $res instanceof ResultWrapper
) {
279 return sqlsrv_num_rows( $res );
286 public function numFields( $res ) {
287 if ( $res instanceof ResultWrapper
) {
291 return sqlsrv_num_fields( $res );
299 public function fieldName( $res, $n ) {
300 if ( $res instanceof ResultWrapper
) {
304 $metadata = sqlsrv_field_metadata( $res );
305 return $metadata[$n]['Name'];
309 * This must be called after nextSequenceVal
312 public function insertId() {
313 return $this->mInsertId
;
317 * @param MssqlResultWrapper $res
321 public function dataSeek( $res, $row ) {
322 return $res->seek( $row );
328 public function lastError() {
330 $retErrors = sqlsrv_errors( SQLSRV_ERR_ALL
);
331 if ( $retErrors != null ) {
332 foreach ( $retErrors as $arrError ) {
333 $strRet .= $this->formatError( $arrError ) . "\n";
336 $strRet = "No errors found";
346 private function formatError( $err ) {
347 return '[SQLSTATE ' . $err['SQLSTATE'] . '][Error Code ' . $err['code'] . ']' . $err['message'];
353 public function lastErrno() {
354 $err = sqlsrv_errors( SQLSRV_ERR_ALL
);
355 if ( $err !== null && isset( $err[0] ) ) {
356 return $err[0]['code'];
365 public function affectedRows() {
366 return $this->mAffectedRows
;
372 * @param mixed $table Array or string, table name(s) (prefix auto-added)
373 * @param mixed $vars Array or string, field name(s) to be retrieved
374 * @param mixed $conds Array or string, condition(s) for WHERE
375 * @param string $fname Calling function name (use __METHOD__) for logs/profiling
376 * @param array $options Associative array of options (e.g.
377 * array('GROUP BY' => 'page_title')), see Database::makeSelectOptions
378 * code for list of supported stuff
379 * @param array $join_conds Associative array of table join conditions
380 * (optional) (e.g. array( 'page' => array('LEFT JOIN','page_latest=rev_id') )
381 * @return mixed Database result resource (feed to Database::fetchObject
382 * or whatever), or false on failure
383 * @throws DBQueryError
384 * @throws DBUnexpectedError
387 public function select( $table, $vars, $conds = '', $fname = __METHOD__
,
388 $options = array(), $join_conds = array()
390 $sql = $this->selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
391 if ( isset( $options['EXPLAIN'] ) ) {
393 $this->mScrollableCursor
= false;
394 $this->mPrepareStatements
= false;
395 $this->query( "SET SHOWPLAN_ALL ON" );
396 $ret = $this->query( $sql, $fname );
397 $this->query( "SET SHOWPLAN_ALL OFF" );
398 } catch ( DBQueryError
$dqe ) {
399 if ( isset( $options['FOR COUNT'] ) ) {
400 // likely don't have privs for SHOWPLAN, so run a select count instead
401 $this->query( "SET SHOWPLAN_ALL OFF" );
402 unset( $options['EXPLAIN'] );
403 $ret = $this->select(
405 'COUNT(*) AS EstimateRows',
412 // someone actually wanted the query plan instead of an est row count
413 // let them know of the error
414 $this->mScrollableCursor
= true;
415 $this->mPrepareStatements
= true;
419 $this->mScrollableCursor
= true;
420 $this->mPrepareStatements
= true;
423 return $this->query( $sql, $fname );
429 * @param mixed $table Array or string, table name(s) (prefix auto-added)
430 * @param mixed $vars Array or string, field name(s) to be retrieved
431 * @param mixed $conds Array or string, condition(s) for WHERE
432 * @param string $fname Calling function name (use __METHOD__) for logs/profiling
433 * @param array $options Associative array of options (e.g. array('GROUP BY' => 'page_title')),
434 * see Database::makeSelectOptions code for list of supported stuff
435 * @param array $join_conds Associative array of table join conditions (optional)
436 * (e.g. array( 'page' => array('LEFT JOIN','page_latest=rev_id') )
437 * @return string The SQL text
439 public function selectSQLText( $table, $vars, $conds = '', $fname = __METHOD__
,
440 $options = array(), $join_conds = array()
442 if ( isset( $options['EXPLAIN'] ) ) {
443 unset( $options['EXPLAIN'] );
446 $sql = parent
::selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
448 // try to rewrite aggregations of bit columns (currently MAX and MIN)
449 if ( strpos( $sql, 'MAX(' ) !== false ||
strpos( $sql, 'MIN(' ) !== false ) {
450 $bitColumns = array();
451 if ( is_array( $table ) ) {
452 foreach ( $table as $t ) {
453 $bitColumns +
= $this->getBitColumns( $this->tableName( $t ) );
456 $bitColumns = $this->getBitColumns( $this->tableName( $table ) );
459 foreach ( $bitColumns as $col => $info ) {
461 "MAX({$col})" => "MAX(CAST({$col} AS tinyint))",
462 "MIN({$col})" => "MIN(CAST({$col} AS tinyint))",
464 $sql = str_replace( array_keys( $replace ), array_values( $replace ), $sql );
471 public function deleteJoin( $delTable, $joinTable, $delVar, $joinVar, $conds,
474 $this->mScrollableCursor
= false;
476 parent
::deleteJoin( $delTable, $joinTable, $delVar, $joinVar, $conds, $fname );
477 } catch ( Exception
$e ) {
478 $this->mScrollableCursor
= true;
481 $this->mScrollableCursor
= true;
484 public function delete( $table, $conds, $fname = __METHOD__
) {
485 $this->mScrollableCursor
= false;
487 parent
::delete( $table, $conds, $fname );
488 } catch ( Exception
$e ) {
489 $this->mScrollableCursor
= true;
492 $this->mScrollableCursor
= true;
496 * Estimate rows in dataset
497 * Returns estimated count, based on SHOWPLAN_ALL output
498 * This is not necessarily an accurate estimate, so use sparingly
499 * Returns -1 if count cannot be found
500 * Takes same arguments as Database::select()
501 * @param string $table
502 * @param string $vars
503 * @param string $conds
504 * @param string $fname
505 * @param array $options
508 public function estimateRowCount( $table, $vars = '*', $conds = '',
509 $fname = __METHOD__
, $options = array()
511 // http://msdn2.microsoft.com/en-us/library/aa259203.aspx
512 $options['EXPLAIN'] = true;
513 $options['FOR COUNT'] = true;
514 $res = $this->select( $table, $vars, $conds, $fname, $options );
518 $row = $this->fetchRow( $res );
520 if ( isset( $row['EstimateRows'] ) ) {
521 $rows = $row['EstimateRows'];
529 * Returns information about an index
530 * If errors are explicitly ignored, returns NULL on failure
531 * @param string $table
532 * @param string $index
533 * @param string $fname
534 * @return array|bool|null
536 public function indexInfo( $table, $index, $fname = __METHOD__
) {
537 # This does not return the same info as MYSQL would, but that's OK
538 # because MediaWiki never uses the returned value except to check for
539 # the existance of indexes.
540 $sql = "sp_helpindex '" . $table . "'";
541 $res = $this->query( $sql, $fname );
547 foreach ( $res as $row ) {
548 if ( $row->index_name
== $index ) {
549 $row->Non_unique
= !stristr( $row->index_description
, "unique" );
550 $cols = explode( ", ", $row->index_keys
);
551 foreach ( $cols as $col ) {
552 $row->Column_name
= trim( $col );
553 $result[] = clone $row;
555 } elseif ( $index == 'PRIMARY' && stristr( $row->index_description
, 'PRIMARY' ) ) {
556 $row->Non_unique
= 0;
557 $cols = explode( ", ", $row->index_keys
);
558 foreach ( $cols as $col ) {
559 $row->Column_name
= trim( $col );
560 $result[] = clone $row;
565 return empty( $result ) ?
false : $result;
569 * INSERT wrapper, inserts an array into a table
571 * $arrToInsert may be a single associative array, or an array of these with numeric keys, for
574 * Usually aborts on failure
575 * If errors are explicitly ignored, returns success
576 * @param string $table
577 * @param array $arrToInsert
578 * @param string $fname
579 * @param array $options
583 public function insert( $table, $arrToInsert, $fname = __METHOD__
, $options = array() ) {
584 # No rows to insert, easy just return now
585 if ( !count( $arrToInsert ) ) {
589 if ( !is_array( $options ) ) {
590 $options = array( $options );
593 $table = $this->tableName( $table );
595 if ( !( isset( $arrToInsert[0] ) && is_array( $arrToInsert[0] ) ) ) { // Not multi row
596 $arrToInsert = array( 0 => $arrToInsert ); // make everything multi row compatible
599 // We know the table we're inserting into, get its identity column
601 // strip matching square brackets and the db/schema from table name
602 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
603 $tableRaw = array_pop( $tableRawArr );
604 $res = $this->doQuery(
605 "SELECT NAME AS idColumn FROM SYS.IDENTITY_COLUMNS " .
606 "WHERE OBJECT_NAME(OBJECT_ID)='{$tableRaw}'"
608 if ( $res && sqlsrv_has_rows( $res ) ) {
609 // There is an identity for this table.
610 $identityArr = sqlsrv_fetch_array( $res, SQLSRV_FETCH_ASSOC
);
611 $identity = array_pop( $identityArr );
613 sqlsrv_free_stmt( $res );
615 // Determine binary/varbinary fields so we can encode data as a hex string like 0xABCDEF
616 $binaryColumns = $this->getBinaryColumns( $table );
618 // INSERT IGNORE is not supported by SQL Server
619 // remove IGNORE from options list and set ignore flag to true
620 if ( in_array( 'IGNORE', $options ) ) {
621 $options = array_diff( $options, array( 'IGNORE' ) );
622 $this->mIgnoreDupKeyErrors
= true;
625 foreach ( $arrToInsert as $a ) {
626 // start out with empty identity column, this is so we can return
627 // it as a result of the insert logic
630 $identityClause = '';
632 // if we have an identity column
635 foreach ( $a as $k => $v ) {
636 if ( $k == $identity ) {
637 if ( !is_null( $v ) ) {
638 // there is a value being passed to us,
639 // we need to turn on and off inserted identity
640 $sqlPre = "SET IDENTITY_INSERT $table ON;";
641 $sqlPost = ";SET IDENTITY_INSERT $table OFF;";
643 // we can't insert NULL into an identity column,
644 // so remove the column from the insert.
650 // we want to output an identity column as result
651 $identityClause = "OUTPUT INSERTED.$identity ";
654 $keys = array_keys( $a );
656 // Build the actual query
657 $sql = $sqlPre . 'INSERT ' . implode( ' ', $options ) .
658 " INTO $table (" . implode( ',', $keys ) . ") $identityClause VALUES (";
661 foreach ( $a as $key => $value ) {
662 if ( isset( $binaryColumns[$key] ) ) {
663 $value = new MssqlBlob( $value );
670 if ( is_null( $value ) ) {
672 } elseif ( is_array( $value ) ||
is_object( $value ) ) {
673 if ( is_object( $value ) && $value instanceof Blob
) {
674 $sql .= $this->addQuotes( $value );
676 $sql .= $this->addQuotes( serialize( $value ) );
679 $sql .= $this->addQuotes( $value );
682 $sql .= ')' . $sqlPost;
685 $this->mScrollableCursor
= false;
687 $ret = $this->query( $sql );
688 } catch ( Exception
$e ) {
689 $this->mScrollableCursor
= true;
690 $this->mIgnoreDupKeyErrors
= false;
693 $this->mScrollableCursor
= true;
695 if ( !is_null( $identity ) ) {
696 // then we want to get the identity column value we were assigned and save it off
697 $row = $ret->fetchObject();
698 if ( is_object( $row ) ) {
699 $this->mInsertId
= $row->$identity;
703 $this->mIgnoreDupKeyErrors
= false;
708 * INSERT SELECT wrapper
709 * $varMap must be an associative array of the form array( 'dest1' => 'source1', ...)
710 * Source items may be literals rather than field names, but strings should
711 * be quoted with Database::addQuotes().
712 * @param string $destTable
713 * @param array|string $srcTable May be an array of tables.
714 * @param array $varMap
715 * @param array $conds May be "*" to copy the whole table.
716 * @param string $fname
717 * @param array $insertOptions
718 * @param array $selectOptions
719 * @return null|ResultWrapper
722 public function insertSelect( $destTable, $srcTable, $varMap, $conds, $fname = __METHOD__
,
723 $insertOptions = array(), $selectOptions = array()
725 $this->mScrollableCursor
= false;
727 $ret = parent
::insertSelect(
736 } catch ( Exception
$e ) {
737 $this->mScrollableCursor
= true;
740 $this->mScrollableCursor
= true;
746 * UPDATE wrapper. Takes a condition array and a SET array.
748 * @param string $table Name of the table to UPDATE. This will be passed through
749 * DatabaseBase::tableName().
751 * @param array $values An array of values to SET. For each array element,
752 * the key gives the field name, and the value gives the data
753 * to set that field to. The data will be quoted by
754 * DatabaseBase::addQuotes().
756 * @param array $conds An array of conditions (WHERE). See
757 * DatabaseBase::select() for the details of the format of
758 * condition arrays. Use '*' to update all rows.
760 * @param string $fname The function name of the caller (from __METHOD__),
761 * for logging and profiling.
763 * @param array $options An array of UPDATE options, can be:
764 * - IGNORE: Ignore unique key conflicts
765 * - LOW_PRIORITY: MySQL-specific, see MySQL manual.
767 * @throws DBUnexpectedError
769 * @throws MWException
771 function update( $table, $values, $conds, $fname = __METHOD__
, $options = array() ) {
772 $table = $this->tableName( $table );
773 $binaryColumns = $this->getBinaryColumns( $table );
775 $opts = $this->makeUpdateOptions( $options );
776 $sql = "UPDATE $opts $table SET " . $this->makeList( $values, LIST_SET
, $binaryColumns );
778 if ( $conds !== array() && $conds !== '*' ) {
779 $sql .= " WHERE " . $this->makeList( $conds, LIST_AND
, $binaryColumns );
782 $this->mScrollableCursor
= false;
784 $ret = $this->query( $sql );
785 } catch ( Exception
$e ) {
786 $this->mScrollableCursor
= true;
789 $this->mScrollableCursor
= true;
794 * Makes an encoded list of strings from an array
795 * @param array $a Containing the data
796 * @param int $mode Constant
797 * - LIST_COMMA: comma separated, no field names
798 * - LIST_AND: ANDed WHERE clause (without the WHERE). See
799 * the documentation for $conds in DatabaseBase::select().
800 * - LIST_OR: ORed WHERE clause (without the WHERE)
801 * - LIST_SET: comma separated with field names, like a SET clause
802 * - LIST_NAMES: comma separated field names
803 * @param array $binaryColumns Contains a list of column names that are binary types
804 * This is a custom parameter only present for MS SQL.
806 * @throws MWException|DBUnexpectedError
809 public function makeList( $a, $mode = LIST_COMMA
, $binaryColumns = array() ) {
810 if ( !is_array( $a ) ) {
811 throw new DBUnexpectedError( $this,
812 'DatabaseBase::makeList called with incorrect parameters' );
818 foreach ( $a as $field => $value ) {
819 if ( $mode != LIST_NAMES
&& isset( $binaryColumns[$field] ) ) {
820 if ( is_array( $value ) ) {
821 foreach ( $value as &$v ) {
822 $v = new MssqlBlob( $v );
825 $value = new MssqlBlob( $value );
830 if ( $mode == LIST_AND
) {
832 } elseif ( $mode == LIST_OR
) {
841 if ( ( $mode == LIST_AND ||
$mode == LIST_OR
) && is_numeric( $field ) ) {
843 } elseif ( ( $mode == LIST_SET
) && is_numeric( $field ) ) {
845 } elseif ( ( $mode == LIST_AND ||
$mode == LIST_OR
) && is_array( $value ) ) {
846 if ( count( $value ) == 0 ) {
847 throw new MWException( __METHOD__
. ": empty input for field $field" );
848 } elseif ( count( $value ) == 1 ) {
849 // Special-case single values, as IN isn't terribly efficient
850 // Don't necessarily assume the single key is 0; we don't
851 // enforce linear numeric ordering on other arrays here.
852 $value = array_values( $value );
853 $list .= $field . " = " . $this->addQuotes( $value[0] );
855 $list .= $field . " IN (" . $this->makeList( $value ) . ") ";
857 } elseif ( $value === null ) {
858 if ( $mode == LIST_AND ||
$mode == LIST_OR
) {
859 $list .= "$field IS ";
860 } elseif ( $mode == LIST_SET
) {
861 $list .= "$field = ";
865 if ( $mode == LIST_AND ||
$mode == LIST_OR ||
$mode == LIST_SET
) {
866 $list .= "$field = ";
868 $list .= $mode == LIST_NAMES ?
$value : $this->addQuotes( $value );
876 * @param string $table
877 * @param string $field
878 * @return int Returns the size of a text field, or -1 for "unlimited"
880 public function textFieldSize( $table, $field ) {
881 $table = $this->tableName( $table );
882 $sql = "SELECT CHARACTER_MAXIMUM_LENGTH,DATA_TYPE FROM INFORMATION_SCHEMA.Columns
883 WHERE TABLE_NAME = '$table' AND COLUMN_NAME = '$field'";
884 $res = $this->query( $sql );
885 $row = $this->fetchRow( $res );
887 if ( strtolower( $row['DATA_TYPE'] ) != 'text' ) {
888 $size = $row['CHARACTER_MAXIMUM_LENGTH'];
895 * Construct a LIMIT query with optional offset
896 * This is used for query pages
898 * @param string $sql SQL query we will append the limit too
899 * @param int $limit The SQL limit
900 * @param bool|int $offset The SQL offset (default false)
901 * @return array|string
902 * @throws DBUnexpectedError
904 public function limitResult( $sql, $limit, $offset = false ) {
905 if ( $offset === false ||
$offset == 0 ) {
906 if ( strpos( $sql, "SELECT" ) === false ) {
907 return "TOP {$limit} " . $sql;
909 return preg_replace( '/\bSELECT(\s+DISTINCT)?\b/Dsi',
910 'SELECT$1 TOP ' . $limit, $sql, 1 );
913 // This one is fun, we need to pull out the select list as well as any ORDER BY clause
914 $select = $orderby = array();
915 $s1 = preg_match( '#SELECT\s+(.+?)\s+FROM#Dis', $sql, $select );
916 $s2 = preg_match( '#(ORDER BY\s+.+?)(\s*FOR XML .*)?$#Dis', $sql, $orderby );
917 $overOrder = $postOrder = '';
918 $first = $offset +
1;
919 $last = $offset +
$limit;
920 $sub1 = 'sub_' . $this->mSubqueryId
;
921 $sub2 = 'sub_' . ( $this->mSubqueryId +
1 );
922 $this->mSubqueryId +
= 2;
925 throw new DBUnexpectedError( $this, "Attempting to LIMIT a non-SELECT query\n" );
929 $overOrder = 'ORDER BY (SELECT 1)';
931 if ( !isset( $orderby[2] ) ||
!$orderby[2] ) {
932 // don't need to strip it out if we're using a FOR XML clause
933 $sql = str_replace( $orderby[1], '', $sql );
935 $overOrder = $orderby[1];
936 $postOrder = ' ' . $overOrder;
938 $sql = "SELECT {$select[1]}
940 SELECT ROW_NUMBER() OVER({$overOrder}) AS rowNumber, *
941 FROM ({$sql}) {$sub1}
943 WHERE rowNumber BETWEEN {$first} AND {$last}{$postOrder}";
950 * If there is a limit clause, parse it, strip it, and pass the remaining
951 * SQL through limitResult() with the appropriate parameters. Not the
952 * prettiest solution, but better than building a whole new parser. This
953 * exists becase there are still too many extensions that don't use dynamic
957 * @return array|mixed|string
959 public function LimitToTopN( $sql ) {
960 // Matches: LIMIT {[offset,] row_count | row_count OFFSET offset}
961 $pattern = '/\bLIMIT\s+((([0-9]+)\s*,\s*)?([0-9]+)(\s+OFFSET\s+([0-9]+))?)/i';
962 if ( preg_match( $pattern, $sql, $matches ) ) {
963 $row_count = $matches[4];
964 $offset = $matches[3] ?
: $matches[6] ?
: false;
966 // strip the matching LIMIT clause out
967 $sql = str_replace( $matches[0], '', $sql );
969 return $this->limitResult( $sql, $row_count, $offset );
976 * @return string Wikitext of a link to the server software's web site
978 public function getSoftwareLink() {
979 return "[{{int:version-db-mssql-url}} MS SQL Server]";
983 * @return string Version information from the database
985 public function getServerVersion() {
986 $server_info = sqlsrv_server_info( $this->mConn
);
988 if ( isset( $server_info['SQLServerVersion'] ) ) {
989 $version = $server_info['SQLServerVersion'];
996 * @param string $table
997 * @param string $fname
1000 public function tableExists( $table, $fname = __METHOD__
) {
1001 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
1003 if ( $db !== false ) {
1005 wfDebug( "Attempting to call tableExists on a remote table" );
1009 if ( $schema === false ) {
1010 global $wgDBmwschema;
1011 $schema = $wgDBmwschema;
1014 $res = $this->query( "SELECT 1 FROM INFORMATION_SCHEMA.TABLES
1015 WHERE TABLE_TYPE = 'BASE TABLE'
1016 AND TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table'" );
1018 if ( $res->numRows() ) {
1026 * Query whether a given column exists in the mediawiki schema
1027 * @param string $table
1028 * @param string $field
1029 * @param string $fname
1032 public function fieldExists( $table, $field, $fname = __METHOD__
) {
1033 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
1035 if ( $db !== false ) {
1037 wfDebug( "Attempting to call fieldExists on a remote table" );
1041 $res = $this->query( "SELECT 1 FROM INFORMATION_SCHEMA.COLUMNS
1042 WHERE TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
1044 if ( $res->numRows() ) {
1051 public function fieldInfo( $table, $field ) {
1052 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
1054 if ( $db !== false ) {
1056 wfDebug( "Attempting to call fieldInfo on a remote table" );
1060 $res = $this->query( "SELECT * FROM INFORMATION_SCHEMA.COLUMNS
1061 WHERE TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
1063 $meta = $res->fetchRow();
1065 return new MssqlField( $meta );
1072 * Begin a transaction, committing any previously open transaction
1073 * @param string $fname
1075 protected function doBegin( $fname = __METHOD__
) {
1076 sqlsrv_begin_transaction( $this->mConn
);
1077 $this->mTrxLevel
= 1;
1082 * @param string $fname
1084 protected function doCommit( $fname = __METHOD__
) {
1085 sqlsrv_commit( $this->mConn
);
1086 $this->mTrxLevel
= 0;
1090 * Rollback a transaction.
1091 * No-op on non-transactional databases.
1092 * @param string $fname
1094 protected function doRollback( $fname = __METHOD__
) {
1095 sqlsrv_rollback( $this->mConn
);
1096 $this->mTrxLevel
= 0;
1100 * Escapes a identifier for use inm SQL.
1101 * Throws an exception if it is invalid.
1102 * Reference: http://msdn.microsoft.com/en-us/library/aa224033%28v=SQL.80%29.aspx
1103 * @param string $identifier
1104 * @throws MWException
1107 private function escapeIdentifier( $identifier ) {
1108 if ( strlen( $identifier ) == 0 ) {
1109 throw new MWException( "An identifier must not be empty" );
1111 if ( strlen( $identifier ) > 128 ) {
1112 throw new MWException( "The identifier '$identifier' is too long (max. 128)" );
1114 if ( ( strpos( $identifier, '[' ) !== false )
1115 ||
( strpos( $identifier, ']' ) !== false )
1117 // It may be allowed if you quoted with double quotation marks, but
1118 // that would break if QUOTED_IDENTIFIER is OFF
1119 throw new MWException( "Square brackets are not allowed in '$identifier'" );
1122 return "[$identifier]";
1129 public function strencode( $s ) { # Should not be called by us
1130 return str_replace( "'", "''", $s );
1137 public function addQuotes( $s ) {
1138 if ( $s instanceof MssqlBlob
) {
1140 } elseif ( $s instanceof Blob
) {
1141 // this shouldn't really ever be called, but it's here if needed
1142 // (and will quite possibly make the SQL error out)
1143 $blob = new MssqlBlob( $s->fetch() );
1144 return $blob->fetch();
1146 if ( is_bool( $s ) ) {
1149 return parent
::addQuotes( $s );
1157 public function addIdentifierQuotes( $s ) {
1158 // http://msdn.microsoft.com/en-us/library/aa223962.aspx
1159 return '[' . $s . ']';
1163 * @param string $name
1166 public function isQuotedIdentifier( $name ) {
1167 return strlen( $name ) && $name[0] == '[' && substr( $name, -1, 1 ) == ']';
1174 public function selectDB( $db ) {
1176 $this->mDBname
= $db;
1177 $this->query( "USE $db" );
1179 } catch ( Exception
$e ) {
1185 * @param array $options An associative array of options to be turned into
1186 * an SQL query, valid keys are listed in the function.
1189 public function makeSelectOptions( $options ) {
1193 $noKeyOptions = array();
1194 foreach ( $options as $key => $option ) {
1195 if ( is_numeric( $key ) ) {
1196 $noKeyOptions[$option] = true;
1200 $tailOpts .= $this->makeGroupByWithHaving( $options );
1202 $tailOpts .= $this->makeOrderBy( $options );
1204 if ( isset( $noKeyOptions['DISTINCT'] ) ||
isset( $noKeyOptions['DISTINCTROW'] ) ) {
1205 $startOpts .= 'DISTINCT';
1208 if ( isset( $noKeyOptions['FOR XML'] ) ) {
1209 // used in group concat field emulation
1210 $tailOpts .= " FOR XML PATH('')";
1213 // we want this to be compatible with the output of parent::makeSelectOptions()
1214 return array( $startOpts, '', $tailOpts, '' );
1218 * Get the type of the DBMS, as it appears in $wgDBtype.
1221 public function getType() {
1226 * @param array $stringList
1229 public function buildConcat( $stringList ) {
1230 return implode( ' + ', $stringList );
1234 * Build a GROUP_CONCAT or equivalent statement for a query.
1235 * MS SQL doesn't have GROUP_CONCAT so we emulate it with other stuff (and boy is it nasty)
1237 * This is useful for combining a field for several rows into a single string.
1238 * NULL values will not appear in the output, duplicated values will appear,
1239 * and the resulting delimiter-separated values have no defined sort order.
1240 * Code using the results may need to use the PHP unique() or sort() methods.
1242 * @param string $delim Glue to bind the results together
1243 * @param string|array $table Table name
1244 * @param string $field Field name
1245 * @param string|array $conds Conditions
1246 * @param string|array $join_conds Join conditions
1247 * @return string SQL text
1250 public function buildGroupConcatField( $delim, $table, $field, $conds = '',
1251 $join_conds = array()
1253 $gcsq = 'gcsq_' . $this->mSubqueryId
;
1254 $this->mSubqueryId++
;
1256 $delimLen = strlen( $delim );
1257 $fld = "{$field} + {$this->addQuotes( $delim )}";
1258 $sql = "(SELECT LEFT({$field}, LEN({$field}) - {$delimLen}) FROM ("
1259 . $this->selectSQLText( $table, $fld, $conds, null, array( 'FOR XML' ), $join_conds )
1260 . ") {$gcsq} ({$field}))";
1268 public function getSearchEngine() {
1269 return "SearchMssql";
1273 * Returns an associative array for fields that are of type varbinary, binary, or image
1274 * $table can be either a raw table name or passed through tableName() first
1275 * @param string $table
1278 private function getBinaryColumns( $table ) {
1279 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
1280 $tableRaw = array_pop( $tableRawArr );
1282 if ( $this->mBinaryColumnCache
=== null ) {
1283 $this->populateColumnCaches();
1286 return isset( $this->mBinaryColumnCache
[$tableRaw] )
1287 ?
$this->mBinaryColumnCache
[$tableRaw]
1292 * @param string $table
1295 private function getBitColumns( $table ) {
1296 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
1297 $tableRaw = array_pop( $tableRawArr );
1299 if ( $this->mBitColumnCache
=== null ) {
1300 $this->populateColumnCaches();
1303 return isset( $this->mBitColumnCache
[$tableRaw] )
1304 ?
$this->mBitColumnCache
[$tableRaw]
1308 private function populateColumnCaches() {
1309 $res = $this->select( 'INFORMATION_SCHEMA.COLUMNS', '*',
1311 'TABLE_CATALOG' => $this->mDBname
,
1312 'TABLE_SCHEMA' => $this->mSchema
,
1313 'DATA_TYPE' => array( 'varbinary', 'binary', 'image', 'bit' )
1316 $this->mBinaryColumnCache
= array();
1317 $this->mBitColumnCache
= array();
1318 foreach ( $res as $row ) {
1319 if ( $row->DATA_TYPE
== 'bit' ) {
1320 $this->mBitColumnCache
[$row->TABLE_NAME
][$row->COLUMN_NAME
] = $row;
1322 $this->mBinaryColumnCache
[$row->TABLE_NAME
][$row->COLUMN_NAME
] = $row;
1328 * @param string $name
1329 * @param string $format
1332 function tableName( $name, $format = 'quoted' ) {
1333 # Replace reserved words with better ones
1336 return $this->realTableName( 'mwuser', $format );
1338 return $this->realTableName( $name, $format );
1343 * call this instead of tableName() in the updater when renaming tables
1344 * @param string $name
1345 * @param string $format One of quoted, raw, or split
1348 function realTableName( $name, $format = 'quoted' ) {
1349 $table = parent
::tableName( $name, $format );
1350 if ( $format == 'split' ) {
1351 // Used internally, we want the schema split off from the table name and returned
1352 // as a list with 3 elements (database, schema, table)
1353 $table = explode( '.', $table );
1354 while ( count( $table ) < 3 ) {
1355 array_unshift( $table, false );
1362 * Called in the installer and updater.
1363 * Probably doesn't need to be called anywhere else in the codebase.
1364 * @param bool|null $value
1367 public function prepareStatements( $value = null ) {
1368 return wfSetVar( $this->mPrepareStatements
, $value );
1372 * Called in the installer and updater.
1373 * Probably doesn't need to be called anywhere else in the codebase.
1374 * @param bool|null $value
1377 public function scrollableCursor( $value = null ) {
1378 return wfSetVar( $this->mScrollableCursor
, $value );
1380 } // end DatabaseMssql class
1387 class MssqlField
implements Field
{
1388 private $name, $tableName, $default, $max_length, $nullable, $type;
1390 function __construct( $info ) {
1391 $this->name
= $info['COLUMN_NAME'];
1392 $this->tableName
= $info['TABLE_NAME'];
1393 $this->default = $info['COLUMN_DEFAULT'];
1394 $this->max_length
= $info['CHARACTER_MAXIMUM_LENGTH'];
1395 $this->nullable
= !( strtolower( $info['IS_NULLABLE'] ) == 'no' );
1396 $this->type
= $info['DATA_TYPE'];
1403 function tableName() {
1404 return $this->tableName
;
1407 function defaultValue() {
1408 return $this->default;
1411 function maxLength() {
1412 return $this->max_length
;
1415 function isNullable() {
1416 return $this->nullable
;
1424 class MssqlBlob
extends Blob
{
1425 public function __construct( $data ) {
1426 if ( $data instanceof MssqlBlob
) {
1428 } elseif ( $data instanceof Blob
) {
1429 $this->mData
= $data->fetch();
1430 } elseif ( is_array( $data ) && is_object( $data ) ) {
1431 $this->mData
= serialize( $data );
1433 $this->mData
= $data;
1438 * Returns an unquoted hex representation of a binary string
1439 * for insertion into varbinary-type fields
1442 public function fetch() {
1443 if ( $this->mData
=== null ) {
1448 $dataLength = strlen( $this->mData
);
1449 for ( $i = 0; $i < $dataLength; $i++
) {
1450 $ret .= bin2hex( pack( 'C', ord( $this->mData
[$i] ) ) );
1457 class MssqlResultWrapper
extends ResultWrapper
{
1458 private $mSeekTo = null;
1461 * @return stdClass|bool
1463 public function fetchObject() {
1464 $res = $this->result
;
1466 if ( $this->mSeekTo
!== null ) {
1467 $result = sqlsrv_fetch_object( $res, 'stdClass', array(),
1468 SQLSRV_SCROLL_ABSOLUTE
, $this->mSeekTo
);
1469 $this->mSeekTo
= null;
1471 $result = sqlsrv_fetch_object( $res );
1474 // MediaWiki expects us to return boolean false when there are no more rows instead of null
1475 if ( $result === null ) {
1483 * @return array|bool
1485 public function fetchRow() {
1486 $res = $this->result
;
1488 if ( $this->mSeekTo
!== null ) {
1489 $result = sqlsrv_fetch_array( $res, SQLSRV_FETCH_BOTH
,
1490 SQLSRV_SCROLL_ABSOLUTE
, $this->mSeekTo
);
1491 $this->mSeekTo
= null;
1493 $result = sqlsrv_fetch_array( $res );
1496 // MediaWiki expects us to return boolean false when there are no more rows instead of null
1497 if ( $result === null ) {
1508 public function seek( $row ) {
1509 $res = $this->result
;
1512 $numRows = $this->db
->numRows( $res );
1513 $row = intval( $row );
1515 if ( $numRows === 0 ) {
1517 } elseif ( $row < 0 ||
$row > $numRows - 1 ) {
1521 // Unlike MySQL, the seek actually happens on the next access
1522 $this->mSeekTo
= $row;