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