License: GNU GPL-3.0 or later Description: This library extends the builtin PDO object by several useful features. Version: 1.0.0 Milestones: 2015-10-09 23:52 Igor - Created for Beteha 2015-12-01 23:09 Igor - Added LEFT a RIGHT JOIN, added flag DEBUG, userd for print of query 2016-07-28 09:44 Igor - Added return of associative array 2025-05-27 20:43 Igor - Forked from Beteha to standalone public library */ namespace TPsoft\DBmodel; class DBmodel { public static DBmodel $instance; public \PDO $dbh; public \PDOStatement $stmt; private $type = 'mysql'; private $oldErrorHandler; public $debug = false; public $log = null; public $tables = array(); public function __construct(string $dsn = null, ?string $username = null, #[\SensitiveParameter] ?string $password = null, ?array $options = null) { if (is_null($dsn)) { if (DBmodel::$instance) { $this->dbh = DBmodel::$instance->dbh; } else { throw new \Exception('DB handler from DBmodel::$instance is null'); } } else { $this->dbh = new \PDO($dsn, $username, $password, $options); DBmodel::$instance = $this; } if (is_null($this->dbh)) { throw new \Exception('DB handler is null'); } } public function _debug($msg) { if (!is_null($this->log)) { call_user_func_array($this->log, array($msg)); } if ((is_bool($this->debug) && $this->debug == true) || (is_numeric($this->debug) && $this->debug-- <= 0) ) { throw new \Exception($msg); } } /* ---------------------------------------------------- * CORE METHODS */ public function tableInfoExist($table_id, $info) { return (isset($this->tables) && isset($this->tables[$table_id]) && isset($this->tables[$table_id][$info])); } public function tableInfo($table_id, $info) { if ( !isset($this->tables) || !isset($this->tables[$table_id]) || !isset($this->tables[$table_id][$info]) ) { throw new \Exception('Error: Incorrect table "' . $info . '" for table ID "' . $table_id . '"'); } return $this->tables[$table_id][$info]; } public function tableInfoSet($table_id, $info, $content) { $this->tables[$table_id][$info] = $content; } public function tableName($table_id) { return $this->tableInfo($table_id, 'name'); } public function primaryKeyName($table_id) { return $this->tableInfo($table_id, 'primary_key_name'); } public function allowAttributes($table_id) { $allow_attributes = $this->tableInfo($table_id, 'allow_attributes'); if (count($allow_attributes) <= 0) return array(); $keys = array_keys($allow_attributes); return (strlen($keys[0]) <= 1) ? $allow_attributes : array_keys($allow_attributes); } public function typesAttributes($table_id) { if ($this->tableInfoExist($table_id, 'allow_attributes_types')) { return $this->tableInfo($table_id, 'allow_attributes_types'); } $allow_attributes = $this->tableInfo($table_id, 'allow_attributes'); if (count($allow_attributes) <= 0) return false; $keys = array_keys($allow_attributes); if (strlen($keys[0]) <= 1) { $this->tableInfoSet($table_id, 'allow_attributes_types', false); return false; } $types = array(); foreach ($allow_attributes as $key => $type) { $type = str_replace(' ', '', $type); $type = str_replace('(', '|', $type); $type = str_replace(')', '|', $type); $type_parts = explode('|', $type); $rettype = array( 'format' => strtolower(@$type_parts[0]), 'length' => @$type_parts[1] ); if (strtolower($rettype['format']) == 'enum') { $allowed_values = explode(',', $rettype['length']); foreach ($allowed_values as $index => $part) $allowed_values[$index] = trim($part, '"\''); $rettype['allowed_values'] = $allowed_values; $rettype['length'] = count($allowed_values); } $types[$key] = $rettype; } $this->tableInfoSet($table_id, 'allow_attributes_types', $types); return $types; } private function buildWherePrimaryKey($table_id, $primary_key) { $primary_key_name = $this->primaryKeyName($table_id); if (is_array($primary_key_name)) { if (!is_array($primary_key)) { throw new \Exception('Error: table ' . $table_id . ' required multikey select'); } $conds = array(); foreach ($primary_key_name as $name) { $conds[] = sprintf('`%s` = %s', $name, $this->quote($primary_key[$name])); } $where = implode(' AND ', $conds); } else { $pk = is_array($primary_key) ? $primary_key[$primary_key_name] : $primary_key; $where = sprintf('`%s` = %s', $primary_key_name, $this->quote($pk)); } return $where; } public function existTable($table_id) { $query = sprintf( 'SHOW TABLES LIKE "%s"', $this->tableName($table_id) ); return $this->getOne($query) == $this->tableName($table_id); } public function existRecord($table_id, $primary_key) { if ( is_null($primary_key) || (is_string($primary_key) && strlen(trim($primary_key)) <= 0) ) { return false; } $query = sprintf( 'SELECT COUNT(*)' . ' FROM %s' . ' WHERE %s', $this->tableName($table_id), $this->buildWherePrimaryKey($table_id, $primary_key) ); return $this->getOne($query) == 1; } public function record($table_id, $primary_key = null, $data = array()) { $action = null; $action = (!is_null($primary_key) && is_array($data) && count($data) <= 0) ? 'SELECT' : $action; $action = (is_null($primary_key) && is_array($data) && count($data) > 0) ? 'INSERT' : $action; $action = (!is_null($primary_key) && is_array($data) && count($data) > 0) ? 'UPDATE' : $action; $action = (!is_null($primary_key) && is_null($data)) ? 'DELETE' : $action; if (is_null($action)) { $this->_debug('[DBmodel][record]: action = null'); return false; } $table = $this->tableName($table_id); $primary_key_name = $this->primaryKeyName($table_id); $allow_attributes = $this->allowAttributes($table_id); $data = $this->fixDecimalPoints($table_id, $data); $data = $this->fixBooleans($table_id, $data); $data = $this->fixJSONs($table_id, $data); $data = $this->fixTypes($table_id, $data); if ($action == 'SELECT') { if (!$this->existRecord($table_id, $primary_key)) { return false; } $query = sprintf( 'SELECT *' . ' FROM %s' . ' WHERE %s' . ' LIMIT 1', $table, $this->buildWherePrimaryKey($table_id, $primary_key) ); $this->_debug('[DBmodel][record][SELECT]: ' . $query); $ret = $this->getRow($query); $ret = $this->unfixJSONs($table_id, $ret); if ($ret === false) { throw new \Exception('Error: unfixJSONs failed'); } return $ret; } if ($action == 'INSERT') { // check all required primary keys $primary_key_names = is_array($primary_key_name) ? $primary_key_name : array($primary_key_name); foreach ($primary_key_names as $pk_name) { if ( in_array($pk_name, $allow_attributes) && (!isset($data[$pk_name]) || is_null($data[$pk_name]) || strlen($data[$pk_name]) <= 0) ) { $this->_debug('[DBmodel][record][INSERT]: missing primary key in data'); return false; } } $keys = ''; $values = ''; $delimiter = ''; foreach ($data as $key => $value) { $key = trim($key); if (!in_array($key, $allow_attributes)) { continue; } if (is_array($value)) { $value = implode(',', array_keys($value)); } $keys .= $delimiter . '`' . $key . '`'; if (is_string($value) && $value === '`NOW`') $value = date('Y-m-d H:i:s'); $values .= (strlen($value) > 0) ? $delimiter . $this->quote($value) : $delimiter . 'NULL'; $delimiter = ','; } $query = sprintf( 'INSERT INTO %s' . ' (%s)' . ' VALUES' . ' (%s)', $table, $keys, $values ); $this->_debug('[DBmodel][record][INSERT]: ' . $query); $ret = $this->query($query); if ($ret === false) { throw new \Exception($this->errorMessage()); } if ($this->affectedRows() != 1) { return false; } if (count($primary_key_names) > 1) return true; if (method_exists($this->dbh, 'getLastInsertID')) { $last_id = $this->getLastInsertID(); } else { $last_id = $this->getOne('SELECT last_insert_id()'); } return $last_id; } if ($action == 'UPDATE') { if (!$this->existRecord($table_id, $primary_key)) { if (is_array($primary_key)) { return $this->record($table_id, null, array_merge($data, $primary_key)); } $this->_debug('Record with primary key = ' . json_encode($primary_key) . ' was not exists'); return false; } $set = ''; $delimiter = ''; foreach ($data as $key => $value) { $key = trim($key); if (!in_array($key, $allow_attributes)) { continue; } if (is_array($value)) { $value = implode(',', array_keys($value)); } $q_val = (strlen($value) > 0) ? $this->quote($value) : 'NULL'; $q_val = (substr($value, 0, 1) == '_' && substr($value, -1) == '_') ? substr($value, 1, -1) : $q_val; $q_val = (is_string($value) && $value === '`NOW`') ? $this->quote(date('Y-m-d H:i:s')) : $q_val; $set .= $delimiter . '`' . $key . '` = ' . $q_val; $delimiter = ','; } $query = sprintf( 'UPDATE %s' . ' SET %s' . ' WHERE %s' . ' LIMIT 1', $table, $set, $this->buildWherePrimaryKey($table_id, $primary_key) ); $this->_debug('[DBmodel][record][UPDATE]: ' . $query); $ret = $this->query($query); if ($ret === false) { throw new \Exception($this->errorMessage()); } /* data is not always updated, if the same data is updated if ($this->affectedRows() != 1) { $this->_debug('Error during uprade: ' . $query); return false; } */ return $primary_key; } if ($action == 'DELETE') { if (!$this->existRecord($table_id, $primary_key)) { $this->_debug('Record with primary key = "' . $primary_key . '" was not exists'); return false; } $query = sprintf( 'DELETE FROM %s' . ' WHERE %s' . ' LIMIT 1', $table, $this->buildWherePrimaryKey($table_id, $primary_key) ); $this->_debug('[DBmodel][record][DELETE]: ' . $query); $ret = $this->query($query); if ($ret === false) { throw new \Exception($this->errorMessage()); } if ($this->affectedRows() != 1) { return false; } return true; } return false; } public function recordBy($table_id, $colname, $colvalue) { if ( is_null($colname) || is_null($colvalue) || !is_string($colname) || strlen(trim($colname)) <= 0 || !is_string($colvalue) || strlen(trim($colvalue)) <= 0 ) { return false; } $data = array($colname => $colvalue); $data = $this->fixDecimalPoints($table_id, $data); $data = $this->fixBooleans($table_id, $data); $data = $this->fixJSONs($table_id, $data); $data = $this->fixTypes($table_id, $data); if (!is_array($data) || count($data) <= 0) return false; $allow_attributes = $this->allowAttributes($table_id); $where = ''; $delimiter = ''; foreach ($data as $key => $value) { $key = trim($key); if (!in_array($key, $allow_attributes)) continue; if (is_array($value)) $value = implode(',', array_keys($value)); $q_val = (strlen($value) > 0) ? $this->quote($value) : 'NULL'; $q_val = (substr($value, 0, 1) == '_' && substr($value, -1) == '_') ? substr($value, 1, -1) : $q_val; $q_val = (is_string($value) && $value === '`NOW`') ? $this->quote(date('Y-m-d H:i:s')) : $q_val; $where .= $delimiter . '`' . $key . '` = ' . $q_val; $delimiter = ' AND '; } $query = sprintf( 'SELECT *' . ' FROM %s' . ' WHERE %s', $this->tableName($table_id), $where ); $this->_debug('[DBmodel][recordBy]: ' . $query); $ret = $this->getRow($query); $ret = $this->unfixJSONs($table_id, $ret); return $ret; } public function recordEmpty($table_id) { $allow = $this->allowAttributes($table_id); if (!is_array($allow)) { return false; } $ret = array(); foreach ($allow as $a) { $ret[$a] = null; } return $ret; } public function count($table_id) { $query = sprintf( 'SELECT COUNT(*)' . ' FROM %s', $this->tableName($table_id) ); return $this->getOne($query); } public function search($table_id, $tab_hash = 'tab') { $qb = new QueryBuilder($this); return $qb->beginAction('SELECT', $table_id, $tab_hash); } public function insert($table_id, $tab_hash = 'tab') { $qb = new QueryBuilder($this); return $qb->beginAction('INSERT', $table_id, $tab_hash); } public function update($table_id, $tab_hash = 'tab') { $qb = new QueryBuilder($this); return $qb->beginAction('UPDATE', $table_id, $tab_hash); } public function delete($table_id, $tab_hash = 'tab') { $qb = new QueryBuilder($this); return $qb->beginAction('DELETE', $table_id, $tab_hash); } public function optimize($table_id) { $query = sprintf('OPTIMIZE TABLE `%s`', $this->tableName($table_id)); $this->_debug('[DBmodel][optimize]: ' . $query); $ret = $this->query($query); if ($ret === false) { throw new \Exception($this->errorMessage()); } return true; } public function toGroupBy($arr, $col_name) { $ret = array(); foreach ($arr as $row) { if (!isset($ret[$row[$col_name]])) { $ret[$row[$col_name]] = array(); } $ret[$row[$col_name]][] = $row; } return $ret; } /* ---------------------------------------------------- * BASIC DB METHODS */ public function query(string $query, ?int $fetch_mode = null, ?int $colno = null): bool|\PDOStatement { $this->_debug('[DBmodel][query]: ' . $query); if ($fetch_mode == \PDO::FETCH_COLUMN) { if (is_null($colno)) $colno = 0; $this->stmt = $this->dbh->query($query, $fetch_mode, $colno); } else { $this->stmt = $this->dbh->query($query, $fetch_mode); } return $this->stmt; } public function getOne(string $query): string|false { $result = $this->query($query, \PDO::FETCH_NUM); if ($result === false) { return false; } $row = $result->fetch(\PDO::FETCH_NUM); if (!is_array($row) || count($row) <= 0) return false; return $row[0]; } public function getRow(string $query): array|false { $result = $this->query($query, \PDO::FETCH_ASSOC); if ($result === false) { return false; } $row = $result->fetch(\PDO::FETCH_ASSOC); return $row; } public function getCol(string $query): array|false { $result = $this->query($query, \PDO::FETCH_COLUMN); if ($result === false) { return false; } $return = []; while ($row = $result->fetchColumn()) { $return[] = $row; } return $return; } public function getAll(string $query): array|false { $result = $this->query($query, \PDO::FETCH_ASSOC); if ($result === false) { return false; } return $result->fetchAll(\PDO::FETCH_ASSOC); } public function affectedRows(): int { if ( $this->stmt === false || $this->stmt === null ) return 0; return $this->stmt->rowCount(); } public function quote(string $value): string { return $this->dbh->quote($value); } public function getLastInsertID(?string $name = null): ?string { if ($this->type === 'pgsql') { $id = $this->dbh->query('SELECT LASTVAL()')->fetchColumn(); return (string) $id ?: null; } return $this->dbh->lastInsertId($name); } public function errorMessage(): string { return implode(':', $this->dbh->errorInfo()); } public function getTableColumns($table_name) { $desc = $this->getAll(sprintf('DESC %s', $table_name)); $desc = $this->arrayKeysToLowerCase($desc); $pks = array(); $columns = array(); foreach ($desc as $d) { $colname = strtolower($d['field']); $types[$colname] = $d['type']; if ($d['key'] == 'PRI') { $pks[] = $colname; if (strtolower($d['extra']) != 'auto_increment') { $columns[] = $colname; } } else { $columns[] = $colname; } } return array('pks' => $pks, 'columns' => $columns, 'types' => $types); } /* ---------------------------------------------------- * HELPER METHODS */ public function fixTypes($table_id, $data, $where_prefixes = array()) { $types = $this->typesAttributes($table_id); if ($types === false || !is_array($data)) return $data; $data_keys = array_keys($data); if (is_array($types)) foreach ($types as $column => $type) { if (!in_array($column, $data_keys)) continue; if (is_null($data[$column])) continue; // kontrola special $val = $data[$column]; if (is_array($val)) continue; $prefix = $this->extractPrefix($val, $where_prefixes); $n_val = str_replace($prefix, '', $val); if (substr($n_val, 0, 1) == '`' && substr($n_val, -1) == '`') continue; // kontrola formatu $max_length = null; $min_number = null; $max_number = null; $allowed_values = null; switch (strtolower($type['format'])) { case 'varchar': $max_length = intval($type['length']); break; case 'tinyblob': case 'tinytext': $max_length = 255; break; case 'text': case 'blob': $max_length = 65535; break; case 'mediumblob': case 'mediumtext': $max_length = 16777216; break; case 'longblob': case 'longtext': $max_length = 4294967296; break; case 'tinyint': $min_number = -128; $max_number = 128; break; // 1B case 'smallint': $min_number = -32768; $max_number = 32768; break; // 2B case 'mediumint': $min_number = -8388608; $max_number = 8388608; break; // 3B case 'integer': case 'int': $min_number = -2147483648; $max_number = 2147483648; break; // 4B case 'bigint': $min_number = -1 * pow(2, 63); $max_number = pow(2, 63); break; // 8B case 'decimal': if (is_array($data[$column])) { foreach ($data[$column] as $key => $val) { $prefix = $this->extractPrefix($val, $where_prefixes); $data[$column] = $prefix . $this->fixDecimalMysql($val, $type['length']); } } else { $prefix = $this->extractPrefix($data[$column], $where_prefixes); $data[$column] = $prefix . $this->fixDecimalMysql($data[$column], $type['length']); } break; case 'float': if (is_array($data[$column])) { foreach ($data[$column] as $key => $val) { $prefix = $this->extractPrefix($val, $where_prefixes); $data[$column][$key] = $prefix . $this->fixDecimalPoint(floatval($this->fixDecimalPoint($val))); } } else { $prefix = $this->extractPrefix($data[$column], $where_prefixes); $data[$column] = $prefix . $this->fixDecimalPoint(floatval($this->fixDecimalPoint($data[$column]))); } break; case 'enum': $allowed_values = $type['allowed_values']; break; case 'date': if (is_array($data[$column])) { foreach ($data[$column] as $key => $val) { $prefix = $this->extractPrefix($val, $where_prefixes); $n_val = str_replace($prefix, '', $val); $data[$column] = $prefix . date('Y-m-d', strtotime($n_val)); } } else { $prefix = $this->extractPrefix($data[$column], $where_prefixes); $n_val = str_replace($prefix, '', $data[$column]); $data[$column] = $prefix . date('Y-m-d', strtotime($n_val)); } break; case 'datetime': if (is_array($data[$column])) { foreach ($data[$column] as $key => $val) { $prefix = $this->extractPrefix($val, $where_prefixes); $n_val = str_replace($prefix, '', $val); $data[$column] = $prefix . date('Y-m-d H:i:s', strtotime($n_val)); } } else { $prefix = $this->extractPrefix($data[$column], $where_prefixes); $n_val = str_replace($prefix, '', $data[$column]); $data[$column] = $prefix . date('Y-m-d H:i:s', strtotime($n_val)); } break; } if (!is_null($max_length)) { if (strlen($data[$column]) > $max_length) { if (is_array($data[$column])) { foreach ($data[$column] as $key => $val) { $data[$column][$key] = mb_substr($val, 0, $max_length); } } else { $data[$column] = mb_substr($data[$column], 0, $max_length); } } } if (!is_null($min_number)) { if (is_array($data[$column])) { foreach ($data[$column] as $key => $val) { $prefix = $this->extractPrefix($val, $where_prefixes); $n_val = str_replace($prefix, '', $val); $data[$column][$key] = $prefix . max(intval($n_val), $min_number); } } else { $prefix = $this->extractPrefix($data[$column], $where_prefixes); $n_val = str_replace($prefix, '', $data[$column]); $data[$column] = $prefix . max(intval($n_val), $min_number); } } if (!is_null($max_number)) { if (is_array($data[$column])) { foreach ($data[$column] as $key => $val) { $prefix = $this->extractPrefix($val, $where_prefixes); $n_val = str_replace($prefix, '', $val); $data[$column][$key] = $prefix . min(intval($n_val), $max_number); } } else { $prefix = $this->extractPrefix($data[$column], $where_prefixes); $n_val = str_replace($prefix, '', $data[$column]); $data[$column] = $prefix . min(intval($n_val), $max_number); } } if (!is_null($allowed_values)) { if (is_array($data[$column])) { foreach ($data[$column] as $key => $val) { if (!in_array($val, $allowed_values)) $data[$column][$key] = null; } } else { if (!in_array($data[$column], $allowed_values)) $data[$column] = null; } } } return $data; } public function fixDecimalMysql($num, $length) { $lengths = explode(',', $length); $lengths_0 = intval($lengths[0]); $lengths_1 = intval($lengths[1]); $num = $this->fixDecimalPoint($num); $num_parts = explode('.', $num); if (!is_array($num_parts)) return 0; if (count($num_parts) == 0) return intval($num); if (count($num_parts) == 1) return intval($num_parts[0]); $num = intval(substr($num_parts[0], 0, $lengths_0 - $lengths_1)) . '.' . $this->allowedChars(substr($num_parts[1] . str_repeat('0', $lengths_1), 0, $lengths_1), '0123456789'); return $num; } public function fixDecimalPoint($num) { return str_replace(',', '.', $num); } public function fixDecimalPoints($table_id, $data) { if (!$this->tableInfoExist($table_id, 'fix_decimal_points')) return $data; $for_fix = $this->tableInfo($table_id, 'fix_decimal_points'); if (is_array($data)) foreach ($data as $key => $val) { if (in_array($key, $for_fix)) { $data[$key] = $this->fixDecimalPoint($val); } } return $data; } public function fixBoolean($val) { return in_array(strtolower($val), array('on', 'true', '1', 'yes', 'ano', 'checked', 'selected')) ? 1 : 0; } public function fixBooleans($table_id, $data) { if (!$this->tableInfoExist($table_id, 'fix_booleans')) return $data; $for_fix = $this->tableInfo($table_id, 'fix_booleans'); if (is_array($data)) foreach ($data as $key => $val) { if (in_array($key, $for_fix)) { $data[$key] = $this->fixBoolean($val); } } return $data; } public function forceBooleans($table_id, &$data) { if (!$this->tableInfoExist($table_id, 'fix_booleans')) return $data; $for_fix = $this->tableInfo($table_id, 'fix_booleans'); if (is_array($for_fix)) foreach ($for_fix as $key) { $data[$key] = $this->fixBoolean($data[$key]); } return $data; } public function fixJSON($val) { return json_encode($val); } public function fixJSONs($table_id, $data) { if (!$this->tableInfoExist($table_id, 'fix_json')) return $data; $for_fix = $this->tableInfo($table_id, 'fix_json'); if (is_array($data)) foreach ($data as $key => $val) { if (in_array($key, $for_fix)) { $data[$key] = $this->fixJSON($val); } } return $data; } public function unfixJSON($val) { if (!is_string($val)) return $val; try { $decoded = json_decode($val, true); return $decoded; } catch (\Exception $e) { return $val; } } public function unfixJSONs($table_id, $data) { if (!$this->tableInfoExist($table_id, 'fix_json')) return $data; $for_fix = $this->tableInfo($table_id, 'fix_json'); if (is_array($data)) foreach ($data as $key => $val) { if (in_array($key, $for_fix)) { $data[$key] = $this->unfixJSON($val); } } return $data; } public function preventOneError() { $this->oldErrorHandler = set_error_handler(array($this, 'silentErrorHandler')); } public function allowNextError() { if (is_null($this->oldErrorHandler)) { return false; } set_error_handler($this->oldErrorHandler); $this->oldErrorHandler = null; return true; } public function silentErrorHandler($errno, $errstr, $errfile, $errline) { return $this->allowNextError(); } public function import($objModel) { if (is_null($objModel)) return false; if ( !isset($objModel->tables) || !is_array($objModel->tables) ) return false; $this->tables = array_merge($this->tables, $objModel->tables); return is_array($this->tables); } public function textSearch($find, $table_id = null) { if (is_null($table_id)) { $ret = array(); if (is_array($this->tables)) foreach ($this->tables as $t_id => $table_settings) { $ret = array_merge($ret, $this->textSearch($find, $t_id)); } return $ret; } $allow_attributes = $this->tableInfo($table_id, 'allow_attributes'); if (!is_array($allow_attributes) || count($allow_attributes) <= 0) return array(); $keys = array_keys($allow_attributes); if (strlen($keys[0]) <= 1) { // stary format bez typov $table_columns = $this->getTableColumns($this->tableName($table_id)); $attributes = $table_columns['types']; } else { // novy format s typmi $attributes = $allow_attributes; } if (!is_array($attributes) || count($attributes) <= 0) return array(); $forsearch = array(); foreach ($attributes as $name => $type) { if ($this->checkPrefix(array('varchar', 'tinyblob', 'tinytext', 'text', 'blob', 'mediumblob', 'mediumtext', 'longblob', 'longtext'), $type, true)) { $forsearch[] = $name; } } if (count($forsearch) <= 0) return array(); foreach ($forsearch as $colname) $conds[] = sprintf('`%s` LIKE %s', $colname, $this->quote('%' . $find . '%')); $query = sprintf('SELECT * FROM %s WHERE %s', $this->tableName($table_id), implode(' OR ', $conds)); $all = $this->getAll($query); $ret = array(); $pk_name = $this->primaryKeyName($table_id); if (is_array($all)) foreach ($all as $row) { if (is_array($pk_name)) { $pk = array(); foreach ($pk_name as $pkn) $pk[$pkn] = $row[$pkn]; } else { $pk = $row[$pk_name]; } $ret[] = array( 'table_id' => $table_id, 'record_id' => $pk, 'name' => $row['name'], 'context' => $this->context($find, implode(' ', array_values($row))) ); } return $ret; } public function extractPrefix($str, $prefixes) { if (is_null($prefixes)) return ''; if (!is_array($prefixes)) $prefixes = array($prefixes); usort($prefixes, function ($a, $b) { return strlen($b) - strlen($a); }); foreach ($prefixes as $prefix) { if ($this->checkPrefix($prefix, $str)) return $prefix; } return ''; } public function checkPrefix($prefix, $str, $case_insensitive = false) { if (is_array($prefix)) { foreach ($prefix as $one) { if ($this->checkPrefix($one, $str, $case_insensitive)) return true; } return false; } if ($case_insensitive) { $prefix = strtolower($prefix); $str = strtolower($str); } return $prefix == substr($str, 0, strlen($prefix)); } public function allowedChars($str, $allowed = 'abcdefghijklmnopqrstuvwxyz0123456789') { $ret = ''; for ($i = 0; $i < strlen($str); $i++) { $char = substr($str, $i, 1); if (strpos($allowed, $char) !== false) { $ret .= $char; } } return $ret; } public function context($findme, $string, $around_words = 2) { $findme = strtolower($findme); $parts = explode(' ', $string); $is = array(); for ($i = 0; $i < count($parts); $i++) { if (strtolower($parts[$i]) == $findme) { for ($j = max(0, $i - $around_words); $j < min(count($parts) - 1, $i + $around_words); $j++) { if (!in_array($j, $is)) $is[] = $j; } } } $out = ''; $last_i = 0; foreach ($is as $i) { if ($last_i + 1 < $i) $out .= ' ...'; $out .= ' ' . $parts[$i]; $last_i = $i; } return $out . ' ...'; } public function arrayKeysToLowerCase(array $array, int $case = CASE_LOWER): array { $newArray = []; foreach ($array as $key => $value) { $newKey = is_string($key) ? ($case === CASE_LOWER ? strtolower($key) : strtoupper($key)) : $key; if (is_array($value)) { $value = $this->arrayKeysToLowerCase($value, $case); } $newArray[$newKey] = $value; } return $newArray; } } class QueryBuilder { private DBmodel $model; private $action = null; private $tab_hash = 'tab'; private $tab_key = null; private $table_id = null; private $tables = array(); private $columns = array(); private $vk_keys = array(); private $vk_values = array(); private $duplicates = array(); private $sets = array(); private $conditions = array(); private $group_by = array(); private $order_by = array(); private $limit = null; private $alias = null; private $offset = null; public function __construct($_model) { $this->model = $_model; } private function incTabKey() { $this->tab_key = $this->tab_hash . (count($this->tables) + 1); } private function allAttributes($table_id) { $primary_key = $this->model->primaryKeyName($table_id); $primary_key = (is_array($primary_key)) ? $primary_key : array($primary_key); return array_merge($this->model->allowAttributes($table_id), $primary_key); } public function beginAction($action, $table_id, $tab_hash = 'tab') { $this->action = $action; $this->table_id = $table_id; $this->tab_hash = $tab_hash; if ( $action == 'SELECT' || $action == 'UPDATE' ) { $this->incTabKey(); $this->tables[$this->tab_key] = sprintf('%s AS %s', $this->model->tableName($table_id), $this->tab_key); } if ( $action == 'DELETE' || $action == 'INSERT' ) { $this->tables[$this->tab_key] = sprintf('%s', $this->model->tableName($table_id)); } return $this; } private function _join($join_type, $table_id, $left_attr, $right_attr, $joined_tab_key = null) { $this->table_id = $table_id; $last_tab_key = is_null($joined_tab_key) ? $this->tab_key : $joined_tab_key; $this->incTabKey(); $left_attr = is_array($left_attr) ? $left_attr : array($left_attr); $right_attr = is_array($right_attr) ? $right_attr : array($right_attr); $min_count = min(count($left_attr), count($right_attr)); if ($min_count <= 0) { return $this; } $on = array(); for ($index = 0; $index < $min_count; $index++) { $on[] = sprintf( '%s%s = %s%s', (!in_array(substr($left_attr[$index], 0, 1), array('"', ' '))) ? $last_tab_key . '.' : '', $left_attr[$index], (!in_array(substr($right_attr[$index], 0, 1), array('"', ' '))) ? $this->tab_key . '.' : '', $right_attr[$index] ); } $this->tables[$this->tab_key] = sprintf( '%s %s AS %s ON %s', $join_type, $this->model->tableName($table_id), $this->tab_key, implode(' AND ', $on) ); return $this; } public function join($table_id, $left_attr, $right_attr, $joined_tab_key = null) { return $this->_join('JOIN', $table_id, $left_attr, $right_attr, $joined_tab_key); } public function leftjoin($table_id, $left_attr, $right_attr, $joined_tab_key = null) { return $this->_join('LEFT JOIN', $table_id, $left_attr, $right_attr, $joined_tab_key); } public function rightjoin($table_id, $left_attr, $right_attr, $joined_tab_key = null) { return $this->_join('RIGHT JOIN', $table_id, $left_attr, $right_attr, $joined_tab_key); } public function column($colname, $as = null) { if (is_array($colname)) { foreach ($colname as $col) { $this->column($col, $as); } } else { $allow_attributes = $this->allAttributes($this->table_id); if (in_array($colname, $allow_attributes)) { $column = sprintf('%s.`%s`', $this->tab_key, $colname); } else if ($colname == '*') { $column = sprintf('%s.*', $this->tab_key); } else if ( is_object($colname) && get_class($colname) == 'QueryBuilder' ) { $column = sprintf('(%s) AS %s', $colname->completeQuery(), $colname->alias); } else { $column = sprintf('%s', $colname); } if (!is_null($as)) { $column .= ' AS ' . $as; } $this->columns[] = $column; } return $this; } public function set($set = array()) { $allow_attributes = $this->model->allowAttributes($this->table_id); $set = $this->model->fixDecimalPoints($this->table_id, $set); $set = $this->model->fixBooleans($this->table_id, $set); $set = $this->model->fixJSONs($this->table_id, $set); $set = $this->model->fixTypes($this->table_id, $set); if (is_array($set)) foreach ($set as $key => $val) { if (in_array($key, $allow_attributes)) { if (is_null($val)) { $this->sets[] = sprintf('%s.%s = NULL', $this->tab_key, $key); } else if ( is_object($val) && get_class($val) == 'QueryBuilder' ) { $this->sets[] = sprintf('%s.%s = (%s)', $this->tab_key, $key, $val->completeQuery()); } else { $q_val = (substr($val, 0, 1) == '_' && substr($val, -1) == '_') ? substr($val, 1, -1) : $this->model->quote($val); $this->sets[] = sprintf('%s.%s = %s', $this->tab_key, $key, $q_val); } } } return $this; } public function value($values = array()) { $allow_attributes = $this->model->allowAttributes($this->table_id); if (is_array($values)) foreach ($values as $key => $val) { if (in_array($key, $allow_attributes)) { $this->vk_keys[] = sprintf('`%s`', $key); $this->vk_values[] = is_null($val) ? 'NULL' : sprintf('%s', $this->model->quote($val)); } } return $this; } public function duplicate($dupls = array()) { $allow_attributes = $this->model->allowAttributes($this->table_id); $dupls = $this->model->fixTypes($this->table_id, $dupls); if (is_array($dupls)) foreach ($dupls as $key => $val) { if (in_array($key, $allow_attributes)) { if (is_null($val)) { $this->duplicates[] = sprintf('%s = NULL', $key); } else { $this->duplicates[] = sprintf('%s = %s', $key, $this->model->quote($val)); } } } return $this; } private $where_prefixes = array('!', '%', '<', '<=', '>', '>='); public function where($search = array(), $concat_or = false) { $allow_attributes = $this->allAttributes($this->table_id); $search = $this->model->fixTypes($this->table_id, $search, $this->where_prefixes); $_tab_key = (strlen($this->tab_key) > 0) ? $this->tab_key . '.' : ''; $conds = array(); if (is_array($search)) foreach ($search as $key => $val) { if (is_string($key)) { $as_no_equal = (substr($key, 0, 1) == '!'); } if (is_string($val)) { if (strlen($val) <= 0) continue; $as_like = (stristr($val, '%') !== false); $as_lesser_equal = (substr($val, 0, 2) == '<='); $as_lesser = (!$as_lesser_equal && substr($val, 0, 1) == '<'); $as_greater_equal = (substr($val, 0, 2) == '>='); $as_greater = (!$as_greater_equal && substr($val, 0, 1) == '>'); $as_no_equal = $as_no_equal || (substr($val, 0, 1) == '!'); } if ( is_array($val) && count($val) <= 0 ) { continue; } $key = trim(str_replace(array('%', '!'), '', $key)); if ( in_array($key, $allow_attributes) || (substr($key, 0, 1) == '_' && substr($key, -1) == '_') || (substr($key, 0, 1) == '*' && substr($key, -1) == '*') ) { $__tab_key = $_tab_key; if ( substr($key, 0, 1) == '_' && substr($key, -1) == '_' ) { $key = $this->model->quote(substr($key, 1, -1)); $__tab_key = ''; } if ( substr($key, 0, 1) == '*' && substr($key, -1) == '*' ) { $key = substr($key, 1, -1); $__tab_key = ''; } if (is_null($val)) { $conds[] = sprintf('%s%s IS NULL', $__tab_key, $key); } else if ( is_object($val) && get_class($val) == 'QueryBuilder' ) { $conds[] = sprintf('%s%s %s IN (%s)', $__tab_key, $key, $as_no_equal ? 'NOT' : '', $val->completeQuery()); } else if (is_array($val)) { $values = array(); foreach ($val as $v) { if (is_null($v)) continue; $values[] = $this->model->quote($v); } $add_or = (in_array(null, $val, true)) ? sprintf('OR %s%s IS NULL', $__tab_key, $key) : ''; $conds[] = sprintf('(%s%s %s IN (%s) %s)', $__tab_key, $key, $as_no_equal ? 'NOT' : '', implode(', ', $values), $add_or); } else if (in_array(strtolower($val), array('not null', 'is not null', '! null', '!null', '!= null', '!=null'))) { $conds[] = sprintf('%s%s IS NOT NULL', $__tab_key, $key); } else { if ($as_like) { $sign = 'LIKE'; } else if ($as_lesser) { $sign = '<'; $val = substr($val, 1); } else if ($as_lesser_equal) { $sign = '<='; $val = substr($val, 2); } else if ($as_greater) { $sign = '>'; $val = substr($val, 1); } else if ($as_greater_equal) { $sign = '>='; $val = substr($val, 2); } else if ($as_no_equal) { $sign = '!='; $val = substr($val, 1); } else { $sign = '='; } $q_val = (substr($val, 0, 1) == '`' && substr($val, -1) == '`') ? $val : $this->model->quote($val); $q_val = (substr($val, 0, 1) == '_' && substr($val, -1) == '_') ? substr($val, 1, -1) : $q_val; $conds[] = sprintf('%s%s %s %s', $__tab_key, $key, $sign, $q_val); } } } if ($concat_or) { if (count($conds) > 0) { $this->conditions[] = '(' . implode(' OR ', $conds) . ')'; } } else { $this->conditions = array_merge($this->conditions, $conds); } return $this; } public function whereOR($search = array()) { return $this->where($search, true); } public function group($group) { if (is_array($group)) { foreach ($group as $g) { $this->group($g); } } else { $allow_attributes = $this->allAttributes($this->table_id); if (in_array($group, $allow_attributes)) { $this->group_by[] = sprintf('%s.%s', $this->tab_key, $group); } else if (substr($group, 0, 1) == '`' && substr($group, -1) == '`') { $this->group_by[] = sprintf('%s', $group); } } return $this; } public function order($order = array()) { $allow_attributes = $this->allAttributes($this->table_id); if (is_array($order)) foreach ($order as $key => $direction) { $direction_sign = in_array(strtolower($direction), array('desc', 'descending', 'down')) ? 'DESC' : 'ASC'; if (in_array($key, $allow_attributes)) { $this->order_by[] = sprintf('%s.%s %s', $this->tab_key, $key, $direction_sign); } else if (substr($key, 0, 1) == '`' && substr($key, -1) == '`') { $this->order_by[] = sprintf('%s %s', $key, $direction_sign); } } return $this; } public function limit($count_or_from, $count = null) { if (is_null($count_or_from)) return $this; if (is_array($count_or_from)) { $count = $count_or_from[1]; $count_or_from = $count_or_from[0]; } if (is_null($count)) { $this->limit = sprintf('LIMIT %d', intval($count_or_from)); } else { $this->limit = sprintf('LIMIT %d,%d', intval($count_or_from), intval($count)); } return $this; } public function offset($offset) { if (is_null($offset)) return $this; $this->offset = sprintf('OFFSET %d', intval($offset)); return $this; } private function completeQuery() { if ($this->action == 'SELECT') { $query = sprintf( 'SELECT %s' . ' FROM %s' . ' %s' // WHERE . ' %s' // GROUP . ' %s' // ORDER . ' %s' // LIMIT . ' %s', // OFFSET (count($this->columns) > 0) ? implode(', ', $this->columns) : '*', implode(' ', $this->tables), (count($this->conditions) > 0) ? 'WHERE ' . implode(' AND ', $this->conditions) : '', (count($this->group_by) > 0) ? 'GROUP BY ' . implode(', ', $this->group_by) : '', (count($this->order_by) > 0) ? 'ORDER BY ' . implode(', ', $this->order_by) : '', is_null($this->limit) ? '' : $this->limit, is_null($this->offset) ? '' : $this->offset ); } else if ($this->action == 'INSERT') { $query = sprintf( 'INSERT INTO %s' . ' (%s)' // KEYS . ' VALUES' . ' (%s)' // VALUES . ' %s', // ON DUPLICATE implode(' ', $this->tables), implode(', ', $this->vk_keys), implode(', ', $this->vk_values), ((count($this->duplicates) > 0) ? 'ON DUPLICATE KEY UPDATE ' . implode(', ', $this->duplicates) : '') ); } else if ($this->action == 'UPDATE') { $query = sprintf( 'UPDATE %s' . ' %s' // SET . ' %s' // WHERE . ' %s', // LIMIT implode(' ', $this->tables), (count($this->sets) > 0) ? 'SET ' . implode(', ', $this->sets) : '', (count($this->conditions) > 0) ? 'WHERE ' . implode(' AND ', $this->conditions) : '', is_null($this->limit) ? '' : $this->limit ); } else if ($this->action == 'DELETE') { $query = sprintf( 'DELETE FROM %s' . ' %s' // WHERE . ' %s', // LIMIT implode(' ', $this->tables), (count($this->conditions) > 0) ? 'WHERE ' . implode(' AND ', $this->conditions) : '', is_null($this->limit) ? '' : $this->limit ); } else { throw new \Exception('Unknown action "' . $this->action . '"'); } $this->model->_debug('[Model][completeQuery]: ' . $query); return $query; } public function alias($alias) { $this->alias = $alias; return $this; } public function toArray() { $query = $this->completeQuery(); $all = $this->model->getAll($query); if (is_array($all)) foreach ($all as $index => $row) { $all[$index] = $this->model->unfixJSONs($this->table_id, $row); } return $all; } public function getCol() { $query = $this->completeQuery(); return $this->model->getCol($query); } public function getOne() { $query = $this->completeQuery(); return $this->model->getOne($query); } public function toArrayFirst() { $query = $this->completeQuery(); $row = $this->model->getRow($query); $row = $this->model->unfixJSONs($this->table_id, $row); return $row; } public function toCombo($name_key, $name_value, $add_empty = false) { $all = $this->toArray(); $ret = array(); if ($add_empty) $ret[''] = ''; if (is_array($all)) foreach ($all as $row) { $ret[$row[$name_key]] = $row[$name_value]; } return $ret; } public function getRow() { return $this->toArrayFirst(); } public function execute() { $query = $this->completeQuery(); if (!$this->model->query($query)) return false; return $this->model->affectedRows(); } }