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