213 lines
		
	
	
		
			5.6 KiB
		
	
	
	
		
			MySQL
		
	
	
	
	
	
		
		
			
		
	
	
			213 lines
		
	
	
		
			5.6 KiB
		
	
	
	
		
			MySQL
		
	
	
	
	
	
| 
								 | 
							
								--
							 | 
						||
| 
								 | 
							
								-- What's the latest show today?
							 | 
						||
| 
								 | 
							
								--
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT concat('Latest show number on this date: ',curdate()) AS '';
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT max(id) AS latest_show
							 | 
						||
| 
								 | 
							
								FROM eps
							 | 
						||
| 
								 | 
							
								WHERE date <= curdate();
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								-- -----------------------------------------------------------------------------
							 | 
						||
| 
								 | 
							
								-- How many hosts are there up to and including today? Note there are 49 hosts
							 | 
						||
| 
								 | 
							
								-- with no shows at all, imported from the TWAT data, so a simple count of
							 | 
						||
| 
								 | 
							
								-- rows is not going to be correct.
							 | 
						||
| 
								 | 
							
								--
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT count(*) AS total_users_to_today
							 | 
						||
| 
								 | 
							
								FROM
							 | 
						||
| 
								 | 
							
								  ( SELECT e.id
							 | 
						||
| 
								 | 
							
								   FROM hosts h,
							 | 
						||
| 
								 | 
							
								        eps e
							 | 
						||
| 
								 | 
							
								   WHERE e.hostid = h.hostid
							 | 
						||
| 
								 | 
							
								     AND e.date <= curdate()
							 | 
						||
| 
								 | 
							
								   GROUP BY h.host) AS ttab;
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								--
							 | 
						||
| 
								 | 
							
								-- How many new hosts are there in the (future) queue?
							 | 
						||
| 
								 | 
							
								--
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT h.host AS upcoming_new_host,
							 | 
						||
| 
								 | 
							
								       min(e.date) AS joindate
							 | 
						||
| 
								 | 
							
								FROM hosts h,
							 | 
						||
| 
								 | 
							
								     eps e
							 | 
						||
| 
								 | 
							
								WHERE e.hostid = h.hostid
							 | 
						||
| 
								 | 
							
								GROUP BY h.host
							 | 
						||
| 
								 | 
							
								HAVING min(e.date) > curdate();
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								-- -----------------------------------------------------------------------------
							 | 
						||
| 
								 | 
							
								-- Find all new hosts who joined in the last year (ignoring those with queued
							 | 
						||
| 
								 | 
							
								-- shows in the future)
							 | 
						||
| 
								 | 
							
								--
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT 'Hosts joining in the last year with number of shows done' AS '';
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT h.hostid,
							 | 
						||
| 
								 | 
							
								       h.host,
							 | 
						||
| 
								 | 
							
								       min(e.date) AS joindate,
							 | 
						||
| 
								 | 
							
								       count(e.id) AS COUNT
							 | 
						||
| 
								 | 
							
								FROM eps e
							 | 
						||
| 
								 | 
							
								JOIN hosts h ON e.hostid = h.hostid
							 | 
						||
| 
								 | 
							
								GROUP BY h.hostid
							 | 
						||
| 
								 | 
							
								HAVING min(e.date) >= (curdate() - INTERVAL 364 DAY)
							 | 
						||
| 
								 | 
							
								AND min(e.date) <= curdate()
							 | 
						||
| 
								 | 
							
								ORDER BY min(e.date);
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT COUNT(*) AS new_host_count,
							 | 
						||
| 
								 | 
							
								            sum(COUNT) AS total_shows
							 | 
						||
| 
								 | 
							
								FROM
							 | 
						||
| 
								 | 
							
								  ( SELECT h.hostid,
							 | 
						||
| 
								 | 
							
								           h.host,
							 | 
						||
| 
								 | 
							
								           min(e.date) AS joindate,
							 | 
						||
| 
								 | 
							
								                          count(e.id) AS COUNT
							 | 
						||
| 
								 | 
							
								   FROM eps e
							 | 
						||
| 
								 | 
							
								   JOIN hosts h ON e.hostid = h.hostid
							 | 
						||
| 
								 | 
							
								   GROUP BY h.hostid
							 | 
						||
| 
								 | 
							
								   HAVING min(e.date) >= (curdate() - INTERVAL 364 DAY)
							 | 
						||
| 
								 | 
							
								   AND min(e.date) <= curdate()
							 | 
						||
| 
								 | 
							
								   ORDER BY min(e.date)) src;
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								-- -----------------------------------------------------------------------------
							 | 
						||
| 
								 | 
							
								-- Display all hosts contributing > 10 shows in the last year then count the
							 | 
						||
