MediaWiki  REL1_19
DatabaseMssql.php
Go to the documentation of this file.
00001 <?php
00015 class DatabaseMssql extends DatabaseBase {
00016         var $mInsertId = NULL;
00017         var $mLastResult = NULL;
00018         var $mAffectedRows = NULL;
00019 
00020         var $mPort;
00021 
00022         function cascadingDeletes() {
00023                 return true;
00024         }
00025         function cleanupTriggers() {
00026                 return true;
00027         }
00028         function strictIPs() {
00029                 return true;
00030         }
00031         function realTimestamps() {
00032                 return true;
00033         }
00034         function implicitGroupby() {
00035                 return false;
00036         }
00037         function implicitOrderby() {
00038                 return false;
00039         }
00040         function functionalIndexes() {
00041                 return true;
00042         }
00043         function unionSupportsOrderAndLimit() {
00044                 return false;
00045         }
00046 
00050         function open( $server, $user, $password, $dbName ) {
00051                 # Test for driver support, to avoid suppressed fatal error
00052                 if ( !function_exists( 'sqlsrv_connect' ) ) {
00053                         throw new DBConnectionError( $this, "MS Sql Server Native (sqlsrv) functions missing. You can download the driver from: http://go.microsoft.com/fwlink/?LinkId=123470\n" );
00054                 }
00055 
00056                 global $wgDBport;
00057 
00058                 if ( !strlen( $user ) ) { # e.g. the class is being loaded
00059                         return;
00060                 }
00061 
00062                 $this->close();
00063                 $this->mServer = $server;
00064                 $this->mPort = $wgDBport;
00065                 $this->mUser = $user;
00066                 $this->mPassword = $password;
00067                 $this->mDBname = $dbName;
00068 
00069                 $connectionInfo = array();
00070 
00071                 if( $dbName ) {
00072                         $connectionInfo['Database'] = $dbName;
00073                 }
00074 
00075                 // Start NT Auth Hack
00076                 // Quick and dirty work around to provide NT Auth designation support.
00077                 // Current solution requires installer to know to input 'ntauth' for both username and password
00078                 // to trigger connection via NT Auth. - ugly, ugly, ugly
00079                 // TO-DO: Make this better and add NT Auth choice to MW installer when SQL Server option is chosen.
00080                 $ntAuthUserTest = strtolower( $user );
00081                 $ntAuthPassTest = strtolower( $password );
00082 
00083                 // Decide which auth scenerio to use
00084                 if( $ntAuthPassTest == 'ntauth' && $ntAuthUserTest == 'ntauth' ){
00085                         // Don't add credentials to $connectionInfo
00086                 } else {
00087                         $connectionInfo['UID'] = $user;
00088                         $connectionInfo['PWD'] = $password;
00089                 }
00090                 // End NT Auth Hack
00091 
00092                 wfSuppressWarnings();
00093                 $this->mConn = sqlsrv_connect( $server, $connectionInfo );
00094                 wfRestoreWarnings();
00095 
00096                 if ( $this->mConn === false ) {
00097                         wfDebug( "DB connection error\n" );
00098                         wfDebug( "Server: $server, Database: $dbName, User: $user, Password: " . substr( $password, 0, 3 ) . "...\n" );
00099                         wfDebug( $this->lastError() . "\n" );
00100                         return false;
00101                 }
00102 
00103                 $this->mOpened = true;
00104                 return $this->mConn;
00105         }
00106 
00111         function close() {
00112                 $this->mOpened = false;
00113                 if ( $this->mConn ) {
00114                         return sqlsrv_close( $this->mConn );
00115                 } else {
00116                         return true;
00117                 }
00118         }
00119 
00120         protected function doQuery( $sql ) {
00121                 wfDebug( "SQL: [$sql]\n" );
00122                 $this->offset = 0;
00123 
00124                 // several extensions seem to think that all databases support limits via LIMIT N after the WHERE clause
00125                 // well, MSSQL uses SELECT TOP N, so to catch any of those extensions we'll do a quick check for a LIMIT
00126                 // clause and pass $sql through $this->LimitToTopN() which parses the limit clause and passes the result to
00127                 // $this->limitResult();
00128                 if ( preg_match( '/\bLIMIT\s*/i', $sql ) ) {
00129                         // massage LIMIT -> TopN
00130                         $sql = $this->LimitToTopN( $sql ) ;
00131                 }
00132 
00133                 // MSSQL doesn't have EXTRACT(epoch FROM XXX)
00134                 if ( preg_match('#\bEXTRACT\s*?\(\s*?EPOCH\s+FROM\b#i', $sql, $matches ) ) {
00135                         // This is same as UNIX_TIMESTAMP, we need to calc # of seconds from 1970
00136                         $sql = str_replace( $matches[0], "DATEDIFF(s,CONVERT(datetime,'1/1/1970'),", $sql );
00137                 }
00138 
00139                 // perform query
00140                 $stmt = sqlsrv_query( $this->mConn, $sql );
00141                 if ( $stmt == false ) {
00142                         $message = "A database error has occurred.  Did you forget to run maintenance/update.php after upgrading?  See: http://www.mediawiki.org/wiki/Manual:Upgrading#Run_the_update_script\n" .
00143                                 "Query: " . htmlentities( $sql ) . "\n" .
00144                                 "Function: " . __METHOD__ . "\n";
00145                         // process each error (our driver will give us an array of errors unlike other providers)
00146                         foreach ( sqlsrv_errors() as $error ) {
00147                                 $message .= $message . "ERROR[" . $error['code'] . "] " . $error['message'] . "\n";
00148                         }
00149 
00150                         throw new DBUnexpectedError( $this, $message );
00151                 }
00152                 // remember number of rows affected
00153                 $this->mAffectedRows = sqlsrv_rows_affected( $stmt );
00154 
00155                 // if it is a SELECT statement, or an insert with a request to output something we want to return a row.
00156                 if ( ( preg_match( '#\bSELECT\s#i', $sql ) ) ||
00157                         ( preg_match( '#\bINSERT\s#i', $sql ) && preg_match( '#\bOUTPUT\s+INSERTED\b#i', $sql ) ) ) {
00158                         // this is essentially a rowset, but Mediawiki calls these 'result'
00159                         // the rowset owns freeing the statement
00160                         $res = new MssqlResult( $stmt );
00161                 } else {
00162                         // otherwise we simply return it was successful, failure throws an exception
00163                         $res = true;
00164                 }
00165                 return $res;
00166         }
00167 
00168         function freeResult( $res ) {
00169                 if ( $res instanceof ResultWrapper ) {
00170                         $res = $res->result;
00171                 }
00172                 $res->free();
00173         }
00174 
00175         function fetchObject( $res ) {
00176                 if ( $res instanceof ResultWrapper ) {
00177                         $res = $res->result;
00178                 }
00179                 $row = $res->fetch( 'OBJECT' );
00180                 return $row;
00181         }
00182 
00183         function getErrors() {
00184                 $strRet = '';
00185                 $retErrors = sqlsrv_errors( SQLSRV_ERR_ALL );
00186                 if ( $retErrors != null ) {
00187                         foreach ( $retErrors as $arrError ) {
00188                                 $strRet .= "SQLState: " . $arrError[ 'SQLSTATE'] . "\n";
00189                                 $strRet .= "Error Code: " . $arrError[ 'code'] . "\n";
00190                                 $strRet .= "Message: " . $arrError[ 'message'] . "\n";
00191                         }
00192                 } else {
00193                         $strRet = "No errors found";
00194                 }
00195                 return $strRet;
00196         }
00197 
00198         function fetchRow( $res ) {
00199                 if ( $res instanceof ResultWrapper ) {
00200                         $res = $res->result;
00201                 }
00202                 $row = $res->fetch( SQLSRV_FETCH_BOTH );
00203                 return $row;
00204         }
00205 
00206         function numRows( $res ) {
00207                 if ( $res instanceof ResultWrapper ) {
00208                         $res = $res->result;
00209                 }
00210                 return ( $res ) ? $res->numrows() : 0;
00211         }
00212 
00213         function numFields( $res ) {
00214                 if ( $res instanceof ResultWrapper ) {
00215                         $res = $res->result;
00216                 }
00217                 return ( $res ) ? $res->numfields() : 0;
00218         }
00219 
00220         function fieldName( $res, $n ) {
00221                 if ( $res instanceof ResultWrapper ) {
00222                         $res = $res->result;
00223                 }
00224                 return ( $res ) ? $res->fieldname( $n ) : 0;
00225         }
00226 
00230         function insertId() {
00231                 return $this->mInsertId;
00232         }
00233 
00234         function dataSeek( $res, $row ) {
00235                 if ( $res instanceof ResultWrapper ) {
00236                         $res = $res->result;
00237                 }
00238                 return ( $res ) ? $res->seek( $row ) : false;
00239         }
00240 
00241         function lastError() {
00242                 if ( $this->mConn ) {
00243                         return $this->getErrors();
00244                 } else {
00245                         return "No database connection";
00246                 }
00247         }
00248 
00249         function lastErrno() {
00250                 $err = sqlsrv_errors( SQLSRV_ERR_ALL );
00251                 if ( $err[0] ) {
00252                         return $err[0]['code'];
00253                 } else {
00254                         return 0;
00255                 }
00256         }
00257 
00258         function affectedRows() {
00259                 return $this->mAffectedRows;
00260         }
00261 
00275         function select( $table, $vars, $conds = '', $fname = 'DatabaseMssql::select', $options = array(), $join_conds = array() )
00276         {
00277                 $sql = $this->selectSQLText( $table, $vars, $conds, $fname, $options, $join_conds );
00278                 if ( isset( $options['EXPLAIN'] ) ) {
00279                         sqlsrv_query( $this->mConn, "SET SHOWPLAN_ALL ON;" );
00280                         $ret = $this->query( $sql, $fname );
00281                         sqlsrv_query( $this->mConn, "SET SHOWPLAN_ALL OFF;" );
00282                         return $ret;
00283                 }
00284                 return $this->query( $sql, $fname );
00285         }
00286 
00300         function selectSQLText( $table, $vars, $conds = '', $fname = 'DatabaseMssql::select', $options = array(), $join_conds = array() ) {
00301                 if ( isset( $options['EXPLAIN'] ) ) {
00302                         unset( $options['EXPLAIN'] );
00303                 }
00304                 return parent::selectSQLText(  $table, $vars, $conds, $fname, $options, $join_conds );
00305         }
00306 
00314         function estimateRowCount( $table, $vars = '*', $conds = '', $fname = 'DatabaseMssql::estimateRowCount', $options = array() ) {
00315                 $options['EXPLAIN'] = true;// http://msdn2.microsoft.com/en-us/library/aa259203.aspx
00316                 $res = $this->select( $table, $vars, $conds, $fname, $options );
00317 
00318                 $rows = -1;
00319                 if ( $res ) {
00320                         $row = $this->fetchRow( $res );
00321                         if ( isset( $row['EstimateRows'] ) ) $rows = $row['EstimateRows'];
00322                 }
00323                 return $rows;
00324         }
00325 
00330         function indexInfo( $table, $index, $fname = 'DatabaseMssql::indexExists' ) {
00331                 # This does not return the same info as MYSQL would, but that's OK because MediaWiki never uses the
00332                 # returned value except to check for the existance of indexes.
00333                 $sql = "sp_helpindex '" . $table . "'";
00334                 $res = $this->query( $sql, $fname );
00335                 if ( !$res ) {
00336                         return NULL;
00337                 }
00338 
00339                 $result = array();
00340                 foreach ( $res as $row ) {
00341                         if ( $row->index_name == $index ) {
00342                                 $row->Non_unique = !stristr( $row->index_description, "unique" );
00343                                 $cols = explode( ", ", $row->index_keys );
00344                                 foreach ( $cols as $col ) {
00345                                         $row->Column_name = trim( $col );
00346                                         $result[] = clone $row;
00347                                 }
00348                         } elseif ( $index == 'PRIMARY' && stristr( $row->index_description, 'PRIMARY' ) ) {
00349                                 $row->Non_unique = 0;
00350                                 $cols = explode( ", ", $row->index_keys );
00351                                 foreach ( $cols as $col ) {
00352                                         $row->Column_name = trim( $col );
00353                                         $result[] = clone $row;
00354                                 }
00355                         }
00356                 }
00357                 return empty( $result ) ? false : $result;
00358         }
00359 
00369         function insert( $table, $arrToInsert, $fname = 'DatabaseMssql::insert', $options = array() ) {
00370                 # No rows to insert, easy just return now
00371                 if ( !count( $arrToInsert ) ) {
00372                         return true;
00373                 }
00374 
00375                 if ( !is_array( $options ) ) {
00376                         $options = array( $options );
00377                 }
00378 
00379                 $table = $this->tableName( $table );
00380 
00381                 if ( !( isset( $arrToInsert[0] ) && is_array( $arrToInsert[0] ) ) ) {// Not multi row
00382                         $arrToInsert = array( 0 => $arrToInsert );// make everything multi row compatible
00383                 }
00384 
00385                 $allOk = true;
00386 
00387                 // We know the table we're inserting into, get its identity column
00388                 $identity = null;
00389                 $tableRaw = preg_replace( '#\[([^\]]*)\]#', '$1', $table ); // strip matching square brackets from table name
00390                 $res = $this->doQuery( "SELECT NAME AS idColumn FROM SYS.IDENTITY_COLUMNS WHERE OBJECT_NAME(OBJECT_ID)='{$tableRaw}'" );
00391                 if( $res && $res->numrows() ){
00392                         // There is an identity for this table.
00393                         $identity = array_pop( $res->fetch( SQLSRV_FETCH_ASSOC ) );
00394                 }
00395                 unset( $res );
00396 
00397                 foreach ( $arrToInsert as $a ) {
00398                         // start out with empty identity column, this is so we can return it as a result of the insert logic
00399                         $sqlPre = '';
00400                         $sqlPost = '';
00401                         $identityClause = '';
00402 
00403                         // if we have an identity column
00404                         if( $identity ) {
00405                                 // iterate through
00406                                 foreach ($a as $k => $v ) {
00407                                         if ( $k == $identity ) {
00408                                                 if( !is_null($v) ){
00409                                                         // there is a value being passed to us, we need to turn on and off inserted identity
00410                                                         $sqlPre = "SET IDENTITY_INSERT $table ON;" ;
00411                                                         $sqlPost = ";SET IDENTITY_INSERT $table OFF;";
00412 
00413                                                 } else {
00414                                                         // we can't insert NULL into an identity column, so remove the column from the insert.
00415                                                         unset( $a[$k] );
00416                                                 }
00417                                         }
00418                                 }
00419                                 $identityClause = "OUTPUT INSERTED.$identity "; // we want to output an identity column as result
00420                         }
00421 
00422                         $keys = array_keys( $a );
00423 
00424                         // INSERT IGNORE is not supported by SQL Server
00425                         // remove IGNORE from options list and set ignore flag to true
00426                         $ignoreClause = false;
00427                         foreach ( $options as $k => $v ) {
00428                                 if ( strtoupper( $v ) == "IGNORE" ) {
00429                                         unset( $options[$k] );
00430                                         $ignoreClause = true;
00431                                 }
00432                         }
00433 
00434                         // translate MySQL INSERT IGNORE to something SQL Server can use
00435                         // example:
00436                         // MySQL: INSERT IGNORE INTO user_groups (ug_user,ug_group) VALUES ('1','sysop')
00437                         // MSSQL: IF NOT EXISTS (SELECT * FROM user_groups WHERE ug_user = '1') INSERT INTO user_groups (ug_user,ug_group) VALUES ('1','sysop')
00438                         if ( $ignoreClause ) {
00439                                 $prival = $a[$keys[0]];
00440                                 $sqlPre .= "IF NOT EXISTS (SELECT * FROM $table WHERE $keys[0] = '$prival')";
00441                         }
00442 
00443                         // Build the actual query
00444                         $sql = $sqlPre . 'INSERT ' . implode( ' ', $options ) .
00445                                 " INTO $table (" . implode( ',', $keys ) . ") $identityClause VALUES (";
00446 
00447                         $first = true;
00448                         foreach ( $a as $value ) {
00449                                 if ( $first ) {
00450                                         $first = false;
00451                                 } else {
00452                                         $sql .= ',';
00453                                 }
00454                                 if ( is_string( $value ) ) {
00455                                         $sql .= $this->addQuotes( $value );
00456                                 } elseif ( is_null( $value ) ) {
00457                                         $sql .= 'null';
00458                                 } elseif ( is_array( $value ) || is_object( $value ) ) {
00459                                         if ( is_object( $value ) && strtolower( get_class( $value ) ) == 'blob' ) {
00460                                                 $sql .= $this->addQuotes( $value );
00461                                         }  else {
00462                                                 $sql .= $this->addQuotes( serialize( $value ) );
00463                                         }
00464                                 } else {
00465                                         $sql .= $value;
00466                                 }
00467                         }
00468                         $sql .= ')' . $sqlPost;
00469 
00470                         // Run the query
00471                         $ret = sqlsrv_query( $this->mConn, $sql );
00472 
00473                         if ( $ret === false ) {
00474                                 throw new DBQueryError( $this, $this->getErrors(), $this->lastErrno(), $sql, $fname );
00475                         } elseif ( $ret != NULL ) {
00476                                 // remember number of rows affected
00477                                 $this->mAffectedRows = sqlsrv_rows_affected( $ret );
00478                                 if ( !is_null($identity) ) {
00479                                         // then we want to get the identity column value we were assigned and save it off
00480                                         $row = sqlsrv_fetch_object( $ret );
00481                                         $this->mInsertId = $row->$identity;
00482                                 }
00483                                 sqlsrv_free_stmt( $ret );
00484                                 continue;
00485                         }
00486                         $allOk = false;
00487                 }
00488                 return $allOk;
00489         }
00490 
00498         function insertSelect( $destTable, $srcTable, $varMap, $conds, $fname = 'DatabaseMssql::insertSelect',
00499                 $insertOptions = array(), $selectOptions = array() ) {
00500                 $ret = parent::insertSelect( $destTable, $srcTable, $varMap, $conds, $fname, $insertOptions, $selectOptions );
00501 
00502                 if ( $ret === false ) {
00503                         throw new DBQueryError( $this, $this->getErrors(), $this->lastErrno(), /*$sql*/ '', $fname );
00504                 } elseif ( $ret != NULL ) {
00505                         // remember number of rows affected
00506                         $this->mAffectedRows = sqlsrv_rows_affected( $ret );
00507                         return $ret;
00508                 }
00509                 return NULL;
00510         }
00511 
00515         function nextSequenceValue( $seqName ) {
00516                 if ( !$this->tableExists( 'sequence_' . $seqName ) ) {
00517                         sqlsrv_query( $this->mConn, "CREATE TABLE [sequence_$seqName] (id INT NOT NULL IDENTITY PRIMARY KEY, junk varchar(10) NULL)" );
00518                 }
00519                 sqlsrv_query( $this->mConn, "INSERT INTO [sequence_$seqName] (junk) VALUES ('')" );
00520                 $ret = sqlsrv_query( $this->mConn, "SELECT TOP 1 id FROM [sequence_$seqName] ORDER BY id DESC" );
00521                 $row = sqlsrv_fetch_array( $ret, SQLSRV_FETCH_ASSOC );// KEEP ASSOC THERE, weird weird bug dealing with the return value if you don't
00522 
00523                 sqlsrv_free_stmt( $ret );
00524                 $this->mInsertId = $row['id'];
00525                 return $row['id'];
00526         }
00527 
00531         function currentSequenceValue( $seqName ) {
00532                 $ret = sqlsrv_query( $this->mConn, "SELECT TOP 1 id FROM [sequence_$seqName] ORDER BY id DESC" );
00533                 if ( $ret !== false ) {
00534                         $row = sqlsrv_fetch_array( $ret );
00535                         sqlsrv_free_stmt( $ret );
00536                         return $row['id'];
00537                 } else {
00538                         return $this->nextSequenceValue( $seqName );
00539                 }
00540         }
00541 
00542         # Returns the size of a text field, or -1 for "unlimited"
00543         function textFieldSize( $table, $field ) {
00544                 $table = $this->tableName( $table );
00545                 $sql = "SELECT CHARACTER_MAXIMUM_LENGTH,DATA_TYPE FROM INFORMATION_SCHEMA.Columns
00546                         WHERE TABLE_NAME = '$table' AND COLUMN_NAME = '$field'";
00547                 $res = $this->query( $sql );
00548                 $row = $this->fetchRow( $res );
00549                 $size = -1;
00550                 if ( strtolower( $row['DATA_TYPE'] ) != 'text' ) {
00551                         $size = $row['CHARACTER_MAXIMUM_LENGTH'];
00552                 }
00553                 return $size;
00554         }
00555 
00563         function limitResult( $sql, $limit, $offset = false ) {
00564                 if ( $offset === false || $offset == 0 ) {
00565                         if ( strpos( $sql, "SELECT" ) === false ) {
00566                                 return "TOP {$limit} " . $sql;
00567                         } else {
00568                                 return preg_replace( '/\bSELECT(\s*DISTINCT)?\b/Dsi', 'SELECT$1 TOP ' . $limit, $sql, 1 );
00569                         }
00570                 } else {
00571                         $sql = '
00572                                 SELECT * FROM (
00573                                   SELECT sub2.*, ROW_NUMBER() OVER(ORDER BY sub2.line2) AS line3 FROM (
00574                                         SELECT 1 AS line2, sub1.* FROM (' . $sql . ') AS sub1
00575                                   ) as sub2
00576                                 ) AS sub3
00577                                 WHERE line3 BETWEEN ' . ( $offset + 1 ) . ' AND ' . ( $offset + $limit );
00578                         return $sql;
00579                 }
00580         }
00581 
00582         // If there is a limit clause, parse it, strip it, and pass the remaining sql through limitResult()
00583         // with the appropriate parameters. Not the prettiest solution, but better than building a whole new parser.
00584         // This exists becase there are still too many extensions that don't use dynamic sql generation.
00585         function LimitToTopN( $sql ) {
00586                 // Matches: LIMIT {[offset,] row_count | row_count OFFSET offset}
00587                 $pattern = '/\bLIMIT\s+((([0-9]+)\s*,\s*)?([0-9]+)(\s+OFFSET\s+([0-9]+))?)/i';
00588                 if ( preg_match( $pattern, $sql, $matches ) ) {
00589                         // row_count = $matches[4]
00590                         $row_count = $matches[4];
00591                         // offset = $matches[3] OR $matches[6]
00592                         $offset = $matches[3] or
00593                                 $offset = $matches[6] or
00594                                 $offset = false;
00595 
00596                         // strip the matching LIMIT clause out
00597                         $sql = str_replace( $matches[0], '', $sql );
00598                         return $this->limitResult( $sql, $row_count, $offset );
00599                 }
00600                 return $sql;
00601         }
00602 
00603         // MSSQL does support this, but documentation is too thin to make a generalized
00604         // function for this. Apparently UPDATE TOP (N) works, but the sort order
00605         // may not be what we're expecting so the top n results may be a random selection.
00606         // TODO: Implement properly.
00607         function limitResultForUpdate( $sql, $num ) {
00608                 return $sql;
00609         }
00610 
00611         function timestamp( $ts = 0 ) {
00612                 return wfTimestamp( TS_ISO_8601, $ts );
00613         }
00614 
00618         public static function getSoftwareLink() {
00619                 return "[http://www.microsoft.com/sql/ MS SQL Server]";
00620         }
00621 
00625         function getServerVersion() {
00626                 $server_info = sqlsrv_server_info( $this->mConn );
00627                 $version = 'Error';
00628                 if ( isset( $server_info['SQLServerVersion'] ) ) {
00629                         $version = $server_info['SQLServerVersion'];
00630                 }
00631                 return $version;
00632         }
00633 
00634         function tableExists ( $table, $fname = __METHOD__, $schema = false ) {
00635                 $res = sqlsrv_query( $this->mConn, "SELECT * FROM information_schema.tables
00636                         WHERE table_type='BASE TABLE' AND table_name = '$table'" );
00637                 if ( $res === false ) {
00638                         print( "Error in tableExists query: " . $this->getErrors() );
00639                         return false;
00640                 }
00641                 if ( sqlsrv_fetch( $res ) ) {
00642                         return true;
00643                 } else {
00644                         return false;
00645                 }
00646         }
00647 
00651         function fieldExists( $table, $field, $fname = 'DatabaseMssql::fieldExists' ) {
00652                 $table = $this->tableName( $table );
00653                 $res = sqlsrv_query( $this->mConn, "SELECT DATA_TYPE FROM INFORMATION_SCHEMA.Columns
00654                         WHERE TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
00655                 if ( $res === false ) {
00656                         print( "Error in fieldExists query: " . $this->getErrors() );
00657                         return false;
00658                 }
00659                 if ( sqlsrv_fetch( $res ) ) {
00660                         return true;
00661                 } else {
00662                         return false;
00663                 }
00664         }
00665 
00666         function fieldInfo( $table, $field ) {
00667                 $table = $this->tableName( $table );
00668                 $res = sqlsrv_query( $this->mConn, "SELECT * FROM INFORMATION_SCHEMA.Columns
00669                         WHERE TABLE_NAME = '$table' AND COLUMN_NAME = '$field'" );
00670                 if ( $res === false ) {
00671                         print( "Error in fieldInfo query: " . $this->getErrors() );
00672                         return false;
00673                 }
00674                 $meta = $this->fetchRow( $res );
00675                 if ( $meta ) {
00676                         return new MssqlField( $meta );
00677                 }
00678                 return false;
00679         }
00680 
00684         function begin( $fname = 'DatabaseMssql::begin' ) {
00685                 sqlsrv_begin_transaction( $this->mConn );
00686                 $this->mTrxLevel = 1;
00687         }
00688 
00692         function commit( $fname = 'DatabaseMssql::commit' ) {
00693                 sqlsrv_commit( $this->mConn );
00694                 $this->mTrxLevel = 0;
00695         }
00696 
00701         function rollback( $fname = 'DatabaseMssql::rollback' ) {
00702                 sqlsrv_rollback( $this->mConn );
00703                 $this->mTrxLevel = 0;
00704         }
00705 
00711         private function escapeIdentifier( $identifier ) {
00712                 if ( strlen( $identifier ) == 0 ) {
00713                         throw new MWException( "An identifier must not be empty" );
00714                 }
00715                 if ( strlen( $identifier ) > 128 ) {
00716                         throw new MWException( "The identifier '$identifier' is too long (max. 128)" );
00717                 }
00718                 if ( ( strpos( $identifier, '[' ) !== false ) || ( strpos( $identifier, ']' ) !== false ) ) {
00719                         // It may be allowed if you quoted with double quotation marks, but that would break if QUOTED_IDENTIFIER is OFF
00720                         throw new MWException( "You can't use square brackers in the identifier '$identifier'" );
00721                 }
00722                 return "[$identifier]";
00723         }
00724 
00730         function initial_setup( $dbName, $newUser, $loginPassword ) {
00731                 $dbName = $this->escapeIdentifier( $dbName );
00732 
00733                 // It is not clear what can be used as a login,
00734                 // From http://msdn.microsoft.com/en-us/library/ms173463.aspx
00735                 // a sysname may be the same as an identifier.
00736                 $newUser = $this->escapeIdentifier( $newUser );
00737                 $loginPassword = $this->addQuotes( $loginPassword );
00738 
00739                 $this->doQuery("CREATE DATABASE $dbName;");
00740                 $this->doQuery("USE $dbName;");
00741                 $this->doQuery("CREATE SCHEMA $dbName;");
00742                 $this->doQuery("
00743                                                 CREATE
00744                                                         LOGIN $newUser
00745                                                 WITH
00746                                                         PASSWORD=$loginPassword
00747                                                 ;
00748                                         ");
00749                 $this->doQuery("
00750                                                 CREATE
00751                                                         USER $newUser
00752                                                 FOR
00753                                                         LOGIN $newUser
00754                                                 WITH
00755                                                         DEFAULT_SCHEMA=$dbName
00756                                                 ;
00757                                         ");
00758                 $this->doQuery("
00759                                                 GRANT
00760                                                         BACKUP DATABASE,
00761                                                         BACKUP LOG,
00762                                                         CREATE DEFAULT,
00763                                                         CREATE FUNCTION,
00764                                                         CREATE PROCEDURE,
00765                                                         CREATE RULE,
00766                                                         CREATE TABLE,
00767                                                         CREATE VIEW,
00768                                                         CREATE FULLTEXT CATALOG
00769                                                 ON
00770                                                         DATABASE::$dbName
00771                                                 TO $newUser
00772                                                 ;
00773                                         ");
00774                 $this->doQuery("
00775                                                 GRANT
00776                                                         CONTROL
00777                                                 ON
00778                                                         SCHEMA::$dbName
00779                                                 TO $newUser
00780                                                 ;
00781                                         ");
00782 
00783 
00784         }
00785 
00786         function encodeBlob( $b ) {
00787         // we can't have zero's and such, this is a simple encoding to make sure we don't barf
00788                 return base64_encode( $b );
00789         }
00790 
00791         function decodeBlob( $b ) {
00792         // we can't have zero's and such, this is a simple encoding to make sure we don't barf
00793         return base64_decode( $b );
00794         }
00795 
00799         function tableNamesWithUseIndexOrJOIN( $tables, $use_index = array(), $join_conds = array() ) {
00800                 $ret = array();
00801                 $retJOIN = array();
00802                 $use_index_safe = is_array( $use_index ) ? $use_index : array();
00803                 $join_conds_safe = is_array( $join_conds ) ? $join_conds : array();
00804                 foreach ( $tables as $table ) {
00805                         // Is there a JOIN and INDEX clause for this table?
00806                         if ( isset( $join_conds_safe[$table] ) && isset( $use_index_safe[$table] ) ) {
00807                                 $tableClause = $join_conds_safe[$table][0] . ' ' . $this->tableName( $table );
00808                                 $tableClause .= ' ' . $this->useIndexClause( implode( ',', (array)$use_index_safe[$table] ) );
00809                                 $tableClause .= ' ON (' . $this->makeList( (array)$join_conds_safe[$table][1], LIST_AND ) . ')';
00810                                 $retJOIN[] = $tableClause;
00811                         // Is there an INDEX clause?
00812                         } elseif ( isset( $use_index_safe[$table] ) ) {
00813                                 $tableClause = $this->tableName( $table );
00814                                 $tableClause .= ' ' . $this->useIndexClause( implode( ',', (array)$use_index_safe[$table] ) );
00815                                 $ret[] = $tableClause;
00816                         // Is there a JOIN clause?
00817                         } elseif ( isset( $join_conds_safe[$table] ) ) {
00818                                 $tableClause = $join_conds_safe[$table][0] . ' ' . $this->tableName( $table );
00819                                 $tableClause .= ' ON (' . $this->makeList( (array)$join_conds_safe[$table][1], LIST_AND ) . ')';
00820                                 $retJOIN[] = $tableClause;
00821                         } else {
00822                                 $tableClause = $this->tableName( $table );
00823                                 $ret[] = $tableClause;
00824                         }
00825                 }
00826                 // We can't separate explicit JOIN clauses with ',', use ' ' for those
00827                 $straightJoins = !empty( $ret ) ? implode( ',', $ret ) : "";
00828                 $otherJoins = !empty( $retJOIN ) ? implode( ' ', $retJOIN ) : "";
00829                 // Compile our final table clause
00830                 return implode( ' ', array( $straightJoins, $otherJoins ) );
00831         }
00832 
00833         function strencode( $s ) { # Should not be called by us
00834                 return str_replace( "'", "''", $s );
00835         }
00836 
00837         function addQuotes( $s ) {
00838                 if ( $s instanceof Blob ) {
00839                         return "'" . $s->fetch( $s ) . "'";
00840                 } else {
00841                         return parent::addQuotes( $s );
00842                 }
00843         }
00844 
00845         public function addIdentifierQuotes( $s ) {
00846                 // http://msdn.microsoft.com/en-us/library/aa223962.aspx
00847                 return '[' . $s . ']';
00848         }
00849 
00850         public function isQuotedIdentifier( $name ) {
00851                 return $name[0] == '[' && substr( $name, -1, 1 ) == ']';
00852         }
00853 
00854         function selectDB( $db ) {
00855                 return ( $this->query( "SET DATABASE $db" ) !== false );
00856         }
00857 
00865         function makeSelectOptions( $options ) {
00866                 $tailOpts = '';
00867                 $startOpts = '';
00868 
00869                 $noKeyOptions = array();
00870                 foreach ( $options as $key => $option ) {
00871                         if ( is_numeric( $key ) ) {
00872                                 $noKeyOptions[$option] = true;
00873                         }
00874                 }
00875 
00876                 if ( isset( $options['GROUP BY'] ) ) {
00877                         $tailOpts .= " GROUP BY {$options['GROUP BY']}";
00878                 }
00879                 if ( isset( $options['HAVING'] ) ) {
00880                         $tailOpts .= " HAVING {$options['GROUP BY']}";
00881                 }
00882                 if ( isset( $options['ORDER BY'] ) ) {
00883                         $tailOpts .= " ORDER BY {$options['ORDER BY']}";
00884                 }
00885 
00886                 if ( isset( $noKeyOptions['DISTINCT'] ) && isset( $noKeyOptions['DISTINCTROW'] ) ) {
00887                         $startOpts .= 'DISTINCT';
00888                 }
00889 
00890                 // we want this to be compatible with the output of parent::makeSelectOptions()
00891                 return array( $startOpts, '' , $tailOpts, '' );
00892         }
00893 
00897         function getType(){
00898                 return 'mssql';
00899         }
00900 
00901         function buildConcat( $stringList ) {
00902                 return implode( ' + ', $stringList );
00903         }
00904 
00905         public function getSearchEngine() {
00906                 return "SearchMssql";
00907         }
00908 
00913         public function getInfinity() {
00914                 return '3000-01-31 00:00:00.000';
00915         }
00916 
00917 } // end DatabaseMssql class
00918 
00924 class MssqlField implements Field {
00925         private $name, $tablename, $default, $max_length, $nullable, $type;
00926         function __construct ( $info ) {
00927                 $this->name = $info['COLUMN_NAME'];
00928                 $this->tablename = $info['TABLE_NAME'];
00929                 $this->default = $info['COLUMN_DEFAULT'];
00930                 $this->max_length = $info['CHARACTER_MAXIMUM_LENGTH'];
00931                 $this->nullable = !( strtolower( $info['IS_NULLABLE'] ) == 'no' );
00932                 $this->type = $info['DATA_TYPE'];
00933         }
00934 
00935         function name() {
00936                 return $this->name;
00937         }
00938 
00939         function tableName() {
00940                 return $this->tableName;
00941         }
00942 
00943         function defaultValue() {
00944                 return $this->default;
00945         }
00946 
00947         function maxLength() {
00948                 return $this->max_length;
00949         }
00950 
00951         function isNullable() {
00952                 return $this->nullable;
00953         }
00954 
00955         function type() {
00956                 return $this->type;
00957         }
00958 }
00959 
00966 class MssqlResult {
00967 
00968         public function __construct( $queryresult = false ) {
00969                 $this->mCursor = 0;
00970                 $this->mRows = array();
00971                 $this->mNumFields = sqlsrv_num_fields( $queryresult );
00972                 $this->mFieldMeta = sqlsrv_field_metadata( $queryresult );
00973 
00974                 $rows = sqlsrv_fetch_array( $queryresult, SQLSRV_FETCH_ASSOC );
00975 
00976                 foreach( $rows as $row ) {
00977                         if ( $row !== null ) {
00978                                 foreach ( $row as $k => $v ) {
00979                                         if ( is_object( $v ) && method_exists( $v, 'format' ) ) {// DateTime Object
00980                                                 $row[$k] = $v->format( "Y-m-d\TH:i:s\Z" );
00981                                         }
00982                                 }
00983                                 $this->mRows[] = $row;// read results into memory, cursors are not supported
00984                         }
00985                 }
00986                 $this->mRowCount = count( $this->mRows );
00987                 sqlsrv_free_stmt( $queryresult );
00988         }
00989 
00990         private function array_to_obj( $array, &$obj ) {
00991                 foreach ( $array as $key => $value ) {
00992                         if ( is_array( $value ) ) {
00993                                 $obj->$key = new stdClass();
00994                                 $this->array_to_obj( $value, $obj->$key );
00995                         } else {
00996                                 if ( !empty( $key ) ) {
00997                                         $obj->$key = $value;
00998                                 }
00999                         }
01000                 }
01001                 return $obj;
01002         }
01003 
01004         public function fetch( $mode = SQLSRV_FETCH_BOTH, $object_class = 'stdClass' ) {
01005                 if ( $this->mCursor >= $this->mRowCount || $this->mRowCount == 0 ) {
01006                         return false;
01007                 }
01008                 $arrNum = array();
01009                 if ( $mode == SQLSRV_FETCH_NUMERIC || $mode == SQLSRV_FETCH_BOTH ) {
01010                         foreach ( $this->mRows[$this->mCursor] as $value ) {
01011                                 $arrNum[] = $value;
01012                         }
01013                 }
01014                 switch( $mode ) {
01015                         case SQLSRV_FETCH_ASSOC:
01016                                 $ret = $this->mRows[$this->mCursor];
01017                                 break;
01018                         case SQLSRV_FETCH_NUMERIC:
01019                                 $ret = $arrNum;
01020                                 break;
01021                         case 'OBJECT':
01022                                 $o = new $object_class;
01023                                 $ret = $this->array_to_obj( $this->mRows[$this->mCursor], $o );
01024                                 break;
01025                         case SQLSRV_FETCH_BOTH:
01026                         default:
01027                                 $ret = $this->mRows[$this->mCursor] + $arrNum;
01028                                 break;
01029                 }
01030 
01031                 $this->mCursor++;
01032                 return $ret;
01033         }
01034 
01035         public function get( $pos, $fld ) {
01036                 return $this->mRows[$pos][$fld];
01037         }
01038 
01039         public function numrows() {
01040                 return $this->mRowCount;
01041         }
01042 
01043         public function seek( $iRow ) {
01044                 $this->mCursor = min( $iRow, $this->mRowCount );
01045         }
01046 
01047         public function numfields() {
01048                 return $this->mNumFields;
01049         }
01050 
01051         public function fieldname( $nr ) {
01052                 $arrKeys = array_keys( $this->mRows[0] );
01053                 return $arrKeys[$nr];
01054         }
01055 
01056         public function fieldtype( $nr ) {
01057                 $i = 0;
01058                 $intType = -1;
01059                 foreach ( $this->mFieldMeta as $meta ) {
01060                         if ( $nr == $i ) {
01061                                 $intType = $meta['Type'];
01062                                 break;
01063                         }
01064                         $i++;
01065                 }
01066                 // http://msdn.microsoft.com/en-us/library/cc296183.aspx contains type table
01067                 switch( $intType ) {
01068                         case SQLSRV_SQLTYPE_BIGINT:             $strType = 'bigint'; break;
01069                         case SQLSRV_SQLTYPE_BINARY:             $strType = 'binary'; break;
01070                         case SQLSRV_SQLTYPE_BIT:                        $strType = 'bit'; break;
01071                         case SQLSRV_SQLTYPE_CHAR:                       $strType = 'char'; break;
01072                         case SQLSRV_SQLTYPE_DATETIME:           $strType = 'datetime'; break;
01073                         case SQLSRV_SQLTYPE_DECIMAL/*($precision, $scale)*/: $strType = 'decimal'; break;
01074                         case SQLSRV_SQLTYPE_FLOAT:                      $strType = 'float'; break;
01075                         case SQLSRV_SQLTYPE_IMAGE:                      $strType = 'image'; break;
01076                         case SQLSRV_SQLTYPE_INT:                        $strType = 'int'; break;
01077                         case SQLSRV_SQLTYPE_MONEY:                      $strType = 'money'; break;
01078                         case SQLSRV_SQLTYPE_NCHAR/*($charCount)*/: $strType = 'nchar'; break;
01079                         case SQLSRV_SQLTYPE_NUMERIC/*($precision, $scale)*/: $strType = 'numeric'; break;
01080                         case SQLSRV_SQLTYPE_NVARCHAR/*($charCount)*/: $strType = 'nvarchar'; break;
01081                         // case SQLSRV_SQLTYPE_NVARCHAR('max'): $strType = 'nvarchar(MAX)'; break;
01082                         case SQLSRV_SQLTYPE_NTEXT:                      $strType = 'ntext'; break;
01083                         case SQLSRV_SQLTYPE_REAL:                       $strType = 'real'; break;
01084                         case SQLSRV_SQLTYPE_SMALLDATETIME:      $strType = 'smalldatetime'; break;
01085                         case SQLSRV_SQLTYPE_SMALLINT:           $strType = 'smallint'; break;
01086                         case SQLSRV_SQLTYPE_SMALLMONEY:         $strType = 'smallmoney'; break;
01087                         case SQLSRV_SQLTYPE_TEXT:                       $strType = 'text'; break;
01088                         case SQLSRV_SQLTYPE_TIMESTAMP:          $strType = 'timestamp'; break;
01089                         case SQLSRV_SQLTYPE_TINYINT:            $strType = 'tinyint'; break;
01090                         case SQLSRV_SQLTYPE_UNIQUEIDENTIFIER: $strType = 'uniqueidentifier'; break;
01091                         case SQLSRV_SQLTYPE_UDT:                        $strType = 'UDT'; break;
01092                         case SQLSRV_SQLTYPE_VARBINARY/*($byteCount)*/: $strType = 'varbinary'; break;
01093                         // case SQLSRV_SQLTYPE_VARBINARY('max'): $strType = 'varbinary(MAX)'; break;
01094                         case SQLSRV_SQLTYPE_VARCHAR/*($charCount)*/: $strType = 'varchar'; break;
01095                         // case SQLSRV_SQLTYPE_VARCHAR('max'): $strType = 'varchar(MAX)'; break;
01096                         case SQLSRV_SQLTYPE_XML:                        $strType = 'xml'; break;
01097                         default: $strType = $intType;
01098                 }
01099                 return $strType;
01100         }
01101 
01102         public function free() {
01103                 unset( $this->mRows );
01104                 return;
01105         }
01106 }