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