From b758ee9395b807c3ca82847cf3c8c1782de4a35a Mon Sep 17 00:00:00 2001 From: Sebastian Grewe Date: Thu, 10 Jul 2014 11:49:33 +0200 Subject: [PATCH] [PoC] Cronjob based Hashrate graphs --- cronjobs/statistics.php | 12 +- include/classes/statistics.class.php | 113 +++++++++++-------- include/pages/statistics/graphs.inc.php | 2 +- include/version.inc.php | 2 +- sql/000_base_structure.sql | 17 +-- upgrade/definitions/0.0.12_to_0.0.13.inc.php | 39 +++++++ 6 files changed, 128 insertions(+), 57 deletions(-) create mode 100644 upgrade/definitions/0.0.12_to_0.0.13.inc.php diff --git a/cronjobs/statistics.php b/cronjobs/statistics.php index 6530fab7..eb564c1a 100755 --- a/cronjobs/statistics.php +++ b/cronjobs/statistics.php @@ -27,7 +27,7 @@ require_once('shared.inc.php'); // Header $log->logInfo('Running statistical queries, errors may just mean no shares were available'); -$strLogMask = "| %-26.26s | %8.8s | %-6.6s |"; +$strLogMask = "| %-33.33s | %8.8s | %-6.6s |"; $log->logInfo(sprintf($strLogMask, 'Method', 'Runtime', 'Status')); // Per user share statistics based on all shares submitted @@ -37,9 +37,15 @@ $log->logInfo(sprintf($strLogMask, 'getAllUserShares', number_format(microtime(t // Get all user hashrate statistics for caching $start = microtime(true); -$statistics->getAllUserMiningStats() ? $status = 'OK' : $status = 'ERROR'; -$log->logInfo(sprintf($strLogMask, 'getAllUserMiningStats', number_format(microtime(true) - $start, 3), $status)); +$statistics->fetchAllUserMiningStats() ? $status = 'OK' : $status = 'ERROR'; +$log->logInfo(sprintf($strLogMask, 'fetchAllUserMiningStats', number_format(microtime(true) - $start, 3), $status)); +// Store our statistical data into our `statistics_users` table +$start = microtime(true); +$statistics->storeAllUserMiningStatsSnapshot($statistics->getAllUserMiningStats()) ? $status = 'OK' : $status = 'ERROR'; +$log->logInfo(sprintf($strLogMask, 'storeAllUserMiningStatsSnapshot', number_format(microtime(true) - $start, 3), $status)); + +// Get stats for pool overview $start = microtime(true); $statistics->getTopContributors('hashes') ? $status = 'OK' : $status = 'ERROR'; $log->logInfo(sprintf($strLogMask, 'getTopContributors(hashes)', number_format(microtime(true) - $start, 3), $status)); diff --git a/include/classes/statistics.class.php b/include/classes/statistics.class.php index ae6736b4..51a63410 100644 --- a/include/classes/statistics.class.php +++ b/include/classes/statistics.class.php @@ -9,6 +9,7 @@ $defflip = (!cfip()) ? exit(header('HTTP/1.1 401 Unauthorized')) : 1; **/ class Statistics extends Base { protected $table = 'statistics_shares'; + protected $table_user_stats = 'statistics_users'; private $getcache = true; // Disable fetching values from cache @@ -18,6 +19,12 @@ class Statistics extends Base { public function getGetCache() { return $this->getcache; } + public function getAllUserMiningStats() { + return $this->allUserMiningStats; + } + public function getUserStatsTableName() { + return $this->table_user_stats; + } /** * Get our first block found @@ -451,14 +458,17 @@ class Statistics extends Base { /** * Fetch all user hashrates based on shares and archived shares + * Store it in cache, also keep a copy of the data internally to + * return it for further processing * @return data array Set of all user stats **/ - public function getAllUserMiningStats($interval=180) { + public function fetchAllUserMiningStats($interval=180) { $this->debug->append("STA " . __METHOD__, 4); $stmt = $this->mysqli->prepare(" SELECT a.id AS id, a.username AS account, + COUNT(DISTINCT t1.username) AS workers, IFNULL(SUM(t1.difficulty), 0) AS shares, ROUND(COUNT(t1.id) / ?, 2) AS sharerate, IFNULL(AVG(IF(difficulty=0, pow(2, (" . $this->config['difficulty'] . " - 16)), difficulty)), 0) AS avgsharediff @@ -489,12 +499,43 @@ class Statistics extends Base { $aData['data'][$row['id']] = $row; $aData['data'][$row['id']]['hashrate'] = $this->coin->calcHashrate($row['shares'], $interval); } + $this->allUserMiningStats = $aData; return $this->memcache->setStaticCache(STATISTICS_ALL_USER_HASHRATES, $aData, 600); } else { return $this->sqlError(); } } + /** + * Store our gathered data into our statistic table for users + * @param aData array Data created by fetchAllUserMiningStats + * @return bool true or false + **/ + public function storeAllUserMiningStatsSnapshot($aData) { + // initilize + $timestamp = time(); // Store all entries with the same timestamp to reduce cardinality + $ok = 0; + $failed = 0; + foreach ($aData['data'] as $key => $aUserData) { + $stmt = $this->mysqli->prepare(" + INSERT INTO " . $this->getUserStatsTableName() . " + ( account_id, hashrate, workers, sharerate, timestamp ) VALUES ( ?, ?, ?, ?, ?)"); + if ($this->checkStmt($stmt) && $stmt->bind_param("ididi", $aUserData['id'], $aUserData['hashrate'], $aUserData['workers'], $aUserData['sharerate'], $timestamp) && $stmt->execute() ) { + $ok++; + } else { + $failed++; + } + } + return array('ok' => $ok, 'failed' => $failed); + } + + /** + * Fetch unpaid PPS shares for an account + * @param username string Username + * @param account_id int User ID + * @param last_paid_pps_id int Last paid out share by pps_payout cron + * @return data int Sum of unpaid diff1 shares + **/ public function getUserUnpaidPPSShares($username, $account_id=NULL, $last_paid_pps_id) { $this->debug->append("STA " . __METHOD__, 4); if ($this->getGetCache() && $data = $this->memcache->get(__FUNCTION__ . $account_id)) return $data; @@ -655,38 +696,26 @@ class Statistics extends Base { * @param $account_id int account id * @return data array NOT FINISHED YET **/ - public function getHourlyHashrateByAccount($username, $account_id=NULL) { + public function getHourlyHashrateByAccount($account_id) { $this->debug->append("STA " . __METHOD__, 4); if ($data = $this->memcache->get(__FUNCTION__ . $account_id)) return $data; $stmt = $this->mysqli->prepare(" SELECT - id, - IFNULL(SUM(IF(difficulty=0, pow(2, (" . $this->config['difficulty'] . " - 16)), difficulty)), 0) AS shares, - HOUR(time) AS hour - FROM " . $this->share->getTableName() . " - WHERE time <= FROM_UNIXTIME(FLOOR(UNIX_TIMESTAMP(NOW())/(60*60))*(60*60)) - AND time >= FROM_UNIXTIME(FLOOR(UNIX_TIMESTAMP(NOW())/(60*60))*(60*60)) - INTERVAL 24 HOUR - AND our_result = 'Y' - AND username LIKE ? - GROUP BY HOUR(time) - UNION - SELECT - share_id, - IFNULL(SUM(IF(difficulty=0, pow(2, (" . $this->config['difficulty'] . " - 16)), difficulty)), 0) AS shares, - HOUR(time) AS hour - FROM " . $this->share->getArchiveTableName() . " - WHERE time <= FROM_UNIXTIME(FLOOR(UNIX_TIMESTAMP(NOW())/(60*60))*(60*60)) - AND time >= FROM_UNIXTIME(FLOOR(UNIX_TIMESTAMP(NOW())/(60*60))*(60*60)) - INTERVAL 24 HOUR - AND our_result = 'Y' - AND username LIKE ? - GROUP BY HOUR(time)"); - $username = $username . ".%"; - if ($this->checkStmt($stmt) && $stmt->bind_param('ss', $username, $username) && $stmt->execute() && $result = $stmt->get_result()) { + account_id AS id, + AVG(hashrate) AS hashrate, + HOUR(FROM_UNIXTIME(timestamp)) AS hour + FROM " . $this->getUserStatsTableName() . " + WHERE + account_id = ? + AND timestamp <= UNIX_TIMESTAMP(DATE_SUB(NOW(), INTERVAL 1 HOUR)) + AND timestamp >= UNIX_TIMESTAMP(DATE_SUB(NOW(), INTERVAL 24 HOUR)) + GROUP BY HOUR(FROM_UNIXTIME(timestamp))"); + if ($this->checkStmt($stmt) && $stmt->bind_param('i', $account_id) && $stmt->execute() && $result = $stmt->get_result()) { $iStartHour = date('G'); // Initilize array for ($i = 0; $i < 24; $i++) $aData[($iStartHour + $i) % 24] = 0; - // Fill data - while ($row = $result->fetch_assoc()) $aData[$row['hour']] += (int) $this->coin->calcHashrate($row['shares'], 3600); + // Fill data in proper hour order, result in SQL was ordered 0 - 23 + while ($row = $result->fetch_assoc()) $aData[$row['hour']] += (int)$row['hashrate']; return $this->memcache->setCache(__FUNCTION__ . $account_id, $aData); } return $this->sqlError(); @@ -702,30 +731,24 @@ class Statistics extends Base { if ($this->getGetCache() && $data = $this->memcache->get(__FUNCTION__)) return $data; $stmt = $this->mysqli->prepare(" SELECT - id, - IFNULL(SUM(IF(s.difficulty=0, pow(2, (" . $this->config['difficulty'] . " - 16)), s.difficulty)), 0) AS shares, - HOUR(s.time) AS hour - FROM " . $this->share->getTableName() . " AS s - WHERE time <= FROM_UNIXTIME(FLOOR(UNIX_TIMESTAMP(NOW())/(60*60))*(60*60)) - AND time >= FROM_UNIXTIME(FLOOR(UNIX_TIMESTAMP(NOW())/(60*60))*(60*60)) - INTERVAL 24 HOUR - AND our_result = 'Y' - GROUP BY HOUR(time) - UNION - SELECT - share_id, - IFNULL(SUM(IF(s.difficulty=0, pow(2, (" . $this->config['difficulty'] . " - 16)), s.difficulty)), 0) AS shares, - HOUR(s.time) AS hour - FROM " . $this->share->getArchiveTableName() . " AS s - WHERE time <= FROM_UNIXTIME(FLOOR(UNIX_TIMESTAMP(NOW())/(60*60))*(60*60)) - AND time >= FROM_UNIXTIME(FLOOR(UNIX_TIMESTAMP(NOW())/(60*60))*(60*60)) - INTERVAL 24 HOUR - AND our_result = 'Y' - GROUP BY HOUR(time)"); + SUM(hashrate) / ( + SELECT + COUNT(DISTINCT timestamp) + FROM " . $this->getUserStatsTableName() . " + WHERE timestamp <= UNIX_TIMESTAMP(DATE_SUB(NOW(), INTERVAL 1 HOUR)) + AND timestamp >= UNIX_TIMESTAMP(DATE_SUB(NOW(), INTERVAL 24 HOUR)) + ) AS hashrate, + HOUR(FROM_UNIXTIME(timestamp)) AS hour + FROM " . $this->getUserStatsTableName() . " + WHERE timestamp <= UNIX_TIMESTAMP(DATE_SUB(NOW(), INTERVAL 1 HOUR)) + AND timestamp >= UNIX_TIMESTAMP(DATE_SUB(NOW(), INTERVAL 24 HOUR)) + GROUP BY HOUR(FROM_UNIXTIME(timestamp))"); if ($this->checkStmt($stmt) && $stmt->execute() && $result = $stmt->get_result()) { $iStartHour = date('G'); // Initilize array for ($i = 0; $i < 24; $i++) $aData[($iStartHour + $i) % 24] = 0; // Fill data - while ($row = $result->fetch_assoc()) $aData[$row['hour']] += (int) $this->coin->calcHashrate($row['shares'], 3600); + while ($row = $result->fetch_assoc()) $aData[$row['hour']] += (int)$row['hashrate']; return $this->memcache->setCache(__FUNCTION__, $aData); } return $this->sqlError(); diff --git a/include/pages/statistics/graphs.inc.php b/include/pages/statistics/graphs.inc.php index 0a19492d..291229cf 100644 --- a/include/pages/statistics/graphs.inc.php +++ b/include/pages/statistics/graphs.inc.php @@ -4,7 +4,7 @@ $defflip = (!cfip()) ? exit(header('HTTP/1.1 401 Unauthorized')) : 1; if (!$smarty->isCached('master.tpl', $smarty_cache_key)) { $debug->append('No cached version available, fetching from backend', 3); if ($user->isAuthenticated()) { - $aHourlyHashRates = $statistics->getHourlyHashrateByAccount($_SESSION['USERDATA']['username'], $_SESSION['USERDATA']['id']); + $aHourlyHashRates = $statistics->getHourlyHashrateByAccount($_SESSION['USERDATA']['id']); $aPoolHourlyHashRates = $statistics->getHourlyHashrateByPool(); } $smarty->assign("YOURHASHRATES", @$aHourlyHashRates); diff --git a/include/version.inc.php b/include/version.inc.php index a4e0d533..2b7ea18a 100644 --- a/include/version.inc.php +++ b/include/version.inc.php @@ -2,7 +2,7 @@ $defflip = (!cfip()) ? exit(header('HTTP/1.1 401 Unauthorized')) : 1; define('MPOS_VERSION', '0.0.4'); -define('DB_VERSION', '0.0.12'); +define('DB_VERSION', '0.0.13'); define('CONFIG_VERSION', '0.0.8'); define('HASH_VERSION', 1); diff --git a/sql/000_base_structure.sql b/sql/000_base_structure.sql index a52829b5..b9887a51 100644 --- a/sql/000_base_structure.sql +++ b/sql/000_base_structure.sql @@ -144,7 +144,7 @@ CREATE TABLE IF NOT EXISTS `settings` ( UNIQUE KEY `setting` (`name`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8; -INSERT INTO `settings` (`name`, `value`) VALUES ('DB_VERSION', '0.0.12'); +INSERT INTO `settings` (`name`, `value`) VALUES ('DB_VERSION', '0.0.13'); CREATE TABLE IF NOT EXISTS `shares` ( `id` bigint(30) NOT NULL AUTO_INCREMENT, @@ -239,12 +239,15 @@ CREATE TABLE IF NOT EXISTS `transactions` ( KEY `account_id_archived` (`account_id`,`archived`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8; -CREATE TABLE IF NOT EXISTS `templates` ( - `template` varchar(255) NOT NULL, - `active` tinyint(1) NOT NULL DEFAULT 0, - `content` mediumtext, - `modified_at` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, - PRIMARY KEY (`template`) +CREATE TABLE `statistics_users` ( + `id` int(11) NOT NULL AUTO_INCREMENT, + `account_id` int(11) NOT NULL, + `hashrate` int(11) NOT NULL, + `workers` int(11) NOT NULL, + `sharerate` float NOT NULL, + `timestamp` int(11) NOT NULL, + PRIMARY KEY (`id`), + KEY `account_id_timestamp` (`account_id`,`timestamp`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8; /*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */; diff --git a/upgrade/definitions/0.0.12_to_0.0.13.inc.php b/upgrade/definitions/0.0.12_to_0.0.13.inc.php new file mode 100644 index 00000000..e661c4d1 --- /dev/null +++ b/upgrade/definitions/0.0.12_to_0.0.13.inc.php @@ -0,0 +1,39 @@ +getValue('DB_VERSION'); // Our actual version installed + + // Upgrade specific variables + $aSql[] = "CREATE TABLE `statistics_users` ( + `id` int(11) NOT NULL AUTO_INCREMENT, + `account_id` int(11) NOT NULL, + `hashrate` int(11) NOT NULL, + `workers` int(11) NOT NULL, + `sharerate` float NOT NULL, + `timestamp` int(11) NOT NULL, + PRIMARY KEY (`id`), + KEY `account_id_timestamp` (`account_id`,`timestamp`) + ) ENGINE=InnoDB DEFAULT CHARSET=utf8"; + $aSql[] = "UPDATE " . $setting->getTableName() . " SET value = '0.0.13' WHERE name = 'DB_VERSION'"; + + if ($db_version_now == $db_version_old && version_compare($db_version_now, DB_VERSION, '<')) { + // Run the upgrade + echo '- Starting database migration to version ' . $db_version_new . PHP_EOL; + foreach ($aSql as $sql) { + echo '- Preparing: ' . $sql . PHP_EOL; + $stmt = $mysqli->prepare($sql); + if ($stmt && $stmt->execute()) { + echo '- success' . PHP_EOL; + } else { + echo '- failed: ' . $mysqli->error . PHP_EOL; + exit(1); + } + } + } +} +?>