Merge "Add SelectQueryBuilder"

This commit is contained in:
jenkins-bot 2020-02-13 00:04:11 +00:00 committed by Gerrit Code Review
commit c3f20ad3f7
10 changed files with 1423 additions and 6 deletions

View file

@ -1682,6 +1682,8 @@ $wgAutoloadLocalClasses = [
'Wikimedia\\Rdbms\\ILoadMonitor' => __DIR__ . '/includes/libs/rdbms/loadmonitor/ILoadMonitor.php',
'Wikimedia\\Rdbms\\IMaintainableDatabase' => __DIR__ . '/includes/libs/rdbms/database/IMaintainableDatabase.php',
'Wikimedia\\Rdbms\\IResultWrapper' => __DIR__ . '/includes/libs/rdbms/database/resultwrapper/IResultWrapper.php',
'Wikimedia\\Rdbms\\JoinGroup' => __DIR__ . '/includes/libs/rdbms/querybuilder/JoinGroup.php',
'Wikimedia\\Rdbms\\JoinGroupBase' => __DIR__ . '/includes/libs/rdbms/querybuilder/JoinGroupBase.php',
'Wikimedia\\Rdbms\\LBFactory' => __DIR__ . '/includes/libs/rdbms/lbfactory/LBFactory.php',
'Wikimedia\\Rdbms\\LBFactoryMulti' => __DIR__ . '/includes/libs/rdbms/lbfactory/LBFactoryMulti.php',
'Wikimedia\\Rdbms\\LBFactorySimple' => __DIR__ . '/includes/libs/rdbms/lbfactory/LBFactorySimple.php',
@ -1701,6 +1703,7 @@ $wgAutoloadLocalClasses = [
'Wikimedia\\Rdbms\\ResultWrapper' => __DIR__ . '/includes/libs/rdbms/database/resultwrapper/ResultWrapper.php',
'Wikimedia\\Rdbms\\SQLiteField' => __DIR__ . '/includes/libs/rdbms/field/SQLiteField.php',
'Wikimedia\\Rdbms\\SchemaBuilder' => __DIR__ . '/includes/libs/rdbms/database/SchemaBuilder.php',
'Wikimedia\\Rdbms\\SelectQueryBuilder' => __DIR__ . '/includes/libs/rdbms/querybuilder/SelectQueryBuilder.php',
'Wikimedia\\Rdbms\\SessionConsistentConnectionManager' => __DIR__ . '/includes/libs/rdbms/connectionmanager/SessionConsistentConnectionManager.php',
'Wikimedia\\Rdbms\\Subquery' => __DIR__ . '/includes/libs/rdbms/encasing/Subquery.php',
'Wikimedia\\Rdbms\\TransactionProfiler' => __DIR__ . '/includes/libs/rdbms/TransactionProfiler.php',

View file

@ -299,6 +299,10 @@ class DBConnRef implements IDatabase {
return $this->__call( __FUNCTION__, func_get_args() );
}
public function newSelectQueryBuilder() {
return $this->__call( __FUNCTION__, func_get_args() );
}
public function selectField(
$table, $var, $cond = '', $fname = __METHOD__, $options = [], $join_conds = []
) {

View file

@ -1649,6 +1649,10 @@ abstract class Database implements IDatabase, IMaintainableDatabase, LoggerAware
public function freeResult( $res ) {
}
public function newSelectQueryBuilder() {
return new SelectQueryBuilder( $this );
}
public function selectField(
$table, $var, $cond = '', $fname = __METHOD__, $options = [], $join_conds = []
) {

View file

@ -530,6 +530,14 @@ interface IDatabase {
*/
public function freeResult( $res );
/**
* Create an empty SelectQueryBuilder which can be used to run queries
* against this connection.
*
* @return SelectQueryBuilder
*/
public function newSelectQueryBuilder();
/**
* A SELECT wrapper which returns a single field from a single result row
*
@ -653,7 +661,7 @@ interface IDatabase {
* Escaping of untrusted input used in values of numeric keys should be done via
* IDatabase::addQuotes()
*
* Use an empty array, string, or '*' to update all rows.
* Use an empty array, string, or '*' to select all rows.
*
* @param string $fname Caller function name
*
@ -701,6 +709,12 @@ interface IDatabase {
* use for that table. All strings are SQL fragments and so should be
* validated by the caller.
*
* - IGNORE INDEX: This may be either be a string giving an index name to
* ignore for the query, or an array. If it is an associative array,
* each key gives the table name (or alias), each value gives the index
* name to ignore for that table. All strings are SQL fragments and so
* should be validated by the caller.
*
* - EXPLAIN: In MySQL, this causes an EXPLAIN SELECT query to be run,
* instead of SELECT.
*
@ -1096,7 +1110,7 @@ interface IDatabase {
public function buildIntegerCast( $field );
/**
* Equivalent to IDatabase::selectSQLText() except wraps the result in Subqyery
* Equivalent to IDatabase::selectSQLText() except wraps the result in Subquery
*
* @see IDatabase::selectSQLText()
*

View file

@ -0,0 +1,58 @@
<?php
namespace Wikimedia\Rdbms;
/**
* An object representing a parenthesized group of tables and their join
* types and conditions.
*/
class JoinGroup extends JoinGroupBase {
/** @var string */
private $alias;
/** @var int */
private $nextAutoAlias = 0;
/**
* Use SelectQueryBuilder::newJoinGroup() to create a join group
*
* @internal
* @param string $alias
*/
public function __construct( $alias ) {
$this->alias = $alias;
}
/**
* Get a table alias which is unique to the parent SelectQueryBuilder
*
* @return string
*/
protected function getAutoAlias() {
return $this->alias . '_' . ( $this->nextAutoAlias++ );
}
/**
* @internal
* @return array
*/
public function getRawTables() {
return $this->tables;
}
/**
* @internal
* @return array
*/
public function getRawJoinConds() {
return $this->joinConds;
}
/**
* @internal
* @return string
*/
public function getAlias() {
return $this->alias;
}
}

View file

@ -0,0 +1,130 @@
<?php
namespace Wikimedia\Rdbms;
/**
* A class for code shared between SelectQueryBuilder and JoinGroup.
* Represents tables and join conditions.
*/
abstract class JoinGroupBase {
/** @var array */
protected $tables = [];
/** @var array */
protected $joinConds = [];
protected $lastAlias;
/**
* Add a single table or a single parenthesized group.
*
* @param string|JoinGroup|SelectQueryBuilder $table The table to add. If
* this is a string, it is the table name. If it is a JoinGroup created
* by SelectQueryBuilder::newJoinGroup(), the group will be added. If it
* is a SelectQueryBuilder, a table subquery will be added.
* @param string|null $alias The table alias, or null for no alias
* @return $this
*/
public function table( $table, $alias = null ) {
if ( $table instanceof JoinGroup ) {
if ( $alias === null ) {
$alias = $table->getAlias();
}
$table = $table->getRawTables();
} elseif ( $table instanceof SelectQueryBuilder ) {
if ( $alias === null ) {
$alias = $this->getAutoAlias();
}
$table = new Subquery( $table->getSQL() );
} elseif ( !is_string( $table ) ) {
throw new \InvalidArgumentException( __METHOD__ .
': $table must be either string, JoinGroup or SelectQueryBuilder' );
}
if ( $alias === null ) {
$this->tables[] = $table;
$this->lastAlias = $table;
} else {
$this->tables[$alias] = $table;
$this->lastAlias = $alias;
}
return $this;
}
/**
* Left join a table or group of tables. This should be called after table().
*
* @param string|JoinGroup|SelectQueryBuilder $table The table name, or a
* JoinGroup containing multiple tables, or a SelectQueryBuilder
* representing a subquery.
* @param string|null $alias The alias name, or null to automatically
* generate an alias which will be unique to this builder
* @param string|array $conds The conditions for the ON clause
* @return $this
*/
public function leftJoin( $table, $alias = null, $conds = [] ) {
$this->addJoin( 'LEFT JOIN', $table, $alias, $conds );
return $this;
}
/**
* Inner join a table or group of tables. This should be called after table().
*
* @param string|JoinGroup|SelectQueryBuilder $table The table name, or a
* JoinGroup containing multiple tables, or a SelectQueryBuilder
* representing a subquery.
* @param string|null $alias The alias name, or null to automatically
* generate an alias which will be unique to this builder
* @param string|array $conds The conditions for the ON clause
* @return $this
*/
public function join( $table, $alias = null, $conds = [] ) {
$this->addJoin( 'JOIN', $table, $alias, $conds );
return $this;
}
/**
* Private helper for functions that add joins
* @param string $type
* @param string|JoinGroup|SelectQueryBuilder $table
* @param string|null $alias
* @param string|array $joinConds
*/
private function addJoin( $type, $table, $alias, $joinConds ) {
if ( !$this->tables ) {
throw new \LogicException( __METHOD__ .
': cannot add a join unless a regular table is added first' );
}
if ( $alias === null ) {
if ( is_string( $table ) ) {
$alias = $table;
} else {
$alias = $this->getAutoAlias();
}
}
if ( isset( $this->joinConds[$alias] ) ) {
throw new \LogicException( __METHOD__ .
": a join with alias \"$alias\" has already been added" );
}
if ( $table instanceof JoinGroup ) {
$conflicts = array_intersect_key( $this->joinConds, $table->getRawJoinConds() );
if ( $conflicts ) {
$conflict = reset( $conflicts );
throw new \LogicException( __METHOD__ .
": a join with alias \"$conflict\" has already been added" );
}
$this->tables[$alias] = $table->getRawTables();
$this->joinConds += $table->getRawJoinConds();
} elseif ( $table instanceof SelectQueryBuilder ) {
$this->tables[$alias] = new Subquery( $table->getSQL() );
} elseif ( is_string( $table ) ) {
$this->tables[$alias] = $table;
} else {
throw new \InvalidArgumentException( __METHOD__ .
': $table must be either string, JoinGroup or SelectQueryBuilder' );
}
$this->joinConds[$alias] = [ $type, $joinConds ];
$this->lastAlias = $alias;
}
abstract protected function getAutoAlias();
}

View file

@ -0,0 +1,673 @@
<?php
namespace Wikimedia\Rdbms;
class SelectQueryBuilder extends JoinGroupBase {
/**
* @var array The fields to be passed to IDatabase::select()
*/
private $fields = [];
/**
* @var array The conditions to be passed to IDatabase::select()
*/
private $conds = [];
/**
* @var string The caller (function name) to be passed to IDatabase::select()
*/
private $caller = __CLASS__;
/**
* @var array The options to be passed to IDatabase::select()
*/
private $options = [];
/**
* @var int An integer used to assign automatic aliases to tables and groups
*/
private $nextAutoAlias = 1;
/** @var IDatabase */
private $db;
/**
* @internal
*
* @param IDatabase $db
*/
public function __construct( IDatabase $db ) {
$this->db = $db;
}
/**
* Change the IDatabase object the query builder is bound to. The specified
* IDatabase will subsequently be used to execute the query.
*
* @param IDatabase $db
* @return $this
*/
public function connection( IDatabase $db ) {
if ( $this->db->getType() !== $db->getType() ) {
throw new \InvalidArgumentException( __METHOD__ .
' cannot switch to a database of a different type.' );
}
$this->db = $db;
return $this;
}
/**
* Get an empty SelectQueryBuilder which can be used to build a subquery
* of this query.
* @return SelectQueryBuilder
*/
public function newSubquery() {
return new self( $this->db );
}
/**
* Add a single table to the SELECT query. Alias for table().
*
* @param string $table The table name
* @param string|null $alias The table alias, or null for no alias
* @return $this
*/
public function from( $table, $alias = null ) {
return $this->table( $table, $alias );
}
/**
* Add multiple tables. It's recommended to use join() and leftJoin() instead in new code.
*
* @param string[] $tables
* @return $this
*/
public function tables( $tables ) {
foreach ( $tables as $alias => $table ) {
if ( is_string( $alias ) ) {
$this->table( $table, $alias );
} else {
$this->table( $table );
}
}
return $this;
}
/**
* Add a field or an array of fields to the query. Each field is an SQL
* fragment. If the array key is non-numeric, the key is taken to be an
* alias for the field.
*
* @see IDatabase::select()
*
* @param string|string[] $fields
* @return $this
*/
public function fields( $fields ) {
if ( is_array( $fields ) ) {
$this->fields = array_merge( $this->fields, $fields );
} else {
$this->fields[] = $fields;
}
return $this;
}
/**
* Add a field or an array of fields to the query. Alias for fields().
*
* @param string|string[] $fields
* @return $this
*/
public function select( $fields ) {
return $this->fields( $fields );
}
/**
* Add a single field to the query, optionally with an alias. The field is
* an SQL fragment. It is unsafe to pass user input to this function.
*
* @param string $field
* @param string|null $alias
* @return $this
*/
public function field( $field, $alias = null ) {
if ( $alias === null ) {
$this->fields[] = $field;
} else {
$this->fields[$alias] = $field;
}
return $this;
}
/**
* Add conditions to the query. The supplied conditions will be appended
* to the existing conditions, separated by AND.
*
* @param string|array $conds
*
* May be either a string containing a single condition, or an array of
* conditions. If an array is given, the conditions constructed from each
* element are combined with AND.
*
* Array elements may take one of two forms:
*
* - Elements with a numeric key are interpreted as raw SQL fragments.
* - Elements with a string key are interpreted as equality conditions,
* where the key is the field name.
* - If the value of such an array element is a scalar (such as a
* string), it will be treated as data and thus quoted appropriately.
* If it is null, an IS NULL clause will be added.
* - If the value is an array, an IN (...) clause will be constructed
* from its non-null elements, and an IS NULL clause will be added
* if null is present, such that the field may match any of the
* elements in the array. The non-null elements will be quoted.
*
* Note that expressions are often DBMS-dependent in their syntax.
* DBMS-independent wrappers are provided for constructing several types of
* expression commonly used in condition queries. See:
* - IDatabase::buildLike()
* - IDatabase::conditional()
*
* Untrusted user input is safe in the values of string keys, however untrusted
* input must not be used in the array key names or in the values of numeric keys.
* Escaping of untrusted input used in values of numeric keys should be done via
* IDatabase::addQuotes()
*
* @return $this
*/
public function where( $conds ) {
if ( is_array( $conds ) ) {
$this->conds = array_merge( $this->conds, $conds );
} else {
$this->conds[] = $conds;
}
return $this;
}
/**
* Add conditions to the query. Alias for where().
*
* @param string|array $conds
* @return $this
*/
public function andWhere( $conds ) {
return $this->where( $conds );
}
/**
* Add conditions to the query. Alias for where().
*
* @param string|array $conds
* @return $this
*/
public function conds( $conds ) {
return $this->where( $conds );
}
/**
* Manually append to the $join_conds array which will be passed to
* IDatabase::select(). This is not recommended for new code. Instead,
* join() and leftJoin() should be used.
*
* @param array $joinConds
* @return $this
*/
public function joinConds( array $joinConds ) {
$this->joinConds = array_merge( $this->joinConds, $joinConds );
return $this;
}
/**
* Get a table alias which is unique to this SelectQueryBuilder
*
* @return string
*/
protected function getAutoAlias() {
return 'sqb' . ( $this->nextAutoAlias++ );
}
/**
* Create a parenthesized group of joins which can be added to the object
* like a table. The group is initially empty.
*
* @return JoinGroup
*/
public function newJoinGroup() {
return new JoinGroup( $this->getAutoAlias() );
}
/**
* Set the offset. Skip this many rows at the start of the result set. Offset
* with limit() can theoretically be used for paging through a result set,
* but this is discouraged for performance reasons.
*
* If the query builder already has an offset, the old offset will be discarded.
*
* @param int $offset
* @return $this
*/
public function offset( $offset ) {
$this->options['OFFSET'] = $offset;
return $this;
}
/**
* Set the query limit. Return at most this many rows. The rows are sorted
* and then the first rows are taken until the limit is reached. Limit
* is applied to a result set after offset.
*
* If the query builder already has a limit, the old limit will be discarded.
*
* @param int $limit
* @return $this
*/
public function limit( $limit ) {
$this->options['LIMIT'] = $limit;
return $this;
}
/**
* Enable the LOCK IN SHARE MODE option. Lock the returned rows so that
* they can't be changed until the next COMMIT. Cannot be used with
* aggregate functions (COUNT, MAX, etc., but also DISTINCT).
*
* @return $this
*/
public function lockInShareMode() {
$this->options[] = 'LOCK IN SHARE MODE';
return $this;
}
/**
* Enable the FOR UPDATE option. Lock the returned rows so that
* they can't be changed until the next COMMIT. Cannot be used with
* aggregate functions (COUNT, MAX, etc., but also DISTINCT).
*
* @return $this
*/
public function forUpdate() {
$this->options[] = 'FOR UPDATE';
return $this;
}
/**
* Enable the DISTINCT option. Return only unique result rows.
*
* @return $this
*/
public function distinct() {
$this->options[] = 'DISTINCT';
return $this;
}
/**
* Add a GROUP BY clause. May be either an SQL fragment string naming a
* field or expression to group by, or an array of such SQL fragments.
*
* If there is an existing GROUP BY clause, the new one will be appended.
*
* @param string|string[] $group
* @return $this
*/
public function groupBy( $group ) {
$this->mergeOption( 'GROUP BY', $group );
return $this;
}
/**
* Add a HAVING clause. May be either an string containing a HAVING clause
* or an array of conditions building the HAVING clause. If an array is
* given, the conditions constructed from each element are combined with
* AND.
*
* If there is an existing HAVING clause, the new one will be appended.
*
* @param string|string[] $having
* @return $this
*/
public function having( $having ) {
$this->mergeOption( 'HAVING', $having );
return $this;
}
/**
* Set the ORDER BY clause. If it has already been set, append the
* additional fields to it.
*
* @param string[]|string $fields The field or list of fields to order by.
* @param string|null $direction ASC or DESC. If this is null then $fields
* is assumed to optionally contain ASC or DESC after each field name.
* @return $this
*/
public function orderBy( $fields, $direction = null ) {
if ( $direction === null ) {
$this->mergeOption( 'ORDER BY', $fields );
} elseif ( is_array( $fields ) ) {
$fieldsWithDirection = [];
foreach ( $fields as $field ) {
$fieldsWithDirection[] = "$field $direction";
}
$this->mergeOption( 'ORDER BY', $fieldsWithDirection );
} else {
$this->mergeOption( 'ORDER BY', "$fields $direction" );
}
return $this;
}
/**
* Add a value to an option which may be not set or a string or array.
*
* @param string $name
* @param string|string[] $newArrayOrValue
*/
private function mergeOption( $name, $newArrayOrValue ) {
$value = isset( $this->options[$name] )
? (array)$this->options[$name] : [];
if ( is_array( $newArrayOrValue ) ) {
$value = array_merge( $value, $newArrayOrValue );
} else {
$value[] = $newArrayOrValue;
}
$this->options[$name] = $value;
}
/**
* Set a USE INDEX option.
*
* If a string is given, the index hint is applied to the most recently
* appended table or alias. If an array is given, it is assumed to be an
* associative array with the alias names in the keys and the indexes in
* the values, as in the USE INDEX option to IDatabase::select(). The
* array will be merged with the existing value.
*
* @param string|string[] $index
* @return $this
*/
public function useIndex( $index ) {
$this->setIndexHint( 'USE INDEX', $index );
return $this;
}
/**
* Set the IGNORE INDEX option.
*
* If a string is given, the index hint is applied to the most recently
* appended table or alias. If an array is given, it is assumed to be an
* associative array with the alias names in the keys and the indexes in
* the values, as in the IGNORE INDEX option to IDatabase::select(). The
* array will be merged with the existing value.
*
* @param string|string[] $index
* @return $this
*/
public function ignoreIndex( $index ) {
$this->setIndexHint( 'IGNORE INDEX', $index );
return $this;
}
/**
* Private helper for methods that set index hints.
*
* @param string $type
* @param string|string[] $value
*/
private function setIndexHint( $type, $value ) {
if ( !isset( $this->options[$type] ) ) {
$this->options[$type] = [];
} elseif ( !is_array( $this->options[$type] ) ) {
throw new \UnexpectedValueException(
__METHOD__ . ": The $type option cannot be appended to " .
'because it is not an array. This may have been caused by a prior ' .
'call to option() or options().' );
}
if ( is_array( $value ) ) {
$this->options[$type] = array_merge( $this->options[$type], $value );
} elseif ( $this->lastAlias === null ) {
throw new \UnexpectedValueException(
__METHOD__ . ': Cannot append index value since there is no' .
'prior table' );
} else {
$this->options[$type][$this->lastAlias] = $value;
}
}
/**
* Make the query be an EXPLAIN SELECT query instead of a SELECT query.
*
* @return $this
*/
public function explain() {
$this->options['EXPLAIN'] = true;
return $this;
}
/**
* Enable the STRAIGHT_JOIN option.
*
* @return $this
*/
public function straightJoin() {
$this->options[] = 'STRAIGHT_JOIN';
return $this;
}
/**
* Enable the SQL_BIG_RESULT option.
*
* @return $this
*/
public function bigResult() {
$this->options[] = 'SQL_BIG_RESULT';
return $this;
}
/**
* Enable the SQL_BUFFER_RESULT option.
*
* @return $this
*/
public function bufferResult() {
$this->options[] = 'SQL_BUFFER_RESULT';
return $this;
}
/**
* Enable the SQL_SMALL_RESULT option.
*
* @return $this
*/
public function smallResult() {
$this->options[] = 'SQL_SMALL_RESULT';
return $this;
}
/**
* Enable the SQL_CALC_FOUND_ROWS option.
*
* @return $this
*/
public function calcFoundRows() {
$this->options[] = 'SQL_CALC_FOUND_ROWS';
return $this;
}
/**
* Manually set an option in the $options array to be passed to
* IDatabase::select()
*
* @param string $name The option name
* @param mixed $value The option value, or null for a boolean option
* @return $this
*/
public function option( $name, $value = null ) {
if ( $value === null ) {
$this->options[] = $name;
} else {
$this->options[$name] = $value;
}
return $this;
}
/**
* Manually set multiple options in the $options array to be passed to
* IDatabase::select().
*
* @param array $options
* @return $this
*/
public function options( array $options ) {
$this->options = array_merge( $this->options, $options );
return $this;
}
/**
* Set the method name to be included in an SQL comment.
*
* @param string $fname
* @return $this
*/
public function caller( $fname ) {
$this->caller = $fname;
return $this;
}
/**
* Run the constructed SELECT query and return all results.
*
* @return IResultWrapper
*/
public function fetchResultSet() {
return $this->db->select( $this->tables, $this->fields, $this->conds, $this->caller,
$this->options, $this->joinConds );
}
/**
* Run the constructed SELECT query, and return a single field extracted
* from the first result row. This may only be called when only one field
* has been added to the builder.
*
* @return mixed
*/
public function fetchField() {
if ( count( $this->fields ) !== 1 ) {
throw new \UnexpectedValueException(
__METHOD__ . ' expects the query to have only one field' );
}
$field = reset( $this->fields );
return $this->db->selectField( $this->tables, $field, $this->conds, $this->caller,
$this->options, $this->joinConds );
}
/**
* Run the constructed SELECT query, and extract a single field from each
* result row, returning an array containing all the values. This may only
* be called when only one field has been added to the builder.
*
* @return array
*/
public function fetchFieldValues() {
if ( count( $this->fields ) !== 1 ) {
throw new \UnexpectedValueException(
__METHOD__ . ' expects the query to have only one field' );
}
$field = reset( $this->fields );
return $this->db->selectFieldValues( $this->tables, $field, $this->conds, $this->caller,
$this->options, $this->joinConds );
}
/**
* Run the constructed SELECT query, and return the first result row. If
* there were no results, return false.
*
* @return bool|\stdClass
*/
public function fetchRow() {
return $this->db->selectRow( $this->tables, $this->fields, $this->conds, $this->caller,
$this->options, $this->joinConds );
}
/**
* Run the SELECT query, and return the number of results. This typically
* uses a subquery to discard the actual results on the server side, and
* is useful when counting rows with a limit.
*
* @return int
*/
public function fetchRowCount() {
return $this->db->selectRowCount( $this->tables, $this->getRowCountVar(), $this->conds,
$this->caller, $this->options, $this->joinConds );
}
/**
* Estimate the number of rows in dataset
*
* MySQL allows you to estimate the number of rows that would be returned
* by a SELECT query, using EXPLAIN SELECT. The estimate is provided using
* index cardinality statistics, and is notoriously inaccurate, especially
* when large numbers of rows have recently been added or deleted.
*
* @return int
*/
public function estimateRowCount() {
return $this->db->estimateRowCount( $this->tables, $this->getRowCountVar(), $this->conds,
$this->caller, $this->options, $this->joinConds );
}
/**
* Private helper which extracts a field suitable for row counting from the
* fields array
*
* @return string
*/
private function getRowCountVar() {
if ( count( $this->fields ) === 0 ) {
return '*';
} elseif ( count( $this->fields ) === 1 ) {
return reset( $this->fields );
} else {
throw new \UnexpectedValueException(
__METHOD__ . ' expects the query to have at most one field' );
}
}
/**
* Run the SELECT query with the FOR UPDATE option. The field list is ignored.
*
* @return int
*/
public function lockForUpdate() {
return $this->db->lockForUpdate( $this->tables, $this->conds, $this->caller,
$this->options, $this->joinConds );
}
/**
* Build a GROUP_CONCAT or equivalent statement for a query.
*
* This is useful for combining a field for several rows into a single string.
* NULL values will not appear in the output, duplicated values will appear,
* and the resulting delimiter-separated values have no defined sort order.
* Code using the results may need to use the PHP unique() or sort() methods.
*
* @param string $delim
* @return string
*/
public function buildGroupConcatField( $delim ) {
if ( count( $this->fields ) !== 1 ) {
throw new \UnexpectedValueException(
__METHOD__ . ' expects the query to have only one field' );
}
$field = reset( $this->fields );
return $this->db->buildGroupConcatField( $delim, $this->tables, $field,
$this->conds, $this->joinConds );
}
/**
* Get the SQL query string which would be used by fetchResultSet().
*
* @return string
*/
public function getSQL() {
return $this->db->selectSQLText( $this->tables, $this->fields, $this->conds, $this->caller,
$this->options, $this->joinConds );
}
}

View file

@ -277,4 +277,12 @@ class DatabaseTestHelper extends Database {
public function setUnionSupportsOrderAndLimit( $v ) {
$this->unionSupportsOrderAndLimit = (bool)$v;
}
public function useIndexClause( $index ) {
return "FORCE INDEX (" . $this->indexName( $index ) . ")";
}
public function ignoreIndexClause( $index ) {
return "IGNORE INDEX (" . $this->indexName( $index ) . ")";
}
}

View file

@ -208,8 +208,7 @@ class DatabaseSQLTest extends PHPUnit\Framework\TestCase {
'fields' => [ 'field' ],
'options' => [ 'USE INDEX' => [ 'table' => 'X' ] ],
],
// No-op by default
"SELECT field FROM table"
"SELECT field FROM table FORCE INDEX (X)"
],
[
[
@ -217,8 +216,7 @@ class DatabaseSQLTest extends PHPUnit\Framework\TestCase {
'fields' => [ 'field' ],
'options' => [ 'IGNORE INDEX' => [ 'table' => 'X' ] ],
],
// No-op by default
"SELECT field FROM table"
"SELECT field FROM table IGNORE INDEX (X)"
],
[
[

View file

@ -0,0 +1,525 @@
<?php
use Wikimedia\Rdbms\IResultWrapper;
use Wikimedia\Rdbms\SelectQueryBuilder;
/**
* @covers \Wikimedia\Rdbms\SelectQueryBuilder
* @covers \Wikimedia\Rdbms\JoinGroup
* @covers \Wikimedia\Rdbms\BuilderSubquery
*/
class SelectQueryBuilderTest extends PHPUnit\Framework\TestCase {
/** @var DatabaseTestHelper */
private $db;
/** @var SelectQueryBuilder */
private $sqb;
protected function setUp() : void {
$this->db = new DatabaseTestHelper( __CLASS__ . '::' . $this->getName() );
$this->sqb = $this->db->newSelectQueryBuilder();
}
private function assertSQL( $expected ) {
$actual = $this->sqb->getSQL();
$actual = preg_replace( '/ +/', ' ', $actual );
$actual = preg_replace( '/ +$/', '', $actual );
$this->assertEquals( $expected, $actual );
}
public function testNoTable() {
$this->sqb
->select( '1' );
$this->assertSQL( 'SELECT 1' );
}
public function testCondsEtc() {
$this->sqb
->table( 'a' )
->where( '1' )
->andWhere( '2' )
->conds( '3' )
->field( 'f' );
$this->assertSQL( 'SELECT f FROM a WHERE (1) AND (2) AND (3)' );
}
public function testTableAlias() {
$this->sqb
->table( 't', 'a' )
->field( 'f' );
$this->assertSQL( 'SELECT f FROM t a' );
}
public function testTableIndex() {
$this->sqb
->table( 't', null )
->useIndex( 'i' )
->field( 'f' );
$this->assertSQL( 'SELECT f FROM t FORCE INDEX (i)' );
}
public function testTableAliasIndex() {
$this->sqb
->table( 't', 'a' )
->useIndex( 'i' )
->field( 'f' );
$this->assertSQL( 'SELECT f FROM t a FORCE INDEX (i)' );
}
public function testIgnoreIndex() {
$this->sqb
->table( 't' )
->ignoreIndex( 'i' )
->field( 'f' );
$this->assertSQL( 'SELECT f FROM t IGNORE INDEX (i)' );
}
public function testSubquery() {
$this->sqb
->table(
$this->sqb->newSubquery()
->field( 'f' )
->from( 't' )
->useIndex( 'i' ),
'sq'
)
->field( 'sq.f' );
$this->assertSql( 'SELECT sq.f FROM (SELECT f FROM t FORCE INDEX (i) ) sq' );
}
public function testTablesFields() {
$this->sqb
->tables( [ 'a' => 'b', 'c' ] )
->useIndex( 'ic' )
->useIndex( [ 'a' => 'ia' ] )
->fields( [ 'a', 'b' ] );
$this->assertSQL( 'SELECT a,b FROM b a FORCE INDEX (ia),c FORCE INDEX (ic)' );
}
public function testJoin() {
$this->sqb
->table( 'a' )
->join( 'b', 'b', 'aa=bb' )
->field( '*' );
$this->assertSQL( 'SELECT * FROM a JOIN b ON ((aa=bb))' );
}
public function testLeftJoin() {
$this->sqb
->table( 'a' )
->leftJoin( 'b', 'b', 'aa=bb' )
->fields( '*' );
$this->assertSQL( 'SELECT * FROM a LEFT JOIN b ON ((aa=bb))' );
}
public function testAutoAliasedJoin() {
$this->sqb
->table( 'a' )
->join( 'b' )
->field( '*' );
$this->assertSQL( 'SELECT * FROM a JOIN b' );
}
public function testAutoAliasedLeftJoin() {
$this->sqb
->table( 'a' )
->leftJoin( 'b', null, 'aa=bb' )
->field( '*' );
$this->assertSQL( 'SELECT * FROM a LEFT JOIN b ON ((aa=bb))' );
}
public function testLeftJoinGroup() {
$this->sqb
->table( 'a' )
->field( 'f' )
->leftJoin(
$this->sqb->newJoinGroup()
->table( 'b' )
->leftJoin( 'c', 'c', 'bb=cc' ),
null,
'bb=aa'
);
$this->assertSQL( 'SELECT f FROM a LEFT JOIN (b LEFT JOIN c ON ((bb=cc))) ON ((bb=aa))' );
}
public function testInnerJoinGroup() {
$this->sqb
->table( 'a' )
->field( 'f' )
->join(
$this->sqb->newJoinGroup()
->table( 'b' )
->join( 'c', 'c', 'bb=cc' ),
null,
'bb=aa'
);
$this->assertSQL( 'SELECT f FROM a JOIN (b JOIN c ON ((bb=cc))) ON ((bb=aa))' );
}
public function testDoubleJoinGroup() {
$this->sqb
->table( 'a' )
->field( 'f' )
->join(
$this->sqb->newJoinGroup()
->table( 'b' )
->join(
$this->sqb->newJoinGroup()
->table( 'c' )
->join( 'd', 'd', [] ),
null, [] ),
null,
[]
);
$this->assertSQL( 'SELECT f FROM a JOIN (b JOIN (c JOIN d))' );
}
public function testInitialJoinGroup() {
$this->sqb
->table(
$this->sqb->newJoinGroup()
->table( 'a' )
->table( 'b' )
)
->field( 'f' );
$this->assertSQL( 'SELECT f FROM (a,b )' );
}
public function testInitialDoubleJoinGroup() {
$this->sqb
->table( $this->sqb->newJoinGroup()
->table(
$this->sqb->newJoinGroup()
->table( 'a' )
->table( 'b' )
)
->table(
$this->sqb->newJoinGroup()
->table( 'c' )
->table( 'd' )
)
)
->field( 'f' );
$this->assertSQL( 'SELECT f FROM ((a,b ),(c,d ) )' );
}
public function testDegenerateJoinGroup() {
$this->sqb
->table( $this->sqb->newJoinGroup()->table( 'a' ) )
->field( 'f' );
$this->assertSQL( 'SELECT f FROM a' );
}
public function testSubqueryInJoinGroup() {
$this->sqb
->field( 'f' )
->table(
$this->sqb->newJoinGroup()
->table( 'a' )
->join( $this->sqb->newSubquery()->select( '1' ) )
);
$this->assertSQL( 'SELECT f FROM (a,(SELECT 1 ) sqb1_0 )' );
}
public function testConditionsOnGroup() {
$this->sqb
->field( 'f' )
->table( 'a' )
->join(
$this->sqb->newJoinGroup()
->table( 'b' )
->table( 'c' ),
null,
'aa=bb' );
$this->assertSQL( 'SELECT f FROM a JOIN (b,c ) ON ((aa=bb))' );
}
public function testJoinToEmpty() {
$this->expectException( LogicException::class );
$this->sqb->join( 'a', 'a', [] );
}
public function testJoinToEmptyInJoinGroup() {
$this->expectException( LogicException::class );
$this->sqb->newJoinGroup()->join( 'a', 'a', [] );
}
public function testConflictingAlias() {
$this->expectException( LogicException::class );
$this->sqb
->table( 'a' )
->join( 'b' )
->join( 'b' );
}
public function testConflictingAliasInGroup() {
$this->expectException( LogicException::class );
$this->sqb->newJoinGroup()
->table( 'a' )
->join( 'b' )
->join( 'b' );
}
public function testJoinConds() {
$this->sqb
->field( '*' )
->tables( [ 'a', 'b' => 'b' ] )
->joinConds( [ 'b' => [ 'LEFT JOIN', 'aa=bb' ] ] );
$this->assertSQL( 'SELECT * FROM a LEFT JOIN b ON ((aa=bb))' );
}
public function testJoinSubquery() {
$this->sqb
->select( 'sq.a' )
->from( 't1' )
->join(
$this->sqb->newSubquery()->select( 'a' )->from( 't2' ),
'sq',
[]
);
$this->assertSQL( 'SELECT sq.a FROM t1 JOIN (SELECT a FROM t2 ) sq' );
}
public function testLeftJoinSubquery() {
$this->sqb
->select( 'sq.a' )
->from( 't1' )
->leftJoin(
$this->sqb->newSubquery()->select( 'a' )->from( 't2' ),
'sq',
[ 'aa' => null ]
);
$this->assertSQL( 'SELECT sq.a FROM t1 LEFT JOIN (SELECT a FROM t2 ) sq ON (aa IS NULL)' );
}
public function testOffsetLimit() {
$this->sqb
->select( 'f' )
->from( 't' )
->offset( 1 )
->limit( 2 );
$this->assertSQL( 'SELECT f FROM t LIMIT 1,2' );
}
public function testLockInShareMode() {
$this->sqb
->select( 'f' )
->from( 't' )
->lockInShareMode();
$this->assertSQL( 'SELECT f FROM t LOCK IN SHARE MODE' );
}
public function testForUpdate() {
$this->sqb
->select( 'f' )
->from( 't' )
->forUpdate();
$this->assertSQL( 'SELECT f FROM t FOR UPDATE' );
}
public function testDistinct() {
$this->sqb
->select( 'f' )
->from( 't' )
->distinct();
$this->assertSQL( 'SELECT DISTINCT f FROM t' );
}
public function testGroupBy() {
$this->sqb
->select( 'f' )
->from( 't' )
->groupBy( [ '1', '2' ] );
$this->assertSQL( 'SELECT f FROM t GROUP BY 1,2' );
}
public function testHaving() {
$this->sqb
->select( 'f' )
->from( 't' )
->having( [ 'a' => 1 ] );
$this->assertSQL( 'SELECT f FROM t HAVING a = 1' );
}
public function testOrderBy1() {
$this->sqb
->select( [ 'a', 'b', 'c' ] )
->from( 't' )
->orderBy( 'a' )
->orderBy( 'b', 'DESC' )
->orderBy( 'c' );
$this->assertSQL( 'SELECT a,b,c FROM t ORDER BY a,b DESC,c' );
}
public function testOrderBy2() {
$this->sqb
->select( [ 'a', 'b', 'c' ] )
->from( 't' )
->orderBy( [ 'a', 'b', 'c' ] );
$this->assertSQL( 'SELECT a,b,c FROM t ORDER BY a,b,c' );
}
public function testOrderBy3() {
$this->sqb
->select( [ 'a', 'b', 'c' ] )
->from( 't' )
->orderBy( [ 'a', 'b', 'c' ], 'DESC' );
$this->assertSQL( 'SELECT a,b,c FROM t ORDER BY a DESC,b DESC,c DESC' );
}
public function testOrderBy4() {
$this->sqb
->select( [ 'a', 'b', 'c' ] )
->from( 't' )
->orderBy( 'a' )
->orderBy( [ 'b', 'c' ] );
$this->assertSQL( 'SELECT a,b,c FROM t ORDER BY a,b,c' );
}
public function testOrderBy5() {
$this->sqb
->select( [ 'a', 'b', 'c' ] )
->from( 't' )
->option( 'ORDER BY', 'a' )
->orderBy( [ 'b', 'c' ] );
$this->assertSQL( 'SELECT a,b,c FROM t ORDER BY a,b,c' );
}
public function testExplain() {
$this->sqb
->explain()
->select( '*' )
->from( 't' );
$this->assertSQL( 'EXPLAIN SELECT * FROM t' );
}
public function testStraightJoin() {
$this->sqb
->straightJoin()
->select( '1' )
->from( 't' );
$this->assertSQL( 'SELECT /*! STRAIGHT_JOIN */ 1 FROM t' );
}
public function testBigResult() {
$this->sqb
->bigResult()
->select( '1' )
->from( 't' );
$this->assertSQL( 'SELECT SQL_BIG_RESULT 1 FROM t' );
}
public function testSmallResult() {
$this->sqb
->smallResult()
->select( '1' )
->from( 't' );
$this->assertSQL( 'SELECT SQL_SMALL_RESULT 1 FROM t' );
}
public function testCalcFoundRows() {
$this->sqb
->calcFoundRows()
->select( '1' )
->from( 't' );
$this->assertSQL( 'SELECT SQL_CALC_FOUND_ROWS 1 FROM t' );
}
public function testOption() {
$this->sqb
->select( 'f' )
->from( 't' )
->option( 'ORDER BY', 'a' );
$this->assertSQL( 'SELECT f FROM t ORDER BY a' );
}
public function testOptions() {
$this->sqb
->select( '1' )
->options( [ 'ORDER BY' => '1', 'GROUP BY' => '2' ] );
$this->assertSQL( 'SELECT 1 GROUP BY 2 ORDER BY 1' );
}
public function testFetchResultSet() {
$this->sqb->select( '1' )->caller( __METHOD__ );
$res = $this->sqb->fetchResultSet();
$this->assertEquals( 'SELECT 1', $this->db->getLastSqls() );
$this->assertInstanceOf( IResultWrapper::class, $res );
}
public function testFetchField() {
$this->sqb->select( '1' )->caller( __METHOD__ );
$this->sqb->fetchField();
$this->assertEquals( 'SELECT 1 LIMIT 1', $this->db->getLastSqls() );
}
public function testFetchFieldValues() {
$this->sqb->select( '1' )->caller( __METHOD__ );
$res = $this->sqb->fetchFieldValues();
$this->assertEquals( 'SELECT 1 AS value', $this->db->getLastSqls() );
$this->assertIsArray( $res );
}
public function testFetchRow() {
$this->sqb->select( '1' )->caller( __METHOD__ );
$this->sqb->fetchRow();
$this->assertEquals( 'SELECT 1 LIMIT 1', $this->db->getLastSqls() );
}
public function testFetchRowCount() {
$this->sqb->table( 't' )->caller( __METHOD__ );
$this->sqb->fetchRowCount();
$this->assertEquals( 'SELECT COUNT(*) AS rowcount FROM (SELECT 1 FROM t ) tmp_count',
$this->db->getLastSqls() );
}
public function testFetchRowCountWithField() {
$this->sqb->table( 't' )->field( 'f' )->caller( __METHOD__ );
$this->sqb->fetchRowCount();
// phpcs:ignore Generic.Files.LineLength.TooLong
$this->assertEquals( 'SELECT COUNT(*) AS rowcount FROM (SELECT 1 FROM t WHERE (f IS NOT NULL) ) tmp_count',
$this->db->getLastSqls() );
}
public function testEstimateRowCount() {
$this->sqb
->table( 't' )
->conds( [ 'a' => 'b' ] )
->caller( __METHOD__ );
$this->sqb->estimateRowCount();
$this->assertEquals( 'SELECT COUNT(*) AS rowcount FROM t WHERE a = \'b\'',
$this->db->getLastSqls() );
}
public function testLockForUpdate() {
$this->sqb
->table( 't' )
->conds( [ 'a' => 'b' ] )
->caller( __METHOD__ );
$this->db->begin( __METHOD__ );
$this->sqb->lockForUpdate();
$this->db->rollback( __METHOD__ );
// phpcs:ignore Generic.Files.LineLength.TooLong
$this->assertEquals( 'BEGIN; SELECT COUNT(*) AS rowcount FROM (SELECT 1 FROM t WHERE a = \'b\' FOR UPDATE) tmp_count; ROLLBACK',
$this->db->getLastSqls() );
}
public function testBuildGroupConcatField() {
$this->sqb
->select( 'f' )
->from( 't' )
->caller( __METHOD__ );
$res = $this->sqb->buildGroupConcatField( '|' );
$this->assertEquals( '(SELECT GROUP_CONCAT(f SEPARATOR \'|\') FROM t )',
$res );
}
public function testGetSQL() {
$this->sqb
->select( 'f' )
->from( 't' )
->caller( __METHOD__ );
$res = $this->sqb->getSQL();
$this->assertEquals( 'SELECT f FROM t ', $res );
}
}