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