3 namespace Friendica\Database;
5 // Do not use Core\Config in this class at risk of infinite loop.
6 // Please use App->getConfigVariable() instead.
7 //use Friendica\Core\Config;
9 use Friendica\Core\System;
10 use Friendica\Util\DateTimeFormat;
17 * @class MySQL database class
19 * This class is for the low level database stuff that does driver specific things.
23 public static $connected = false;
25 private static $server_info = '';
27 private static $driver;
28 private static $error = false;
29 private static $errorno = 0;
30 private static $affected_rows = 0;
31 private static $in_transaction = false;
32 private static $in_retrial = false;
33 private static $relation = [];
34 private static $db_serveraddr = '';
35 private static $db_user = '';
36 private static $db_pass = '';
37 private static $db_name = '';
38 private static $db_charset = '';
40 public static function connect($serveraddr, $user, $pass, $db, $charset = null)
42 if (!is_null(self::$db) && self::connected()) {
46 // We are storing these values for being able to perform a reconnect
47 self::$db_serveraddr = $serveraddr;
48 self::$db_user = $user;
49 self::$db_pass = $pass;
51 self::$db_charset = $charset;
53 $serveraddr = trim($serveraddr);
55 $serverdata = explode(':', $serveraddr);
56 $server = $serverdata[0];
58 if (count($serverdata) > 1) {
59 $port = trim($serverdata[1]);
62 $server = trim($server);
66 $charset = trim($charset);
68 if (!(strlen($server) && strlen($user))) {
72 if (class_exists('\PDO') && in_array('mysql', PDO::getAvailableDrivers())) {
73 self::$driver = 'pdo';
74 $connect = "mysql:host=".$server.";dbname=".$db;
77 $connect .= ";port=".$port;
81 $connect .= ";charset=".$charset;
85 self::$db = @new PDO($connect, $user, $pass);
86 self::$db->setAttribute(PDO::ATTR_EMULATE_PREPARES, false);
87 self::$connected = true;
88 } catch (PDOException $e) {
92 if (!self::$connected && class_exists('mysqli')) {
93 self::$driver = 'mysqli';
94 self::$db = @new mysqli($server, $user, $pass, $db, $port);
95 if (!mysqli_connect_errno()) {
96 self::$connected = true;
99 self::$db->set_charset($charset);
104 // No suitable SQL driver was found.
105 if (!self::$connected) {
106 self::$driver = null;
110 return self::$connected;
114 * Disconnects the current database connection
116 public static function disconnect()
118 if (is_null(self::$db)) {
122 switch (self::$driver) {
134 * Perform a reconnect of an existing database connection
136 public static function reconnect() {
139 $ret = self::connect(self::$db_serveraddr, self::$db_user, self::$db_pass, self::$db_name, self::$db_charset);
144 * Return the database object.
147 public static function get_db()
153 * @brief Returns the MySQL server version string
155 * This function discriminate between the deprecated mysql API and the current
156 * object-oriented mysqli API. Example of returned string: 5.5.46-0+deb8u1
160 public static function server_info() {
161 if (self::$server_info == '') {
162 switch (self::$driver) {
164 self::$server_info = self::$db->getAttribute(PDO::ATTR_SERVER_VERSION);
167 self::$server_info = self::$db->server_info;
171 return self::$server_info;
175 * @brief Returns the selected database name
179 public static function database_name() {
180 $ret = self::p("SELECT DATABASE() AS `db`");
181 $data = self::inArray($ret);
182 return $data[0]['db'];
186 * @brief Analyze a database query and log this if some conditions are met.
188 * @param string $query The database query that will be analyzed
190 private static function logIndex($query) {
193 if (!$a->getConfigVariable('system', 'db_log_index')) {
197 // Don't explain an explain statement
198 if (strtolower(substr($query, 0, 7)) == "explain") {
202 // Only do the explain on "select", "update" and "delete"
203 if (!in_array(strtolower(substr($query, 0, 6)), ["select", "update", "delete"])) {
207 $r = self::p("EXPLAIN ".$query);
208 if (!DBM::is_result($r)) {
212 $watchlist = explode(',', $a->getConfigVariable('system', 'db_log_index_watch'));
213 $blacklist = explode(',', $a->getConfigVariable('system', 'db_log_index_blacklist'));
215 while ($row = self::fetch($r)) {
216 if ((intval($a->getConfigVariable('system', 'db_loglimit_index')) > 0)) {
217 $log = (in_array($row['key'], $watchlist) &&
218 ($row['rows'] >= intval($a->getConfigVariable('system', 'db_loglimit_index'))));
223 if ((intval($a->getConfigVariable('system', 'db_loglimit_index_high')) > 0) && ($row['rows'] >= intval($a->getConfigVariable('system', 'db_loglimit_index_high')))) {
227 if (in_array($row['key'], $blacklist) || ($row['key'] == "")) {
232 $backtrace = debug_backtrace(DEBUG_BACKTRACE_IGNORE_ARGS);
233 @file_put_contents($a->getConfigVariable('system', 'db_log_index'), DateTimeFormat::utcNow()."\t".
234 $row['key']."\t".$row['rows']."\t".$row['Extra']."\t".
235 basename($backtrace[1]["file"])."\t".
236 $backtrace[1]["line"]."\t".$backtrace[2]["function"]."\t".
237 substr($query, 0, 2000)."\n", FILE_APPEND);
242 public static function escape($str) {
243 switch (self::$driver) {
245 return substr(@self::$db->quote($str, PDO::PARAM_STR), 1, -1);
247 return @self::$db->real_escape_string($str);
251 public static function connected() {
254 if (is_null(self::$db)) {
258 switch (self::$driver) {
260 $r = self::p("SELECT 1");
261 if (DBM::is_result($r)) {
262 $row = self::inArray($r);
263 $connected = ($row[0]['1'] == '1');
267 $connected = self::$db->ping();
274 * @brief Replaces ANY_VALUE() function by MIN() function,
275 * if the database server does not support ANY_VALUE().
277 * Considerations for Standard SQL, or MySQL with ONLY_FULL_GROUP_BY (default since 5.7.5).
278 * ANY_VALUE() is available from MySQL 5.7.5 https://dev.mysql.com/doc/refman/5.7/en/miscellaneous-functions.html
279 * A standard fall-back is to use MIN().
281 * @param string $sql An SQL string without the values
282 * @return string The input SQL string modified if necessary.
284 public static function any_value_fallback($sql) {
285 $server_info = self::server_info();
286 if (version_compare($server_info, '5.7.5', '<') ||
287 (stripos($server_info, 'MariaDB') !== false)) {
288 $sql = str_ireplace('ANY_VALUE(', 'MIN(', $sql);
294 * @brief beautifies the query - useful for "SHOW PROCESSLIST"
296 * This is safe when we bind the parameters later.
297 * The parameter values aren't part of the SQL.
299 * @param string $sql An SQL string without the values
300 * @return string The input SQL string modified if necessary.
302 public static function clean_query($sql) {
303 $search = ["\t", "\n", "\r", " "];
304 $replace = [' ', ' ', ' ', ' '];
307 $sql = str_replace($search, $replace, $sql);
308 } while ($oldsql != $sql);
315 * @brief Replaces the ? placeholders with the parameters in the $args array
317 * @param string $sql SQL query
318 * @param array $args The parameters that are to replace the ? placeholders
319 * @return string The replaced SQL query
321 private static function replaceParameters($sql, $args) {
323 foreach ($args AS $param => $value) {
324 if (is_int($args[$param]) || is_float($args[$param])) {
325 $replace = intval($args[$param]);
327 $replace = "'".self::escape($args[$param])."'";
330 $pos = strpos($sql, '?', $offset);
331 if ($pos !== false) {
332 $sql = substr_replace($sql, $replace, $pos, 1);
334 $offset = $pos + strlen($replace);
340 * @brief Convert parameter array to an universal form
341 * @param array $args Parameter array
342 * @return array universalized parameter array
344 private static function getParam($args) {
347 // When the second function parameter is an array then use this as the parameter array
348 if ((count($args) > 0) && (is_array($args[1]))) {
356 * @brief Executes a prepared statement that returns data
357 * @usage Example: $r = p("SELECT * FROM `item` WHERE `guid` = ?", $guid);
359 * Please only use it with complicated queries.
360 * For all regular queries please use dba::select or dba::exists
362 * @param string $sql SQL statement
363 * @return bool|object statement object or result object
365 public static function p($sql) {
368 $stamp1 = microtime(true);
370 $params = self::getParam(func_get_args());
372 // Renumber the array keys to be sure that they fit
375 foreach ($params AS $param) {
376 // Avoid problems with some MySQL servers and boolean values. See issue #3645
377 if (is_bool($param)) {
378 $param = (int)$param;
380 $args[++$i] = $param;
383 if (!self::$connected) {
387 if ((substr_count($sql, '?') != count($args)) && (count($args) > 0)) {
388 // Question: Should we continue or stop the query here?
389 logger('Parameter mismatch. Query "'.$sql.'" - Parameters '.print_r($args, true), LOGGER_DEBUG);
392 $sql = self::clean_query($sql);
393 $sql = self::any_value_fallback($sql);
397 if ($a->getConfigValue('system', 'db_callstack')) {
398 $sql = "/*".System::callstack()." */ ".$sql;
403 self::$affected_rows = 0;
405 // We have to make some things different if this function is called from "e"
406 $trace = debug_backtrace(DEBUG_BACKTRACE_IGNORE_ARGS, 2);
408 if (isset($trace[1])) {
409 $called_from = $trace[1];
411 // We use just something that is defined to avoid warnings
412 $called_from = $trace[0];
414 // We are having an own error logging in the function "e"
415 $called_from_e = ($called_from['function'] == 'e');
417 switch (self::$driver) {
419 // If there are no arguments we use "query"
420 if (count($args) == 0) {
421 if (!$retval = self::$db->query($sql)) {
422 $errorInfo = self::$db->errorInfo();
423 self::$error = $errorInfo[2];
424 self::$errorno = $errorInfo[1];
428 self::$affected_rows = $retval->rowCount();
432 if (!$stmt = self::$db->prepare($sql)) {
433 $errorInfo = self::$db->errorInfo();
434 self::$error = $errorInfo[2];
435 self::$errorno = $errorInfo[1];
440 foreach ($args AS $param => $value) {
441 if (is_int($args[$param])) {
442 $data_type = PDO::PARAM_INT;
444 $data_type = PDO::PARAM_STR;
446 $stmt->bindParam($param, $args[$param], $data_type);
449 if (!$stmt->execute()) {
450 $errorInfo = $stmt->errorInfo();
451 self::$error = $errorInfo[2];
452 self::$errorno = $errorInfo[1];
456 self::$affected_rows = $retval->rowCount();
460 // There are SQL statements that cannot be executed with a prepared statement
461 $parts = explode(' ', $orig_sql);
462 $command = strtolower($parts[0]);
463 $can_be_prepared = in_array($command, ['select', 'update', 'insert', 'delete']);
465 // The fallback routine is called as well when there are no arguments
466 if (!$can_be_prepared || (count($args) == 0)) {
467 $retval = self::$db->query(self::replaceParameters($sql, $args));
468 if (self::$db->errno) {
469 self::$error = self::$db->error;
470 self::$errorno = self::$db->errno;
473 if (isset($retval->num_rows)) {
474 self::$affected_rows = $retval->num_rows;
476 self::$affected_rows = self::$db->affected_rows;
482 $stmt = self::$db->stmt_init();
484 if (!$stmt->prepare($sql)) {
485 self::$error = $stmt->error;
486 self::$errorno = $stmt->errno;
493 foreach ($args AS $param => $value) {
494 if (is_int($args[$param])) {
496 } elseif (is_float($args[$param])) {
498 } elseif (is_string($args[$param])) {
503 $values[] = &$args[$param];
506 if (count($values) > 0) {
507 array_unshift($values, $param_types);
508 call_user_func_array([$stmt, 'bind_param'], $values);
511 if (!$stmt->execute()) {
512 self::$error = self::$db->error;
513 self::$errorno = self::$db->errno;
516 $stmt->store_result();
518 self::$affected_rows = $retval->affected_rows;
523 // We are having an own error logging in the function "e"
524 if ((self::$errorno != 0) && !$called_from_e) {
525 // We have to preserve the error code, somewhere in the logging it get lost
526 $error = self::$error;
527 $errorno = self::$errorno;
529 logger('DB Error '.self::$errorno.': '.self::$error."\n".
530 System::callstack(8)."\n".self::replaceParameters($sql, $args));
532 // On a lost connection we try to reconnect - but only once.
533 if ($errorno == 2006) {
534 if (self::$in_retrial || !self::reconnect()) {
535 // It doesn't make sense to continue when the database connection was lost
536 if (self::$in_retrial) {
537 logger('Giving up retrial because of database error '.$errorno.': '.$error);
539 logger("Couldn't reconnect after database error ".$errorno.': '.$error);
544 logger('Reconnected after database error '.$errorno.': '.$error);
545 self::$in_retrial = true;
546 $ret = self::p($sql, $args);
547 self::$in_retrial = false;
552 self::$error = $error;
553 self::$errorno = $errorno;
556 $a->save_timestamp($stamp1, 'database');
558 if ($a->getConfigValue('system', 'db_log')) {
559 $stamp2 = microtime(true);
560 $duration = (float)($stamp2 - $stamp1);
562 if (($duration > $a->getConfigValue('system', 'db_loglimit'))) {
563 $duration = round($duration, 3);
564 $backtrace = debug_backtrace(DEBUG_BACKTRACE_IGNORE_ARGS);
566 @file_put_contents($a->getConfigValue('system', 'db_log'), DateTimeFormat::utcNow()."\t".$duration."\t".
567 basename($backtrace[1]["file"])."\t".
568 $backtrace[1]["line"]."\t".$backtrace[2]["function"]."\t".
569 substr(self::replaceParameters($sql, $args), 0, 2000)."\n", FILE_APPEND);
576 * @brief Executes a prepared statement like UPDATE or INSERT that doesn't return data
578 * Please use dba::delete, dba::insert, dba::update, ... instead
580 * @param string $sql SQL statement
581 * @return boolean Was the query successfull? False is returned only if an error occurred
583 public static function e($sql) {
586 $stamp = microtime(true);
588 $params = self::getParam(func_get_args());
590 // In a case of a deadlock we are repeating the query 20 times
594 $stmt = self::p($sql, $params);
596 if (is_bool($stmt)) {
598 } elseif (is_object($stmt)) {
606 } while ((self::$errorno == 1213) && (--$timeout > 0));
608 if (self::$errorno != 0) {
609 // We have to preserve the error code, somewhere in the logging it get lost
610 $error = self::$error;
611 $errorno = self::$errorno;
613 logger('DB Error '.self::$errorno.': '.self::$error."\n".
614 System::callstack(8)."\n".self::replaceParameters($sql, $params));
616 // On a lost connection we simply quit.
617 // A reconnect like in self::p could be dangerous with modifications
618 if ($errorno == 2006) {
619 logger('Giving up because of database error '.$errorno.': '.$error);
623 self::$error = $error;
624 self::$errorno = $errorno;
627 $a->save_timestamp($stamp, "database_write");
633 * @brief Check if data exists
635 * @param string $table Table name
636 * @param array $condition array of fields for condition
638 * @return boolean Are there rows for that condition?
640 public static function exists($table, $condition) {
647 if (empty($condition)) {
648 return DBStructure::existsTable($table);
652 $first_key = key($condition);
653 if (!is_int($first_key)) {
654 $fields = [$first_key];
657 $stmt = self::select($table, $fields, $condition, ['limit' => 1]);
659 if (is_bool($stmt)) {
662 $retval = (self::num_rows($stmt) > 0);
671 * Fetches the first row
673 * Please use dba::selectFirst or dba::exists whenever this is possible.
675 * @brief Fetches the first row
676 * @param string $sql SQL statement
677 * @return array first row of query
679 public static function fetch_first($sql) {
680 $params = self::getParam(func_get_args());
682 $stmt = self::p($sql, $params);
684 if (is_bool($stmt)) {
687 $retval = self::fetch($stmt);
696 * @brief Returns the number of affected rows of the last statement
698 * @return int Number of rows
700 public static function affected_rows() {
701 return self::$affected_rows;
705 * @brief Returns the number of columns of a statement
707 * @param object Statement object
708 * @return int Number of columns
710 public static function columnCount($stmt) {
711 if (!is_object($stmt)) {
714 switch (self::$driver) {
716 return $stmt->columnCount();
718 return $stmt->field_count;
723 * @brief Returns the number of rows of a statement
725 * @param PDOStatement|mysqli_result|mysqli_stmt Statement object
726 * @return int Number of rows
728 public static function num_rows($stmt) {
729 if (!is_object($stmt)) {
732 switch (self::$driver) {
734 return $stmt->rowCount();
736 return $stmt->num_rows;
742 * @brief Fetch a single row
744 * @param mixed $stmt statement object
745 * @return array current row
747 public static function fetch($stmt) {
750 $stamp1 = microtime(true);
754 if (!is_object($stmt)) {
758 switch (self::$driver) {
760 $columns = $stmt->fetch(PDO::FETCH_ASSOC);
763 if (get_class($stmt) == 'mysqli_result') {
764 $columns = $stmt->fetch_assoc();
768 // This code works, but is slow
770 // Bind the result to a result array
774 for ($x = 0; $x < $stmt->field_count; $x++) {
775 $cols[] = &$cols_num[$x];
778 call_user_func_array([$stmt, 'bind_result'], $cols);
780 if (!$stmt->fetch()) {
785 // We need to get the field names for the array keys
786 // It seems that there is no better way to do this.
787 $result = $stmt->result_metadata();
788 $fields = $result->fetch_fields();
790 foreach ($cols_num AS $param => $col) {
791 $columns[$fields[$param]->name] = $col;
795 $a->save_timestamp($stamp1, 'database');
801 * @brief Insert a row into a table
803 * @param string $table Table name
804 * @param array $param parameter array
805 * @param bool $on_duplicate_update Do an update on a duplicate entry
807 * @return boolean was the insert successfull?
809 public static function insert($table, $param, $on_duplicate_update = false) {
811 if (empty($table) || empty($param)) {
812 logger('Table and fields have to be set');
816 $sql = "INSERT INTO `".self::escape($table)."` (`".implode("`, `", array_keys($param))."`) VALUES (".
817 substr(str_repeat("?, ", count($param)), 0, -2).")";
819 if ($on_duplicate_update) {
820 $sql .= " ON DUPLICATE KEY UPDATE `".implode("` = ?, `", array_keys($param))."` = ?";
822 $values = array_values($param);
823 $param = array_merge_recursive($values, $values);
826 return self::e($sql, $param);
830 * @brief Fetch the id of the last insert command
832 * @return integer Last inserted id
834 public static function lastInsertId() {
835 switch (self::$driver) {
837 $id = self::$db->lastInsertId();
840 $id = self::$db->insert_id;
847 * @brief Locks a table for exclusive write access
849 * This function can be extended in the future to accept a table array as well.
851 * @param string $table Table name
853 * @return boolean was the lock successful?
855 public static function lock($table) {
856 // See here: https://dev.mysql.com/doc/refman/5.7/en/lock-tables-and-transactions.html
857 if (self::$driver == 'pdo') {
858 self::e("SET autocommit=0");
859 self::$db->setAttribute(PDO::ATTR_EMULATE_PREPARES, true);
861 self::$db->autocommit(false);
864 $success = self::e("LOCK TABLES `".self::escape($table)."` WRITE");
866 if (self::$driver == 'pdo') {
867 self::$db->setAttribute(PDO::ATTR_EMULATE_PREPARES, false);
871 if (self::$driver == 'pdo') {
872 self::e("SET autocommit=1");
874 self::$db->autocommit(true);
877 self::$in_transaction = true;
883 * @brief Unlocks all locked tables
885 * @return boolean was the unlock successful?
887 public static function unlock() {
888 // See here: https://dev.mysql.com/doc/refman/5.7/en/lock-tables-and-transactions.html
889 self::performCommit();
891 if (self::$driver == 'pdo') {
892 self::$db->setAttribute(PDO::ATTR_EMULATE_PREPARES, true);
895 $success = self::e("UNLOCK TABLES");
897 if (self::$driver == 'pdo') {
898 self::$db->setAttribute(PDO::ATTR_EMULATE_PREPARES, false);
899 self::e("SET autocommit=1");
901 self::$db->autocommit(true);
904 self::$in_transaction = false;
909 * @brief Starts a transaction
911 * @return boolean Was the command executed successfully?
913 public static function transaction() {
914 if (!self::performCommit()) {
918 switch (self::$driver) {
920 if (self::$db->inTransaction()) {
923 if (!self::$db->beginTransaction()) {
928 if (!self::$db->begin_transaction()) {
934 self::$in_transaction = true;
938 private static function performCommit()
940 switch (self::$driver) {
942 if (!self::$db->inTransaction()) {
945 return self::$db->commit();
947 return self::$db->commit();
953 * @brief Does a commit
955 * @return boolean Was the command executed successfully?
957 public static function commit() {
958 if (!self::performCommit()) {
961 self::$in_transaction = false;
966 * @brief Does a rollback
968 * @return boolean Was the command executed successfully?
970 public static function rollback() {
973 switch (self::$driver) {
975 if (!self::$db->inTransaction()) {
979 $ret = self::$db->rollBack();
982 $ret = self::$db->rollback();
985 self::$in_transaction = false;
990 * @brief Build the array with the table relations
992 * The array is build from the database definitions in DBStructure.php
994 * This process must only be started once, since the value is cached.
996 private static function buildRelationData() {
997 $definition = DBStructure::definition();
999 foreach ($definition AS $table => $structure) {
1000 foreach ($structure['fields'] AS $field => $field_struct) {
1001 if (isset($field_struct['relation'])) {
1002 foreach ($field_struct['relation'] AS $rel_table => $rel_field) {
1003 self::$relation[$rel_table][$rel_field][$table][] = $field;
1011 * @brief Delete a row from a table
1013 * @param string $table Table name
1014 * @param array $conditions Field condition(s)
1015 * @param array $options
1016 * - cascade: If true we delete records in other tables that depend on the one we're deleting through
1017 * relations (default: true)
1018 * @param boolean $in_process Internal use: Only do a commit after the last delete
1019 * @param array $callstack Internal use: prevent endless loops
1021 * @return boolean|array was the delete successful? When $in_process is set: deletion data
1023 public static function delete($table, array $conditions, array $options = [], $in_process = false, array &$callstack = [])
1025 if (empty($table) || empty($conditions)) {
1026 logger('Table and conditions have to be set');
1032 // Create a key for the loop prevention
1033 $key = $table . ':' . json_encode($conditions);
1035 // We quit when this key already exists in the callstack.
1036 if (isset($callstack[$key])) {
1040 $callstack[$key] = true;
1042 $table = self::escape($table);
1044 $commands[$key] = ['table' => $table, 'conditions' => $conditions];
1046 $cascade = defaults($options, 'cascade', true);
1048 // To speed up the whole process we cache the table relations
1049 if ($cascade && count(self::$relation) == 0) {
1050 self::buildRelationData();
1053 // Is there a relation entry for the table?
1054 if ($cascade && isset(self::$relation[$table])) {
1055 // We only allow a simple "one field" relation.
1056 $field = array_keys(self::$relation[$table])[0];
1057 $rel_def = array_values(self::$relation[$table])[0];
1059 // Create a key for preventing double queries
1060 $qkey = $field . '-' . $table . ':' . json_encode($conditions);
1062 // When the search field is the relation field, we don't need to fetch the rows
1063 // This is useful when the leading record is already deleted in the frontend but the rest is done in the backend
1064 if ((count($conditions) == 1) && ($field == array_keys($conditions)[0])) {
1065 foreach ($rel_def AS $rel_table => $rel_fields) {
1066 foreach ($rel_fields AS $rel_field) {
1067 $retval = self::delete($rel_table, [$rel_field => array_values($conditions)[0]], $options, true, $callstack);
1068 $commands = array_merge($commands, $retval);
1071 // We quit when this key already exists in the callstack.
1072 } elseif (!isset($callstack[$qkey])) {
1074 $callstack[$qkey] = true;
1076 // Fetch all rows that are to be deleted
1077 $data = self::select($table, [$field], $conditions);
1079 while ($row = self::fetch($data)) {
1080 // Now we accumulate the delete commands
1081 $retval = self::delete($table, [$field => $row[$field]], $options, true, $callstack);
1082 $commands = array_merge($commands, $retval);
1087 // Since we had split the delete command we don't need the original command anymore
1088 unset($commands[$key]);
1093 // Now we finalize the process
1094 $do_transaction = !self::$in_transaction;
1096 if ($do_transaction) {
1097 self::transaction();
1103 foreach ($commands AS $command) {
1104 $conditions = $command['conditions'];
1106 $first_key = key($conditions);
1108 $condition_string = self::buildCondition($conditions);
1110 if ((count($command['conditions']) > 1) || is_int($first_key)) {
1111 $sql = "DELETE FROM `" . $command['table'] . "`" . $condition_string;
1112 logger(self::replaceParameters($sql, $conditions), LOGGER_DATA);
1114 if (!self::e($sql, $conditions)) {
1115 if ($do_transaction) {
1121 $key_table = $command['table'];
1122 $key_condition = array_keys($command['conditions'])[0];
1123 $value = array_values($command['conditions'])[0];
1125 // Split the SQL queries in chunks of 100 values
1126 // We do the $i stuff here to make the code better readable
1127 $i = isset($counter[$key_table][$key_condition]) ? $counter[$key_table][$key_condition] : 0;
1128 if (isset($compacted[$key_table][$key_condition][$i]) && count($compacted[$key_table][$key_condition][$i]) > 100) {
1132 $compacted[$key_table][$key_condition][$i][$value] = $value;
1133 $counter[$key_table][$key_condition] = $i;
1136 foreach ($compacted AS $table => $values) {
1137 foreach ($values AS $field => $field_value_list) {
1138 foreach ($field_value_list AS $field_values) {
1139 $sql = "DELETE FROM `" . $table . "` WHERE `" . $field . "` IN (" .
1140 substr(str_repeat("?, ", count($field_values)), 0, -2) . ");";
1142 logger(self::replaceParameters($sql, $field_values), LOGGER_DATA);
1144 if (!self::e($sql, $field_values)) {
1145 if ($do_transaction) {
1153 if ($do_transaction) {
1163 * @brief Updates rows
1165 * Updates rows in the database. When $old_fields is set to an array,
1166 * the system will only do an update if the fields in that array changed.
1169 * Only the values in $old_fields are compared.
1170 * This is an intentional behaviour.
1173 * We include the timestamp field in $fields but not in $old_fields.
1174 * Then the row will only get the new timestamp when the other fields had changed.
1176 * When $old_fields is set to a boolean value the system will do this compare itself.
1177 * When $old_fields is set to "true" the system will do an insert if the row doesn't exists.
1180 * Only set $old_fields to a boolean value when you are sure that you will update a single row.
1181 * When you set $old_fields to "true" then $fields must contain all relevant fields!
1183 * @param string $table Table name
1184 * @param array $fields contains the fields that are updated
1185 * @param array $condition condition array with the key values
1186 * @param array|boolean $old_fields array with the old field values that are about to be replaced (true = update on duplicate)
1188 * @return boolean was the update successfull?
1190 public static function update($table, $fields, $condition, $old_fields = []) {
1192 if (empty($table) || empty($fields) || empty($condition)) {
1193 logger('Table, fields and condition have to be set');
1197 $table = self::escape($table);
1199 $condition_string = self::buildCondition($condition);
1201 if (is_bool($old_fields)) {
1202 $do_insert = $old_fields;
1204 $old_fields = self::selectFirst($table, [], $condition);
1206 if (is_bool($old_fields)) {
1208 $values = array_merge($condition, $fields);
1209 return self::insert($table, $values, $do_insert);
1215 $do_update = (count($old_fields) == 0);
1217 foreach ($old_fields AS $fieldname => $content) {
1218 if (isset($fields[$fieldname])) {
1219 if ($fields[$fieldname] == $content) {
1220 unset($fields[$fieldname]);
1227 if (!$do_update || (count($fields) == 0)) {
1231 $sql = "UPDATE `".$table."` SET `".
1232 implode("` = ?, `", array_keys($fields))."` = ?".$condition_string;
1234 $params1 = array_values($fields);
1235 $params2 = array_values($condition);
1236 $params = array_merge_recursive($params1, $params2);
1238 return self::e($sql, $params);
1242 * Retrieve a single record from a table and returns it in an associative array
1244 * @brief Retrieve a single record from a table
1245 * @param string $table
1246 * @param array $fields
1247 * @param array $condition
1248 * @param array $params
1249 * @return bool|array
1252 public static function selectFirst($table, array $fields = [], array $condition = [], $params = [])
1254 $params['limit'] = 1;
1255 $result = self::select($table, $fields, $condition, $params);
1257 if (is_bool($result)) {
1260 $row = self::fetch($result);
1261 self::close($result);
1267 * @brief Select rows from a table
1269 * @param string $table Table name
1270 * @param array $fields Array of selected fields, empty for all
1271 * @param array $condition Array of fields for condition
1272 * @param array $params Array of several parameters
1274 * @return boolean|object
1278 * $fields = array("id", "uri", "uid", "network");
1280 * $condition = array("uid" => 1, "network" => 'dspr');
1282 * $condition = array("`uid` = ? AND `network` IN (?, ?)", 1, 'dfrn', 'dspr');
1284 * $params = array("order" => array("id", "received" => true), "limit" => 10);
1286 * $data = dba::select($table, $fields, $condition, $params);
1288 public static function select($table, array $fields = [], array $condition = [], array $params = [])
1294 $table = self::escape($table);
1296 if (count($fields) > 0) {
1297 $select_fields = "`" . implode("`, `", array_values($fields)) . "`";
1299 $select_fields = "*";
1302 $condition_string = self::buildCondition($condition);
1304 $param_string = self::buildParameter($params);
1306 $sql = "SELECT " . $select_fields . " FROM `" . $table . "`" . $condition_string . $param_string;
1308 $result = self::p($sql, $condition);
1314 * @brief Counts the rows from a table satisfying the provided condition
1316 * @param string $table Table name
1317 * @param array $condition array of fields for condition
1324 * $condition = ["uid" => 1, "network" => 'dspr'];
1326 * $condition = ["`uid` = ? AND `network` IN (?, ?)", 1, 'dfrn', 'dspr'];
1328 * $count = dba::count($table, $condition);
1330 public static function count($table, array $condition = [])
1336 $condition_string = self::buildCondition($condition);
1338 $sql = "SELECT COUNT(*) AS `count` FROM `".$table."`".$condition_string;
1340 $row = self::fetch_first($sql, $condition);
1342 return $row['count'];
1346 * @brief Returns the SQL condition string built from the provided condition array
1348 * This function operates with two modes.
1349 * - Supplied with a filed/value associative array, it builds simple strict
1350 * equality conditions linked by AND.
1351 * - Supplied with a flat list, the first element is the condition string and
1352 * the following arguments are the values to be interpolated
1354 * $condition = ["uid" => 1, "network" => 'dspr'];
1356 * $condition = ["`uid` = ? AND `network` IN (?, ?)", 1, 'dfrn', 'dspr'];
1358 * In either case, the provided array is left with the parameters only
1360 * @param array $condition
1363 public static function buildCondition(array &$condition = [])
1365 $condition_string = '';
1366 if (count($condition) > 0) {
1368 $first_key = key($condition);
1369 if (is_int($first_key)) {
1370 $condition_string = " WHERE (" . array_shift($condition) . ")";
1373 $condition_string = "";
1374 foreach ($condition as $field => $value) {
1375 if ($condition_string != "") {
1376 $condition_string .= " AND ";
1378 if (is_array($value)) {
1379 /* Workaround for MySQL Bug #64791.
1380 * Never mix data types inside any IN() condition.
1381 * In case of mixed types, cast all as string.
1382 * Logic needs to be consistent with dba::p() data types.
1386 foreach ($value as $single_value) {
1387 if (is_int($single_value)) {
1394 if ($is_int && $is_alpha) {
1395 foreach ($value as &$ref) {
1397 $ref = (string)$ref;
1400 unset($ref); //Prevent accidental re-use.
1403 $new_values = array_merge($new_values, array_values($value));
1404 $placeholders = substr(str_repeat("?, ", count($value)), 0, -2);
1405 $condition_string .= "`" . $field . "` IN (" . $placeholders . ")";
1407 $new_values[$field] = $value;
1408 $condition_string .= "`" . $field . "` = ?";
1411 $condition_string = " WHERE (" . $condition_string . ")";
1412 $condition = $new_values;
1416 return $condition_string;
1420 * @brief Returns the SQL parameter string built from the provided parameter array
1422 * @param array $params
1425 public static function buildParameter(array $params = [])
1428 if (isset($params['order'])) {
1429 $order_string = " ORDER BY ";
1430 foreach ($params['order'] AS $fields => $order) {
1431 if (!is_int($fields)) {
1432 $order_string .= "`" . $fields . "` " . ($order ? "DESC" : "ASC") . ", ";
1434 $order_string .= "`" . $order . "`, ";
1437 $order_string = substr($order_string, 0, -2);
1441 if (isset($params['limit']) && is_int($params['limit'])) {
1442 $limit_string = " LIMIT " . $params['limit'];
1445 if (isset($params['limit']) && is_array($params['limit'])) {
1446 $limit_string = " LIMIT " . intval($params['limit'][0]) . ", " . intval($params['limit'][1]);
1449 return $order_string.$limit_string;
1453 * @brief Fills an array with data from a query
1455 * @param object $stmt statement object
1456 * @return array Data array
1458 public static function inArray($stmt, $do_close = true) {
1459 if (is_bool($stmt)) {
1464 while ($row = self::fetch($stmt)) {
1474 * @brief Returns the error number of the last query
1476 * @return string Error number (0 if no error)
1478 public static function errorNo() {
1479 return self::$errorno;
1483 * @brief Returns the error message of the last query
1485 * @return string Error message ('' if no error)
1487 public static function errorMessage() {
1488 return self::$error;
1492 * @brief Closes the current statement
1494 * @param object $stmt statement object
1495 * @return boolean was the close successful?
1497 public static function close($stmt) {
1500 $stamp1 = microtime(true);
1502 if (!is_object($stmt)) {
1506 switch (self::$driver) {
1508 $ret = $stmt->closeCursor();
1511 // MySQLi offers both a mysqli_stmt and a mysqli_result class.
1512 // We should be careful not to assume the object type of $stmt
1513 // because dba::p() has been able to return both types.
1514 if ($stmt instanceof mysqli_stmt) {
1515 $stmt->free_result();
1516 $ret = $stmt->close();
1517 } elseif ($stmt instanceof mysqli_result) {
1526 $a->save_timestamp($stamp1, 'database');