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