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