| 
								 | 
							
								-- number of shows
							 | 
						||
| 
								 | 
							
								--
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT 'Hosts contributing > 10 shows in the last year' AS '';
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT e.hostid,
							 | 
						||
| 
								 | 
							
								       h.host,
							 | 
						||
| 
								 | 
							
								       COUNT(e.hostid) AS shows
							 | 
						||
| 
								 | 
							
								FROM eps e
							 | 
						||
| 
								 | 
							
								JOIN hosts h ON e.hostid = h.hostid
							 | 
						||
| 
								 | 
							
								WHERE e.date <= curdate()
							 | 
						||
| 
								 | 
							
								  AND e.date >= (curdate() - interval 364 DAY)
							 | 
						||
| 
								 | 
							
								GROUP BY e.hostid
							 | 
						||
| 
								 | 
							
								HAVING COUNT(e.hostid) > 10
							 | 
						||
| 
								 | 
							
								ORDER BY COUNT(e.hostid) DESC;
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT COUNT(*) AS no_of_hosts,
							 | 
						||
| 
								 | 
							
								            sum(shows) AS sum_of_shows_by_group
							 | 
						||
| 
								 | 
							
								FROM
							 | 
						||
| 
								 | 
							
								  ( SELECT e.hostid,
							 | 
						||
| 
								 | 
							
								           h.host,
							 | 
						||
| 
								 | 
							
								           COUNT(e.hostid) AS shows
							 | 
						||
| 
								 | 
							
								   FROM eps e
							 | 
						||
| 
								 | 
							
								   JOIN hosts h ON e.hostid = h.hostid
							 | 
						||
| 
								 | 
							
								   WHERE e.date <= curdate()
							 | 
						||
| 
								 | 
							
								     AND e.date >= (curdate() - interval 364 DAY)
							 | 
						||
| 
								 | 
							
								   GROUP BY e.hostid
							 | 
						||
| 
								 | 
							
								   HAVING COUNT(e.hostid) > 10
							 | 
						||
| 
								 | 
							
								   ORDER BY COUNT(e.hostid) DESC) AS ttab;
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								--
							 | 
						||
| 
								 | 
							
								-- Display all hosts contributing > 5 shows in the last year then count the
							 | 
						||
| 
								 | 
							
								-- number of shows. Remember this includes the > 10 group too!
							 | 
						||
| 
								 | 
							
								--
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT 'Hosts contributing > 5 shows in the last year' AS '';
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT e.hostid,
							 | 
						||
| 
								 | 
							
								       h.host,
							 | 
						||
| 
								 | 
							
								       COUNT(e.hostid) AS shows
							 | 
						||
| 
								 | 
							
								FROM eps e
							 | 
						||
| 
								 | 
							
								JOIN hosts h ON e.hostid = h.hostid
							 | 
						||
| 
								 | 
							
								WHERE e.date <= curdate()
							 | 
						||
| 
								 | 
							
								  AND e.date >= (curdate() - interval 364 DAY)
							 | 
						||
| 
								 | 
							
								GROUP BY e.hostid
							 | 
						||
| 
								 | 
							
								HAVING COUNT(e.hostid) > 5
							 | 
						||
| 
								 | 
							
								ORDER BY COUNT(e.hostid) DESC;
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT COUNT(*) AS no_of_hosts,
							 | 
						||
| 
								 | 
							
								            sum(shows) AS sum_of_shows_by_group
							 | 
						||
| 
								 | 
							
								FROM
							 | 
						||
| 
								 | 
							
								  ( SELECT e.hostid,
							 | 
						||
| 
								 | 
							
								           h.host,
							 | 
						||
| 
								 | 
							
								           COUNT(e.hostid) AS shows
							 | 
						||
| 
								 | 
							
								   FROM eps e
							 | 
						||
| 
								 | 
							
								   JOIN hosts h ON e.hostid = h.hostid
							 | 
						||
| 
								 | 
							
								   WHERE e.date <= curdate()
							 | 
						||
| 
								 | 
							
								     AND e.date >= (curdate() - interval 364 DAY)
							 | 
						||
| 
								 | 
							
								   GROUP BY e.hostid
							 | 
						||
| 
								 | 
							
								   HAVING COUNT(e.hostid) > 5
							 | 
						||
| 
								 | 
							
								   ORDER BY COUNT(e.hostid) DESC) AS ttab;
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								--
							 | 
						||
| 
								 | 
							
								-- How many hosts contributed shows in the last year
							 | 
						||
| 
								 | 
							
								--
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT 'Number of hosts contributing shows in the last year' AS '';
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT COUNT(*) AS hosts_contributing_last_year,
							 | 
						||
| 
								 | 
							
								            sum(shows) AS sum_of_shows_by_group
							 | 
						||
