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