package storage // ToDo: The last seen statistic is done in days, maybe change or add in how many draws x days ways for ease. // Top 5 main numbers since inception of the game. const top5AllTime = ` SELECT ball AS Number, COUNT(*) AS Frequency FROM ( SELECT ball1 AS ball FROM results_thunderball UNION ALL SELECT ball2 FROM results_thunderball UNION ALL SELECT ball3 FROM results_thunderball UNION ALL SELECT ball4 FROM results_thunderball UNION ALL SELECT ball5 FROM results_thunderball ) GROUP BY ball ORDER BY Frequency DESC, Number LIMIT 5;` // Top 5 main numbers since the ball count change on May 9th 2010. const top5Since = ` SELECT ball AS Number, COUNT(*) AS Frequency FROM ( SELECT ball1 AS ball FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' UNION ALL SELECT ball2 FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' UNION ALL SELECT ball3 FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' UNION ALL SELECT ball4 FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' UNION ALL SELECT ball5 FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' ) GROUP BY ball ORDER BY Frequency DESC, Number LIMIT 5;` // Top 5 main numbers in the last 180 draws. const top5Last180draws = ` SELECT ball AS Number, COUNT(*) AS Frequency FROM ( SELECT ball1 AS ball FROM ( SELECT * FROM results_thunderball ORDER BY date(draw_date) DESC LIMIT 180 ) UNION ALL SELECT ball2 FROM ( SELECT * FROM results_thunderball ORDER BY date(draw_date) DESC LIMIT 180 ) UNION ALL SELECT ball3 FROM ( SELECT * FROM results_thunderball ORDER BY date(draw_date) DESC LIMIT 180 ) UNION ALL SELECT ball4 FROM ( SELECT * FROM results_thunderball ORDER BY date(draw_date) DESC LIMIT 180 ) UNION ALL SELECT ball5 FROM ( SELECT * FROM results_thunderball ORDER BY date(draw_date) DESC LIMIT 180 ) ) GROUP BY ball ORDER BY Frequency DESC LIMIT 5;` // The top 5 thunderballs drawn since the inception of the game. const top5ThunderballAllTime = ` SELECT thunderball AS Number, COUNT(*) AS Frequency FROM ( SELECT thunderball AS thunderball FROM results_thunderball ) GROUP BY thunderball ORDER BY Frequency DESC, Number LIMIT 5;` // The top 5 thunderballs drawn since the ball count change on May 9th 2010. const top5ThunderballSince = ` SELECT thunderball AS Number, COUNT(*) AS Frequency FROM ( SELECT thunderball AS thunderball FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' ) GROUP BY thunderball ORDER BY Frequency DESC, Number LIMIT 5;` const top5TunderballLast180draws = ` SELECT thunderball AS Number, COUNT(*) AS Frequency FROM ( SELECT thunderball AS thunderball FROM ( SELECT * FROM results_thunderball ORDER BY date(draw_date) DESC LIMIT 180 ) ) GROUP BY thunderball ORDER BY Frequency DESC LIMIT 5;` const thunderballMainLastSeen = ` SELECT n.ball AS Number, julianday('now') - julianday(MAX(r.draw_date)) AS DaysSinceLastDrawn, MAX(r.draw_date) AS LastDrawDate FROM ( SELECT ball1 AS ball, draw_date FROM results_thunderball UNION ALL SELECT ball2, draw_date FROM results_thunderball UNION ALL SELECT ball3, draw_date FROM results_thunderball UNION ALL SELECT ball4, draw_date FROM results_thunderball UNION ALL SELECT ball5, draw_date FROM results_thunderball ) AS r JOIN ( -- This generates a list of all possible ball numbers (1–39) SELECT 1 AS ball UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL SELECT 4 UNION ALL SELECT 5 UNION ALL SELECT 6 UNION ALL SELECT 7 UNION ALL SELECT 8 UNION ALL SELECT 9 UNION ALL SELECT 10 UNION ALL SELECT 11 UNION ALL SELECT 12 UNION ALL SELECT 13 UNION ALL SELECT 14 UNION ALL SELECT 15 UNION ALL SELECT 16 UNION ALL SELECT 17 UNION ALL SELECT 18 UNION ALL SELECT 19 UNION ALL SELECT 20 UNION ALL SELECT 21 UNION ALL SELECT 22 UNION ALL SELECT 23 UNION ALL SELECT 24 UNION ALL SELECT 25 UNION ALL SELECT 26 UNION ALL SELECT 27 UNION ALL SELECT 28 UNION ALL SELECT 29 UNION ALL SELECT 30 UNION ALL SELECT 31 UNION ALL SELECT 32 UNION ALL SELECT 33 UNION ALL SELECT 34 UNION ALL SELECT 35 UNION ALL SELECT 36 UNION ALL SELECT 37 UNION ALL SELECT 38 UNION ALL SELECT 39 ) AS n ON n.ball = r.ball GROUP BY n.ball ORDER BY DaysSinceLastDrawn DESC;` const thunderballLastSeen = ` SELECT n.thunderball AS Number, julianday('now') - julianday(MAX(r.draw_date)) AS DaysSinceLastDrawn, MAX(r.draw_date) AS LastDrawDate FROM ( SELECT thunderball AS thunderball, draw_date FROM results_thunderball ) AS r JOIN ( SELECT 1 AS thunderball UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL SELECT 4 UNION ALL SELECT 5 UNION ALL SELECT 6 UNION ALL SELECT 7 UNION ALL SELECT 8 UNION ALL SELECT 9 UNION ALL SELECT 10 UNION ALL SELECT 11 UNION ALL SELECT 12 UNION ALL SELECT 13 UNION ALL SELECT 14 ) AS n ON n.thunderball = r.thunderball GROUP BY n.thunderball ORDER BY DaysSinceLastDrawn DESC;` const thunderballCommonPairsSince = ` WITH unpivot AS ( SELECT draw_date, ball1 AS ball FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' UNION ALL SELECT draw_date, ball2 FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' UNION ALL SELECT draw_date, ball3 FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' UNION ALL SELECT draw_date, ball4 FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' UNION ALL SELECT draw_date, ball5 FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' ), pairs AS ( SELECT a.draw_date, MIN(a.ball, b.ball) AS ball_a, MAX(a.ball, b.ball) AS ball_b FROM unpivot a JOIN unpivot b ON a.draw_date = b.draw_date AND a.ball < b.ball ) SELECT ball_a, ball_b, COUNT(*) AS frequency FROM pairs GROUP BY ball_a, ball_b ORDER BY frequency DESC, ball_a, ball_b LIMIT 25;` const thunderballCommonPairsLast180 = ` WITH recent AS ( SELECT * FROM results_thunderball ORDER BY date(draw_date) DESC LIMIT 180 ), unpivot AS ( SELECT draw_date, ball1 AS ball FROM recent UNION ALL SELECT draw_date, ball2 FROM recent UNION ALL SELECT draw_date, ball3 FROM recent UNION ALL SELECT draw_date, ball4 FROM recent UNION ALL SELECT draw_date, ball5 FROM recent ), pairs AS ( SELECT a.draw_date, MIN(a.ball, b.ball) AS ball_a, MAX(a.ball, b.ball) AS ball_b FROM unpivot a JOIN unpivot b ON a.draw_date = b.draw_date AND a.ball < b.ball ) SELECT ball_a, ball_b, COUNT(*) AS frequency FROM pairs GROUP BY ball_a, ball_b ORDER BY frequency DESC, ball_a, ball_b LIMIT 25;` // Best pair balls if you choose x try picking these numbers that are frequencly seen with it (ToDo: Update this description) // ToDo No All Time for this, go back and ensure everything has an all time for completeness. const thunderballSepecificCommonPairsSince = ` WITH unpivot AS ( SELECT draw_date, ball1 AS ball FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' UNION ALL SELECT draw_date, ball2 FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' UNION ALL SELECT draw_date, ball3 FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' UNION ALL SELECT draw_date, ball4 FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' UNION ALL SELECT draw_date, ball5 FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' ), pairs AS ( SELECT a.draw_date, MIN(a.ball, b.ball) AS ball_a, MAX(a.ball, b.ball) AS ball_b FROM unpivot a JOIN unpivot b ON a.draw_date = b.draw_date AND a.ball < b.ball ) SELECT CASE WHEN ball_a = 26 THEN ball_b ELSE ball_a END AS partner, COUNT(*) AS frequency FROM pairs WHERE ball_a = 26 OR ball_b = 26 GROUP BY partner ORDER BY frequency DESC, partner LIMIT 20;` const thunderballCommonConsecutiveNumbersAllTime = ` WITH unpivot AS ( SELECT draw_date, ball1 AS ball FROM results_thunderball UNION ALL SELECT draw_date, ball2 FROM results_thunderball UNION ALL SELECT draw_date, ball3 FROM results_thunderball UNION ALL SELECT draw_date, ball4 FROM results_thunderball UNION ALL SELECT draw_date, ball5 FROM results_thunderball ), pairs AS ( SELECT a.draw_date, MIN(a.ball, b.ball) AS a_ball, MAX(a.ball, b.ball) AS b_ball FROM unpivot a JOIN unpivot b ON a.draw_date = b.draw_date AND a.ball < b.ball AND ABS(a.ball - b.ball) = 1 -- consecutive only ) SELECT a_ball AS num1, b_ball AS num2, COUNT(*) AS frequency FROM pairs GROUP BY a_ball, b_ball ORDER BY frequency DESC, num1, num2 LIMIT 25; ` const thunderballCommonConsecutiveNumbersSince = ` WITH unpivot AS ( SELECT draw_date, ball1 AS ball FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' UNION ALL SELECT draw_date, ball2 FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' UNION ALL SELECT draw_date, ball3 FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' UNION ALL SELECT draw_date, ball4 FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' UNION ALL SELECT draw_date, ball5 FROM results_thunderball WHERE date(draw_date) >= '2010-05-09' ), pairs AS ( SELECT a.draw_date, MIN(a.ball, b.ball) AS a_ball, MAX(a.ball, b.ball) AS b_ball FROM unpivot a JOIN unpivot b ON a.draw_date = b.draw_date AND a.ball < b.ball AND ABS(a.ball - b.ball) = 1 -- consecutive only ) SELECT a_ball AS num1, b_ball AS num2, COUNT(*) AS frequency FROM pairs GROUP BY a_ball, b_ball ORDER BY frequency DESC, num1, num2 LIMIT 25; ` // Wait, double check common number queries, consecutive and consecutive numbers make sure ive not mixed them up