├── .gitignore ├── CHANGELOG.md ├── DB.php ├── MySQL.php ├── Oracle.php ├── PostgreSQL.php ├── Query.php ├── README.md ├── SQL.php ├── SQLServer.php ├── SQLite.php ├── codeception.yml ├── composer.json └── tests ├── _data └── .gitkeep ├── _output └── .gitignore ├── _support ├── AcceptanceTester.php ├── FunctionalTester.php ├── Helper │ ├── Acceptance.php │ ├── Functional.php │ └── Unit.php ├── UnitTester.php └── _generated │ └── .gitignore ├── acceptance.suite.yml ├── functional.suite.yml ├── unit.suite.yml └── unit └── koolreport └── querybuilder └── QueryTest.php /.gitignore: -------------------------------------------------------------------------------- 1 | # Build and Release Folders 2 | vendor 3 | 4 | # Other files and folders 5 | *.zip 6 | 7 | # Executables 8 | *.exe 9 | 10 | # Project files, i.e. `.project`, `.actionScriptProperties` and `.flexProperties` 11 | # should NOT be excluded as they contain compiler settings and other important 12 | # information for Eclipse / Flash Builder. 13 | -------------------------------------------------------------------------------- /CHANGELOG.md: -------------------------------------------------------------------------------- 1 | # Change Log 2 | 3 | ## Version 3.5.0 4 | 1. Added: Support SQLite 5 | 6 | ## Version 3.4.1 7 | 1. Fixed: SQL Server syntax for fetch rows 8 | 9 | ## Version 3.4.0 10 | 1. Added: new line before keyword sql output mode 11 | 12 | ## Version 3.3.0 13 | 14 | 1. Added: Ability to return new query of anonymous alias function in from() method 15 | 16 | ## Version 3.2.0 17 | 18 | 1. Added: Ability to query from table alias 19 | 20 | ## Version 3.1.0 21 | 22 | 1. Fixed: Small bug in generating delete query 23 | 24 | ## Version 3.0.0 25 | 26 | 1. Add whereOpenBracket(), whereCloseBracket() methods 27 | 2. Add option to build named and question mark parameter query and its parameter values to improve security 28 | 3. Add schemas to Query to check select validity 29 | 4. Add ability to call procedure with parameters 30 | 5. Add procedure call 31 | 6. Add Oracle syntax support 32 | 33 | ## Version 2.5.3 34 | 35 | 1. Fix the `toArray()` method 36 | 2. Fix issue with `where()` method 37 | 38 | ## Version 2.5.1 39 | 40 | 1. Fix Query's rebuildSubQueries() method and make its toArray() recursive. 41 | 42 | 43 | ## Version 2.5.0 44 | 45 | 1. Enhance the `selectRaw()`, `whereRaw()` and `orderByRaw()` 46 | 47 | ## Version 2.0.0 48 | 49 | 1. `Query`: Fix the selectRaw rendering 50 | 2. `Query`: Adding parameters to `whereRaw()`, `havingRaw()`, `orderByRaw()` methods 51 | 3. `SQL`: Add options to set quotes for identifiers 52 | 4. `SQL`: Make default not use quotes for identifiers 53 | 5. `SQLServer`: Generate correct query for limit and offset 54 | 6. `Query`: Add `groupByRaw()` method 55 | 7. `Query`: Add `create()` static function to create query from array 56 | 8. `Query`: Adding `toArray()` function to export query to array format 57 | 9. `Query`: Add `fill()` method to quickly fill query with array 58 | 10. `Query`: Fix the whereRaw binding params 59 | 60 | ## Version 1.5.0 61 | 62 | 1. Change README 63 | 64 | ## Version 1.4.0 65 | 66 | 1. Fix aggregate 67 | 68 | ## Version 1.3.0 69 | 70 | 1. Fix error of `where` condition when value is boolean type 71 | 2. Fix the cover identifier for [table.column] format 72 | 73 | ## Version 1.2.0 74 | 75 | 1. Change function "as" to "alias", 76 | 2. Change function "switch" to "branch" 77 | 3. Render query correctly for update and insert when encounter boolean value 78 | 4. Fix the PostgresQL interpreter 79 | 80 | 81 | ## Version 1.1.0 82 | 83 | 1. When value of where condition is null, change from "=" to is null 84 | 85 | ## Version 1.0.0 -------------------------------------------------------------------------------- /DB.php: -------------------------------------------------------------------------------- 1 | call($procedureName,$params); 44 | return $query; 45 | } 46 | } -------------------------------------------------------------------------------- /MySQL.php: -------------------------------------------------------------------------------- 1 | query->distinct) { 11 | $sql .= "DISTINCT "; 12 | } 13 | if (count($this->query->columns) > 0) { 14 | $sql .= $this->getSelect($this->query->columns); 15 | } else { 16 | $sql .= "*"; 17 | } 18 | if (count($this->query->tables) > 0) { 19 | $sql .= " FROM " . $this->getFrom($this->query->tables); 20 | } else { 21 | throw new \Exception("No table available in SQL Query"); 22 | } 23 | 24 | if (count($this->query->joins) > 0) { 25 | $sql .= $this->getJoin($this->query->joins); 26 | } 27 | 28 | if (count($this->query->conditions) > 0) { 29 | $where = trim($this->getWhere($this->query->conditions, $options)); 30 | if (!empty($where)) $sql .= " WHERE " . $where; 31 | } 32 | 33 | if (count($this->query->groups) > 0) { 34 | $groupBy = trim($this->getGroupBy($this->query->groups)); 35 | if (!empty($groupBy)) $sql .= " GROUP BY " . $groupBy; 36 | } 37 | 38 | if ($this->query->having) { 39 | $having = trim($this->getHaving($this->query->having, $options)); 40 | if (!empty($having)) $sql .= " HAVING " . $having; 41 | } 42 | 43 | 44 | if (count($this->query->orders) > 0) { 45 | $orderBy = trim($this->getOrderBy($this->query->orders)); 46 | if (!empty($orderBy)) $sql .= " ORDER BY " . $orderBy; 47 | } 48 | 49 | if ($this->query->offset !== null) { 50 | $sql .= " OFFSET ".$this->query->offset." ROWS "; 51 | } 52 | 53 | if ($this->query->limit !== null) { 54 | $sql .= " FETCH NEXT ".$this->query->limit." ROWS ONLY "; 55 | } 56 | 57 | 58 | if (count($this->query->unions) > 0) { 59 | $sql .= $this->getUnions($this->query->unions); 60 | } 61 | if ($this->query->lock) { 62 | $sql .= " " . $this->query->lock; 63 | } 64 | return $sql; 65 | } 66 | 67 | } -------------------------------------------------------------------------------- /PostgreSQL.php: -------------------------------------------------------------------------------- 1 | id = "qb_" . ($this::$instanceId++); 38 | 39 | $this->tables = array(); 40 | $this->columns = array(); 41 | $this->conditions = array(); 42 | $this->orders = array(); 43 | $this->groups = array(); 44 | $this->having = null; 45 | $this->joins = array(); 46 | $this->unions = array(); 47 | $this->values = array(); 48 | $this->procedures = array(); 49 | } 50 | 51 | public function call($procedureName, $params = array()) 52 | { 53 | $this->type = "procedure"; 54 | array_push($this->procedures, array( 55 | $procedureName, 56 | $params 57 | )); 58 | return $this; 59 | } 60 | 61 | public function setSchemas($schemas) 62 | { 63 | $this->schemas = $schemas; 64 | foreach ($this->schemas as $schemaName => $schema) { 65 | if ($schemaName !== "{meta}") $this->currentSchema = $schemaName; 66 | break; 67 | } 68 | // Util::prettyPrint($schemas); 69 | return $this; 70 | } 71 | 72 | public function getSchemas() 73 | { 74 | return $this->schemas; 75 | } 76 | 77 | public function isTableInSchemas($table) 78 | { 79 | if (!isset($this->schemas[$this->currentSchema])) return true; 80 | $schema = $this->schemas[$this->currentSchema]; 81 | $tableInfos = Util::get($schema, 'tables', []); 82 | if (isset($tableInfos[$table])) return true; 83 | return false; 84 | } 85 | 86 | public function isFieldInSchemas($field) 87 | { 88 | // return true; 89 | // echo "function isFieldInSchemas field=$field
"; 90 | // echo "this->tableAliases = "; Util::prettyPrint($this->tableAliases); 91 | if (!isset($this->schemas[$this->currentSchema])) return true; 92 | $schema = $this->schemas[$this->currentSchema]; 93 | $tableInfos = Util::get($schema, 'tables', []); 94 | foreach ($tableInfos as $table => $fieldInfos) { 95 | $tableAliases = Util::get($this->tableAliases, $table, []); 96 | foreach ($fieldInfos as $f => $fieldInfo) { 97 | $exp = Util::get($fieldInfo, "expression", $f); 98 | if ($f === $field|| $exp === $field) return true; 99 | if ($exp === "{meta}") continue; 100 | // echo "exp = $exp
"; 101 | foreach ($tableAliases as $tableAlias => $v) { 102 | if ("$tableAlias.$f" === $field) return true; 103 | $expAlias = str_ireplace($table . ".", $tableAlias . ".", $exp); 104 | // echo "expAlias = $expAlias
"; 105 | if ($expAlias === $field) return true; 106 | } 107 | } 108 | } 109 | return false; 110 | } 111 | 112 | public function addTableAlias($tableName, $tableAlias) 113 | { 114 | // echo "addTableAlias $tableName $tableAlias
"; 115 | Util::init($this->tableAliases, $tableName, []); 116 | $this->tableAliases[$tableName][$tableAlias] = true; 117 | return $this; 118 | } 119 | 120 | public function distinct() 121 | { 122 | $this->distinct = true; 123 | return $this; 124 | } 125 | 126 | public function from() 127 | { 128 | $params = func_get_args(); 129 | if (count($params) > 1) { 130 | foreach ($params as $param) $this->from($param); 131 | } elseif (gettype($params[0]) == "string") { 132 | $tableName = $params[0]; 133 | if ($this->isTableInSchemas($tableName)) array_push($this->tables, $tableName); 134 | } elseif (gettype($params[0]) == "array") { 135 | foreach ($params[0] as $tableAlias => $tableName) { 136 | if (gettype($tableName) == "string") { 137 | if (!$this->isTableInSchemas($tableName)) continue; 138 | if (is_numeric($tableAlias)) { 139 | array_push($this->tables, $tableName); 140 | } elseif (is_string($tableAlias)) { 141 | array_push($this->tables, array($tableName, $tableAlias)); 142 | $this->addTableAlias($tableName, $tableAlias); 143 | } 144 | } elseif (is_callable($tableName)) { 145 | $query = new Query; 146 | //To accept the return of new query object from return of anynomous function 147 | $result = $tableName($query); 148 | if ($result !== null) { 149 | $query = $result; 150 | } 151 | array_push($this->tables, array($query, $tableAlias)); 152 | } 153 | } 154 | } 155 | return $this; 156 | } 157 | 158 | public function select() 159 | { 160 | $params = func_get_args(); 161 | foreach ($params as $columnName) { 162 | if ($this->isFieldInSchemas($columnName)) { 163 | array_push($this->columns, array($columnName)); 164 | } 165 | } 166 | return $this; 167 | } 168 | public function selectRaw($text, $params = array()) 169 | { 170 | array_push($this->columns, array(DB::raw($text, $params))); 171 | return $this; 172 | } 173 | 174 | public function addSelect() 175 | { 176 | call_user_func_array(array($this, "select"), func_get_args()); 177 | return $this; 178 | } 179 | public function addSelectRaw($text, $params = array()) 180 | { 181 | return $this->selectRaw($text, $params); 182 | } 183 | 184 | protected function aggregate($method, $params) 185 | { 186 | foreach ($params as $name) { 187 | array_push($this->columns, array(array($method, $name))); 188 | } 189 | return $this; 190 | } 191 | 192 | public function alias($name) 193 | { 194 | $index = count($this->columns) - 1; 195 | if ($index > -1) { 196 | array_push($this->columns[$index], $name); 197 | } 198 | return $this; 199 | } 200 | 201 | 202 | public function count() 203 | { 204 | $params = func_get_args(); 205 | if (count($params) == 0) { 206 | $params = array("1"); 207 | } 208 | return $this->aggregate("COUNT", $params); 209 | } 210 | 211 | public function count_distinct() 212 | { 213 | return $this->aggregate("COUNT DISTINCT", func_get_args()); 214 | } 215 | 216 | public function sum() 217 | { 218 | return $this->aggregate("SUM", func_get_args()); 219 | } 220 | public function avg() 221 | { 222 | return $this->aggregate("AVG", func_get_args()); 223 | } 224 | public function max() 225 | { 226 | return $this->aggregate("MAX", func_get_args()); 227 | } 228 | public function min() 229 | { 230 | return $this->aggregate("MIN", func_get_args()); 231 | } 232 | 233 | protected function andCondition() 234 | { 235 | // if (count($this->conditions) > 0) { 236 | // array_push($this->conditions, "AND"); 237 | // return $this; 238 | // } 239 | for ($i = count($this->conditions) - 1; $i >= 0; $i--) { 240 | $condition = $this->conditions[$i]; 241 | if ($condition !== "(") break; 242 | } 243 | // echo "before condition = "; 244 | // \koolreport\core\Utility::prettyPrint($this->conditions); 245 | // echo "i=$i
"; 246 | if ($i > -1) array_splice($this->conditions, $i + 1, 0, "AND"); 247 | // echo "after condition = "; 248 | // \koolreport\core\Utility::prettyPrint($this->conditions); 249 | // echo "

"; 250 | return $this; 251 | } 252 | 253 | protected function orCondition() 254 | { 255 | // if (count($this->conditions) > 0) { 256 | // array_push($this->conditions, "OR"); 257 | // return $this; 258 | // } 259 | for ($i = count($this->conditions) - 1; $i >= 0; $i--) { 260 | $condition = $this->conditions[$i]; 261 | if ($condition !== "(") break; 262 | } 263 | // echo "before condition = "; 264 | // \koolreport\core\Utility::prettyPrint($this->conditions); 265 | // echo "i=$i
"; 266 | if ($i > -1) array_splice($this->conditions, $i + 1, 0, "OR"); 267 | // echo "after condition = "; 268 | // \koolreport\core\Utility::prettyPrint($this->conditions); 269 | // echo "

"; 270 | return $this; 271 | } 272 | 273 | public function whereOpenBracket() 274 | { 275 | array_push($this->conditions, "("); 276 | return $this; 277 | } 278 | 279 | public function whereCloseBracket() 280 | { 281 | $lastcondition = end($this->conditions); 282 | if ($lastcondition === "(") { 283 | array_pop($this->conditions); 284 | } else { 285 | array_push($this->conditions, ")"); 286 | } 287 | return $this; 288 | } 289 | 290 | public function havingOpenBracket() 291 | { 292 | $params = func_get_args(); 293 | if (!$this->having) { 294 | $this->having = new Query; 295 | } 296 | call_user_func_array(array($this->having, "whereOpenBracket"), $params); 297 | return $this; 298 | } 299 | 300 | public function havingCloseBracket() 301 | { 302 | $params = func_get_args(); 303 | if (!$this->having) { 304 | $this->having = new Query; 305 | } 306 | call_user_func_array(array($this->having, "whereCloseBracket"), $params); 307 | return $this; 308 | } 309 | 310 | public function isStandardConditionValid($params) 311 | { 312 | $field = $params[0]; 313 | $compareOperator = strtolower(trim($params[1])); 314 | // $value1 = Util::get($params, 2); 315 | // $value2 = Util::get($params, 3); 316 | if (!$this->isFieldInSchemas($field)) return false; 317 | $compareOperators = array_flip([ 318 | "=", "<", "<=", ">=", ">", "!=", "<>", 319 | "is", "is not", "between", "not between", 320 | "in", "not in", "like", "not like" 321 | ]); 322 | if (!isset($compareOperators[$compareOperator])) return false; 323 | return true; 324 | } 325 | 326 | protected function pushStandardCondition($params) 327 | { 328 | if ($params[2] === null && $params[1] === "=") { 329 | $params[1] = "IS"; 330 | } 331 | $field = $params[0]; 332 | if ($this->isFieldInSchemas($field)) { 333 | array_push($this->conditions, $params); 334 | } 335 | } 336 | 337 | 338 | public function where() 339 | { 340 | $params = func_get_args(); 341 | switch (count($params)) { 342 | case 1: 343 | if (gettype($params[0]) == "array") { 344 | $query = new Query; 345 | foreach ($params[0] as $where) { 346 | call_user_func_array(array($query, "where"), $where); 347 | } 348 | $this->andCondition(); 349 | array_push($this->conditions, $query); 350 | } elseif (is_callable($params[0])) { 351 | $query = new Query; 352 | $params[0]($query); 353 | $this->andCondition(); 354 | array_push($this->conditions, $query); 355 | } 356 | break; 357 | case 2: 358 | $this->where($params[0], "=", $params[1]); 359 | break; 360 | case 3: 361 | case 4: 362 | case 5: 363 | if ($this->isStandardConditionValid($params)) { 364 | $this->andCondition(); 365 | $this->pushStandardCondition($params); 366 | } else { 367 | // echo "isStandardConditionValid = false
"; 368 | } 369 | break; 370 | } 371 | return $this; 372 | } 373 | public function orWhere() 374 | { 375 | $params = func_get_args(); 376 | switch (count($params)) { 377 | case 1: 378 | if (gettype($params[0]) == "array") { 379 | $query = new Query; 380 | foreach ($params[0] as $where) { 381 | call_user_func_array(array($query, "where"), $where); 382 | } 383 | $this->orCondition(); 384 | array_push($this->conditions, $query); 385 | } elseif (is_callable($params[0])) { 386 | $query = new Query; 387 | $params[0]($query); 388 | $this->orCondition(); 389 | array_push($this->conditions, $query); 390 | } 391 | break; 392 | case 2: 393 | $this->orWhere($params[0], "=", $params[1]); 394 | break; 395 | case 3: 396 | if ($this->isStandardConditionValid($params)) { 397 | $this->orCondition(); 398 | $this->pushStandardCondition($params); 399 | } 400 | break; 401 | } 402 | return $this; 403 | } 404 | 405 | //Null 406 | public function whereNull($name) 407 | { 408 | return $this->where($name, 'IS', null); 409 | } 410 | public function whereNotNull($name) 411 | { 412 | return $this->where($name, 'IS NOT', null); 413 | } 414 | public function orWhereNull($name) 415 | { 416 | return $this->orWhere($name, 'IS', null); 417 | } 418 | public function orWhereNotNull($name) 419 | { 420 | return $this->orWhere($name, 'IS NOT', null); 421 | } 422 | 423 | //In 424 | public function whereIn($name, $array) 425 | { 426 | return $this->where($name, 'IN', $array); 427 | } 428 | public function whereNotIn($name, $array) 429 | { 430 | return $this->where($name, 'NOT IN', $array); 431 | } 432 | public function orWhereIn($name, $array) 433 | { 434 | return $this->orWhere($name, 'IN', $array); 435 | } 436 | public function orWhereNotIn($name, $array) 437 | { 438 | return $this->orWhere($name, 'NOT IN', $array); 439 | } 440 | 441 | //Between 442 | public function whereBetween($name, $array) 443 | { 444 | return $this->where(array( 445 | array($name, ">=", $array[0]), 446 | array($name, "<=", $array[1]) 447 | )); 448 | } 449 | public function whereNotBetween($name, $array) 450 | { 451 | $this->where(function ($query) use ($name, $array) { 452 | $query->where($name, "<", $array[0]) 453 | ->orWhere($name, ">", $array[1]); 454 | }); 455 | return $this; 456 | } 457 | public function orWhereBetween($name, $array) 458 | { 459 | return $this->orWhere(array( 460 | array($name, ">=", $array[0]), 461 | array($name, "<=", $array[1]) 462 | )); 463 | } 464 | public function orWhereNotBetween($name, $array) 465 | { 466 | $this->orWhere(function ($query) use ($name, $array) { 467 | $query->where($name, "<", $array[0]) 468 | ->orWhere($name, ">", $array[1]); 469 | }); 470 | return $this; 471 | } 472 | 473 | //Datetime 474 | 475 | protected function whereFunction($name, $params) 476 | { 477 | $c = count($params); 478 | if ($c > 0 && !$this->isFieldInSchemas($params[0])) return $this; 479 | if ($c == 1) { 480 | return $this->where("$name($params[0])", "=", date("Y-m-d")); 481 | } elseif ($c == 2) { 482 | return $this->where("$name($params[0])", "=", $params[1]); 483 | } elseif ($c > 2) { 484 | return $this->where("$name($params[0])", $params[1], $params[2]); 485 | } 486 | return $this; 487 | } 488 | protected function orWhereFunction($name, $params) 489 | { 490 | $c = count($params); 491 | if ($c == 1) { 492 | return $this->orWhere("$name($params[0])", "=", date("Y-m-d")); 493 | } elseif ($c == 2) { 494 | return $this->orWhere("$name($params[0])", "=", $params[1]); 495 | } elseif ($c > 2) { 496 | return $this->orWhere("$name($params[0])", $params[1], $params[2]); 497 | } 498 | return $this; 499 | } 500 | 501 | public function whereDate() 502 | { 503 | return $this->whereFunction("DATE", func_get_args()); 504 | } 505 | public function whereDay() 506 | { 507 | return $this->whereFunction("DAY", func_get_args()); 508 | } 509 | public function whereMonth() 510 | { 511 | return $this->whereFunction("MONTH", func_get_args()); 512 | } 513 | public function whereYear() 514 | { 515 | return $this->whereFunction("YEAR", func_get_args()); 516 | } 517 | public function whereTime() 518 | { 519 | return $this->whereFunction("TIME", func_get_args()); 520 | } 521 | public function orWhereDate() 522 | { 523 | return $this->whereFunction("DATE", func_get_args()); 524 | } 525 | public function orWhereDay() 526 | { 527 | return $this->orWhereFunction("DAY", func_get_args()); 528 | } 529 | public function orWhereMonth() 530 | { 531 | return $this->orWhereFunction("MONTH", func_get_args()); 532 | } 533 | public function orWhereYear() 534 | { 535 | return $this->orWhereFunction("YEAR", func_get_args()); 536 | } 537 | public function orWhereTime() 538 | { 539 | return $this->orWhereFunction("TIME", func_get_args()); 540 | } 541 | 542 | //Column 543 | public function whereColumn() 544 | { 545 | $params = func_get_args(); 546 | switch (count($params)) { 547 | case 1: 548 | if (gettype($params[0]) == "array") { 549 | $query = new Query; 550 | foreach ($params[0] as $where) { 551 | call_user_func_array(array($query, "whereColumn"), $where); 552 | } 553 | $this->andCondition(); 554 | array_push($this->conditions, $query); 555 | } 556 | break; 557 | case 2: 558 | if ( 559 | $this->isFieldInSchemas($params[0]) 560 | && $this->isFieldInSchemas($params[1]) 561 | ) { 562 | $this->whereColumn($params[0], "=", $params[1]); 563 | } 564 | break; 565 | case 3: 566 | if ( 567 | $this->isFieldInSchemas($params[0]) 568 | && $this->isFieldInSchemas($params[2]) 569 | ) { 570 | $this->andCondition(); 571 | $params[2] = "[{colName}]" . $params[2]; 572 | array_push($this->conditions, $params); 573 | } 574 | break; 575 | } 576 | return $this; 577 | } 578 | 579 | public function orWhereColumn() 580 | { 581 | $params = func_get_args(); 582 | switch (count($params)) { 583 | case 1: 584 | if (gettype($params[0]) == "array") { 585 | $query = new Query; 586 | foreach ($params[0] as $where) { 587 | call_user_func_array(array($query, "orWhereColumn"), $where); 588 | } 589 | $this->orCondition(); 590 | array_push($this->conditions, $query); 591 | } 592 | break; 593 | case 2: 594 | if ( 595 | $this->isFieldInSchemas($params[0]) 596 | && $this->isFieldInSchemas($params[1]) 597 | ) { 598 | $this->orWhereColumn($params[0], "=", $params[1]); 599 | } 600 | break; 601 | case 3: 602 | if ( 603 | $this->isFieldInSchemas($params[0]) 604 | && $this->isFieldInSchemas($params[2]) 605 | ) { 606 | $this->orCondition(); 607 | $params[2] = "[{colName}]" . $params[2]; 608 | array_push($this->conditions, $params); 609 | } 610 | break; 611 | } 612 | return $this; 613 | } 614 | 615 | 616 | //Exists 617 | public function whereExists($table) 618 | { 619 | if (is_callable($table)) { 620 | $query = new Query; 621 | $table($query); 622 | $this->andCondition(); 623 | array_push($this->conditions, array("[{exists}]", $query)); 624 | } else { 625 | throw new \Exception("whereExists() required function as parameter"); 626 | } 627 | return $this; 628 | } 629 | public function orWhereExists($table) 630 | { 631 | if (is_callable($table)) { 632 | $query = new Query; 633 | $table($query); 634 | $this->orCondition(); 635 | array_push($this->conditions, array("[{exists}]", $query)); 636 | } else { 637 | throw new \Exception("whereExists() required function as parameter"); 638 | } 639 | return $this; 640 | } 641 | 642 | //Raw 643 | public function whereRaw($raw, $params = null) 644 | { 645 | $this->andCondition(); 646 | array_push($this->conditions, DB::raw($raw, $params)); 647 | return $this; 648 | } 649 | public function orWhereRaw($raw, $params = null) 650 | { 651 | $this->orCondition(); 652 | array_push($this->conditions, DB::raw($raw, $params)); 653 | return $this; 654 | } 655 | 656 | 657 | //------------------// 658 | public function orderBy() 659 | { 660 | $params = func_get_args(); 661 | if (count($params) == 1) { 662 | if (gettype($params[0]) == "array") { 663 | foreach ($params[0] as $order) { 664 | call_user_func_array(array($this, "orderBy"), $order); 665 | } 666 | } else { 667 | $field = $params[0]; 668 | if ($this->isFieldInSchemas($field)) { 669 | $this->orderBy($field, 'asc'); 670 | } 671 | } 672 | } elseif (count($params) > 1) { 673 | array_push($this->orders, $params); 674 | } 675 | return $this; 676 | } 677 | 678 | public function orderByRaw($raw, $params = null) 679 | { 680 | array_push($this->orders, DB::raw($raw, $params)); 681 | return $this; 682 | } 683 | 684 | public function latest($name = 'created_at') 685 | { 686 | return $this->orderBy($name, 'desc'); 687 | } 688 | 689 | public function oldest($name = 'created_at') 690 | { 691 | return $this->orderBy($name, 'asc'); 692 | } 693 | 694 | //--------------------// 695 | public function groupBy() 696 | { 697 | $params = func_get_args(); 698 | foreach ($params as $group) { 699 | if ( 700 | !in_array($group, $this->groups) 701 | && $this->isFieldInSchemas($group) 702 | ) { 703 | array_push($this->groups, $group); 704 | } 705 | } 706 | return $this; 707 | } 708 | 709 | public function groupByRaw() 710 | { 711 | $params = func_get_args(); 712 | foreach ($params as $group) { 713 | if (!in_array("[{raw}]" . $group, $this->groups)) { 714 | array_push($this->groups, "[{raw}]" . $group); 715 | } 716 | } 717 | return $this; 718 | } 719 | 720 | public function having() 721 | { 722 | $params = func_get_args(); 723 | 724 | if (!$this->having) { 725 | $this->having = new Query; 726 | } 727 | call_user_func_array(array($this->having, "where"), $params); 728 | return $this; 729 | } 730 | 731 | public function orHaving() 732 | { 733 | $params = func_get_args(); 734 | if (!$this->having) { 735 | $this->having = new Query; 736 | } 737 | 738 | call_user_func_array(array($this->having, "orWhere"), $params); 739 | return $this; 740 | } 741 | 742 | public function havingRaw($raw, $params = null) 743 | { 744 | if (!$this->having) { 745 | $this->having = new Query; 746 | } 747 | $this->having->whereRaw($raw, $params); 748 | return $this; 749 | } 750 | 751 | public function orHavingRaw($raw, $params = null) 752 | { 753 | if (!$this->having) { 754 | $this->having = new Query; 755 | } 756 | $this->having->orWhereRaw($raw, $params); 757 | return $this; 758 | } 759 | 760 | //---------------// 761 | public function skip($number) 762 | { 763 | return $this->offset($number); 764 | } 765 | public function offset($number) 766 | { 767 | if (is_numeric($number)) { 768 | $this->offset = $number; 769 | } 770 | return $this; 771 | } 772 | 773 | public function limit($number) 774 | { 775 | if (is_numeric($number)) { 776 | $this->limit = $number; 777 | } 778 | return $this; 779 | } 780 | 781 | public function take($number) 782 | { 783 | return $this->limit($number); 784 | } 785 | 786 | public function first() 787 | { 788 | $this->limit = 1; 789 | return $this; 790 | } 791 | 792 | //--------------// 793 | public function when($condition, $trueExecution, $falseExecution = null) 794 | { 795 | if ($condition) { 796 | if (is_callable($trueExecution)) { 797 | $trueExecution($this); 798 | } 799 | } else { 800 | if (is_callable($falseExecution)) { 801 | $falseExecution($this); 802 | } 803 | } 804 | return $this; 805 | } 806 | 807 | public function branch($value, $array) 808 | { 809 | if (isset($array[$value]) && is_callable($array[$value])) { 810 | $array[$value]($this); 811 | } 812 | return $this; 813 | } 814 | 815 | //---------------// 816 | protected function allJoin($method, $params) 817 | { 818 | // echo "params = "; var_dump($params); echo "
"; 819 | if (gettype($params[0]) == "string") { 820 | if (!$this->isTableInSchemas($params[0])) return $this; 821 | else $table = $params[0]; 822 | } elseif (gettype($params[0]) == "array") { 823 | foreach ($params[0] as $tableAlias => $tableName) { 824 | if (gettype($tableName) == "string") { 825 | if ($this->isTableInSchemas($tableName)) { 826 | $table = "$tableName $tableAlias"; 827 | $this->addTableAlias($tableName, $tableAlias); 828 | } 829 | } 830 | } 831 | } 832 | // echo "table = $table
"; 833 | $join = array($method, $table); 834 | array_splice($params, 0, 1); 835 | if (count($params) == 1 && is_callable($params[0])) { 836 | $query = new Query; 837 | $params[0]($query); 838 | array_push($join, $query); 839 | } elseif (count($params) > 1) { 840 | $query = new Query; 841 | call_user_func_array(array($query, "on"), $params); 842 | array_push($join, $query); 843 | } 844 | array_push($this->joins, $join); 845 | return $this; 846 | } 847 | public function on() 848 | { 849 | call_user_func_array(array($this, "whereColumn"), func_get_args()); 850 | return $this; 851 | } 852 | public function orOn() 853 | { 854 | call_user_func_array(array($this, "orWhereColumn"), func_get_args()); 855 | return $this; 856 | } 857 | 858 | public function join() 859 | { 860 | return $this->allJoin('JOIN', func_get_args()); 861 | } 862 | public function leftJoin() 863 | { 864 | return $this->allJoin('LEFT JOIN', func_get_args()); 865 | } 866 | public function rightJoin() 867 | { 868 | return $this->allJoin('RIGHT JOIN', func_get_args()); 869 | } 870 | public function crossJoin($tableName) 871 | { 872 | return $this->allJoin('CROSS JOIN', array($tableName)); 873 | } 874 | public function innerJoin() 875 | { 876 | return $this->allJoin('INNER JOIN', func_get_args()); 877 | } 878 | public function outerJoin() 879 | { 880 | return $this->allJoin('OUTER JOIN', func_get_args()); 881 | } 882 | 883 | //-------------------// 884 | public function union($query) 885 | { 886 | array_push($this->unions, $query); 887 | return $this; 888 | } 889 | //-------------------// 890 | public function insert($values) 891 | { 892 | $this->type = "insert"; 893 | $this->values = array_merge($this->values, $values); 894 | return $this; 895 | } 896 | 897 | public function update($values) 898 | { 899 | $this->type = "update"; 900 | $this->values = array_merge($this->values, $values); 901 | return $this; 902 | } 903 | 904 | public function decrement($name, $value = 1) 905 | { 906 | $this->type = "update"; 907 | $this->values[$name] = array($name, "-", $value); 908 | return $this; 909 | } 910 | 911 | public function increment($name, $value = 1) 912 | { 913 | $this->type = "update"; 914 | $this->values[$name] = array($name, "+", $value); 915 | return $this; 916 | } 917 | 918 | public function delete() 919 | { 920 | $this->type = "delete"; 921 | return $this; 922 | } 923 | 924 | public function truncate() 925 | { 926 | $this->type = "delete"; 927 | $this->conditions = array(); 928 | return $this; 929 | } 930 | 931 | public function sharedLock() 932 | { 933 | $this->lock = "LOCK IN SHARE MODE"; 934 | return $this; 935 | } 936 | 937 | public function lockForUpdate() 938 | { 939 | $this->lock = "FOR UPDATE"; 940 | return $this; 941 | } 942 | //------------------// 943 | public function toSQL($options = []) 944 | { 945 | // echo "options = "; 946 | // Util::prettyPrint($options); 947 | if (gettype($options) === 'boolean') $quoteIdentifier = false; 948 | else $quoteIdentifier = Util::get($options, 'quoteIdentifier', false); 949 | $interpreter = new SQL($this, $quoteIdentifier); 950 | return $interpreter->buildQuery($options); 951 | } 952 | public function toOracle($options = []) 953 | { 954 | if (gettype($options) === 'boolean') $quoteIdentifier = false; 955 | else $quoteIdentifier = Util::get($options, 'quoteIdentifier', false); 956 | $interpreter = new Oracle($this, $quoteIdentifier); 957 | return $interpreter->buildQuery($options); 958 | } 959 | 960 | public function toMySQL($options = []) 961 | { 962 | if (gettype($options) === 'boolean') $quoteIdentifier = false; 963 | else $quoteIdentifier = Util::get($options, 'quoteIdentifier', false); 964 | $interpreter = new MySQL($this, $quoteIdentifier); 965 | return $interpreter->buildQuery($options); 966 | } 967 | public function toSQLite($options = []) 968 | { 969 | if (gettype($options) === 'boolean') $quoteIdentifier = false; 970 | else $quoteIdentifier = Util::get($options, 'quoteIdentifier', false); 971 | $interpreter = new SQLite($this, $quoteIdentifier); 972 | return $interpreter->buildQuery($options); 973 | } 974 | 975 | public function toPostgreSQL($options = []) 976 | { 977 | if (gettype($options) === 'boolean') $quoteIdentifier = false; 978 | else $quoteIdentifier = Util::get($options, 'quoteIdentifier', false); 979 | $interpreter = new PostgreSQL($this, $quoteIdentifier); 980 | return $interpreter->buildQuery($options); 981 | } 982 | public function toSQLServer($options = []) 983 | { 984 | if (gettype($options) === 'boolean') $quoteIdentifier = false; 985 | else $quoteIdentifier = Util::get($options, 'quoteIdentifier', false); 986 | $interpreter = new SQLServer($this, $quoteIdentifier); 987 | return $interpreter->buildQuery($options); 988 | } 989 | 990 | public function getSQLParams() 991 | { 992 | return $this->sqlParams; 993 | } 994 | 995 | public function __toString() 996 | { 997 | return $this->toSQL(); 998 | } 999 | 1000 | 1001 | /** 1002 | * Check if there is sub serialized query 1003 | * and convert it to query 1004 | */ 1005 | protected function rebuildSubQueries($arr) 1006 | { 1007 | if (!gettype($arr) == "array") { 1008 | return $arr; 1009 | } 1010 | 1011 | foreach ($arr as $key => $value) { 1012 | if (gettype($value) == "array") { 1013 | 1014 | if ( 1015 | isset($value["type"]) 1016 | && isset($value["tables"]) 1017 | && isset($value["columns"]) 1018 | && isset($value["conditions"]) 1019 | && isset($value["groups"]) 1020 | && isset($value["orders"]) 1021 | ) { 1022 | $class = get_class($this); 1023 | $arr[$key] = $class::create($value); 1024 | } else { 1025 | $arr[$key] = $this->rebuildSubQueries($value); 1026 | } 1027 | } 1028 | } 1029 | return $arr; 1030 | } 1031 | 1032 | public function fill($arr) 1033 | { 1034 | if ($arr !== null) { 1035 | $arr = $this->rebuildSubQueries($arr); 1036 | foreach ($arr as $key => $value) { 1037 | $this->$key = $value; 1038 | } 1039 | } 1040 | } 1041 | 1042 | public static function create($arr) 1043 | { 1044 | $query = new Query; 1045 | $query->fill($arr); 1046 | return $query; 1047 | } 1048 | 1049 | public function toArray($obj = null) 1050 | { 1051 | if (!isset($obj)) $obj = $this; 1052 | $arr = is_object($obj) ? get_object_vars($obj) : $obj; 1053 | foreach ($arr as $key => $val) { 1054 | $recursive = !empty($val) && (is_array($val) || is_object($val)); 1055 | $val = $recursive ? $this->toArray($val) : $val; 1056 | $arr[$key] = $val; 1057 | } 1058 | return $arr; 1059 | } 1060 | } 1061 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Introduction 2 | 3 | `QueryBuilder` helps you to generate SQL Query using pure PHP code. The benefits of using this package are: 4 | 5 | 1. To create faster, better and more precise SQL query without any syntax error. 6 | 2. To overcome to complexity of SQL even if you are expert. 7 | 3. To prevent your data from security risks such as sql injection. 8 | 9 | If you are familiar with `Laravel`, an famous PHP Framework, you will like this package very much because you will not need to learn how to use this package. 10 | 11 | # Installation 12 | 13 | ## By downloading .zip file 14 | 15 | 1. [Download](https://www.koolreport.com/packages/querybuilder) 16 | 2. Unzip the zip file 17 | 3. Copy the folder `querybuilder` into `koolreport` folder so that look like below 18 | 19 | ```bash 20 | koolreport 21 | ├── core 22 | ├── querybuilder 23 | ``` 24 | 25 | ## By composer 26 | 27 | ``` 28 | composer require koolreport/querybuilder 29 | ``` 30 | 31 | # Documentation 32 | 33 | ## Generate compatible SQL query for different database systems 34 | 35 | `QueryBuilder` package support `MySQL`, `PostgreSQL`, `SQLServer` query type. 36 | 37 | #### MySQL Query 38 | 39 | Use may cover your query in `MySQL::type()` function to get SQL in string or use `toMySQL()` of the query. 40 | 41 | ``` 42 | $this->src('mysql_database')->query(MySQL::type( 43 | DB::table('orders') 44 | )) 45 | 46 | $this->src('mysql_database')->query( 47 | DB::table('orders')->toMySQL() 48 | ) 49 | ``` 50 | 51 | #### PostgreSQL Query 52 | 53 | Use may cover your query in `PostgreSQL::type()` function to get SQL in string or use `toPostgreSQL()` of the query. 54 | 55 | ``` 56 | $this->src('mysql_database')->query(PostgreSQL::type( 57 | DB::table('orders') 58 | )) 59 | 60 | $this->src('postgresql_database')->query( 61 | DB::table('orders')->toPostgreSQL() 62 | ) 63 | ``` 64 | 65 | #### SQLServer Query 66 | 67 | Use may cover your query in `SQLServer::type()` function to get SQL in string or use `toSQLServer()` of the query. 68 | 69 | ``` 70 | $this->src('sqlserver_database')->query(SQLServer::type( 71 | DB::table('orders') 72 | )) 73 | 74 | $this->src('sqlserver_database')->query( 75 | DB::table('orders')->toSQLServer() 76 | ) 77 | ``` 78 | 79 | #### Parameterized Query and Parameters (version >= 3.0.0) 80 | 81 | When you build a query builder with data from untrusted source (says, user inputs) it's dangerous to use the query builder's generated query directly because of possible SQL injection attack. In those cases it's advisable to get the query builder's generated parameterized query together with parameters and use them to get data instead: 82 | 83 | ``` 84 | $querybuilder = DB::...; 85 | 86 | $queryWithParams = $querybuilder->toMySQL(["useSQLParams" => "name"]); // or "useSQLParams" => "question mark" 87 | $params = $querybuilder->getSQLParams(); 88 | ``` 89 | 90 | ## Set Schemas 91 | 92 | For security and authentication reasons users could set a query builder's schemas so that only tables and fields from those schemas are included in its generated queries: 93 | 94 | ``` 95 | $querybuilder = DB::...; 96 | 97 | $querybuilder->setSchemas(array( 98 | "salesSchema" => array( 99 | "tables" => array( 100 | "customers"=>array( 101 | "customerNumber"=>array( 102 | "alias"=>"Customer Number", 103 | ), 104 | "customerName"=>array( 105 | "alias"=>"Customer Name", 106 | ), 107 | ), 108 | "orders"=>array( 109 | "orderNumber"=>array( 110 | "alias"=>"Order Number" 111 | ), 112 | "orderDate"=>array( 113 | "alias"=>"Order Date", 114 | "type" => "datetime" 115 | ), 116 | "orderMonth" => [ 117 | "expression" => "month(orderDate)", 118 | ] 119 | ), 120 | ... 121 | ), 122 | ), 123 | ... 124 | )); 125 | ``` 126 | 127 | ## Retrieving Results 128 | 129 | #### Retrieving All Rows From A Table 130 | 131 | You may use the `table` method on the `DB` facade to begin a query. The `table` method returns a fluent query builder instance for the given table, allowing you to chain more constraints onto the query. 132 | 133 | ``` 134 | 135 | use \koolreport\querybuilder\DB; 136 | use \koolreport\querybuilder\MySQL; 137 | 138 | class MyReport extends \koolreport\KoolReport 139 | { 140 | function settings() 141 | { 142 | return array( 143 | "dataSources"=>array( 144 | "automaker"=>array( 145 | "connectionString"=>"mysql:host=localhost;dbname=automaker", 146 | "username"=>"root", 147 | "password"=>"", 148 | "charset"=>"utf8" 149 | ), 150 | ) 151 | ); 152 | } 153 | function setup() 154 | { 155 | $this->src('automaker')->query(MySQL::type( 156 | DB::table("payments") // Equivalent to : "SELECT * FROM payments" 157 | )) 158 | ->pipe($this->dataStore('payments')); 159 | } 160 | } 161 | 162 | ``` 163 | 164 | #### Retrieving A Single Row 165 | 166 | If you just need to retrieve a single row from the database table, you may use the `first` method. 167 | 168 | ``` 169 | DB::table('users')->where('name', 'John')->first() 170 | 171 | // Equivalent: "SELECT * FROM users WHERE `name`='John' LIMIT 1" 172 | ``` 173 | 174 | ## Aggregates 175 | 176 | The query builder also provides a variety of aggregate methods such as `count`, `max`, `min`, `avg`, and `sum`. You may call any of these methods after constructing your query: 177 | 178 | ``` 179 | DB::table('orders')->groupBy('country')->sum('amount') 180 | 181 | DB::table('orders')->count() 182 | 183 | DB::table('customers')->groupBy('state') 184 | ->avg('income')->alias('avgIncome') 185 | ``` 186 | 187 | ## Sub query table 188 | 189 | `QueryBuilder` support creating sub query. Meaning that you can query from a table generated by another query. 190 | 191 | ``` 192 | DB::table([ 193 | 'orders', 194 | 't'=>function($query){ 195 | $query->select('name','age')->from('customers'); 196 | }] 197 | )->... 198 | ``` 199 | 200 | Above will generate: 201 | 202 | ``` 203 | SELECT * 204 | FROM orders, (SELECT name,age FROM customer) t 205 | ``` 206 | 207 | 208 | ## Selects 209 | 210 | #### Specifying A Select Clause 211 | 212 | Of course, you may not always want to select all columns from a database table. Using the `select` method, you can specify a custom `select` clause for the query: 213 | 214 | ``` 215 | DB::table('users')->select('name', 'email') 216 | ``` 217 | 218 | To change name of column, you may use `alias` function 219 | 220 | ``` 221 | DB::table('users') 222 | ->select('customerName')->alias('name') 223 | ->addSelect('customerAge')->alias('age') 224 | ``` 225 | 226 | The `distinct` method allows you to force the query to return distinct results: 227 | 228 | ``` 229 | DB::table('users')->distinct() 230 | ``` 231 | 232 | If you already have a query builder instance and you wish to add a column to its existing select clause, you may use the `addSelect` method or simple use continuously `select` method: 233 | 234 | ``` 235 | DB::table('users')->select('name')->addSelect('age') 236 | ``` 237 | 238 | ## Raw Expressions 239 | 240 | Sometimes you may need to use a raw expression in a query. 241 | 242 | #### selectRaw 243 | 244 | The `selectRaw` method can be used to create raw select. This method accepts an optional array of bindings as its second argument: 245 | 246 | ``` 247 | DB::table('orders')->selectRaw('price * ? as price_with_tax', [1.0825]) 248 | ``` 249 | 250 | #### whereRaw / orWhereRaw 251 | 252 | The `whereRaw` and `orWhereRaw` methods can be used to inject a raw `where` clause into your query. These methods accept an optional array of bindings as their second argument: 253 | 254 | ``` 255 | DB::table('orders')->whereRaw('price > IF(state = "TX", ?, 100)', [200]) 256 | ``` 257 | 258 | #### havingRaw / orHavingRaw 259 | 260 | The `havingRaw` and `orHavingRaw` methods may be used to set a raw string as the value of the `having` clause: 261 | 262 | ``` 263 | DB::table('orders') 264 | ->select('department') 265 | ->sum('price')->alias('total_sales') 266 | ->groupBy('department') 267 | ->havingRaw('SUM(price) > 2500') 268 | ``` 269 | 270 | #### orderByRaw 271 | 272 | The `orderByRaw` method may be used to set a raw string as the value of the `order` by clause: 273 | 274 | ``` 275 | DB::table('orders') 276 | ->orderByRaw('updated_at - created_at DESC') 277 | ``` 278 | 279 | ## Joins 280 | 281 | #### Inner Join Clause 282 | 283 | The query builder may also be used to write join statements. To perform a basic "inner join", you may use the `join` method or `innerJoin` on a query builder instance. The first argument passed to the `join` method is the name of the table you need to join to, while the remaining arguments specify the column constraints for the join. Of course, as you can see, you can join to multiple tables in a single query: 284 | 285 | ``` 286 | DB::table('users') 287 | ->join('contacts', 'users.id', '=', 'contacts.user_id') 288 | ->join('orders', 'users.id', '=', 'orders.user_id') 289 | ->select('users.*', 'contacts.phone', 'orders.price') 290 | ``` 291 | 292 | #### leftJoin/rightJoin/outerJoin 293 | 294 | ``` 295 | DB::table('users') 296 | ->leftJoin('posts', 'users.id', '=', 'posts.user_id') 297 | ``` 298 | 299 | #### crossJoin 300 | 301 | To perform a "cross join" use the `crossJoin` method with the name of the table you wish to cross join to. Cross joins generate a cartesian product between the first table and the joined table: 302 | 303 | ``` 304 | DB::table('sizes') 305 | ->crossJoin('colours') 306 | ``` 307 | 308 | #### Advanced Join Clauses 309 | 310 | You may also specify more advanced join clauses. To get started, pass a `Closure` as the second argument into the `join` method. The `Closure` will receive a `JoinClause` object which allows you to specify constraints on the `join` clause: 311 | 312 | ``` 313 | DB::table('users') 314 | ->join('contacts', function ($join) { 315 | $join->on('users.id', '=', 'contacts.user_id')->orOn(...); 316 | }) 317 | ``` 318 | 319 | If you would like to use a "where" style clause on your joins, you may use the `where` and `orWhere` methods on a join. Instead of comparing two columns, these methods will compare the column against a value: 320 | 321 | ``` 322 | DB::table('users') 323 | ->join('contacts', function ($join) { 324 | $join->on('users.id', '=', 'contacts.user_id') 325 | ->where('contacts.user_id', '>', 5); 326 | }) 327 | ``` 328 | 329 | ## Unions 330 | 331 | The query builder also provides a quick way to "union" two queries together. For example, you may create an initial query and use the union method to `union` it with a second query: 332 | 333 | ``` 334 | DB::table('users')->whereNull('first_name')->union( 335 | DB::table('users')->whereNull('last_name') 336 | ); 337 | ``` 338 | 339 | ## Where Clauses 340 | 341 | #### Simple Where Clauses 342 | 343 | You may use the `where` method on a query builder instance to add `where` clauses to the query. The most basic call to `where` requires three arguments. The first argument is the name of the column. The second argument is an operator, which can be any of the database's supported operators. Finally, the third argument is the value to evaluate against the column. 344 | 345 | For example, here is a query that verifies the value of the "votes" column is equal to 100: 346 | 347 | ``` 348 | DB::table('users')->where('votes', '=', 100) 349 | ``` 350 | 351 | For convenience, if you simply want to verify that a column is equal to a given value, you may pass the value directly as the second argument to the `where` method: 352 | 353 | ``` 354 | DB::table('users')->where('votes', 100) 355 | ``` 356 | 357 | Of course, you may use a variety of other operators when writing a `where` clause: 358 | 359 | ``` 360 | DB::table('users')->where('votes', '>=', 100) 361 | 362 | DB::table('users')->where('votes', '<>', 100) 363 | 364 | DB::table('users')->where('name', 'like', 'T%') 365 | ``` 366 | 367 | You may also pass an array of conditions to the `where` function: 368 | 369 | ``` 370 | DB::table('users')->where([ 371 | ['status', '=', '1'], 372 | ['subscribed', '<>', '1'], 373 | ]) 374 | ``` 375 | 376 | #### Or Statements 377 | 378 | You may chain where constraints together as well as add or clauses to the query. The `orWhere` method accepts the same arguments as the `where` method: 379 | 380 | ``` 381 | DB::table('users') 382 | ->where('votes', '>', 100) 383 | ->orWhere('name', 'John') 384 | ``` 385 | 386 | #### Brackets in where 387 | 388 | You could add opening and closing brackets to where clause with `whereOpenBracket` and `whereCloseBracket` methods: 389 | 390 | ``` 391 | DB::table('users') 392 | ->where(...) 393 | ->whereOpenBracket() 394 | ->where(...) 395 | ->whereCloseBracket() 396 | ``` 397 | 398 | These brackets can work for multiple levels of where conditions. 399 | 400 | #### Additional Where Clauses 401 | 402 | __whereBetween__ 403 | 404 | The `whereBetween` method verifies that a column's value is between two values: 405 | 406 | ``` 407 | DB::table('users')->whereBetween('votes', [1, 100]) 408 | ``` 409 | 410 | __whereNotBetween__ 411 | 412 | The `whereNotBetween` method verifies that a column's value lies outside of two values: 413 | 414 | ``` 415 | DB::table('users')->whereNotBetween('votes', [1, 100]) 416 | ``` 417 | 418 | __whereIn / whereNotIn__ 419 | 420 | The `whereIn` method verifies that a given column's value is contained within the given array: 421 | 422 | ``` 423 | DB::table('users')->whereIn('id', [1, 2, 3]) 424 | ``` 425 | 426 | The `whereNotIn` method verifies that the given column's value is not contained in the given array: 427 | 428 | ``` 429 | DB::table('users')->whereNotIn('id', [1, 2, 3]) 430 | ``` 431 | 432 | __whereNull / whereNotNull__ 433 | 434 | The `whereNull` method verifies that the value of the given column is `NULL`: 435 | 436 | ``` 437 | DB::table('users')->whereNull('updated_at') 438 | ``` 439 | 440 | The `whereNotNull` method verifies that the column's value is not `NULL`: 441 | 442 | ``` 443 | DB::table('users')->whereNotNull('updated_at') 444 | ``` 445 | 446 | __whereDate / whereMonth / whereDay / whereYear / whereTime__ 447 | 448 | The `whereDate` method may be used to compare a column's value against a date: 449 | 450 | ``` 451 | DB::table('users')->whereDate('created_at', '2016-12-31') 452 | ``` 453 | 454 | The `whereMonth` method may be used to compare a column's value against a specific month of a year: 455 | 456 | ``` 457 | DB::table('users')->whereMonth('created_at', '12') 458 | ``` 459 | 460 | The `whereDay` method may be used to compare a column's value against a specific day of a month: 461 | 462 | ``` 463 | DB::table('users')->whereDay('created_at', '31') 464 | ``` 465 | 466 | The `whereYear` method may be used to compare a column's value against a specific year: 467 | 468 | ``` 469 | DB::table('users')->whereYear('created_at', '2016') 470 | ``` 471 | 472 | The `whereTime` method may be used to compare a column's value against a specific time: 473 | 474 | ``` 475 | DB::table('users')->whereTime('created_at', '=', '11:20') 476 | ``` 477 | 478 | __whereColumn__ 479 | 480 | The `whereColumn` method may be used to verify that two columns are equal: 481 | 482 | ``` 483 | DB::table('users')->whereColumn('first_name', 'last_name') 484 | ``` 485 | 486 | You may also pass a comparison operator to the method: 487 | 488 | ``` 489 | DB::table('users')->whereColumn('updated_at', '>', 'created_at') 490 | ``` 491 | 492 | The `whereColumn` method can also be passed an array of multiple conditions. These conditions will be joined using the `and` operator: 493 | 494 | ``` 495 | DB::table('users') 496 | ->whereColumn([ 497 | ['first_name', '=', 'last_name'], 498 | ['updated_at', '>', 'created_at'] 499 | ]) 500 | ``` 501 | 502 | ## Parameter Grouping 503 | 504 | Sometimes you may need to create more advanced where clauses such as "where exists" clauses or nested parameter groupings. The KoolReport query builder can handle these as well. To get started, let's look at an example of grouping constraints within parenthesis: 505 | 506 | ``` 507 | DB::table('users') 508 | ->where('name', '=', 'John') 509 | ->orWhere(function ($query) { 510 | $query->where('votes', '>', 100) 511 | ->where('title', '<>', 'Admin'); 512 | }) 513 | ``` 514 | 515 | As you can see, passing a `Closure` into the `orWhere` method instructs the query builder to begin a constraint group. The `Closure` will receive a query builder instance which you can use to set the constraints that should be contained within the parenthesis group. The example above will produce the following SQL: 516 | 517 | ``` 518 | select * from users where name = 'John' or (votes > 100 and title <> 'Admin') 519 | ``` 520 | 521 | ## Where Exists Clauses 522 | 523 | The `whereExists` method allows you to write `where exists` SQL clauses. The `whereExists` method accepts a `Closure` argument, which will receive a query builder instance allowing you to define the query that should be placed inside of the "exists" clause: 524 | 525 | ``` 526 | DB::table('users') 527 | ->whereExists(function ($query) { 528 | $query->select(DB::raw(1)) 529 | ->from('orders') 530 | ->whereRaw('orders.user_id = users.id'); 531 | }) 532 | ``` 533 | 534 | The query above will produce the following SQL: 535 | 536 | ``` 537 | select * from users 538 | where exists ( 539 | select 1 from orders where orders.user_id = users.id 540 | ) 541 | ``` 542 | 543 | ## JSON Where Clauses 544 | 545 | `QueryBuilder` package also supports querying JSON column types on databases that provide support for JSON column types. Currently, this includes MySQL 5.7 and PostgreSQL. To query a JSON column, use the `->` operator: 546 | 547 | ``` 548 | DB::table('users') 549 | ->where('options->language', 'en') 550 | 551 | DB::table('users') 552 | ->where('preferences->dining->meal', 'salad') 553 | ``` 554 | 555 | ## Ordering, Grouping, Limit, & Offset 556 | 557 | #### orderBy 558 | 559 | The `orderBy` method allows you to sort the result of the query by a given column. The first argument to the `orderBy` method should be the column you wish to sort by, while the second argument controls the direction of the sort and may be either `asc` or `desc`: 560 | 561 | ``` 562 | DB::table('users') 563 | ->orderBy('name', 'desc') 564 | ``` 565 | 566 | #### latest / oldest 567 | 568 | The `latest` and `oldest` methods allow you to easily order results by date. By default, result will be ordered by the `created_at` column. Or, you may pass the column name that you wish to sort by: 569 | 570 | ``` 571 | DB::table('users') 572 | ->latest() 573 | ->first() 574 | ``` 575 | 576 | #### groupBy / having 577 | 578 | The `groupBy` and `having` methods may be used to group the query results. The `having` method's signature is similar to that of the `where` method: 579 | 580 | ``` 581 | DB::table('users') 582 | ->groupBy('account_id') 583 | ->having('account_id', '>', 100) 584 | ``` 585 | 586 | You may pass multiple arguments to the `groupBy` method to group by multiple columns: 587 | 588 | ``` 589 | DB::table('users') 590 | ->groupBy('first_name', 'status') 591 | ->having('account_id', '>', 100) 592 | ``` 593 | 594 | For more advanced `having` statements, see the `havingRaw` method. 595 | 596 | #### skip / take 597 | 598 | To limit the number of results returned from the query, or to skip a given number of results in the query, you may use the `skip` and `take` methods: 599 | 600 | ``` 601 | DB::table('users')->skip(10)->take(5) 602 | ``` 603 | 604 | Alternatively, you may use the `limit` and `offset` methods: 605 | 606 | ``` 607 | DB::table('users') 608 | ->offset(10) 609 | ->limit(5) 610 | ``` 611 | 612 | ## Conditional Clauses 613 | 614 | #### when 615 | 616 | Sometimes you may want clauses to apply to a query only when something else is true. For instance you may only want to apply a `where` statement if a given input value is present on the incoming request. You may accomplish this using the `when` method: 617 | 618 | ``` 619 | $role = $_POST['role']; 620 | 621 | DB::table('users') 622 | ->when($role, function ($query) use ($role) { 623 | return $query->where('role_id', $role); 624 | }) 625 | ``` 626 | 627 | The `when` method only executes the given Closure when the first parameter is `true`. If the first parameter is `false`, the Closure will not be executed. 628 | 629 | You may pass another Closure as the third parameter to the `when` method. This Closure will execute if the first parameter evaluates as `false`. To illustrate how this feature may be used, we will use it to configure the default sorting of a query: 630 | 631 | ``` 632 | $sortBy = null; 633 | 634 | $users = DB::table('users') 635 | ->when($sortBy, 636 | function ($query) use ($sortBy) { 637 | return $query->orderBy($sortBy); 638 | }, 639 | function ($query) { 640 | return $query->orderBy('name'); 641 | } 642 | ) 643 | ``` 644 | 645 | #### branch 646 | 647 | Sometime you may need clause to apply to query when a parameter has specific value, you may use the `branch` statement. 648 | 649 | You will pass to the `branch` function the list of `Closure` in second parameters. 650 | 651 | ``` 652 | $user_role = "admin"; //"registered_user","public" 653 | 654 | DB::table('orders') 655 | ->branch($user_role,[ 656 | "admin"=>function($query){ 657 | $query->whereIn('state',['TX','NY','DC']) 658 | }, 659 | "registered_user"=>function($query){ 660 | $query->whereIn('state',['TX','NY']) 661 | }, 662 | "public"=>function($query){ 663 | $query->where('state','TX') 664 | }, 665 | ]) 666 | ``` 667 | 668 | ## Inserts 669 | 670 | Although working with KoolReport, most of the time you will deal with `select` statement, the query builder also provides an `insert` method for inserting records into the database table. The `insert` method accepts an array of column names and values: 671 | 672 | ``` 673 | DB::table('users')->insert( 674 | ['email' => 'john@example.com', 'votes' => 0] 675 | ); 676 | ``` 677 | 678 | You may even insert several records into the table with a single call to `insert` by passing an array of arrays. Each array represents a row to be inserted into the table: 679 | 680 | ``` 681 | DB::table('users')->insert([ 682 | ['email' => 'taylor@example.com', 'votes' => 0], 683 | ['email' => 'dayle@example.com', 'votes' => 0] 684 | ]); 685 | ``` 686 | 687 | ## Updates 688 | 689 | Although working with KoolReport, most of the time you will deal with `select` statement, the query builder can also `update` existing records using the `update` method. The `update` method, like the `insert` method, accepts an array of column and value pairs containing the columns to be updated. You may constrain the `update` query using `where` clauses: 690 | 691 | ``` 692 | DB::table('users') 693 | ->where('id', 1) 694 | ->update(['votes' => 1]); 695 | ``` 696 | 697 | ### Increment & Decrement 698 | 699 | The query builder also provides convenient methods for incrementing or decrementing the value of a given column. This is a shortcut, providing a more expressive and terse interface compared to manually writing the `update` statement. 700 | 701 | Both of these methods accept at least one argument: the column to modify. A second argument may optionally be passed to control the amount by which the column should be incremented or decremented: 702 | 703 | ``` 704 | DB::table('users')->increment('votes') 705 | 706 | DB::table('users')->increment('votes', 5) 707 | 708 | DB::table('users')->decrement('votes') 709 | 710 | DB::table('users')->decrement('votes', 5) 711 | ``` 712 | 713 | ## Deletes 714 | 715 | Although working with KoolReport, most of the time you will deal with `select` statement,the query builder may also be used to `delete` records from the table via the `delete` method. You may constrain `delete` statements by adding `where` clauses before calling the `delete` method: 716 | 717 | ``` 718 | DB::table('users')->delete() 719 | 720 | DB::table('users')->where('votes', '>', 100)->delete() 721 | ``` 722 | 723 | If you wish to truncate the entire table, which will remove all rows and reset the auto-incrementing ID to zero, you may use the `truncate` method: 724 | 725 | ``` 726 | DB::table('users')->truncate(); 727 | ``` 728 | 729 | ## Pessimistic Locking 730 | 731 | The query builder also includes a few functions to help you do "pessimistic locking" on your `select` statements. To run the statement with a "shared lock", you may use the `sharedLock` method on a query. A shared lock prevents the selected rows from being modified until your transaction commits: 732 | 733 | ``` 734 | DB::table('users')->where('votes', '>', 100)->sharedLock() 735 | ``` 736 | 737 | Alternatively, you may use the `lockForUpdate` method. A "for update" lock prevents the rows from being modified or from being selected with another shared lock: 738 | 739 | ``` 740 | DB::table('users')->where('votes', '>', 100)->lockForUpdate() 741 | ``` 742 | 743 | # Support 744 | 745 | Please use our forum if you need support, by this way other people can benefit as well. If the support request need privacy, you may send email to us at __support@koolreport.com__. 746 | 747 | 748 | 749 | 750 | -------------------------------------------------------------------------------- /SQL.php: -------------------------------------------------------------------------------- 1 | query = $query; 16 | if (!$quoteIdentifier) { 17 | $this->identifierQuotes = null; 18 | } elseif (gettype($quoteIdentifier) === "array") { 19 | $this->identifierQuotes = $quoteIdentifier; 20 | } 21 | } 22 | 23 | protected function renderValue($value) 24 | { 25 | if ($value === null) { 26 | return "NULL"; 27 | } elseif (gettype($value) === "array") { 28 | for ($i = 0; $i < count($value); $i++) { 29 | if (gettype($value[$i]) == "string") { 30 | $value[$i] = $this->coverValue($this->escapeString($value[$i])); 31 | } 32 | } 33 | return "(" . implode(",", $value) . ")"; 34 | } elseif (gettype($value) === "string") { 35 | return $this->coverValue($this->escapeString($value)); 36 | } elseif (gettype($value) === "boolean") { 37 | return ($value === true) ? 1 : 0; 38 | } 39 | return $value; 40 | } 41 | 42 | protected function escapeString($string) 43 | { 44 | if($this->escapeValue) { 45 | return DB::escapeString($string); 46 | } 47 | return $string; 48 | } 49 | protected function coverValue($value) 50 | { 51 | return "'$value'"; 52 | } 53 | protected function quoteIdentifier($name) 54 | { 55 | if ($this->identifierQuotes === null || $this->identifierQuotes === array()) { 56 | return $name; 57 | } 58 | $dot = strpos($name, "."); 59 | if ($dot === false) { 60 | return $this->identifierQuotes[0] . $name . $this->identifierQuotes[1]; 61 | } else { 62 | $table = substr($name, 0, $dot); 63 | $column = str_replace($table . ".", "", $name); 64 | return $this->identifierQuotes[0] . $table . $this->identifierQuotes[1] 65 | . "." . $this->identifierQuotes[0] . $column . $this->identifierQuotes[1]; 66 | } 67 | } 68 | 69 | protected function getWhere($conditions, $options = []) 70 | { 71 | $useSQLParams = Util::get($options, "useSQLParams", false); //"named parameter", "question mark" 72 | if ( 73 | $useSQLParams !== false 74 | && $useSQLParams !== "name" 75 | && $useSQLParams !== "question mark" 76 | ) { 77 | $useSQLParams = "name"; 78 | } 79 | // echo "useSQLParams=$useSQLParams
"; 80 | // var_dump($this->query); echo "
"; 81 | $queryId = gettype($this->query) === 'object' ? $this->query->id : 0; 82 | $result = ""; 83 | foreach ($conditions as $condition) { 84 | if (gettype($condition) == "array") { 85 | switch ($condition[0]) { 86 | case "[{exists}]": 87 | $class = get_class($this); 88 | $object = new $class($condition[1], $this->identifierQuotes); 89 | $result .= "exists( " . $object->buildQuery() . " )"; 90 | break; 91 | case "[{raw}]": 92 | $result .= $condition[1]; 93 | break; 94 | default: 95 | $field = $condition[0]; 96 | $operator = Util::get($condition, 1); 97 | if (gettype($operator) === 'string') $operator = strtoupper(trim($operator)); 98 | $value = Util::get($condition, 2); 99 | // var_dump($operator); echo "
"; 100 | // var_dump($value); echo "
"; 101 | $part = "{key} {operator} {value}"; 102 | $part = str_replace("{key}", $this->quoteIdentifier($field), $part); 103 | $part = str_replace("{operator}", $operator, $part); 104 | if (gettype($value) == "string" && strpos($value, "[{colName}]") === 0) { 105 | $part = str_replace("{value}", str_replace("[{colName}]", "", $this->quoteIdentifier($value)), $part); 106 | } else { 107 | // echo "operator=$operator
"; 108 | if ($useSQLParams === 'name') { 109 | if (($operator === "IN" || $operator === "NOT IN") 110 | && gettype($value) === "array" 111 | ) { 112 | // echo "in not in
"; 113 | $valueLength = count($value); 114 | $paramNames = []; 115 | $paramCount = $this->query->paramCount++; 116 | for ($i = 0; $i < $valueLength; $i++) { 117 | $paramName = ":{$queryId}_param_{$paramCount}_$i"; 118 | $paramNames[] = $paramName; 119 | $this->query->sqlParams[$paramName] = $value[$i]; 120 | } 121 | $paramNames = implode(", ", $paramNames); 122 | $part = str_replace("{value}", "(" . $paramNames . ")", $part); 123 | } else if ( 124 | ($operator === "IS" || $operator === "IS NOT") 125 | && $value === null 126 | ) { 127 | // echo "is null is not null
"; 128 | $part = str_replace("{value}", $this->renderValue($value), $part); 129 | } else { 130 | $paramName = ":" . $queryId . "_param_" . ($this->query->paramCount++); 131 | // echo "paramName=$paramName
"; 132 | $part = str_replace("{value}", $paramName, $part); 133 | $this->query->sqlParams[$paramName] = $value; 134 | } 135 | } else if ($useSQLParams === 'question mark') { 136 | if ( 137 | ($operator === "IN" || $operator === "NOT IN") 138 | && gettype($value) === "array" 139 | ) { 140 | $valueLength = count($value); 141 | $paramNames = []; 142 | $paramCount = $this->query->paramCount++; 143 | for ($i = 0; $i < $valueLength; $i++) { 144 | $paramName = "?"; 145 | $paramNames[] = $paramName; 146 | $this->query->sqlParams[] = $value[$i]; 147 | } 148 | $paramNames = implode(", ", $paramNames); 149 | $part = str_replace("{value}", "(" . $paramNames . ")", $part); 150 | } else if ( 151 | ($operator === "IS" || $operator === "IS NOT") 152 | && $value === null 153 | ) { 154 | $part = str_replace("{value}", $this->renderValue($value), $part); 155 | } else { 156 | $part = str_replace("{value}", "?", $part); 157 | $this->query->sqlParams[] = $value; 158 | } 159 | } else { 160 | $part = str_replace("{value}", $this->renderValue($value), $part); 161 | } 162 | } 163 | $result .= $part; 164 | break; 165 | } 166 | } elseif (gettype($condition) == "string") { 167 | $result .= " $condition "; 168 | } elseif (is_a($condition, 'koolreport\querybuilder\Query')) { 169 | $result .= "(" . $this->getWhere($condition->conditions, $options) . ")"; 170 | } 171 | } 172 | return $result; 173 | } 174 | 175 | protected function getFrom($tables) 176 | { 177 | $array = array(); 178 | foreach ($tables as $table) { 179 | if (gettype($table) == "array") { 180 | $class = get_class($this); 181 | if(is_string($table[0])) { 182 | array_push($array, $this->quoteIdentifier($table[0]) ." " . $this->quoteIdentifier($table[1])); 183 | } else if($table[0] instanceof Query) { 184 | $interpreter = new $class($table[0], $this->identifierQuotes); 185 | array_push($array, "(" . $interpreter->buildQuery() . ") " . $this->quoteIdentifier($table[1])); 186 | } 187 | } else { 188 | array_push($array, $this->quoteIdentifier($table)); 189 | } 190 | } 191 | return implode(", ", $array); 192 | } 193 | 194 | protected function getOrderBy($orders) 195 | { 196 | $array = array(); 197 | foreach ($orders as $order) { 198 | if ($order[0] == "[{raw}]") { 199 | array_push($array, $order[1]); 200 | } else { 201 | array_push($array, $this->quoteIdentifier($order[0]) . " " . $order[1]); 202 | } 203 | } 204 | return implode(", ", $array); 205 | } 206 | 207 | protected function getGroupBy($groups) 208 | { 209 | $array = array(); 210 | foreach ($groups as $group) { 211 | if (strpos($group, "[{raw}]") !== false) { 212 | $group = str_replace("[{raw}]", "", $group); 213 | array_push($array, $group); 214 | } else { 215 | array_push($array, $this->quoteIdentifier($group)); 216 | } 217 | } 218 | return implode(", ", $array); 219 | } 220 | 221 | protected function getHaving($having, $options = []) 222 | { 223 | return $this->getWhere($having->conditions, $options); 224 | } 225 | 226 | protected function getJoin($joins) 227 | { 228 | $array = array(); 229 | foreach ($joins as $join) { 230 | $class = get_class($this); 231 | $object = new $class($join[1], $this->identifierQuotes); 232 | $part = " $join[0] " . $this->quoteIdentifier($join[1]); 233 | if (isset($join[2])) { 234 | $part .= " ON " . $object->getWhere($join[2]->conditions); 235 | } 236 | array_push($array, $part); 237 | } 238 | return implode(" ", $array); 239 | } 240 | 241 | protected function getSelect($columns) 242 | { 243 | $array = array(); 244 | foreach ($columns as $column) { 245 | $part = ""; 246 | if (gettype($column[0]) == "array") { 247 | //Raw or aggregate 248 | if ($column[0][0] == "[{raw}]") { 249 | $part .= $column[0][1]; 250 | } else if ($column[0][0] == "COUNT" && $column[0][1] == 1) { 251 | $part .= "COUNT(1)"; 252 | } else if ($column[0][0] == "COUNT DISTINCT") { 253 | $part .= "COUNT(DISTINCT " . $this->quoteIdentifier($column[0][1]) . ")"; 254 | } else { 255 | $part .= $column[0][0] . "(" . $this->quoteIdentifier($column[0][1]) . ")"; 256 | } 257 | } else { 258 | $part .= $this->quoteIdentifier($column[0]); 259 | } 260 | if (isset($column[1])) { 261 | $part .= " AS " . $this->quoteIdentifier($column[1]); 262 | } 263 | array_push($array, $part); 264 | } 265 | return implode(", ", $array); 266 | } 267 | protected function getUnions($unions) 268 | { 269 | $res = ""; 270 | $class = get_class($this); 271 | foreach ($unions as $union) { 272 | $interpreter = new $class($union, $this->identifierQuotes); 273 | $res .= " UNION (" . $interpreter->buildQuery() . ")"; 274 | } 275 | return $res; 276 | } 277 | 278 | protected function getUpdateSet($list) 279 | { 280 | $array = array(); 281 | foreach ($list as $key => $value) { 282 | $part = ""; 283 | if (gettype($value) == "array") { 284 | $part .= $this->quoteIdentifier($key) . " = " . $this->quoteIdentifier($value[0]) . " $value[1] $value[2]"; 285 | } elseif (gettype($value) == "string") { 286 | $part .= $this->quoteIdentifier($key) . " = " . $this->coverValue($this->escapeString($value)); 287 | } elseif (gettype($value) == "boolean") { 288 | $part .= $this->quoteIdentifier($key) . " = " . (($value === true) ? "1" : "0"); 289 | } else { 290 | $part .= $this->quoteIdentifier($key) . " = " . (($value !== null) ? $value : "NULL"); 291 | } 292 | array_push($array, $part); 293 | } 294 | return implode(", ", $array); 295 | } 296 | 297 | protected function getInsertValues($list) 298 | { 299 | $keys = array_keys($list); 300 | $values = array_values($list); 301 | for ($i = 0; $i < count($values); $i++) { 302 | if (gettype($values[$i]) == "string") { 303 | $values[$i] = $this->coverValue($this->escapeString($values[$i])); 304 | } elseif (gettype($values[$i]) == "boolean") { 305 | $values[$i] = ($values[$i] === true) ? "1" : "0"; 306 | } 307 | } 308 | for ($i = 0; $i < count($keys); $i++) { 309 | $keys[$i] = $this->quoteIdentifier($keys[$i]); 310 | } 311 | 312 | return ' (' . implode(", ", $keys) . ')' . ' VALUES ' . '(' . implode(", ", $values) . ')'; 313 | } 314 | 315 | protected function buildSelectQuery($options = []) 316 | { 317 | $newLine = Util::get($options, 'newLineBeforeKeyword', false) ? "\n" : " "; 318 | $sql = "SELECT "; 319 | if ($this->query->distinct) { 320 | $sql .= "DISTINCT "; 321 | } 322 | // var_dump($this->query->columns); echo "
"; 323 | if (count($this->query->columns) > 0) { 324 | $sql .= $this->getSelect($this->query->columns); 325 | } else { 326 | $sql .= "*"; 327 | } 328 | if (count($this->query->tables) > 0) { 329 | $sql .= "{$newLine}FROM " . $this->getFrom($this->query->tables); 330 | } else { 331 | throw new \Exception("No table available in SQL Query"); 332 | } 333 | 334 | // var_dump($this->query->joins); 335 | if (count($this->query->joins) > 0) { 336 | $sql .= $this->getJoin($this->query->joins); 337 | } 338 | 339 | if (count($this->query->conditions) > 0) { 340 | $where = trim($this->getWhere($this->query->conditions, $options)); 341 | if (!empty($where)) $sql .= "{$newLine}WHERE " . $where; 342 | } 343 | 344 | if (count($this->query->groups) > 0) { 345 | $groupBy = trim($this->getGroupBy($this->query->groups)); 346 | if (!empty($groupBy)) $sql .= "{$newLine}GROUP BY " . $groupBy; 347 | } 348 | 349 | if ($this->query->having) { 350 | $having = trim($this->getHaving($this->query->having, $options)); 351 | if (!empty($having)) $sql .= "{$newLine}HAVING " . $having; 352 | } 353 | 354 | 355 | if (count($this->query->orders) > 0) { 356 | $orderBy = trim($this->getOrderBy($this->query->orders)); 357 | if (!empty($orderBy)) $sql .= "{$newLine}ORDER BY " . $orderBy; 358 | } 359 | 360 | if ($this->query->limit !== null) { 361 | $sql .= "{$newLine}LIMIT " . $this->query->limit; 362 | } 363 | 364 | if ($this->query->offset !== null) { 365 | $sql .= " OFFSET " . $this->query->offset; 366 | } 367 | 368 | if (count($this->query->unions) > 0) { 369 | $sql .= $this->getUnions($this->query->unions); 370 | } 371 | if ($this->query->lock) { 372 | $sql .= " " . $this->query->lock; 373 | } 374 | return $sql; 375 | } 376 | 377 | protected function buildUpdateQuery($options = []) 378 | { 379 | $sql = "UPDATE "; 380 | if (count($this->query->tables) == 1) { 381 | $sql .= $this->getFrom(array($this->query->tables[0])); 382 | } elseif (count($this->query->tables) > 1) { 383 | throw new \Exception("Only one table is updated"); 384 | } else { 385 | throw new \Exception("Update query need table specified"); 386 | } 387 | if (count($this->query->values) > 0) { 388 | $sql .= " SET " . $this->getUpdateSet($this->query->values); 389 | } 390 | 391 | if (count($this->query->conditions) > 0) { 392 | $sql .= " WHERE " . $this->getWhere($this->query->conditions); 393 | } 394 | return $sql; 395 | } 396 | 397 | protected function buildInsertQuery($options = []) 398 | { 399 | $sql = "INSERT INTO "; 400 | if (count($this->query->tables) == 1) { 401 | $sql .= $this->getFrom(array($this->query->tables[0])); 402 | } elseif (count($this->query->tables) > 1) { 403 | throw new \Exception("Only one table is inserted"); 404 | } else { 405 | throw new \Exception("Insert query need a table specified"); 406 | } 407 | if (count($this->query->values) > 0) { 408 | $sql .= $this->getInsertValues($this->query->values); 409 | } 410 | if (count($this->query->conditions) > 0) { 411 | $sql .= " WHERE " . $this->getWhere($this->query->conditions); 412 | } 413 | return $sql; 414 | } 415 | protected function buildDeleteQuery($options = []) 416 | { 417 | $sql = "DELETE FROM "; 418 | if (count($this->query->tables) == 1) { 419 | $sql .= $this->getFrom(array($this->query->tables[0])); 420 | } elseif (count($this->query->tables) > 1) { 421 | throw new \Exception("Only one table is deleted"); 422 | } else { 423 | throw new \Exception("Delete query need a table specified"); 424 | } 425 | if (count($this->query->conditions) > 0) { 426 | $sql .= " WHERE " . $this->getWhere($this->query->conditions); 427 | } 428 | return $sql; 429 | } 430 | 431 | protected function buildProcedureQuery($options = []) 432 | { 433 | $sql = ""; 434 | foreach($this->query->procedures as $proc) { 435 | $statement = "CALL ".$proc[0]."(@params);"; 436 | $params = []; 437 | foreach($proc[1] as $value) { 438 | if(gettype($value)==="string") { 439 | array_push($params,$this->coverValue($this->escapeString($value))); 440 | } else { 441 | array_push($params,$value); 442 | } 443 | } 444 | $statement = str_replace("@params",implode(",",$params),$statement); 445 | $sql.=$statement; 446 | } 447 | return $sql; 448 | } 449 | 450 | public function buildQuery($options = []) 451 | { 452 | $this->query->paramCount = 0; 453 | $this->query->sqlParams = []; 454 | switch ($this->query->type) { 455 | case "select": 456 | return $this->buildSelectQuery($options); 457 | case "update": 458 | return $this->buildUpdateQuery($options); 459 | case "insert": 460 | return $this->buildInsertQuery($options); 461 | case "delete": 462 | return $this->buildDeleteQuery($options); 463 | case "procedure": 464 | return $this->buildProcedureQuery($options); 465 | } 466 | return "Unknown query type"; 467 | } 468 | 469 | public static function type($query, $quoteIdentifier = false) 470 | { 471 | $class = get_called_class(); 472 | $interpreter = new $class($query, $quoteIdentifier); 473 | return $interpreter->buildQuery(); 474 | } 475 | } -------------------------------------------------------------------------------- /SQLServer.php: -------------------------------------------------------------------------------- 1 | query->procedures as $proc) { 14 | $statement = "EXEC " . $proc[0] . " @params ;"; 15 | $params = []; 16 | foreach ($proc[1] as $value) { 17 | if (gettype($value) === "string") { 18 | array_push($params, $this->coverValue($this->escapeString($value))); 19 | } else { 20 | array_push($params, $value); 21 | } 22 | } 23 | $statement = str_replace("@params", implode(",", $params), $statement); 24 | $sql .= $statement; 25 | } 26 | return $sql; 27 | } 28 | 29 | 30 | protected function buildSelectQuery($options = []) 31 | { 32 | $sql = "SELECT "; 33 | if ($this->query->distinct) { 34 | $sql .= "DISTINCT "; 35 | } 36 | if (count($this->query->columns) > 0) { 37 | $sql .= $this->getSelect($this->query->columns); 38 | } else { 39 | $sql .= "*"; 40 | } 41 | if (count($this->query->tables) > 0) { 42 | $sql .= " FROM " . $this->getFrom($this->query->tables); 43 | } else { 44 | throw new \Exception("No table available in SQL Query"); 45 | } 46 | 47 | if (count($this->query->joins) > 0) { 48 | $sql .= $this->getJoin($this->query->joins); 49 | } 50 | 51 | if (count($this->query->conditions) > 0) { 52 | $sql .= " WHERE " . $this->getWhere($this->query->conditions); 53 | } 54 | 55 | if (count($this->query->groups) > 0) { 56 | $sql .= " GROUP BY " . $this->getGroupBy($this->query->groups); 57 | } 58 | 59 | if ($this->query->having) { 60 | $sql .= " HAVING " . $this->getHaving($this->query->having); 61 | } 62 | 63 | /* 64 | SQL Server requires ORDER BY and OFFET ROWS if using FETCH ROWS 65 | */ 66 | if (isset($this->query->limit)) { 67 | if (empty($this->query->orders)) $this->query->orders = [['[{raw}]', 1]]; 68 | if (empty($this->query->offset)) $this->query->offset = 0; 69 | } 70 | 71 | if (count($this->query->orders) > 0) { 72 | $sql .= " ORDER BY " . $this->getOrderBy($this->query->orders); 73 | } 74 | 75 | if ($this->query->offset !== null) { 76 | $sql .= " OFFSET " . $this->query->offset . " ROWS"; 77 | } 78 | 79 | if ($this->query->limit !== null) { 80 | $sql .= " FETCH NEXT " . $this->query->limit . " ROWS ONLY"; 81 | } 82 | 83 | 84 | if (count($this->query->unions) > 0) { 85 | $sql .= $this->getUnions($this->query->unions); 86 | } 87 | // echo "sql: $sql
"; 88 | return $sql; 89 | } 90 | } 91 | -------------------------------------------------------------------------------- /SQLite.php: -------------------------------------------------------------------------------- 1 | escapeValue) { 13 | return str_replace("'","''",$string); 14 | } 15 | return $string; 16 | } 17 | } -------------------------------------------------------------------------------- /codeception.yml: -------------------------------------------------------------------------------- 1 | paths: 2 | tests: tests 3 | output: tests/_output 4 | data: tests/_data 5 | support: tests/_support 6 | envs: tests/_envs 7 | actor_suffix: Tester 8 | extensions: 9 | enabled: 10 | - Codeception\Extension\RunFailed 11 | -------------------------------------------------------------------------------- /composer.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "koolreport/querybuilder", 3 | "version":"3.5.0", 4 | "description": "Create query by php code", 5 | "keywords": ["PHP","php reprting tools","php reporting framework","mysql reporting tools","charts","graphs","query builder","sql query generator"], 6 | "homepage": "https://www.koolreport.com", 7 | "type": "library", 8 | "license": "MIT" 9 | } -------------------------------------------------------------------------------- /tests/_data/.gitkeep: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/koolreport/querybuilder/4291a4b89a0aa16aa543a3f3822e331eb602e7a8/tests/_data/.gitkeep -------------------------------------------------------------------------------- /tests/_output/.gitignore: -------------------------------------------------------------------------------- 1 | * 2 | !.gitignore -------------------------------------------------------------------------------- /tests/_support/AcceptanceTester.php: -------------------------------------------------------------------------------- 1 | selectRaw('price * ? as price_with_tax', [1.0825])->toMySQL(); 14 | $this->assertEquals("SELECT price * 1.0825 as price_with_tax FROM orders",$sql); 15 | } 16 | 17 | public function testCoverIdentity() 18 | { 19 | $sql = DB::table('orders')->select('orders.id')->toMySQL(true); 20 | $this->assertEquals($sql, "SELECT `orders`.`id` FROM `orders`"); 21 | } 22 | 23 | public function testNoCoverIdentity() 24 | { 25 | $sql = DB::table('orders')->select('orders.id')->toMySQL(); 26 | $this->assertEquals($sql, "SELECT orders.id FROM orders"); 27 | 28 | $sql = MySQL::type( 29 | DB::table('orders')->select('orders.id') 30 | ); 31 | $this->assertEquals($sql, "SELECT orders.id FROM orders"); 32 | } 33 | 34 | public function testSetCoverEntity() 35 | { 36 | $sql = DB::table('orders')->select('orders.id')->toMySQL(['[',']']); 37 | $this->assertEquals($sql, "SELECT [orders].[id] FROM [orders]"); 38 | } 39 | 40 | public function testSQLServerLimitAndOffset() 41 | { 42 | $sql = DB::table('orders') 43 | ->select('orders.id') 44 | ->limit(10) 45 | ->offset(10) 46 | ->toSQLServer(); 47 | $this->assertEquals($sql, "SELECT orders.id FROM orders OFFSET 10 ROWS FETCH NEXT 10 ROWS ONLY"); 48 | } 49 | 50 | public function testGroupBy() 51 | { 52 | $sql = DB::table('orders') 53 | ->groupBy('name')->toMySQL(); 54 | $this->assertEquals($sql, "SELECT * FROM orders GROUP BY name"); 55 | 56 | $sql2 = DB::table('orders') 57 | ->groupBy('DAY(created_time)')->toMySQL(); 58 | $this->assertEquals($sql2, "SELECT * FROM orders GROUP BY DAY(created_time)"); 59 | 60 | $sql3 = DB::table('orders') 61 | ->groupByRaw('DAY(created_time)')->toMySQL(true); 62 | $this->assertEquals($sql3, "SELECT * FROM `orders` GROUP BY DAY(created_time)"); 63 | } 64 | 65 | public function testCreate() 66 | { 67 | $query = Query::create([ 68 | "type"=>"select", 69 | "tables"=>["orders"], 70 | "groups"=>["name"], 71 | "limit"=>2 72 | ]); 73 | $sql = $query->toMySQL(); 74 | $this->assertEquals("SELECT * FROM orders GROUP BY name LIMIT 2",$sql); 75 | } 76 | 77 | public function testToArray() 78 | { 79 | // $query = Query::create([ 80 | // "type"=>"select", 81 | // "tables"=>["orders"], 82 | // "limit"=>2, 83 | // "offset"=>3, 84 | // "distinct"=>true, 85 | // "lock"=>true, 86 | // ]); 87 | // $str_arr = json_encode($query->toArray()); 88 | // $this->assertEquals("abc",$str_arr); 89 | } 90 | 91 | public function testSerialize() 92 | { 93 | $st = '{"type":"select","tables":["orders",[{"type":"select","tables":["orderdetails"],"columns":[["amount"]],"conditions":[],"orders":[],"groups":[],"having":null,"limit":null,"offset":null,"joins":[],"distinct":false,"unions":[],"values":[],"lock":null},"t"]],"columns":[["name","firstName"]],"conditions":[],"orders":[],"groups":["name"],"having":null,"limit":null,"offset":null,"joins":[["JOIN","customers",{"type":"select","tables":[],"columns":[],"conditions":[["customerId","=","[{colName}]id"]],"orders":[],"groups":[],"having":null,"limit":null,"offset":null,"joins":[],"distinct":false,"unions":[],"values":[],"lock":null}]],"distinct":false,"unions":[],"values":[],"lock":null}'; 94 | 95 | $query = Query::create(json_decode($st,true)); 96 | $serial = json_encode($query->toArray()); 97 | $this->assertEquals($serial, $st); 98 | } 99 | 100 | public function testWhereRaw() 101 | { 102 | $query = new Query(); 103 | $query->whereRaw("a>?",[1.2])->from("test"); 104 | $this->assertEquals("SELECT * FROM test WHERE a>1.2",$query->toMySQL()); 105 | } 106 | 107 | public function testOrderByRaw() 108 | { 109 | $this->assertEquals("SELECT * FROM test ORDER BY a - 1 desc", 110 | DB::table("test")->orderByRaw("a - 1 desc",[1]) 111 | ); 112 | } 113 | 114 | public function testGroupByRaw() 115 | { 116 | $this->assertEquals("SELECT * FROM test GROUP BY DATE(a)", 117 | DB::table("test")->groupByRaw("DATE(a)") 118 | ); 119 | } 120 | 121 | } --------------------------------------------------------------------------------