| 
								 | 
							
								FROM
							 | 
						||
| 
								 | 
							
								  ( SELECT e.hostid,
							 | 
						||
| 
								 | 
							
								           h.host,
							 | 
						||
| 
								 | 
							
								           COUNT(e.hostid) AS shows
							 | 
						||
| 
								 | 
							
								   FROM eps e
							 | 
						||
| 
								 | 
							
								   JOIN hosts h ON e.hostid = h.hostid
							 | 
						||
| 
								 | 
							
								   WHERE e.date <= curdate()
							 | 
						||
| 
								 | 
							
								     AND e.date >= (curdate() - interval 364 DAY)
							 | 
						||
| 
								 | 
							
								   GROUP BY e.hostid
							 | 
						||
| 
								 | 
							
								   ORDER BY COUNT(e.hostid) DESC ) AS hly;
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								-- -----------------------------------------------------------------------------
							 | 
						||
| 
								 | 
							
								-- How many new hosts were there per year and how many shows have they
							 | 
						||
| 
								 | 
							
								-- contributed overall?
							 | 
						||
| 
								 | 
							
								--
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT 'Hosts per year and their contributions' AS '';
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT joinyear,
							 | 
						||
| 
								 | 
							
								       COUNT(*) AS new_hosts,
							 | 
						||
| 
								 | 
							
								            sum(shows) AS shows
							 | 
						||
| 
								 | 
							
								FROM
							 | 
						||
| 
								 | 
							
								  ( SELECT extract(YEAR
							 | 
						||
| 
								 | 
							
								                   FROM min(e.date)) AS joinyear,
							 | 
						||
| 
								 | 
							
								           count(e.id) AS shows
							 | 
						||
| 
								 | 
							
								   FROM eps e
							 | 
						||
| 
								 | 
							
								   JOIN hosts h ON e.hostid = h.hostid
							 | 
						||
| 
								 | 
							
								   WHERE e.date <= curdate()
							 | 
						||
| 
								 | 
							
								   GROUP BY h.hostid
							 | 
						||
| 
								 | 
							
								   ORDER BY min(e.date)) AS ttab
							 | 
						||
| 
								 | 
							
								GROUP BY joinyear;
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								-- -----------------------------------------------------------------------------
							 | 
						||
| 
								 | 
							
								-- Hosts who joined, did a show but haven't been seen since January of the
							 | 
						||
| 
								 | 
							
								-- year 3 years ago.
							 | 
						||
| 
								 | 
							
								--
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT 'Hosts not seen for the past three years' AS '';
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT COUNT(*) AS departed_hosts
							 | 
						||
| 
								 | 
							
								FROM
							 | 
						||
| 
								 | 
							
								  ( SELECT h.hostid,
							 | 
						||
| 
								 | 
							
								           h.host,
							 | 
						||
| 
								 | 
							
								           min(e.date) AS joindate,
							 | 
						||
| 
								 | 
							
								                          max(e.date) AS lastshow,
							 | 
						||
| 
								 | 
							
								                                         count(e.id) AS shows
							 | 
						||
| 
								 | 
							
								   FROM eps e
							 | 
						||
| 
								 | 
							
								   JOIN hosts h ON e.hostid = h.hostid
							 | 
						||
| 
								 | 
							
								   WHERE e.date <= curdate()
							 | 
						||
| 
								 | 
							
								   GROUP BY h.hostid
							 | 
						||
| 
								 | 
							
								   HAVING lastshow < date_format(date_sub(curdate(),INTERVAL 3 YEAR),'%Y-01-01')
							 | 
						||
| 
								 | 
							
								   ORDER BY shows,
							 | 
						||
| 
								 | 
							
								            min(e.date)) ttab;
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								-- -----------------------------------------------------------------------------
							 | 
						||
| 
								 | 
							
								-- Show hosts and shows per month throughout the HPR history
							 | 
						||
| 
								 | 
							
								--
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT 'Hosts and shows per month throughout the HPR history' AS '';
							 | 
						||
| 
								 | 
							
								
							 | 
						||
| 
								 | 
							
								SELECT extract(year_month
							 | 
						||
| 
								 | 
							
								               FROM e.date) AS MONTH,
							 | 
						||
| 
								 | 
							
								       COUNT(e.id) AS shows,
							 | 
						||
| 
								 | 
							
								            COUNT(DISTINCT e.hostid) AS hosts
							 | 
						||
| 
								 | 
							
								FROM eps e
							 | 
						||
| 
								 | 
							
								WHERE e.date < date_format(curdate(),"%Y-%c-01")
							 | 
						||
| 
								 | 
							
								GROUP BY MONTH;
							 | 
						||
| 
								 | 
							
								
							 |