You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

269 lines
9.0 KiB

This file contains ambiguous Unicode characters!

This file contains ambiguous Unicode characters that may be confused with others in your current locale. If your use case is intentional and legitimate, you can safely ignore this warning. Use the Escape button to highlight these characters.

/*
=> TP 2, Fréville Clément G8
*/
-- 1. Nombre dathlètes par pays.
SELECT p.nom pays, COUNT(*) athletes FROM athlete a
INNER JOIN pays p ON p.code = a.pays
GROUP BY p.code;
/*
pays | athletes
----------------------------------+----------
Ethiopia | 37
Kuwait | 10
Denmark | 108
Nauru | 2
Netherlands | 283
Palau | 3
Samoa (until 1996 Western Samoa) | 8
United Arab Emirates | 5
[...]
*/
-- 2. Nombre dépreuves par discipline.
SELECT d.nom discipline, COUNT(*) nombre_epreuves FROM epreuve e
INNER JOIN discipline d ON d.code = e.discipl
GROUP BY d.code;
/*
discipline | nombre_epreuves
-----------------------+-----------------
Equestrian | 6
Taekwondo | 8
Hockey | 2
Volleyball | 2
Sport Climbing | 2
Skateboarding | 4
Handball | 2
Baseball/Softball | 2
Diving | 8
[...]
*/
-- 3. Date de la dernière épreuve de chaque discipline.
SELECT d.nom, to_char(MAX(e.dateE), 'dd/mm/YYYY') derniere_epreuve FROM epreuve e
INNER JOIN discipline d ON d.code = e.discipl
GROUP BY d.code;
/*
nom | derniere_epreuve
-----------------------+------------------
Equestrian | 07/08/2021
Taekwondo | 27/07/2021
Hockey | 06/08/2021
Volleyball | 08/08/2021
Sport Climbing | 06/08/2021
Skateboarding | 05/08/2021
Handball | 08/08/2021
Baseball/Softball | 07/08/2021
[...]
*/
-- 4. Date de naissance du plus jeune athlète par discipline et par sexe.
SELECT d.nom discipline, a.sexe, MAX(a.dateNaiss) date_naissance_plus_jeune FROM athlete a
INNER JOIN pratiquer p ON p.athlete = a.code
INNER JOIN discipline d ON p.discipl = d.code
WHERE a.dateNaiss IS NOT NULL
GROUP BY d.code, a.sexe;
/*
discipline | sexe | date_naissance_plus_jeune
-----------------------+------+---------------------------
Basketball | M | 2002-03-09
Water Polo | F | 2004-10-29
Water Polo | M | 2003-06-02
Athletics | M | 2004-01-29
Rhythmic Gymnastics | F | 2004-11-29
Equestrian | F | 1998-08-19
Modern Pentathlon | M | 2000-03-01
Triathlon | M | 1999-10-07
Hockey | M | 2002-03-19
Football | M | 2003-07-24
Swimming | M | 2005-07-19
[...]
*/
-- 5. Nombre total de médailles par pays, les pays ayant remporté le plus de médailles en premier.
SELECT p.nom pays, COUNT(*) medailles_remportees FROM resultat r
INNER JOIN athlete a ON a.code = r.athlete
INNER JOIN pays p ON p.code = a.pays
GROUP BY p.code
ORDER BY medailles_remportees DESC;
/*
pays | medailles_remportees
----------------------------+----------------------
United States of America | 295
ROC | 147
People's Republic of China | 140
France | 137
Japan | 131
Great Britain | 130
Australia | 129
Canada | 82
[...]
*/
-- 6. Nombre de médailles dor par pays, les pays ayant remporté le plus de médailles en premier.
SELECT p.nom pays, COUNT(*) medailles_or_remportees FROM resultat r
INNER JOIN athlete a ON a.code = r.athlete
INNER JOIN pays p ON p.code = a.pays
WHERE r.medaille = 1
GROUP BY p.code, r.medaille
ORDER BY medailles_or_remportees DESC;
/*
pays | medailles_or_remportees
----------------------------+-------------------------
United States of America | 112
Japan | 68
France | 65
People's Republic of China | 58
ROC | 40
Great Britain | 39
Australia | 36
Canada | 36
Netherlands | 31
Brazil | 29
[...]
*/
-- 7. Même question, mais uniquement les pays ayant remporté plus de 30 médailles dor
SELECT p.nom, COUNT(*) medailles_or_remportees FROM resultat r
INNER JOIN athlete a ON a.code = r.athlete
INNER JOIN pays p ON p.code = a.pays
WHERE r.medaille = 1
GROUP BY p.nom, r.medaille
HAVING COUNT(*) >= 30
ORDER BY medailles_or_remportees DESC;
/*
nom | medailles_or_remportees
----------------------------+-------------------------
United States of America | 112
Japan | 68
France | 65
People's Republic of China | 58
ROC | 40
Great Britain | 39
Australia | 36
Canada | 36
Netherlands | 31
*/
-- 8. Athlètes (code, nom, prénom, code du pays) pratiquant plusieurs disciplines.
SELECT a.code, a.nom, a.prenom, a.pays
FROM pratiquer p
INNER JOIN athlete a ON a.code = p.athlete
GROUP BY a.code, a.nom, a.prenom, a.pays
HAVING COUNT(*) > 1;
/*
code | nom | prenom | pays
--------+----------------+------------+------
A05315 | KOPECKY | Lotte | BEL
A01327 | BRENNAUER | Lisa | GER
A07786 | PALTRINIERI | Gregorio | ITA
A05148 | KIRPICHNIKOVA | Anastasiia | ROC
A02686 | DYGERT | Chloe | USA
A10627 | VAN ROUWENDAAL | Sharon | NED
A00622 | AUBRY | David | FRA
A05189 | KLEIN | Lisa | GER
A03293 | GANNA | Filippo | ITA
A11041 | WELLBROCK | Florian | GER
A03991 | HAVIK | Yoeri | NED
*/
-- 9. Athlètes (code, nom, prénom, code du pays) ayant remporté quatre médailles.
SELECT a.code, a.nom, a.prenom, a.pays
FROM resultat r
INNER JOIN athlete a ON a.code = r.athlete
GROUP BY a.code
HAVING COUNT(*) = 4;
/*
code | nom | prenom | pays
--------+---------+----------+------
A11582 | ZHANG | Yufei | CHN
A09215 | SCOTT | Duncan | GBR
A10225 | TITMUS | Ariarne | AUS
A06581 | McKEOWN | Kaylee | AUS
A05668 | LEDECKY | Kathleen | USA
*/
-- 10. Nombre dathlètes mineurs au début des Jeux Olympiques (le 23 juillet 2021) par discipline,uniquement pour les disciplines ayant au moins trois athlètes mineurs.
SELECT d.nom discipline, COUNT(*) athletes_mineurs
FROM pratiquer p
INNER JOIN athlete a ON a.code = p.athlete
INNER JOIN discipline d ON d.code = p.discipl
WHERE (('2021-07-23'-dateNaiss) / 365.2422) < 18
GROUP BY d.code
HAVING COUNT(*) > 2;
/*
discipline | athletes_mineurs
---------------------+------------------
Diving | 10
Skateboarding | 18
Artistic Swimming | 3
Athletics | 6
Artistic Gymnastics | 15
Table Tennis | 3
Swimming | 72
Rhythmic Gymnastics | 8
Shooting | 3
Sailing | 5
Archery | 4
*/
-- 11. Pays ayant le plus dathlètes.
SELECT pays, COUNT(*) athletes
FROM athlete a
GROUP BY a.pays
ORDER BY athletes DESC
LIMIT 1;
/*
pays | athletes
------+----------
USA | 633
*/
-- 11. (Variante) Pays ayant le plus dathlètes.
SELECT pays, COUNT(*) athletes
FROM athlete a
GROUP BY a.pays
HAVING COUNT(*) = (
SELECT MAX(c) FROM (
SELECT COUNT(*) c
FROM athlete
GROUP BY pays
) n_athletes
);
/*
pays | athletes
------+----------
USA | 633
*/
-- 12. Athlète (nom, prénom, code pays) ayant remporté le plus de médailles.
SELECT a.nom, a.prenom, a.pays, COUNT(*) medailles_remportees FROM resultat r
INNER JOIN athlete a ON a.code = r.athlete
GROUP BY a.code
ORDER BY medailles_remportees DESC
LIMIT 1;
/*
nom | prenom | pays | medailles_remportees
--------+--------+------+----------------------
McKEON | Emma | AUS | 7
*/
-- 12. (Variante) Athlète (nom, prénom, code pays) ayant remporté le plus de médailles.
SELECT a.nom, a.prenom, a.pays, COUNT(*) medailles_remportees
FROM resultat r
INNER JOIN athlete a ON a.code = r.athlete
GROUP BY a.code
HAVING COUNT(*) = (
SELECT MAX(c) FROM (
SELECT COUNT(*) c
FROM resultat
GROUP BY athlete
) n_resultats
);
/*
nom | prenom | pays | medailles_remportees
--------+--------+------+----------------------
McKEON | Emma | AUS | 7
*/