Merge "Rewrite pref cleanup script"
[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 protected function fetchAffectedRowCount() {
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 $tables = $table;
444 while ( $tables ) {
445 $t = array_pop( $tables );
446 if ( is_array( $t ) ) {
447 $tables = array_merge( $tables, $t );
448 } else {
449 $bitColumns += $this->getBitColumns( $this->tableName( $t ) );
450 }
451 }
452 } else {
453 $bitColumns = $this->getBitColumns( $this->tableName( $table ) );
454 }
455
456 foreach ( $bitColumns as $col => $info ) {
457 $replace = [
458 "MAX({$col})" => "MAX(CAST({$col} AS tinyint))",
459 "MIN({$col})" => "MIN(CAST({$col} AS tinyint))",
460 ];
461 $sql = str_replace( array_keys( $replace ), array_values( $replace ), $sql );
462 }
463 }
464
465 return $sql;
466 }
467
468 public function deleteJoin( $delTable, $joinTable, $delVar, $joinVar, $conds,
469 $fname = __METHOD__
470 ) {
471 $this->mScrollableCursor = false;
472 try {
473 parent::deleteJoin( $delTable, $joinTable, $delVar, $joinVar, $conds, $fname );
474 } catch ( Exception $e ) {
475 $this->mScrollableCursor = true;
476 throw $e;
477 }
478 $this->mScrollableCursor = true;
479 }
480
481 public function delete( $table, $conds, $fname = __METHOD__ ) {
482 $this->mScrollableCursor = false;
483 try {
484 parent::delete( $table, $conds, $fname );
485 } catch ( Exception $e ) {
486 $this->mScrollableCursor = true;
487 throw $e;
488 }
489 $this->mScrollableCursor = true;
490 }
491
492 /**
493 * Estimate rows in dataset
494 * Returns estimated count, based on SHOWPLAN_ALL output
495 * This is not necessarily an accurate estimate, so use sparingly
496 * Returns -1 if count cannot be found
497 * Takes same arguments as Database::select()
498 * @param string $table
499 * @param string $vars
500 * @param string $conds
501 * @param string $fname
502 * @param array $options
503 * @return int
504 */
505 public function estimateRowCount( $table, $vars = '*', $conds = '',
506 $fname = __METHOD__, $options = []
507 ) {
508 // http://msdn2.microsoft.com/en-us/library/aa259203.aspx
509 $options['EXPLAIN'] = true;
510 $options['FOR COUNT'] = true;
511 $res = $this->select( $table, $vars, $conds, $fname, $options );
512
513 $rows = -1;
514 if ( $res ) {
515 $row = $this->fetchRow( $res );
516
517 if ( isset( $row['EstimateRows'] ) ) {
518 $rows = (int)$row['EstimateRows'];
519 }
520 }
521
522 return $rows;
523 }
524
525 /**
526 * Returns information about an index
527 * If errors are explicitly ignored, returns NULL on failure
528 * @param string $table
529 * @param string $index
530 * @param string $fname
531 * @return array|bool|null
532 */
533 public function indexInfo( $table, $index, $fname = __METHOD__ ) {
534 # This does not return the same info as MYSQL would, but that's OK
535 # because MediaWiki never uses the returned value except to check for
536 # the existence of indexes.
537 $sql = "sp_helpindex '" . $this->tableName( $table ) . "'";
538 $res = $this->query( $sql, $fname );
539
540 if ( !$res ) {
541 return null;
542 }
543
544 $result = [];
545 foreach ( $res as $row ) {
546 if ( $row->index_name == $index ) {
547 $row->Non_unique = !stristr( $row->index_description, "unique" );
548 $cols = explode( ", ", $row->index_keys );
549 foreach ( $cols as $col ) {
550 $row->Column_name = trim( $col );
551 $result[] = clone $row;
552 }
553 } elseif ( $index == 'PRIMARY' && stristr( $row->index_description, 'PRIMARY' ) ) {
554 $row->Non_unique = 0;
555 $cols = explode( ", ", $row->index_keys );
556 foreach ( $cols as $col ) {
557 $row->Column_name = trim( $col );
558 $result[] = clone $row;
559 }
560 }
561 }
562
563 return empty( $result ) ? false : $result;
564 }
565
566 /**
567 * INSERT wrapper, inserts an array into a table
568 *
569 * $arrToInsert may be a single associative array, or an array of these with numeric keys, for
570 * multi-row insert.
571 *
572 * Usually aborts on failure
573 * If errors are explicitly ignored, returns success
574 * @param string $table
575 * @param array $arrToInsert
576 * @param string $fname
577 * @param array $options
578 * @return bool
579 * @throws Exception
580 */
581 public function insert( $table, $arrToInsert, $fname = __METHOD__, $options = [] ) {
582 # No rows to insert, easy just return now
583 if ( !count( $arrToInsert ) ) {
584 return true;
585 }
586
587 if ( !is_array( $options ) ) {
588 $options = [ $options ];
589 }
590
591 $table = $this->tableName( $table );
592
593 if ( !( isset( $arrToInsert[0] ) && is_array( $arrToInsert[0] ) ) ) { // Not multi row
594 $arrToInsert = [ 0 => $arrToInsert ]; // make everything multi row compatible
595 }
596
597 // We know the table we're inserting into, get its identity column
598 $identity = null;
599 // strip matching square brackets and the db/schema from table name
600 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
601 $tableRaw = array_pop( $tableRawArr );
602 $res = $this->doQuery(
603 "SELECT NAME AS idColumn FROM SYS.IDENTITY_COLUMNS " .
604 "WHERE OBJECT_NAME(OBJECT_ID)='{$tableRaw}'"
605 );
606 if ( $res && sqlsrv_has_rows( $res ) ) {
607 // There is an identity for this table.
608 $identityArr = sqlsrv_fetch_array( $res, SQLSRV_FETCH_ASSOC );
609 $identity = array_pop( $identityArr );
610 }
611 sqlsrv_free_stmt( $res );
612
613 // Determine binary/varbinary fields so we can encode data as a hex string like 0xABCDEF
614 $binaryColumns = $this->getBinaryColumns( $table );
615
616 // INSERT IGNORE is not supported by SQL Server
617 // remove IGNORE from options list and set ignore flag to true
618 if ( in_array( 'IGNORE', $options ) ) {
619 $options = array_diff( $options, [ 'IGNORE' ] );
620 $this->mIgnoreDupKeyErrors = true;
621 }
622
623 $ret = null;
624 foreach ( $arrToInsert as $a ) {
625 // start out with empty identity column, this is so we can return
626 // it as a result of the INSERT logic
627 $sqlPre = '';
628 $sqlPost = '';
629 $identityClause = '';
630
631 // if we have an identity column
632 if ( $identity ) {
633 // iterate through
634 foreach ( $a as $k => $v ) {
635 if ( $k == $identity ) {
636 if ( !is_null( $v ) ) {
637 // there is a value being passed to us,
638 // we need to turn on and off inserted identity
639 $sqlPre = "SET IDENTITY_INSERT $table ON;";
640 $sqlPost = ";SET IDENTITY_INSERT $table OFF;";
641 } else {
642 // we can't insert NULL into an identity column,
643 // so remove the column from the insert.
644 unset( $a[$k] );
645 }
646 }
647 }
648
649 // we want to output an identity column as result
650 $identityClause = "OUTPUT INSERTED.$identity ";
651 }
652
653 $keys = array_keys( $a );
654
655 // Build the actual query
656 $sql = $sqlPre . 'INSERT ' . implode( ' ', $options ) .
657 " INTO $table (" . implode( ',', $keys ) . ") $identityClause VALUES (";
658
659 $first = true;
660 foreach ( $a as $key => $value ) {
661 if ( isset( $binaryColumns[$key] ) ) {
662 $value = new MssqlBlob( $value );
663 }
664 if ( $first ) {
665 $first = false;
666 } else {
667 $sql .= ',';
668 }
669 if ( is_null( $value ) ) {
670 $sql .= 'null';
671 } elseif ( is_array( $value ) || is_object( $value ) ) {
672 if ( is_object( $value ) && $value instanceof Blob ) {
673 $sql .= $this->addQuotes( $value );
674 } else {
675 $sql .= $this->addQuotes( serialize( $value ) );
676 }
677 } else {
678 $sql .= $this->addQuotes( $value );
679 }
680 }
681 $sql .= ')' . $sqlPost;
682
683 // Run the query
684 $this->mScrollableCursor = false;
685 try {
686 $ret = $this->query( $sql );
687 } catch ( Exception $e ) {
688 $this->mScrollableCursor = true;
689 $this->mIgnoreDupKeyErrors = false;
690 throw $e;
691 }
692 $this->mScrollableCursor = true;
693
694 if ( $ret instanceof ResultWrapper && !is_null( $identity ) ) {
695 // Then we want to get the identity column value we were assigned and save it off
696 $row = $ret->fetchObject();
697 if ( is_object( $row ) ) {
698 $this->mInsertId = $row->$identity;
699 // It seems that mAffectedRows is -1 sometimes when OUTPUT INSERTED.identity is
700 // used if we got an identity back, we know for sure a row was affected, so
701 // adjust that here
702 if ( $this->mAffectedRows == -1 ) {
703 $this->mAffectedRows = 1;
704 }
705 }
706 }
707 }
708
709 $this->mIgnoreDupKeyErrors = false;
710
711 return $ret;
712 }
713
714 /**
715 * INSERT SELECT wrapper
716 * $varMap must be an associative array of the form [ 'dest1' => 'source1', ... ]
717 * Source items may be literals rather than field names, but strings should
718 * be quoted with Database::addQuotes().
719 * @param string $destTable
720 * @param array|string $srcTable May be an array of tables.
721 * @param array $varMap
722 * @param array $conds May be "*" to copy the whole table.
723 * @param string $fname
724 * @param array $insertOptions
725 * @param array $selectOptions
726 * @param array $selectJoinConds
727 * @return null|ResultWrapper
728 * @throws Exception
729 */
730 public function nativeInsertSelect( $destTable, $srcTable, $varMap, $conds, $fname = __METHOD__,
731 $insertOptions = [], $selectOptions = [], $selectJoinConds = []
732 ) {
733 $this->mScrollableCursor = false;
734 try {
735 $ret = parent::nativeInsertSelect(
736 $destTable,
737 $srcTable,
738 $varMap,
739 $conds,
740 $fname,
741 $insertOptions,
742 $selectOptions,
743 $selectJoinConds
744 );
745 } catch ( Exception $e ) {
746 $this->mScrollableCursor = true;
747 throw $e;
748 }
749 $this->mScrollableCursor = true;
750
751 return $ret;
752 }
753
754 /**
755 * UPDATE wrapper. Takes a condition array and a SET array.
756 *
757 * @param string $table Name of the table to UPDATE. This will be passed through
758 * Database::tableName().
759 *
760 * @param array $values An array of values to SET. For each array element,
761 * the key gives the field name, and the value gives the data
762 * to set that field to. The data will be quoted by
763 * Database::addQuotes().
764 *
765 * @param array $conds An array of conditions (WHERE). See
766 * Database::select() for the details of the format of
767 * condition arrays. Use '*' to update all rows.
768 *
769 * @param string $fname The function name of the caller (from __METHOD__),
770 * for logging and profiling.
771 *
772 * @param array $options An array of UPDATE options, can be:
773 * - IGNORE: Ignore unique key conflicts
774 * - LOW_PRIORITY: MySQL-specific, see MySQL manual.
775 * @return bool
776 * @throws DBUnexpectedError
777 * @throws Exception
778 */
779 function update( $table, $values, $conds, $fname = __METHOD__, $options = [] ) {
780 $table = $this->tableName( $table );
781 $binaryColumns = $this->getBinaryColumns( $table );
782
783 $opts = $this->makeUpdateOptions( $options );
784 $sql = "UPDATE $opts $table SET " . $this->makeList( $values, LIST_SET, $binaryColumns );
785
786 if ( $conds !== [] && $conds !== '*' ) {
787 $sql .= " WHERE " . $this->makeList( $conds, LIST_AND, $binaryColumns );
788 }
789
790 $this->mScrollableCursor = false;
791 try {
792 $this->query( $sql );
793 } catch ( Exception $e ) {
794 $this->mScrollableCursor = true;
795 throw $e;
796 }
797 $this->mScrollableCursor = true;
798 return true;
799 }
800
801 /**
802 * Makes an encoded list of strings from an array
803 * @param array $a Containing the data
804 * @param int $mode Constant
805 * - LIST_COMMA: comma separated, no field names
806 * - LIST_AND: ANDed WHERE clause (without the WHERE). See
807 * the documentation for $conds in Database::select().
808 * - LIST_OR: ORed WHERE clause (without the WHERE)
809 * - LIST_SET: comma separated with field names, like a SET clause
810 * - LIST_NAMES: comma separated field names
811 * @param array $binaryColumns Contains a list of column names that are binary types
812 * This is a custom parameter only present for MS SQL.
813 *
814 * @throws DBUnexpectedError
815 * @return string
816 */
817 public function makeList( $a, $mode = LIST_COMMA, $binaryColumns = [] ) {
818 if ( !is_array( $a ) ) {
819 throw new DBUnexpectedError( $this, __METHOD__ . ' called with incorrect parameters' );
820 }
821
822 if ( $mode != LIST_NAMES ) {
823 // In MS SQL, values need to be specially encoded when they are
824 // inserted into binary fields. Perform this necessary encoding
825 // for the specified set of columns.
826 foreach ( array_keys( $a ) as $field ) {
827 if ( !isset( $binaryColumns[$field] ) ) {
828 continue;
829 }
830
831 if ( is_array( $a[$field] ) ) {
832 foreach ( $a[$field] as &$v ) {
833 $v = new MssqlBlob( $v );
834 }
835 unset( $v );
836 } else {
837 $a[$field] = new MssqlBlob( $a[$field] );
838 }
839 }
840 }
841
842 return parent::makeList( $a, $mode );
843 }
844
845 /**
846 * @param string $table
847 * @param string $field
848 * @return int Returns the size of a text field, or -1 for "unlimited"
849 */
850 public function textFieldSize( $table, $field ) {
851 $table = $this->tableName( $table );
852 $sql = "SELECT CHARACTER_MAXIMUM_LENGTH,DATA_TYPE FROM INFORMATION_SCHEMA.Columns
853 WHERE TABLE_NAME = '$table' AND COLUMN_NAME = '$field'";
854 $res = $this->query( $sql );
855 $row = $this->fetchRow( $res );
856 $size = -1;
857 if ( strtolower( $row['DATA_TYPE'] ) != 'text' ) {
858 $size = $row['CHARACTER_MAXIMUM_LENGTH'];
859 }
860
861 return $size;
862 }
863
864 /**
865 * Construct a LIMIT query with optional offset
866 * This is used for query pages
867 *
868 * @param string $sql SQL query we will append the limit too
869 * @param int $limit The SQL limit
870 * @param bool|int $offset The SQL offset (default false)
871 * @return array|string
872 * @throws DBUnexpectedError
873 */
874 public function limitResult( $sql, $limit, $offset = false ) {
875 if ( $offset === false || $offset == 0 ) {
876 if ( strpos( $sql, "SELECT" ) === false ) {
877 return "TOP {$limit} " . $sql;
878 } else {
879 return preg_replace( '/\bSELECT(\s+DISTINCT)?\b/Dsi',
880 'SELECT$1 TOP ' . $limit, $sql, 1 );
881 }
882 } else {
883 // This one is fun, we need to pull out the select list as well as any ORDER BY clause
884 $select = $orderby = [];
885 $s1 = preg_match( '#SELECT\s+(.+?)\s+FROM#Dis', $sql, $select );
886 $s2 = preg_match( '#(ORDER BY\s+.+?)(\s*FOR XML .*)?$#Dis', $sql, $orderby );
887 $postOrder = '';
888 $first = $offset + 1;
889 $last = $offset + $limit;
890 $sub1 = 'sub_' . $this->mSubqueryId;
891 $sub2 = 'sub_' . ( $this->mSubqueryId + 1 );
892 $this->mSubqueryId += 2;
893 if ( !$s1 ) {
894 // wat
895 throw new DBUnexpectedError( $this, "Attempting to LIMIT a non-SELECT query\n" );
896 }
897 if ( !$s2 ) {
898 // no ORDER BY
899 $overOrder = 'ORDER BY (SELECT 1)';
900 } else {
901 if ( !isset( $orderby[2] ) || !$orderby[2] ) {
902 // don't need to strip it out if we're using a FOR XML clause
903 $sql = str_replace( $orderby[1], '', $sql );
904 }
905 $overOrder = $orderby[1];
906 $postOrder = ' ' . $overOrder;
907 }
908 $sql = "SELECT {$select[1]}
909 FROM (
910 SELECT ROW_NUMBER() OVER({$overOrder}) AS rowNumber, *
911 FROM ({$sql}) {$sub1}
912 ) {$sub2}
913 WHERE rowNumber BETWEEN {$first} AND {$last}{$postOrder}";
914
915 return $sql;
916 }
917 }
918
919 /**
920 * If there is a limit clause, parse it, strip it, and pass the remaining
921 * SQL through limitResult() with the appropriate parameters. Not the
922 * prettiest solution, but better than building a whole new parser. This
923 * exists becase there are still too many extensions that don't use dynamic
924 * sql generation.
925 *
926 * @param string $sql
927 * @return array|mixed|string
928 */
929 public function LimitToTopN( $sql ) {
930 // Matches: LIMIT {[offset,] row_count | row_count OFFSET offset}
931 $pattern = '/\bLIMIT\s+((([0-9]+)\s*,\s*)?([0-9]+)(\s+OFFSET\s+([0-9]+))?)/i';
932 if ( preg_match( $pattern, $sql, $matches ) ) {
933 $row_count = $matches[4];
934 $offset = $matches[3] ?: $matches[6] ?: false;
935
936 // strip the matching LIMIT clause out
937 $sql = str_replace( $matches[0], '', $sql );
938
939 return $this->limitResult( $sql, $row_count, $offset );
940 }
941
942 return $sql;
943 }
944
945 /**
946 * @return string Wikitext of a link to the server software's web site
947 */
948 public function getSoftwareLink() {
949 return "[{{int:version-db-mssql-url}} MS SQL Server]";
950 }
951
952 /**
953 * @return string Version information from the database
954 */
955 public function getServerVersion() {
956 $server_info = sqlsrv_server_info( $this->mConn );
957 $version = 'Error';
958 if ( isset( $server_info['SQLServerVersion'] ) ) {
959 $version = $server_info['SQLServerVersion'];
960 }
961
962 return $version;
963 }
964
965 /**
966 * @param string $table
967 * @param string $fname
968 * @return bool
969 */
970 public function tableExists( $table, $fname = __METHOD__ ) {
971 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
972
973 if ( $db !== false ) {
974 // remote database
975 $this->queryLogger->error( "Attempting to call tableExists on a remote table" );
976 return false;
977 }
978
979 if ( $schema === false ) {
980 $schema = $this->mSchema;
981 }
982
983 $res = $this->query( "SELECT 1 FROM INFORMATION_SCHEMA.TABLES
984 WHERE TABLE_TYPE = 'BASE TABLE'
985 AND TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table'" );
986
987 if ( $res->numRows() ) {
988 return true;
989 } else {
990 return false;
991 }
992 }
993
994 /**
995 * Query whether a given column exists in the mediawiki schema
996 * @param string $table
997 * @param string $field
998 * @param string $fname
999 * @return bool
1000 */
1001 public function fieldExists( $table, $field, $fname = __METHOD__ ) {
1002 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
1003
1004 if ( $db !== false ) {
1005 // remote database
1006 $this->queryLogger->error( "Attempting to call fieldExists on a remote table" );
1007 return false;
1008 }
1009
1010 $res = $this->query( "SELECT 1 FROM INFORMATION_SCHEMA.COLUMNS
1011 WHERE TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
1012
1013 if ( $res->numRows() ) {
1014 return true;
1015 } else {
1016 return false;
1017 }
1018 }
1019
1020 public function fieldInfo( $table, $field ) {
1021 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
1022
1023 if ( $db !== false ) {
1024 // remote database
1025 $this->queryLogger->error( "Attempting to call fieldInfo on a remote table" );
1026 return false;
1027 }
1028
1029 $res = $this->query( "SELECT * FROM INFORMATION_SCHEMA.COLUMNS
1030 WHERE TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
1031
1032 $meta = $res->fetchRow();
1033 if ( $meta ) {
1034 return new MssqlField( $meta );
1035 }
1036
1037 return false;
1038 }
1039
1040 /**
1041 * Begin a transaction, committing any previously open transaction
1042 * @param string $fname
1043 */
1044 protected function doBegin( $fname = __METHOD__ ) {
1045 sqlsrv_begin_transaction( $this->mConn );
1046 $this->mTrxLevel = 1;
1047 }
1048
1049 /**
1050 * End a transaction
1051 * @param string $fname
1052 */
1053 protected function doCommit( $fname = __METHOD__ ) {
1054 sqlsrv_commit( $this->mConn );
1055 $this->mTrxLevel = 0;
1056 }
1057
1058 /**
1059 * Rollback a transaction.
1060 * No-op on non-transactional databases.
1061 * @param string $fname
1062 */
1063 protected function doRollback( $fname = __METHOD__ ) {
1064 sqlsrv_rollback( $this->mConn );
1065 $this->mTrxLevel = 0;
1066 }
1067
1068 /**
1069 * @param string $s
1070 * @return string
1071 */
1072 public function strencode( $s ) {
1073 // Should not be called by us
1074 return str_replace( "'", "''", $s );
1075 }
1076
1077 /**
1078 * @param string|int|null|bool|Blob $s
1079 * @return string|int
1080 */
1081 public function addQuotes( $s ) {
1082 if ( $s instanceof MssqlBlob ) {
1083 return $s->fetch();
1084 } elseif ( $s instanceof Blob ) {
1085 // this shouldn't really ever be called, but it's here if needed
1086 // (and will quite possibly make the SQL error out)
1087 $blob = new MssqlBlob( $s->fetch() );
1088 return $blob->fetch();
1089 } else {
1090 if ( is_bool( $s ) ) {
1091 $s = $s ? 1 : 0;
1092 }
1093 return parent::addQuotes( $s );
1094 }
1095 }
1096
1097 /**
1098 * @param string $s
1099 * @return string
1100 */
1101 public function addIdentifierQuotes( $s ) {
1102 // http://msdn.microsoft.com/en-us/library/aa223962.aspx
1103 return '[' . $s . ']';
1104 }
1105
1106 /**
1107 * @param string $name
1108 * @return bool
1109 */
1110 public function isQuotedIdentifier( $name ) {
1111 return strlen( $name ) && $name[0] == '[' && substr( $name, -1, 1 ) == ']';
1112 }
1113
1114 /**
1115 * MS SQL supports more pattern operators than other databases (ex: [,],^)
1116 *
1117 * @param string $s
1118 * @param string $escapeChar
1119 * @return string
1120 */
1121 protected function escapeLikeInternal( $s, $escapeChar = '`' ) {
1122 return str_replace( [ $escapeChar, '%', '_', '[', ']', '^' ],
1123 [ "{$escapeChar}{$escapeChar}", "{$escapeChar}%", "{$escapeChar}_",
1124 "{$escapeChar}[", "{$escapeChar}]", "{$escapeChar}^" ],
1125 $s );
1126 }
1127
1128 /**
1129 * @param string $db
1130 * @return bool
1131 */
1132 public function selectDB( $db ) {
1133 try {
1134 $this->mDBname = $db;
1135 $this->query( "USE $db" );
1136 return true;
1137 } catch ( Exception $e ) {
1138 return false;
1139 }
1140 }
1141
1142 /**
1143 * @param array $options An associative array of options to be turned into
1144 * an SQL query, valid keys are listed in the function.
1145 * @return array
1146 */
1147 public function makeSelectOptions( $options ) {
1148 $tailOpts = '';
1149 $startOpts = '';
1150
1151 $noKeyOptions = [];
1152 foreach ( $options as $key => $option ) {
1153 if ( is_numeric( $key ) ) {
1154 $noKeyOptions[$option] = true;
1155 }
1156 }
1157
1158 $tailOpts .= $this->makeGroupByWithHaving( $options );
1159
1160 $tailOpts .= $this->makeOrderBy( $options );
1161
1162 if ( isset( $noKeyOptions['DISTINCT'] ) || isset( $noKeyOptions['DISTINCTROW'] ) ) {
1163 $startOpts .= 'DISTINCT';
1164 }
1165
1166 if ( isset( $noKeyOptions['FOR XML'] ) ) {
1167 // used in group concat field emulation
1168 $tailOpts .= " FOR XML PATH('')";
1169 }
1170
1171 // we want this to be compatible with the output of parent::makeSelectOptions()
1172 return [ $startOpts, '', $tailOpts, '', '' ];
1173 }
1174
1175 public function getType() {
1176 return 'mssql';
1177 }
1178
1179 /**
1180 * @param array $stringList
1181 * @return string
1182 */
1183 public function buildConcat( $stringList ) {
1184 return implode( ' + ', $stringList );
1185 }
1186
1187 /**
1188 * Build a GROUP_CONCAT or equivalent statement for a query.
1189 * MS SQL doesn't have GROUP_CONCAT so we emulate it with other stuff (and boy is it nasty)
1190 *
1191 * This is useful for combining a field for several rows into a single string.
1192 * NULL values will not appear in the output, duplicated values will appear,
1193 * and the resulting delimiter-separated values have no defined sort order.
1194 * Code using the results may need to use the PHP unique() or sort() methods.
1195 *
1196 * @param string $delim Glue to bind the results together
1197 * @param string|array $table Table name
1198 * @param string $field Field name
1199 * @param string|array $conds Conditions
1200 * @param string|array $join_conds Join conditions
1201 * @return string SQL text
1202 * @since 1.23
1203 */
1204 public function buildGroupConcatField( $delim, $table, $field, $conds = '',
1205 $join_conds = []
1206 ) {
1207 $gcsq = 'gcsq_' . $this->mSubqueryId;
1208 $this->mSubqueryId++;
1209
1210 $delimLen = strlen( $delim );
1211 $fld = "{$field} + {$this->addQuotes( $delim )}";
1212 $sql = "(SELECT LEFT({$field}, LEN({$field}) - {$delimLen}) FROM ("
1213 . $this->selectSQLText( $table, $fld, $conds, null, [ 'FOR XML' ], $join_conds )
1214 . ") {$gcsq} ({$field}))";
1215
1216 return $sql;
1217 }
1218
1219 /**
1220 * Returns an associative array for fields that are of type varbinary, binary, or image
1221 * $table can be either a raw table name or passed through tableName() first
1222 * @param string $table
1223 * @return array
1224 */
1225 private function getBinaryColumns( $table ) {
1226 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
1227 $tableRaw = array_pop( $tableRawArr );
1228
1229 if ( $this->mBinaryColumnCache === null ) {
1230 $this->populateColumnCaches();
1231 }
1232
1233 return isset( $this->mBinaryColumnCache[$tableRaw] )
1234 ? $this->mBinaryColumnCache[$tableRaw]
1235 : [];
1236 }
1237
1238 /**
1239 * @param string $table
1240 * @return array
1241 */
1242 private function getBitColumns( $table ) {
1243 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
1244 $tableRaw = array_pop( $tableRawArr );
1245
1246 if ( $this->mBitColumnCache === null ) {
1247 $this->populateColumnCaches();
1248 }
1249
1250 return isset( $this->mBitColumnCache[$tableRaw] )
1251 ? $this->mBitColumnCache[$tableRaw]
1252 : [];
1253 }
1254
1255 private function populateColumnCaches() {
1256 $res = $this->select( 'INFORMATION_SCHEMA.COLUMNS', '*',
1257 [
1258 'TABLE_CATALOG' => $this->mDBname,
1259 'TABLE_SCHEMA' => $this->mSchema,
1260 'DATA_TYPE' => [ 'varbinary', 'binary', 'image', 'bit' ]
1261 ] );
1262
1263 $this->mBinaryColumnCache = [];
1264 $this->mBitColumnCache = [];
1265 foreach ( $res as $row ) {
1266 if ( $row->DATA_TYPE == 'bit' ) {
1267 $this->mBitColumnCache[$row->TABLE_NAME][$row->COLUMN_NAME] = $row;
1268 } else {
1269 $this->mBinaryColumnCache[$row->TABLE_NAME][$row->COLUMN_NAME] = $row;
1270 }
1271 }
1272 }
1273
1274 /**
1275 * @param string $name
1276 * @param string $format
1277 * @return string
1278 */
1279 function tableName( $name, $format = 'quoted' ) {
1280 # Replace reserved words with better ones
1281 switch ( $name ) {
1282 case 'user':
1283 return $this->realTableName( 'mwuser', $format );
1284 default:
1285 return $this->realTableName( $name, $format );
1286 }
1287 }
1288
1289 /**
1290 * call this instead of tableName() in the updater when renaming tables
1291 * @param string $name
1292 * @param string $format One of quoted, raw, or split
1293 * @return string
1294 */
1295 function realTableName( $name, $format = 'quoted' ) {
1296 $table = parent::tableName( $name, $format );
1297 if ( $format == 'split' ) {
1298 // Used internally, we want the schema split off from the table name and returned
1299 // as a list with 3 elements (database, schema, table)
1300 $table = explode( '.', $table );
1301 while ( count( $table ) < 3 ) {
1302 array_unshift( $table, false );
1303 }
1304 }
1305 return $table;
1306 }
1307
1308 /**
1309 * Delete a table
1310 * @param string $tableName
1311 * @param string $fName
1312 * @return bool|ResultWrapper
1313 * @since 1.18
1314 */
1315 public function dropTable( $tableName, $fName = __METHOD__ ) {
1316 if ( !$this->tableExists( $tableName, $fName ) ) {
1317 return false;
1318 }
1319
1320 // parent function incorrectly appends CASCADE, which we don't want
1321 $sql = "DROP TABLE " . $this->tableName( $tableName );
1322
1323 return $this->query( $sql, $fName );
1324 }
1325
1326 /**
1327 * Called in the installer and updater.
1328 * Probably doesn't need to be called anywhere else in the codebase.
1329 * @param bool|null $value
1330 * @return bool|null
1331 */
1332 public function prepareStatements( $value = null ) {
1333 $old = $this->mPrepareStatements;
1334 if ( $value !== null ) {
1335 $this->mPrepareStatements = $value;
1336 }
1337
1338 return $old;
1339 }
1340
1341 /**
1342 * Called in the installer and updater.
1343 * Probably doesn't need to be called anywhere else in the codebase.
1344 * @param bool|null $value
1345 * @return bool|null
1346 */
1347 public function scrollableCursor( $value = null ) {
1348 $old = $this->mScrollableCursor;
1349 if ( $value !== null ) {
1350 $this->mScrollableCursor = $value;
1351 }
1352
1353 return $old;
1354 }
1355 }
1356
1357 class_alias( DatabaseMssql::class, 'DatabaseMssql' );