paniers/paniers.sql

288 lines
12 KiB
SQL

SET SQL_MODE = "NO_AUTO_VALUE_ON_ZERO";
START TRANSACTION;
SET time_zone = "+00:00";
-- --------------------------------------------------------
-- STRUCTURE DE LA TABLE `paniers_groupes`
-- --------------------------------------------------------
CREATE TABLE `paniers_groupes` (
`ref` smallint(5) UNSIGNED NOT NULL AUTO_INCREMENT,
`nom` varchar(64) NOT NULL,
`del` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
PRIMARY KEY (`ref`),
INDEX (`del`)
)
ENGINE=InnoDB
DEFAULT CHARSET=utf8;
-- --------------------------------------------------------
-- STRUCTURE DE LA TABLE `paniers_types`
-- --------------------------------------------------------
CREATE TABLE `paniers_types` (
`ref` smallint(5) UNSIGNED NOT NULL AUTO_INCREMENT,
`groupe` smallint(5) UNSIGNED NOT NULL,
`nom` varchar(64) NOT NULL,
`valeur` float(5,2) UNSIGNED NOT NULL,
`del` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
PRIMARY KEY (`ref`),
CONSTRAINT `paniers_types_groupe_fk` FOREIGN KEY (`groupe`) REFERENCES `paniers_groupes`(`ref`) ON DELETE RESTRICT ON UPDATE RESTRICT,
INDEX (`del`)
)
ENGINE=InnoDB
DEFAULT CHARSET=utf8;
-- --------------------------------------------------------
-- STRUCTURE DE LA TABLE `lieux`
-- --------------------------------------------------------
CREATE TABLE `lieux` (
`ref` smallint(5) UNSIGNED NOT NULL AUTO_INCREMENT,
`nom` varchar(64) NOT NULL,
`del` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
PRIMARY KEY (`ref`),
INDEX (`del`)
)
ENGINE=InnoDB
DEFAULT CHARSET=utf8;
-- --------------------------------------------------------
-- STRUCTURE DE LA TABLE `clients`
-- --------------------------------------------------------
CREATE TABLE `clients` (
`ref` smallint(5) UNSIGNED NOT NULL AUTO_INCREMENT,
`nom` varchar(64) NOT NULL,
`prenom` varchar(64) NOT NULL,
`tel` varchar(20) NULL DEFAULT NULL,
`email` varchar(128) NULL DEFAULT NULL,
`del` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
PRIMARY KEY (`ref`),
INDEX (`del`)
)
ENGINE=InnoDB
DEFAULT CHARSET=utf8;
-- --------------------------------------------------------
-- STRUCTURE DE LA TABLE `clients_absences`
-- --------------------------------------------------------
CREATE TABLE `clients_absences` (
`ref` smallint(5) UNSIGNED NOT NULL AUTO_INCREMENT ,
`client` smallint(5) UNSIGNED NOT NULL ,
`debut` DATE NOT NULL ,
`fin` DATE NOT NULL ,
`remarque` TEXT CHARACTER SET utf8 COLLATE utf8_general_ci NOT NULL,
`del` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
PRIMARY KEY (`ref`),
CONSTRAINT `clients_absences_client_fk` FOREIGN KEY (`client`) REFERENCES `clients`(`ref`) ON DELETE RESTRICT ON UPDATE RESTRICT,
INDEX (`del`)
)
ENGINE = InnoDB
DEFAULT CHARSET=utf8;
-- --------------------------------------------------------
-- STRUCTURE DE LA TABLE `contrats_types`
-- --------------------------------------------------------
CREATE TABLE `contrats_types` (
`ref` smallint(5) UNSIGNED NOT NULL AUTO_INCREMENT,
`groupe` smallint(5) UNSIGNED NOT NULL,
`nom` varchar(128) NOT NULL,
`frequence` set('hebdo','quinz') NOT NULL,
`panier_type` smallint(5) UNSIGNED NOT NULL,
`nb_paniers` smallint(2) UNSIGNED NOT NULL,
`prix_total` float(6,2) UNSIGNED NOT NULL,
`del` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
PRIMARY KEY (`ref`),
CONSTRAINT `contrats_types_groupe_fk` FOREIGN KEY (`groupe`) REFERENCES `paniers_groupes`(`ref`) ON DELETE RESTRICT ON UPDATE RESTRICT,
INDEX(`frequence`),
CONSTRAINT `contrats_types_panier_type_fk` FOREIGN KEY (`panier_type`) REFERENCES `paniers_types`(`ref`) ON DELETE RESTRICT ON UPDATE RESTRICT,
INDEX (`del`)
)
ENGINE=InnoDB
DEFAULT CHARSET=utf8;
-- --------------------------------------------------------
-- STRUCTURE DE LA TABLE `contrats`
-- --------------------------------------------------------
CREATE TABLE `contrats` (
`ref` smallint(5) UNSIGNED NOT NULL AUTO_INCREMENT,
`client` smallint(5) UNSIGNED NOT NULL,
`type` smallint(5) UNSIGNED NULL DEFAULT NULL,
`groupe` smallint(5) UNSIGNED NOT NULL,
`frequence` set('hebdo','quinz') NOT NULL,
`panier_type` smallint(5) UNSIGNED NOT NULL,
`nb_paniers` smallint(2) UNSIGNED NOT NULL,
`date` date NOT NULL,
`quinz_groupe` set('A','B') NULL DEFAULT NULL,
`lieu_depot` smallint(5) UNSIGNED NOT NULL,
`nb_cheque` int(2) UNSIGNED NOT NULL DEFAULT '0',
`np_paniers_distrib_avt_saisie` int(2) UNSIGNED NOT NULL DEFAULT '0',
`force_eligible` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
`force_not_archive` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
`archive` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
`del` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
PRIMARY KEY (`ref`),
CONSTRAINT `contrats_client_fk` FOREIGN KEY (`client`) REFERENCES `clients`(`ref`) ON DELETE RESTRICT ON UPDATE RESTRICT,
CONSTRAINT `contrats_type_fk` FOREIGN KEY (`type`) REFERENCES `contrats_types`(`ref`) ON DELETE RESTRICT ON UPDATE RESTRICT,
CONSTRAINT `paniers_groupe_fk` FOREIGN KEY (`groupe`) REFERENCES `paniers_groupes`(`ref`) ON DELETE RESTRICT ON UPDATE RESTRICT,
INDEX(`frequence`),
CONSTRAINT `contrats_panier_type_fk` FOREIGN KEY (`panier_type`) REFERENCES `paniers_types`(`ref`) ON DELETE RESTRICT ON UPDATE RESTRICT,
INDEX(`quinz_groupe`),
CONSTRAINT `contrats_lieu_depot_fk` FOREIGN KEY (`lieu_depot`) REFERENCES `lieux`(`ref`) ON DELETE RESTRICT ON UPDATE RESTRICT,
INDEX(`archive`),
INDEX (`force_not_archive`),
INDEX (`del`)
)
ENGINE=InnoDB
DEFAULT CHARSET=utf8;
-- --------------------------------------------------------
-- STRUCTURE DE LA TABLE `legumes`
-- --------------------------------------------------------
CREATE TABLE `legumes` (
`ref` smallint(5) UNSIGNED NOT NULL AUTO_INCREMENT,
`nom` varchar(64) NOT NULL,
`tarif` smallint(5) UNSIGNED NULL DEFAULT NULL,
`del` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
PRIMARY KEY (`ref`),
INDEX (`tarif`),
INDEX (`del`)
)
ENGINE = InnoDB
DEFAULT CHARSET=utf8;
-- --------------------------------------------------------
-- STRUCTURE DE LA TABLE `legume_tarifs`
-- --------------------------------------------------------
CREATE TABLE `legumes_tarifs` (
`ref` smallint(5) UNSIGNED NOT NULL AUTO_INCREMENT,
`legume` smallint(5) UNSIGNED NOT NULL,
`prix` float(5,2) UNSIGNED NOT NULL,
`unite` set('kg','pièce','botte') NOT NULL DEFAULT 'kg',
`date` date NOT NULL,
`del` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
PRIMARY KEY (`ref`),
CONSTRAINT `legumes_tarifs_legume_fk` FOREIGN KEY (`legume`) REFERENCES `legumes`(`ref`) ON DELETE RESTRICT ON UPDATE RESTRICT,
INDEX (`del`)
)
ENGINE=InnoDB
DEFAULT CHARSET=utf8;
-- --------------------------------------------------------
-- STRUCTURE DE LA TABLE `livraisons`
-- --------------------------------------------------------
CREATE TABLE `livraisons` (
`ref` smallint(5) UNSIGNED NOT NULL AUTO_INCREMENT,
`paniers_groupe` smallint(5) UNSIGNED NOT NULL,
`date` date NOT NULL,
`quinz_groupe` set('A','B') NOT NULL,
`archive` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
`force_not_archive` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
`del` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
PRIMARY KEY (`ref`),
CONSTRAINT `livraisons_paniers_groupe_fk` FOREIGN KEY (`paniers_groupe`) REFERENCES `paniers_groupes`(`ref`) ON DELETE RESTRICT ON UPDATE RESTRICT,
INDEX (`archive`),
INDEX (`force_not_archive`),
INDEX (`del`)
)
ENGINE=InnoDB
DEFAULT CHARSET=utf8;
-- --------------------------------------------------------
-- STRUCTURE DE LA TABLE `livraisons_legumes`
-- --------------------------------------------------------
CREATE TABLE `livraisons_legumes` (
`livraison` smallint(5) UNSIGNED NOT NULL,
`legume` smallint(5) UNSIGNED NOT NULL,
`panier_type` smallint(5) UNSIGNED NOT NULL,
`tarif` smallint(5) UNSIGNED NOT NULL,
`quantite` float(5,2) UNSIGNED NOT NULL,
`del` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
UNIQUE (`livraison`, `legume`, `panier_type`),
CONSTRAINT `livraisons_legumes_livraison_fk` FOREIGN KEY (`livraison`) REFERENCES `livraisons`(`ref`) ON DELETE RESTRICT ON UPDATE RESTRICT,
CONSTRAINT `livraisons_legumes_panier_type_fk` FOREIGN KEY (`panier_type`) REFERENCES `paniers_types`(`ref`) ON DELETE RESTRICT ON UPDATE RESTRICT,
CONSTRAINT `livraisons_legumes_legume_fk` FOREIGN KEY (`legume`) REFERENCES `legumes`(`ref`) ON DELETE RESTRICT ON UPDATE RESTRICT,
CONSTRAINT `livraisons_legumes_tarif_fk` FOREIGN KEY (`tarif`) REFERENCES `legumes_tarifs`(`ref`) ON DELETE RESTRICT ON UPDATE RESTRICT,
INDEX (`del`)
)
ENGINE=InnoDB
DEFAULT CHARSET=utf8;
-- --------------------------------------------------------
-- STRUCTURE DE LA TABLE `livraisons_paniers`
-- --------------------------------------------------------
CREATE TABLE `livraisons_paniers` (
`livraison` smallint(5) UNSIGNED NOT NULL,
`contrat` smallint(5) UNSIGNED NOT NULL,
`force_not_archive` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
`del` tinyint(1) UNSIGNED NOT NULL DEFAULT '0',
UNIQUE (`livraison`, `contrat`),
CONSTRAINT `livraisons_paniers_livraison_fk` FOREIGN KEY (`livraison`) REFERENCES `livraisons`(`ref`) ON DELETE RESTRICT ON UPDATE RESTRICT,
CONSTRAINT `livraisons_paniers_contrat_fk` FOREIGN KEY (`contrat`) REFERENCES `contrats`(`ref`) ON DELETE RESTRICT ON UPDATE RESTRICT,
INDEX (`del`)
)
ENGINE=InnoDB
DEFAULT CHARSET=utf8;
-- ########################################################
-- ### SQL VIEWS ##########################################
-- ########################################################
-- --------------------------------------------------------
-- STRUCTURE DE LA VIEW `contrats_nb_paniers_livres`
-- --------------------------------------------------------
CREATE VIEW `contrats_count_nb_paniers_livres` AS
SELECT
`contrats`.ref,
COUNT(*) as 'nb_paniers_livres'
FROM `livraisons_paniers`
LEFT JOIN contrats ON livraisons_paniers.contrat = contrats.ref
WHERE `livraisons_paniers`.`del`=0
GROUP BY `contrat`;
-- --------------------------------------------------------
-- STRUCTURE DE LA VIEW `contrats_nb_paniers_statut`
-- --------------------------------------------------------
CREATE VIEW `contrats_paniers_statut` AS
SELECT
contrats.ref,
contrats.nb_paniers,
CASE WHEN ISNULL(contrats_count_nb_paniers_livres.nb_paniers_livres)
THEN 0
ELSE contrats_count_nb_paniers_livres.nb_paniers_livres
END as 'nb_paniers_livres_absolute',
CASE WHEN ISNULL(contrats_count_nb_paniers_livres.nb_paniers_livres)
THEN contrats.np_paniers_distrib_avt_saisie
ELSE contrats.np_paniers_distrib_avt_saisie + contrats_count_nb_paniers_livres.nb_paniers_livres
END as 'nb_paniers_livres',
CASE WHEN ISNULL(contrats_count_nb_paniers_livres.nb_paniers_livres)
THEN CAST(contrats.nb_paniers AS signed) - CAST(contrats.np_paniers_distrib_avt_saisie AS signed)
ELSE CAST(contrats.nb_paniers AS signed) - CAST(contrats.np_paniers_distrib_avt_saisie AS signed) - CAST(contrats_count_nb_paniers_livres.nb_paniers_livres AS signed)
END as 'nb_paniers_restants'
FROM contrats
LEFT JOIN contrats_count_nb_paniers_livres ON contrats.ref = contrats_count_nb_paniers_livres.ref;
-- --------------------------------------------------------
-- STRUCTURE DE LA VIEW `livraisons_nb_paniers`
-- --------------------------------------------------------
CREATE VIEW `livraisons_nb_paniers` AS
SELECT
`livraisons_paniers`.`livraison` as 'ref',
COUNT(*) as 'nb_paniers'
FROM `livraisons_paniers`
GROUP BY `livraisons_paniers`.`livraison`;
COMMIT;