Merge pull request #321 from silverstripe/sqlquery-enhancements

FEATURE: implement SS_List->reverse(). API CHANGE: SQLQuery:: now an arr...
This commit is contained in:
Sam Minnée 2012-04-26 20:55:53 -07:00
commit 809ed8e205
11 changed files with 458 additions and 174 deletions

View File

@ -293,7 +293,18 @@ class ArrayList extends ViewableData implements SS_List, SS_Filterable, SS_Sorta
public function canSortBy($by) {
return true;
}
/**
* Reverses an {@link ArrayList}
*
* @return ArrayList
*/
public function reverse() {
$this->items = array_reverse($this->items);
return $this;
}
/**
* Sorts this list by one or more fields. You can either pass in a single
* field name and direction, or a map of field names to sort directions.

View File

@ -37,6 +37,7 @@ class DataList extends ViewableData implements SS_List, SS_Filterable, SS_Sortab
public function __construct($dataClass) {
$this->dataClass = $dataClass;
$this->dataQuery = new DataQuery($this->dataClass);
parent::__construct();
}
@ -148,51 +149,48 @@ class DataList extends ViewableData implements SS_List, SS_Filterable, SS_Sortab
/**
* Set the sort order of this data list
*
* @return DataList
* @see SS_List::sort()
* @see SQLQuery::orderby
*
* @example $list->sort('Name'); // default ASC sorting
* @example $list->sort('Name DESC'); // DESC sorting
* @example $list->sort('Name', 'ASC');
* @example $list->sort(array('Name'=>'ASC,'Age'=>'DESC'));
*
* @return DataList
*/
public function sort() {
if(count(func_get_args())==0){
if(count(func_get_args()) == 0) {
return $this;
}
if(count(func_get_args())>2){
if(count(func_get_args()) > 2) {
throw new InvalidArgumentException('This method takes zero, one or two arguments');
}
// sort('Name','Desc')
if(count(func_get_args())==2){
if(count(func_get_args()) == 2) {
// sort('Name','Desc')
if(!in_array(strtolower(func_get_arg(1)),array('desc','asc'))){
user_error('Second argument to sort must be either ASC or DESC');
}
$this->dataQuery->sort(func_get_arg(0).' '.func_get_arg(1));
return $this;
$this->dataQuery->sort(func_get_arg(0), func_get_arg(1));
}
// sort('Name') - default to ASC sorting if not specified
if(is_string(func_get_arg(0)) && func_get_arg(0)){
else if(is_string(func_get_arg(0)) && func_get_arg(0)){
// sort('Name ASC')
if(stristr(func_get_arg(0), ' asc') || stristr(func_get_arg(0), ' desc')){
if(stristr(func_get_arg(0), ' asc') || stristr(func_get_arg(0), ' desc')) {
$this->dataQuery->sort(func_get_arg(0));
} else {
$this->dataQuery->sort(func_get_arg(0).' ASC');
$this->dataQuery->sort(func_get_arg(0), 'ASC');
}
return $this;
}
// sort(array('Name'=>'desc'));
$argumentArray = func_get_arg(0);
if(is_array($argumentArray)){
$sort = array();
foreach($argumentArray as $column => $direction) {
$sort[]= ''.$this->getRelationName($column).' '.$direction;
else if(is_array(func_get_arg(0))) {
// sort(array('Name'=>'desc'));
$this->dataQuery->sort(null, null); // wipe the sort
foreach(func_get_arg(0) as $col => $dir) {
$this->dataQuery->sort($this->getRelationName($col), $dir, false);
}
$this->dataQuery->sort(implode(',', $sort));
return $this;
}
return $this;
@ -201,8 +199,8 @@ class DataList extends ViewableData implements SS_List, SS_Filterable, SS_Sortab
/**
* Filter the list to include items with these charactaristics
*
* @return DataList
* @see SS_List::filter()
*
* @example $list->filter('Name', 'bob'); // only bob in the list
* @example $list->filter('Name', array('aziz', 'bob'); // aziz and bob in list
* @example $list->filter(array('Name'=>'bob, 'Age'=>21)); // bob with the age 21
@ -210,6 +208,8 @@ class DataList extends ViewableData implements SS_List, SS_Filterable, SS_Sortab
* @example $list->filter(array('Name'=>array('aziz','bob'), 'Age'=>array(21, 43))); // aziz with the age 21 or 43 and bob with the Age 21 or 43
*
* @todo extract the sql from $customQuery into a SQLGenerator class
*
* @return DataList
*/
public function filter() {
$numberFuncArgs = count(func_get_args());
@ -284,9 +284,8 @@ class DataList extends ViewableData implements SS_List, SS_Filterable, SS_Sortab
}
/**
* Exclude the list to not contain items with these charactaristics
* Exclude the list to not contain items with these characteristics
*
* @return DataList
* @see SS_List::exclude()
* @example $list->exclude('Name', 'bob'); // exclude bob from list
* @example $list->exclude('Name', array('aziz', 'bob'); // exclude aziz and bob from list
@ -295,6 +294,8 @@ class DataList extends ViewableData implements SS_List, SS_Filterable, SS_Sortab
* @example $list->exclude(array('Name'=>array('bob','phil'), 'Age'=>array(21, 43))); // bob age 21 or 43, phil age 21 or 43 would be excluded
*
* @todo extract the sql from this method into a SQLGenerator class
*
* @return DataList
*/
public function exclude(){
$numberFuncArgs = count(func_get_args());
@ -338,6 +339,7 @@ class DataList extends ViewableData implements SS_List, SS_Filterable, SS_Sortab
$newlist = clone $this;
$newlist->dataQuery->subtract($list->dataQuery());
return $newlist;
}
@ -351,6 +353,7 @@ class DataList extends ViewableData implements SS_List, SS_Filterable, SS_Sortab
*/
public function innerJoin($table, $onClause, $alias = null) {
$this->dataQuery->innerJoin($table, $onClause, $alias);
return $this;
}
@ -364,6 +367,7 @@ class DataList extends ViewableData implements SS_List, SS_Filterable, SS_Sortab
*/
public function leftJoin($table, $onClause, $alias = null) {
$this->dataQuery->leftJoin($table, $onClause, $alias);
return $this;
}
@ -377,9 +381,11 @@ class DataList extends ViewableData implements SS_List, SS_Filterable, SS_Sortab
$query = $this->dataQuery->query();
$rows = $query->execute();
$results = array();
foreach($rows as $row) {
$results[] = $this->createDataObject($row);
}
return $results;
}
@ -390,6 +396,7 @@ class DataList extends ViewableData implements SS_List, SS_Filterable, SS_Sortab
*/
public function toNestedArray() {
$result = array();
foreach($this as $item) {
$result[] = $item->toMap();
}
@ -399,6 +406,7 @@ class DataList extends ViewableData implements SS_List, SS_Filterable, SS_Sortab
public function debug() {
$val = "<h2>" . $this->class . "</h2><ul>";
foreach($this->toNestedArray() as $item) {
$val .= "<li style=\"list-style-type: disc; margin-left: 20px\">" . Debug::text($item) . "</li>";
}
@ -574,6 +582,7 @@ class DataList extends ViewableData implements SS_List, SS_Filterable, SS_Sortab
public function byIDs(array $ids) {
$baseClass = ClassInfo::baseDataClass($this->dataClass);
$this->where("\"$baseClass\".\"ID\" IN (" . implode(',', $ids) .")");
return $this;
}
@ -586,6 +595,7 @@ class DataList extends ViewableData implements SS_List, SS_Filterable, SS_Sortab
public function byID($id) {
$baseClass = ClassInfo::baseDataClass($this->dataClass);
$clone = clone $this;
return $clone->where("\"$baseClass\".\"ID\" = " . (int)$id)->First();
}
@ -755,7 +765,18 @@ class DataList extends ViewableData implements SS_List, SS_Filterable, SS_Sortab
$item = $this->byID($itemID);
if($item) return $item->delete();
}
/**
* Reverses a list of items.
*
* @return DataList
*/
public function reverse() {
$this->dataQuery->reverseSort();
return $this;
}
/**
* This method won't function on DataLists due to the specific query that it represent
*

View File

@ -3,14 +3,31 @@
/**
* An object representing a query of data from the DataObject's supporting database.
* Acts as a wrapper over {@link SQLQuery} and performs all of the query generation.
* Used extensively by DataList.
* Used extensively by {@link DataList}.
*
* @subpackage model
* @package sapphire
*/
class DataQuery {
/**
* @var String
*/
protected $dataClass;
/**
* @var SQLQuery
*/
protected $query;
/**
* @var array
*/
protected $collidingFields = array();
/**
* @var Boolean
*/
private $queryFinalised = false;
// TODO: replace subclass_access with this
@ -20,7 +37,8 @@ class DataQuery {
/**
* Create a new DataQuery.
* @param $dataClass The name of the DataObject class that you wish to query
*
* @param String The name of the DataObject class that you wish to query
*/
function __construct($dataClass) {
$this->dataClass = $dataClass;
@ -172,49 +190,50 @@ class DataQuery {
$baseClass = array_shift($tableClasses);
if($query->orderby) {
$orderByFields = explode(',', $query->orderby);
foreach($orderByFields as $ob => $col) {
$col = trim($col);
$orderby = $query->getOrderBy();
// don't touch functions in the ORDER BY or function calls selected as fields
if(strpos($col, '(') !== false || preg_match('/_SortColumn/', $col)) continue;
$columnParts = explode(' ', $col);
if (count($columnParts) == 2) {
$col = $columnParts[0];
$dir = $columnParts[1];
} else {
$dir = 'ASC';
}
$orderByFields[$ob] = $col . ' ' . $dir;
$col = str_replace('"', '', $col);
foreach($orderby as $k => $dir) {
// don't touch functions in the ORDER BY or function calls
// selected as fields
if(strpos($k, '(') !== false || preg_match('/_SortColumn/', $k))
continue;
$col = str_replace('"', '', trim($k));
$parts = explode('.', $col);
if(count($parts) == 1) {
$databaseFields = DataObject::database_fields($baseClass);
// database_fields() doesn't return ID, so we need to manually add it here
// database_fields() doesn't return ID, so we need to
// manually add it here
$databaseFields['ID'] = true;
if(isset($databaseFields[$parts[0]])) {
$qualCol = "\"$baseClass\".\"{$parts[0]}\"";
$orderByFields[$ob] = trim($qualCol . " " . $dir);
// remove original sort
unset($orderby[$k]);
// add new columns sort
$orderby[$qualCol] = $dir;
} else {
$qualCol = "\"$parts[0]\"";
}
if(!isset($query->select[$parts[0]]) && !in_array($qualCol, $query->select)) {
if(!isset($query->select[$col]) && !in_array($qualCol, $query->select)) {
$query->select[] = $qualCol;
}
} else {
$qualCol = '"' . implode('"."', $parts) . '"';
if(!in_array($qualCol, $query->select)) {
$query->select[] = $qualCol;
}
}
}
$query->orderby = implode(',', $orderByFields);
$query->orderby = $orderby;
}
}
@ -357,17 +376,28 @@ class DataQuery {
/**
* Set the ORDER BY clause of this query
*
* @see SQLQuery::orderby()
*
* @return DataQuery
*/
function sort($sort) {
if($sort) {
$clone = $this;
// Add quoting to sort expression if it's a simple column name
if(!is_array($sort) && preg_match('/^[A-Z][A-Z0-9_]*$/i', $sort)) $sort = "\"$sort\"";
$clone->query->orderby($sort);
return $clone;
} else {
return $this;
}
function sort($sort = null, $direction = null, $clear = true) {
$clone = $this;
$clone->query->orderby($sort, $direction, $clear);
return $clone;
}
/**
* Reverse order by clause
*
* @return DataQuery
*/
function reverseSort() {
$clone = $this;
$clone->query->reverseOrderBy();
return $clone;
}
/**

View File

@ -725,16 +725,17 @@ abstract class SS_Database {
*/
public function sqlQueryToString(SQLQuery $sqlQuery) {
$distinct = $sqlQuery->distinct ? "DISTINCT " : "";
if($sqlQuery->delete) {
$text = "DELETE ";
} else if($sqlQuery->select) {
$text = "SELECT $distinct" . implode(", ", $sqlQuery->select);
}
if($sqlQuery->from) $text .= " FROM " . implode(" ", $sqlQuery->from);
if($sqlQuery->where) $text .= " WHERE (" . $sqlQuery->getFilter(). ")";
if($sqlQuery->groupby) $text .= " GROUP BY " . implode(", ", $sqlQuery->groupby);
if($sqlQuery->having) $text .= " HAVING ( " . implode(" ) AND ( ", $sqlQuery->having) . " )";
if($sqlQuery->orderby) $text .= " ORDER BY " . $sqlQuery->orderby;
if($sqlQuery->where) $text .= " WHERE (" . $sqlQuery->prepareSelect(). ")";
if($sqlQuery->groupby) $text .= " GROUP BY " . $sqlQuery->prepareGroupBy();
if($sqlQuery->having) $text .= " HAVING ( " .$sqlQuery->prepareHaving() . " )";
if($sqlQuery->orderby) $text .= " ORDER BY " . $sqlQuery->prepareOrderBy();
if($sqlQuery->limit) {
$limit = $sqlQuery->limit;

View File

@ -77,5 +77,4 @@ interface SS_List extends ArrayAccess, Countable, IteratorAggregate {
* @return array
*/
public function column($colName = "ID");
}

View File

@ -9,6 +9,9 @@
*/
abstract class SS_ListDecorator extends ViewableData implements SS_List, SS_Sortable, SS_Filterable, SS_Limitable {
/**
* @var SS_List
*/
protected $list;
public function __construct(SS_List $list) {
@ -105,6 +108,10 @@ abstract class SS_ListDecorator extends ViewableData implements SS_List, SS_Sort
return $this->list->canSortBy($by);
}
public function reverse() {
return $this->list->reverse();
}
/**
* Sorts this list by one or more fields. You can either pass in a single
* field name and direction, or a map of field names to sort directions.

View File

@ -14,42 +14,50 @@ class SQLQuery {
/**
* An array of fields to select.
*
* @var array
*/
public $select = array();
/**
* An array of join clauses. The first one is just the table name.
*
* @var array
*/
public $from = array();
/**
* An array of filters.
*
* @var array
*/
public $where = array();
/**
* An ORDER BY clause.
* An array of order by clauses, functions. Stores as an associative
* array of column / function to direction.
*
* @var string
*/
public $orderby;
public $orderby = array();
/**
* An array of fields to group by.
*
* @var array
*/
public $groupby = array();
/**
* An array of having clauses.
*
* @var array
*/
public $having = array();
/**
* A limit clause.
*
* @var string
*/
public $limit;
@ -62,12 +70,14 @@ class SQLQuery {
/**
* If this is true, this statement will delete rather than select.
*
* @var boolean
*/
public $delete = false;
/**
* The logical connective used to join WHERE clauses. Defaults to AND.
*
* @var string
*/
public $connective = 'AND';
@ -129,28 +139,34 @@ class SQLQuery {
/**
* Add addition columns to the select clause
*
* @param array|string
*/
public function selectMore($fields) {
if (func_num_args() > 1) $fields = func_get_args();
public function selectMore($fields) {
if(func_num_args() > 1) $fields = func_get_args();
if(is_array($fields)) {
foreach($fields as $field) $this->select[] = $field;
} else {
$this->select[] = $fields;
}
}
/**
* Return the SQL expression for the given field
* @todo This should be refactored after $this->select is changed to make that easier
*/
public function expressionForField($field) {
foreach($this->select as $sel) {
if(preg_match('/AS +"?([^"]*)"?/i', $sel, $matches)) $selField = $matches[1];
else if(preg_match('/"([^"]*)"\."([^"]*)"/', $sel, $matches)) $selField = $matches[2];
else if(preg_match('/"?([^"]*)"?/', $sel, $matches)) $selField = $matches[2];
if($selField == $field) return $sel;
foreach($fields as $field) {
$this->select[] = $field;
}
} else {
$this->select[] = $fields;
}
}
}
/**
* Return the SQL expression for the given field
*
* @todo This should be refactored after $this->select is changed to make that easier
*/
public function expressionForField($field) {
foreach($this->select as $sel) {
if(preg_match('/AS +"?([^"]*)"?/i', $sel, $matches)) $selField = $matches[1];
else if(preg_match('/"([^"]*)"\."([^"]*)"/', $sel, $matches)) $selField = $matches[2];
else if(preg_match('/"?([^"]*)"?/', $sel, $matches)) $selField = $matches[2];
if($selField == $field) return $sel;
}
}
/**
* Specify the target table to select from.
@ -206,16 +222,16 @@ class SQLQuery {
* Add an additional filter (part of the ON clause) on a join
*/
public function addFilterToJoin($tableAlias, $filter) {
$this->from[$tableAlias]['filter'][] = $filter;
}
$this->from[$tableAlias]['filter'][] = $filter;
}
/**
* Replace the existing filter (ON clause) on a join
*/
public function setJoinFilter($tableAlias, $filter) {
if(is_string($this->from[$tableAlias])) {Debug::message($tableAlias); Debug::dump($this->from);}
$this->from[$tableAlias]['filter'] = array($filter);
}
if(is_string($this->from[$tableAlias])) {Debug::message($tableAlias); Debug::dump($this->from);}
$this->from[$tableAlias]['filter'] = array($filter);
}
/**
* Returns true if we are already joining to the given table alias
@ -229,8 +245,9 @@ class SQLQuery {
*/
public function queriedTables() {
$tables = array();
foreach($this->from as $key => $tableClause) {
if(is_array($tableClause)) $table = '"'.$tableClause['table'].'"';
if(is_array($tableClause)) $table = '"'.$tableClause['table'].'"';
else if(is_string($tableClause) && preg_match('/JOIN +("[^"]+") +(AS|ON) +/i', $tableClause, $matches)) $table = $matches[1];
else $table = $tableClause;
@ -239,11 +256,9 @@ class SQLQuery {
$tables[] = preg_replace('/^"|"$/','',$table);
}
return $tables;
return $tables;
}
/**
* Pass LIMIT clause either as SQL snippet or in array format.
@ -276,63 +291,137 @@ class SQLQuery {
/**
* Pass ORDER BY clause either as SQL snippet or in array format.
*
* @todo Implement passing of multiple orderby pairs in nested array syntax,
* e.g. array(array('sort'=>'A','dir'=>'asc'),array('sort'=>'B'))
*
* @example $sql->orderby("Column");
* @example $sql->orderby("Column DESC");
* @example $sql->orderby("Column DESC, ColumnTwo ASC");
* @example $sql->orderby("Column", "DESC");
* @example $sql->orderby(array("Column" => "ASC", "ColumnTwo" => "DESC"));
*
* @param string|array $orderby
* @return SQLQuery This instance
* @param string $dir
* @param bool $clear remove existing order by clauses
*
* @return SQLQuery
*/
public function orderby($orderby) {
// if passed as an array, assume two array values with column and direction (asc|desc)
if(is_array($orderby)) {
if(!array_key_exists('sort', $orderby)) user_error('SQLQuery::orderby(): Wrong format for $orderby array', E_USER_ERROR);
public function orderby($clauses = null, $direction = null, $clear = true) {
if($clear) $this->orderby = array();
if(isset($orderby['sort']) && !empty($orderby['sort']) && isset($orderby['dir']) && !empty($orderby['dir'])) {
$combinedOrderby = "\"" . Convert::raw2sql($orderby['sort']) . "\" " . Convert::raw2sql(strtoupper($orderby['dir']));
} elseif(isset($orderby['sort']) && !empty($orderby['sort'])) {
$combinedOrderby = "\"" . Convert::raw2sql($orderby['sort']) . "\"";
} else {
$combinedOrderby = false;
}
} else {
$combinedOrderby = $orderby;
if(!$clauses) {
return $this;
}
// If sort contains a function call, let's move the sort clause into a separate selected field.
// Some versions of MySQL choke if you have a group function referenced directly in the ORDER BY
if($combinedOrderby && strpos($combinedOrderby,'(') !== false) {
// Sort can be "Col1 DESC|ASC, Col2 DESC|ASC", we need to handle that
$sortParts = explode(",", $combinedOrderby);
// If you have select if(X,A,B),C then the array will return 'if(X','A','B)','C'.
// Turn this into 'if(X,A,B)','C' by counting brackets
while(list($i,$sortPart) = each($sortParts)) {
while(substr_count($sortPart,'(') > substr_count($sortPart,')')) {
list($i,$nextSortPart) = each($sortParts);
if($i === null) break;
$sortPart .= ',' . $nextSortPart;
}
$lumpedSortParts[] = $sortPart;
if(is_string($clauses)) {
if(strpos($clauses, "(") !== false) {
$sort = preg_split("/,(?![^()]*+\\))/", $clauses);
}
foreach($lumpedSortParts as $i => $sortPart) {
$sortPart = trim($sortPart);
if(substr(strtolower($sortPart),-5) == ' desc') {
$this->select[] = substr($sortPart,0,-5) . " AS \"_SortColumn{$i}\"";
$newSorts[] = "\"_SortColumn{$i}\" DESC";
} else if(substr(strtolower($sortPart),-4) == ' asc') {
$this->select[] = substr($sortPart,0,-4) . " AS \"_SortColumn{$i}\"";
$newSorts[] = "\"_SortColumn{$i}\" ASC";
} else {
$this->select[] = "$sortPart AS \"_SortColumn{$i}\"";
$newSorts[] = "\"_SortColumn{$i}\" ASC";
}
else {
$sort = explode(",", $clauses);
}
$clauses = array();
foreach($sort as $clause) {
$clause = explode(" ", trim($clause));
$dir = (isset($clause[1])) ? $clause[1] : $direction;
$clauses[$clause[0]] = $dir;
}
$combinedOrderby = implode(", ", $newSorts);
}
if(!empty($combinedOrderby)) $this->orderby = $combinedOrderby;
if(is_array($clauses)) {
foreach($clauses as $key => $value) {
if(!is_numeric($key)) {
$column = trim($key);
$direction = strtoupper(trim($value));
}
else {
$clause = explode(" ", trim($value));
$column = trim($clause[0]);
$direction = (isset($clause[1])) ? strtoupper(trim($clause[1])) : "";
}
$this->orderby[$column] = $direction;
}
}
else {
user_error('SQLQuery::orderby() incorrect format for $orderby', E_USER_WARNING);
}
// If sort contains a function call, let's move the sort clause into a
// separate selected field.
//
// Some versions of MySQL choke if you have a group function referenced
// directly in the ORDER BY
if($this->orderby) {
$i = 0;
foreach($this->orderby as $clause => $dir) {
if(strpos($clause, '(') !== false) {
// remove the old orderby
unset($this->orderby[$clause]);
$clause = trim($clause);
$column = "_SortColumn{$i}";
$this->select(sprintf("%s AS \"%s\"", $clause, $column));
$this->orderby($column, $dir, false);
$i++;
}
}
}
return $this;
}
/**
* Returns the current order by as array if not already. To handle legacy
* statements which are stored as strings. Without clauses and directions,
* convert the orderby clause to something readable.
*
* @todo When $orderby is a private variable and all orderby statements
* set through
*
* @return array
*/
public function getOrderBy() {
$orderby = $this->orderby;
if(!is_array($orderby)) {
// spilt by any commas not within brackets
$orderby = preg_split("/,(?![^()]*+\\))/", $orderby);
}
foreach($orderby as $k => $v) {
if(strpos($v, " ") !== false) {
unset($orderby[$k]);
$rule = explode(" ", trim($v));
$clause = $rule[0];
$dir = (isset($rule[1])) ? $rule[1] : "ASC";
$orderby[$clause] = $dir;
}
}
return $orderby;
}
/**
* Reverses the order by clause by replacing ASC or DESC references in the
* current order by with it's corollary.
*
* @return SQLQuery
*/
public function reverseOrderBy() {
$order = $this->getOrderBy();
$this->orderby = array();
foreach($order as $clause => $dir) {
$dir = (strtoupper($dir) == "DESC") ? "ASC" : "DESC";
$this->orderby($clause, $dir, false);
}
return $this;
}
@ -454,39 +543,76 @@ class SQLQuery {
*
* @return string
*/
function getFilter() {
public function prepareSelect() {
return ($this->where) ? implode(") {$this->connective} (" , $this->where) : '';
}
/**
* Returns the ORDER BY columns ready for inserting into a query
*
* @return string
*/
public function prepareOrderBy() {
$statments = array();
if($order = $this->getOrderBy()) {
foreach($order as $clause => $dir) {
$statements[] = trim($clause . ' '. $dir);
}
}
return implode(", ", $statements);
}
/**
* Returns the GROUP by columns ready for inserting into a query.
*
* @return string
*/
public function prepareGroupBy() {
return implode(", ", $this->groupby);
}
/**
* Returns the HAVING columns ready for inserting into a query.
*
* @return string
*/
public function prepareHaving() {
return implode(" ) AND ( ", $sqlQuery->having);
}
/**
* Generate the SQL statement for this query.
*
* @return string
*/
function sql() {
// TODO: Don't require this internal-state manipulate-and-preserve - let sqlQueryToString() handle the new syntax
$origFrom = $this->from;
// TODO: Don't require this internal-state manipulate-and-preserve - let sqlQueryToString() handle the new syntax
$origFrom = $this->from;
// Build from clauses
foreach($this->from as $alias => $join) {
// $join can be something like this array structure
// array('type' => 'inner', 'table' => 'SiteTree', 'filter' => array("SiteTree.ID = 1", "Status = 'approved'"))
if(is_array($join)) {
if(is_string($join['filter'])) $filter = $join['filter'];
else if(sizeof($join['filter']) == 1) $filter = $join['filter'][0];
else $filter = "(" . implode(") AND (", $join['filter']) . ")";
// Build from clauses
foreach($this->from as $alias => $join) {
// $join can be something like this array structure
// array('type' => 'inner', 'table' => 'SiteTree', 'filter' => array("SiteTree.ID = 1", "Status = 'approved'"))
if(is_array($join)) {
if(is_string($join['filter'])) $filter = $join['filter'];
else if(sizeof($join['filter']) == 1) $filter = $join['filter'][0];
else $filter = "(" . implode(") AND (", $join['filter']) . ")";
$aliasClause = ($alias != $join['table']) ? " AS \"$alias\"" : "";
$this->from[$alias] = strtoupper($join['type']) . " JOIN \"{$join['table']}\"$aliasClause ON $filter";
}
}
$this->from[$alias] = strtoupper($join['type']) . " JOIN \"{$join['table']}\"$aliasClause ON $filter";
}
}
$sql = DB::getConn()->sqlQueryToString($this);
if($this->replacementsOld) {
$sql = str_replace($this->replacementsOld, $this->replacementsNew, $sql);
}
$this->from = $origFrom;
$this->from = $origFrom;
// The query was most likely just created and then exectued.
if($sql === 'SELECT *') {

View File

@ -26,4 +26,13 @@ interface SS_Sortable {
*/
public function sort();
/**
* Reverses the list based on reversing the current sort.
*
* @example $list->reverse();
*
* @return array
*/
public function reverse();
}

View File

@ -257,6 +257,23 @@ class ArrayListTest extends SapphireTest {
(object) array('Name' => 'Bob')
));
}
public function testReverse() {
$list = new ArrayList(array(
array('Name' => 'John'),
array('Name' => 'Bob'),
array('Name' => 'Steve')
));
$list->sort('Name', 'ASC');
$list->reverse();
$this->assertEquals($list->toArray(), array(
array('Name' => 'Steve'),
array('Name' => 'John'),
array('Name' => 'Bob')
));
}
public function testSimpleMultiSort() {
$list = new ArrayList(array(

View File

@ -506,4 +506,13 @@ class DataListTest extends SapphireTest {
$this->assertEquals($this->idFromFixture('DataObjectTest_Team', 'team2'), $list->first()->TeamID, 'First comment should be for Team 2');
$this->assertEquals($this->idFromFixture('DataObjectTest_Team', 'team1'), $list->last()->TeamID, 'Last comment should be for Team 1');
}
public function testReverse() {
$list = DataList::create("DataObjectTest_TeamComment");
$list->sort('Name');
$list->reverse();
$this->assertEquals('Bob', $list->last()->Name, 'Last comment should be from Bob');
$this->assertEquals('Phil', $list->first()->Name, 'First comment should be from Phil');
}
}

View File

@ -99,30 +99,84 @@ class SQLQueryTest extends SapphireTest {
}
function testSelectWithOrderbyClause() {
// numeric limit
$query = new SQLQuery();
$query->from[] = "MyTable";
$query->orderby('MyName ASC');
// can't escape as we don't know if ASC or DESC is appended
$this->assertEquals("SELECT * FROM MyTable ORDER BY MyName ASC", $query->sql());
$query->orderby('MyName');
$this->assertEquals('SELECT * FROM MyTable ORDER BY MyName', $query->sql());
// array limit
$query = new SQLQuery();
$query->from[] = "MyTable";
$query->orderby(array('sort'=>'MyName'));
$this->assertEquals('SELECT * FROM MyTable ORDER BY "MyName"', $query->sql());
$query->orderby('MyName desc');
$this->assertEquals('SELECT * FROM MyTable ORDER BY MyName DESC', $query->sql());
$query = new SQLQuery();
$query->from[] = "MyTable";
$query->orderby('MyName ASC, Color DESC');
$this->assertEquals('SELECT * FROM MyTable ORDER BY MyName ASC, Color DESC', $query->sql());
$query = new SQLQuery();
$query->from[] = "MyTable";
$query->orderby('MyName ASC, Color');
$this->assertEquals('SELECT * FROM MyTable ORDER BY MyName ASC, Color', $query->sql());
// array limit with start (MySQL specific)
$query = new SQLQuery();
$query->from[] = "MyTable";
$query->orderby(array('sort'=>'MyName','dir'=>'desc'));
$this->assertEquals('SELECT * FROM MyTable ORDER BY "MyName" DESC', $query->sql());
$query->orderby(array('MyName' => 'desc'));
$this->assertEquals('SELECT * FROM MyTable ORDER BY MyName DESC', $query->sql());
$query = new SQLQuery();
$query->from[] = "MyTable";
$query->orderby(array('MyName' => 'desc', 'Color'));
$this->assertEquals('SELECT * FROM MyTable ORDER BY MyName DESC, Color', $query->sql());
$query = new SQLQuery();
$query->from[] = "MyTable";
$query->orderby('implode("MyName","Color")');
$this->assertEquals('SELECT implode("MyName","Color") AS "_SortColumn0" FROM MyTable ORDER BY _SortColumn0', $query->sql());
$query = new SQLQuery();
$query->from[] = "MyTable";
$query->orderby('implode("MyName","Color") DESC');
$this->assertEquals('SELECT implode("MyName","Color") AS "_SortColumn0" FROM MyTable ORDER BY _SortColumn0 DESC', $query->sql());
$query = new SQLQuery();
$query->from[] = "MyTable";
$query->orderby('RAND()');
$this->assertEquals('SELECT RAND() AS "_SortColumn0" FROM MyTable ORDER BY _SortColumn0', $query->sql());
}
function testSelectWithComplexOrderbyClause() {
// @todo Test "ORDER BY RANDOM() ASC,MyName DESC" etc.
public function testReverseOrderBy() {
$query = new SQLQuery();
$query->from('MyTable');
// default is ASC
$query->orderby("Name");
$query->reverseOrderBy();
$this->assertEquals('SELECT * FROM MyTable ORDER BY Name DESC',$query->sql());
$query->orderby("Name DESC");
$query->reverseOrderBy();
$this->assertEquals('SELECT * FROM MyTable ORDER BY Name ASC',$query->sql());
$query->orderby(array("Name" => "ASC"));
$query->reverseOrderBy();
$this->assertEquals('SELECT * FROM MyTable ORDER BY Name DESC',$query->sql());
$query->orderby(array("Name" => 'DESC', 'Color' => 'asc'));
$query->reverseOrderBy();
$this->assertEquals('SELECT * FROM MyTable ORDER BY Name ASC, Color DESC',$query->sql());
$query->orderby('implode("MyName","Color") DESC');
$query->reverseOrderBy();
$this->assertEquals('SELECT implode("MyName","Color") AS "_SortColumn0" FROM MyTable ORDER BY _SortColumn0 ASC',$query->sql());
}
function testFiltersOnID() {
$query = new SQLQuery();
$query->where[] = "ID = 5";