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.
316 lines
7.1 KiB
316 lines
7.1 KiB
-- 2
|
|
DO $$
|
|
DECLARE
|
|
a INT := 0;
|
|
b INT := 1;
|
|
c INT := 1;
|
|
n INT := 7;
|
|
BEGIN
|
|
for i in 2..n loop
|
|
c = a + b;
|
|
a = b;
|
|
b = c;
|
|
end loop;
|
|
raise notice '%', c;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- 3
|
|
CREATE OR REPLACE FUNCTION fibonacci(n INT)
|
|
RETURNS INT AS $$
|
|
DECLARE
|
|
a INT := 0;
|
|
b INT := 1;
|
|
c INT := 1;
|
|
BEGIN
|
|
if n = 0 then
|
|
return 0;
|
|
end if;
|
|
for i in 2..n loop
|
|
c = a + b;
|
|
a = b;
|
|
b = c;
|
|
end loop;
|
|
return c;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- 4
|
|
SELECT fibonacci(0); -- 0
|
|
SELECT fibonacci(1); -- 1
|
|
SELECT fibonacci(2); -- 1
|
|
SELECT fibonacci(10); -- 55
|
|
|
|
-- 5
|
|
--DROP FUNCTION IF EXISTS nb_athletes;
|
|
CREATE OR REPLACE FUNCTION nb_athletes(code_pays pays.code%TYPE)
|
|
RETURNS INT AS $$
|
|
BEGIN
|
|
return (
|
|
SELECT COUNT(*)
|
|
FROM athlete
|
|
WHERE pays = code_pays
|
|
);
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- 6
|
|
SELECT nb_athletes('FRA');
|
|
|
|
-- 7
|
|
SELECT p.code, p.nom
|
|
FROM athlete a
|
|
INNER JOIN pays p ON p.code = a.pays
|
|
GROUP BY p.code
|
|
HAVING COUNT(*) > nb_athletes('FRA');
|
|
|
|
-- 8
|
|
CREATE OR REPLACE FUNCTION epr(nom_discipline discipline.nom%TYPE, date DATE)
|
|
RETURNS TABLE (code epreuve.code%TYPE, nom epreuve.nom%TYPE) AS $$
|
|
BEGIN
|
|
return query
|
|
SELECT e.code, e.nom
|
|
FROM epreuve e
|
|
WHERE e.discipl = (
|
|
SELECT d.code FROM discipline d WHERE d.nom = nom_discipline
|
|
) AND dateE = date;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- 9
|
|
SELECT epr('Athletics', '2021-08-03');
|
|
|
|
-- 10
|
|
UPDATE epreuve SET dateE = dateE+1 WHERE code IN (SELECT code FROM epr('Equestrian', '2021-08-02'));
|
|
|
|
-- 11
|
|
CREATE OR REPLACE FUNCTION pratique(code_athlete athlete.code%TYPE)
|
|
RETURNS discipline.nom%TYPE AS $$
|
|
DECLARE
|
|
res discipline.nom%TYPE;
|
|
BEGIN
|
|
SELECT d.nom INTO STRICT res FROM pratiquer p
|
|
INNER JOIN discipline d ON d.code = p.discipl
|
|
WHERE p.athlete = code_athlete;
|
|
return res;
|
|
EXCEPTION
|
|
WHEN TOO_MANY_ROWS THEN
|
|
RAISE EXCEPTION 'L''athlète % pratique plusieurs sports.', code_athlete;
|
|
WHEN NO_DATA_FOUND THEN
|
|
RAISE EXCEPTION 'Athlète % inconnu.', code_athlete;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- 12
|
|
SELECT pratique(
|
|
(
|
|
SELECT code FROM athlete WHERE prenom = 'Earvin' AND nom = upper('Ngapeth')
|
|
)
|
|
);
|
|
|
|
-- 13
|
|
SELECT pratique(
|
|
(
|
|
SELECT code FROM athlete WHERE prenom = 'Lotte' AND nom = upper('Kopecky')
|
|
)
|
|
);
|
|
|
|
-- 14
|
|
SELECT pratique('B01');
|
|
|
|
-- 15
|
|
CREATE OR REPLACE FUNCTION medailles(code_pays pays.code%TYPE)
|
|
RETURNS FLOAT AS $$
|
|
DECLARE
|
|
total_athletes INT;
|
|
athletes_medailles INT;
|
|
BEGIN
|
|
SELECT COUNT(*) INTO total_athletes
|
|
FROM athlete
|
|
WHERE pays = code_pays;
|
|
|
|
IF total_athletes = 0 THEN
|
|
RAISE EXCEPTION 'Le pays [%] % n''a pas d''athlète.', code_pays, (SELECT nom FROM pays WHERE code = code_pays);
|
|
END IF;
|
|
|
|
SELECT COUNT(DISTINCT r.athlete) INTO athletes_medailles
|
|
FROM resultat r
|
|
INNER JOIN athlete a ON a.code = r.athlete
|
|
WHERE a.pays = code_pays;
|
|
return athletes_medailles::FLOAT / total_athletes;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- 16
|
|
SELECT medailles(
|
|
(
|
|
SELECT code FROM pays WHERE nom = 'France'
|
|
)
|
|
);
|
|
|
|
-- 17
|
|
SELECT medailles(
|
|
(
|
|
SELECT code FROM pays WHERE nom = 'URSS'
|
|
)
|
|
);
|
|
|
|
-- 18
|
|
SELECT p.nom, ROUND((medailles(p.code) * 100)::numeric, 2) medailles
|
|
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 2 DESC;
|
|
|
|
-- 19
|
|
--DROP FUNCTION IF EXISTS ageMoy_V1;
|
|
CREATE OR REPLACE FUNCTION ageMoy_V1(code_pays pays.code%TYPE)
|
|
RETURNS FLOAT AS $$
|
|
BEGIN
|
|
return (
|
|
SELECT AVG(CURRENT_DATE - dateNaiss) / 365.2422
|
|
FROM athlete
|
|
WHERE pays = code_pays
|
|
);
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- 20
|
|
/*CREATE OR REPLACE FUNCTION ageMoy_V2(code_pays pays.code%TYPE)
|
|
RETURNS FLOAT AS $$
|
|
DECLARE
|
|
total INT := 0;
|
|
nb INT := 0;
|
|
r athlete%rowtype;
|
|
BEGIN
|
|
for r in
|
|
SELECT * FROM athlete WHERE pays = code_pays AND dateNaiss IS NOT NULL
|
|
loop
|
|
total = (CURRENT_DATE - r.dateNaiss) + total;
|
|
nb = nb + 1;
|
|
end loop;
|
|
return total::FLOAT / nb / 365.2422;
|
|
END;
|
|
$$ LANGUAGE plpgsql;*/
|
|
DROP FUNCTION IF EXISTS ageMoy_V2;
|
|
CREATE OR REPLACE FUNCTION ageMoy_V2(code_pays pays.code%TYPE)
|
|
RETURNS FLOAT AS $$
|
|
DECLARE
|
|
i INT;
|
|
fin INT;
|
|
total INT := 0;
|
|
nb INT := 0;
|
|
date_naiss athlete.dateNaiss%TYPE;
|
|
BEGIN
|
|
-- Oui.
|
|
SELECT SUBSTR(MIN(code), 2)::int INTO i FROM athlete WHERE pays = code_pays;
|
|
SELECT SUBSTR(MAX(code), 2)::int INTO fin FROM athlete WHERE pays = code_pays;
|
|
|
|
if i IS NULL then
|
|
return 0;
|
|
end if;
|
|
|
|
-- Teste pour chaque code possible
|
|
while i <= fin loop
|
|
SELECT dateNaiss INTO date_naiss FROM athlete WHERE code = to_char(i, 'FMA00000');
|
|
if date_naiss IS NOT NULL then
|
|
total = (CURRENT_DATE - date_naiss) + total;
|
|
nb = nb + 1;
|
|
end if;
|
|
i = i + 1;
|
|
end loop;
|
|
|
|
if nb = 0 then
|
|
return 0;
|
|
end if;
|
|
|
|
return total::FLOAT / nb / 365.2422;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- 21
|
|
--SELECT ageMoy_V1('FRA') v1, ageMoy_V2('FRA') v2;
|
|
--SELECT ageMoy_V1('USA') v1, ageMoy_V2('USA') v2;
|
|
|
|
-- 22
|
|
CREATE OR REPLACE FUNCTION ageMoy_V1(code_pays pays.code%TYPE)
|
|
RETURNS FLOAT AS $$
|
|
BEGIN
|
|
return (
|
|
SELECT COALESCE(AVG(CURRENT_DATE - dateNaiss), 0) / 365.2422
|
|
FROM athlete
|
|
WHERE pays = code_pays AND dateNaiss IS NOT NULL
|
|
);
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
SELECT ageMoy_V1('') v1, ageMoy_V2('') v2;
|
|
|
|
-- 23
|
|
WITH age_moyen AS (
|
|
SELECT nom, ageMoy_V1(code) AS age_moyen FROM pays
|
|
) SELECT nom, age_moyen
|
|
FROM age_moyen
|
|
ORDER BY age_moyen DESC
|
|
LIMIT 1;
|
|
-- Ou
|
|
WITH age_moyen AS (
|
|
SELECT nom, ageMoy_V1(code) AS age_moyen FROM pays
|
|
) SELECT nom, age_moyen
|
|
FROM age_moyen
|
|
WHERE age_moyen = (SELECT MAX(age_moyen) FROM age_moyen);
|
|
|
|
-- 24
|
|
WITH age_moyen AS (
|
|
SELECT nom, ageMoy_V1(code) AS age_moyen FROM pays
|
|
) SELECT nom, age_moyen
|
|
FROM age_moyen
|
|
WHERE age_moyen != 0
|
|
ORDER BY age_moyen
|
|
LIMIT 1;
|
|
|
|
-- 25
|
|
CREATE OR REPLACE FUNCTION gagner(code_athlete athlete.code%TYPE, couleur_medaille medaille.couleur%TYPE)
|
|
RETURNS INT AS $$
|
|
BEGIN
|
|
return (
|
|
SELECT COUNT(*) FROM resultat WHERE athlete = code_athlete AND medaille = (
|
|
SELECT place FROM medaille WHERE couleur = couleur_medaille
|
|
)
|
|
);
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- 26
|
|
SELECT gagner(
|
|
(SELECT code FROM athlete WHERE prenom = 'Teddy' AND nom = 'RINER'),
|
|
'Or'
|
|
) medailles_or, gagner(
|
|
(SELECT code FROM athlete WHERE prenom = 'Teddy' AND nom = 'RINER'),
|
|
'Argent'
|
|
) medailles_argent, gagner(
|
|
(SELECT code FROM athlete WHERE prenom = 'Teddy' AND nom = 'RINER'),
|
|
'Bronze'
|
|
) medailles_bronze;
|
|
|
|
-- 27
|
|
CREATE TABLE IF NOT EXISTS resultat_fr (
|
|
code CHAR(6) PRIMARY KEY REFERENCES athlete(code),
|
|
nom VARCHAR(40) NOT NULL,
|
|
prenom VARCHAR(40) NOT NULL,
|
|
dateNaiss DATE,
|
|
nb_or INT DEFAULT 0,
|
|
nb_argent INT DEFAULT 0,
|
|
nb_bronze INT DEFAULT 0
|
|
);
|
|
|
|
-- 28
|
|
INSERT INTO resultat_fr
|
|
SELECT code, nom, prenom, dateNaiss, gagner(code, 'Or'), gagner(code, 'Argent'), gagner(code, 'Bronze')
|
|
FROM athlete
|
|
WHERE pays = (SELECT code FROM pays WHERE nom = 'France');
|
|
|
|
-- 29
|
|
SELECT * FROM resultat_fr ORDER BY (nb_or + nb_argent + nb_bronze) DESC, dateNaiss;
|