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