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.
359 lines
14 KiB
359 lines
14 KiB
-- Script SQL pour créer la base de données guycom_database_v1
|
|
-- Création des tables et insertion des données par défaut
|
|
|
|
-- =====================================================
|
|
-- CRÉATION DES TABLES
|
|
-- =====================================================
|
|
|
|
-- Table permissions
|
|
CREATE TABLE `permissions` (
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`name` varchar(255) NOT NULL,
|
|
PRIMARY KEY (`id`),
|
|
UNIQUE KEY `name` (`name`)
|
|
) ENGINE=InnoDB AUTO_INCREMENT=8 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
|
|
|
-- Table menu
|
|
CREATE TABLE `menu` (
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`name` varchar(255) NOT NULL,
|
|
`route` varchar(255) NOT NULL,
|
|
PRIMARY KEY (`id`)
|
|
) ENGINE=InnoDB AUTO_INCREMENT=14 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
|
|
|
-- Table roles
|
|
CREATE TABLE `roles` (
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`designation` varchar(255) NOT NULL,
|
|
PRIMARY KEY (`id`),
|
|
UNIQUE KEY `designation` (`designation`)
|
|
) ENGINE=InnoDB AUTO_INCREMENT=6 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
|
|
|
-- Table points_de_vente
|
|
CREATE TABLE `points_de_vente` (
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`nom` varchar(255) NOT NULL,
|
|
PRIMARY KEY (`id`),
|
|
UNIQUE KEY `nom` (`nom`)
|
|
) ENGINE=InnoDB AUTO_INCREMENT=8 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
|
|
|
-- Table clients
|
|
CREATE TABLE `clients` (
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`nom` varchar(255) NOT NULL,
|
|
`prenom` varchar(255) NOT NULL,
|
|
`email` varchar(255) NOT NULL,
|
|
`telephone` varchar(255) NOT NULL,
|
|
`adresse` varchar(500) DEFAULT NULL,
|
|
`dateCreation` datetime NOT NULL,
|
|
`actif` tinyint(1) NOT NULL DEFAULT 1,
|
|
PRIMARY KEY (`id`),
|
|
UNIQUE KEY `email` (`email`),
|
|
KEY `idx_clients_email` (`email`),
|
|
KEY `idx_clients_telephone` (`telephone`)
|
|
) ENGINE=InnoDB AUTO_INCREMENT=9 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
|
|
|
-- Table users
|
|
CREATE TABLE `users` (
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`name` varchar(255) NOT NULL,
|
|
`lastname` varchar(255) NOT NULL,
|
|
`email` varchar(255) NOT NULL,
|
|
`password` varchar(255) NOT NULL,
|
|
`username` varchar(255) NOT NULL,
|
|
`role_id` int(11) NOT NULL,
|
|
`point_de_vente_id` int(11) DEFAULT NULL,
|
|
PRIMARY KEY (`id`),
|
|
UNIQUE KEY `email` (`email`),
|
|
UNIQUE KEY `username` (`username`),
|
|
KEY `role_id` (`role_id`),
|
|
KEY `point_de_vente_id` (`point_de_vente_id`),
|
|
CONSTRAINT `users_ibfk_1` FOREIGN KEY (`role_id`) REFERENCES `roles` (`id`),
|
|
CONSTRAINT `users_ibfk_2` FOREIGN KEY (`point_de_vente_id`) REFERENCES `points_de_vente` (`id`)
|
|
) ENGINE=InnoDB AUTO_INCREMENT=4 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
|
|
|
-- Table products
|
|
CREATE TABLE `products` (
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`name` varchar(255) NOT NULL,
|
|
`price` decimal(10,2) NOT NULL,
|
|
`image` varchar(2000) DEFAULT NULL,
|
|
`category` varchar(255) NOT NULL,
|
|
`stock` int(11) NOT NULL DEFAULT 0,
|
|
`description` varchar(1000) DEFAULT NULL,
|
|
`qrCode` varchar(500) DEFAULT NULL,
|
|
`reference` varchar(255) DEFAULT NULL,
|
|
`point_de_vente_id` int(11) DEFAULT NULL,
|
|
`marque` varchar(255) DEFAULT NULL,
|
|
`ram` varchar(100) DEFAULT NULL,
|
|
`memoire_interne` varchar(100) DEFAULT NULL,
|
|
`imei` varchar(255) DEFAULT NULL,
|
|
PRIMARY KEY (`id`),
|
|
UNIQUE KEY `imei` (`imei`),
|
|
KEY `point_de_vente_id` (`point_de_vente_id`),
|
|
KEY `idx_products_category` (`category`),
|
|
KEY `idx_products_reference` (`reference`),
|
|
KEY `idx_products_imei` (`imei`),
|
|
CONSTRAINT `products_ibfk_1` FOREIGN KEY (`point_de_vente_id`) REFERENCES `points_de_vente` (`id`)
|
|
) ENGINE=InnoDB AUTO_INCREMENT=127 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
|
|
|
-- Table commandes
|
|
CREATE TABLE `commandes` (
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`clientId` int(11) NOT NULL,
|
|
`dateCommande` datetime NOT NULL,
|
|
`statut` int(11) NOT NULL DEFAULT 0,
|
|
`montantTotal` decimal(10,2) NOT NULL,
|
|
`notes` varchar(1000) DEFAULT NULL,
|
|
`dateLivraison` datetime DEFAULT NULL,
|
|
`commandeurId` int(11) DEFAULT NULL,
|
|
`validateurId` int(11) DEFAULT NULL,
|
|
PRIMARY KEY (`id`),
|
|
KEY `commandeurId` (`commandeurId`),
|
|
KEY `validateurId` (`validateurId`),
|
|
KEY `idx_commandes_client` (`clientId`),
|
|
KEY `idx_commandes_date` (`dateCommande`),
|
|
CONSTRAINT `commandes_ibfk_1` FOREIGN KEY (`commandeurId`) REFERENCES `users` (`id`),
|
|
CONSTRAINT `commandes_ibfk_2` FOREIGN KEY (`validateurId`) REFERENCES `users` (`id`),
|
|
CONSTRAINT `commandes_ibfk_3` FOREIGN KEY (`clientId`) REFERENCES `clients` (`id`)
|
|
) ENGINE=InnoDB AUTO_INCREMENT=22 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
|
|
|
-- Table details_commandes
|
|
CREATE TABLE `details_commandes` (
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`commandeId` int(11) NOT NULL,
|
|
`produitId` int(11) NOT NULL,
|
|
`quantite` int(11) NOT NULL,
|
|
`prixUnitaire` decimal(10,2) NOT NULL,
|
|
`sousTotal` decimal(10,2) NOT NULL,
|
|
`remise_type` enum('pourcentage','montant') DEFAULT NULL,
|
|
`remise_valeur` decimal(10,2) DEFAULT 0.00,
|
|
`montant_remise` decimal(10,2) DEFAULT 0.00,
|
|
`prix_final` decimal(10,2) NOT NULL DEFAULT 0.00,
|
|
`est_cadeau` tinyint(1) NOT NULL DEFAULT 0,
|
|
PRIMARY KEY (`id`),
|
|
KEY `produitId` (`produitId`),
|
|
KEY `idx_details_commande` (`commandeId`),
|
|
KEY `idx_est_cadeau` (`est_cadeau`),
|
|
CONSTRAINT `details_commandes_ibfk_1` FOREIGN KEY (`commandeId`) REFERENCES `commandes` (`id`) ON DELETE CASCADE,
|
|
CONSTRAINT `details_commandes_ibfk_2` FOREIGN KEY (`produitId`) REFERENCES `products` (`id`)
|
|
) ENGINE=InnoDB AUTO_INCREMENT=28 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
|
|
|
-- Table role_permissions
|
|
CREATE TABLE `role_permissions` (
|
|
`role_id` int(11) NOT NULL,
|
|
`permission_id` int(11) NOT NULL,
|
|
PRIMARY KEY (`role_id`,`permission_id`),
|
|
KEY `permission_id` (`permission_id`),
|
|
CONSTRAINT `role_permissions_ibfk_1` FOREIGN KEY (`role_id`) REFERENCES `roles` (`id`) ON DELETE CASCADE,
|
|
CONSTRAINT `role_permissions_ibfk_2` FOREIGN KEY (`permission_id`) REFERENCES `permissions` (`id`) ON DELETE CASCADE
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
|
|
|
-- Table role_menu_permissions
|
|
CREATE TABLE `role_menu_permissions` (
|
|
`role_id` int(11) NOT NULL,
|
|
`menu_id` int(11) NOT NULL,
|
|
`permission_id` int(11) NOT NULL,
|
|
PRIMARY KEY (`role_id`,`menu_id`,`permission_id`),
|
|
KEY `menu_id` (`menu_id`),
|
|
KEY `permission_id` (`permission_id`),
|
|
CONSTRAINT `role_menu_permissions_ibfk_1` FOREIGN KEY (`role_id`) REFERENCES `roles` (`id`) ON DELETE CASCADE,
|
|
CONSTRAINT `role_menu_permissions_ibfk_2` FOREIGN KEY (`menu_id`) REFERENCES `menu` (`id`) ON DELETE CASCADE,
|
|
CONSTRAINT `role_menu_permissions_ibfk_3` FOREIGN KEY (`permission_id`) REFERENCES `permissions` (`id`) ON DELETE CASCADE
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
|
|
|
-- =====================================================
|
|
-- INSERTION DES DONNÉES PAR DÉFAUT
|
|
-- =====================================================
|
|
|
|
-- Insertion des permissions par défaut
|
|
INSERT INTO `permissions` (`name`) VALUES
|
|
('view'),
|
|
('create'),
|
|
('update'),
|
|
('delete'),
|
|
('admin'),
|
|
('manage'),
|
|
('read');
|
|
|
|
-- Insertion des menus par défaut
|
|
INSERT INTO `menu` (`name`, `route`) VALUES
|
|
('Accueil', '/accueil'),
|
|
('Ajouter un utilisateur', '/ajouter-utilisateur'),
|
|
('Modifier/Supprimer un utilisateur', '/modifier-utilisateur'),
|
|
('Ajouter un produit', '/ajouter-produit'),
|
|
('Modifier/Supprimer un produit', '/modifier-produit'),
|
|
('Bilan', '/bilan'),
|
|
('Gérer les rôles', '/gerer-roles'),
|
|
('Gestion de stock', '/gestion-stock'),
|
|
('Historique', '/historique'),
|
|
('Déconnexion', '/deconnexion'),
|
|
('Nouvelle commande', '/nouvelle-commande'),
|
|
('Gérer les commandes', '/gerer-commandes'),
|
|
('Points de vente', '/points-de-vente');
|
|
|
|
-- Insertion des rôles par défaut
|
|
INSERT INTO `roles` (`designation`) VALUES
|
|
('Super Admin'),
|
|
('Admin'),
|
|
('User'),
|
|
('commercial'),
|
|
('caisse');
|
|
|
|
-- Attribution de TOUTES les permissions à TOUS les menus pour le Super Admin
|
|
-- On utilise une sous-requête pour récupérer l'ID réel du rôle Super Admin
|
|
INSERT INTO `role_menu_permissions` (`role_id`, `menu_id`, `permission_id`)
|
|
SELECT r.id, m.id, p.id
|
|
FROM menu m
|
|
CROSS JOIN permissions p
|
|
CROSS JOIN roles r
|
|
WHERE r.designation = 'Super Admin';
|
|
|
|
-- Attribution de permissions basiques pour Admin
|
|
-- Accès en lecture/écriture à la plupart des menus sauf gestion des rôles
|
|
INSERT INTO `role_menu_permissions` (`role_id`, `menu_id`, `permission_id`)
|
|
SELECT r.id, m.id, p.id
|
|
FROM menu m
|
|
CROSS JOIN permissions p
|
|
CROSS JOIN roles r
|
|
WHERE r.designation = 'Admin'
|
|
AND m.name != 'Gérer les rôles'
|
|
AND p.name IN ('view', 'create', 'update', 'read');
|
|
|
|
-- Attribution de permissions basiques pour User
|
|
-- Accès principalement en lecture et quelques actions de base
|
|
INSERT INTO `role_menu_permissions` (`role_id`, `menu_id`, `permission_id`)
|
|
SELECT r.id, m.id, p.id
|
|
FROM menu m
|
|
CROSS JOIN permissions p
|
|
CROSS JOIN roles r
|
|
WHERE r.designation = 'User'
|
|
AND m.name IN ('Accueil', 'Nouvelle commande', 'Gérer les commandes', 'Gestion de stock', 'Historique')
|
|
AND p.name IN ('view', 'read', 'create');
|
|
|
|
-- Attribution de permissions pour Commercial
|
|
-- Accès aux commandes, clients, produits
|
|
INSERT INTO `role_menu_permissions` (`role_id`, `menu_id`, `permission_id`)
|
|
SELECT r.id, m.id, p.id
|
|
FROM menu m
|
|
CROSS JOIN permissions p
|
|
CROSS JOIN roles r
|
|
WHERE r.designation = 'commercial'
|
|
AND m.name IN ('Accueil', 'Nouvelle commande', 'Gérer les commandes', 'Bilan', 'Historique')
|
|
AND p.name IN ('view', 'create', 'update', 'read');
|
|
|
|
-- Attribution de permissions pour Caisse
|
|
-- Accès principalement aux commandes et stock
|
|
INSERT INTO `role_menu_permissions` (`role_id`, `menu_id`, `permission_id`)
|
|
SELECT r.id, m.id, p.id
|
|
FROM menu m
|
|
CROSS JOIN permissions p
|
|
CROSS JOIN roles r
|
|
WHERE r.designation = 'caisse'
|
|
AND m.name IN ('Accueil', 'Nouvelle commande', 'Gestion de stock')
|
|
AND p.name IN ('view', 'create', 'read');
|
|
|
|
-- Insertion du Super Admin par défaut
|
|
-- On utilise une sous-requête pour récupérer l'ID réel du rôle Super Admin
|
|
INSERT INTO `users` (`name`, `lastname`, `email`, `password`, `username`, `role_id`)
|
|
SELECT 'Super', 'Admin', 'superadmin@youmazgestion.com', 'admin123', 'superadmin', r.id
|
|
FROM roles r
|
|
WHERE r.designation = 'Super Admin';
|
|
|
|
-- =====================================================
|
|
-- DONNÉES D'EXEMPLE (OPTIONNEL)
|
|
-- =====================================================
|
|
|
|
-- Insertion d'un point de vente d'exemple
|
|
INSERT INTO `points_de_vente` (`nom`) VALUES ('Magasin Principal');
|
|
|
|
-- Insertion d'un client d'exemple
|
|
INSERT INTO `clients` (`nom`, `prenom`, `email`, `telephone`, `adresse`, `dateCreation`, `actif`) VALUES
|
|
('Dupont', 'Jean', 'jean.dupont@email.com', '0123456789', '123 Rue de la Paix, Paris', NOW(), 1);
|
|
|
|
-- =====================================================
|
|
-- VÉRIFICATIONS
|
|
-- =====================================================
|
|
|
|
-- Afficher les rôles créés
|
|
SELECT 'RÔLES CRÉÉS:' as info;
|
|
SELECT * FROM roles;
|
|
|
|
-- Afficher les permissions créées
|
|
SELECT 'PERMISSIONS CRÉÉES:' as info;
|
|
SELECT * FROM permissions;
|
|
|
|
-- Afficher les menus créés
|
|
SELECT 'MENUS CRÉÉS:' as info;
|
|
SELECT * FROM menu;
|
|
|
|
-- Afficher le Super Admin créé
|
|
SELECT 'SUPER ADMIN CRÉÉ:' as info;
|
|
SELECT u.username, u.email, r.designation as role
|
|
FROM users u
|
|
JOIN roles r ON u.role_id = r.id
|
|
WHERE r.designation = 'Super Admin';
|
|
|
|
-- Vérifier les permissions du Super Admin
|
|
SELECT 'PERMISSIONS SUPER ADMIN:' as info;
|
|
SELECT COUNT(*) as total_permissions_assignees
|
|
FROM role_menu_permissions rmp
|
|
INNER JOIN roles r ON rmp.role_id = r.id
|
|
WHERE r.designation = 'Super Admin';
|
|
|
|
SELECT 'Script terminé avec succès!' as resultat;
|
|
|
|
|
|
|
|
|
|
CREATE TABLE `demandes_transfert` (
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`produit_id` int(11) NOT NULL,
|
|
`point_de_vente_source_id` int(11) NOT NULL,
|
|
`point_de_vente_destination_id` int(11) NOT NULL,
|
|
`demandeur_id` int(11) NOT NULL,
|
|
`validateur_id` int(11) DEFAULT NULL,
|
|
`quantite` int(11) NOT NULL DEFAULT 1,
|
|
`statut` enum('en_attente','validee','refusee') NOT NULL DEFAULT 'en_attente',
|
|
`date_demande` datetime NOT NULL,
|
|
`date_validation` datetime DEFAULT NULL,
|
|
`notes` text DEFAULT NULL,
|
|
PRIMARY KEY (`id`),
|
|
KEY `produit_id` (`produit_id`),
|
|
KEY `point_de_vente_source_id` (`point_de_vente_source_id`),
|
|
KEY `point_de_vente_destination_id` (`point_de_vente_destination_id`),
|
|
KEY `demandeur_id` (`demandeur_id`),
|
|
KEY `validateur_id` (`validateur_id`),
|
|
CONSTRAINT `demandes_transfert_ibfk_1` FOREIGN KEY (`produit_id`) REFERENCES `products` (`id`),
|
|
CONSTRAINT `demandes_transfert_ibfk_2` FOREIGN KEY (`point_de_vente_source_id`) REFERENCES `points_de_vente` (`id`),
|
|
CONSTRAINT `demandes_transfert_ibfk_3` FOREIGN KEY (`point_de_vente_destination_id`) REFERENCES `points_de_vente` (`id`),
|
|
CONSTRAINT `demandes_transfert_ibfk_4` FOREIGN KEY (`demandeur_id`) REFERENCES `users` (`id`),
|
|
CONSTRAINT `demandes_transfert_ibfk_5` FOREIGN KEY (`validateur_id`) REFERENCES `users` (`id`)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|
|
|
|
|
|
|
|
|
|
-- Table pour tracer les sorties de stock personnelles
|
|
CREATE TABLE `sorties_stock_personnelles` (
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`produit_id` int(11) NOT NULL,
|
|
`admin_id` int(11) NOT NULL,
|
|
`quantite` int(11) NOT NULL DEFAULT 1,
|
|
`motif` varchar(500) NOT NULL,
|
|
`date_sortie` datetime NOT NULL,
|
|
`point_de_vente_id` int(11) DEFAULT NULL,
|
|
`notes` text DEFAULT NULL,
|
|
`statut` enum('en_attente','approuvee','refusee') NOT NULL DEFAULT 'en_attente',
|
|
`approbateur_id` int(11) DEFAULT NULL,
|
|
`date_approbation` datetime DEFAULT NULL,
|
|
PRIMARY KEY (`id`),
|
|
KEY `produit_id` (`produit_id`),
|
|
KEY `admin_id` (`admin_id`),
|
|
KEY `point_de_vente_id` (`point_de_vente_id`),
|
|
KEY `approbateur_id` (`approbateur_id`),
|
|
CONSTRAINT `sorties_personnelles_ibfk_1` FOREIGN KEY (`produit_id`) REFERENCES `products` (`id`),
|
|
CONSTRAINT `sorties_personnelles_ibfk_2` FOREIGN KEY (`admin_id`) REFERENCES `users` (`id`),
|
|
CONSTRAINT `sorties_personnelles_ibfk_3` FOREIGN KEY (`point_de_vente_id`) REFERENCES `points_de_vente` (`id`),
|
|
CONSTRAINT `sorties_personnelles_ibfk_4` FOREIGN KEY (`approbateur_id`) REFERENCES `users` (`id`)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
|