diff --git a/MysqliDb.php b/MysqliDb.php index f3bc1ca7..e69cd16f 100644 --- a/MysqliDb.php +++ b/MysqliDb.php @@ -64,6 +64,13 @@ class MysqliDb */ protected $_where = array(); + /** + * An array that holds where join ands + * + * @var array + */ + protected $_joinAnd = array(); + /** * An array that holds having conditions * @var array @@ -311,6 +318,7 @@ protected function reset() $this->_where = array(); $this->_having = array(); $this->_join = array(); + $this->_joinAnd = array(); $this->_orderBy = array(); $this->_groupBy = array(); $this->_bindParams = array(''); // Create the empty 0 index @@ -1081,6 +1089,7 @@ private function _buildInsert($tableName, $insertData, $operation) */ protected function _buildQuery($numRows = null, $tableData = null) { + // $this->_buildJoinOld(); $this->_buildJoin(); $this->_buildInsertQuery($tableData); $this->_buildCondition('WHERE', $this->_where); @@ -1229,7 +1238,7 @@ protected function _dynamicBindResults(mysqli_stmt $stmt) * * @return void */ - protected function _buildJoin() + protected function _buildJoinOld() { if (empty($this->_join)) { return; @@ -1906,6 +1915,106 @@ public function paginate ($table, $page, $fields = null) { $this->totalPages = ceil($this->totalCount / $this->pageLimit); return $res; } + + /** + * This method allows you to specify multiple (method chaining optional) AND WHERE statements for the join table on part of the SQL query. + * + * @uses $dbWrapper->joinWhere('user u', 'u.id', 7)->where('user u', 'u.title', 'MyTitle'); + * + * @param string $whereJoin The name of the table followed by its prefix. + * @param string $whereProp The name of the database field. + * @param mixed $whereValue The value of the database field. + * + * @return dbWrapper + */ + public function joinWhere($whereJoin, $whereProp, $whereValue = 'DBNULL', $operator = '=', $cond = 'AND') + { + $this->_joinAnd[$whereJoin][] = Array ($cond, $whereProp, $operator, $whereValue); + return $this; + } + + /** + * This method allows you to specify multiple (method chaining optional) OR WHERE statements for the join table on part of the SQL query. + * + * @uses $dbWrapper->joinWhere('user u', 'u.id', 7)->where('user u', 'u.title', 'MyTitle'); + * + * @param string $whereJoin The name of the table followed by its prefix. + * @param string $whereProp The name of the database field. + * @param mixed $whereValue The value of the database field. + * + * @return dbWrapper + */ + public function joinOrWhere($whereJoin, $whereProp, $whereValue = 'DBNULL', $operator = '=', $cond = 'AND') + { + return $this->joinWhere($whereJoin, $whereProp, $whereValue, $operator, 'OR'); + } + + /** + * Abstraction method that will build an JOIN part of the query + */ + protected function _buildJoin () { + if (empty ($this->_join)) + return; + + foreach ($this->_join as $data) { + list ($joinType, $joinTable, $joinCondition) = $data; + + if (is_object ($joinTable)) + $joinStr = $this->_buildPair ("", $joinTable); + else + $joinStr = $joinTable; + + $this->_query .= " " . $joinType. " JOIN " . $joinStr ." on " . $joinCondition; + + // Add join and query + if (!empty($this->_joinAnd) && isset($this->_joinAnd[$joinStr])) { + foreach($this->_joinAnd[$joinStr] as $join_and_cond) { + list ($concat, $varName, $operator, $val) = $join_and_cond; + $this->_query .= " " . $concat ." " . $varName; + $this->conditionToSql($operator, $val); + } + } + } + } + + /** + * Convert a condition and value into the sql string + * @param String $operator The where constraint operator + * @param String $val The where constraint value + */ + private function conditionToSql($operator, $val) { + switch (strtolower ($operator)) { + case 'not in': + case 'in': + $comparison = ' ' . $operator. ' ('; + if (is_object ($val)) { + $comparison .= $this->_buildPair ("", $val); + } else { + foreach ($val as $v) { + $comparison .= ' ?,'; + $this->_bindParam ($v); + } + } + $this->_query .= rtrim($comparison, ',').' ) '; + break; + case 'not between': + case 'between': + $this->_query .= " $operator ? AND ? "; + $this->_bindParams ($val); + break; + case 'not exists': + case 'exists': + $this->_query.= $operator . $this->_buildPair ("", $val); + break; + default: + if (is_array ($val)) + $this->_bindParams ($val); + else if ($val === null) + $this->_query .= $operator . " NULL"; + else if ($val != 'DBNULL' || $val == '0') + $this->_query .= $this->_buildPair ($operator, $val); + } + } } // END class diff --git a/readme.md b/readme.md index 8cc97059..7e95a368 100644 --- a/readme.md +++ b/readme.md @@ -500,6 +500,24 @@ $products = $db->get ("products p", null, "u.name, p.productName"); print_r ($products); ``` +### Join Conditions +Add AND condition to join statement +```php +$db->join("users u", "p.tenantID=u.tenantID", "LEFT"); +$db->joinWhere("users u", "u.tenantID", 5); +$products = $db->get ("products p", null, "u.name, p.productName"); +print_r ($products); +// Gives: SELECT u.login, p.productName FROM products p LEFT JOIN users u ON (p.tenantID=u.tenantID AND u.tenantID = 5) +``` +Add OR condition to join statement +```php +$db->join("users u", "p.tenantID=u.tenantID", "LEFT"); +$db->joinOrWhere("users u", "u.tenantID", 5); +$products = $db->get ("products p", null, "u.name, p.productName"); +print_r ($products); +// Gives: SELECT u.login, p.productName FROM products p LEFT JOIN users u ON (p.tenantID=u.tenantID OR u.tenantID = 5) +``` + ### Properties sharing Its is also possible to copy properties diff --git a/tests/mysqliDbTests.php b/tests/mysqliDbTests.php index cc993391..58b3fd22 100644 --- a/tests/mysqliDbTests.php +++ b/tests/mysqliDbTests.php @@ -2,6 +2,12 @@ require_once ("../MysqliDb.php"); error_reporting(E_ALL); +function pretty_print($array) { + echo '
';
+  print_r($array);
+  echo '
'; +} + $prefix = 't_'; $db = new Mysqlidb('localhost', 'root', '', 'testdb'); if(!$db) die("Database error"); @@ -322,6 +328,34 @@ function createTable ($name, $data) { exit; } /// +$db->join("users u", "p.userId=u.id", "LEFT"); +$db->joinWhere('t_users u', 'u.id', 'non existant value'); +$products = $db->get ("products p", null, "u.login, p.productName"); +if ($db->count != 5) { + echo 'Invalid product count on joinWhere'; + exit; +} +foreach($products as $product) { + if ($product['login']) { + echo 'Invalid login result on joinWhere'; + exit; + } +} +/// +$db->join("users u", "p.userId=u.id", "LEFT"); +$db->joinOrWhere('t_users u', 'u.id', 'non existant value'); +$products = $db->get ("products p", null, "u.login, p.productName"); +if ($db->count != 5) { + echo 'Invalid product count on joinOrWhere'; + exit; +} +foreach($products as $product) { + if (!$product['login']) { + echo 'Invalid login result on joinWhere'; + exit; + } +} +/// $db->where("id = ? or id = ?", Array(1,2)); $res = $db->get ("users"); if ($db->count != 2) { @@ -422,7 +456,10 @@ function createTable ($name, $data) { //print_r($db->rawQuery("CALL simpleproc(?)",Array("test"))); -print_r ($db->trace); +echo '
';
+pretty_print($db->trace);
+echo '
'; echo "All done\n"; echo "Memory usage: ".memory_get_peak_usage()."\n"; + ?>