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