--? 1 - L’objectif de ce TP étant d’étudier l’optimisation et les index, --? mettez à jour les statistiques utilisées par PostgreSQL pour établir les plans d’exécution afin de partir sur de bonnes bases. -- TODO : ANALYZE table_name; ANALYSE; -- Pour tout d'un coup. --? 2 - Lors du TP précédent, vous avez écrit une requête permettant de répondre à la question --? suivante : --? Quel est le joueur qui a fait le plus rapidement 6 fautes personnelles ? Donner la date de cette performance et le nom des deux équipes qui se sont affrontées lors de ce match. --? Afficher le plan d’exécution détaillé avec le temps d’exécution de cette requête. EXPLAIN ANALYZE SELECT p.name , t1.abbreviation , t2.abbreviation , g.dateGame FROM Player p, Team t1, Team t2, GameDetail gd, Game g WHERE p.id = gd.idPlayer AND g.id = gd.idGame AND t1.id = gd.idTeam AND ((g.idHomeTeam = t1.id AND g.idVisitorTeam = t2.id) OR (g.idVisitorTeam = t1.id AND g.idHomeTeam = t2.id)) AND gd.personnalFoul > 6; -- QUERY PLAN -- --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- -- Nested Loop (cost=1001.37..16948.56 rows=1 width=49) (actual time=85.074..86.860 rows=1 loops=1) -- Join Filter: ((((g.idhometeam)::text = (t1.id)::text) AND ((g.idvisitorteam)::text = (t2.id)::text)) OR (((g.idvisitorteam)::text = (t1.id)::text) AND ((g.idhometeam)::text = (t2.id)::text))) -- Rows Removed by Join Filter: 1 -- -> Nested Loop (cost=1000.97..16940.34 rows=1 width=93) (actual time=85.034..86.818 rows=1 loops=1) -- Join Filter: ((gd.idteam)::text = (t1.id)::text) -- -> Nested Loop (cost=1000.57..16933.54 rows=1 width=50) (actual time=84.985..86.769 rows=1 loops=1) -- -> Nested Loop (cost=1000.28..16925.24 rows=1 width=33) (actual time=84.973..86.756 rows=1 loops=1) -- -> Gather (cost=1000.00..16916.93 rows=1 width=26) (actual time=83.900..85.640 rows=1 loops=1) -- Workers Planned: 2 -- Workers Launched: 2 -- -> Parallel Seq Scan on gamedetail gd (cost=0.00..15916.83 rows=1 width=26) (actual time=56.639..67.325 rows=0 loops=3) -- Filter: (personnalfoul > '6'::numeric) -- Rows Removed by Filter: 215221 -- -> Index Scan using player_pkey on player p (cost=0.28..8.30 rows=1 width=19) (actual time=1.005..1.005 rows=1 loops=1) -- Index Cond: ((id)::text = (gd.idplayer)::text) -- -> Index Scan using game_pkey on game g (cost=0.29..8.30 rows=1 width=35) (actual time=0.008..0.008 rows=1 loops=1) -- Index Cond: (id = gd.idgame) -- -> Bitmap Heap Scan on team t1 (cost=0.40..4.42 rows=190 width=54) (actual time=0.012..0.012 rows=1 loops=1) -- Recheck Cond: (((g.idhometeam)::text = (id)::text) OR ((g.idvisitorteam)::text = (id)::text)) -- Heap Blocks: exact=1 -- -> BitmapOr (cost=0.40..0.40 rows=2 width=0) (actual time=0.007..0.008 rows=0 loops=1) -- -> Bitmap Index Scan on team_pkey (cost=0.00..0.15 rows=1 width=0) (actual time=0.005..0.005 rows=1 loops=1) -- Index Cond: ((id)::text = (g.idhometeam)::text) -- -> Bitmap Index Scan on team_pkey (cost=0.00..0.15 rows=1 width=0) (actual time=0.001..0.001 rows=1 loops=1) -- Index Cond: ((id)::text = (g.idvisitorteam)::text) -- -> Bitmap Heap Scan on team t2 (cost=0.40..4.42 rows=190 width=54) (actual time=0.003..0.004 rows=2 loops=1) -- Recheck Cond: (((g.idvisitorteam)::text = (id)::text) OR ((g.idhometeam)::text = (id)::text)) -- Heap Blocks: exact=1 -- -> BitmapOr (cost=0.40..0.40 rows=2 width=0) (actual time=0.003..0.003 rows=0 loops=1) -- -> Bitmap Index Scan on team_pkey (cost=0.00..0.15 rows=1 width=0) (actual time=0.001..0.001 rows=1 loops=1) -- Index Cond: ((id)::text = (g.idvisitorteam)::text) -- -> Bitmap Index Scan on team_pkey (cost=0.00..0.15 rows=1 width=0) (actual time=0.001..0.001 rows=1 loops=1) -- Index Cond: ((id)::text = (g.idhometeam)::text) -- Planning Time: 1.956 ms -- Execution Time: 87.197 ms -- (35 rows) --? 3 - En indexant une colonne, il est possible de grandement améliorer le temps d’exécution de la requête. Laquelle ? Tester et comparer le temps d’exécution. CREATE INDEX idx ON GameDetail(personnalFoul); EXPLAIN ANALYZE SELECT p.name , t1.abbreviation , t2.abbreviation , g.dateGame FROM Player p, Team t1, Team t2, GameDetail gd, Game g WHERE p.id = gd.idPlayer AND g.id = gd.idGame AND t1.id = gd.idTeam AND ((g.idHomeTeam = t1.id AND g.idVisitorTeam = t2.id) OR (g.idVisitorTeam = t1.id AND g.idHomeTeam = t2.id)) AND gd.personnalFoul > 6; -- QUERY PLAN -- --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- -- Nested Loop (cost=1.79..40.07 rows=1 width=49) (actual time=0.201..0.214 rows=1 loops=1) -- Join Filter: ((((g.idhometeam)::text = (t1.id)::text) AND ((g.idvisitorteam)::text = (t2.id)::text)) OR (((g.idvisitorteam)::text = (t1.id)::text) AND ((g.idhometeam)::text = (t2.id)::text))) -- Rows Removed by Join Filter: 1 -- -> Nested Loop (cost=1.39..31.85 rows=1 width=93) (actual time=0.174..0.183 rows=1 loops=1) -- Join Filter: ((gd.idteam)::text = (t1.id)::text) -- -> Nested Loop (cost=0.99..25.05 rows=1 width=50) (actual time=0.128..0.134 rows=1 loops=1) -- -> Nested Loop (cost=0.71..16.75 rows=1 width=33) (actual time=0.093..0.097 rows=1 loops=1) -- -> Index Scan using idx on gamedetail gd (cost=0.42..8.44 rows=1 width=26) (actual time=0.044..0.046 rows=1 loops=1) -- Index Cond: (personnalfoul > '6'::numeric) -- -> Index Scan using player_pkey on player p (cost=0.28..8.30 rows=1 width=19) (actual time=0.031..0.032 rows=1 loops=1) -- Index Cond: ((id)::text = (gd.idplayer)::text) -- -> Index Scan using game_pkey on game g (cost=0.29..8.30 rows=1 width=35) (actual time=0.029..0.030 rows=1 loops=1) -- Index Cond: (id = gd.idgame) -- -> Bitmap Heap Scan on team t1 (cost=0.40..4.42 rows=190 width=54) (actual time=0.032..0.035 rows=1 loops=1) -- Recheck Cond: (((g.idhometeam)::text = (id)::text) OR ((g.idvisitorteam)::text = (id)::text)) -- Heap Blocks: exact=1 -- -> BitmapOr (cost=0.40..0.40 rows=2 width=0) (actual time=0.020..0.022 rows=0 loops=1) -- -> Bitmap Index Scan on team_pkey (cost=0.00..0.15 rows=1 width=0) (actual time=0.012..0.012 rows=1 loops=1) -- Index Cond: ((id)::text = (g.idhometeam)::text) -- -> Bitmap Index Scan on team_pkey (cost=0.00..0.15 rows=1 width=0) (actual time=0.003..0.003 rows=1 loops=1) -- Index Cond: ((id)::text = (g.idvisitorteam)::text) -- -> Bitmap Heap Scan on team t2 (cost=0.40..4.42 rows=190 width=54) (actual time=0.012..0.014 rows=2 loops=1) -- Recheck Cond: (((g.idvisitorteam)::text = (id)::text) OR ((g.idhometeam)::text = (id)::text)) -- Heap Blocks: exact=1 -- -> BitmapOr (cost=0.40..0.40 rows=2 width=0) (actual time=0.009..0.010 rows=0 loops=1) -- -> Bitmap Index Scan on team_pkey (cost=0.00..0.15 rows=1 width=0) (actual time=0.004..0.004 rows=1 loops=1) -- Index Cond: ((id)::text = (g.idvisitorteam)::text) -- -> Bitmap Index Scan on team_pkey (cost=0.00..0.15 rows=1 width=0) (actual time=0.003..0.003 rows=1 loops=1) -- Index Cond: ((id)::text = (g.idhometeam)::text) -- Planning Time: 2.722 ms -- Execution Time: 0.558 ms -- (31 rows) --? 4 - Trouver le nom de l’équipe ayant gagné un match avec le plus grand écart de points, avec le score final. SELECT t1.nickname, abs(g.ptsAway - g.ptsHome), ptsAway, ptsHome FROM Team t1, Team t2, Game g WHERE t1.id = g.idHomeTeam AND t2.id = g.idVisitorTeam AND g.homeTeamWins = TRUE GROUP BY t1.nickname, abs(g.ptsAway - g.ptsHome), ptsAway, ptsHome HAVING abs(g.ptsAway - g.ptsHome) >= ALL(SELECT abs(g.ptsAway - g.ptsHome) FROM Team t3, Team t4, Game g WHERE t3.id = g.idHomeTeam AND t4.id = g.idVisitorTeam AND g.homeTeamWins = true); -- nickname | abs | ptsaway | ptshome -- -----------+-----+---------+--------- -- Grizzlies | 73 | 79 | 152 -- (1 row) --? 5 - Analyser le plan d’exécution. --! devrait marcher normalement (sans HAVING)==> OUI --? Mais change pas grand chose ????!!!! EXPLAIN ANALYZE SELECT t1.nickname, abs(g.ptsAway - g.ptsHome), ptsAway, ptsHome FROM Team t1, Team t2, Game g WHERE t1.id = g.idHomeTeam AND t2.id = g.idVisitorTeam AND g.homeTeamWins = TRUE AND abs(g.ptsAway - g.ptsHome) >= ALL(SELECT abs(g.ptsAway - g.ptsHome) FROM Team t1, Team t2, Game g WHERE t1.id = g.idHomeTeam AND t2.id = g.idVisitorTeam AND g.homeTeamWins = true); EXPLAIN ANALYZE -- SELECT t1.nickname, abs(g.ptsAway - g.ptsHome), ptsAway, ptsHome -- FROM Team t1, Team t2, Game g -- WHERE t1.id = g.idHomeTeam AND t2.id = g.idVisitorTeam AND g.homeTeamWins = TRUE -- GROUP BY t1.nickname, abs(g.ptsAway - g.ptsHome), ptsAway, ptsHome -- HAVING abs(g.ptsAway - g.ptsHome) >= ALL(SELECT abs(g.ptsAway - g.ptsHome) -- FROM Team t1, Team t2, Game g -- WHERE t1.id = g.idHomeTeam AND t2.id = g.idVisitorTeam AND g.homeTeamWins = true); -- QUERY PLAN -- ---------------------------------------------------------------------------------------------------------------------------------------- -- HashAggregate (cost=1065.09..7344429.42 rows=7569 width=120) (actual time=73.608..80.050 rows=1 loops=1) -- Group Key: t1.nickname, abs((g.ptsaway - g.ptshome)), g.ptsaway, g.ptshome -- Filter: (SubPlan 1) -- Batches: 1 Memory Usage: 1433kB -- Rows Removed by Filter: 11863 -- -> Hash Join (cost=28.55..885.16 rows=15138 width=120) (actual time=0.139..26.082 rows=15138 loops=1) -- Hash Cond: ((g.idvisitorteam)::text = (t2.id)::text) -- -> Hash Join (cost=14.28..754.57 rows=15138 width=99) (actual time=0.060..15.497 rows=15138 loops=1) -- Hash Cond: ((g.idhometeam)::text = (t1.id)::text) -- -> Seq Scan on game g (cost=0.00..699.67 rows=15138 width=32) (actual time=0.014..8.369 rows=15138 loops=1) -- Filter: hometeamwins -- Rows Removed by Filter: 10629 -- -> Hash (cost=11.90..11.90 rows=190 width=116) (actual time=0.027..0.027 rows=30 loops=1) -- Buckets: 1024 Batches: 1 Memory Usage: 10kB -- -> Seq Scan on team t1 (cost=0.00..11.90 rows=190 width=116) (actual time=0.004..0.012 rows=30 loops=1) -- -> Hash (cost=11.90..11.90 rows=190 width=38) (actual time=0.054..0.054 rows=30 loops=1) -- Buckets: 1024 Batches: 1 Memory Usage: 10kB -- -> Seq Scan on team t2 (cost=0.00..11.90 rows=190 width=38) (actual time=0.024..0.032 rows=30 loops=1) -- SubPlan 1 -- -> Materialize (cost=28.55..960.85 rows=15138 width=32) (actual time=0.000..0.002 rows=9 loops=11864) -- -> Hash Join (cost=28.55..885.16 rows=15138 width=32) (actual time=0.096..14.368 rows=15138 loops=1) -- Hash Cond: ((g_1.idvisitorteam)::text = (t2_1.id)::text) -- -> Hash Join (cost=14.28..754.57 rows=15138 width=21) (actual time=0.032..8.845 rows=15138 loops=1) -- Hash Cond: ((g_1.idhometeam)::text = (t1_1.id)::text) -- -> Seq Scan on game g_1 (cost=0.00..699.67 rows=15138 width=32) (actual time=0.010..5.103 rows=15138 loops=1) -- Filter: hometeamwins -- Rows Removed by Filter: 10629 -- -> Hash (cost=11.90..11.90 rows=190 width=38) (actual time=0.016..0.016 rows=30 loops=1) -- Buckets: 1024 Batches: 1 Memory Usage: 10kB -- -> Seq Scan on team t1_1 (cost=0.00..11.90 rows=190 width=38) (actual time=0.002..0.009 rows=30 loops=1) -- -> Hash (cost=11.90..11.90 rows=190 width=38) (actual time=0.039..0.039 rows=30 loops=1) -- Buckets: 1024 Batches: 1 Memory Usage: 10kB -- -> Seq Scan on team t2_1 (cost=0.00..11.90 rows=190 width=38) (actual time=0.028..0.032 rows=30 loops=1) -- Planning Time: 0.916 ms -- Execution Time: 80.363 ms -- (35 rows) --! Optimiser le JOIN --? 6 - Comment améliorer les performances de cette requête ? Tester et comparer. ==> But : faire des index CREATE INDEX idx2 ON Game(idHomeTeam, idVisitorTeam); --? 7 - Trouver les joueurs ayant fait plus de 5 interceptions (steal) tout en ayant commencé au centre. SELECT p.id, p.name FROM Player p, GameDetail gd WHERE p.id = gd.idPlayer AND gd.steals >= 5 AND gd.startposition = 'C'; -- id | name -- ---------+--------------------- -- 1630596 | Evan Mobley -- 1628389 | Bam Adebayo -- 202326 | DeMarcus Cousins -- 203991 | Clint Capela -- 1628389 | Bam Adebayo -- 203083 | Andre Drummond -- 202696 | Nikola Vucevic -- 203110 | Draymond Green -- 203083 | Andre Drummond -- 203954 | Joel Embiid -- 202326 | DeMarcus Cousins -- 1628976 | Wendell Carter Jr. -- 202696 | Nikola Vucevic -- 203999 | Nikola Jokic -- 1626167 | Myles Turner -- 203496 | Robert Covington --? 8 - Analyser le plan d’exécution EXPLAIN ANALYZE SELECT p.id, p.name FROM Player p, GameDetail gd WHERE p.id = gd.idPlayer AND gd.steals >= 5 AND gd.startposition = 'C'; -- QUERY PLAN -- ------------------------------------------------------------------------------------------------------------------------------------- -- Gather (cost=1000.28..17684.64 rows=201 width=19) (actual time=1.410..80.509 rows=137 loops=1) -- Workers Planned: 2 -- Workers Launched: 2 -- -> Nested Loop (cost=0.28..16664.54 rows=84 width=19) (actual time=2.226..64.468 rows=46 loops=3) -- -> Parallel Seq Scan on gamedetail gd (cost=0.00..16589.40 rows=84 width=6) (actual time=2.122..64.080 rows=46 loops=3) -- Filter: ((steals >= '5'::numeric) AND (startposition = 'C'::bpchar)) -- Rows Removed by Filter: 215176 -- -> Index Scan using player_pkey on player p (cost=0.28..0.89 rows=1 width=19) (actual time=0.007..0.007 rows=1 loops=137) -- Index Cond: ((id)::text = (gd.idplayer)::text) -- Planning Time: 0.988 ms -- Execution Time: 81.023 ms -- (11 rows) --? 9 - Comment améliorer les performances de cette requête ? Tester et comparer. CREATE INDEX idx3 ON GameDetail(startposition, steals); EXPLAIN ANALYZE SELECT p.id, p.name FROM Player p, GameDetail gd WHERE p.id = gd.idPlayer AND gd.steals >= 5 AND gd.startposition = 'C'; -- QUERY PLAN -- --------------------------------------------------------------------------------------------------------------------------- -- Hash Join (cost=82.42..810.23 rows=201 width=19) (actual time=5.164..6.532 rows=137 loops=1) -- Hash Cond: ((gd.idplayer)::text = (p.id)::text) -- -> Bitmap Heap Scan on gamedetail gd (cost=6.49..733.77 rows=201 width=6) (actual time=0.648..1.910 rows=137 loops=1) -- Recheck Cond: ((startposition = 'C'::bpchar) AND (steals >= '5'::numeric)) -- Heap Blocks: exact=135 -- -> Bitmap Index Scan on idx3 (cost=0.00..6.43 rows=201 width=0) (actual time=0.567..0.568 rows=137 loops=1) -- Index Cond: ((startposition = 'C'::bpchar) AND (steals >= '5'::numeric)) -- -> Hash (cost=43.75..43.75 rows=2575 width=19) (actual time=4.471..4.471 rows=2575 loops=1) -- Buckets: 4096 Batches: 1 Memory Usage: 165kB -- -> Seq Scan on player p (cost=0.00..43.75 rows=2575 width=19) (actual time=0.027..2.996 rows=2575 loops=1) -- Planning Time: 1.538 ms -- Execution Time: 6.690 ms -- (12 rows) --? 10 - Supprimer tout les index précédents. --? Pour s'aider : commande \di qui affiche tous les index de votre base. --? (Remarquez qu’il existe plusieurs index dont le nom se termine par _pkey. --? Ce sont des index créés automatiquement sur les clés primaires des tables. --? Inutile de les supprimer.) \di DROP INDEX idx; DROP INDEX idx2; DROP INDEX idx3; \di --? 11 - Les deux requêtes ci-dessous calculent la même chose. Que font-elles? SELECT t.nickname, t.city, count(*) FROM Team t, Game g WHERE (t.id = g.idHomeTeam AND g.homeTeamWins) OR (t.id = g.idVisitorTeam AND NOT g.homeTeamWins) GROUP BY t.nickname , t.city ORDER BY 3 DESC; -- * Celle ci affiche le surnom, la ville de l'équipe ainsi que le nombre de match victorieux au total (exterieur ou non) -- * De la table game et team puis koin la team soit en equipe maison ou externe au terrain (si maison, alors victorieuse (impossible en exterieur)) -- * Enfin, on ordonne le tout par nombre de match gagné -- nickname | city | count -- ---------------+---------------+------- -- Spurs | San Antonio | 1166 -- Heat | Miami | 1037 -- Celtics | Boston | 1011 -- Mavericks | Dallas | 1002 -- Warriors | Golden State | 982 -- Rockets | Houston | 982 -- Nuggets | Denver | 968 -- Lakers | Los Angeles | 929 -- Jazz | Utah | 925 -- Thunder | Oklahoma City | 911 -- Pacers | Indiana | 905 -- Cavaliers | Cleveland | 899 -- Clippers | Los Angeles | 892 -- Raptors | Toronto | 884 -- Suns | Phoenix | 881 -- Bulls | Chicago | 866 -- Trail Blazers | Portland | 850 -- Grizzlies | Memphis | 850 -- Pistons | Detroit | 835 -- Bucks | Milwaukee | 816 -- Hawks | Atlanta | 804 -- Magic | Orlando | 761 -- 76ers | Philadelphia | 760 -- Pelicans | New Orleans | 759 -- Nets | Brooklyn | 750 -- Wizards | Washington | 736 -- Kings | Sacramento | 674 -- Knicks | New York | 657 -- Timberwolves | Minnesota | 654 -- Hornets | Charlotte | 621 -- (30 rows) SELECT t.nickname, t.city, hw.nb+vw.nb FROM Team t, (SELECT t.id, count(*) nb FROM Team t, Game g WHERE t.id = g.idHomeTeam AND g.homeTeamWins GROUP BY t.id) hw, (SELECT t.id, count(*) nb FROM Team t, Game g WHERE t.id = g.idVisitorTeam AND NOT g.homeTeamWins GROUP BY t.id) vw WHERE t.id = hw.id AND t.id = vw.id ORDER BY 3 DESC; -- * Pour celle ci, on affiche le surnom, la ville de l'équipe ainsi que son nombre de win maison + son nombre de win exterieur -- * Depuis la table team et deux autres tables qui contiennent le nombre de win hom et le nombre de win exterieur -- * On join la team à ses deux win -- * Puis on le trie par nombre de win total. -- nickname | city | ?column? -- ---------------+---------------+---------- -- Spurs | San Antonio | 1166 -- Heat | Miami | 1037 -- Celtics | Boston | 1011 -- Mavericks | Dallas | 1002 -- Rockets | Houston | 982 -- Warriors | Golden State | 982 -- Nuggets | Denver | 968 -- Lakers | Los Angeles | 929 -- Jazz | Utah | 925 -- Thunder | Oklahoma City | 911 -- Pacers | Indiana | 905 -- Cavaliers | Cleveland | 899 -- Clippers | Los Angeles | 892 -- Raptors | Toronto | 884 -- Suns | Phoenix | 881 -- Bulls | Chicago | 866 -- Trail Blazers | Portland | 850 -- Grizzlies | Memphis | 850 -- Pistons | Detroit | 835 -- Bucks | Milwaukee | 816 -- Hawks | Atlanta | 804 -- Magic | Orlando | 761 -- 76ers | Philadelphia | 760 -- Pelicans | New Orleans | 759 -- Nets | Brooklyn | 750 -- Wizards | Washington | 736 -- Kings | Sacramento | 674 -- Knicks | New York | 657 -- Timberwolves | Minnesota | 654 -- Hornets | Charlotte | 621 -- (30 rows) --? 12 - Sans les exécuter, laquelle de ces deux requêtes est la plus rapide selon vous ? Justifier. -- * Selon moi, Je pense que la deuxième est meilleur car d'une part elle n'as pas de GROUP BY, ce qui devrait etre moins gourmand. -- * D'autre part, elle calcule séparement le home du away ce qui, je pense, en indexant devrait etre plus rapide. --? 13 - Vérifier votre réponse en affichant le temps d’exécution de chaque requête. EXPLAIN ANALYZE SELECT t.nickname, t.city, count(*) FROM Team t, Game g WHERE (t.id = g.idHomeTeam AND g.homeTeamWins) OR (t.id = g.idVisitorTeam AND NOT g.homeTeamWins) GROUP BY t.nickname , t.city ORDER BY 3 DESC; -- QUERY PLAN -- ---------------------------------------------------------------------------------------------------------------------------------------------------------------- -- Sort (cost=65828.12..65828.60 rows=190 width=164) (actual time=159.839..159.842 rows=30 loops=1) -- Sort Key: (count(*)) DESC -- Sort Method: quicksort Memory: 27kB -- -> HashAggregate (cost=65819.03..65820.93 rows=190 width=164) (actual time=159.815..159.820 rows=30 loops=1) -- Group Key: t.nickname, t.city -- Batches: 1 Memory Usage: 40kB -- -> Nested Loop (cost=0.00..65626.02 rows=25735 width=156) (actual time=0.072..152.901 rows=25767 loops=1) -- Join Filter: ((((t.id)::text = (g.idhometeam)::text) AND g.hometeamwins) OR (((t.id)::text = (g.idvisitorteam)::text) AND (NOT g.hometeamwins))) -- Rows Removed by Join Filter: 747243 -- -> Seq Scan on game g (cost=0.00..699.67 rows=19523 width=23) (actual time=0.026..5.395 rows=25767 loops=1) -- Filter: (hometeamwins OR (NOT hometeamwins)) -- -> Materialize (cost=0.00..12.85 rows=190 width=194) (actual time=0.000..0.001 rows=30 loops=25767) -- -> Seq Scan on team t (cost=0.00..11.90 rows=190 width=194) (actual time=0.008..0.016 rows=30 loops=1) -- Planning Time: 0.486 ms -- Execution Time: 159.978 ms -- (15 rows) -- * Pour cette premiere question, cela bloque bien à l'endroit que je pensais -- * En indexant, on devrait surement avoir de meilleures résultats. EXPLAIN ANALYZE SELECT t.nickname, t.city, hw.nb+vw.nb FROM Team t, (SELECT t.id, count(*) nb FROM Team t, Game g WHERE t.id = g.idHomeTeam AND g.homeTeamWins GROUP BY t.id) hw, (SELECT t.id, count(*) nb FROM Team t, Game g WHERE t.id = g.idVisitorTeam AND NOT g.homeTeamWins GROUP BY t.id) vw WHERE t.id = hw.id AND t.id = vw.id ORDER BY 3 DESC; -- QUERY PLAN -- ------------------------------------------------------------------------------------------------------------------------------------------------------- -- Sort (cost=1658.81..1659.29 rows=190 width=164) (actual time=34.733..34.742 rows=30 loops=1) -- Sort Key: ((hw.nb + vw.nb)) DESC -- Sort Method: quicksort Memory: 27kB -- -> Hash Join (cost=1638.23..1651.62 rows=190 width=164) (actual time=34.660..34.698 rows=30 loops=1) -- Hash Cond: ((t.id)::text = (vw.id)::text) -- -> Hash Join (cost=836.44..848.85 rows=190 width=240) (actual time=19.458..19.477 rows=30 loops=1) -- Hash Cond: ((t.id)::text = (hw.id)::text) -- -> Seq Scan on team t (cost=0.00..11.90 rows=190 width=194) (actual time=0.030..0.034 rows=30 loops=1) -- -> Hash (cost=834.06..834.06 rows=190 width=46) (actual time=19.374..19.376 rows=30 loops=1) -- Buckets: 1024 Batches: 1 Memory Usage: 10kB -- -> Subquery Scan on hw (cost=830.26..834.06 rows=190 width=46) (actual time=19.302..19.317 rows=30 loops=1) -- -> HashAggregate (cost=830.26..832.16 rows=190 width=46) (actual time=19.300..19.308 rows=30 loops=1) -- Group Key: t_1.id -- Batches: 1 Memory Usage: 40kB -- -> Hash Join (cost=14.28..754.57 rows=15138 width=38) (actual time=0.048..13.843 rows=15138 loops=1) -- Hash Cond: ((g.idhometeam)::text = (t_1.id)::text) -- -> Seq Scan on game g (cost=0.00..699.67 rows=15138 width=11) (actual time=0.009..7.778 rows=15138 loops=1) -- Filter: hometeamwins -- Rows Removed by Filter: 10629 -- -> Hash (cost=11.90..11.90 rows=190 width=38) (actual time=0.024..0.025 rows=30 loops=1) -- Buckets: 1024 Batches: 1 Memory Usage: 10kB -- -> Seq Scan on team t_1 (cost=0.00..11.90 rows=190 width=38) (actual time=0.004..0.010 rows=30 loops=1) -- -> Hash (cost=799.41..799.41 rows=190 width=46) (actual time=15.177..15.180 rows=30 loops=1) -- Buckets: 1024 Batches: 1 Memory Usage: 10kB -- -> Subquery Scan on vw (cost=795.61..799.41 rows=190 width=46) (actual time=15.132..15.148 rows=30 loops=1) -- -> HashAggregate (cost=795.61..797.51 rows=190 width=46) (actual time=15.128..15.139 rows=30 loops=1) -- Group Key: t_2.id -- Batches: 1 Memory Usage: 40kB -- -> Hash Join (cost=14.28..742.47 rows=10629 width=38) (actual time=0.110..11.306 rows=10629 loops=1) -- Hash Cond: ((g_1.idvisitorteam)::text = (t_2.id)::text) -- -> Seq Scan on game g_1 (cost=0.00..699.67 rows=10629 width=11) (actual time=0.037..7.024 rows=10629 loops=1) -- Filter: (NOT hometeamwins) -- Rows Removed by Filter: 15138 -- -> Hash (cost=11.90..11.90 rows=190 width=38) (actual time=0.044..0.045 rows=30 loops=1) -- Buckets: 1024 Batches: 1 Memory Usage: 10kB -- -> Seq Scan on team t_2 (cost=0.00..11.90 rows=190 width=38) (actual time=0.012..0.020 rows=30 loops=1) -- Planning Time: 0.826 ms -- Execution Time: 35.012 ms -- (38 rows) -- * La différence est choquante, je ne m'attendais pas à ca mais je n'étais pas du tout sur la bonne raison. -- * On dirait que c'est grace à la jointure des id que l'on gagne bcp de temps car comme on l'a vu précédemment, -- * les PK sont déjà indéxé de base ce qui améliore l'éxécution de bcp. Mais ce point serait bien à revoir pour moi. --? 14 - Lister les joueurs ayant marqué plus de 40 points dans un match, avec le nombre de matchs --? pour lesquels le joueur a réussi cette performance. SELECT p.id, p.name, count(*) FROM Player p, GameDetail gd WHERE p.id = gd.idPlayer AND gd.points >= 40 GROUP BY p.id, p.name ORDER BY 3 DESC; -- * Meme structure que la première donc devrait etre moins opti -- id | name | count -- ---------+-------------------------+------- -- 201935 | James Harden | 112 -- 977 | Kobe Bryant | 106 -- 2544 | LeBron James | 97 -- 201142 | Kevin Durant | 73 -- 201939 | Stephen Curry | 64 -- 201566 | Russell Westbrook | 57 -- 203081 | Damian Lillard | 44 -- 2546 | Carmelo Anthony | 41 -- 2548 | Dwyane Wade | 41 -- 203076 | Anthony Davis | 38 -- 947 | Allen Iverson | 32 -- 203507 | Giannis Antetokounmpo | 32 -- 203078 | Bradley Beal | 30 -- 2240 | Gilbert Arenas | 29 -- 202681 | Kyrie Irving | 27 -- 203954 | Joel Embiid | 24 -- 1503 | Tracy McGrady | 24 -- 1629027 | Trae Young | 23 -- 2405 | Amar'e Stoudemire | 22 -- 1717 | Dirk Nowitzki | 22 -- 1713 | Vince Carter | 22 -- 1626164 | Devin Booker | 20 -- 1629029 | Luka Doncic | 20 -- 202331 | Paul George | 19 -- 202689 | Kemba Walker | 19 -- 201942 | DeMar DeRozan | 16 -- 203897 | Zach LaVine | 15 -- 202691 | Klay Thompson | 14 -- 1628369 | Jayson Tatum | 14 -- 1628378 | Donovan Mitchell | 13 -- 202326 | DeMarcus Cousins | 13 -- 203999 | Nikola Jokic | 12 -- 2072 | Michael Redd | 12 -- 101108 | Chris Paul | 11 -- 200746 | LaMarcus Aldridge | 11 -- 201933 | Blake Griffin | 11 -- 201567 | Kevin Love | 11 -- 2547 | Chris Bosh | 10 -- 203468 | CJ McCollum | 10 -- 101145 | Monta Ellis | 10 -- 202695 | Kawhi Leonard | 10 -- 1626157 | Karl-Anthony Towns | 10 -- 202710 | Jimmy Butler | 10 -- 2037 | Jamal Crawford | 9 --? 15 - Quel index pourrait permettre d’améliorer le temps d’exécution de la requête ? Justifier votre réponse. EXPLAIN ANALYZE SELECT p.id, p.name, count(*) FROM Player p, GameDetail gd WHERE p.id = gd.idPlayer AND gd.points >= 40 GROUP BY p.id, p.name ORDER BY 3 DESC; -- QUERY PLAN -- -------------------------------------------------------------------------------------------------------------------------------------------------------------- -- Sort (cost=17293.10..17297.02 rows=1570 width=27) (actual time=166.819..168.162 rows=196 loops=1) -- Sort Key: (count(*)) DESC -- Sort Method: quicksort Memory: 40kB -- -> Finalize GroupAggregate (cost=17025.10..17209.76 rows=1570 width=27) (actual time=166.127..168.110 rows=196 loops=1) -- Group Key: p.id -- -> Gather Merge (cost=17025.10..17187.52 rows=1308 width=27) (actual time=166.117..168.026 rows=376 loops=1) -- Workers Planned: 2 -- Workers Launched: 2 -- -> Partial GroupAggregate (cost=16025.07..16036.52 rows=654 width=27) (actual time=152.688..152.792 rows=125 loops=3) -- Group Key: p.id -- -> Sort (cost=16025.07..16026.71 rows=654 width=19) (actual time=152.674..152.698 rows=546 loops=3) -- Sort Key: p.id -- Sort Method: quicksort Memory: 71kB -- Worker 0: Sort Method: quicksort Memory: 61kB -- Worker 1: Sort Method: quicksort Memory: 64kB -- -> Hash Join (cost=75.94..15994.49 rows=654 width=19) (actual time=2.969..152.075 rows=546 loops=3) -- Hash Cond: ((gd.idplayer)::text = (p.id)::text) -- -> Parallel Seq Scan on gamedetail gd (cost=0.00..15916.83 rows=654 width=6) (actual time=1.040..149.731 rows=546 loops=3) -- Filter: (points >= '40'::numeric) -- Rows Removed by Filter: 214675 -- -> Hash (cost=43.75..43.75 rows=2575 width=19) (actual time=1.770..1.771 rows=2575 loops=3) -- Buckets: 4096 Batches: 1 Memory Usage: 165kB -- -> Seq Scan on player p (cost=0.00..43.75 rows=2575 width=19) (actual time=0.051..0.730 rows=2575 loops=3) -- Planning Time: 1.028 ms -- Execution Time: 168.314 ms -- (25 rows) -- ! DONC : CREATE INDEX idx ON GameDetail(points); -- QUERY PLAN -- -------------------------------------------------------------------------------------------------------------------------------------------- -- Sort (cost=4622.02..4625.93 rows=1566 width=27) (actual time=17.991..18.038 rows=196 loops=1) -- Sort Key: (count(*)) DESC -- Sort Method: quicksort Memory: 40kB -- -> HashAggregate (cost=4523.26..4538.92 rows=1566 width=27) (actual time=17.787..17.860 rows=196 loops=1) -- Group Key: p.id -- Batches: 1 Memory Usage: 97kB -- -> Hash Join (cost=108.50..4515.43 rows=1566 width=19) (actual time=2.438..16.954 rows=1639 loops=1) -- Hash Cond: ((gd.idplayer)::text = (p.id)::text) -- -> Bitmap Heap Scan on gamedetail gd (cost=32.56..4435.37 rows=1566 width=6) (actual time=0.956..14.274 rows=1639 loops=1) -- Recheck Cond: (points >= '40'::numeric) -- Heap Blocks: exact=1504 -- -> Bitmap Index Scan on idx (cost=0.00..32.17 rows=1566 width=0) (actual time=0.633..0.634 rows=1639 loops=1) -- Index Cond: (points >= '40'::numeric) -- -> Hash (cost=43.75..43.75 rows=2575 width=19) (actual time=1.456..1.458 rows=2575 loops=1) -- Buckets: 4096 Batches: 1 Memory Usage: 165kB -- -> Seq Scan on player p (cost=0.00..43.75 rows=2575 width=19) (actual time=0.022..0.606 rows=2575 loops=1) -- Planning Time: 2.630 ms -- Execution Time: 18.270 ms -- (18 rows) --? 16 - Lister les joueurs ayant réalisé un total d’assists et de vols supérieur à 22 pendant un match. SELECT p.id, p.name, assists, blockedShots FROM Player p, GameDetail gd WHERE p.id = gd.idPlayer AND assists > 22 AND blockedShots > 22; -- id | name | assists | blockedshots -- ----+------+---------+-------------- -- (0 rows) -- ! Ou ??? : SELECT p.id, p.name, assists, blockedShots FROM Player p, GameDetail gd WHERE p.id = gd.idPlayer AND (assists + blockedShots) > 22; -- id | name | assists | blockedshots -- --------+-------------------+---------+-------------- -- 201566 | Russell Westbrook | 24 | 1 -- 201196 | Ramon Sessions | 24 | 1 -- 959 | Steve Nash | 23 | 1 -- 200765 | Rajon Rondo | 23 | 1 -- 200765 | Rajon Rondo | 24 | 0 -- 201566 | Russell Westbrook | 24 | 0 -- 200765 | Rajon Rondo | 25 | 0 -- 201566 | Russell Westbrook | 22 | 1 -- (8 rows) --? 17 - Quel index pourrait permettre d’améliorer le temps d’exécution de la requête ? Justifier votre --? réponse. EXPLAIN ANALYZE SELECT p.id, p.name, gd.assists, gd.blockedShots FROM Player p, GameDetail gd WHERE p.id = gd.idPlayer AND (gd.assists + gd.blockedShots) > 22; -- QUERY PLAN -- -------------------------------------------------------------------------------------------------------------------------- -- Hash Join (cost=75.94..22880.79 rows=215221 width=26) (actual time=19.979..161.473 rows=8 loops=1) -- Hash Cond: ((gd.idplayer)::text = (p.id)::text) -- -> Seq Scan on gamedetail gd (cost=0.00..22238.96 rows=215221 width=13) (actual time=18.738..160.218 rows=8 loops=1) -- Filter: ((assists + blockedshots) > '22'::numeric) -- Rows Removed by Filter: 645656 -- -> Hash (cost=43.75..43.75 rows=2575 width=19) (actual time=1.201..1.202 rows=2575 loops=1) -- Buckets: 4096 Batches: 1 Memory Usage: 165kB -- -> Seq Scan on player p (cost=0.00..43.75 rows=2575 width=19) (actual time=0.023..0.512 rows=2575 loops=1) -- Planning Time: 1.002 ms -- Execution Time: 161.535 ms -- (10 rows) --! CREATE INDEX idx2 ON GameDetail(assists, blockedshots); PAS OK -- * JSP la