Merge "Improve "selfmove" message's wording"
[lhc/web/wiklou.git] / includes / libs / rdbms / database / DatabaseMssql.php
1 <?php
2 /**
3 * This is the MS SQL Server Native database abstraction layer.
4 *
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.
9 *
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.
14 *
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
19 *
20 * @file
21 * @ingroup Database
22 * @author Joel Penner <a-joelpe at microsoft dot com>
23 * @author Chris Pucci <a-cpucci at microsoft dot com>
24 * @author Ryan Biesemeyer <v-ryanbi at microsoft dot com>
25 * @author Ryan Schmidt <skizzerz at gmail dot com>
26 */
27
28 namespace Wikimedia\Rdbms;
29
30 use MediaWiki;
31 use Exception;
32 use stdClass;
33
34 /**
35 * @ingroup Database
36 */
37 class DatabaseMssql extends Database {
38 protected $mPort;
39 protected $mUseWindowsAuth = false;
40
41 protected $mInsertId = null;
42 protected $mLastResult = null;
43 protected $mAffectedRows = null;
44 protected $mSubqueryId = 0;
45 protected $mScrollableCursor = true;
46 protected $mPrepareStatements = true;
47 protected $mBinaryColumnCache = null;
48 protected $mBitColumnCache = null;
49 protected $mIgnoreDupKeyErrors = false;
50 protected $mIgnoreErrors = [];
51
52 public function implicitGroupby() {
53 return false;
54 }
55
56 public function implicitOrderby() {
57 return false;
58 }
59
60 public function unionSupportsOrderAndLimit() {
61 return false;
62 }
63
64 public function __construct( array $params ) {
65 $this->mPort = $params['port'];
66 $this->mUseWindowsAuth = $params['UseWindowsAuth'];
67
68 parent::__construct( $params );
69 }
70
71 /**
72 * Usually aborts on failure
73 * @param string $server
74 * @param string $user
75 * @param string $password
76 * @param string $dbName
77 * @throws DBConnectionError
78 * @return bool|resource|null
79 */
80 public function open( $server, $user, $password, $dbName ) {
81 # Test for driver support, to avoid suppressed fatal error
82 if ( !function_exists( 'sqlsrv_connect' ) ) {
83 throw new DBConnectionError(
84 $this,
85 "Microsoft SQL Server Native (sqlsrv) functions missing.
86 You can download the driver from: http://go.microsoft.com/fwlink/?LinkId=123470\n"
87 );
88 }
89
90 # e.g. the class is being loaded
91 if ( !strlen( $user ) ) {
92 return null;
93 }
94
95 $this->close();
96 $this->mServer = $server;
97 $this->mUser = $user;
98 $this->mPassword = $password;
99 $this->mDBname = $dbName;
100
101 $connectionInfo = [];
102
103 if ( $dbName ) {
104 $connectionInfo['Database'] = $dbName;
105 }
106
107 // Decide which auth scenerio to use
108 // if we are using Windows auth, then don't add credentials to $connectionInfo
109 if ( !$this->mUseWindowsAuth ) {
110 $connectionInfo['UID'] = $user;
111 $connectionInfo['PWD'] = $password;
112 }
113
114 MediaWiki\suppressWarnings();
115 $this->mConn = sqlsrv_connect( $server, $connectionInfo );
116 MediaWiki\restoreWarnings();
117
118 if ( $this->mConn === false ) {
119 throw new DBConnectionError( $this, $this->lastError() );
120 }
121
122 $this->mOpened = true;
123
124 return $this->mConn;
125 }
126
127 /**
128 * Closes a database connection, if it is open
129 * Returns success, true if already closed
130 * @return bool
131 */
132 protected function closeConnection() {
133 return sqlsrv_close( $this->mConn );
134 }
135
136 /**
137 * @param bool|MssqlResultWrapper|resource $result
138 * @return bool|MssqlResultWrapper
139 */
140 protected function resultObject( $result ) {
141 if ( !$result ) {
142 return false;
143 } elseif ( $result instanceof MssqlResultWrapper ) {
144 return $result;
145 } elseif ( $result === true ) {
146 // Successful write query
147 return $result;
148 } else {
149 return new MssqlResultWrapper( $this, $result );
150 }
151 }
152
153 /**
154 * @param string $sql
155 * @return bool|MssqlResultWrapper|resource
156 * @throws DBUnexpectedError
157 */
158 protected function doQuery( $sql ) {
159 // several extensions seem to think that all databases support limits
160 // via LIMIT N after the WHERE clause, but MSSQL uses SELECT TOP N,
161 // so to catch any of those extensions we'll do a quick check for a
162 // LIMIT clause and pass $sql through $this->LimitToTopN() which parses
163 // the LIMIT clause and passes the result to $this->limitResult();
164 if ( preg_match( '/\bLIMIT\s*/i', $sql ) ) {
165 // massage LIMIT -> TopN
166 $sql = $this->LimitToTopN( $sql );
167 }
168
169 // MSSQL doesn't have EXTRACT(epoch FROM XXX)
170 if ( preg_match( '#\bEXTRACT\s*?\(\s*?EPOCH\s+FROM\b#i', $sql, $matches ) ) {
171 // This is same as UNIX_TIMESTAMP, we need to calc # of seconds from 1970
172 $sql = str_replace( $matches[0], "DATEDIFF(s,CONVERT(datetime,'1/1/1970'),", $sql );
173 }
174
175 // perform query
176
177 // SQLSRV_CURSOR_STATIC is slower than SQLSRV_CURSOR_CLIENT_BUFFERED (one of the two is
178 // needed if we want to be able to seek around the result set), however CLIENT_BUFFERED
179 // has a bug in the sqlsrv driver where wchar_t types (such as nvarchar) that are empty
180 // strings make php throw a fatal error "Severe error translating Unicode"
181 if ( $this->mScrollableCursor ) {
182 $scrollArr = [ 'Scrollable' => SQLSRV_CURSOR_STATIC ];
183 } else {
184 $scrollArr = [];
185 }
186
187 if ( $this->mPrepareStatements ) {
188 // we do prepare + execute so we can get its field metadata for later usage if desired
189 $stmt = sqlsrv_prepare( $this->mConn, $sql, [], $scrollArr );
190 $success = sqlsrv_execute( $stmt );
191 } else {
192 $stmt = sqlsrv_query( $this->mConn, $sql, [], $scrollArr );
193 $success = (bool)$stmt;
194 }
195
196 // Make a copy to ensure what we add below does not get reflected in future queries
197 $ignoreErrors = $this->mIgnoreErrors;
198
199 if ( $this->mIgnoreDupKeyErrors ) {
200 // ignore duplicate key errors
201 // this emulates INSERT IGNORE in MySQL
202 $ignoreErrors[] = '2601'; // duplicate key error caused by unique index
203 $ignoreErrors[] = '2627'; // duplicate key error caused by primary key
204 $ignoreErrors[] = '3621'; // generic "the statement has been terminated" error
205 }
206
207 if ( $success === false ) {
208 $errors = sqlsrv_errors();
209 $success = true;
210
211 foreach ( $errors as $err ) {
212 if ( !in_array( $err['code'], $ignoreErrors ) ) {
213 $success = false;
214 break;
215 }
216 }
217
218 if ( $success === false ) {
219 return false;
220 }
221 }
222 // remember number of rows affected
223 $this->mAffectedRows = sqlsrv_rows_affected( $stmt );
224
225 return $stmt;
226 }
227
228 public function freeResult( $res ) {
229 if ( $res instanceof ResultWrapper ) {
230 $res = $res->result;
231 }
232
233 sqlsrv_free_stmt( $res );
234 }
235
236 /**
237 * @param MssqlResultWrapper $res
238 * @return stdClass
239 */
240 public function fetchObject( $res ) {
241 // $res is expected to be an instance of MssqlResultWrapper here
242 return $res->fetchObject();
243 }
244
245 /**
246 * @param MssqlResultWrapper $res
247 * @return array
248 */
249 public function fetchRow( $res ) {
250 return $res->fetchRow();
251 }
252
253 /**
254 * @param mixed $res
255 * @return int
256 */
257 public function numRows( $res ) {
258 if ( $res instanceof ResultWrapper ) {
259 $res = $res->result;
260 }
261
262 $ret = sqlsrv_num_rows( $res );
263
264 if ( $ret === false ) {
265 // we cannot get an amount of rows from this cursor type
266 // has_rows returns bool true/false if the result has rows
267 $ret = (int)sqlsrv_has_rows( $res );
268 }
269
270 return $ret;
271 }
272
273 /**
274 * @param mixed $res
275 * @return int
276 */
277 public function numFields( $res ) {
278 if ( $res instanceof ResultWrapper ) {
279 $res = $res->result;
280 }
281
282 return sqlsrv_num_fields( $res );
283 }
284
285 /**
286 * @param mixed $res
287 * @param int $n
288 * @return int
289 */
290 public function fieldName( $res, $n ) {
291 if ( $res instanceof ResultWrapper ) {
292 $res = $res->result;
293 }
294
295 return sqlsrv_field_metadata( $res )[$n]['Name'];
296 }
297
298 /**
299 * This must be called after nextSequenceVal
300 * @return int|null
301 */
302 public function insertId() {
303 return $this->mInsertId;
304 }
305
306 /**
307 * @param MssqlResultWrapper $res
308 * @param int $row
309 * @return bool
310 */
311 public function dataSeek( $res, $row ) {
312 return $res->seek( $row );
313 }
314
315 /**
316 * @return string
317 */
318 public function lastError() {
319 $strRet = '';
320 $retErrors = sqlsrv_errors( SQLSRV_ERR_ALL );
321 if ( $retErrors != null ) {
322 foreach ( $retErrors as $arrError ) {
323 $strRet .= $this->formatError( $arrError ) . "\n";
324 }
325 } else {
326 $strRet = "No errors found";
327 }
328
329 return $strRet;
330 }
331
332 /**
333 * @param array $err
334 * @return string
335 */
336 private function formatError( $err ) {
337 return '[SQLSTATE ' .
338 $err['SQLSTATE'] . '][Error Code ' . $err['code'] . ']' . $err['message'];
339 }
340
341 /**
342 * @return string|int
343 */
344 public function lastErrno() {
345 $err = sqlsrv_errors( SQLSRV_ERR_ALL );
346 if ( $err !== null && isset( $err[0] ) ) {
347 return $err[0]['code'];
348 } else {
349 return 0;
350 }
351 }
352
353 /**
354 * @return int
355 */
356 public function affectedRows() {
357 return $this->mAffectedRows;
358 }
359
360 /**
361 * SELECT wrapper
362 *
363 * @param mixed $table Array or string, table name(s) (prefix auto-added)
364 * @param mixed $vars Array or string, field name(s) to be retrieved
365 * @param mixed $conds Array or string, condition(s) for WHERE
366 * @param string $fname Calling function name (use __METHOD__) for logs/profiling
367 * @param array $options Associative array of options (e.g.
368 * [ 'GROUP BY' => 'page_title' ]), see Database::makeSelectOptions
369 * code for list of supported stuff
370 * @param array $join_conds Associative array of table join conditions
371 * (optional) (e.g. [ 'page' => [ 'LEFT JOIN','page_latest=rev_id' ] ]
372 * @return mixed Database result resource (feed to Database::fetchObject
373 * or whatever), or false on failure
374 * @throws DBQueryError
375 * @throws DBUnexpectedError
376 * @throws Exception
377 */
378 public function select( $table, $vars, $conds = '', $fname = __METHOD__,
379 $options = [], $join_conds = []
380 ) {
381 $sql = $this->selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
382 if ( isset( $options['EXPLAIN'] ) ) {
383 try {
384 $this->mScrollableCursor = false;
385 $this->mPrepareStatements = false;
386 $this->query( "SET SHOWPLAN_ALL ON" );
387 $ret = $this->query( $sql, $fname );
388 $this->query( "SET SHOWPLAN_ALL OFF" );
389 } catch ( DBQueryError $dqe ) {
390 if ( isset( $options['FOR COUNT'] ) ) {
391 // likely don't have privs for SHOWPLAN, so run a select count instead
392 $this->query( "SET SHOWPLAN_ALL OFF" );
393 unset( $options['EXPLAIN'] );
394 $ret = $this->select(
395 $table,
396 'COUNT(*) AS EstimateRows',
397 $conds,
398 $fname,
399 $options,
400 $join_conds
401 );
402 } else {
403 // someone actually wanted the query plan instead of an est row count
404 // let them know of the error
405 $this->mScrollableCursor = true;
406 $this->mPrepareStatements = true;
407 throw $dqe;
408 }
409 }
410 $this->mScrollableCursor = true;
411 $this->mPrepareStatements = true;
412 return $ret;
413 }
414 return $this->query( $sql, $fname );
415 }
416
417 /**
418 * SELECT wrapper
419 *
420 * @param mixed $table Array or string, table name(s) (prefix auto-added)
421 * @param mixed $vars Array or string, field name(s) to be retrieved
422 * @param mixed $conds Array or string, condition(s) for WHERE
423 * @param string $fname Calling function name (use __METHOD__) for logs/profiling
424 * @param array $options Associative array of options (e.g. [ 'GROUP BY' => 'page_title' ]),
425 * see Database::makeSelectOptions code for list of supported stuff
426 * @param array $join_conds Associative array of table join conditions (optional)
427 * (e.g. [ 'page' => [ 'LEFT JOIN','page_latest=rev_id' ] ]
428 * @return string The SQL text
429 */
430 public function selectSQLText( $table, $vars, $conds = '', $fname = __METHOD__,
431 $options = [], $join_conds = []
432 ) {
433 if ( isset( $options['EXPLAIN'] ) ) {
434 unset( $options['EXPLAIN'] );
435 }
436
437 $sql = parent::selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
438
439 // try to rewrite aggregations of bit columns (currently MAX and MIN)
440 if ( strpos( $sql, 'MAX(' ) !== false || strpos( $sql, 'MIN(' ) !== false ) {
441 $bitColumns = [];
442 if ( is_array( $table ) ) {
443 foreach ( $table as $t ) {
444 $bitColumns += $this->getBitColumns( $this->tableName( $t ) );
445 }
446 } else {
447 $bitColumns = $this->getBitColumns( $this->tableName( $table ) );
448 }
449
450 foreach ( $bitColumns as $col => $info ) {
451 $replace = [
452 "MAX({$col})" => "MAX(CAST({$col} AS tinyint))",
453 "MIN({$col})" => "MIN(CAST({$col} AS tinyint))",
454 ];
455 $sql = str_replace( array_keys( $replace ), array_values( $replace ), $sql );
456 }
457 }
458
459 return $sql;
460 }
461
462 public function deleteJoin( $delTable, $joinTable, $delVar, $joinVar, $conds,
463 $fname = __METHOD__
464 ) {
465 $this->mScrollableCursor = false;
466 try {
467 parent::deleteJoin( $delTable, $joinTable, $delVar, $joinVar, $conds, $fname );
468 } catch ( Exception $e ) {
469 $this->mScrollableCursor = true;
470 throw $e;
471 }
472 $this->mScrollableCursor = true;
473 }
474
475 public function delete( $table, $conds, $fname = __METHOD__ ) {
476 $this->mScrollableCursor = false;
477 try {
478 parent::delete( $table, $conds, $fname );
479 } catch ( Exception $e ) {
480 $this->mScrollableCursor = true;
481 throw $e;
482 }
483 $this->mScrollableCursor = true;
484 }
485
486 /**
487 * Estimate rows in dataset
488 * Returns estimated count, based on SHOWPLAN_ALL output
489 * This is not necessarily an accurate estimate, so use sparingly
490 * Returns -1 if count cannot be found
491 * Takes same arguments as Database::select()
492 * @param string $table
493 * @param string $vars
494 * @param string $conds
495 * @param string $fname
496 * @param array $options
497 * @return int
498 */
499 public function estimateRowCount( $table, $vars = '*', $conds = '',
500 $fname = __METHOD__, $options = []
501 ) {
502 // http://msdn2.microsoft.com/en-us/library/aa259203.aspx
503 $options['EXPLAIN'] = true;
504 $options['FOR COUNT'] = true;
505 $res = $this->select( $table, $vars, $conds, $fname, $options );
506
507 $rows = -1;
508 if ( $res ) {
509 $row = $this->fetchRow( $res );
510
511 if ( isset( $row['EstimateRows'] ) ) {
512 $rows = (int)$row['EstimateRows'];
513 }
514 }
515
516 return $rows;
517 }
518
519 /**
520 * Returns information about an index
521 * If errors are explicitly ignored, returns NULL on failure
522 * @param string $table
523 * @param string $index
524 * @param string $fname
525 * @return array|bool|null
526 */
527 public function indexInfo( $table, $index, $fname = __METHOD__ ) {
528 # This does not return the same info as MYSQL would, but that's OK
529 # because MediaWiki never uses the returned value except to check for
530 # the existence of indexes.
531 $sql = "sp_helpindex '" . $this->tableName( $table ) . "'";
532 $res = $this->query( $sql, $fname );
533
534 if ( !$res ) {
535 return null;
536 }
537
538 $result = [];
539 foreach ( $res as $row ) {
540 if ( $row->index_name == $index ) {
541 $row->Non_unique = !stristr( $row->index_description, "unique" );
542 $cols = explode( ", ", $row->index_keys );
543 foreach ( $cols as $col ) {
544 $row->Column_name = trim( $col );
545 $result[] = clone $row;
546 }
547 } elseif ( $index == 'PRIMARY' && stristr( $row->index_description, 'PRIMARY' ) ) {
548 $row->Non_unique = 0;
549 $cols = explode( ", ", $row->index_keys );
550 foreach ( $cols as $col ) {
551 $row->Column_name = trim( $col );
552 $result[] = clone $row;
553 }
554 }
555 }
556
557 return empty( $result ) ? false : $result;
558 }
559
560 /**
561 * INSERT wrapper, inserts an array into a table
562 *
563 * $arrToInsert may be a single associative array, or an array of these with numeric keys, for
564 * multi-row insert.
565 *
566 * Usually aborts on failure
567 * If errors are explicitly ignored, returns success
568 * @param string $table
569 * @param array $arrToInsert
570 * @param string $fname
571 * @param array $options
572 * @return bool
573 * @throws Exception
574 */
575 public function insert( $table, $arrToInsert, $fname = __METHOD__, $options = [] ) {
576 # No rows to insert, easy just return now
577 if ( !count( $arrToInsert ) ) {
578 return true;
579 }
580
581 if ( !is_array( $options ) ) {
582 $options = [ $options ];
583 }
584
585 $table = $this->tableName( $table );
586
587 if ( !( isset( $arrToInsert[0] ) && is_array( $arrToInsert[0] ) ) ) { // Not multi row
588 $arrToInsert = [ 0 => $arrToInsert ]; // make everything multi row compatible
589 }
590
591 // We know the table we're inserting into, get its identity column
592 $identity = null;
593 // strip matching square brackets and the db/schema from table name
594 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
595 $tableRaw = array_pop( $tableRawArr );
596 $res = $this->doQuery(
597 "SELECT NAME AS idColumn FROM SYS.IDENTITY_COLUMNS " .
598 "WHERE OBJECT_NAME(OBJECT_ID)='{$tableRaw}'"
599 );
600 if ( $res && sqlsrv_has_rows( $res ) ) {
601 // There is an identity for this table.
602 $identityArr = sqlsrv_fetch_array( $res, SQLSRV_FETCH_ASSOC );
603 $identity = array_pop( $identityArr );
604 }
605 sqlsrv_free_stmt( $res );
606
607 // Determine binary/varbinary fields so we can encode data as a hex string like 0xABCDEF
608 $binaryColumns = $this->getBinaryColumns( $table );
609
610 // INSERT IGNORE is not supported by SQL Server
611 // remove IGNORE from options list and set ignore flag to true
612 if ( in_array( 'IGNORE', $options ) ) {
613 $options = array_diff( $options, [ 'IGNORE' ] );
614 $this->mIgnoreDupKeyErrors = true;
615 }
616
617 $ret = null;
618 foreach ( $arrToInsert as $a ) {
619 // start out with empty identity column, this is so we can return
620 // it as a result of the INSERT logic
621 $sqlPre = '';
622 $sqlPost = '';
623 $identityClause = '';
624
625 // if we have an identity column
626 if ( $identity ) {
627 // iterate through
628 foreach ( $a as $k => $v ) {
629 if ( $k == $identity ) {
630 if ( !is_null( $v ) ) {
631 // there is a value being passed to us,
632 // we need to turn on and off inserted identity
633 $sqlPre = "SET IDENTITY_INSERT $table ON;";
634 $sqlPost = ";SET IDENTITY_INSERT $table OFF;";
635 } else {
636 // we can't insert NULL into an identity column,
637 // so remove the column from the insert.
638 unset( $a[$k] );
639 }
640 }
641 }
642
643 // we want to output an identity column as result
644 $identityClause = "OUTPUT INSERTED.$identity ";
645 }
646
647 $keys = array_keys( $a );
648
649 // Build the actual query
650 $sql = $sqlPre . 'INSERT ' . implode( ' ', $options ) .
651 " INTO $table (" . implode( ',', $keys ) . ") $identityClause VALUES (";
652
653 $first = true;
654 foreach ( $a as $key => $value ) {
655 if ( isset( $binaryColumns[$key] ) ) {
656 $value = new MssqlBlob( $value );
657 }
658 if ( $first ) {
659 $first = false;
660 } else {
661 $sql .= ',';
662 }
663 if ( is_null( $value ) ) {
664 $sql .= 'null';
665 } elseif ( is_array( $value ) || is_object( $value ) ) {
666 if ( is_object( $value ) && $value instanceof Blob ) {
667 $sql .= $this->addQuotes( $value );
668 } else {
669 $sql .= $this->addQuotes( serialize( $value ) );
670 }
671 } else {
672 $sql .= $this->addQuotes( $value );
673 }
674 }
675 $sql .= ')' . $sqlPost;
676
677 // Run the query
678 $this->mScrollableCursor = false;
679 try {
680 $ret = $this->query( $sql );
681 } catch ( Exception $e ) {
682 $this->mScrollableCursor = true;
683 $this->mIgnoreDupKeyErrors = false;
684 throw $e;
685 }
686 $this->mScrollableCursor = true;
687
688 if ( $ret instanceof ResultWrapper && !is_null( $identity ) ) {
689 // Then we want to get the identity column value we were assigned and save it off
690 $row = $ret->fetchObject();
691 if ( is_object( $row ) ) {
692 $this->mInsertId = $row->$identity;
693 // It seems that mAffectedRows is -1 sometimes when OUTPUT INSERTED.identity is
694 // used if we got an identity back, we know for sure a row was affected, so
695 // adjust that here
696 if ( $this->mAffectedRows == -1 ) {
697 $this->mAffectedRows = 1;
698 }
699 }
700 }
701 }
702
703 $this->mIgnoreDupKeyErrors = false;
704
705 return $ret;
706 }
707
708 /**
709 * INSERT SELECT wrapper
710 * $varMap must be an associative array of the form [ 'dest1' => 'source1', ... ]
711 * Source items may be literals rather than field names, but strings should
712 * be quoted with Database::addQuotes().
713 * @param string $destTable
714 * @param array|string $srcTable May be an array of tables.
715 * @param array $varMap
716 * @param array $conds May be "*" to copy the whole table.
717 * @param string $fname
718 * @param array $insertOptions
719 * @param array $selectOptions
720 * @param array $selectJoinConds
721 * @return null|ResultWrapper
722 * @throws Exception
723 */
724 public function nativeInsertSelect( $destTable, $srcTable, $varMap, $conds, $fname = __METHOD__,
725 $insertOptions = [], $selectOptions = [], $selectJoinConds = []
726 ) {
727 $this->mScrollableCursor = false;
728 try {
729 $ret = parent::nativeInsertSelect(
730 $destTable,
731 $srcTable,
732 $varMap,
733 $conds,
734 $fname,
735 $insertOptions,
736 $selectOptions,
737 $selectJoinConds
738 );
739 } catch ( Exception $e ) {
740 $this->mScrollableCursor = true;
741 throw $e;
742 }
743 $this->mScrollableCursor = true;
744
745 return $ret;
746 }
747
748 /**
749 * UPDATE wrapper. Takes a condition array and a SET array.
750 *
751 * @param string $table Name of the table to UPDATE. This will be passed through
752 * Database::tableName().
753 *
754 * @param array $values An array of values to SET. For each array element,
755 * the key gives the field name, and the value gives the data
756 * to set that field to. The data will be quoted by
757 * Database::addQuotes().
758 *
759 * @param array $conds An array of conditions (WHERE). See
760 * Database::select() for the details of the format of
761 * condition arrays. Use '*' to update all rows.
762 *
763 * @param string $fname The function name of the caller (from __METHOD__),
764 * for logging and profiling.
765 *
766 * @param array $options An array of UPDATE options, can be:
767 * - IGNORE: Ignore unique key conflicts
768 * - LOW_PRIORITY: MySQL-specific, see MySQL manual.
769 * @return bool
770 * @throws DBUnexpectedError
771 * @throws Exception
772 */
773 function update( $table, $values, $conds, $fname = __METHOD__, $options = [] ) {
774 $table = $this->tableName( $table );
775 $binaryColumns = $this->getBinaryColumns( $table );
776
777 $opts = $this->makeUpdateOptions( $options );
778 $sql = "UPDATE $opts $table SET " . $this->makeList( $values, LIST_SET, $binaryColumns );
779
780 if ( $conds !== [] && $conds !== '*' ) {
781 $sql .= " WHERE " . $this->makeList( $conds, LIST_AND, $binaryColumns );
782 }
783
784 $this->mScrollableCursor = false;
785 try {
786 $this->query( $sql );
787 } catch ( Exception $e ) {
788 $this->mScrollableCursor = true;
789 throw $e;
790 }
791 $this->mScrollableCursor = true;
792 return true;
793 }
794
795 /**
796 * Makes an encoded list of strings from an array
797 * @param array $a Containing the data
798 * @param int $mode Constant
799 * - LIST_COMMA: comma separated, no field names
800 * - LIST_AND: ANDed WHERE clause (without the WHERE). See
801 * the documentation for $conds in Database::select().
802 * - LIST_OR: ORed WHERE clause (without the WHERE)
803 * - LIST_SET: comma separated with field names, like a SET clause
804 * - LIST_NAMES: comma separated field names
805 * @param array $binaryColumns Contains a list of column names that are binary types
806 * This is a custom parameter only present for MS SQL.
807 *
808 * @throws DBUnexpectedError
809 * @return string
810 */
811 public function makeList( $a, $mode = LIST_COMMA, $binaryColumns = [] ) {
812 if ( !is_array( $a ) ) {
813 throw new DBUnexpectedError( $this, __METHOD__ . ' called with incorrect parameters' );
814 }
815
816 if ( $mode != LIST_NAMES ) {
817 // In MS SQL, values need to be specially encoded when they are
818 // inserted into binary fields. Perform this necessary encoding
819 // for the specified set of columns.
820 foreach ( array_keys( $a ) as $field ) {
821 if ( !isset( $binaryColumns[$field] ) ) {
822 continue;
823 }
824
825 if ( is_array( $a[$field] ) ) {
826 foreach ( $a[$field] as &$v ) {
827 $v = new MssqlBlob( $v );
828 }
829 unset( $v );
830 } else {
831 $a[$field] = new MssqlBlob( $a[$field] );
832 }
833 }
834 }
835
836 return parent::makeList( $a, $mode );
837 }
838
839 /**
840 * @param string $table
841 * @param string $field
842 * @return int Returns the size of a text field, or -1 for "unlimited"
843 */
844 public function textFieldSize( $table, $field ) {
845 $table = $this->tableName( $table );
846 $sql = "SELECT CHARACTER_MAXIMUM_LENGTH,DATA_TYPE FROM INFORMATION_SCHEMA.Columns
847 WHERE TABLE_NAME = '$table' AND COLUMN_NAME = '$field'";
848 $res = $this->query( $sql );
849 $row = $this->fetchRow( $res );
850 $size = -1;
851 if ( strtolower( $row['DATA_TYPE'] ) != 'text' ) {
852 $size = $row['CHARACTER_MAXIMUM_LENGTH'];
853 }
854
855 return $size;
856 }
857
858 /**
859 * Construct a LIMIT query with optional offset
860 * This is used for query pages
861 *
862 * @param string $sql SQL query we will append the limit too
863 * @param int $limit The SQL limit
864 * @param bool|int $offset The SQL offset (default false)
865 * @return array|string
866 * @throws DBUnexpectedError
867 */
868 public function limitResult( $sql, $limit, $offset = false ) {
869 if ( $offset === false || $offset == 0 ) {
870 if ( strpos( $sql, "SELECT" ) === false ) {
871 return "TOP {$limit} " . $sql;
872 } else {
873 return preg_replace( '/\bSELECT(\s+DISTINCT)?\b/Dsi',
874 'SELECT$1 TOP ' . $limit, $sql, 1 );
875 }
876 } else {
877 // This one is fun, we need to pull out the select list as well as any ORDER BY clause
878 $select = $orderby = [];
879 $s1 = preg_match( '#SELECT\s+(.+?)\s+FROM#Dis', $sql, $select );
880 $s2 = preg_match( '#(ORDER BY\s+.+?)(\s*FOR XML .*)?$#Dis', $sql, $orderby );
881 $postOrder = '';
882 $first = $offset + 1;
883 $last = $offset + $limit;
884 $sub1 = 'sub_' . $this->mSubqueryId;
885 $sub2 = 'sub_' . ( $this->mSubqueryId + 1 );
886 $this->mSubqueryId += 2;
887 if ( !$s1 ) {
888 // wat
889 throw new DBUnexpectedError( $this, "Attempting to LIMIT a non-SELECT query\n" );
890 }
891 if ( !$s2 ) {
892 // no ORDER BY
893 $overOrder = 'ORDER BY (SELECT 1)';
894 } else {
895 if ( !isset( $orderby[2] ) || !$orderby[2] ) {
896 // don't need to strip it out if we're using a FOR XML clause
897 $sql = str_replace( $orderby[1], '', $sql );
898 }
899 $overOrder = $orderby[1];
900 $postOrder = ' ' . $overOrder;
901 }
902 $sql = "SELECT {$select[1]}
903 FROM (
904 SELECT ROW_NUMBER() OVER({$overOrder}) AS rowNumber, *
905 FROM ({$sql}) {$sub1}
906 ) {$sub2}
907 WHERE rowNumber BETWEEN {$first} AND {$last}{$postOrder}";
908
909 return $sql;
910 }
911 }
912
913 /**
914 * If there is a limit clause, parse it, strip it, and pass the remaining
915 * SQL through limitResult() with the appropriate parameters. Not the
916 * prettiest solution, but better than building a whole new parser. This
917 * exists becase there are still too many extensions that don't use dynamic
918 * sql generation.
919 *
920 * @param string $sql
921 * @return array|mixed|string
922 */
923 public function LimitToTopN( $sql ) {
924 // Matches: LIMIT {[offset,] row_count | row_count OFFSET offset}
925 $pattern = '/\bLIMIT\s+((([0-9]+)\s*,\s*)?([0-9]+)(\s+OFFSET\s+([0-9]+))?)/i';
926 if ( preg_match( $pattern, $sql, $matches ) ) {
927 $row_count = $matches[4];
928 $offset = $matches[3] ?: $matches[6] ?: false;
929
930 // strip the matching LIMIT clause out
931 $sql = str_replace( $matches[0], '', $sql );
932
933 return $this->limitResult( $sql, $row_count, $offset );
934 }
935
936 return $sql;
937 }
938
939 /**
940 * @return string Wikitext of a link to the server software's web site
941 */
942 public function getSoftwareLink() {
943 return "[{{int:version-db-mssql-url}} MS SQL Server]";
944 }
945
946 /**
947 * @return string Version information from the database
948 */
949 public function getServerVersion() {
950 $server_info = sqlsrv_server_info( $this->mConn );
951 $version = 'Error';
952 if ( isset( $server_info['SQLServerVersion'] ) ) {
953 $version = $server_info['SQLServerVersion'];
954 }
955
956 return $version;
957 }
958
959 /**
960 * @param string $table
961 * @param string $fname
962 * @return bool
963 */
964 public function tableExists( $table, $fname = __METHOD__ ) {
965 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
966
967 if ( $db !== false ) {
968 // remote database
969 $this->queryLogger->error( "Attempting to call tableExists on a remote table" );
970 return false;
971 }
972
973 if ( $schema === false ) {
974 $schema = $this->mSchema;
975 }
976
977 $res = $this->query( "SELECT 1 FROM INFORMATION_SCHEMA.TABLES
978 WHERE TABLE_TYPE = 'BASE TABLE'
979 AND TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table'" );
980
981 if ( $res->numRows() ) {
982 return true;
983 } else {
984 return false;
985 }
986 }
987
988 /**
989 * Query whether a given column exists in the mediawiki schema
990 * @param string $table
991 * @param string $field
992 * @param string $fname
993 * @return bool
994 */
995 public function fieldExists( $table, $field, $fname = __METHOD__ ) {
996 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
997
998 if ( $db !== false ) {
999 // remote database
1000 $this->queryLogger->error( "Attempting to call fieldExists on a remote table" );
1001 return false;
1002 }
1003
1004 $res = $this->query( "SELECT 1 FROM INFORMATION_SCHEMA.COLUMNS
1005 WHERE TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
1006
1007 if ( $res->numRows() ) {
1008 return true;
1009 } else {
1010 return false;
1011 }
1012 }
1013
1014 public function fieldInfo( $table, $field ) {
1015 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
1016
1017 if ( $db !== false ) {
1018 // remote database
1019 $this->queryLogger->error( "Attempting to call fieldInfo on a remote table" );
1020 return false;
1021 }
1022
1023 $res = $this->query( "SELECT * FROM INFORMATION_SCHEMA.COLUMNS
1024 WHERE TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
1025
1026 $meta = $res->fetchRow();
1027 if ( $meta ) {
1028 return new MssqlField( $meta );
1029 }
1030
1031 return false;
1032 }
1033
1034 /**
1035 * Begin a transaction, committing any previously open transaction
1036 * @param string $fname
1037 */
1038 protected function doBegin( $fname = __METHOD__ ) {
1039 sqlsrv_begin_transaction( $this->mConn );
1040 $this->mTrxLevel = 1;
1041 }
1042
1043 /**
1044 * End a transaction
1045 * @param string $fname
1046 */
1047 protected function doCommit( $fname = __METHOD__ ) {
1048 sqlsrv_commit( $this->mConn );
1049 $this->mTrxLevel = 0;
1050 }
1051
1052 /**
1053 * Rollback a transaction.
1054 * No-op on non-transactional databases.
1055 * @param string $fname
1056 */
1057 protected function doRollback( $fname = __METHOD__ ) {
1058 sqlsrv_rollback( $this->mConn );
1059 $this->mTrxLevel = 0;
1060 }
1061
1062 /**
1063 * @param string $s
1064 * @return string
1065 */
1066 public function strencode( $s ) {
1067 // Should not be called by us
1068
1069 return str_replace( "'", "''", $s );
1070 }
1071
1072 /**
1073 * @param string|int|null|bool|Blob $s
1074 * @return string|int
1075 */
1076 public function addQuotes( $s ) {
1077 if ( $s instanceof MssqlBlob ) {
1078 return $s->fetch();
1079 } elseif ( $s instanceof Blob ) {
1080 // this shouldn't really ever be called, but it's here if needed
1081 // (and will quite possibly make the SQL error out)
1082 $blob = new MssqlBlob( $s->fetch() );
1083 return $blob->fetch();
1084 } else {
1085 if ( is_bool( $s ) ) {
1086 $s = $s ? 1 : 0;
1087 }
1088 return parent::addQuotes( $s );
1089 }
1090 }
1091
1092 /**
1093 * @param string $s
1094 * @return string
1095 */
1096 public function addIdentifierQuotes( $s ) {
1097 // http://msdn.microsoft.com/en-us/library/aa223962.aspx
1098 return '[' . $s . ']';
1099 }
1100
1101 /**
1102 * @param string $name
1103 * @return bool
1104 */
1105 public function isQuotedIdentifier( $name ) {
1106 return strlen( $name ) && $name[0] == '[' && substr( $name, -1, 1 ) == ']';
1107 }
1108
1109 /**
1110 * MS SQL supports more pattern operators than other databases (ex: [,],^)
1111 *
1112 * @param string $s
1113 * @param string $escapeChar
1114 * @return string
1115 */
1116 protected function escapeLikeInternal( $s, $escapeChar = '`' ) {
1117 return str_replace( [ $escapeChar, '%', '_', '[', ']', '^' ],
1118 [ "{$escapeChar}{$escapeChar}", "{$escapeChar}%", "{$escapeChar}_",
1119 "{$escapeChar}[", "{$escapeChar}]", "{$escapeChar}^" ],
1120 $s );
1121 }
1122
1123 /**
1124 * @param string $db
1125 * @return bool
1126 */
1127 public function selectDB( $db ) {
1128 try {
1129 $this->mDBname = $db;
1130 $this->query( "USE $db" );
1131 return true;
1132 } catch ( Exception $e ) {
1133 return false;
1134 }
1135 }
1136
1137 /**
1138 * @param array $options An associative array of options to be turned into
1139 * an SQL query, valid keys are listed in the function.
1140 * @return array
1141 */
1142 public function makeSelectOptions( $options ) {
1143 $tailOpts = '';
1144 $startOpts = '';
1145
1146 $noKeyOptions = [];
1147 foreach ( $options as $key => $option ) {
1148 if ( is_numeric( $key ) ) {
1149 $noKeyOptions[$option] = true;
1150 }
1151 }
1152
1153 $tailOpts .= $this->makeGroupByWithHaving( $options );
1154
1155 $tailOpts .= $this->makeOrderBy( $options );
1156
1157 if ( isset( $noKeyOptions['DISTINCT'] ) || isset( $noKeyOptions['DISTINCTROW'] ) ) {
1158 $startOpts .= 'DISTINCT';
1159 }
1160
1161 if ( isset( $noKeyOptions['FOR XML'] ) ) {
1162 // used in group concat field emulation
1163 $tailOpts .= " FOR XML PATH('')";
1164 }
1165
1166 // we want this to be compatible with the output of parent::makeSelectOptions()
1167 return [ $startOpts, '', $tailOpts, '', '' ];
1168 }
1169
1170 public function getType() {
1171 return 'mssql';
1172 }
1173
1174 /**
1175 * @param array $stringList
1176 * @return string
1177 */
1178 public function buildConcat( $stringList ) {
1179 return implode( ' + ', $stringList );
1180 }
1181
1182 /**
1183 * Build a GROUP_CONCAT or equivalent statement for a query.
1184 * MS SQL doesn't have GROUP_CONCAT so we emulate it with other stuff (and boy is it nasty)
1185 *
1186 * This is useful for combining a field for several rows into a single string.
1187 * NULL values will not appear in the output, duplicated values will appear,
1188 * and the resulting delimiter-separated values have no defined sort order.
1189 * Code using the results may need to use the PHP unique() or sort() methods.
1190 *
1191 * @param string $delim Glue to bind the results together
1192 * @param string|array $table Table name
1193 * @param string $field Field name
1194 * @param string|array $conds Conditions
1195 * @param string|array $join_conds Join conditions
1196 * @return string SQL text
1197 * @since 1.23
1198 */
1199 public function buildGroupConcatField( $delim, $table, $field, $conds = '',
1200 $join_conds = []
1201 ) {
1202 $gcsq = 'gcsq_' . $this->mSubqueryId;
1203 $this->mSubqueryId++;
1204
1205 $delimLen = strlen( $delim );
1206 $fld = "{$field} + {$this->addQuotes( $delim )}";
1207 $sql = "(SELECT LEFT({$field}, LEN({$field}) - {$delimLen}) FROM ("
1208 . $this->selectSQLText( $table, $fld, $conds, null, [ 'FOR XML' ], $join_conds )
1209 . ") {$gcsq} ({$field}))";
1210
1211 return $sql;
1212 }
1213
1214 /**
1215 * Returns an associative array for fields that are of type varbinary, binary, or image
1216 * $table can be either a raw table name or passed through tableName() first
1217 * @param string $table
1218 * @return array
1219 */
1220 private function getBinaryColumns( $table ) {
1221 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
1222 $tableRaw = array_pop( $tableRawArr );
1223
1224 if ( $this->mBinaryColumnCache === null ) {
1225 $this->populateColumnCaches();
1226 }
1227
1228 return isset( $this->mBinaryColumnCache[$tableRaw] )
1229 ? $this->mBinaryColumnCache[$tableRaw]
1230 : [];
1231 }
1232
1233 /**
1234 * @param string $table
1235 * @return array
1236 */
1237 private function getBitColumns( $table ) {
1238 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
1239 $tableRaw = array_pop( $tableRawArr );
1240
1241 if ( $this->mBitColumnCache === null ) {
1242 $this->populateColumnCaches();
1243 }
1244
1245 return isset( $this->mBitColumnCache[$tableRaw] )
1246 ? $this->mBitColumnCache[$tableRaw]
1247 : [];
1248 }
1249
1250 private function populateColumnCaches() {
1251 $res = $this->select( 'INFORMATION_SCHEMA.COLUMNS', '*',
1252 [
1253 'TABLE_CATALOG' => $this->mDBname,
1254 'TABLE_SCHEMA' => $this->mSchema,
1255 'DATA_TYPE' => [ 'varbinary', 'binary', 'image', 'bit' ]
1256 ] );
1257
1258 $this->mBinaryColumnCache = [];
1259 $this->mBitColumnCache = [];
1260 foreach ( $res as $row ) {
1261 if ( $row->DATA_TYPE == 'bit' ) {
1262 $this->mBitColumnCache[$row->TABLE_NAME][$row->COLUMN_NAME] = $row;
1263 } else {
1264 $this->mBinaryColumnCache[$row->TABLE_NAME][$row->COLUMN_NAME] = $row;
1265 }
1266 }
1267 }
1268
1269 /**
1270 * @param string $name
1271 * @param string $format
1272 * @return string
1273 */
1274 function tableName( $name, $format = 'quoted' ) {
1275 # Replace reserved words with better ones
1276 switch ( $name ) {
1277 case 'user':
1278 return $this->realTableName( 'mwuser', $format );
1279 default:
1280 return $this->realTableName( $name, $format );
1281 }
1282 }
1283
1284 /**
1285 * call this instead of tableName() in the updater when renaming tables
1286 * @param string $name
1287 * @param string $format One of quoted, raw, or split
1288 * @return string
1289 */
1290 function realTableName( $name, $format = 'quoted' ) {
1291 $table = parent::tableName( $name, $format );
1292 if ( $format == 'split' ) {
1293 // Used internally, we want the schema split off from the table name and returned
1294 // as a list with 3 elements (database, schema, table)
1295 $table = explode( '.', $table );
1296 while ( count( $table ) < 3 ) {
1297 array_unshift( $table, false );
1298 }
1299 }
1300 return $table;
1301 }
1302
1303 /**
1304 * Delete a table
1305 * @param string $tableName
1306 * @param string $fName
1307 * @return bool|ResultWrapper
1308 * @since 1.18
1309 */
1310 public function dropTable( $tableName, $fName = __METHOD__ ) {
1311 if ( !$this->tableExists( $tableName, $fName ) ) {
1312 return false;
1313 }
1314
1315 // parent function incorrectly appends CASCADE, which we don't want
1316 $sql = "DROP TABLE " . $this->tableName( $tableName );
1317
1318 return $this->query( $sql, $fName );
1319 }
1320
1321 /**
1322 * Called in the installer and updater.
1323 * Probably doesn't need to be called anywhere else in the codebase.
1324 * @param bool|null $value
1325 * @return bool|null
1326 */
1327 public function prepareStatements( $value = null ) {
1328 $old = $this->mPrepareStatements;
1329 if ( $value !== null ) {
1330 $this->mPrepareStatements = $value;
1331 }
1332
1333 return $old;
1334 }
1335
1336 /**
1337 * Called in the installer and updater.
1338 * Probably doesn't need to be called anywhere else in the codebase.
1339 * @param bool|null $value
1340 * @return bool|null
1341 */
1342 public function scrollableCursor( $value = null ) {
1343 $old = $this->mScrollableCursor;
1344 if ( $value !== null ) {
1345 $this->mScrollableCursor = $value;
1346 }
1347
1348 return $old;
1349 }
1350 }
1351
1352 class_alias( DatabaseMssql::class, 'DatabaseMssql' );