├── .gitattributes
├── LICENSE
├── MysqliDb.php
├── composer.json
├── dbObject.md
├── dbObject.php
└── readme.md
/.gitattributes:
--------------------------------------------------------------------------------
1 | /tests/ export-ignore
2 | /index.php export-ignore
3 |
--------------------------------------------------------------------------------
/LICENSE:
--------------------------------------------------------------------------------
1 | Wrapper for a PHP MySQL class, which utilizes MySQLi and prepared statements.
2 | Copyright (C) 2013 Josh Campbell (ajillion)
3 |
4 | This program is free software: you can redistribute it and/or modify it under the terms of the GNU General Public License as published by
5 | the Free Software Foundation, either version 3 of the License, or (at your option) any later version.
6 |
7 | This program is distributed in the hope that it will be useful, but WITHOUT ANY WARRANTY; without even the implied warranty of
8 | MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU General Public License for more details.
9 |
10 | You should have received a copy of the GNU General Public License along with this program. If not, see .
11 |
--------------------------------------------------------------------------------
/MysqliDb.php:
--------------------------------------------------------------------------------
1 |
8 | * @author Josh Campbell
9 | * @author Alexander V. Butenko
10 | * @copyright Copyright (c) 2010-2017
11 | * @license http://opensource.org/licenses/gpl-3.0.html GNU Public License
12 | * @link http://github.com/joshcam/PHP-MySQLi-Database-Class
13 | * @version 2.9.3
14 | */
15 |
16 | class MysqliDb
17 | {
18 |
19 | /**
20 | * Static instance of self
21 | *
22 | * @var MysqliDb
23 | */
24 | protected static $_instance;
25 |
26 | /**
27 | * Table prefix
28 | *
29 | * @var string
30 | */
31 | public static $prefix = '';
32 |
33 | /**
34 | * MySQLi instances
35 | *
36 | * @var mysqli[]
37 | */
38 | protected $_mysqli = array();
39 |
40 | /**
41 | * The SQL query to be prepared and executed
42 | *
43 | * @var string
44 | */
45 | protected $_query;
46 |
47 | /**
48 | * The previously executed SQL query
49 | *
50 | * @var string
51 | */
52 | protected $_lastQuery;
53 |
54 | /**
55 | * The SQL query options required after SELECT, INSERT, UPDATE or DELETE
56 | *
57 | * @var array
58 | */
59 | protected $_queryOptions = array();
60 |
61 | /**
62 | * An array that holds where joins
63 | *
64 | * @var array
65 | */
66 | protected $_join = array();
67 |
68 | /**
69 | * An array that holds where conditions
70 | *
71 | * @var array
72 | */
73 | protected $_where = array();
74 |
75 | /**
76 | * An array that holds where join ands
77 | *
78 | * @var array
79 | */
80 | protected $_joinAnd = array();
81 |
82 | /**
83 | * An array that holds having conditions
84 | *
85 | * @var array
86 | */
87 | protected $_having = array();
88 |
89 | /**
90 | * Dynamic type list for order by condition value
91 | *
92 | * @var array
93 | */
94 | protected $_orderBy = array();
95 |
96 | /**
97 | * Dynamic type list for group by condition value
98 | *
99 | * @var array
100 | */
101 | protected $_groupBy = array();
102 |
103 | /**
104 | * Dynamic type list for temporary locking tables.
105 | *
106 | * @var array
107 | */
108 | protected $_tableLocks = array();
109 |
110 | /**
111 | * Variable which holds the current table lock method.
112 | *
113 | * @var string
114 | */
115 | protected $_tableLockMethod = "READ";
116 |
117 | /**
118 | * Dynamic array that holds a combination of where condition/table data value types and parameter references
119 | *
120 | * @var array
121 | */
122 | protected $_bindParams = array(''); // Create the empty 0 index
123 |
124 | /**
125 | * Variable which holds an amount of returned rows during get/getOne/select queries
126 | *
127 | * @var string
128 | */
129 | public $count = 0;
130 |
131 | /**
132 | * Variable which holds an amount of returned rows during get/getOne/select queries with withTotalCount()
133 | *
134 | * @var string
135 | */
136 | public $totalCount = 0;
137 |
138 | /**
139 | * Variable which holds last statement error
140 | *
141 | * @var string
142 | */
143 | protected $_stmtError;
144 |
145 | /**
146 | * Variable which holds last statement error code
147 | *
148 | * @var int
149 | */
150 | protected $_stmtErrno;
151 |
152 | /**
153 | * Is Subquery object
154 | *
155 | * @var bool
156 | */
157 | protected $isSubQuery = false;
158 |
159 | /**
160 | * Name of the auto increment column
161 | *
162 | * @var int
163 | */
164 | protected $_lastInsertId = null;
165 |
166 | /**
167 | * Column names for update when using onDuplicate method
168 | *
169 | * @var array
170 | */
171 | protected $_updateColumns = null;
172 |
173 | /**
174 | * Return type: 'array' to return results as array, 'object' as object
175 | * 'json' as json string
176 | *
177 | * @var string
178 | */
179 | public $returnType = 'array';
180 |
181 | /**
182 | * Should join() results be nested by table
183 | *
184 | * @var bool
185 | */
186 | protected $_nestJoin = false;
187 |
188 | /**
189 | * Table name (with prefix, if used)
190 | *
191 | * @var string
192 | */
193 | private $_tableName = '';
194 |
195 | /**
196 | * FOR UPDATE flag
197 | *
198 | * @var bool
199 | */
200 | protected $_forUpdate = false;
201 |
202 | /**
203 | * LOCK IN SHARE MODE flag
204 | *
205 | * @var bool
206 | */
207 | protected $_lockInShareMode = false;
208 |
209 | /**
210 | * Key field for Map()'ed result array
211 | *
212 | * @var string
213 | */
214 | protected $_mapKey = null;
215 |
216 | /**
217 | * Variables for query execution tracing
218 | */
219 | protected $traceStartQ = 0;
220 | protected $traceEnabled = false;
221 | protected $traceStripPrefix = '';
222 | public $trace = array();
223 |
224 | /**
225 | * Per page limit for pagination
226 | *
227 | * @var int
228 | */
229 |
230 | public $pageLimit = 20;
231 | /**
232 | * Variable that holds total pages count of last paginate() query
233 | *
234 | * @var int
235 | */
236 | public $totalPages = 0;
237 |
238 | /**
239 | * @var array connections settings [profile_name=>[same_as_contruct_args]]
240 | */
241 | protected $connectionsSettings = array();
242 | /**
243 | * @var string the name of a default (main) mysqli connection
244 | */
245 | public $defConnectionName = 'default';
246 |
247 | public $autoReconnect = true;
248 | protected $autoReconnectCount = 0;
249 |
250 | /**
251 | * @var bool Operations in transaction indicator
252 | */
253 | protected $_transaction_in_progress = false;
254 |
255 | /**
256 | * @param string $host
257 | * @param string $username
258 | * @param string $password
259 | * @param string $db
260 | * @param int $port
261 | * @param string $charset
262 | * @param string $socket
263 | */
264 | public function __construct($host = null, $username = null, $password = null, $db = null, $port = null, $charset = 'utf8', $socket = null)
265 | {
266 | $isSubQuery = false;
267 |
268 | // if params were passed as array
269 | if (is_array($host)) {
270 | foreach ($host as $key => $val) {
271 | $$key = $val;
272 | }
273 | }
274 |
275 | $this->addConnection('default', array(
276 | 'host' => $host,
277 | 'username' => $username,
278 | 'password' => $password,
279 | 'db' => $db,
280 | 'port' => $port,
281 | 'socket' => $socket,
282 | 'charset' => $charset
283 | ));
284 |
285 | if ($isSubQuery) {
286 | $this->isSubQuery = true;
287 | return;
288 | }
289 |
290 | if (isset($prefix)) {
291 | $this->setPrefix($prefix);
292 | }
293 |
294 | self::$_instance = $this;
295 | }
296 |
297 | /**
298 | * A method to connect to the database
299 | *
300 | * @param null|string $connectionName
301 | *
302 | * @throws Exception
303 | * @return void
304 | */
305 | public function connect($connectionName = 'default')
306 | {
307 | if(!isset($this->connectionsSettings[$connectionName]))
308 | throw new Exception('Connection profile not set');
309 |
310 | $pro = $this->connectionsSettings[$connectionName];
311 | $params = array_values($pro);
312 | $charset = array_pop($params);
313 |
314 | if ($this->isSubQuery) {
315 | return;
316 | }
317 |
318 | if (empty($pro['host']) && empty($pro['socket'])) {
319 | throw new Exception('MySQL host or socket is not set');
320 | }
321 |
322 | $mysqlic = new ReflectionClass('mysqli');
323 | $mysqli = $mysqlic->newInstanceArgs($params);
324 |
325 | if ($mysqli->connect_error) {
326 | throw new Exception('Connect Error ' . $mysqli->connect_errno . ': ' . $mysqli->connect_error, $mysqli->connect_errno);
327 | }
328 |
329 | if (!empty($charset)) {
330 | $mysqli->set_charset($charset);
331 | }
332 | $this->_mysqli[$connectionName] = $mysqli;
333 | }
334 |
335 | /**
336 | * @throws Exception
337 | */
338 | public function disconnectAll()
339 | {
340 | foreach (array_keys($this->_mysqli) as $k) {
341 | $this->disconnect($k);
342 | }
343 | }
344 |
345 | /**
346 | * Set the connection name to use in the next query
347 | *
348 | * @param string $name
349 | *
350 | * @return $this
351 | * @throws Exception
352 | */
353 | public function connection($name)
354 | {
355 | if (!isset($this->connectionsSettings[$name]))
356 | throw new Exception('Connection ' . $name . ' was not added.');
357 |
358 | $this->defConnectionName = $name;
359 | return $this;
360 | }
361 |
362 | /**
363 | * A method to disconnect from the database
364 | *
365 | * @params string $connection connection name to disconnect
366 | *
367 | * @param string $connection
368 | *
369 | * @return void
370 | */
371 | public function disconnect($connection = 'default')
372 | {
373 | if (!isset($this->_mysqli[$connection]))
374 | return;
375 |
376 | $this->_mysqli[$connection]->close();
377 | unset($this->_mysqli[$connection]);
378 | }
379 |
380 | /**
381 | * Create & store at _mysqli new mysqli instance
382 | *
383 | * @param string $name
384 | * @param array $params
385 | *
386 | * @return $this
387 | */
388 | public function addConnection($name, array $params)
389 | {
390 | $this->connectionsSettings[$name] = array();
391 | foreach (array('host', 'username', 'password', 'db', 'port', 'socket', 'charset') as $k) {
392 | $prm = isset($params[$k]) ? $params[$k] : null;
393 |
394 | if ($k == 'host') {
395 | if (is_object($prm))
396 | $this->_mysqli[$name] = $prm;
397 |
398 | if (!is_string($prm))
399 | $prm = null;
400 | }
401 | $this->connectionsSettings[$name][$k] = $prm;
402 | }
403 | return $this;
404 | }
405 |
406 | /**
407 | * A method to get mysqli object or create it in case needed
408 | *
409 | * @return mysqli
410 | * @throws Exception
411 | */
412 | public function mysqli()
413 | {
414 | if (!isset($this->_mysqli[$this->defConnectionName])) {
415 | $this->connect($this->defConnectionName);
416 | }
417 | return $this->_mysqli[$this->defConnectionName];
418 | }
419 |
420 | /**
421 | * A method of returning the static instance to allow access to the
422 | * instantiated object from within another class.
423 | * Inheriting this class would require reloading connection info.
424 | *
425 | * @uses $db = MySqliDb::getInstance();
426 | *
427 | * @return MysqliDb Returns the current instance.
428 | */
429 | public static function getInstance()
430 | {
431 | return self::$_instance;
432 | }
433 |
434 | /**
435 | * Reset states after an execution
436 | *
437 | * @return MysqliDb Returns the current instance.
438 | */
439 | protected function reset()
440 | {
441 | if ($this->traceEnabled) {
442 | $this->trace[] = array($this->_lastQuery, (microtime(true) - $this->traceStartQ), $this->_traceGetCaller());
443 | }
444 |
445 | $this->_where = array();
446 | $this->_having = array();
447 | $this->_join = array();
448 | $this->_joinAnd = array();
449 | $this->_orderBy = array();
450 | $this->_groupBy = array();
451 | $this->_bindParams = array(''); // Create the empty 0 index
452 | $this->_query = null;
453 | $this->_queryOptions = array();
454 | $this->returnType = 'array';
455 | $this->_nestJoin = false;
456 | $this->_forUpdate = false;
457 | $this->_lockInShareMode = false;
458 | $this->_tableName = '';
459 | $this->_lastInsertId = null;
460 | $this->_updateColumns = null;
461 | $this->_mapKey = null;
462 | if(!$this->_transaction_in_progress ) {
463 | $this->defConnectionName = 'default';
464 | }
465 | $this->autoReconnectCount = 0;
466 | return $this;
467 | }
468 |
469 | /**
470 | * Helper function to create dbObject with JSON return type
471 | *
472 | * @return MysqliDb
473 | */
474 | public function jsonBuilder()
475 | {
476 | $this->returnType = 'json';
477 | return $this;
478 | }
479 |
480 | /**
481 | * Helper function to create dbObject with array return type
482 | * Added for consistency as that's default output type
483 | *
484 | * @return MysqliDb
485 | */
486 | public function arrayBuilder()
487 | {
488 | $this->returnType = 'array';
489 | return $this;
490 | }
491 |
492 | /**
493 | * Helper function to create dbObject with object return type.
494 | *
495 | * @return MysqliDb
496 | */
497 | public function objectBuilder()
498 | {
499 | $this->returnType = 'object';
500 | return $this;
501 | }
502 |
503 | /**
504 | * Method to set a prefix
505 | *
506 | * @param string $prefix Contains a table prefix
507 | *
508 | * @return MysqliDb
509 | */
510 | public function setPrefix($prefix = '')
511 | {
512 | self::$prefix = $prefix;
513 | return $this;
514 | }
515 |
516 | /**
517 | * Pushes a unprepared statement to the mysqli stack.
518 | * WARNING: Use with caution.
519 | * This method does not escape strings by default so make sure you'll never use it in production.
520 | *
521 | * @author Jonas Barascu
522 | *
523 | * @param [[Type]] $query [[Description]]
524 | *
525 | * @return bool|mysqli_result
526 | * @throws Exception
527 | */
528 | private function queryUnprepared($query)
529 | {
530 | // Execute query
531 | $stmt = $this->mysqli()->query($query);
532 |
533 | // Failed?
534 | if ($stmt !== false)
535 | return $stmt;
536 |
537 | if ($this->mysqli()->errno === 2006 && $this->autoReconnect === true && $this->autoReconnectCount === 0) {
538 | $this->connect($this->defConnectionName);
539 | $this->autoReconnectCount++;
540 | return $this->queryUnprepared($query);
541 | }
542 |
543 | throw new Exception(sprintf('Unprepared Query Failed, ERRNO: %u (%s)', $this->mysqli()->errno, $this->mysqli()->error), $this->mysqli()->errno);
544 | }
545 |
546 | /**
547 | * Prefix add raw SQL query.
548 | *
549 | * @author Emre Emir
550 | * @param string $query User-provided query to execute.
551 | * @return string Contains the returned rows from the query.
552 | */
553 | public function rawAddPrefix($query){
554 | $query = str_replace(PHP_EOL, '', $query);
555 | $query = preg_replace('/\s+/', ' ', $query);
556 | preg_match_all("/(from|into|update|join|describe) [\\'\\´\\`]?([a-zA-Z0-9_-]+)[\\'\\´\\`]?/i", $query, $matches);
557 | list($from_table, $from, $table) = $matches;
558 |
559 | // Check if there are matches
560 | if (empty($table[0]))
561 | return $query;
562 |
563 | return str_replace($table[0], self::$prefix.$table[0], $query);
564 | }
565 |
566 | /**
567 | * Execute raw SQL query.
568 | *
569 | * @param string $query User-provided query to execute.
570 | * @param array $bindParams Variables array to bind to the SQL statement.
571 | *
572 | * @return array Contains the returned rows from the query.
573 | * @throws Exception
574 | */
575 | public function rawQuery($query, $bindParams = null)
576 | {
577 | $query = $this->rawAddPrefix($query);
578 | $params = array(''); // Create the empty 0 index
579 | $this->_query = $query;
580 | $stmt = $this->_prepareQuery();
581 |
582 | if (is_array($bindParams) === true) {
583 | foreach ($bindParams as $prop => $val) {
584 | $params[0] .= $this->_determineType($val);
585 | array_push($params, $bindParams[$prop]);
586 | }
587 |
588 | call_user_func_array(array($stmt, 'bind_param'), $this->refValues($params));
589 | }
590 |
591 | $stmt->execute();
592 | $this->count = $stmt->affected_rows;
593 | $this->_stmtError = $stmt->error;
594 | $this->_stmtErrno = $stmt->errno;
595 | $this->_lastQuery = $this->replacePlaceHolders($this->_query, $params);
596 | $res = $this->_dynamicBindResults($stmt);
597 | $this->reset();
598 |
599 | return $res;
600 | }
601 |
602 | /**
603 | * Helper function to execute raw SQL query and return only 1 row of results.
604 | * Note that function do not add 'limit 1' to the query by itself
605 | * Same idea as getOne()
606 | *
607 | * @param string $query User-provided query to execute.
608 | * @param array $bindParams Variables array to bind to the SQL statement.
609 | *
610 | * @return array|null Contains the returned row from the query.
611 | * @throws Exception
612 | */
613 | public function rawQueryOne($query, $bindParams = null)
614 | {
615 | $res = $this->rawQuery($query, $bindParams);
616 | if (is_array($res) && isset($res[0])) {
617 | return $res[0];
618 | }
619 |
620 | return null;
621 | }
622 |
623 | /**
624 | * Helper function to execute raw SQL query and return only 1 column of results.
625 | * If 'limit 1' will be found, then string will be returned instead of array
626 | * Same idea as getValue()
627 | *
628 | * @param string $query User-provided query to execute.
629 | * @param array $bindParams Variables array to bind to the SQL statement.
630 | *
631 | * @return mixed Contains the returned rows from the query.
632 | * @throws Exception
633 | */
634 | public function rawQueryValue($query, $bindParams = null)
635 | {
636 | $res = $this->rawQuery($query, $bindParams);
637 | if (!$res) {
638 | return null;
639 | }
640 |
641 | $limit = preg_match('/limit\s+1;?$/i', $query);
642 | $key = key($res[0]);
643 | if (isset($res[0][$key]) && $limit == true) {
644 | return $res[0][$key];
645 | }
646 |
647 | $newRes = Array();
648 | for ($i = 0; $i < $this->count; $i++) {
649 | $newRes[] = $res[$i][$key];
650 | }
651 | return $newRes;
652 | }
653 |
654 | /**
655 | * A method to perform select query
656 | *
657 | * @param string $query Contains a user-provided select query.
658 | * @param int|array $numRows Array to define SQL limit in format Array ($offset, $count)
659 | *
660 | * @return array Contains the returned rows from the query.
661 | * @throws Exception
662 | */
663 | public function query($query, $numRows = null)
664 | {
665 | $this->_query = $query;
666 | $stmt = $this->_buildQuery($numRows);
667 | $stmt->execute();
668 | $this->_stmtError = $stmt->error;
669 | $this->_stmtErrno = $stmt->errno;
670 | $res = $this->_dynamicBindResults($stmt);
671 | $this->reset();
672 |
673 | return $res;
674 | }
675 |
676 | /**
677 | * This method allows you to specify multiple (method chaining optional) options for SQL queries.
678 | *
679 | * @uses $MySqliDb->setQueryOption('name');
680 | *
681 | * @param string|array $options The options name of the query.
682 | *
683 | * @throws Exception
684 | * @return MysqliDb
685 | */
686 | public function setQueryOption($options)
687 | {
688 | $allowedOptions = Array('ALL', 'DISTINCT', 'DISTINCTROW', 'HIGH_PRIORITY', 'STRAIGHT_JOIN', 'SQL_SMALL_RESULT',
689 | 'SQL_BIG_RESULT', 'SQL_BUFFER_RESULT', 'SQL_CACHE', 'SQL_NO_CACHE', 'SQL_CALC_FOUND_ROWS',
690 | 'LOW_PRIORITY', 'IGNORE', 'QUICK', 'MYSQLI_NESTJOIN', 'FOR UPDATE', 'LOCK IN SHARE MODE');
691 |
692 | if (!is_array($options)) {
693 | $options = Array($options);
694 | }
695 |
696 | foreach ($options as $option) {
697 | $option = strtoupper($option);
698 | if (!in_array($option, $allowedOptions)) {
699 | throw new Exception('Wrong query option: ' . $option);
700 | }
701 |
702 | if ($option == 'MYSQLI_NESTJOIN') {
703 | $this->_nestJoin = true;
704 | } elseif ($option == 'FOR UPDATE') {
705 | $this->_forUpdate = true;
706 | } elseif ($option == 'LOCK IN SHARE MODE') {
707 | $this->_lockInShareMode = true;
708 | } else {
709 | $this->_queryOptions[] = $option;
710 | }
711 | }
712 |
713 | return $this;
714 | }
715 |
716 | /**
717 | * Function to enable SQL_CALC_FOUND_ROWS in the get queries
718 | *
719 | * @return MysqliDb
720 | * @throws Exception
721 | */
722 | public function withTotalCount()
723 | {
724 | $this->setQueryOption('SQL_CALC_FOUND_ROWS');
725 | return $this;
726 | }
727 |
728 | /**
729 | * A convenient SELECT * function.
730 | *
731 | * @param string $tableName The name of the database table to work with.
732 | * @param int|array $numRows Array to define SQL limit in format Array ($offset, $count)
733 | * or only $count
734 | * @param string|array $columns Desired columns
735 | *
736 | * @return array|MysqliDb Contains the returned rows from the select query.
737 | * @throws Exception
738 | */
739 | public function get($tableName, $numRows = null, $columns = '*')
740 | {
741 | if (empty($columns)) {
742 | $columns = '*';
743 | }
744 |
745 | $column = is_array($columns) ? implode(', ', $columns) : $columns;
746 |
747 | if (strpos($tableName, '.') === false) {
748 | $this->_tableName = self::$prefix . $tableName;
749 | } else {
750 | $this->_tableName = $tableName;
751 | }
752 |
753 | $this->_query = 'SELECT ' . implode(' ', $this->_queryOptions) . ' ' .
754 | $column . " FROM " . $this->_tableName;
755 | $stmt = $this->_buildQuery($numRows);
756 |
757 | if ($this->isSubQuery) {
758 | return $this;
759 | }
760 |
761 | $stmt->execute();
762 | $this->_stmtError = $stmt->error;
763 | $this->_stmtErrno = $stmt->errno;
764 | $res = $this->_dynamicBindResults($stmt);
765 | $this->reset();
766 |
767 | return $res;
768 | }
769 |
770 | /**
771 | * A convenient SELECT * function to get one record.
772 | *
773 | * @param string $tableName The name of the database table to work with.
774 | * @param string|array $columns Desired columns
775 | *
776 | * @return array Contains the returned rows from the select query.
777 | * @throws Exception
778 | */
779 | public function getOne($tableName, $columns = '*')
780 | {
781 | $res = $this->get($tableName, 1, $columns);
782 |
783 | if ($res instanceof MysqliDb) {
784 | return $res;
785 | } elseif (is_array($res) && isset($res[0])) {
786 | return $res[0];
787 | } elseif ($res) {
788 | return $res;
789 | }
790 |
791 | return null;
792 | }
793 |
794 | /**
795 | * A convenient SELECT COLUMN function to get a single column value from one row
796 | *
797 | * @param string $tableName The name of the database table to work with.
798 | * @param string $column The desired column
799 | * @param int|null $limit Limit of rows to select. Use null for unlimited. 1 by default
800 | *
801 | * @return mixed Contains the value of a returned column / array of values
802 | * @throws Exception
803 | */
804 | public function getValue($tableName, $column, $limit = 1)
805 | {
806 | $res = $this->ArrayBuilder()->get($tableName, $limit, "{$column} AS retval");
807 |
808 | if (!$res) {
809 | return null;
810 | }
811 |
812 | if ($limit == 1) {
813 | if (isset($res[0]["retval"])) {
814 | return $res[0]["retval"];
815 | }
816 | return null;
817 | }
818 |
819 | $newRes = Array();
820 | for ($i = 0; $i < $this->count; $i++) {
821 | $newRes[] = $res[$i]['retval'];
822 | }
823 | return $newRes;
824 | }
825 |
826 | /**
827 | * Insert method to add new row
828 | *
829 | * @param string $tableName The name of the table.
830 | * @param array $insertData Data containing information for inserting into the DB.
831 | *
832 | * @return bool Boolean indicating whether the insert query was completed successfully.
833 | * @throws Exception
834 | */
835 | public function insert($tableName, $insertData)
836 | {
837 | return $this->_buildInsert($tableName, $insertData, 'INSERT');
838 | }
839 |
840 | /**
841 | * Insert method to add several rows at once
842 | *
843 | * @param string $tableName The name of the table.
844 | * @param array $multiInsertData Two-dimensional Data-array containing information for inserting into the DB.
845 | * @param array $dataKeys Optional Table Key names, if not set in insertDataSet.
846 | *
847 | * @return bool|array Boolean indicating the insertion failed (false), else return id-array ([int])
848 | * @throws Exception
849 | */
850 | public function insertMulti($tableName, array $multiInsertData, array $dataKeys = null)
851 | {
852 | // only auto-commit our inserts, if no transaction is currently running
853 | $autoCommit = (isset($this->_transaction_in_progress) ? !$this->_transaction_in_progress : true);
854 | $ids = array();
855 |
856 | if($autoCommit) {
857 | $this->startTransaction();
858 | }
859 |
860 | foreach ($multiInsertData as $insertData) {
861 | if($dataKeys !== null) {
862 | // apply column-names if given, else assume they're already given in the data
863 | $insertData = array_combine($dataKeys, $insertData);
864 | }
865 |
866 | $id = $this->insert($tableName, $insertData);
867 | if(!$id) {
868 | if($autoCommit) {
869 | $this->rollback();
870 | }
871 | return false;
872 | }
873 | $ids[] = $id;
874 | }
875 |
876 | if($autoCommit) {
877 | $this->commit();
878 | }
879 |
880 | return $ids;
881 | }
882 |
883 | /**
884 | * Replace method to add new row
885 | *
886 | * @param string $tableName The name of the table.
887 | * @param array $insertData Data containing information for inserting into the DB.
888 | *
889 | * @return bool Boolean indicating whether the insert query was completed successfully.
890 | * @throws Exception
891 | */
892 | public function replace($tableName, $insertData)
893 | {
894 | return $this->_buildInsert($tableName, $insertData, 'REPLACE');
895 | }
896 |
897 | /**
898 | * A convenient function that returns TRUE if exists at least an element that
899 | * satisfy the where condition specified calling the "where" method before this one.
900 | *
901 | * @param string $tableName The name of the database table to work with.
902 | *
903 | * @return bool
904 | * @throws Exception
905 | */
906 | public function has($tableName)
907 | {
908 | $this->getOne($tableName, '1');
909 | return $this->count >= 1;
910 | }
911 |
912 | /**
913 | * Update query. Be sure to first call the "where" method.
914 | *
915 | * @param string $tableName The name of the database table to work with.
916 | * @param array $tableData Array of data to update the desired row.
917 | * @param int $numRows Limit on the number of rows that can be updated.
918 | *
919 | * @return bool
920 | * @throws Exception
921 | */
922 | public function update($tableName, $tableData, $numRows = null)
923 | {
924 | if ($this->isSubQuery) {
925 | return;
926 | }
927 |
928 | $this->_query = "UPDATE " . self::$prefix . $tableName;
929 |
930 | $stmt = $this->_buildQuery($numRows, $tableData);
931 | $status = $stmt->execute();
932 | $this->reset();
933 | $this->_stmtError = $stmt->error;
934 | $this->_stmtErrno = $stmt->errno;
935 | $this->count = $stmt->affected_rows;
936 |
937 | return $status;
938 | }
939 |
940 | /**
941 | * Delete query. Call the "where" method first.
942 | *
943 | * @param string $tableName The name of the database table to work with.
944 | * @param int|array $numRows Array to define SQL limit in format Array ($offset, $count)
945 | * or only $count
946 | *
947 | * @return bool Indicates success. 0 or 1.
948 | * @throws Exception
949 | */
950 | public function delete($tableName, $numRows = null)
951 | {
952 | if ($this->isSubQuery) {
953 | return;
954 | }
955 |
956 | $table = self::$prefix . $tableName;
957 |
958 | if (count($this->_join)) {
959 | $this->_query = "DELETE " . preg_replace('/.* (.*)/', '$1', $table) . " FROM " . $table;
960 | } else {
961 | $this->_query = "DELETE FROM " . $table;
962 | }
963 |
964 | $stmt = $this->_buildQuery($numRows);
965 | $stmt->execute();
966 | $this->_stmtError = $stmt->error;
967 | $this->_stmtErrno = $stmt->errno;
968 | $this->count = $stmt->affected_rows;
969 | $this->reset();
970 |
971 | return ($stmt->affected_rows > -1); // -1 indicates that the query returned an error
972 | }
973 |
974 | /**
975 | * This method allows you to specify multiple (method chaining optional) AND WHERE statements for SQL queries.
976 | *
977 | * @uses $MySqliDb->where('id', 7)->where('title', 'MyTitle');
978 | *
979 | * @param string $whereProp The name of the database field.
980 | * @param mixed $whereValue The value of the database field.
981 | * @param string $operator Comparison operator. Default is =
982 | * @param string $cond Condition of where statement (OR, AND)
983 | *
984 | * @return MysqliDb
985 | */
986 | public function where($whereProp, $whereValue = 'DBNULL', $operator = '=', $cond = 'AND')
987 | {
988 | if (count($this->_where) == 0) {
989 | $cond = '';
990 | }
991 |
992 | $this->_where[] = array($cond, $whereProp, $operator, $whereValue);
993 | return $this;
994 | }
995 |
996 | /**
997 | * This function store update column's name and column name of the
998 | * autoincrement column
999 | *
1000 | * @param array $updateColumns Variable with values
1001 | * @param string $lastInsertId Variable value
1002 | *
1003 | * @return MysqliDb
1004 | */
1005 | public function onDuplicate($updateColumns, $lastInsertId = null)
1006 | {
1007 | $this->_lastInsertId = $lastInsertId;
1008 | $this->_updateColumns = $updateColumns;
1009 | return $this;
1010 | }
1011 |
1012 | /**
1013 | * This method allows you to specify multiple (method chaining optional) OR WHERE statements for SQL queries.
1014 | *
1015 | * @uses $MySqliDb->orWhere('id', 7)->orWhere('title', 'MyTitle');
1016 | *
1017 | * @param string $whereProp The name of the database field.
1018 | * @param mixed $whereValue The value of the database field.
1019 | * @param string $operator Comparison operator. Default is =
1020 | *
1021 | * @return MysqliDb
1022 | */
1023 | public function orWhere($whereProp, $whereValue = 'DBNULL', $operator = '=')
1024 | {
1025 | return $this->where($whereProp, $whereValue, $operator, 'OR');
1026 | }
1027 |
1028 | /**
1029 | * This method allows you to specify multiple (method chaining optional) AND HAVING statements for SQL queries.
1030 | *
1031 | * @uses $MySqliDb->having('SUM(tags) > 10')
1032 | *
1033 | * @param string $havingProp The name of the database field.
1034 | * @param mixed $havingValue The value of the database field.
1035 | * @param string $operator Comparison operator. Default is =
1036 | *
1037 | * @param string $cond
1038 | *
1039 | * @return MysqliDb
1040 | */
1041 |
1042 | public function having($havingProp, $havingValue = 'DBNULL', $operator = '=', $cond = 'AND')
1043 | {
1044 | // forkaround for an old operation api
1045 | if (is_array($havingValue) && ($key = key($havingValue)) != "0") {
1046 | $operator = $key;
1047 | $havingValue = $havingValue[$key];
1048 | }
1049 |
1050 | if (count($this->_having) == 0) {
1051 | $cond = '';
1052 | }
1053 |
1054 | $this->_having[] = array($cond, $havingProp, $operator, $havingValue);
1055 | return $this;
1056 | }
1057 |
1058 | /**
1059 | * This method allows you to specify multiple (method chaining optional) OR HAVING statements for SQL queries.
1060 | *
1061 | * @uses $MySqliDb->orHaving('SUM(tags) > 10')
1062 | *
1063 | * @param string $havingProp The name of the database field.
1064 | * @param mixed $havingValue The value of the database field.
1065 | * @param string $operator Comparison operator. Default is =
1066 | *
1067 | * @return MysqliDb
1068 | */
1069 | public function orHaving($havingProp, $havingValue = null, $operator = null)
1070 | {
1071 | return $this->having($havingProp, $havingValue, $operator, 'OR');
1072 | }
1073 |
1074 | /**
1075 | * This method allows you to concatenate joins for the final SQL statement.
1076 | *
1077 | * @uses $MySqliDb->join('table1', 'field1 <> field2', 'LEFT')
1078 | *
1079 | * @param string $joinTable The name of the table.
1080 | * @param string $joinCondition the condition.
1081 | * @param string $joinType 'LEFT', 'INNER' etc.
1082 | *
1083 | * @throws Exception
1084 | * @return MysqliDb
1085 | */
1086 | public function join($joinTable, $joinCondition, $joinType = '')
1087 | {
1088 | $allowedTypes = array('LEFT', 'RIGHT', 'OUTER', 'INNER', 'LEFT OUTER', 'RIGHT OUTER', 'NATURAL');
1089 | $joinType = strtoupper(trim($joinType));
1090 |
1091 | if ($joinType && !in_array($joinType, $allowedTypes)) {
1092 | throw new Exception('Wrong JOIN type: ' . $joinType);
1093 | }
1094 |
1095 | if (!is_object($joinTable)) {
1096 | $joinTable = self::$prefix . $joinTable;
1097 | }
1098 |
1099 | $this->_join[] = Array($joinType, $joinTable, $joinCondition);
1100 |
1101 | return $this;
1102 | }
1103 |
1104 |
1105 | /**
1106 | * This is a basic method which allows you to import raw .CSV data into a table
1107 | * Please check out http://dev.mysql.com/doc/refman/5.7/en/load-data.html for a valid .csv file.
1108 | *
1109 | * @author Jonas Barascu (Noneatme)
1110 | *
1111 | * @param string $importTable The database table where the data will be imported into.
1112 | * @param string $importFile The file to be imported. Please use double backslashes \\ and make sure you
1113 | * @param string $importSettings An Array defining the import settings as described in the README.md
1114 | *
1115 | * @return boolean
1116 | * @throws Exception
1117 | */
1118 | public function loadData($importTable, $importFile, $importSettings = null)
1119 | {
1120 | // We have to check if the file exists
1121 | if (!file_exists($importFile)) {
1122 | // Throw an exception
1123 | throw new Exception("importCSV -> importFile " . $importFile . " does not exists!");
1124 | }
1125 |
1126 | // Define the default values
1127 | // We will merge it later
1128 | $settings = Array("fieldChar" => ';', "lineChar" => PHP_EOL, "linesToIgnore" => 1);
1129 |
1130 | // Check the import settings
1131 | if (gettype($importSettings) == "array") {
1132 | // Merge the default array with the custom one
1133 | $settings = array_merge($settings, $importSettings);
1134 | }
1135 |
1136 | // Add the prefix to the import table
1137 | $table = self::$prefix . $importTable;
1138 |
1139 | // Add 1 more slash to every slash so maria will interpret it as a path
1140 | $importFile = str_replace("\\", "\\\\", $importFile);
1141 |
1142 | // Switch between LOAD DATA and LOAD DATA LOCAL
1143 | $loadDataLocal = isset($settings["loadDataLocal"]) ? 'LOCAL' : '';
1144 |
1145 | // Build SQL Syntax
1146 | $sqlSyntax = sprintf('LOAD DATA %s INFILE \'%s\' INTO TABLE %s',
1147 | $loadDataLocal, $importFile, $table);
1148 |
1149 | // FIELDS
1150 | $sqlSyntax .= sprintf(' FIELDS TERMINATED BY \'%s\'', $settings["fieldChar"]);
1151 | if (isset($settings["fieldEnclosure"])) {
1152 | $sqlSyntax .= sprintf(' ENCLOSED BY \'%s\'', $settings["fieldEnclosure"]);
1153 | }
1154 |
1155 | // LINES
1156 | $sqlSyntax .= sprintf(' LINES TERMINATED BY \'%s\'', $settings["lineChar"]);
1157 | if (isset($settings["lineStarting"])) {
1158 | $sqlSyntax .= sprintf(' STARTING BY \'%s\'', $settings["lineStarting"]);
1159 | }
1160 |
1161 | // IGNORE LINES
1162 | $sqlSyntax .= sprintf(' IGNORE %d LINES', $settings["linesToIgnore"]);
1163 |
1164 | // Execute the query unprepared because LOAD DATA only works with unprepared statements.
1165 | $result = $this->queryUnprepared($sqlSyntax);
1166 |
1167 | // Are there rows modified?
1168 | // Let the user know if the import failed / succeeded
1169 | return (bool) $result;
1170 | }
1171 |
1172 | /**
1173 | * This method is useful for importing XML files into a specific table.
1174 | * Check out the LOAD XML syntax for your MySQL server.
1175 | *
1176 | * @author Jonas Barascu
1177 | *
1178 | * @param string $importTable The table in which the data will be imported to.
1179 | * @param string $importFile The file which contains the .XML data.
1180 | * @param string $importSettings An Array defining the import settings as described in the README.md
1181 | *
1182 | * @return boolean Returns true if the import succeeded, false if it failed.
1183 | * @throws Exception
1184 | */
1185 | public function loadXml($importTable, $importFile, $importSettings = null)
1186 | {
1187 | // We have to check if the file exists
1188 | if(!file_exists($importFile)) {
1189 | // Does not exists
1190 | throw new Exception("loadXml: Import file does not exists");
1191 | return;
1192 | }
1193 |
1194 | // Create default values
1195 | $settings = Array("linesToIgnore" => 0);
1196 |
1197 | // Check the import settings
1198 | if(gettype($importSettings) == "array") {
1199 | $settings = array_merge($settings, $importSettings);
1200 | }
1201 |
1202 | // Add the prefix to the import table
1203 | $table = self::$prefix . $importTable;
1204 |
1205 | // Add 1 more slash to every slash so maria will interpret it as a path
1206 | $importFile = str_replace("\\", "\\\\", $importFile);
1207 |
1208 | // Build SQL Syntax
1209 | $sqlSyntax = sprintf('LOAD XML INFILE \'%s\' INTO TABLE %s',
1210 | $importFile, $table);
1211 |
1212 | // FIELDS
1213 | if(isset($settings["rowTag"])) {
1214 | $sqlSyntax .= sprintf(' ROWS IDENTIFIED BY \'%s\'', $settings["rowTag"]);
1215 | }
1216 |
1217 | // IGNORE LINES
1218 | $sqlSyntax .= sprintf(' IGNORE %d LINES', $settings["linesToIgnore"]);
1219 |
1220 | // Exceute the query unprepared because LOAD XML only works with unprepared statements.
1221 | $result = $this->queryUnprepared($sqlSyntax);
1222 |
1223 | // Are there rows modified?
1224 | // Let the user know if the import failed / succeeded
1225 | return (bool) $result;
1226 | }
1227 |
1228 | /**
1229 | * This method allows you to specify multiple (method chaining optional) ORDER BY statements for SQL queries.
1230 | *
1231 | * @uses $MySqliDb->orderBy('id', 'desc')->orderBy('name', 'desc', '^[a-z]')->orderBy('name', 'desc');
1232 | *
1233 | * @param string $orderByField The name of the database field.
1234 | * @param string $orderbyDirection
1235 | * @param mixed $customFieldsOrRegExp Array with fieldset for ORDER BY FIELD() ordering or string with regular expression for ORDER BY REGEXP ordering
1236 | *
1237 | * @return MysqliDb
1238 | * @throws Exception
1239 | */
1240 | public function orderBy($orderByField, $orderbyDirection = "DESC", $customFieldsOrRegExp = null)
1241 | {
1242 | $allowedDirection = Array("ASC", "DESC");
1243 | $orderbyDirection = strtoupper(trim($orderbyDirection));
1244 | $orderByField = preg_replace("/[^ -a-z0-9\.\(\),_`\*\'\"]+/i", '', $orderByField);
1245 |
1246 | // Add table prefix to orderByField if needed.
1247 | //FIXME: We are adding prefix only if table is enclosed into `` to distinguish aliases
1248 | // from table names
1249 | $orderByField = preg_replace('/(\`)([`a-zA-Z0-9_]*\.)/', '\1' . self::$prefix . '\2', $orderByField);
1250 |
1251 |
1252 | if (empty($orderbyDirection) || !in_array($orderbyDirection, $allowedDirection)) {
1253 | throw new Exception('Wrong order direction: ' . $orderbyDirection);
1254 | }
1255 |
1256 | if (is_array($customFieldsOrRegExp)) {
1257 | foreach ($customFieldsOrRegExp as $key => $value) {
1258 | $customFieldsOrRegExp[$key] = preg_replace("/[^\x80-\xff-a-z0-9\.\(\),_` ]+/i", '', $value);
1259 | }
1260 | $orderByField = 'FIELD (' . $orderByField . ', "' . implode('","', $customFieldsOrRegExp) . '")';
1261 | }elseif(is_string($customFieldsOrRegExp)){
1262 | $orderByField = $orderByField . " REGEXP '" . $customFieldsOrRegExp . "'";
1263 | }elseif($customFieldsOrRegExp !== null){
1264 | throw new Exception('Wrong custom field or Regular Expression: ' . $customFieldsOrRegExp);
1265 | }
1266 |
1267 | $this->_orderBy[$orderByField] = $orderbyDirection;
1268 | return $this;
1269 | }
1270 |
1271 | /**
1272 | * This method allows you to specify multiple (method chaining optional) GROUP BY statements for SQL queries.
1273 | *
1274 | * @uses $MySqliDb->groupBy('name');
1275 | *
1276 | * @param string $groupByField The name of the database field.
1277 | *
1278 | * @return MysqliDb
1279 | */
1280 | public function groupBy($groupByField)
1281 | {
1282 | $groupByField = preg_replace("/[^-a-z0-9\.\(\),_\* <>=!]+/i", '', $groupByField);
1283 |
1284 | $this->_groupBy[] = $groupByField;
1285 | return $this;
1286 | }
1287 |
1288 |
1289 | /**
1290 | * This method sets the current table lock method.
1291 | *
1292 | * @author Jonas Barascu
1293 | *
1294 | * @param string $method The table lock method. Can be READ or WRITE.
1295 | *
1296 | * @throws Exception
1297 | * @return MysqliDb
1298 | */
1299 | public function setLockMethod($method)
1300 | {
1301 | // Switch the uppercase string
1302 | switch(strtoupper($method)) {
1303 | // Is it READ or WRITE?
1304 | case "READ" || "WRITE":
1305 | // Succeed
1306 | $this->_tableLockMethod = $method;
1307 | break;
1308 | default:
1309 | // Else throw an exception
1310 | throw new Exception("Bad lock type: Can be either READ or WRITE");
1311 | break;
1312 | }
1313 | return $this;
1314 | }
1315 |
1316 | /**
1317 | * Locks a table for R/W action.
1318 | *
1319 | * @author Jonas Barascu
1320 | *
1321 | * @param string|array $table The table to be locked. Can be a table or a view.
1322 | *
1323 | * @return bool if succeeded;
1324 | * @throws Exception
1325 | */
1326 | public function lock($table)
1327 | {
1328 | // Main Query
1329 | $this->_query = "LOCK TABLES";
1330 |
1331 | // Is the table an array?
1332 | if(gettype($table) == "array") {
1333 | // Loop trough it and attach it to the query
1334 | foreach($table as $key => $value) {
1335 | if(gettype($value) == "string") {
1336 | if($key > 0) {
1337 | $this->_query .= ",";
1338 | }
1339 | $this->_query .= " ".self::$prefix.$value." ".$this->_tableLockMethod;
1340 | }
1341 | }
1342 | }
1343 | else{
1344 | // Build the table prefix
1345 | $table = self::$prefix . $table;
1346 |
1347 | // Build the query
1348 | $this->_query = "LOCK TABLES ".$table." ".$this->_tableLockMethod;
1349 | }
1350 |
1351 | // Execute the query unprepared because LOCK only works with unprepared statements.
1352 | $result = $this->queryUnprepared($this->_query);
1353 | $errno = $this->mysqli()->errno;
1354 |
1355 | // Reset the query
1356 | $this->reset();
1357 |
1358 | // Are there rows modified?
1359 | if($result) {
1360 | // Return true
1361 | // We can't return ourself because if one table gets locked, all other ones get unlocked!
1362 | return true;
1363 | }
1364 | // Something went wrong
1365 | else {
1366 | throw new Exception("Locking of table ".$table." failed", $errno);
1367 | }
1368 |
1369 | // Return the success value
1370 | return false;
1371 | }
1372 |
1373 | /**
1374 | * Unlocks all tables in a database.
1375 | * Also commits transactions.
1376 | *
1377 | * @author Jonas Barascu
1378 | * @return MysqliDb
1379 | * @throws Exception
1380 | */
1381 | public function unlock()
1382 | {
1383 | // Build the query
1384 | $this->_query = "UNLOCK TABLES";
1385 |
1386 | // Execute the query unprepared because UNLOCK and LOCK only works with unprepared statements.
1387 | $result = $this->queryUnprepared($this->_query);
1388 | $errno = $this->mysqli()->errno;
1389 |
1390 | // Reset the query
1391 | $this->reset();
1392 |
1393 | // Are there rows modified?
1394 | if($result) {
1395 | // return self
1396 | return $this;
1397 | }
1398 | // Something went wrong
1399 | else {
1400 | throw new Exception("Unlocking of tables failed", $errno);
1401 | }
1402 |
1403 |
1404 | // Return self
1405 | return $this;
1406 | }
1407 |
1408 |
1409 | /**
1410 | * This methods returns the ID of the last inserted item
1411 | *
1412 | * @return int The last inserted item ID.
1413 | * @throws Exception
1414 | */
1415 | public function getInsertId()
1416 | {
1417 | return $this->mysqli()->insert_id;
1418 | }
1419 |
1420 | /**
1421 | * Escape harmful characters which might affect a query.
1422 | *
1423 | * @param string $str The string to escape.
1424 | *
1425 | * @return string The escaped string.
1426 | * @throws Exception
1427 | */
1428 | public function escape($str)
1429 | {
1430 | return $this->mysqli()->real_escape_string($str);
1431 | }
1432 |
1433 | /**
1434 | * Method to call mysqli->ping() to keep unused connections open on
1435 | * long-running scripts, or to reconnect timed out connections (if php.ini has
1436 | * global mysqli.reconnect set to true). Can't do this directly using object
1437 | * since _mysqli is protected.
1438 | *
1439 | * @return bool True if connection is up
1440 | * @throws Exception
1441 | */
1442 | public function ping()
1443 | {
1444 | return $this->mysqli()->ping();
1445 | }
1446 |
1447 | /**
1448 | * This method is needed for prepared statements. They require
1449 | * the data type of the field to be bound with "i" s", etc.
1450 | * This function takes the input, determines what type it is,
1451 | * and then updates the param_type.
1452 | *
1453 | * @param mixed $item Input to determine the type.
1454 | *
1455 | * @return string The joined parameter types.
1456 | */
1457 | protected function _determineType($item)
1458 | {
1459 | switch (gettype($item)) {
1460 | case 'NULL':
1461 | case 'string':
1462 | return 's';
1463 | break;
1464 |
1465 | case 'boolean':
1466 | case 'integer':
1467 | return 'i';
1468 | break;
1469 |
1470 | case 'blob':
1471 | return 'b';
1472 | break;
1473 |
1474 | case 'double':
1475 | return 'd';
1476 | break;
1477 | }
1478 | return '';
1479 | }
1480 |
1481 | /**
1482 | * Helper function to add variables into bind parameters array
1483 | *
1484 | * @param string Variable value
1485 | */
1486 | protected function _bindParam($value)
1487 | {
1488 | $this->_bindParams[0] .= $this->_determineType($value);
1489 | array_push($this->_bindParams, $value);
1490 | }
1491 |
1492 | /**
1493 | * Helper function to add variables into bind parameters array in bulk
1494 | *
1495 | * @param array $values Variable with values
1496 | */
1497 | protected function _bindParams($values)
1498 | {
1499 | foreach ($values as $value) {
1500 | $this->_bindParam($value);
1501 | }
1502 | }
1503 |
1504 | /**
1505 | * Helper function to add variables into bind parameters array and will return
1506 | * its SQL part of the query according to operator in ' $operator ?' or
1507 | * ' $operator ($subquery) ' formats
1508 | *
1509 | * @param string $operator
1510 | * @param mixed $value Variable with values
1511 | *
1512 | * @return string
1513 | */
1514 | protected function _buildPair($operator, $value)
1515 | {
1516 | if (!is_object($value)) {
1517 | $this->_bindParam($value);
1518 | return ' ' . $operator . ' ? ';
1519 | }
1520 |
1521 | $subQuery = $value->getSubQuery();
1522 | $this->_bindParams($subQuery['params']);
1523 |
1524 | return " " . $operator . " (" . $subQuery['query'] . ") " . $subQuery['alias'];
1525 | }
1526 |
1527 | /**
1528 | * Internal function to build and execute INSERT/REPLACE calls
1529 | *
1530 | * @param string $tableName The name of the table.
1531 | * @param array $insertData Data containing information for inserting into the DB.
1532 | * @param string $operation Type of operation (INSERT, REPLACE)
1533 | *
1534 | * @return bool Boolean indicating whether the insert query was completed successfully.
1535 | * @throws Exception
1536 | */
1537 | private function _buildInsert($tableName, $insertData, $operation)
1538 | {
1539 | if ($this->isSubQuery) {
1540 | return;
1541 | }
1542 |
1543 | $this->_query = $operation . " " . implode(' ', $this->_queryOptions) . " INTO " . self::$prefix . $tableName;
1544 | $stmt = $this->_buildQuery(null, $insertData);
1545 | $status = $stmt->execute();
1546 | $this->_stmtError = $stmt->error;
1547 | $this->_stmtErrno = $stmt->errno;
1548 | $haveOnDuplicate = !empty ($this->_updateColumns);
1549 | $this->reset();
1550 | $this->count = $stmt->affected_rows;
1551 |
1552 | if ($stmt->affected_rows < 1) {
1553 | // in case of onDuplicate() usage, if no rows were inserted
1554 | if ($status && $haveOnDuplicate) {
1555 | return true;
1556 | }
1557 | return false;
1558 | }
1559 |
1560 | if ($stmt->insert_id > 0) {
1561 | return $stmt->insert_id;
1562 | }
1563 |
1564 | return true;
1565 | }
1566 |
1567 | /**
1568 | * Abstraction method that will compile the WHERE statement,
1569 | * any passed update data, and the desired rows.
1570 | * It then builds the SQL query.
1571 | *
1572 | * @param int|array $numRows Array to define SQL limit in format Array ($offset, $count)
1573 | * or only $count
1574 | * @param array $tableData Should contain an array of data for updating the database.
1575 | *
1576 | * @return mysqli_stmt|bool Returns the $stmt object.
1577 | * @throws Exception
1578 | */
1579 | protected function _buildQuery($numRows = null, $tableData = null)
1580 | {
1581 | // $this->_buildJoinOld();
1582 | $this->_buildJoin();
1583 | $this->_buildInsertQuery($tableData);
1584 | $this->_buildCondition('WHERE', $this->_where);
1585 | $this->_buildGroupBy();
1586 | $this->_buildCondition('HAVING', $this->_having);
1587 | $this->_buildOrderBy();
1588 | $this->_buildLimit($numRows);
1589 | $this->_buildOnDuplicate($tableData);
1590 |
1591 | if ($this->_forUpdate) {
1592 | $this->_query .= ' FOR UPDATE';
1593 | }
1594 | if ($this->_lockInShareMode) {
1595 | $this->_query .= ' LOCK IN SHARE MODE';
1596 | }
1597 |
1598 | $this->_lastQuery = $this->replacePlaceHolders($this->_query, $this->_bindParams);
1599 |
1600 | if ($this->isSubQuery) {
1601 | return;
1602 | }
1603 |
1604 | // Prepare query
1605 | $stmt = $this->_prepareQuery();
1606 |
1607 | // Bind parameters to statement if any
1608 | if (count($this->_bindParams) > 1) {
1609 | call_user_func_array(array($stmt, 'bind_param'), $this->refValues($this->_bindParams));
1610 | }
1611 |
1612 | return $stmt;
1613 | }
1614 |
1615 | /**
1616 | * This helper method takes care of prepared statements' "bind_result method
1617 | * , when the number of variables to pass is unknown.
1618 | *
1619 | * @param mysqli_stmt $stmt Equal to the prepared statement object.
1620 | *
1621 | * @return array|string The results of the SQL fetch.
1622 | * @throws Exception
1623 | */
1624 | protected function _dynamicBindResults(mysqli_stmt $stmt)
1625 | {
1626 | $parameters = array();
1627 | $results = array();
1628 | /**
1629 | * @see http://php.net/manual/en/mysqli-result.fetch-fields.php
1630 | */
1631 | $mysqlLongType = 252;
1632 | $shouldStoreResult = false;
1633 |
1634 | $meta = $stmt->result_metadata();
1635 |
1636 | // if $meta is false yet sqlstate is true, there's no sql error but the query is
1637 | // most likely an update/insert/delete which doesn't produce any results
1638 | if (!$meta && $stmt->sqlstate)
1639 | return array();
1640 |
1641 | $row = array();
1642 | while ($field = $meta->fetch_field()) {
1643 | if ($field->type == $mysqlLongType) {
1644 | $shouldStoreResult = true;
1645 | }
1646 |
1647 | if ($this->_nestJoin && $field->table != $this->_tableName) {
1648 | $field->table = substr($field->table, strlen(self::$prefix));
1649 | $row[$field->table][$field->name] = null;
1650 | $parameters[] = & $row[$field->table][$field->name];
1651 | } else {
1652 | $row[$field->name] = null;
1653 | $parameters[] = & $row[$field->name];
1654 | }
1655 | }
1656 |
1657 | // avoid out of memory bug in php 5.2 and 5.3. Mysqli allocates lot of memory for long*
1658 | // and blob* types. So to avoid out of memory issues store_result is used
1659 | // https://github.com/joshcam/PHP-MySQLi-Database-Class/pull/119
1660 | if ($shouldStoreResult) {
1661 | $stmt->store_result();
1662 | }
1663 |
1664 | call_user_func_array(array($stmt, 'bind_result'), $parameters);
1665 |
1666 | $this->totalCount = 0;
1667 | $this->count = 0;
1668 |
1669 | while ($stmt->fetch()) {
1670 | if ($this->returnType == 'object') {
1671 | $result = new stdClass ();
1672 | foreach ($row as $key => $val) {
1673 | if (is_array($val)) {
1674 | $result->$key = new stdClass ();
1675 | foreach ($val as $k => $v) {
1676 | $result->$key->$k = $v;
1677 | }
1678 | } else {
1679 | $result->$key = $val;
1680 | }
1681 | }
1682 | } else {
1683 | $result = array();
1684 | foreach ($row as $key => $val) {
1685 | if (is_array($val)) {
1686 | foreach ($val as $k => $v) {
1687 | $result[$key][$k] = $v;
1688 | }
1689 | } else {
1690 | $result[$key] = $val;
1691 | }
1692 | }
1693 | }
1694 | $this->count++;
1695 | if ($this->_mapKey) {
1696 | if (count($row) < 3 && $this->returnType == 'object') {
1697 | $res = new ArrayIterator($result);
1698 | $res->seek($_res->count() - 1);
1699 | $results[$row[$this->_mapKey]] = $res->current();
1700 | }
1701 | else $results[$row[$this->_mapKey]] = count($row) > 2 ? $result : end($result);
1702 | } else {
1703 | array_push($results, $result);
1704 | }
1705 | }
1706 |
1707 | if ($shouldStoreResult) {
1708 | $stmt->free_result();
1709 | }
1710 |
1711 | $stmt->close();
1712 |
1713 | // stored procedures sometimes can return more then 1 resultset
1714 | if ($this->mysqli()->more_results()) {
1715 | $this->mysqli()->next_result();
1716 | }
1717 |
1718 | if (in_array('SQL_CALC_FOUND_ROWS', $this->_queryOptions)) {
1719 | $stmt = $this->mysqli()->query('SELECT FOUND_ROWS()');
1720 | $totalCount = $stmt->fetch_row();
1721 | $this->totalCount = $totalCount[0];
1722 | }
1723 |
1724 | if ($this->returnType == 'json') {
1725 | return json_encode($results);
1726 | }
1727 |
1728 | return $results;
1729 | }
1730 |
1731 | /**
1732 | * Abstraction method that will build an JOIN part of the query
1733 | *
1734 | * @return void
1735 | */
1736 | protected function _buildJoinOld()
1737 | {
1738 | if (empty($this->_join)) {
1739 | return;
1740 | }
1741 |
1742 | foreach ($this->_join as $data) {
1743 | list ($joinType, $joinTable, $joinCondition) = $data;
1744 |
1745 | if (is_object($joinTable)) {
1746 | $joinStr = $this->_buildPair("", $joinTable);
1747 | } else {
1748 | $joinStr = $joinTable;
1749 | }
1750 |
1751 | $this->_query .= " " . $joinType . " JOIN " . $joinStr .
1752 | (false !== stripos($joinCondition, 'using') ? " " : " on ")
1753 | . $joinCondition;
1754 | }
1755 | }
1756 |
1757 | /**
1758 | * Insert/Update query helper
1759 | *
1760 | * @param array $tableData
1761 | * @param array $tableColumns
1762 | * @param bool $isInsert INSERT operation flag
1763 | *
1764 | * @throws Exception
1765 | */
1766 | public function _buildDataPairs($tableData, $tableColumns, $isInsert)
1767 | {
1768 | foreach ($tableColumns as $column) {
1769 | $value = $tableData[$column];
1770 |
1771 | if (!$isInsert) {
1772 | if(strpos($column,'.')===false) {
1773 | $this->_query .= "`" . $column . "` = ";
1774 | } else {
1775 | $this->_query .= str_replace('.','.`',$column) . "` = ";
1776 | }
1777 | }
1778 |
1779 | // Subquery value
1780 | if ($value instanceof MysqliDb) {
1781 | $this->_query .= $this->_buildPair("", $value) . ", ";
1782 | continue;
1783 | }
1784 |
1785 | // Simple value
1786 | if (!is_array($value)) {
1787 | $this->_bindParam($value);
1788 | $this->_query .= '?, ';
1789 | continue;
1790 | }
1791 |
1792 | // Function value
1793 | $key = key($value);
1794 | $val = $value[$key];
1795 | switch ($key) {
1796 | case '[I]':
1797 | $this->_query .= $column . $val . ", ";
1798 | break;
1799 | case '[F]':
1800 | $this->_query .= $val[0] . ", ";
1801 | if (!empty($val[1])) {
1802 | $this->_bindParams($val[1]);
1803 | }
1804 | break;
1805 | case '[N]':
1806 | if ($val == null) {
1807 | $this->_query .= "!" . $column . ", ";
1808 | } else {
1809 | $this->_query .= "!" . $val . ", ";
1810 | }
1811 | break;
1812 | default:
1813 | throw new Exception("Wrong operation");
1814 | }
1815 | }
1816 | $this->_query = rtrim($this->_query, ', ');
1817 | }
1818 |
1819 | /**
1820 | * Helper function to add variables into the query statement
1821 | *
1822 | * @param array $tableData Variable with values
1823 | *
1824 | * @throws Exception
1825 | */
1826 | protected function _buildOnDuplicate($tableData)
1827 | {
1828 | if (is_array($this->_updateColumns) && !empty($this->_updateColumns)) {
1829 | $this->_query .= " ON DUPLICATE KEY UPDATE ";
1830 | if ($this->_lastInsertId) {
1831 | $this->_query .= $this->_lastInsertId . "=LAST_INSERT_ID (" . $this->_lastInsertId . "), ";
1832 | }
1833 |
1834 | foreach ($this->_updateColumns as $key => $val) {
1835 | // skip all params without a value
1836 | if (is_numeric($key)) {
1837 | $this->_updateColumns[$val] = '';
1838 | unset($this->_updateColumns[$key]);
1839 | } else {
1840 | $tableData[$key] = $val;
1841 | }
1842 | }
1843 | $this->_buildDataPairs($tableData, array_keys($this->_updateColumns), false);
1844 | }
1845 | }
1846 |
1847 | /**
1848 | * Abstraction method that will build an INSERT or UPDATE part of the query
1849 | *
1850 | * @param array $tableData
1851 | *
1852 | * @throws Exception
1853 | */
1854 | protected function _buildInsertQuery($tableData)
1855 | {
1856 | if (!is_array($tableData)) {
1857 | return;
1858 | }
1859 |
1860 | $isInsert = preg_match('/^[INSERT|REPLACE]/', $this->_query);
1861 | $dataColumns = array_keys($tableData);
1862 | if ($isInsert) {
1863 | if (isset ($dataColumns[0]))
1864 | $this->_query .= ' (`' . implode('`, `', $dataColumns) . '`) ';
1865 | $this->_query .= ' VALUES (';
1866 | } else {
1867 | $this->_query .= " SET ";
1868 | }
1869 |
1870 | $this->_buildDataPairs($tableData, $dataColumns, $isInsert);
1871 |
1872 | if ($isInsert) {
1873 | $this->_query .= ')';
1874 | }
1875 | }
1876 |
1877 | /**
1878 | * Abstraction method that will build the part of the WHERE conditions
1879 | *
1880 | * @param string $operator
1881 | * @param array $conditions
1882 | */
1883 | protected function _buildCondition($operator, &$conditions)
1884 | {
1885 | if (empty($conditions)) {
1886 | return;
1887 | }
1888 |
1889 | //Prepare the where portion of the query
1890 | $this->_query .= ' ' . $operator;
1891 |
1892 | foreach ($conditions as $cond) {
1893 | list ($concat, $varName, $operator, $val) = $cond;
1894 | $this->_query .= " " . $concat . " " . $varName;
1895 |
1896 | switch (strtolower($operator)) {
1897 | case 'not in':
1898 | case 'in':
1899 | $comparison = ' ' . $operator . ' (';
1900 | if (is_object($val)) {
1901 | $comparison .= $this->_buildPair("", $val);
1902 | } else {
1903 | foreach ($val as $v) {
1904 | $comparison .= ' ?,';
1905 | $this->_bindParam($v);
1906 | }
1907 | }
1908 | $this->_query .= rtrim($comparison, ',') . ' ) ';
1909 | break;
1910 | case 'not between':
1911 | case 'between':
1912 | $this->_query .= " $operator ? AND ? ";
1913 | $this->_bindParams($val);
1914 | break;
1915 | case 'not exists':
1916 | case 'exists':
1917 | $this->_query.= $operator . $this->_buildPair("", $val);
1918 | break;
1919 | default:
1920 | if (is_array($val)) {
1921 | $this->_bindParams($val);
1922 | } elseif ($val === null) {
1923 | $this->_query .= ' ' . $operator . " NULL";
1924 | } elseif ($val != 'DBNULL' || $val == '0') {
1925 | $this->_query .= $this->_buildPair($operator, $val);
1926 | }
1927 | }
1928 | }
1929 | }
1930 |
1931 | /**
1932 | * Abstraction method that will build the GROUP BY part of the WHERE statement
1933 | *
1934 | * @return void
1935 | */
1936 | protected function _buildGroupBy()
1937 | {
1938 | if (empty($this->_groupBy)) {
1939 | return;
1940 | }
1941 |
1942 | $this->_query .= " GROUP BY ";
1943 |
1944 | foreach ($this->_groupBy as $key => $value) {
1945 | $this->_query .= $value . ", ";
1946 | }
1947 |
1948 | $this->_query = rtrim($this->_query, ', ') . " ";
1949 | }
1950 |
1951 | /**
1952 | * Abstraction method that will build the LIMIT part of the WHERE statement
1953 | *
1954 | * @return void
1955 | */
1956 | protected function _buildOrderBy()
1957 | {
1958 | if (empty($this->_orderBy)) {
1959 | return;
1960 | }
1961 |
1962 | $this->_query .= " ORDER BY ";
1963 | foreach ($this->_orderBy as $prop => $value) {
1964 | if (strtolower(str_replace(" ", "", $prop)) == 'rand()') {
1965 | $this->_query .= "rand(), ";
1966 | } else {
1967 | $this->_query .= $prop . " " . $value . ", ";
1968 | }
1969 | }
1970 |
1971 | $this->_query = rtrim($this->_query, ', ') . " ";
1972 | }
1973 |
1974 | /**
1975 | * Abstraction method that will build the LIMIT part of the WHERE statement
1976 | *
1977 | * @param int|array $numRows Array to define SQL limit in format Array ($offset, $count)
1978 | * or only $count
1979 | *
1980 | * @return void
1981 | */
1982 | protected function _buildLimit($numRows)
1983 | {
1984 | if (!isset($numRows)) {
1985 | return;
1986 | }
1987 |
1988 | if (is_array($numRows)) {
1989 | $this->_query .= ' LIMIT ' . (int) $numRows[0] . ', ' . (int) $numRows[1];
1990 | } else {
1991 | $this->_query .= ' LIMIT ' . (int) $numRows;
1992 | }
1993 | }
1994 |
1995 | /**
1996 | * Method attempts to prepare the SQL query
1997 | * and throws an error if there was a problem.
1998 | *
1999 | * @return mysqli_stmt
2000 | * @throws Exception
2001 | */
2002 | protected function _prepareQuery()
2003 | {
2004 | $stmt = $this->mysqli()->prepare($this->_query);
2005 |
2006 | if ($stmt !== false) {
2007 | if ($this->traceEnabled)
2008 | $this->traceStartQ = microtime(true);
2009 | return $stmt;
2010 | }
2011 |
2012 | if ($this->mysqli()->errno === 2006 && $this->autoReconnect === true && $this->autoReconnectCount === 0) {
2013 | $this->connect($this->defConnectionName);
2014 | $this->autoReconnectCount++;
2015 | return $this->_prepareQuery();
2016 | }
2017 |
2018 | $error = $this->mysqli()->error;
2019 | $query = $this->_query;
2020 | $errno = $this->mysqli()->errno;
2021 | $this->reset();
2022 | throw new Exception(sprintf('%s query: %s', $error, $query), $errno);
2023 | }
2024 |
2025 | /**
2026 | * Referenced data array is required by mysqli since PHP 5.3+
2027 | *
2028 | * @param array $arr
2029 | *
2030 | * @return array
2031 | */
2032 | protected function refValues(array &$arr)
2033 | {
2034 | //Reference in the function arguments are required for HHVM to work
2035 | //https://github.com/facebook/hhvm/issues/5155
2036 | //Referenced data array is required by mysqli since PHP 5.3+
2037 | if (strnatcmp(phpversion(), '5.3') >= 0) {
2038 | $refs = array();
2039 | foreach ($arr as $key => $value) {
2040 | $refs[$key] = & $arr[$key];
2041 | }
2042 | return $refs;
2043 | }
2044 | return $arr;
2045 | }
2046 |
2047 | /**
2048 | * Function to replace ? with variables from bind variable
2049 | *
2050 | * @param string $str
2051 | * @param array $vals
2052 | *
2053 | * @return string
2054 | */
2055 | protected function replacePlaceHolders($str, $vals)
2056 | {
2057 | $i = 1;
2058 | $newStr = "";
2059 |
2060 | if (empty($vals)) {
2061 | return $str;
2062 | }
2063 |
2064 | while ($pos = strpos($str, "?")) {
2065 | $val = $vals[$i++];
2066 | if (is_object($val)) {
2067 | $val = '[object]';
2068 | }
2069 | if ($val === null) {
2070 | $val = 'NULL';
2071 | }
2072 | $newStr .= substr($str, 0, $pos) . "'" . $val . "'";
2073 | $str = substr($str, $pos + 1);
2074 | }
2075 | $newStr .= $str;
2076 | return $newStr;
2077 | }
2078 |
2079 | /**
2080 | * Method returns last executed query
2081 | *
2082 | * @return string
2083 | */
2084 | public function getLastQuery()
2085 | {
2086 | return $this->_lastQuery;
2087 | }
2088 |
2089 | /**
2090 | * Method returns mysql error
2091 | *
2092 | * @return string
2093 | * @throws Exception
2094 | */
2095 | public function getLastError()
2096 | {
2097 | if (!isset($this->_mysqli[$this->defConnectionName])) {
2098 | return "mysqli is null";
2099 | }
2100 | return trim($this->_stmtError . " " . $this->mysqli()->error);
2101 | }
2102 |
2103 | /**
2104 | * Method returns mysql error code
2105 | *
2106 | * @return int
2107 | */
2108 | public function getLastErrno() {
2109 | return $this->_stmtErrno;
2110 | }
2111 |
2112 | /**
2113 | * Mostly internal method to get query and its params out of subquery object
2114 | * after get() and getAll()
2115 | *
2116 | * @return array
2117 | */
2118 | public function getSubQuery()
2119 | {
2120 | if (!$this->isSubQuery) {
2121 | return null;
2122 | }
2123 |
2124 | array_shift($this->_bindParams);
2125 | $val = Array('query' => $this->_query,
2126 | 'params' => $this->_bindParams,
2127 | 'alias' => isset($this->connectionsSettings[$this->defConnectionName]) ? $this->connectionsSettings[$this->defConnectionName]['host'] : null
2128 | );
2129 | $this->reset();
2130 | return $val;
2131 | }
2132 |
2133 | /* Helper functions */
2134 |
2135 | /**
2136 | * Method returns generated interval function as a string
2137 | *
2138 | * @param string $diff interval in the formats:
2139 | * "1", "-1d" or "- 1 day" -- For interval - 1 day
2140 | * Supported intervals [s]econd, [m]inute, [h]hour, [d]day, [M]onth, [Y]ear
2141 | * Default null;
2142 | * @param string $func Initial date
2143 | *
2144 | * @return string
2145 | * @throws Exception
2146 | */
2147 | public function interval($diff, $func = "NOW()")
2148 | {
2149 | $types = Array("s" => "second", "m" => "minute", "h" => "hour", "d" => "day", "M" => "month", "Y" => "year");
2150 | $incr = '+';
2151 | $items = '';
2152 | $type = 'd';
2153 |
2154 | if ($diff && preg_match('/([+-]?) ?([0-9]+) ?([a-zA-Z]?)/', $diff, $matches)) {
2155 | if (!empty($matches[1])) {
2156 | $incr = $matches[1];
2157 | }
2158 |
2159 | if (!empty($matches[2])) {
2160 | $items = $matches[2];
2161 | }
2162 |
2163 | if (!empty($matches[3])) {
2164 | $type = $matches[3];
2165 | }
2166 |
2167 | if (!in_array($type, array_keys($types))) {
2168 | throw new Exception("invalid interval type in '{$diff}'");
2169 | }
2170 |
2171 | $func .= " " . $incr . " interval " . $items . " " . $types[$type] . " ";
2172 | }
2173 | return $func;
2174 | }
2175 |
2176 | /**
2177 | * Method returns generated interval function as an insert/update function
2178 | *
2179 | * @param string $diff interval in the formats:
2180 | * "1", "-1d" or "- 1 day" -- For interval - 1 day
2181 | * Supported intervals [s]econd, [m]inute, [h]hour, [d]day, [M]onth, [Y]ear
2182 | * Default null;
2183 | * @param string $func Initial date
2184 | *
2185 | * @return array
2186 | * @throws Exception
2187 | */
2188 | public function now($diff = null, $func = "NOW()")
2189 | {
2190 | return array("[F]" => Array($this->interval($diff, $func)));
2191 | }
2192 |
2193 | /**
2194 | * Method generates incremental function call
2195 | *
2196 | * @param int $num increment by int or float. 1 by default
2197 | *
2198 | * @throws Exception
2199 | * @return array
2200 | */
2201 | public function inc($num = 1)
2202 | {
2203 | if (!is_numeric($num)) {
2204 | throw new Exception('Argument supplied to inc must be a number');
2205 | }
2206 | return array("[I]" => "+" . $num);
2207 | }
2208 |
2209 | /**
2210 | * Method generates decremental function call
2211 | *
2212 | * @param int $num increment by int or float. 1 by default
2213 | *
2214 | * @return array
2215 | * @throws Exception
2216 | */
2217 | public function dec($num = 1)
2218 | {
2219 | if (!is_numeric($num)) {
2220 | throw new Exception('Argument supplied to dec must be a number');
2221 | }
2222 | return array("[I]" => "-" . $num);
2223 | }
2224 |
2225 | /**
2226 | * Method generates change boolean function call
2227 | *
2228 | * @param string $col column name. null by default
2229 | *
2230 | * @return array
2231 | */
2232 | public function not($col = null)
2233 | {
2234 | return array("[N]" => (string)$col);
2235 | }
2236 |
2237 | /**
2238 | * Method generates user defined function call
2239 | *
2240 | * @param string $expr user function body
2241 | * @param array $bindParams
2242 | *
2243 | * @return array
2244 | */
2245 | public function func($expr, $bindParams = null)
2246 | {
2247 | return array("[F]" => array($expr, $bindParams));
2248 | }
2249 |
2250 | /**
2251 | * Method creates new mysqlidb object for a subquery generation
2252 | *
2253 | * @param string $subQueryAlias
2254 | *
2255 | * @return MysqliDb
2256 | */
2257 | public static function subQuery($subQueryAlias = "")
2258 | {
2259 | return new self(array('host' => $subQueryAlias, 'isSubQuery' => true));
2260 | }
2261 |
2262 | /**
2263 | * Method returns a copy of a mysqlidb subquery object
2264 | *
2265 | * @return MysqliDb new mysqlidb object
2266 | */
2267 | public function copy()
2268 | {
2269 | $copy = unserialize(serialize($this));
2270 | $copy->_mysqli = array();
2271 | return $copy;
2272 | }
2273 |
2274 | /**
2275 | * Begin a transaction
2276 | *
2277 | * @uses mysqli->autocommit(false)
2278 | * @uses register_shutdown_function(array($this, "_transaction_shutdown_check"))
2279 | * @throws Exception
2280 | */
2281 | public function startTransaction()
2282 | {
2283 | $this->mysqli()->autocommit(false);
2284 | $this->_transaction_in_progress = true;
2285 | register_shutdown_function(array($this, "_transaction_status_check"));
2286 | }
2287 |
2288 | /**
2289 | * Transaction commit
2290 | *
2291 | * @uses mysqli->commit();
2292 | * @uses mysqli->autocommit(true);
2293 | * @throws Exception
2294 | */
2295 | public function commit()
2296 | {
2297 | $result = $this->mysqli()->commit();
2298 | $this->_transaction_in_progress = false;
2299 | $this->mysqli()->autocommit(true);
2300 | return $result;
2301 | }
2302 |
2303 | /**
2304 | * Transaction rollback function
2305 | *
2306 | * @uses mysqli->rollback();
2307 | * @uses mysqli->autocommit(true);
2308 | * @throws Exception
2309 | */
2310 | public function rollback()
2311 | {
2312 | $result = $this->mysqli()->rollback();
2313 | $this->_transaction_in_progress = false;
2314 | $this->mysqli()->autocommit(true);
2315 | return $result;
2316 | }
2317 |
2318 | /**
2319 | * Shutdown handler to rollback uncommited operations in order to keep
2320 | * atomic operations sane.
2321 | *
2322 | * @uses mysqli->rollback();
2323 | * @throws Exception
2324 | */
2325 | public function _transaction_status_check()
2326 | {
2327 | if (!$this->_transaction_in_progress) {
2328 | return;
2329 | }
2330 | $this->rollback();
2331 | }
2332 |
2333 | /**
2334 | * Query execution time tracking switch
2335 | *
2336 | * @param bool $enabled Enable execution time tracking
2337 | * @param string $stripPrefix Prefix to strip from the path in exec log
2338 | *
2339 | * @return MysqliDb
2340 | */
2341 | public function setTrace($enabled, $stripPrefix = '')
2342 | {
2343 | $this->traceEnabled = $enabled;
2344 | $this->traceStripPrefix = $stripPrefix;
2345 | return $this;
2346 | }
2347 |
2348 | /**
2349 | * Get where and what function was called for query stored in MysqliDB->trace
2350 | *
2351 | * @return string with information
2352 | */
2353 | private function _traceGetCaller()
2354 | {
2355 | $dd = debug_backtrace();
2356 | $caller = next($dd);
2357 | while (isset($caller) && $caller["file"] == __FILE__) {
2358 | $caller = next($dd);
2359 | }
2360 |
2361 | return __CLASS__ . "->" . $caller["function"] . "() >> file \"" .
2362 | str_replace($this->traceStripPrefix , '', $caller["file"]) . "\" line #" . $caller["line"] . " ";
2363 | }
2364 |
2365 | /**
2366 | * Method to check if needed table is created
2367 | *
2368 | * @param array $tables Table name or an Array of table names to check
2369 | *
2370 | * @return bool True if table exists
2371 | * @throws Exception
2372 | */
2373 | public function tableExists($tables)
2374 | {
2375 | $tables = !is_array($tables) ? Array($tables) : $tables;
2376 | $count = count($tables);
2377 | if ($count == 0) {
2378 | return false;
2379 | }
2380 |
2381 | foreach ($tables as $i => $value)
2382 | $tables[$i] = self::$prefix . $value;
2383 | $db = isset($this->connectionsSettings[$this->defConnectionName]) ? $this->connectionsSettings[$this->defConnectionName]['db'] : null;
2384 | $this->where('table_schema', $db);
2385 | $this->where('table_name', $tables, 'in');
2386 | $this->get('information_schema.tables', $count);
2387 | return $this->count == $count;
2388 | }
2389 |
2390 | /**
2391 | * Return result as an associative array with $idField field value used as a record key
2392 | *
2393 | * Array Returns an array($k => $v) if get(.."param1, param2"), array ($k => array ($v, $v)) otherwise
2394 | *
2395 | * @param string $idField field name to use for a mapped element key
2396 | *
2397 | * @return MysqliDb
2398 | */
2399 | public function map($idField)
2400 | {
2401 | $this->_mapKey = $idField;
2402 | return $this;
2403 | }
2404 |
2405 | /**
2406 | * Pagination wrapper to get()
2407 | *
2408 | * @access public
2409 | *
2410 | * @param string $table The name of the database table to work with
2411 | * @param int $page Page number
2412 | * @param array|string $fields Array or coma separated list of fields to fetch
2413 | *
2414 | * @return array
2415 | * @throws Exception
2416 | */
2417 | public function paginate ($table, $page, $fields = null) {
2418 | $offset = $this->pageLimit * ($page - 1);
2419 | $res = $this->withTotalCount()->get ($table, Array ($offset, $this->pageLimit), $fields);
2420 | $this->totalPages = ceil($this->totalCount / $this->pageLimit);
2421 | return $res;
2422 | }
2423 |
2424 | /**
2425 | * This method allows you to specify multiple (method chaining optional) AND WHERE statements for the join table on part of the SQL query.
2426 | *
2427 | * @uses $dbWrapper->joinWhere('user u', 'u.id', 7)->where('user u', 'u.title', 'MyTitle');
2428 | *
2429 | * @param string $whereJoin The name of the table followed by its prefix.
2430 | * @param string $whereProp The name of the database field.
2431 | * @param mixed $whereValue The value of the database field.
2432 | *
2433 | * @param string $operator
2434 | * @param string $cond
2435 | *
2436 | * @return $this
2437 | */
2438 | public function joinWhere($whereJoin, $whereProp, $whereValue = 'DBNULL', $operator = '=', $cond = 'AND')
2439 | {
2440 | $this->_joinAnd[self::$prefix . $whereJoin][] = Array ($cond, $whereProp, $operator, $whereValue);
2441 | return $this;
2442 | }
2443 |
2444 | /**
2445 | * This method allows you to specify multiple (method chaining optional) OR WHERE statements for the join table on part of the SQL query.
2446 | *
2447 | * @uses $dbWrapper->joinWhere('user u', 'u.id', 7)->where('user u', 'u.title', 'MyTitle');
2448 | *
2449 | * @param string $whereJoin The name of the table followed by its prefix.
2450 | * @param string $whereProp The name of the database field.
2451 | * @param mixed $whereValue The value of the database field.
2452 | * @param string $operator
2453 | *
2454 | * @return $this
2455 | */
2456 | public function joinOrWhere($whereJoin, $whereProp, $whereValue = 'DBNULL', $operator = '=', $cond = 'AND')
2457 | {
2458 | return $this->joinWhere($whereJoin, $whereProp, $whereValue, $operator, 'OR');
2459 | }
2460 |
2461 | /**
2462 | * Abstraction method that will build an JOIN part of the query
2463 | */
2464 | protected function _buildJoin () {
2465 | if (empty ($this->_join))
2466 | return;
2467 |
2468 | foreach ($this->_join as $data) {
2469 | list ($joinType, $joinTable, $joinCondition) = $data;
2470 |
2471 | if (is_object ($joinTable))
2472 | $joinStr = $this->_buildPair ("", $joinTable);
2473 | else
2474 | $joinStr = $joinTable;
2475 |
2476 | $this->_query .= " " . $joinType. " JOIN " . $joinStr .
2477 | (false !== stripos($joinCondition, 'using') ? " " : " on ")
2478 | . $joinCondition;
2479 |
2480 | // Add join and query
2481 | if (!empty($this->_joinAnd) && isset($this->_joinAnd[$joinStr])) {
2482 | foreach($this->_joinAnd[$joinStr] as $join_and_cond) {
2483 | list ($concat, $varName, $operator, $val) = $join_and_cond;
2484 | $this->_query .= " " . $concat ." " . $varName;
2485 | $this->conditionToSql($operator, $val);
2486 | }
2487 | }
2488 | }
2489 | }
2490 |
2491 | /**
2492 | * Convert a condition and value into the sql string
2493 | *
2494 | * @param String $operator The where constraint operator
2495 | * @param String|array $val The where constraint value
2496 | */
2497 | private function conditionToSql($operator, $val) {
2498 | switch (strtolower ($operator)) {
2499 | case 'not in':
2500 | case 'in':
2501 | $comparison = ' ' . $operator. ' (';
2502 | if (is_object ($val)) {
2503 | $comparison .= $this->_buildPair ("", $val);
2504 | } else {
2505 | foreach ($val as $v) {
2506 | $comparison .= ' ?,';
2507 | $this->_bindParam ($v);
2508 | }
2509 | }
2510 | $this->_query .= rtrim($comparison, ',').' ) ';
2511 | break;
2512 | case 'not between':
2513 | case 'between':
2514 | $this->_query .= " $operator ? AND ? ";
2515 | $this->_bindParams ($val);
2516 | break;
2517 | case 'not exists':
2518 | case 'exists':
2519 | $this->_query.= $operator . $this->_buildPair ("", $val);
2520 | break;
2521 | default:
2522 | if (is_array ($val))
2523 | $this->_bindParams ($val);
2524 | else if ($val === null)
2525 | $this->_query .= $operator . " NULL";
2526 | else if ($val != 'DBNULL' || $val == '0')
2527 | $this->_query .= $this->_buildPair ($operator, $val);
2528 | }
2529 | }
2530 | }
2531 |
2532 | // END class
2533 |
--------------------------------------------------------------------------------
/composer.json:
--------------------------------------------------------------------------------
1 | {
2 | "name": "thingengineer/mysqli-database-class",
3 | "description": "PHP MySQL Wrapper and object mapper which utilizes MySQLi and prepared statements",
4 | "license": "GPL-3.0-or-later",
5 | "authors": [
6 | {
7 | "name": "Josh Campbell",
8 | "email": "josh.lee.campbell@gmail.com",
9 | "homepage": "https://github.com/thingengineer",
10 | "role": "Developer"
11 | },
12 | {
13 | "name": "Alexander V. Butenko",
14 | "email": "a.butenka@gmail.com",
15 | "homepage": "http://smarttechdo.com",
16 | "role": "Developer"
17 | }
18 | ],
19 | "require": {
20 | "php": ">=5.3.0"
21 | },
22 | "autoload": {
23 | "files": ["MysqliDb.php", "dbObject.php"]
24 | }
25 | }
26 |
--------------------------------------------------------------------------------
/dbObject.md:
--------------------------------------------------------------------------------
1 | dbObject - model implementation on top of the MysqliDb.
2 |
3 | Please note that this library is not pretending to be a full stack ORM, but simply an OOP wrapper for `mysqlidb`.
4 |
5 |
6 |
7 | ### Initialization
8 |
9 | Include mysqlidb and dbObject classes. If you want to use model autoloading instead of manually including them in the scripts use `autoload()` method.
10 | ```php
11 | require_once("libs/MysqliDb.php");
12 | require_once("libs/dbObject.php");
13 |
14 | // db instance
15 | $db = new Mysqlidb('localhost', 'user', '', 'testdb');
16 | // enable class autoloading
17 | dbObject::autoload("models");
18 | ```
19 |
20 | Each database table could be easily mapped into a dbObject instance. If you do not want to create model for a simple table its object could be simply created with a `table()` method.
21 | ```php
22 | $user = dbObject::table("users");
23 | ```
24 |
25 | Otherwise basic model should be declared as:
26 | ```php
27 | class user extends dbObject {}
28 | ```
29 | In case autoload is set to 'models' directory, the filename should be models/user.php
30 |
31 | Class will be related to 'user' table. To change the table name, define correct name in the `$dbTable` variable:
32 |
33 | ```php
34 | protected $dbTable = "users";
35 | ```
36 |
37 | Both objects created throw new class file creation of with `table()` method will have the same set of methods available. Only exception is that relations, validation or custom model methods
38 | will not be working with an objects created with `table()` method.
39 |
40 |
41 | ### Selects
42 | Retrieving objects from the database is pretty much the same process as a mysqliDb `get()`/`getOne()`/`getValue()` methods without a need to specify table name. All mysqlidb functions like `where()`, `orWhere()`, `orderBy()`, `join()`, etc. are supported.
43 |
44 | ## Retrieving All Records
45 |
46 | ```php
47 | //$users = dbObject::table('users')->get();
48 | $users = user::get();
49 | foreach ($users as $u) {
50 | echo $u->login;
51 | }
52 | ```
53 |
54 | ## Using Where Condition And A Limit
55 | ```php
56 | $users = user::where("login", "demo")->get(Array (10, 20));
57 | foreach ($users as $u) ...
58 | ```
59 |
60 | ## Retrieving A Model By Primary Key
61 |
62 | ```php
63 | //$user = dbObject::table('users')->byId(1);
64 | $user = user::byId(1);
65 | echo $user->login;
66 | ```
67 |
68 | dbObject will also assume that each table has a primary key column named "id". You may define a primaryKey property to override this assumption.
69 |
70 | ```php
71 | protected $primaryKey = "userId";
72 | ```
73 |
74 |
75 | ### Insert Row
76 | 1. OOP Way. Just create new object of a needed class, fill it in and call `save()` method. Save will return
77 | record id in case of success and false in case if insert will fail.
78 | ```php
79 | //$user = dbObject::table('users');
80 | $user = new user;
81 | $user->login = 'demo';
82 | $user->password = 'demo';
83 | $id = $user->save();
84 | if ($id)
85 | echo "user created with id = " . $id;
86 | ```
87 |
88 | 2. Using arrays
89 | ```php
90 | $data = Array('login' => 'demo',
91 | 'password' => 'demo');
92 | $user = new user ($data);
93 | $id = $user->save();
94 | if ($id == null) {
95 | print_r($user->errors);
96 | echo $db->getLastError;
97 | } else
98 | echo "user created with id = " . $id;
99 | ```
100 |
101 | 3. Multisave
102 |
103 | ```php
104 | $user = new user;
105 | $user->login = 'demo';
106 | $user->pass = 'demo';
107 |
108 | $p = new product;
109 | $p->title = "Apples";
110 | $p->price = 0.5;
111 | $p->seller = $user;
112 | $p->save();
113 | ```
114 |
115 | After `save()` is called, both new objects (user and product) will be saved.
116 |
117 |
118 | ### Update
119 | To update model properties just set them and call `save()` method. Values that need to be changed could be passed as an array to the `save()` method as well.
120 |
121 | ```php
122 | $user = user::byId(1);
123 | $user->password = 'demo2';
124 | $user->save();
125 | ```
126 | ```php
127 | $data = Array('password', 'demo2');
128 | $user = user::byId(1);
129 | $user->save($data);
130 | ```
131 |
132 | ### Delete
133 | Use `delete()` method on any loaded object.
134 | ```php
135 | $user = user::byId(1);
136 | $user->delete();
137 | ```
138 |
139 | ### Relations
140 | Currently dbObject supports only `hasMany` and `hasOne` relations. To use them declare `$relations` array in the model class.
141 | After that you can get related object via variable names defined as keys.
142 |
143 | ## hasOne example:
144 | ```php
145 | protected $relations = Array(
146 | 'person' => Array("hasOne", "person", 'id');
147 | );
148 |
149 | ...
150 |
151 | $user = user::byId(1);
152 | // sql: select * from users where id = $personValue
153 | echo $user->person->firstName . " " . $user->person->lastName . " have the following products:\n";
154 | // one more sql: select * from person where id=x
155 | ```
156 | Please note, that following way of querying will execute 2 sql queries:
157 | 1. `select * from users where id=1`
158 | 2. `select * from person where id=x`
159 |
160 | To optimize this into single select join query use `with()` method.
161 | ```php
162 | $user = user::with('person')->byId(1);
163 | // sql: select * from users left join person on person.id = users.id wher id = 1;
164 | echo $user->person->firstName . " " . $user->person->lastName . " have the following products:\n";
165 | ```
166 |
167 | ## hasMany example:
168 | In the `hasMany` array should be defined the target object name (product in example) and a relation key (userid).
169 | ```php
170 | protected $relations = Array(
171 | 'products' => Array("hasMany", "product", 'userid')
172 | );
173 |
174 | ...
175 |
176 | $user = user::byId(1);
177 | // sql: select * from $product_table where userid = $userPrimaryKey
178 | foreach ($user->products as $p) {
179 | echo $p->title;
180 | }
181 | ```
182 |
183 | ### Joining tables
184 | ```php
185 | $depts = product::join('user');
186 | $depts = product::join('user', 'productid');
187 | ```
188 |
189 | First parameter will set an object which should be joined. Second paramter will define a key. Default key is `$objectName+'Id'`
190 |
191 |
192 | NOTE: Objects returned with `join()` will not save changes to a joined properties. For this you can use relationships.
193 |
194 | ### Timestamps
195 | Library provides a transparent way to set timestamps of an object creation and its modification:
196 | To enable that define `$timestamps` array as follows:
197 | ```php
198 | protected $timestamps = Array ('createdAt', 'updatedAt');
199 | ```
200 | Field names can't be changed.
201 |
202 | ### Array Fields
203 | dbObject can automatically handle array type of values. Optionaly you can store arrays in json encoded or in pipe delimited format.
204 | To enable automatic json serialization of the field define `$jsonFields` array in your modal:
205 | ```php
206 | protected $jsonFields = Array('options');
207 | ```
208 | To enable pipe delimited storage of the field, define `$arrayFields` array in your modal:
209 | ```php
210 | protected $arrayFields = Array('sections');
211 | ```
212 | The following code will now store `'options'` variable as a json string in the database, and will return an array on load.
213 | Same with the `'sections'` variable except that it will be stored in pipe delimited format.
214 | ```php
215 | $user = new user;
216 | $user->login = 'admin';
217 | $user->options = Array('canReadNews', 'canPostNews', 'canDeleteNews');
218 | $user->sections = Array('news', 'companyNews');
219 | $user->save();
220 | ...
221 | $user = user::byId(1);
222 | print_r($user->options);
223 | ```
224 |
225 | ### Validation and Error checking
226 | Before saving and updating the row, dbObject does input validation. In case validation rules are set but their criteria is
227 | not met, then `save()` will return an error with its description. For example:
228 | ```php
229 | $id = $user->save();
230 | if (!$id) {
231 | // show all validation errors
232 | print_r($user->errors);
233 | echo $db->getLastQuery();
234 | echo $db->getLastError();
235 | }
236 | echo "user were created with id" . $id;
237 | ```
238 | Validation rules must be defined in `$dbFields` array.
239 | ```php
240 | protected $dbFields = Array(
241 | 'login' => Array('text', 'required'),
242 | 'password' => Array('text'),
243 | 'createdAt' => Array('datetime'),
244 | 'updatedAt' => Array('datetime'),
245 | 'custom' => Array('/^test/'),
246 | );
247 | ```
248 | First parameter is a field type. Types could be the one of following: text, bool, int, datetime or a custom regexp.
249 | Second parameter is 'required' and its defines that following entry field be always defined.
250 |
251 | **NOTE:** All variables which are not defined in the `$dbFields` array will be ignored from insert/update statement.
252 |
253 | ### Using array as a return value
254 | dbObject can return its data as array instead of object. To do that, the `ArrayBuilder()` function should be used in the beginning of the call.
255 | ```php
256 | $user = user::ArrayBuilder()->byId(1);
257 | echo $user['login'];
258 |
259 | $users = user::ArrayBuilder()->orderBy("id", "desc")->get();
260 | foreach ($users as $u)
261 | echo $u['login'];
262 | ```
263 |
264 | The following call will return data only of the called instance without any relations data. Use `with()` function to include relation data as well.
265 | ```php
266 | $user = user::ArrayBuilder()->with("product")->byId(1);
267 | print_r ($user['products']);
268 | ```
269 |
270 | ### Using json as a return value
271 | Together with `ArrayBuilder()` and `ObjectBuilder()`, dbObject can also return a result in json format to avoid extra coding.
272 | ```php
273 | $userjson = user::JsonBuilder()->with("product")->byId(1);
274 | ```
275 | ### Object serialization
276 |
277 | Object could be easily converted to a json string or an array.
278 |
279 | ```php
280 | $user = user::byId(1);
281 | // echo will display json representation of an object
282 | echo $user;
283 | // userJson will contain json representation of an object
284 | $userJson = $user->toJson();
285 | // userArray will contain array representation of an object
286 | $userArray = $user->toArray();
287 | ```
288 |
289 | ### Pagination
290 | Use paginate() instead of get() to fetch paginated result
291 | ```php
292 | $page = 1;
293 | // set page limit to 2 results per page. 20 by default
294 | product::$pageLimit = 2;
295 | $products = product::arraybuilder()->paginate($page);
296 | echo "showing $page out of " . product::$totalPages;
297 |
298 | ```
299 |
300 | ### Hidden Fields
301 | Sometimes it's important to block some fields that can be accessed from outside the model class (for example, the user password).
302 |
303 | To block the access to certain fields using the `->` operator, you can declare the `$hidden` array into the model class. This array holds column names that can't be accessed with the `->` operator.
304 |
305 | For example:
306 |
307 | ```php
308 | class User extends dbObject {
309 | protected $dbFields = array(
310 | 'username' => array('text', 'required'),
311 | 'password' => array('text', 'required'),
312 | 'is_admin' => array('bool'),
313 | 'token' => array('text')
314 | );
315 |
316 | protected $hidden = array(
317 | 'password', 'token'
318 | );
319 | }
320 | ```
321 |
322 | If you try to:
323 | ```php
324 | echo $user->password;
325 | echo $user->token;
326 | ```
327 |
328 | Will return `null`, and also:
329 | ```php
330 | $user->password = "my-new-password";
331 | ```
332 |
333 | Won't change the current `password` value.
334 |
335 | ### Examples
336 |
337 | Please look for a use examples in tests file and test models inside the test models directory
338 |
--------------------------------------------------------------------------------
/dbObject.php:
--------------------------------------------------------------------------------
1 |
8 | * @copyright Copyright (c) 2015-2017
9 | * @license http://opensource.org/licenses/gpl-3.0.html GNU Public License
10 | * @link http://github.com/joshcam/PHP-MySQLi-Database-Class
11 | * @version 2.9-master
12 | *
13 | * @method int count ()
14 | * @method dbObject ArrayBuilder()
15 | * @method dbObject JsonBuilder()
16 | * @method dbObject ObjectBuilder()
17 | * @method mixed byId(string $id, mixed $fields)
18 | * @method mixed get(mixed $limit, mixed $fields)
19 | * @method mixed getOne(mixed $fields)
20 | * @method mixed paginate(int $page, array $fields)
21 | * @method dbObject query($query, $numRows = null)
22 | * @method dbObject rawQuery($query, $bindParams = null)
23 | * @method dbObject join(string $objectName, string $key, string $joinType, string $primaryKey)
24 | * @method dbObject with(string $objectName)
25 | * @method dbObject groupBy(string $groupByField)
26 | * @method dbObject orderBy($orderByField, $orderbyDirection = "DESC", $customFieldsOrRegExp = null)
27 | * @method dbObject where($whereProp, $whereValue = 'DBNULL', $operator = '=', $cond = 'AND')
28 | * @method dbObject orWhere($whereProp, $whereValue = 'DBNULL', $operator = '=')
29 | * @method dbObject having($havingProp, $havingValue = 'DBNULL', $operator = '=', $cond = 'AND')
30 | * @method dbObject orHaving($havingProp, $havingValue = null, $operator = null)
31 | * @method dbObject setQueryOption($options)
32 | * @method dbObject setTrace($enabled, $stripPrefix = null)
33 | * @method dbObject withTotalCount()
34 | * @method dbObject startTransaction()
35 | * @method dbObject commit()
36 | * @method dbObject rollback()
37 | * @method dbObject ping()
38 | * @method string getLastError()
39 | * @method string getLastQuery()
40 | */
41 | class dbObject {
42 | /**
43 | * Working instance of MysqliDb created earlier
44 | *
45 | * @var MysqliDb
46 | */
47 | private $db;
48 | /**
49 | * Models path
50 | *
51 | * @var modelPath
52 | */
53 | protected static $modelPath;
54 | /**
55 | * An array that holds object data
56 | *
57 | * @var array
58 | */
59 | public $data;
60 | /**
61 | * Flag to define is object is new or loaded from database
62 | *
63 | * @var boolean
64 | */
65 | public $isNew = true;
66 | /**
67 | * Return type: 'Array' to return results as array, 'Object' as object
68 | * 'Json' as json string
69 | *
70 | * @var string
71 | */
72 | public $returnType = 'Object';
73 | /**
74 | * An array that holds has* objects which should be loaded togeather with main
75 | * object togeather with main object
76 | *
77 | * @var string
78 | */
79 | private $_with = Array();
80 | /**
81 | * Per page limit for pagination
82 | *
83 | * @var int
84 | */
85 | public static $pageLimit = 20;
86 | /**
87 | * Variable that holds total pages count of last paginate() query
88 | *
89 | * @var int
90 | */
91 | public static $totalPages = 0;
92 | /**
93 | * Variable which holds an amount of returned rows during paginate queries
94 | * @var string
95 | */
96 | public static $totalCount = 0;
97 | /**
98 | * An array that holds insert/update/select errors
99 | *
100 | * @var array
101 | */
102 | public $errors = null;
103 | /**
104 | * Primary key for an object. 'id' is a default value.
105 | *
106 | * @var stating
107 | */
108 | protected $primaryKey = 'id';
109 | /**
110 | * Table name for an object. Class name will be used by default
111 | *
112 | * @var stating
113 | */
114 | protected $dbTable;
115 |
116 | /**
117 | * @var array name of the fields that will be skipped during validation, preparing & saving
118 | */
119 | protected $toSkip = array();
120 |
121 | /**
122 | * @param array $data Data to preload on object creation
123 | */
124 | public function __construct ($data = null) {
125 | $this->db = MysqliDb::getInstance();
126 | if (empty ($this->dbTable))
127 | $this->dbTable = get_class ($this);
128 |
129 | if ($data)
130 | $this->data = $data;
131 | }
132 |
133 | /**
134 | * Magic setter function
135 | *
136 | * @return mixed
137 | */
138 | public function __set ($name, $value) {
139 | if (property_exists ($this, 'hidden') && array_search ($name, $this->hidden) !== false)
140 | return;
141 |
142 | $this->data[$name] = $value;
143 | }
144 |
145 | /**
146 | * Magic getter function
147 | *
148 | * @param $name Variable name
149 | *
150 | * @return mixed
151 | */
152 | public function __get ($name) {
153 | if (property_exists ($this, 'hidden') && array_search ($name, $this->hidden) !== false)
154 | return null;
155 |
156 | if (isset ($this->data[$name]) && $this->data[$name] instanceof dbObject)
157 | return $this->data[$name];
158 |
159 | if (property_exists ($this, 'relations') && isset ($this->relations[$name])) {
160 | $relationType = strtolower ($this->relations[$name][0]);
161 | $modelName = $this->relations[$name][1];
162 | switch ($relationType) {
163 | case 'hasone':
164 | $key = isset ($this->relations[$name][2]) ? $this->relations[$name][2] : $name;
165 | $obj = new $modelName;
166 | $obj->returnType = $this->returnType;
167 | return $this->data[$name] = $obj->byId($this->data[$key]);
168 | break;
169 | case 'hasmany':
170 | $key = $this->relations[$name][2];
171 | $obj = new $modelName;
172 | $obj->returnType = $this->returnType;
173 | return $this->data[$name] = $obj->where($key, $this->data[$this->primaryKey])->get();
174 | break;
175 | default:
176 | break;
177 | }
178 | }
179 |
180 | if (isset ($this->data[$name]))
181 | return $this->data[$name];
182 |
183 | if (property_exists ($this->db, $name))
184 | return $this->db->$name;
185 | }
186 |
187 | public function __isset ($name) {
188 | if (isset ($this->data[$name]))
189 | return isset ($this->data[$name]);
190 |
191 | if (property_exists ($this->db, $name))
192 | return isset ($this->db->$name);
193 | }
194 |
195 | public function __unset ($name) {
196 | unset ($this->data[$name]);
197 | }
198 |
199 | /**
200 | * Helper function to create dbObject with Json return type
201 | *
202 | * @return dbObject
203 | */
204 | private function JsonBuilder () {
205 | $this->returnType = 'Json';
206 | return $this;
207 | }
208 |
209 | /**
210 | * Helper function to create dbObject with Array return type
211 | *
212 | * @return dbObject
213 | */
214 | private function ArrayBuilder () {
215 | $this->returnType = 'Array';
216 | return $this;
217 | }
218 |
219 | /**
220 | * Helper function to create dbObject with Object return type.
221 | * Added for consistency. Works same way as new $objname ()
222 | *
223 | * @return dbObject
224 | */
225 | private function ObjectBuilder () {
226 | $this->returnType = 'Object';
227 | return $this;
228 | }
229 |
230 | /**
231 | * Helper function to create a virtual table class
232 | *
233 | * @param string tableName Table name
234 | * @return dbObject
235 | */
236 | public static function table ($tableName) {
237 | $tableName = preg_replace ("/[^-a-z0-9_]+/i",'', $tableName);
238 | if (!class_exists ($tableName))
239 | eval ("class $tableName extends dbObject {}");
240 | return new $tableName ();
241 | }
242 | /**
243 | * @return mixed insert id or false in case of failure
244 | */
245 | public function insert () {
246 | if (!empty ($this->timestamps) && in_array ("createdAt", $this->timestamps))
247 | $this->createdAt = date("Y-m-d H:i:s");
248 | $sqlData = $this->prepareData ();
249 | if (!$this->validate ($sqlData))
250 | return false;
251 |
252 | $id = $this->db->insert ($this->dbTable, $sqlData);
253 | if (!empty ($this->primaryKey) && empty ($this->data[$this->primaryKey]))
254 | $this->data[$this->primaryKey] = $id;
255 | $this->isNew = false;
256 | $this->toSkip = array();
257 | return $id;
258 | }
259 |
260 | /**
261 | * @param array $data Optional update data to apply to the object
262 | */
263 | public function update ($data = null) {
264 | if (empty ($this->dbFields))
265 | return false;
266 |
267 | if (empty ($this->data[$this->primaryKey]))
268 | return false;
269 |
270 | if ($data) {
271 | foreach ($data as $k => $v) {
272 | if (in_array($k, $this->toSkip))
273 | continue;
274 |
275 | $this->$k = $v;
276 | }
277 | }
278 |
279 | if (!empty ($this->timestamps) && in_array ("updatedAt", $this->timestamps))
280 | $this->updatedAt = date("Y-m-d H:i:s");
281 |
282 | $sqlData = $this->prepareData ();
283 | if (!$this->validate ($sqlData))
284 | return false;
285 |
286 | $this->db->where ($this->primaryKey, $this->data[$this->primaryKey]);
287 | $res = $this->db->update ($this->dbTable, $sqlData);
288 | $this->toSkip = array();
289 | return $res;
290 | }
291 |
292 | /**
293 | * Save or Update object
294 | *
295 | * @return mixed insert id or false in case of failure
296 | */
297 | public function save ($data = null) {
298 | if ($this->isNew)
299 | return $this->insert();
300 | return $this->update ($data);
301 | }
302 |
303 | /**
304 | * Delete method. Works only if object primaryKey is defined
305 | *
306 | * @return boolean Indicates success. 0 or 1.
307 | */
308 | public function delete () {
309 | if (empty ($this->data[$this->primaryKey]))
310 | return false;
311 |
312 | $this->db->where ($this->primaryKey, $this->data[$this->primaryKey]);
313 | $res = $this->db->delete ($this->dbTable);
314 | $this->toSkip = array();
315 | return $res;
316 | }
317 |
318 | /**
319 | * chained method that append a field or fields to skipping
320 | * @param mixed|array|false $field field name; array of names; empty skipping if false
321 | * @return $this
322 | */
323 | public function skip($field){
324 | if(is_array($field)) {
325 | foreach ($field as $f) {
326 | $this->toSkip[] = $f;
327 | }
328 | } else if($field === false) {
329 | $this->toSkip = array();
330 | } else{
331 | $this->toSkip[] = $field;
332 | }
333 | return $this;
334 | }
335 |
336 | /**
337 | * Get object by primary key.
338 | *
339 | * @access public
340 | * @param $id Primary Key
341 | * @param array|string $fields Array or coma separated list of fields to fetch
342 | *
343 | * @return dbObject|array
344 | */
345 | private function byId ($id, $fields = null) {
346 | $this->db->where (MysqliDb::$prefix . $this->dbTable . '.' . $this->primaryKey, $id);
347 | return $this->getOne ($fields);
348 | }
349 |
350 | /**
351 | * Convinient function to fetch one object. Mostly will be togeather with where()
352 | *
353 | * @access public
354 | * @param array|string $fields Array or coma separated list of fields to fetch
355 | *
356 | * @return dbObject
357 | */
358 | protected function getOne ($fields = null) {
359 | $this->processHasOneWith ();
360 | $results = $this->db->ArrayBuilder()->getOne ($this->dbTable, $fields);
361 | if ($this->db->count == 0)
362 | return null;
363 |
364 | $this->processArrays ($results);
365 | $this->data = $results;
366 | $this->processAllWith ($results);
367 | if ($this->returnType == 'Json')
368 | return json_encode ($results);
369 | if ($this->returnType == 'Array')
370 | return $results;
371 |
372 | $item = new static ($results);
373 | $item->isNew = false;
374 |
375 | return $item;
376 | }
377 |
378 | /**
379 | * A convenient SELECT COLUMN function to get a single column value from model object
380 | *
381 | * @param string $column The desired column
382 | * @param int $limit Limit of rows to select. Use null for unlimited..1 by default
383 | *
384 | * @return mixed Contains the value of a returned column / array of values
385 | * @throws Exception
386 | */
387 | protected function getValue ($column, $limit = 1) {
388 | $res = $this->db->ArrayBuilder()->getValue ($this->dbTable, $column, $limit);
389 | if (!$res)
390 | return null;
391 | return $res;
392 | }
393 |
394 | /**
395 | * A convenient function that returns TRUE if exists at least an element that
396 | * satisfy the where condition specified calling the "where" method before this one.
397 | *
398 | * @return bool
399 | * @throws Exception
400 | */
401 | protected function has() {
402 | return $this->db->has($this->dbTable);
403 | }
404 |
405 | /**
406 | * Fetch all objects
407 | *
408 | * @access public
409 | * @param integer|array $limit Array to define SQL limit in format Array ($count, $offset)
410 | * or only $count
411 | * @param array|string $fields Array or coma separated list of fields to fetch
412 | *
413 | * @return array Array of dbObjects
414 | */
415 | protected function get ($limit = null, $fields = null) {
416 | $objects = Array ();
417 | $this->processHasOneWith ();
418 | $results = $this->db->ArrayBuilder()->get ($this->dbTable, $limit, $fields);
419 | if ($this->db->count == 0)
420 | return null;
421 |
422 | foreach ($results as $k => &$r) {
423 | $this->processArrays ($r);
424 | $this->data = $r;
425 | $this->processAllWith ($r, false);
426 | if ($this->returnType == 'Object') {
427 | $item = new static ($r);
428 | $item->isNew = false;
429 | $objects[$k] = $item;
430 | }
431 | }
432 | $this->_with = Array();
433 | if ($this->returnType == 'Object')
434 | return $objects;
435 |
436 | if ($this->returnType == 'Json')
437 | return json_encode ($results);
438 |
439 | return $results;
440 | }
441 |
442 | /**
443 | * Function to set witch hasOne or hasMany objects should be loaded togeather with a main object
444 | *
445 | * @access public
446 | * @param string $objectName Object Name
447 | *
448 | * @return dbObject
449 | */
450 | private function with ($objectName) {
451 | if (!property_exists ($this, 'relations') || !isset ($this->relations[$objectName]))
452 | die ("No relation with name $objectName found");
453 |
454 | $this->_with[MysqliDb::$prefix.$objectName] = $this->relations[$objectName];
455 |
456 | return $this;
457 | }
458 |
459 | /**
460 | * Function to join object with another object.
461 | *
462 | * @access public
463 | * @param string $objectName Object Name
464 | * @param string $key Key for a join from primary object
465 | * @param string $joinType SQL join type: LEFT, RIGHT, INNER, OUTER
466 | * @param string $primaryKey SQL join On Second primaryKey
467 | *
468 | * @return dbObject
469 | */
470 | private function join ($objectName, $key = null, $joinType = 'LEFT', $primaryKey = null) {
471 | $joinObj = new $objectName;
472 | if (!$key)
473 | $key = $objectName . "id";
474 |
475 | if (!$primaryKey)
476 | $primaryKey = MysqliDb::$prefix . $joinObj->dbTable . "." . $joinObj->primaryKey;
477 |
478 | if (!strchr ($key, '.'))
479 | $joinStr = MysqliDb::$prefix . $this->dbTable . ".{$key} = " . $primaryKey;
480 | else
481 | $joinStr = MysqliDb::$prefix . "{$key} = " . $primaryKey;
482 |
483 | $this->db->join ($joinObj->dbTable, $joinStr, $joinType);
484 | return $this;
485 | }
486 |
487 | /**
488 | * Function to get a total records count
489 | *
490 | * @return int
491 | */
492 | protected function count () {
493 | $res = $this->db->ArrayBuilder()->getValue ($this->dbTable, "count(*)");
494 | if (!$res)
495 | return 0;
496 | return $res;
497 | }
498 |
499 | /**
500 | * Pagination wraper to get()
501 | *
502 | * @access public
503 | * @param int $page Page number
504 | * @param array|string $fields Array or coma separated list of fields to fetch
505 | * @return array
506 | */
507 | private function paginate ($page, $fields = null) {
508 | $this->db->pageLimit = self::$pageLimit;
509 | $objects = Array ();
510 | $this->processHasOneWith ();
511 | $res = $this->db->paginate ($this->dbTable, $page, $fields);
512 | self::$totalPages = $this->db->totalPages;
513 | self::$totalCount = $this->db->totalCount;
514 | if ($this->db->count == 0) return null;
515 |
516 | foreach ($res as $k => &$r) {
517 | $this->processArrays ($r);
518 | $this->data = $r;
519 | $this->processAllWith ($r, false);
520 | if ($this->returnType == 'Object') {
521 | $item = new static ($r);
522 | $item->isNew = false;
523 | $objects[$k] = $item;
524 | }
525 | }
526 | $this->_with = Array();
527 | if ($this->returnType == 'Object')
528 | return $objects;
529 |
530 | if ($this->returnType == 'Json')
531 | return json_encode ($res);
532 |
533 | return $res;
534 | }
535 |
536 | /**
537 | * Catches calls to undefined methods.
538 | *
539 | * Provides magic access to private functions of the class and native public mysqlidb functions
540 | *
541 | * @param string $method
542 | * @param mixed $arg
543 | *
544 | * @return mixed
545 | */
546 | public function __call ($method, $arg) {
547 | if (method_exists ($this, $method))
548 | return call_user_func_array (array ($this, $method), $arg);
549 |
550 | call_user_func_array (array ($this->db, $method), $arg);
551 | return $this;
552 | }
553 |
554 | /**
555 | * Catches calls to undefined static methods.
556 | *
557 | * Transparently creating dbObject class to provide smooth API like name::get() name::orderBy()->get()
558 | *
559 | * @param string $method
560 | * @param mixed $arg
561 | *
562 | * @return mixed
563 | */
564 | public static function __callStatic ($method, $arg) {
565 | $obj = new static;
566 | $result = call_user_func_array (array ($obj, $method), $arg);
567 | if (method_exists ($obj, $method))
568 | return $result;
569 | return $obj;
570 | }
571 |
572 | /**
573 | * Converts object data to an associative array.
574 | *
575 | * @return array Converted data
576 | */
577 | public function toArray () {
578 | $data = $this->data;
579 | $this->processAllWith ($data);
580 | foreach ($data as &$d) {
581 | if ($d instanceof dbObject)
582 | $d = $d->data;
583 | }
584 | return $data;
585 | }
586 |
587 | /**
588 | * Converts object data to a JSON string.
589 | *
590 | * @return string Converted data
591 | */
592 | public function toJson () {
593 | return json_encode ($this->toArray());
594 | }
595 |
596 | /**
597 | * Converts object data to a JSON string.
598 | *
599 | * @return string Converted data
600 | */
601 | public function __toString () {
602 | return $this->toJson ();
603 | }
604 |
605 | /**
606 | * Function queries hasMany relations if needed and also converts hasOne object names
607 | *
608 | * @param array $data
609 | */
610 | private function processAllWith (&$data, $shouldReset = true) {
611 | if (count ($this->_with) == 0)
612 | return;
613 |
614 | foreach ($this->_with as $name => $opts) {
615 | $relationType = strtolower ($opts[0]);
616 | $modelName = $opts[1];
617 | if ($relationType == 'hasone') {
618 | $obj = new $modelName;
619 | $table = $obj->dbTable;
620 | $primaryKey = $obj->primaryKey;
621 |
622 | if (!isset ($data[$table])) {
623 | $data[$name] = $this->$name;
624 | continue;
625 | }
626 | if ($data[$table][$primaryKey] === null) {
627 | $data[$name] = null;
628 | } else {
629 | if ($this->returnType == 'Object') {
630 | $item = new $modelName ($data[$table]);
631 | $item->returnType = $this->returnType;
632 | $item->isNew = false;
633 | $data[$name] = $item;
634 | } else {
635 | $data[$name] = $data[$table];
636 | }
637 | }
638 | unset ($data[$table]);
639 | }
640 | else
641 | $data[$name] = $this->$name;
642 | }
643 | if ($shouldReset)
644 | $this->_with = Array();
645 | }
646 |
647 | /*
648 | * Function building hasOne joins for get/getOne method
649 | */
650 | private function processHasOneWith () {
651 | if (count ($this->_with) == 0)
652 | return;
653 | foreach ($this->_with as $name => $opts) {
654 | $relationType = strtolower ($opts[0]);
655 | $modelName = $opts[1];
656 | $key = null;
657 | if (isset ($opts[2]))
658 | $key = $opts[2];
659 | if ($relationType == 'hasone') {
660 | $this->db->setQueryOption ("MYSQLI_NESTJOIN");
661 | $this->join ($modelName, $key);
662 | }
663 | }
664 | }
665 |
666 | /**
667 | * @param array $data
668 | */
669 | private function processArrays (&$data) {
670 | if (isset ($this->jsonFields) && is_array ($this->jsonFields)) {
671 | foreach ($this->jsonFields as $key)
672 | $data[$key] = json_decode ($data[$key]);
673 | }
674 |
675 | if (isset ($this->arrayFields) && is_array($this->arrayFields)) {
676 | foreach ($this->arrayFields as $key)
677 | $data[$key] = explode ("|", $data[$key]);
678 | }
679 | }
680 |
681 | /**
682 | * @param array $data
683 | */
684 | private function validate ($data) {
685 | if (!$this->dbFields)
686 | return true;
687 |
688 | foreach ($this->dbFields as $key => $desc) {
689 | if(in_array($key, $this->toSkip))
690 | continue;
691 |
692 | $type = null;
693 | $required = false;
694 | if (isset ($data[$key]))
695 | $value = $data[$key];
696 | else
697 | $value = null;
698 |
699 | if (is_array ($value))
700 | continue;
701 |
702 | if (isset ($desc[0]))
703 | $type = $desc[0];
704 | if (isset ($desc[1]) && ($desc[1] == 'required'))
705 | $required = true;
706 |
707 | if ($required && strlen ($value) == 0) {
708 | $this->errors[] = Array ($this->dbTable . "." . $key => "is required");
709 | continue;
710 | }
711 | if ($value == null)
712 | continue;
713 |
714 | switch ($type) {
715 | case "text":
716 | $regexp = null;
717 | break;
718 | case "int":
719 | $regexp = "/^[0-9]*$/";
720 | break;
721 | case "double":
722 | $regexp = "/^[0-9\.]*$/";
723 | break;
724 | case "bool":
725 | $regexp = '/^(yes|no|0|1|true|false)$/i';
726 | break;
727 | case "datetime":
728 | $regexp = "/^[0-9a-zA-Z -:]*$/";
729 | break;
730 | default:
731 | $regexp = $type;
732 | break;
733 | }
734 | if (!$regexp)
735 | continue;
736 |
737 | if (!preg_match ($regexp, $value)) {
738 | $this->errors[] = Array ($this->dbTable . "." . $key => "$type validation failed");
739 | continue;
740 | }
741 | }
742 | return !count ($this->errors) > 0;
743 | }
744 |
745 | private function prepareData () {
746 | $this->errors = Array ();
747 | $sqlData = Array();
748 | if (count ($this->data) == 0)
749 | return Array();
750 |
751 | if (method_exists ($this, "preLoad"))
752 | $this->preLoad ($this->data);
753 |
754 | if (!$this->dbFields)
755 | return $this->data;
756 |
757 | foreach ($this->data as $key => &$value) {
758 | if(in_array($key, $this->toSkip))
759 | continue;
760 |
761 | if ($value instanceof dbObject && $value->isNew == true) {
762 | $id = $value->save();
763 | if ($id)
764 | $value = $id;
765 | else
766 | $this->errors = array_merge ($this->errors, $value->errors);
767 | }
768 |
769 | if (!in_array ($key, array_keys ($this->dbFields)))
770 | continue;
771 |
772 | if (!is_array($value) && !is_object($value)) {
773 | $sqlData[$key] = $value;
774 | continue;
775 | }
776 |
777 | if (isset ($this->jsonFields) && in_array ($key, $this->jsonFields))
778 | $sqlData[$key] = json_encode($value);
779 | else if (isset ($this->arrayFields) && in_array ($key, $this->arrayFields))
780 | $sqlData[$key] = implode ("|", $value);
781 | else
782 | $sqlData[$key] = $value;
783 | }
784 | return $sqlData;
785 | }
786 |
787 | private static function dbObjectAutoload ($classname) {
788 | $filename = static::$modelPath . $classname .".php";
789 | if (file_exists ($filename))
790 | include ($filename);
791 | }
792 |
793 | /*
794 | * Enable models autoload from a specified path
795 | *
796 | * Calling autoload() without path will set path to dbObjectPath/models/ directory
797 | *
798 | * @param string $path
799 | */
800 | public static function autoload ($path = null) {
801 | if ($path)
802 | static::$modelPath = $path . "/";
803 | else
804 | static::$modelPath = __DIR__ . "/models/";
805 | spl_autoload_register ("dbObject::dbObjectAutoload");
806 | }
807 | }
808 |
--------------------------------------------------------------------------------
/readme.md:
--------------------------------------------------------------------------------
1 | MysqliDb -- Simple MySQLi wrapper and object mapper with prepared statements
2 |
3 |
4 | ### Table of Contents
5 |
6 | **[Initialization](#initialization)**
7 | **[Objects mapping](#objects-mapping)**
8 | **[Insert Query](#insert-query)**
9 | **[Update Query](#update-query)**
10 | **[Select Query](#select-query)**
11 | **[Delete Query](#delete-query)**
12 | **[Insert Data](#insert-data)**
13 | **[Insert XML](#insert-xml)**
14 | **[Pagination](#pagination)**
15 | **[Running raw SQL queries](#running-raw-sql-queries)**
16 | **[Query Keywords](#query-keywords)**
17 | **[Where Conditions](#where--having-methods)**
18 | **[Order Conditions](#ordering-method)**
19 | **[Group Conditions](#grouping-method)**
20 | **[Properties Sharing](#properties-sharing)**
21 | **[Joining Tables](#join-method)**
22 | **[Subqueries](#subqueries)**
23 | **[EXISTS / NOT EXISTS condition](#exists--not-exists-condition)**
24 | **[Has method](#has-method)**
25 | **[Helper Methods](#helper-methods)**
26 | **[Transaction Helpers](#transaction-helpers)**
27 | **[Error Helpers](#error-helpers)**
28 | **[Table Locking](#table-locking)**
29 |
30 | ## Support Me
31 |
32 | This software is developed during my free time and I will be glad if somebody will support me.
33 |
34 | Everyone's time should be valuable, so please consider donating.
35 |
36 | [Donate with paypal](https://www.paypal.com/cgi-bin/webscr?cmd=_donations&business=a%2ebutenka%40gmail%2ecom&lc=DO&item_name=mysqlidb¤cy_code=USD&bn=PP%2dDonationsBF%3abtn_donateCC_LG%2egif%3aNonHosted)
37 |
38 | ### Installation
39 | To utilize this class, first import MysqliDb.php into your project, and require it.
40 |
41 | ```php
42 | require_once ('MysqliDb.php');
43 | ```
44 |
45 | ### Installation with composer
46 | It is also possible to install library via composer
47 | ```
48 | composer require thingengineer/mysqli-database-class:dev-master
49 | ```
50 |
51 | ### Initialization
52 | Simple initialization with utf8 charset set by default:
53 | ```php
54 | $db = new MysqliDb ('host', 'username', 'password', 'databaseName');
55 | ```
56 |
57 | Advanced initialization:
58 | ```php
59 | $db = new MysqliDb (Array (
60 | 'host' => 'host',
61 | 'username' => 'username',
62 | 'password' => 'password',
63 | 'db'=> 'databaseName',
64 | 'port' => 3306,
65 | 'prefix' => 'my_',
66 | 'charset' => 'utf8'));
67 | ```
68 | table prefix, port and database charset params are optional.
69 | If no charset should be set charset, set it to null
70 |
71 | Also it is possible to reuse already connected mysqli object:
72 | ```php
73 | $mysqli = new mysqli ('host', 'username', 'password', 'databaseName');
74 | $db = new MysqliDb ($mysqli);
75 | ```
76 |
77 | If no table prefix were set during object creation its possible to set it later with a separate call:
78 | ```php
79 | $db->setPrefix ('my_');
80 | ```
81 |
82 | If connection to mysql will be dropped Mysqlidb will try to automatically reconnect to the database once.
83 | To disable this behavoir use
84 | ```php
85 | $db->autoReconnect = false;
86 | ```
87 |
88 | If you need to get already created mysqliDb object from another class or function use
89 | ```php
90 | function init () {
91 | // db staying private here
92 | $db = new MysqliDb ('host', 'username', 'password', 'databaseName');
93 | }
94 | ...
95 | function myfunc () {
96 | // obtain db object created in init ()
97 | $db = MysqliDb::getInstance();
98 | ...
99 | }
100 | ```
101 |
102 | ### Multiple database connection
103 | If you need to connect to multiple databases use following method:
104 | ```php
105 | $db->addConnection('slave', Array (
106 | 'host' => 'host',
107 | 'username' => 'username',
108 | 'password' => 'password',
109 | 'db'=> 'databaseName',
110 | 'port' => 3306,
111 | 'prefix' => 'my_',
112 | 'charset' => 'utf8')
113 | );
114 | ```
115 | To select database use connection() method
116 | ```php
117 | $users = $db->connection('slave')->get('users');
118 | ```
119 |
120 | ### Objects mapping
121 | dbObject.php is an object mapping library built on top of mysqliDb to provide model representation functionality.
122 | See dbObject manual for more information
123 |
124 | ### Insert Query
125 | Simple example
126 | ```php
127 | $data = Array ("login" => "admin",
128 | "firstName" => "John",
129 | "lastName" => 'Doe'
130 | );
131 | $id = $db->insert ('users', $data);
132 | if($id)
133 | echo 'user was created. Id=' . $id;
134 | ```
135 |
136 | Insert with functions use
137 | ```php
138 | $data = Array (
139 | 'login' => 'admin',
140 | 'active' => true,
141 | 'firstName' => 'John',
142 | 'lastName' => 'Doe',
143 | 'password' => $db->func('SHA1(?)',Array ("secretpassword+salt")),
144 | // password = SHA1('secretpassword+salt')
145 | 'createdAt' => $db->now(),
146 | // createdAt = NOW()
147 | 'expires' => $db->now('+1Y')
148 | // expires = NOW() + interval 1 year
149 | // Supported intervals [s]econd, [m]inute, [h]hour, [d]day, [M]onth, [Y]ear
150 | );
151 |
152 | $id = $db->insert ('users', $data);
153 | if ($id)
154 | echo 'user was created. Id=' . $id;
155 | else
156 | echo 'insert failed: ' . $db->getLastError();
157 | ```
158 |
159 | Insert with on duplicate key update
160 | ```php
161 | $data = Array ("login" => "admin",
162 | "firstName" => "John",
163 | "lastName" => 'Doe',
164 | "createdAt" => $db->now(),
165 | "updatedAt" => $db->now(),
166 | );
167 | $updateColumns = Array ("updatedAt");
168 | $lastInsertId = "id";
169 | $db->onDuplicate($updateColumns, $lastInsertId);
170 | $id = $db->insert ('users', $data);
171 | ```
172 |
173 | Insert multiple datasets at once
174 | ```php
175 | $data = Array(
176 | Array ("login" => "admin",
177 | "firstName" => "John",
178 | "lastName" => 'Doe'
179 | ),
180 | Array ("login" => "other",
181 | "firstName" => "Another",
182 | "lastName" => 'User',
183 | "password" => "very_cool_hash"
184 | )
185 | );
186 | $ids = $db->insertMulti('users', $data);
187 | if(!$ids) {
188 | echo 'insert failed: ' . $db->getLastError();
189 | } else {
190 | echo 'new users inserted with following id\'s: ' . implode(', ', $ids);
191 | }
192 | ```
193 |
194 | If all datasets only have the same keys, it can be simplified
195 | ```php
196 | $data = Array(
197 | Array ("admin", "John", "Doe"),
198 | Array ("other", "Another", "User")
199 | );
200 | $keys = Array("login", "firstName", "lastName");
201 |
202 | $ids = $db->insertMulti('users', $data, $keys);
203 | if(!$ids) {
204 | echo 'insert failed: ' . $db->getLastError();
205 | } else {
206 | echo 'new users inserted with following id\'s: ' . implode(', ', $ids);
207 | }
208 | ```
209 |
210 | ### Replace Query
211 | Replace() method implements same API as insert();
212 |
213 | ### Update Query
214 | ```php
215 | $data = Array (
216 | 'firstName' => 'Bobby',
217 | 'lastName' => 'Tables',
218 | 'editCount' => $db->inc(2),
219 | // editCount = editCount + 2;
220 | 'active' => $db->not()
221 | // active = !active;
222 | );
223 | $db->where ('id', 1);
224 | if ($db->update ('users', $data))
225 | echo $db->count . ' records were updated';
226 | else
227 | echo 'update failed: ' . $db->getLastError();
228 | ```
229 |
230 | `update()` also support limit parameter:
231 | ```php
232 | $db->update ('users', $data, 10);
233 | // Gives: UPDATE users SET ... LIMIT 10
234 | ```
235 |
236 | ### Select Query
237 | After any select/get function calls amount or returned rows is stored in $count variable
238 | ```php
239 | $users = $db->get('users'); //contains an Array of all users
240 | $users = $db->get('users', 10); //contains an Array 10 users
241 | ```
242 |
243 | or select with custom columns set. Functions also could be used
244 |
245 | ```php
246 | $cols = Array ("id", "name", "email");
247 | $users = $db->get ("users", null, $cols);
248 | if ($db->count > 0)
249 | foreach ($users as $user) {
250 | print_r ($user);
251 | }
252 | ```
253 |
254 | or select just one row
255 |
256 | ```php
257 | $db->where ("id", 1);
258 | $user = $db->getOne ("users");
259 | echo $user['id'];
260 |
261 | $stats = $db->getOne ("users", "sum(id), count(*) as cnt");
262 | echo "total ".$stats['cnt']. "users found";
263 | ```
264 |
265 | or select one column value or function result
266 |
267 | ```php
268 | $count = $db->getValue ("users", "count(*)");
269 | echo "{$count} users found";
270 | ```
271 |
272 | select one column value or function result from multiple rows:
273 | ```php
274 | $logins = $db->getValue ("users", "login", null);
275 | // select login from users
276 | $logins = $db->getValue ("users", "login", 5);
277 | // select login from users limit 5
278 | foreach ($logins as $login)
279 | echo $login;
280 | ```
281 |
282 | ### Insert Data
283 | You can also load .CSV or .XML data into a specific table.
284 | To insert .csv data, use the following syntax:
285 | ```php
286 | $path_to_file = "/home/john/file.csv";
287 | $db->loadData("users", $path_to_file);
288 | ```
289 | This will load a .csv file called **file.csv** in the folder **/home/john/** (john's home directory.)
290 | You can also attach an optional array of options.
291 | Valid options are:
292 |
293 | ```php
294 | Array(
295 | "fieldChar" => ';', // Char which separates the data
296 | "lineChar" => '\r\n', // Char which separates the lines
297 | "linesToIgnore" => 1 // Amount of lines to ignore at the beginning of the import
298 | );
299 | ```
300 |
301 | Attach them using
302 | ```php
303 | $options = Array("fieldChar" => ';', "lineChar" => '\r\n', "linesToIgnore" => 1);
304 | $db->loadData("users", "/home/john/file.csv", $options);
305 | // LOAD DATA ...
306 | ```
307 |
308 | You can specify to **use LOCAL DATA** instead of **DATA**:
309 | ```php
310 | $options = Array("fieldChar" => ';', "lineChar" => '\r\n', "linesToIgnore" => 1, "loadDataLocal" => true);
311 | $db->loadData("users", "/home/john/file.csv", $options);
312 | // LOAD DATA LOCAL ...
313 | ```
314 |
315 | ### Insert XML
316 | To load XML data into a table, you can use the method **loadXML**.
317 | The syntax is smillar to the loadData syntax.
318 | ```php
319 | $path_to_file = "/home/john/file.xml";
320 | $db->loadXML("users", $path_to_file);
321 | ```
322 |
323 | You can also add optional parameters.
324 | Valid parameters:
325 | ```php
326 | Array(
327 | "linesToIgnore" => 0, // Amount of lines / rows to ignore at the beginning of the import
328 | "rowTag" => "" // The tag which marks the beginning of an entry
329 | )
330 | ```
331 |
332 | Usage:
333 | ```php
334 | $options = Array("linesToIgnore" => 0, "rowTag" => ""):
335 | $path_to_file = "/home/john/file.xml";
336 | $db->loadXML("users", $path_to_file, $options);
337 | ```
338 |
339 | ### Pagination
340 | Use paginate() instead of get() to fetch paginated result
341 | ```php
342 | $page = 1;
343 | // set page limit to 2 results per page. 20 by default
344 | $db->pageLimit = 2;
345 | $products = $db->arraybuilder()->paginate("products", $page);
346 | echo "showing $page out of " . $db->totalPages;
347 |
348 | ```
349 |
350 | ### Result transformation / map
351 | Instead of getting an pure array of results its possible to get result in an associative array with a needed key. If only 2 fields to fetch will be set in get(),
352 | method will return result in array($k => $v) and array ($k => array ($v, $v)) in rest of the cases.
353 |
354 | ```php
355 | $user = $db->map ('login')->ObjectBuilder()->getOne ('users', 'login, id');
356 | Array
357 | (
358 | [user1] => 1
359 | )
360 |
361 | $user = $db->map ('login')->ObjectBuilder()->getOne ('users', 'id,login,createdAt');
362 | Array
363 | (
364 | [user1] => stdClass Object
365 | (
366 | [id] => 1
367 | [login] => user1
368 | [createdAt] => 2015-10-22 22:27:53
369 | )
370 |
371 | )
372 | ```
373 |
374 | ### Defining a return type
375 | MysqliDb can return result in 3 different formats: Array of Array, Array of Objects and a Json string. To select a return type use ArrayBuilder(), ObjectBuilder() and JsonBuilder() methods. Note that ArrayBuilder() is a default return type
376 | ```php
377 | // Array return type
378 | $u= $db->getOne("users");
379 | echo $u['login'];
380 | // Object return type
381 | $u = $db->ObjectBuilder()->getOne("users");
382 | echo $u->login;
383 | // Json return type
384 | $json = $db->JsonBuilder()->getOne("users");
385 | ```
386 |
387 | ### Running raw SQL queries
388 | ```php
389 | $users = $db->rawQuery('SELECT * from users where id >= ?', Array (10));
390 | foreach ($users as $user) {
391 | print_r ($user);
392 | }
393 | ```
394 | To avoid long if checks there are couple helper functions to work with raw query select results:
395 |
396 | Get 1 row of results:
397 | ```php
398 | $user = $db->rawQueryOne('SELECT * from users where id=?', Array(10));
399 | echo $user['login'];
400 | // Object return type
401 | $user = $db->ObjectBuilder()->rawQueryOne('SELECT * from users where id=?', Array(10));
402 | echo $user->login;
403 | ```
404 | Get 1 column value as a string:
405 | ```php
406 | $password = $db->rawQueryValue('SELECT password from users where id=? limit 1', Array(10));
407 | echo "Password is {$password}";
408 | NOTE: for a rawQueryValue() to return string instead of an array 'limit 1' should be added to the end of the query.
409 | ```
410 | Get 1 column value from multiple rows:
411 | ```php
412 | $logins = $db->rawQueryValue('SELECT login from users limit 10');
413 | foreach ($logins as $login)
414 | echo $login;
415 | ```
416 |
417 | More advanced examples:
418 | ```php
419 | $params = Array(1, 'admin');
420 | $users = $db->rawQuery("SELECT id, firstName, lastName FROM users WHERE id = ? AND login = ?", $params);
421 | print_r($users); // contains Array of returned rows
422 |
423 | // will handle any SQL query
424 | $params = Array(10, 1, 10, 11, 2, 10);
425 | $q = "(
426 | SELECT a FROM t1
427 | WHERE a = ? AND B = ?
428 | ORDER BY a LIMIT ?
429 | ) UNION (
430 | SELECT a FROM t2
431 | WHERE a = ? AND B = ?
432 | ORDER BY a LIMIT ?
433 | )";
434 | $results = $db->rawQuery ($q, $params);
435 | print_r ($results); // contains Array of returned rows
436 | ```
437 |
438 | ### Where / Having Methods
439 | `where()`, `orWhere()`, `having()` and `orHaving()` methods allows you to specify where and having conditions of the query. All conditions supported by where() are supported by having() as well.
440 |
441 | WARNING: In order to use column to column comparisons only raw where conditions should be used as column name or functions cannot be passed as a bind variable.
442 |
443 | Regular == operator with variables:
444 | ```php
445 | $db->where ('id', 1);
446 | $db->where ('login', 'admin');
447 | $results = $db->get ('users');
448 | // Gives: SELECT * FROM users WHERE id=1 AND login='admin';
449 |
450 | // Or you can also use Chain Loaders for above query
451 | $results = $db->where ('id', 1)
452 | ->where ('login', 'admin')
453 | ->get('users');
454 | ```
455 |
456 | ```php
457 | $db->where ('id', 1);
458 | $db->having ('login', 'admin');
459 | $results = $db->get ('users');
460 | // Gives: SELECT * FROM users WHERE id=1 HAVING login='admin';
461 | ```
462 |
463 |
464 | Regular == operator with column to column comparison:
465 | ```php
466 | // WRONG
467 | $db->where ('lastLogin', 'createdAt');
468 | // CORRECT
469 | $db->where ('lastLogin = createdAt');
470 | $results = $db->get ('users');
471 | // Gives: SELECT * FROM users WHERE lastLogin = createdAt;
472 | ```
473 |
474 | ```php
475 | $db->where ('id', 50, ">=");
476 | // or $db->where ('id', Array ('>=' => 50));
477 | $results = $db->get ('users');
478 | // Gives: SELECT * FROM users WHERE id >= 50;
479 | ```
480 |
481 | BETWEEN / NOT BETWEEN:
482 | ```php
483 | $db->where('id', Array (4, 20), 'BETWEEN');
484 | // or $db->where ('id', Array ('BETWEEN' => Array(4, 20)));
485 |
486 | $results = $db->get('users');
487 | // Gives: SELECT * FROM users WHERE id BETWEEN 4 AND 20
488 | ```
489 |
490 | IN / NOT IN:
491 | ```php
492 | $db->where('id', Array(1, 5, 27, -1, 'd'), 'IN');
493 | // or $db->where('id', Array( 'IN' => Array(1, 5, 27, -1, 'd') ) );
494 |
495 | $results = $db->get('users');
496 | // Gives: SELECT * FROM users WHERE id IN (1, 5, 27, -1, 'd');
497 | ```
498 |
499 | OR CASE:
500 | ```php
501 | $db->where ('firstName', 'John');
502 | $db->orWhere ('firstName', 'Peter');
503 | $results = $db->get ('users');
504 | // Gives: SELECT * FROM users WHERE firstName='John' OR firstName='peter'
505 | ```
506 |
507 | NULL comparison:
508 | ```php
509 | $db->where ("lastName", NULL, 'IS NOT');
510 | $results = $db->get("users");
511 | // Gives: SELECT * FROM users where lastName IS NOT NULL
512 | ```
513 |
514 | LIKE comparison:
515 | ```php
516 | $db->where ("fullName", 'John%', 'like');
517 | $results = $db->get("users");
518 | // Gives: SELECT * FROM users where fullName like 'John%'
519 | ```
520 |
521 | Also you can use raw where conditions:
522 | ```php
523 | $db->where ("id != companyId");
524 | $db->where ("DATE(createdAt) = DATE(lastLogin)");
525 | $results = $db->get("users");
526 | ```
527 |
528 | Or raw condition with variables:
529 | ```php
530 | $db->where ("(id = ? or id = ?)", Array(6,2));
531 | $db->where ("login","mike");
532 | $res = $db->get ("users");
533 | // Gives: SELECT * FROM users WHERE (id = 6 or id = 2) and login='mike';
534 | ```
535 |
536 |
537 | Find the total number of rows matched. Simple pagination example:
538 | ```php
539 | $offset = 10;
540 | $count = 15;
541 | $users = $db->withTotalCount()->get('users', Array ($offset, $count));
542 | echo "Showing {$count} from {$db->totalCount}";
543 | ```
544 |
545 | ### Query Keywords
546 | To add LOW PRIORITY | DELAYED | HIGH PRIORITY | IGNORE and the rest of the mysql keywords to INSERT (), REPLACE (), GET (), UPDATE (), DELETE() method or FOR UPDATE | LOCK IN SHARE MODE into SELECT ():
547 | ```php
548 | $db->setQueryOption ('LOW_PRIORITY')->insert ($table, $param);
549 | // GIVES: INSERT LOW_PRIORITY INTO table ...
550 | ```
551 | ```php
552 | $db->setQueryOption ('FOR UPDATE')->get ('users');
553 | // GIVES: SELECT * FROM USERS FOR UPDATE;
554 | ```
555 |
556 | Also you can use an array of keywords:
557 | ```php
558 | $db->setQueryOption (Array('LOW_PRIORITY', 'IGNORE'))->insert ($table,$param);
559 | // GIVES: INSERT LOW_PRIORITY IGNORE INTO table ...
560 | ```
561 |
562 | Same way keywords could be used in SELECT queries as well:
563 | ```php
564 | $db->setQueryOption ('SQL_NO_CACHE');
565 | $db->get("users");
566 | // GIVES: SELECT SQL_NO_CACHE * FROM USERS;
567 | ```
568 |
569 | Optionally you can use method chaining to call where multiple times without referencing your object over and over:
570 |
571 | ```php
572 | $results = $db
573 | ->where('id', 1)
574 | ->where('login', 'admin')
575 | ->get('users');
576 | ```
577 |
578 | ### Delete Query
579 | ```php
580 | $db->where('id', 1);
581 | if($db->delete('users')) echo 'successfully deleted';
582 | ```
583 |
584 |
585 | ### Ordering method
586 | ```php
587 | $db->orderBy("id","asc");
588 | $db->orderBy("login","Desc");
589 | $db->orderBy("RAND ()");
590 | $results = $db->get('users');
591 | // Gives: SELECT * FROM users ORDER BY id ASC,login DESC, RAND ();
592 | ```
593 |
594 | Order by values example:
595 | ```php
596 | $db->orderBy('userGroup', 'ASC', array('superuser', 'admin', 'users'));
597 | $db->get('users');
598 | // Gives: SELECT * FROM users ORDER BY FIELD (userGroup, 'superuser', 'admin', 'users') ASC;
599 | ```
600 |
601 | If you are using setPrefix () functionality and need to use table names in orderBy() method make sure that table names are escaped with ``.
602 |
603 | ```php
604 | $db->setPrefix ("t_");
605 | $db->orderBy ("users.id","asc");
606 | $results = $db->get ('users');
607 | // WRONG: That will give: SELECT * FROM t_users ORDER BY users.id ASC;
608 |
609 | $db->setPrefix ("t_");
610 | $db->orderBy ("`users`.id", "asc");
611 | $results = $db->get ('users');
612 | // CORRECT: That will give: SELECT * FROM t_users ORDER BY t_users.id ASC;
613 | ```
614 |
615 | ### Grouping method
616 | ```php
617 | $db->groupBy ("name");
618 | $results = $db->get ('users');
619 | // Gives: SELECT * FROM users GROUP BY name;
620 | ```
621 |
622 | ### JOIN method
623 | Join table products with table users with LEFT JOIN by tenantID
624 | ```php
625 | $db->join("users u", "p.tenantID=u.tenantID", "LEFT");
626 | $db->where("u.id", 6);
627 | $products = $db->get ("products p", null, "u.name, p.productName");
628 | print_r ($products);
629 | // Gives: SELECT u.name, p.productName FROM products p LEFT JOIN users u ON p.tenantID=u.tenantID WHERE u.id = 6
630 | ```
631 |
632 | ### Join Conditions
633 | Add AND condition to join statement
634 | ```php
635 | $db->join("users u", "p.tenantID=u.tenantID", "LEFT");
636 | $db->joinWhere("users u", "u.tenantID", 5);
637 | $products = $db->get ("products p", null, "u.name, p.productName");
638 | print_r ($products);
639 | // Gives: SELECT u.name, p.productName FROM products p LEFT JOIN users u ON (p.tenantID=u.tenantID AND u.tenantID = 5)
640 | ```
641 | Add OR condition to join statement
642 | ```php
643 | $db->join("users u", "p.tenantID=u.tenantID", "LEFT");
644 | $db->joinOrWhere("users u", "u.tenantID", 5);
645 | $products = $db->get ("products p", null, "u.name, p.productName");
646 | print_r ($products);
647 | // Gives: SELECT u.login, p.productName FROM products p LEFT JOIN users u ON (p.tenantID=u.tenantID OR u.tenantID = 5)
648 | ```
649 |
650 | ### Properties sharing
651 | It is also possible to copy properties
652 |
653 | ```php
654 | $db->where ("agentId", 10);
655 | $db->where ("active", true);
656 |
657 | $customers = $db->copy ();
658 | $res = $customers->get ("customers", Array (10, 10));
659 | // SELECT * FROM customers WHERE agentId = 10 AND active = 1 LIMIT 10, 10
660 |
661 | $cnt = $db->getValue ("customers", "count(id)");
662 | echo "total records found: " . $cnt;
663 | // SELECT count(id) FROM customers WHERE agentId = 10 AND active = 1
664 | ```
665 |
666 | ### Subqueries
667 | Subquery init
668 |
669 | Subquery init without an alias to use in inserts/updates/where Eg. (select * from users)
670 | ```php
671 | $sq = $db->subQuery();
672 | $sq->get ("users");
673 | ```
674 |
675 | A subquery with an alias specified to use in JOINs . Eg. (select * from users) sq
676 | ```php
677 | $sq = $db->subQuery("sq");
678 | $sq->get ("users");
679 | ```
680 |
681 | Subquery in selects:
682 | ```php
683 | $ids = $db->subQuery ();
684 | $ids->where ("qty", 2, ">");
685 | $ids->get ("products", null, "userId");
686 |
687 | $db->where ("id", $ids, 'in');
688 | $res = $db->get ("users");
689 | // Gives SELECT * FROM users WHERE id IN (SELECT userId FROM products WHERE qty > 2)
690 | ```
691 |
692 | Subquery in inserts:
693 | ```php
694 | $userIdQ = $db->subQuery ();
695 | $userIdQ->where ("id", 6);
696 | $userIdQ->getOne ("users", "name"),
697 |
698 | $data = Array (
699 | "productName" => "test product",
700 | "userId" => $userIdQ,
701 | "lastUpdated" => $db->now()
702 | );
703 | $id = $db->insert ("products", $data);
704 | // Gives INSERT INTO PRODUCTS (productName, userId, lastUpdated) values ("test product", (SELECT name FROM users WHERE id = 6), NOW());
705 | ```
706 |
707 | Subquery in joins:
708 | ```php
709 | $usersQ = $db->subQuery ("u");
710 | $usersQ->where ("active", 1);
711 | $usersQ->get ("users");
712 |
713 | $db->join($usersQ, "p.userId=u.id", "LEFT");
714 | $products = $db->get ("products p", null, "u.login, p.productName");
715 | print_r ($products);
716 | // SELECT u.login, p.productName FROM products p LEFT JOIN (SELECT * FROM t_users WHERE active = 1) u on p.userId=u.id;
717 | ```
718 |
719 | ### EXISTS / NOT EXISTS condition
720 | ```php
721 | $sub = $db->subQuery();
722 | $sub->where("company", 'testCompany');
723 | $sub->get ("users", null, 'userId');
724 | $db->where (null, $sub, 'exists');
725 | $products = $db->get ("products");
726 | // Gives SELECT * FROM products WHERE EXISTS (SELECT userId FROM users WHERE company='testCompany')
727 | ```
728 |
729 | ### Has method
730 | A convenient function that returns TRUE if exists at least an element that satisfy the where condition specified calling the "where" method before this one.
731 | ```php
732 | $db->where("user", $user);
733 | $db->where("password", md5($password));
734 | if($db->has("users")) {
735 | return "You are logged";
736 | } else {
737 | return "Wrong user/password";
738 | }
739 | ```
740 | ### Helper methods
741 | Disconnect from the database:
742 | ```php
743 | $db->disconnect();
744 | ```
745 |
746 | Reconnect in case mysql connection died:
747 | ```php
748 | if (!$db->ping())
749 | $db->connect()
750 | ```
751 |
752 | Get last executed SQL query:
753 | Please note that this method returns the SQL query only for debugging purposes as its execution most likely will fail due to missing quotes around char variables.
754 | ```php
755 | $db->get('users');
756 | echo "Last executed query was ". $db->getLastQuery();
757 | ```
758 |
759 | Check if table exists:
760 | ```php
761 | if ($db->tableExists ('users'))
762 | echo "hooray";
763 | ```
764 |
765 | mysqli_real_escape_string() wrapper:
766 | ```php
767 | $escaped = $db->escape ("' and 1=1");
768 | ```
769 |
770 | ### Transaction helpers
771 | Please keep in mind that transactions are working on innoDB tables.
772 | Rollback transaction if insert fails:
773 | ```php
774 | $db->startTransaction();
775 | ...
776 | if (!$db->insert ('myTable', $insertData)) {
777 | //Error while saving, cancel new record
778 | $db->rollback();
779 | } else {
780 | //OK
781 | $db->commit();
782 | }
783 | ```
784 |
785 |
786 | ### Error helpers
787 | After you executed a query you have options to check if there was an error. You can get the MySQL error string or the error code for the last executed query.
788 | ```php
789 | $db->where('login', 'admin')->update('users', ['firstName' => 'Jack']);
790 |
791 | if ($db->getLastErrno() === 0)
792 | echo 'Update succesfull';
793 | else
794 | echo 'Update failed. Error: '. $db->getLastError();
795 | ```
796 |
797 | ### Query execution time benchmarking
798 | To track query execution time setTrace() function should be called.
799 | ```php
800 | $db->setTrace (true);
801 | // As a second parameter it is possible to define prefix of the path which should be striped from filename
802 | // $db->setTrace (true, $_SERVER['SERVER_ROOT']);
803 | $db->get("users");
804 | $db->get("test");
805 | print_r ($db->trace);
806 | ```
807 |
808 | ```
809 | [0] => Array
810 | (
811 | [0] => SELECT * FROM t_users ORDER BY `id` ASC
812 | [1] => 0.0010669231414795
813 | [2] => MysqliDb->get() >> file "/avb/work/PHP-MySQLi-Database-Class/tests.php" line #151
814 | )
815 |
816 | [1] => Array
817 | (
818 | [0] => SELECT * FROM t_test
819 | [1] => 0.00069189071655273
820 | [2] => MysqliDb->get() >> file "/avb/work/PHP-MySQLi-Database-Class/tests.php" line #152
821 | )
822 |
823 | ```
824 |
825 | ### Table Locking
826 | To lock tables, you can use the **lock** method together with **setLockMethod**.
827 | The following example will lock the table **users** for **write** access.
828 | ```php
829 | $db->setLockMethod("WRITE")->lock("users");
830 | ```
831 |
832 | Calling another **->lock()** will remove the first lock.
833 | You can also use
834 | ```php
835 | $db->unlock();
836 | ```
837 | to unlock the previous locked tables.
838 | To lock multiple tables, you can use an array.
839 | Example:
840 | ```php
841 | $db->setLockMethod("READ")->lock(array("users", "log"));
842 | ```
843 | This will lock the tables **users** and **log** for **READ** access only.
844 | Make sure you use **unlock()* afterwards or your tables will remain locked!
845 |
846 |
--------------------------------------------------------------------------------