private $onDuplicates = [];
private $selects = [];
private $from;
+ private $setOps;
private $joins = [];
private $wheres = [];
private $groupBys = [];
return new self($from, $options);
}
+ /**
+ * Create a new SELECT-like query where.
+ *
+ * @param array $options
+ * @return CRM_Utils_SQL_Select
+ */
+ public static function fromSet($options = []) {
+ $result = new self(NULL, $options);
+ $result->setOps = [];
+ return $result;
+ }
+
/**
* Create a partial SELECT query.
*
return $this;
}
+ /**
+ * Add a union to the list of set operations.
+ *
+ * Ex: CRM_Utils_SQL_Select::fromSet()->union([$subQuery1, $subQuery2])
+ * Ex: CRM_Utils_SQL_Select::fromSet()->union($subQuery1)->union($subQuery2);
+ *
+ * @param string|array|\CRM_Utils_SQL_Select $subQueries
+ * @return $this
+ */
+ public function union($subQueries) {
+ return $this->setOp('UNION', $subQueries);
+ }
+
+ /**
+ * Add a set operation.
+ *
+ * Ex: CRM_Utils_SQL_Select::fromSet()->setOp('INTERSECT', [$subQuery1, $subQuery2])
+ *
+ * @param string $setOperation
+ * Ex: 'UNION', 'UNION ALL', 'INTERSECT', 'EXCEPT'
+ * NOTE: The query-builder supports any set-operation. However, MySQL 5.7 only supports UNION.
+ * @param string|array|\CRM_Utils_SQL_Select $subQueries
+ * @return $this
+ * @see https://dev.mysql.com/doc/refman/8.0/en/set-operations.html
+ */
+ public function setOp(string $setOperation, $subQueries) {
+ if ($this->from !== NULL || !is_array($this->setOps)) {
+ throw new CRM_Core_Exception("Set-operation ($setOperation) must have a list of subqueries. Primitive FROM is not supported.");
+ }
+ $subQueries = is_array($subQueries) ? $subQueries : [$subQueries]; /* Simple (array)cast would mishandle objects. */
+ foreach ($subQueries as $subQuery) {
+ if ($this->setOps === []) {
+ $this->setOps[] = ['', $subQuery];
+ }
+ else {
+ $this->setOps[] = [" $setOperation ", $subQuery];
+ }
+ }
+ return $this;
+ }
+
/**
* Insert the results of the SELECT query into another
* table.
if ($this->from !== NULL) {
$sql .= 'FROM ' . $this->from . "\n";
}
+ elseif (is_array($this->setOps)) {
+ $sql .= 'FROM (';
+ foreach ($this->setOps as $setOp) {
+ $sql .= $setOp[0];
+ $sql .= '(' . (is_object($setOp[1]) ? $setOp[1]->toSQL() : $setOp[1]) . ')';
+ }
+ $sql .= ")\n";
+ }
foreach ($this->joins as $join) {
$sql .= $join . "\n";
}
$this->assertLike('SELECT c, d, a, b, e FROM foo WHERE (c = "4") AND (a = 2) AND (whipit())', $query->toSQL());
}
+ public function testUnion() {
+ $a = CRM_Utils_SQL_Select::from('a')->select('a_name')->where('a1 = !num')->param('num', 100);
+ $b = CRM_Utils_SQL_Select::from('b')->select('b_name')->where('b2 = @val')->param('val', "ab cd");
+ $u = CRM_Utils_SQL_Select::fromSet()->union([$a, $b])->limit(100)->orderBy('a_name');
+ $expectA = 'SELECT a_name FROM a WHERE (a1 = 100) ';
+ $expectB = 'SELECT b_name FROM b WHERE (b2 = "ab cd") ';
+ $expectUnion = "SELECT * FROM (($expectA) UNION ($expectB)) ORDER BY a_name LIMIT 100 OFFSET 0";
+ $this->assertLike($expectUnion, $u->toSQL());
+ }
+
+ public function testUnionIntersect() {
+ $a = CRM_Utils_SQL_Select::from('a')->select('a_name')->where('a1 = !num')->param('num', 100);
+ $b = CRM_Utils_SQL_Select::from('b')->select('b_name')->where('b2 = @val')->param('val', "bb bb");
+ $c = CRM_Utils_SQL_Select::from('c')->select('c_name')->where('c3 = @val')->param('val', "cc cc");
+ $u = CRM_Utils_SQL_Select::fromSet()
+ ->union([$a, $b])
+ ->setOp('INTERSECT', $c)
+ ->limit(100)
+ ->orderBy('a_name');
+ $expectA = 'SELECT a_name FROM a WHERE (a1 = 100) ';
+ $expectB = 'SELECT b_name FROM b WHERE (b2 = "bb bb") ';
+ $expectC = 'SELECT c_name FROM c WHERE (c3 = "cc cc") ';
+ $expectUnion = "SELECT * FROM (($expectA) UNION ($expectB) INTERSECT ($expectC)) ORDER BY a_name LIMIT 100 OFFSET 0";
+ $this->assertLike($expectUnion, $u->toSQL());
+ }
+
public function testArrayGet() {
$select = CRM_Utils_SQL_Select::from("foo")
->param('hello', 'world');