rdbms: remove "m" member prefix from DatabaseMssql
[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 * @return int
513 */
514 public function estimateRowCount( $table, $vars = '*', $conds = '',
515 $fname = __METHOD__, $options = []
516 ) {
517 // http://msdn2.microsoft.com/en-us/library/aa259203.aspx
518 $options['EXPLAIN'] = true;
519 $options['FOR COUNT'] = true;
520 $res = $this->select( $table, $vars, $conds, $fname, $options );
521
522 $rows = -1;
523 if ( $res ) {
524 $row = $this->fetchRow( $res );
525
526 if ( isset( $row['EstimateRows'] ) ) {
527 $rows = (int)$row['EstimateRows'];
528 }
529 }
530
531 return $rows;
532 }
533
534 /**
535 * Returns information about an index
536 * If errors are explicitly ignored, returns NULL on failure
537 * @param string $table
538 * @param string $index
539 * @param string $fname
540 * @return array|bool|null
541 */
542 public function indexInfo( $table, $index, $fname = __METHOD__ ) {
543 # This does not return the same info as MYSQL would, but that's OK
544 # because MediaWiki never uses the returned value except to check for
545 # the existence of indexes.
546 $sql = "sp_helpindex '" . $this->tableName( $table ) . "'";
547 $res = $this->query( $sql, $fname );
548
549 if ( !$res ) {
550 return null;
551 }
552
553 $result = [];
554 foreach ( $res as $row ) {
555 if ( $row->index_name == $index ) {
556 $row->Non_unique = !stristr( $row->index_description, "unique" );
557 $cols = explode( ", ", $row->index_keys );
558 foreach ( $cols as $col ) {
559 $row->Column_name = trim( $col );
560 $result[] = clone $row;
561 }
562 } elseif ( $index == 'PRIMARY' && stristr( $row->index_description, 'PRIMARY' ) ) {
563 $row->Non_unique = 0;
564 $cols = explode( ", ", $row->index_keys );
565 foreach ( $cols as $col ) {
566 $row->Column_name = trim( $col );
567 $result[] = clone $row;
568 }
569 }
570 }
571
572 return empty( $result ) ? false : $result;
573 }
574
575 /**
576 * INSERT wrapper, inserts an array into a table
577 *
578 * $arrToInsert may be a single associative array, or an array of these with numeric keys, for
579 * multi-row insert.
580 *
581 * Usually aborts on failure
582 * If errors are explicitly ignored, returns success
583 * @param string $table
584 * @param array $arrToInsert
585 * @param string $fname
586 * @param array $options
587 * @return bool
588 * @throws Exception
589 */
590 public function insert( $table, $arrToInsert, $fname = __METHOD__, $options = [] ) {
591 # No rows to insert, easy just return now
592 if ( !count( $arrToInsert ) ) {
593 return true;
594 }
595
596 if ( !is_array( $options ) ) {
597 $options = [ $options ];
598 }
599
600 $table = $this->tableName( $table );
601
602 if ( !( isset( $arrToInsert[0] ) && is_array( $arrToInsert[0] ) ) ) { // Not multi row
603 $arrToInsert = [ 0 => $arrToInsert ]; // make everything multi row compatible
604 }
605
606 // We know the table we're inserting into, get its identity column
607 $identity = null;
608 // strip matching square brackets and the db/schema from table name
609 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
610 $tableRaw = array_pop( $tableRawArr );
611 $res = $this->doQuery(
612 "SELECT NAME AS idColumn FROM SYS.IDENTITY_COLUMNS " .
613 "WHERE OBJECT_NAME(OBJECT_ID)='{$tableRaw}'"
614 );
615 if ( $res && sqlsrv_has_rows( $res ) ) {
616 // There is an identity for this table.
617 $identityArr = sqlsrv_fetch_array( $res, SQLSRV_FETCH_ASSOC );
618 $identity = array_pop( $identityArr );
619 }
620 sqlsrv_free_stmt( $res );
621
622 // Determine binary/varbinary fields so we can encode data as a hex string like 0xABCDEF
623 $binaryColumns = $this->getBinaryColumns( $table );
624
625 // INSERT IGNORE is not supported by SQL Server
626 // remove IGNORE from options list and set ignore flag to true
627 if ( in_array( 'IGNORE', $options ) ) {
628 $options = array_diff( $options, [ 'IGNORE' ] );
629 $this->ignoreDupKeyErrors = true;
630 }
631
632 $ret = null;
633 foreach ( $arrToInsert as $a ) {
634 // start out with empty identity column, this is so we can return
635 // it as a result of the INSERT logic
636 $sqlPre = '';
637 $sqlPost = '';
638 $identityClause = '';
639
640 // if we have an identity column
641 if ( $identity ) {
642 // iterate through
643 foreach ( $a as $k => $v ) {
644 if ( $k == $identity ) {
645 if ( !is_null( $v ) ) {
646 // there is a value being passed to us,
647 // we need to turn on and off inserted identity
648 $sqlPre = "SET IDENTITY_INSERT $table ON;";
649 $sqlPost = ";SET IDENTITY_INSERT $table OFF;";
650 } else {
651 // we can't insert NULL into an identity column,
652 // so remove the column from the insert.
653 unset( $a[$k] );
654 }
655 }
656 }
657
658 // we want to output an identity column as result
659 $identityClause = "OUTPUT INSERTED.$identity ";
660 }
661
662 $keys = array_keys( $a );
663
664 // Build the actual query
665 $sql = $sqlPre . 'INSERT ' . implode( ' ', $options ) .
666 " INTO $table (" . implode( ',', $keys ) . ") $identityClause VALUES (";
667
668 $first = true;
669 foreach ( $a as $key => $value ) {
670 if ( isset( $binaryColumns[$key] ) ) {
671 $value = new MssqlBlob( $value );
672 }
673 if ( $first ) {
674 $first = false;
675 } else {
676 $sql .= ',';
677 }
678 if ( is_null( $value ) ) {
679 $sql .= 'null';
680 } elseif ( is_array( $value ) || is_object( $value ) ) {
681 if ( is_object( $value ) && $value instanceof Blob ) {
682 $sql .= $this->addQuotes( $value );
683 } else {
684 $sql .= $this->addQuotes( serialize( $value ) );
685 }
686 } else {
687 $sql .= $this->addQuotes( $value );
688 }
689 }
690 $sql .= ')' . $sqlPost;
691
692 // Run the query
693 $this->scrollableCursor = false;
694 try {
695 $ret = $this->query( $sql );
696 } catch ( Exception $e ) {
697 $this->scrollableCursor = true;
698 $this->ignoreDupKeyErrors = false;
699 throw $e;
700 }
701 $this->scrollableCursor = true;
702
703 if ( $ret instanceof ResultWrapper && !is_null( $identity ) ) {
704 // Then we want to get the identity column value we were assigned and save it off
705 $row = $ret->fetchObject();
706 if ( is_object( $row ) ) {
707 $this->lastInsertId = $row->$identity;
708 // It seems that mAffectedRows is -1 sometimes when OUTPUT INSERTED.identity is
709 // used if we got an identity back, we know for sure a row was affected, so
710 // adjust that here
711 if ( $this->lastAffectedRowCount == -1 ) {
712 $this->lastAffectedRowCount = 1;
713 }
714 }
715 }
716 }
717
718 $this->ignoreDupKeyErrors = false;
719
720 return $ret;
721 }
722
723 /**
724 * INSERT SELECT wrapper
725 * $varMap must be an associative array of the form [ 'dest1' => 'source1', ... ]
726 * Source items may be literals rather than field names, but strings should
727 * be quoted with Database::addQuotes().
728 * @param string $destTable
729 * @param array|string $srcTable May be an array of tables.
730 * @param array $varMap
731 * @param array $conds May be "*" to copy the whole table.
732 * @param string $fname
733 * @param array $insertOptions
734 * @param array $selectOptions
735 * @param array $selectJoinConds
736 * @return bool
737 * @throws Exception
738 */
739 public function nativeInsertSelect( $destTable, $srcTable, $varMap, $conds, $fname = __METHOD__,
740 $insertOptions = [], $selectOptions = [], $selectJoinConds = []
741 ) {
742 $this->scrollableCursor = false;
743 try {
744 $ret = parent::nativeInsertSelect(
745 $destTable,
746 $srcTable,
747 $varMap,
748 $conds,
749 $fname,
750 $insertOptions,
751 $selectOptions,
752 $selectJoinConds
753 );
754 } catch ( Exception $e ) {
755 $this->scrollableCursor = true;
756 throw $e;
757 }
758 $this->scrollableCursor = true;
759
760 return $ret;
761 }
762
763 /**
764 * UPDATE wrapper. Takes a condition array and a SET array.
765 *
766 * @param string $table Name of the table to UPDATE. This will be passed through
767 * Database::tableName().
768 *
769 * @param array $values An array of values to SET. For each array element,
770 * the key gives the field name, and the value gives the data
771 * to set that field to. The data will be quoted by
772 * Database::addQuotes().
773 *
774 * @param array $conds An array of conditions (WHERE). See
775 * Database::select() for the details of the format of
776 * condition arrays. Use '*' to update all rows.
777 *
778 * @param string $fname The function name of the caller (from __METHOD__),
779 * for logging and profiling.
780 *
781 * @param array $options An array of UPDATE options, can be:
782 * - IGNORE: Ignore unique key conflicts
783 * - LOW_PRIORITY: MySQL-specific, see MySQL manual.
784 * @return bool
785 * @throws DBUnexpectedError
786 * @throws Exception
787 */
788 function update( $table, $values, $conds, $fname = __METHOD__, $options = [] ) {
789 $table = $this->tableName( $table );
790 $binaryColumns = $this->getBinaryColumns( $table );
791
792 $opts = $this->makeUpdateOptions( $options );
793 $sql = "UPDATE $opts $table SET " . $this->makeList( $values, LIST_SET, $binaryColumns );
794
795 if ( $conds !== [] && $conds !== '*' ) {
796 $sql .= " WHERE " . $this->makeList( $conds, LIST_AND, $binaryColumns );
797 }
798
799 $this->scrollableCursor = false;
800 try {
801 $this->query( $sql );
802 } catch ( Exception $e ) {
803 $this->scrollableCursor = true;
804 throw $e;
805 }
806 $this->scrollableCursor = true;
807 return true;
808 }
809
810 /**
811 * Makes an encoded list of strings from an array
812 * @param array $a Containing the data
813 * @param int $mode Constant
814 * - LIST_COMMA: comma separated, no field names
815 * - LIST_AND: ANDed WHERE clause (without the WHERE). See
816 * the documentation for $conds in Database::select().
817 * - LIST_OR: ORed WHERE clause (without the WHERE)
818 * - LIST_SET: comma separated with field names, like a SET clause
819 * - LIST_NAMES: comma separated field names
820 * @param array $binaryColumns Contains a list of column names that are binary types
821 * This is a custom parameter only present for MS SQL.
822 *
823 * @throws DBUnexpectedError
824 * @return string
825 */
826 public function makeList( $a, $mode = LIST_COMMA, $binaryColumns = [] ) {
827 if ( !is_array( $a ) ) {
828 throw new DBUnexpectedError( $this, __METHOD__ . ' called with incorrect parameters' );
829 }
830
831 if ( $mode != LIST_NAMES ) {
832 // In MS SQL, values need to be specially encoded when they are
833 // inserted into binary fields. Perform this necessary encoding
834 // for the specified set of columns.
835 foreach ( array_keys( $a ) as $field ) {
836 if ( !isset( $binaryColumns[$field] ) ) {
837 continue;
838 }
839
840 if ( is_array( $a[$field] ) ) {
841 foreach ( $a[$field] as &$v ) {
842 $v = new MssqlBlob( $v );
843 }
844 unset( $v );
845 } else {
846 $a[$field] = new MssqlBlob( $a[$field] );
847 }
848 }
849 }
850
851 return parent::makeList( $a, $mode );
852 }
853
854 /**
855 * @param string $table
856 * @param string $field
857 * @return int Returns the size of a text field, or -1 for "unlimited"
858 */
859 public function textFieldSize( $table, $field ) {
860 $table = $this->tableName( $table );
861 $sql = "SELECT CHARACTER_MAXIMUM_LENGTH,DATA_TYPE FROM INFORMATION_SCHEMA.Columns
862 WHERE TABLE_NAME = '$table' AND COLUMN_NAME = '$field'";
863 $res = $this->query( $sql );
864 $row = $this->fetchRow( $res );
865 $size = -1;
866 if ( strtolower( $row['DATA_TYPE'] ) != 'text' ) {
867 $size = $row['CHARACTER_MAXIMUM_LENGTH'];
868 }
869
870 return $size;
871 }
872
873 /**
874 * Construct a LIMIT query with optional offset
875 * This is used for query pages
876 *
877 * @param string $sql SQL query we will append the limit too
878 * @param int $limit The SQL limit
879 * @param bool|int $offset The SQL offset (default false)
880 * @return array|string
881 * @throws DBUnexpectedError
882 */
883 public function limitResult( $sql, $limit, $offset = false ) {
884 if ( $offset === false || $offset == 0 ) {
885 if ( strpos( $sql, "SELECT" ) === false ) {
886 return "TOP {$limit} " . $sql;
887 } else {
888 return preg_replace( '/\bSELECT(\s+DISTINCT)?\b/Dsi',
889 'SELECT$1 TOP ' . $limit, $sql, 1 );
890 }
891 } else {
892 // This one is fun, we need to pull out the select list as well as any ORDER BY clause
893 $select = $orderby = [];
894 $s1 = preg_match( '#SELECT\s+(.+?)\s+FROM#Dis', $sql, $select );
895 $s2 = preg_match( '#(ORDER BY\s+.+?)(\s*FOR XML .*)?$#Dis', $sql, $orderby );
896 $postOrder = '';
897 $first = $offset + 1;
898 $last = $offset + $limit;
899 $sub1 = 'sub_' . $this->subqueryId;
900 $sub2 = 'sub_' . ( $this->subqueryId + 1 );
901 $this->subqueryId += 2;
902 if ( !$s1 ) {
903 // wat
904 throw new DBUnexpectedError( $this, "Attempting to LIMIT a non-SELECT query\n" );
905 }
906 if ( !$s2 ) {
907 // no ORDER BY
908 $overOrder = 'ORDER BY (SELECT 1)';
909 } else {
910 if ( !isset( $orderby[2] ) || !$orderby[2] ) {
911 // don't need to strip it out if we're using a FOR XML clause
912 $sql = str_replace( $orderby[1], '', $sql );
913 }
914 $overOrder = $orderby[1];
915 $postOrder = ' ' . $overOrder;
916 }
917 $sql = "SELECT {$select[1]}
918 FROM (
919 SELECT ROW_NUMBER() OVER({$overOrder}) AS rowNumber, *
920 FROM ({$sql}) {$sub1}
921 ) {$sub2}
922 WHERE rowNumber BETWEEN {$first} AND {$last}{$postOrder}";
923
924 return $sql;
925 }
926 }
927
928 /**
929 * If there is a limit clause, parse it, strip it, and pass the remaining
930 * SQL through limitResult() with the appropriate parameters. Not the
931 * prettiest solution, but better than building a whole new parser. This
932 * exists becase there are still too many extensions that don't use dynamic
933 * sql generation.
934 *
935 * @param string $sql
936 * @return array|mixed|string
937 */
938 public function LimitToTopN( $sql ) {
939 // Matches: LIMIT {[offset,] row_count | row_count OFFSET offset}
940 $pattern = '/\bLIMIT\s+((([0-9]+)\s*,\s*)?([0-9]+)(\s+OFFSET\s+([0-9]+))?)/i';
941 if ( preg_match( $pattern, $sql, $matches ) ) {
942 $row_count = $matches[4];
943 $offset = $matches[3] ?: $matches[6] ?: false;
944
945 // strip the matching LIMIT clause out
946 $sql = str_replace( $matches[0], '', $sql );
947
948 return $this->limitResult( $sql, $row_count, $offset );
949 }
950
951 return $sql;
952 }
953
954 /**
955 * @return string Wikitext of a link to the server software's web site
956 */
957 public function getSoftwareLink() {
958 return "[{{int:version-db-mssql-url}} MS SQL Server]";
959 }
960
961 /**
962 * @return string Version information from the database
963 */
964 public function getServerVersion() {
965 $server_info = sqlsrv_server_info( $this->conn );
966 $version = 'Error';
967 if ( isset( $server_info['SQLServerVersion'] ) ) {
968 $version = $server_info['SQLServerVersion'];
969 }
970
971 return $version;
972 }
973
974 /**
975 * @param string $table
976 * @param string $fname
977 * @return bool
978 */
979 public function tableExists( $table, $fname = __METHOD__ ) {
980 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
981
982 if ( $db !== false ) {
983 // remote database
984 $this->queryLogger->error( "Attempting to call tableExists on a remote table" );
985 return false;
986 }
987
988 if ( $schema === false ) {
989 $schema = $this->schema;
990 }
991
992 $res = $this->query( "SELECT 1 FROM INFORMATION_SCHEMA.TABLES
993 WHERE TABLE_TYPE = 'BASE TABLE'
994 AND TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table'" );
995
996 if ( $res->numRows() ) {
997 return true;
998 } else {
999 return false;
1000 }
1001 }
1002
1003 /**
1004 * Query whether a given column exists in the mediawiki schema
1005 * @param string $table
1006 * @param string $field
1007 * @param string $fname
1008 * @return bool
1009 */
1010 public function fieldExists( $table, $field, $fname = __METHOD__ ) {
1011 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
1012
1013 if ( $db !== false ) {
1014 // remote database
1015 $this->queryLogger->error( "Attempting to call fieldExists on a remote table" );
1016 return false;
1017 }
1018
1019 $res = $this->query( "SELECT 1 FROM INFORMATION_SCHEMA.COLUMNS
1020 WHERE TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
1021
1022 if ( $res->numRows() ) {
1023 return true;
1024 } else {
1025 return false;
1026 }
1027 }
1028
1029 public function fieldInfo( $table, $field ) {
1030 list( $db, $schema, $table ) = $this->tableName( $table, 'split' );
1031
1032 if ( $db !== false ) {
1033 // remote database
1034 $this->queryLogger->error( "Attempting to call fieldInfo on a remote table" );
1035 return false;
1036 }
1037
1038 $res = $this->query( "SELECT * FROM INFORMATION_SCHEMA.COLUMNS
1039 WHERE TABLE_SCHEMA = '$schema' AND TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
1040
1041 $meta = $res->fetchRow();
1042 if ( $meta ) {
1043 return new MssqlField( $meta );
1044 }
1045
1046 return false;
1047 }
1048
1049 /**
1050 * Begin a transaction, committing any previously open transaction
1051 * @param string $fname
1052 */
1053 protected function doBegin( $fname = __METHOD__ ) {
1054 sqlsrv_begin_transaction( $this->conn );
1055 $this->trxLevel = 1;
1056 }
1057
1058 /**
1059 * End a transaction
1060 * @param string $fname
1061 */
1062 protected function doCommit( $fname = __METHOD__ ) {
1063 sqlsrv_commit( $this->conn );
1064 $this->trxLevel = 0;
1065 }
1066
1067 /**
1068 * Rollback a transaction.
1069 * No-op on non-transactional databases.
1070 * @param string $fname
1071 */
1072 protected function doRollback( $fname = __METHOD__ ) {
1073 sqlsrv_rollback( $this->conn );
1074 $this->trxLevel = 0;
1075 }
1076
1077 /**
1078 * @param string $s
1079 * @return string
1080 */
1081 public function strencode( $s ) {
1082 // Should not be called by us
1083 return str_replace( "'", "''", $s );
1084 }
1085
1086 /**
1087 * @param string|int|null|bool|Blob $s
1088 * @return string|int
1089 */
1090 public function addQuotes( $s ) {
1091 if ( $s instanceof MssqlBlob ) {
1092 return $s->fetch();
1093 } elseif ( $s instanceof Blob ) {
1094 // this shouldn't really ever be called, but it's here if needed
1095 // (and will quite possibly make the SQL error out)
1096 $blob = new MssqlBlob( $s->fetch() );
1097 return $blob->fetch();
1098 } else {
1099 if ( is_bool( $s ) ) {
1100 $s = $s ? 1 : 0;
1101 }
1102 return parent::addQuotes( $s );
1103 }
1104 }
1105
1106 /**
1107 * @param string $s
1108 * @return string
1109 */
1110 public function addIdentifierQuotes( $s ) {
1111 // http://msdn.microsoft.com/en-us/library/aa223962.aspx
1112 return '[' . $s . ']';
1113 }
1114
1115 /**
1116 * @param string $name
1117 * @return bool
1118 */
1119 public function isQuotedIdentifier( $name ) {
1120 return strlen( $name ) && $name[0] == '[' && substr( $name, -1, 1 ) == ']';
1121 }
1122
1123 /**
1124 * MS SQL supports more pattern operators than other databases (ex: [,],^)
1125 *
1126 * @param string $s
1127 * @param string $escapeChar
1128 * @return string
1129 */
1130 protected function escapeLikeInternal( $s, $escapeChar = '`' ) {
1131 return str_replace( [ $escapeChar, '%', '_', '[', ']', '^' ],
1132 [ "{$escapeChar}{$escapeChar}", "{$escapeChar}%", "{$escapeChar}_",
1133 "{$escapeChar}[", "{$escapeChar}]", "{$escapeChar}^" ],
1134 $s );
1135 }
1136
1137 /**
1138 * @param string $db
1139 * @return bool
1140 */
1141 public function selectDB( $db ) {
1142 try {
1143 $this->dbName = $db;
1144 $this->query( "USE $db" );
1145 return true;
1146 } catch ( Exception $e ) {
1147 return false;
1148 }
1149 }
1150
1151 /**
1152 * @param array $options An associative array of options to be turned into
1153 * an SQL query, valid keys are listed in the function.
1154 * @return array
1155 */
1156 public function makeSelectOptions( $options ) {
1157 $tailOpts = '';
1158 $startOpts = '';
1159
1160 $noKeyOptions = [];
1161 foreach ( $options as $key => $option ) {
1162 if ( is_numeric( $key ) ) {
1163 $noKeyOptions[$option] = true;
1164 }
1165 }
1166
1167 $tailOpts .= $this->makeGroupByWithHaving( $options );
1168
1169 $tailOpts .= $this->makeOrderBy( $options );
1170
1171 if ( isset( $noKeyOptions['DISTINCT'] ) || isset( $noKeyOptions['DISTINCTROW'] ) ) {
1172 $startOpts .= 'DISTINCT';
1173 }
1174
1175 if ( isset( $noKeyOptions['FOR XML'] ) ) {
1176 // used in group concat field emulation
1177 $tailOpts .= " FOR XML PATH('')";
1178 }
1179
1180 // we want this to be compatible with the output of parent::makeSelectOptions()
1181 return [ $startOpts, '', $tailOpts, '', '' ];
1182 }
1183
1184 public function getType() {
1185 return 'mssql';
1186 }
1187
1188 /**
1189 * @param array $stringList
1190 * @return string
1191 */
1192 public function buildConcat( $stringList ) {
1193 return implode( ' + ', $stringList );
1194 }
1195
1196 /**
1197 * Build a GROUP_CONCAT or equivalent statement for a query.
1198 * MS SQL doesn't have GROUP_CONCAT so we emulate it with other stuff (and boy is it nasty)
1199 *
1200 * This is useful for combining a field for several rows into a single string.
1201 * NULL values will not appear in the output, duplicated values will appear,
1202 * and the resulting delimiter-separated values have no defined sort order.
1203 * Code using the results may need to use the PHP unique() or sort() methods.
1204 *
1205 * @param string $delim Glue to bind the results together
1206 * @param string|array $table Table name
1207 * @param string $field Field name
1208 * @param string|array $conds Conditions
1209 * @param string|array $join_conds Join conditions
1210 * @return string SQL text
1211 * @since 1.23
1212 */
1213 public function buildGroupConcatField( $delim, $table, $field, $conds = '',
1214 $join_conds = []
1215 ) {
1216 $gcsq = 'gcsq_' . $this->subqueryId;
1217 $this->subqueryId++;
1218
1219 $delimLen = strlen( $delim );
1220 $fld = "{$field} + {$this->addQuotes( $delim )}";
1221 $sql = "(SELECT LEFT({$field}, LEN({$field}) - {$delimLen}) FROM ("
1222 . $this->selectSQLText( $table, $fld, $conds, null, [ 'FOR XML' ], $join_conds )
1223 . ") {$gcsq} ({$field}))";
1224
1225 return $sql;
1226 }
1227
1228 /**
1229 * Returns an associative array for fields that are of type varbinary, binary, or image
1230 * $table can be either a raw table name or passed through tableName() first
1231 * @param string $table
1232 * @return array
1233 */
1234 private function getBinaryColumns( $table ) {
1235 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
1236 $tableRaw = array_pop( $tableRawArr );
1237
1238 if ( $this->binaryColumnCache === null ) {
1239 $this->populateColumnCaches();
1240 }
1241
1242 return isset( $this->binaryColumnCache[$tableRaw] )
1243 ? $this->binaryColumnCache[$tableRaw]
1244 : [];
1245 }
1246
1247 /**
1248 * @param string $table
1249 * @return array
1250 */
1251 private function getBitColumns( $table ) {
1252 $tableRawArr = explode( '.', preg_replace( '#\[([^\]]*)\]#', '$1', $table ) );
1253 $tableRaw = array_pop( $tableRawArr );
1254
1255 if ( $this->bitColumnCache === null ) {
1256 $this->populateColumnCaches();
1257 }
1258
1259 return isset( $this->bitColumnCache[$tableRaw] )
1260 ? $this->bitColumnCache[$tableRaw]
1261 : [];
1262 }
1263
1264 private function populateColumnCaches() {
1265 $res = $this->select( 'INFORMATION_SCHEMA.COLUMNS', '*',
1266 [
1267 'TABLE_CATALOG' => $this->dbName,
1268 'TABLE_SCHEMA' => $this->schema,
1269 'DATA_TYPE' => [ 'varbinary', 'binary', 'image', 'bit' ]
1270 ] );
1271
1272 $this->binaryColumnCache = [];
1273 $this->bitColumnCache = [];
1274 foreach ( $res as $row ) {
1275 if ( $row->DATA_TYPE == 'bit' ) {
1276 $this->bitColumnCache[$row->TABLE_NAME][$row->COLUMN_NAME] = $row;
1277 } else {
1278 $this->binaryColumnCache[$row->TABLE_NAME][$row->COLUMN_NAME] = $row;
1279 }
1280 }
1281 }
1282
1283 /**
1284 * @param string $name
1285 * @param string $format
1286 * @return string
1287 */
1288 function tableName( $name, $format = 'quoted' ) {
1289 # Replace reserved words with better ones
1290 switch ( $name ) {
1291 case 'user':
1292 return $this->realTableName( 'mwuser', $format );
1293 default:
1294 return $this->realTableName( $name, $format );
1295 }
1296 }
1297
1298 /**
1299 * call this instead of tableName() in the updater when renaming tables
1300 * @param string $name
1301 * @param string $format One of quoted, raw, or split
1302 * @return string
1303 */
1304 function realTableName( $name, $format = 'quoted' ) {
1305 $table = parent::tableName( $name, $format );
1306 if ( $format == 'split' ) {
1307 // Used internally, we want the schema split off from the table name and returned
1308 // as a list with 3 elements (database, schema, table)
1309 $table = explode( '.', $table );
1310 while ( count( $table ) < 3 ) {
1311 array_unshift( $table, false );
1312 }
1313 }
1314 return $table;
1315 }
1316
1317 /**
1318 * Delete a table
1319 * @param string $tableName
1320 * @param string $fName
1321 * @return bool|ResultWrapper
1322 * @since 1.18
1323 */
1324 public function dropTable( $tableName, $fName = __METHOD__ ) {
1325 if ( !$this->tableExists( $tableName, $fName ) ) {
1326 return false;
1327 }
1328
1329 // parent function incorrectly appends CASCADE, which we don't want
1330 $sql = "DROP TABLE " . $this->tableName( $tableName );
1331
1332 return $this->query( $sql, $fName );
1333 }
1334
1335 /**
1336 * Called in the installer and updater.
1337 * Probably doesn't need to be called anywhere else in the codebase.
1338 * @param bool|null $value
1339 * @return bool|null
1340 */
1341 public function prepareStatements( $value = null ) {
1342 $old = $this->prepareStatements;
1343 if ( $value !== null ) {
1344 $this->prepareStatements = $value;
1345 }
1346
1347 return $old;
1348 }
1349
1350 /**
1351 * Called in the installer and updater.
1352 * Probably doesn't need to be called anywhere else in the codebase.
1353 * @param bool|null $value
1354 * @return bool|null
1355 */
1356 public function scrollableCursor( $value = null ) {
1357 $old = $this->scrollableCursor;
1358 if ( $value !== null ) {
1359 $this->scrollableCursor = $value;
1360 }
1361
1362 return $old;
1363 }
1364 }
1365
1366 class_alias( DatabaseMssql::class, 'DatabaseMssql' );