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