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