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