td3
This commit is contained in:
parent
279452d652
commit
ffc9be1736
120
TD3/familles.sql
Normal file
120
TD3/familles.sql
Normal file
@ -0,0 +1,120 @@
|
|||||||
|
CREATE TABLE `familles` (
|
||||||
|
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||||
|
`bord_gauche` INT(10) UNSIGNED NOT NULL,
|
||||||
|
`bord_droit` INT(10) UNSIGNED NOT NULL,
|
||||||
|
`nom` VARCHAR(250) DEFAULT NULL,
|
||||||
|
PRIMARY KEY (`id`)
|
||||||
|
) ENGINE = 'InnoDB' DEFAULT CHARACTER SET = 'utf8';
|
||||||
|
|
||||||
|
INSERT INTO `familles` (`id`, `bord_gauche`, `bord_droit`, `nom`) VALUES
|
||||||
|
(1, 1, 44, 'Transport'), (2, 2, 21, 'Aérien'), (3, 3, 4, 'Planeur'), (4, 5, 6, 'Parachute'),
|
||||||
|
(5, 7, 8, 'Hélico'), (6, 9, 10, 'Fusée'), (7, 11, 12, 'ULM'), (8, 13, 20, 'Avion'),
|
||||||
|
(9, 14, 15, 'Militaire'), (10, 16, 17, 'Tourisme'), (11, 18, 19, 'Civil'),
|
||||||
|
(12, 22, 35, 'Terrestre'), (13, 23, 24, 'Vélo'), (14, 25, 26, 'Voiture'),
|
||||||
|
(15, 27, 28, 'Camion'), (16, 29, 34, 'Moto'), (17, 30, 31, 'Side-car'),
|
||||||
|
(18, 32, 33, 'Trail'), (19, 36, 43, 'Marin'), (20, 37, 38, 'Planche à voile'),
|
||||||
|
(21, 39, 40, 'Paquebot'), (22, 41, 42, 'Voilier');
|
||||||
|
|
||||||
|
-- Rechercher toutes les feuilles
|
||||||
|
SELECT *
|
||||||
|
FROM familles F
|
||||||
|
WHERE (F.bord_droit - F.bord_gauche) = 1;
|
||||||
|
|
||||||
|
|
||||||
|
--Rechercher toutes les feuilles sous un élément de référence
|
||||||
|
SELECT *
|
||||||
|
FROM familles F
|
||||||
|
WHERE (F.bord_droit - F.bord_gauche) = 1
|
||||||
|
AND F.bord_gauche > 22
|
||||||
|
AND F.bord_droit < 35;
|
||||||
|
|
||||||
|
|
||||||
|
--Rechercher tous les nœuds
|
||||||
|
SELECT *
|
||||||
|
FROM familles F
|
||||||
|
WHERE (F.bord_droit - F.bord_gauche) > 1;
|
||||||
|
|
||||||
|
|
||||||
|
--Rechercher tous les nœuds sous un élément de référence
|
||||||
|
SELECT *
|
||||||
|
FROM familles F
|
||||||
|
WHERE (F.bord_droit - F.bord_gauche) > 1
|
||||||
|
AND F.bord_gauche > 2
|
||||||
|
AND F.bord_droit < 21;
|
||||||
|
|
||||||
|
|
||||||
|
--Tous les éléments dépendant d'un élément de référence (sous-arbre)
|
||||||
|
SELECT *
|
||||||
|
FROM familles F
|
||||||
|
WHERE F.bord_gauche > 2
|
||||||
|
AND F.bord_droit < 21;
|
||||||
|
|
||||||
|
|
||||||
|
--Tous les éléments indépendants d'un élément de référence (complément au sous-arbre)
|
||||||
|
SELECT *
|
||||||
|
FROM familles F
|
||||||
|
WHERE F.bord_gauche < 2
|
||||||
|
OR F.bord_droit > 21;
|
||||||
|
|
||||||
|
|
||||||
|
--Tous les pères d'un élément de référence
|
||||||
|
SELECT *
|
||||||
|
FROM familles F
|
||||||
|
WHERE (F.bord_droit - F.bord_gauche) > 1
|
||||||
|
AND F.bord_gauche < 14
|
||||||
|
AND F.bord_droit > 15;
|
||||||
|
|
||||||
|
|
||||||
|
--Recherche de la racine de l'arbre
|
||||||
|
SELECT *
|
||||||
|
FROM familles F
|
||||||
|
WHERE F.bord_gauche = 1;
|
||||||
|
|
||||||
|
|
||||||
|
--Compter les feuilles
|
||||||
|
SELECT COUNT(*) as nbFeuilles
|
||||||
|
FROM familles F
|
||||||
|
WHERE (F.bord_droit - F.bord_gauche) = 1;
|
||||||
|
|
||||||
|
|
||||||
|
--Compter les nœuds
|
||||||
|
SELECT COUNT(*) as nbNoeux
|
||||||
|
FROM familles F
|
||||||
|
WHERE (F.bord_droit - F.bord_gauche) > 1;
|
||||||
|
|
||||||
|
|
||||||
|
--Insérer l’élément “Roller” en liaison directe avec son père l’élément “Terrestre”
|
||||||
|
SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;
|
||||||
|
START TRANSACTION;
|
||||||
|
UPDATE familles
|
||||||
|
SET bord_gauche = bord_gauche + 2
|
||||||
|
WHERE bord_gauche >= 35;
|
||||||
|
|
||||||
|
UPDATE familles
|
||||||
|
SET bord_droit = bord_droit + 2
|
||||||
|
WHERE bord_droit >= 35;
|
||||||
|
|
||||||
|
INSERT INTO familles (bord_gauche, bord_droit, nom)
|
||||||
|
VALUES (35, 36, "Roller");
|
||||||
|
COMMIT;
|
||||||
|
|
||||||
|
|
||||||
|
--Supprimer l’élément “ULM” (dont le NFM_BG vaut 11)
|
||||||
|
SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;
|
||||||
|
START TRANSACTION;
|
||||||
|
DELETE
|
||||||
|
FROM familles
|
||||||
|
WHERE bord_gauche = 11;
|
||||||
|
|
||||||
|
UPDATE familles
|
||||||
|
SET bord_gauche = bord_gauche - 2
|
||||||
|
WHERE bord_gauche >= 11;
|
||||||
|
|
||||||
|
UPDATE familles
|
||||||
|
SET bord_droit = bord_droit - 2
|
||||||
|
WHERE bord_droit >= 11;
|
||||||
|
COMMIT;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
26
TD3/familles2.sql
Normal file
26
TD3/familles2.sql
Normal file
@ -0,0 +1,26 @@
|
|||||||
|
CREATE TABLE `familles2` (
|
||||||
|
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||||
|
`bord_gauche` INT(10) UNSIGNED NOT NULL,
|
||||||
|
`bord_droit` INT(10) UNSIGNED NOT NULL,
|
||||||
|
`niveau` INT(10) UNSIGNED NOT NULL,
|
||||||
|
`nom` VARCHAR(250) DEFAULT NULL,
|
||||||
|
PRIMARY KEY (`id`)
|
||||||
|
) ENGINE = 'InnoDB' DEFAULT CHARACTER SET = 'utf8';
|
||||||
|
|
||||||
|
INSERT INTO `familles2` (`id`, `bord_gauche`, `bord_droit`, `niveau`, `nom`) VALUES
|
||||||
|
(1, 1, 44, 1, 'Transport'), (2, 2, 21, 2, 'Aérien'), (3, 3, 4, 3, 'Planeur'), (4, 5, 6, 3, 'Parachute'),
|
||||||
|
(5, 7, 8, 3, 'Hélico'), (6, 9, 10, 3, 'Fusée'), (7, 11, 12, 3, 'ULM'), (8, 13, 20, 3, 'Avion'),
|
||||||
|
(9, 14, 15, 4, 'Militaire'), (10, 16, 17, 4, 'Tourisme'), (11, 18, 19, 4, 'Civil'),
|
||||||
|
(12, 22, 35, 2, 'Terrestre'), (13, 23, 24, 3, 'Vélo'), (14, 25, 26, 3, 'Voiture'),
|
||||||
|
(15, 27, 28, 3, 'Camion'), (16, 29, 34, 3, 'Moto'), (17, 30, 31, 4, 'Side-car'),
|
||||||
|
(18, 32, 33, 4, 'Trail'), (19, 36, 43, 2, 'Marin'), (20, 37, 38, 3, 'Planche à voile'),
|
||||||
|
(21, 39, 40, 3, 'Paquebot'), (22, 41, 42, 3, 'Voilier');
|
||||||
|
|
||||||
|
CREATE VIEW arbo AS
|
||||||
|
SELECT `familles2`.`id` AS `id`,
|
||||||
|
Concat(CONVERT(Space((`familles2`.`niveau` * 10)) USING utf8mb3),`familles2`.`nom`) AS `arbre`,
|
||||||
|
`familles2`.`bord_gauche` AS `bord_gauche`,
|
||||||
|
`familles2`.`bord_droit` AS `bord_droit`,
|
||||||
|
`familles2`.`niveau` AS `niveau`
|
||||||
|
FROM `familles2`
|
||||||
|
ORDER BY `familles2`.`bord_gauche`
|
Loading…
x
Reference in New Issue
Block a user