CREATE TABLE `play_action` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`timestamp` timestamp NULL DEFAULT CURRENT_TIMESTAMP,
`play_result` INT (10) NOT NULL
)
想要以天為單位:
SELECT DATE_FORMAT(timestamp, "%Y-%m-%d %a") AS d, play_result, count(*) FROM play_action GROUP BY d, play_result
就能得知一天當中,所有操作結果的次數,那如果是比例呢?只好要先 SUM 加總一下 XD 最後在 JOIN 一下即可。此例就用暫存表來處理,其中暫存表不予許同一個 SQL 內有多次存取,所以只好多開一張暫存表來處理,連續動作:
Step 1: 建立一張暫時表,以天為單位,根據播放後的狀態,依序是播放次數、播放日期、播放結果,其中播放結果 0 是正常的
CREATE TEMPORARY TABLE `play` (
`play_count` INT (10) NOT NULL,
`play_date` VARCHAR(32) NOT NULL,
`play_result` INT (10) NOT NULL,
UNIQUE KEY `play_date` (`play_date`, `play_result`)
);
Step 2: 從 play_action 撈資料來填補,此時可以用條件式挑選想要的資料,此例是 4 月之後的資料
INSERT INTO `play` (play_result, play_date, play_count) SELECT play_result, DATE_FORMAT(timestamp, "%Y-%m-%d %a") AS d, count(*) as c FROM play_action WHERE timestamp >= '2016-04-01 00:00:00' GROUP BY play_result, d ORDER BY d ON DUPLICATE KEY UPDATE play_count=VALUES(play_count);
Step 3: 建立另一張暫存表,單純以天記錄總播放次數
CREATE TEMPORARY TABLE `play_sum` (
`play_count` INT (10) NOT NULL,
`play_date` VARCHAR(32) NOT NULL,
UNIQUE KEY `play_date` (`play_date`)
);
INSERT INTO `play_sum` (play_date, play_count) SELECT play_date, SUM(play_count) AS play_total FROM play GROUP BY play_date;
Step 4: 簡易運算,輸出為日期、播放成功次數的比例,總播放次數
SELECT play.play_date, play.play_result, play.play_count / play_sum.play_count * 100, play_sum.play_count AS play_total FROM play, play_sum WHERE play.play_date = play_sum.play_date;
+----------------+-------------+---------------------------------------------+------------+
| play_date | play_result | play.play_count / play_sum.play_count * 100 | play_total |
+----------------+-------------+---------------------------------------------+------------+
| 2016-04-01 Fri | 0 | 54.9398 | 687 |
| 2016-04-02 Sat | 0 | 68.9445 | 972 |
| 2016-04-03 Sun | 0 | 75.6607 | 1748 |
| 2016-04-04 Mon | 0 | 71.3967 | 1112 |
| 2016-04-05 Tue | 0 | 70.2852 | 886 |
| 2016-04-06 Wed | 0 | 49.8085 | 880 |
| 2016-04-07 Thu | 0 | 53.2239 | 596 |
+----------------+-------------+---------------------------------------------+------------+
沒有留言:
張貼留言