339 lines
7.0 KiB
SQL
339 lines
7.0 KiB
SQL
START TRANSACTION;
|
|
|
|
INSERT INTO
|
|
`contrainte` (`idcontrainte`, `couleur`)
|
|
SELECT DISTINCT
|
|
id_contrainte,
|
|
couleur
|
|
FROM
|
|
donnees_fournies.instances2;
|
|
|
|
INSERT INTO
|
|
`carte` (`idcarte`, `niveau`, `img`, `points`)
|
|
SELECT DISTINCT
|
|
`id_carte`,
|
|
`niveau`,
|
|
`fichier`,
|
|
`points`
|
|
FROM
|
|
donnees_fournies.instances2;
|
|
|
|
INSERT INTO
|
|
`classement` (`idclassement`, `nom`, `portee`)
|
|
SELECT DISTINCT
|
|
`idC`,
|
|
`nom`,
|
|
`portée`
|
|
FROM
|
|
donnees_fournies.classement;
|
|
|
|
INSERT INTO
|
|
`equipe` (`idequipe`, `nom`)
|
|
SELECT DISTINCT
|
|
`idE`,
|
|
`nom`
|
|
FROM
|
|
donnees_fournies.équipe;
|
|
|
|
INSERT INTO `equipe`(`nom`)
|
|
SELECT DISTINCT équipe FROM donnees_fournies.instances1 WHERE équipe IS NOT NULL;
|
|
|
|
INSERT INTO
|
|
`tournoi` (`idtournoi`, `nom`, `date_deb`, `date_fin`)
|
|
SELECT
|
|
`idT`,
|
|
`nom`,
|
|
`dateDeb`,
|
|
`dateFin`
|
|
FROM
|
|
donnees_fournies.tournoi;
|
|
|
|
INSERT INTO
|
|
`joueur` (
|
|
`idjoueur`,
|
|
`nom`,
|
|
`prenom`,
|
|
`pseudo`,
|
|
`annee_nais`,
|
|
`email`,
|
|
`idequipe`
|
|
)
|
|
SELECT DISTINCT
|
|
idJ,
|
|
nom,
|
|
prénom,
|
|
pseudo,
|
|
YEAR (date_naiss),
|
|
email,
|
|
id_équipe
|
|
FROM
|
|
donnees_fournies.joueur;
|
|
|
|
INSERT INTO
|
|
`joueur` (
|
|
`idjoueur`,
|
|
`nom`,
|
|
`prenom`,
|
|
`pseudo`,
|
|
`annee_nais`,
|
|
`email`
|
|
)
|
|
SELECT DISTINCT
|
|
id_joueur,
|
|
nom,
|
|
prénom,
|
|
pseudo,
|
|
YEAR (date_naiss),
|
|
email
|
|
FROM
|
|
donnees_fournies.instances1
|
|
WHERE
|
|
id_joueur > 10;
|
|
|
|
INSERT INTO
|
|
`phase` (`idtournoi`, `niveau`, `date_p`)
|
|
SELECT
|
|
`idT`,
|
|
`niveau`,
|
|
`dateP`
|
|
FROM
|
|
donnees_fournies.phase;
|
|
|
|
INSERT INTO
|
|
`classement_equipe` (`idclassement`, `idequipe`, `rang`)
|
|
SELECT
|
|
`idC`,
|
|
`idE`,
|
|
`rang`
|
|
FROM
|
|
donnees_fournies.classement_equipe;
|
|
|
|
|
|
CREATE TEMPORARY TABLE unique_plateau AS
|
|
SELECT id_partie AS idplateau, c1, c2, c3, c4, c5, c6, c7, c8, c9, c10, c11, c12
|
|
FROM donnees_fournies.instances1
|
|
GROUP BY c1, c2, c3, c4, c5, c6, c7, c8, c9, c10, c11, c12;
|
|
|
|
INSERT INTO plateau (idplateau, taille)
|
|
SELECT idplateau, 12 FROM unique_plateau;
|
|
|
|
INSERT INTO est_compose (idcarte, idplateau, rang)
|
|
SELECT c1, idplateau, 1 FROM unique_plateau
|
|
UNION ALL
|
|
SELECT c2, idplateau, 2 FROM unique_plateau
|
|
UNION ALL
|
|
SELECT c3, idplateau, 3 FROM unique_plateau
|
|
UNION ALL
|
|
SELECT c4, idplateau, 4 FROM unique_plateau
|
|
UNION ALL
|
|
SELECT c5, idplateau, 5 FROM unique_plateau
|
|
UNION ALL
|
|
SELECT c6, idplateau, 6 FROM unique_plateau
|
|
UNION ALL
|
|
SELECT c7, idplateau, 7 FROM unique_plateau
|
|
UNION ALL
|
|
SELECT c8, idplateau, 8 FROM unique_plateau
|
|
UNION ALL
|
|
SELECT c9, idplateau, 9 FROM unique_plateau
|
|
UNION ALL
|
|
SELECT c10, idplateau, 10 FROM unique_plateau
|
|
UNION ALL
|
|
SELECT c11, idplateau, 11 FROM unique_plateau
|
|
UNION ALL
|
|
SELECT c12, idplateau, 12 FROM unique_plateau;
|
|
|
|
|
|
INSERT INTO
|
|
`partie` (
|
|
`idpartie`,
|
|
`date_partie`,
|
|
`horaire`,
|
|
`duree`,
|
|
`etat`,
|
|
`idplateau`,
|
|
`idtournoi`,
|
|
`niveau`
|
|
)
|
|
SELECT DISTINCT
|
|
id_partie,
|
|
dateP,
|
|
heureP,
|
|
ROUND(durée_secondes / 60),
|
|
CASE état
|
|
WHEN 'T' THEN 'terminée'
|
|
WHEN 'AV' THEN 'a venir'
|
|
WHEN 'EC' THEN 'en cours'
|
|
END,
|
|
p.idplateau,
|
|
NULL,
|
|
NULL
|
|
FROM
|
|
donnees_fournies.instances1 JOIN unique_plateau p USING(c1, c2, c3, c4, c5, c6, c7, c8, c9, c10, c11, c12);
|
|
|
|
INSERT INTO
|
|
`participe` (
|
|
`idtournoi`,
|
|
`niveau`,
|
|
`idjoueur`,
|
|
`a_joue`,
|
|
`est_qualifie`
|
|
)
|
|
SELECT
|
|
`idT`,
|
|
`niveau`,
|
|
`idJ`,
|
|
`a_joué`,
|
|
`est_qualifié`
|
|
FROM
|
|
donnees_fournies.participe;
|
|
|
|
INSERT INTO
|
|
`est_en_lien` (`idclassement_1`, `idclassement_2`, `rang`)
|
|
SELECT
|
|
`idC1`,
|
|
`idC2`,
|
|
`type_lien`
|
|
FROM
|
|
donnees_fournies.est_en_lien;
|
|
|
|
INSERT INTO
|
|
`tour` (`idpartie`, `num_tour`)
|
|
SELECT DISTINCT
|
|
`id_partie`,
|
|
`numTour`
|
|
FROM
|
|
donnees_fournies.instances3;
|
|
|
|
INSERT INTO
|
|
`choisit_main` (
|
|
`idjoueur`,
|
|
`idpartie`,
|
|
`num_tour`,
|
|
`nb_de_rouge`,
|
|
`nb_de_jaune`,
|
|
`nb_de_bleu`
|
|
)
|
|
SELECT DISTINCT
|
|
`id_joueur`,
|
|
`id_partie`,
|
|
`numTour`,
|
|
`main_nb_rouge`,
|
|
`main_nb_jaune`,
|
|
`main_nb_bleu`
|
|
FROM
|
|
donnees_fournies.instances3;
|
|
|
|
INSERT INTO
|
|
`classement_individuel` (`idclassement`, `idjoueur`, `rang`)
|
|
SELECT
|
|
`idC`,
|
|
`idJ`,
|
|
`rang`
|
|
FROM
|
|
donnees_fournies.classement_individuel;
|
|
|
|
INSERT INTO
|
|
`est_contrainte` (`idcarte`, `idcontrainte`)
|
|
SELECT
|
|
`id_carte`,
|
|
`id_contrainte`
|
|
FROM
|
|
donnees_fournies.instances2;
|
|
|
|
INSERT INTO
|
|
`face_de_de` (`idcontrainte`, `valeur`)
|
|
SELECT DISTINCT
|
|
`id_contrainte`,
|
|
`valeur`
|
|
FROM
|
|
donnees_fournies.instances2
|
|
WHERE
|
|
nom = 'face_de_dé';
|
|
|
|
INSERT INTO
|
|
`serie_au_choix` (`idcontrainte`, `nombre`)
|
|
SELECT DISTINCT
|
|
`id_contrainte`,
|
|
`valeur`
|
|
FROM
|
|
donnees_fournies.instances2
|
|
WHERE
|
|
nom = 'suite_au_choix';
|
|
|
|
INSERT INTO
|
|
`meme_au_choix` (`idcontrainte`, `nombre`, `couleur`)
|
|
SELECT DISTINCT
|
|
`id_contrainte`,
|
|
`valeur`,
|
|
`couleur`
|
|
FROM
|
|
donnees_fournies.instances2
|
|
WHERE
|
|
nom = 'meme_au_choix';
|
|
|
|
INSERT INTO
|
|
`seuil_de_des` (`idcontrainte`, `valeur`, `sens`)
|
|
SELECT DISTINCT
|
|
`id_contrainte`,
|
|
`valeur`,
|
|
`sens`
|
|
FROM
|
|
donnees_fournies.instances2
|
|
WHERE
|
|
nom = 'seuil_de_dé';
|
|
|
|
SET @row_number = 0;
|
|
|
|
INSERT INTO `comprend`(`idpartie`, `num_tour`, `idlancer`, `numero_lancer_dans_tour`) SELECT `id_partie`, `numTour`, @row_number:=@row_number+1 AS idlancers_de_de, numL
|
|
FROM donnees_fournies.instances3 t;
|
|
|
|
SET @row_number = 0;
|
|
INSERT INTO `effectue`(`idjoueur`, `idlancer`)
|
|
SELECT inst3.id_joueur, @row_number:=@row_number+1 AS idlancer
|
|
FROM donnees_fournies.instances3 inst3;
|
|
|
|
SET @roulement = 0;
|
|
INSERT INTO `de_lance`(`roulement_de_de`, `rang_couleur_valeur`, `idlancer`)
|
|
SELECT @roulement:=@roulement+1 AS roulement, CONCAT('1;', de1) AS rang_couleur_valeur, (FLOOR((@roulement-1)/6) + 1) AS idlancer FROM `donnees_fournies`.`instances3`
|
|
UNION ALL SELECT @roulement:=@roulement+1, CONCAT('2;', de2), (FLOOR((@roulement-1)/6) + 1) AS idlancer FROM `donnees_fournies`.`instances3`
|
|
UNION ALL SELECT @roulement:=@roulement+1, CONCAT('3;', de3), (FLOOR((@roulement-1)/6) + 1) AS idlancer FROM `donnees_fournies`.`instances3`
|
|
UNION ALL SELECT @roulement:=@roulement+1, CONCAT('4;', de4), (FLOOR((@roulement-1)/6) + 1) AS idlancer FROM `donnees_fournies`.`instances3`
|
|
UNION ALL SELECT @roulement:=@roulement+1, CONCAT('5;', de5), (FLOOR((@roulement-1)/6) + 1) AS idlancer FROM `donnees_fournies`.`instances3`
|
|
UNION ALL SELECT @roulement:=@roulement+1, CONCAT('6;', de6), (FLOOR((@roulement-1)/6) + 1) AS idlancer FROM `donnees_fournies`.`instances3`;
|
|
|
|
INSERT INTO `joue`(`idjoueur`, `idpartie`, `couleur_pion`, `rang`)
|
|
SELECT `id_joueur`, `id_partie`, NULL, `rang_arrivee` FROM donnees_fournies.instances1;
|
|
|
|
SET @row_number = 0;
|
|
|
|
INSERT INTO `valide`(`idlancer`, `idcontrainte`)
|
|
SELECT max_idlancer_table.max_idlancer, est_contrainte.idcontrainte
|
|
FROM (
|
|
SELECT `id_partie`, `id_joueur`, `carteAvalider`, MAX(@row_number:=@row_number+1) as max_idlancer
|
|
FROM donnees_fournies.instances3
|
|
GROUP BY `id_partie`, `id_joueur`, `carteAvalider`
|
|
) as max_idlancer_table
|
|
JOIN `est_contrainte` ON max_idlancer_table.carteAvalider = est_contrainte.idcarte;
|
|
|
|
INSERT INTO
|
|
`tente_validation` (
|
|
`idpartie`,
|
|
`num_tour`,
|
|
`idjoueur`,
|
|
`idcarte`,
|
|
`nb_tentatives`
|
|
)
|
|
SELECT
|
|
`id_partie`,
|
|
`numTour`,
|
|
`id_joueur`,
|
|
`carteAvalider`,
|
|
COUNT(`numL`) as nb_tentatives
|
|
FROM
|
|
donnees_fournies.instances3
|
|
GROUP BY
|
|
`id_partie`,
|
|
`id_joueur`,
|
|
`carteAvalider`;
|
|
|
|
COMMIT; |