From d17a4c7bf653db62761deb9119c29530e9386ad6 Mon Sep 17 00:00:00 2001 From: Joel Cavat <jcavat@gmail.com> Date: Tue, 3 May 2022 19:39:12 +0200 Subject: [PATCH] Corr. chapt. 5 --- corrections/chapitre_05/conf.sql | 140 +++++++++++++++++++++++++++++++ 1 file changed, 140 insertions(+) diff --git a/corrections/chapitre_05/conf.sql b/corrections/chapitre_05/conf.sql index 66b5d35..5100ed9 100644 --- a/corrections/chapitre_05/conf.sql +++ b/corrections/chapitre_05/conf.sql @@ -120,3 +120,143 @@ SELECT C.name, start_date, end_date, WHERE C.id_conference = P.id_conference ) AS Speakers FROM Conference AS C; + +-- 15 +SELECT name, SUM(fees) AS total +FROM Conference AS C +LEFT JOIN Participation AS P ON C.id_conference = P.id_conference +GROUP BY C.id_conference +ORDER BY total DESC; + +-- 16 +SELECT T.title, SUM(IFNULL(fees,0)) AS S +FROM Topic AS T LEFT JOIN Conference AS C ON T.title = C.title +LEFT JOIN Participation AS P ON C.id_conference = P.id_conference +GROUP BY T.title +HAVING S < 20000; + +-- 17 +SELECT S.login, firstname, lastname, COUNT(id_conference) +FROM Speaker AS S +LEFT JOIN Participation AS P ON S.login = P.login +GROUP BY S.login; + +-- 18 +SELECT login, firstname, lastname +FROM Speaker +WHERE NOT EXISTS ( + SELECT * + FROM Participation + WHERE Participation.login = Speaker.login +); + +SELECT login, firstname, lastname +FROM Speaker +WHERE login NOT IN ( + SELECT login + FROM Participation +); + +SELECT Speaker.login, firstname, lastname +FROM Speaker +LEFT JOIN Participation ON Speaker.login = Participation.login +WHERE Participation.login IS NULL; + +SELECT Speaker.login, firstname, lastname +FROM Speaker +LEFT JOIN Participation ON Speaker.login = Participation.login +GROUP BY Speaker.login +HAVING COUNT(Participation.id_conference) = 0; + +-- 19 +SELECT DISTINCT T.title +FROM Topic AS T +INNER JOIN Conference AS C ON C.title = T.title +INNER JOIN Participation AS P ON C.id_conference = P.id_conference +WHERE login LIKE "stregunna14"; + +-- 20 +SELECT S.login, firstname, lastname, fees +FROM Speaker AS S +INNER JOIN Participation AS P ON S.login = P.login +WHERE fees = ( + SELECT MAX(fees) FROM Participation +); + +-- 21 +SELECT S.login, firstname, lastname, SUM(fees) AS F +FROM Speaker AS S +INNER JOIN Participation AS P ON S.login = P.login +GROUP BY S.login +HAVING F = ( + SELECT MAX(S) FROM ( + SELECT SUM(fees) AS S FROM Participation GROUP BY login + ) AS G +); + +WITH GBY (login, firstname, lastname, sum) AS ( + SELECT S.login, firstname, lastname, SUM(fees) AS F + FROM Speaker AS S + INNER JOIN Participation AS P ON S.login = P.login + GROUP BY S.login +) +SELECT login, firstname, lastname, sum +FROM GBY +WHERE sum = (SELECT MAX(sum) FROM GBY); + + +-- 22 +SELECT COUNT(DISTINCT login) +FROM Participation +INNER JOIN Conference USING (id_conference) +WHERE strftime("%Y", start_date) = "2019"; + + + + + +-- 23 +SELECT * +FROM Visitor +WHERE login NOT IN ( + SELECT Visitor.login + FROM Visitor + INNER JOIN Registration USING (login) + INNER JOIN Conference USING (id_conference) + WHERE strftime("%Y", start_date) = "2019" +); + +-- 24 +SELECT substr(A.lastname,1,2) AS SUB, A.firstname, A.lastname, B.firstname, B.lastname +FROM Visitor AS A +INNER JOIN Visitor AS B ON substr(A.lastname,1,2) = substr(B.lastname,1,2) +WHERE A.login > B.login +ORDER BY SUB; + + + + + +-- COMMANDES + +-- 1 +INSERT INTO Visitor VALUES ('toto21', 'Di', 'Dju'); + +-- 2 +INSERT INTO Fidelity VALUES ('toto21', 50); + +-- 3 +INSERT INTO Registration +SELECT 'toto21', id_conference +FROM Conference +WHERE name = 'CurryOn'; + +-- 4 +UPDATE Fidelity +SET loyalty_points = loyalty_points * 2; + +-- 5 +INSERT INTO Fidelity +SELECT login, 50 +FROM Visitor +WHERE login NOT IN (SELECT login FROM Fidelity); \ No newline at end of file -- GitLab