summaryrefslogtreecommitdiff
path: root/views/full_season_drivers.sql
diff options
context:
space:
mode:
authoremkael <emkael@tlen.pl>2015-02-18 12:11:37 +0100
committeremkael <emkael@tlen.pl>2015-02-18 12:11:37 +0100
commita0f5e709cfc9b61a8919b9ddb3ce915028128287 (patch)
treeb711d7da5ab1716d667ab53e65514afcdf7fe11b /views/full_season_drivers.sql
parenteba0b7e9529dd8eb6702615e6a8c3b2dc092e5bc (diff)
* useful views, separated by theme
Diffstat (limited to 'views/full_season_drivers.sql')
-rw-r--r--views/full_season_drivers.sql30
1 files changed, 30 insertions, 0 deletions
diff --git a/views/full_season_drivers.sql b/views/full_season_drivers.sql
new file mode 100644
index 0000000..ae36cc8
--- /dev/null
+++ b/views/full_season_drivers.sql
@@ -0,0 +1,30 @@
+-- view holds distinct driver-race entries
+-- (eliminating duplicate race entries from shared drives)
+CREATE VIEW driver_races AS
+ SELECT driverId, raceId
+ FROM results
+ GROUP BY driverId, raceId;
+
+-- view aggregates races by season for each driver
+CREATE VIEW driver_season_races AS
+ SELECT driver_races.driverId, races.year,
+ GROUP_CONCAT(driver_races.raceId
+ ORDER BY driver_races.raceId ASC)
+ AS races
+ FROM driver_races
+ JOIN races ON races.raceId = driver_races.raceId
+ GROUP BY driver_races.driverId, races.year;
+
+-- view aggregates races by season
+CREATE VIEW season_races AS
+ SELECT year, GROUP_CONCAT(raceId ORDER BY raceId ASC) AS races
+ FROM races
+ GROUP BY year;
+
+-- selecting only driver-season pairs with all races in a season
+CREATE VIEW full_season_drivers AS
+ SELECT driver_season_races.driverId, driver_season_races.year
+ FROM season_races
+ JOIN driver_season_races
+ ON (season_races.races = driver_season_races.races)
+ AND (season_races.year = driver_season_races.year);