- Structure complète: utilisateurs, parents, assmat, enfants, contrats - Migrations SQL avec enums et contraintes - Seed: 1 super_admin (admin@ptits-pas.fr) - Mot de passe: 4dm1n1strateur (hash bcrypt)
206 lines
7.1 KiB
SQL
206 lines
7.1 KiB
SQL
|
||
-- ============================================================
|
||
-- verify.sql — Jeux de requêtes de vérification (Sprint 1)
|
||
-- Objectifs :
|
||
-- 1) Vérifier l'intégrité fonctionnelle (joins, données seedées)
|
||
-- 2) Détecter rapidement des problèmes d'index/perf (EXPLAIN)
|
||
-- 3) Servir de référence pour le back/front (requêtes typiques)
|
||
--
|
||
-- Usage (Docker) :
|
||
-- docker compose exec -T postgres \
|
||
-- psql -U ${POSTGRES_USER} -d ${POSTGRES_DB} \
|
||
-- -f /docker-entrypoint-initdb.d/tests/verify.sql
|
||
--
|
||
-- Pré-requis :
|
||
-- - 01_init.sql
|
||
-- - 02_indexes.sql
|
||
-- - 03_checks.sql
|
||
-- - 04_fk_policies.sql
|
||
-- - 05_triggers.sql
|
||
-- - 02_seed.sql (pour résultats non vides)
|
||
-- ============================================================
|
||
|
||
\echo '=== 0) Version & horodatage ===================================='
|
||
SELECT version();
|
||
SELECT NOW() AS executed_at;
|
||
|
||
\echo '=== 1) Comptes & répartition par rôle =========================='
|
||
SELECT role, COUNT(*) AS nb
|
||
FROM utilisateurs
|
||
GROUP BY role
|
||
ORDER BY nb DESC;
|
||
|
||
\echo '=== 2) Utilisateurs en attente / acceptés / rejetés ============'
|
||
SELECT statut, COUNT(*) AS nb
|
||
FROM utilisateurs
|
||
GROUP BY statut
|
||
ORDER BY nb DESC;
|
||
|
||
\echo '=== 3) Parents avec co-parents (NULL si pas de co-parent) ======'
|
||
SELECT p.id_utilisateur AS parent_id,
|
||
u.courriel AS parent_email,
|
||
p.id_co_parent,
|
||
uc.courriel AS co_parent_email
|
||
FROM parents p
|
||
JOIN utilisateurs u ON u.id = p.id_utilisateur
|
||
LEFT JOIN utilisateurs uc ON uc.id = p.id_co_parent
|
||
ORDER BY parent_email;
|
||
|
||
\echo '=== 4) Enfants (statut, dates cohérentes) ======================'
|
||
SELECT id, prenom, nom, statut, date_naissance, date_prevue_naissance
|
||
FROM enfants
|
||
ORDER BY nom, prenom;
|
||
|
||
\echo '=== 5) Liaison N:N parents_enfants ============================='
|
||
SELECT ep.id_parent, up.courriel AS parent_email, ep.id_enfant, e.prenom AS enfant
|
||
FROM enfants_parents ep
|
||
JOIN utilisateurs up ON up.id = ep.id_parent
|
||
JOIN enfants e ON e.id = ep.id_enfant
|
||
ORDER BY parent_email, enfant;
|
||
|
||
\echo '=== 6) Dossiers (parent, enfant, statut) ======================='
|
||
SELECT d.id, up.courriel AS parent_email, e.prenom AS enfant, d.statut, d.budget
|
||
FROM dossiers d
|
||
JOIN utilisateurs up ON up.id = d.id_parent
|
||
JOIN enfants e ON e.id = d.id_enfant
|
||
ORDER BY d.cree_le DESC;
|
||
|
||
\echo '=== 7) Messages par dossier (ordre chronologique) =============='
|
||
SELECT m.id, m.id_dossier, m.id_expediteur, ue.courriel AS expediteur_email, m.contenu, m.cree_le
|
||
FROM messages m
|
||
LEFT JOIN utilisateurs ue ON ue.id = m.id_expediteur
|
||
ORDER BY m.id_dossier, m.cree_le;
|
||
|
||
\echo '=== 8) Contrats 1:1 avec dossier + avenants ===================='
|
||
SELECT c.id AS contrat_id, c.id_dossier, c.statut,
|
||
COUNT(a.id) AS nb_avenants
|
||
FROM contrats c
|
||
LEFT JOIN avenants_contrats a ON a.id_contrat = c.id
|
||
GROUP BY c.id, c.id_dossier, c.statut
|
||
ORDER BY c.cree_le DESC;
|
||
|
||
\echo '=== 9) Evénements par enfant (30 derniers jours) =============='
|
||
SELECT ev.id, ev.type, ev.id_enfant, e.prenom AS enfant, ev.date_debut, ev.date_fin, ev.statut
|
||
FROM evenements ev
|
||
JOIN enfants e ON e.id = ev.id_enfant
|
||
WHERE ev.date_debut >= (NOW()::date - INTERVAL '30 days')
|
||
ORDER BY ev.date_debut DESC;
|
||
|
||
\echo '=== 10) Uploads & notifications récentes ======================='
|
||
SELECT u.courriel, up.fichier_url, up.type_fichier, up.cree_le
|
||
FROM uploads up
|
||
LEFT JOIN utilisateurs u ON u.id = up.id_utilisateur
|
||
ORDER BY up.cree_le DESC;
|
||
|
||
SELECT u.courriel, n.type, n.contenu, n.lu, n.cree_le
|
||
FROM notifications n
|
||
LEFT JOIN utilisateurs u ON u.id = n.id_utilisateur
|
||
ORDER BY n.cree_le DESC;
|
||
|
||
\echo '=== 11) Validations (qui a validé quoi) ========================'
|
||
SELECT v.id, uu.courriel AS utilisateur_valide,
|
||
uv.courriel AS valide_par, v.statut, v.commentaire, v.cree_le
|
||
FROM validations v
|
||
LEFT JOIN utilisateurs uu ON uu.id = v.id_utilisateur
|
||
LEFT JOIN utilisateurs uv ON uv.id = v.valide_par
|
||
ORDER BY v.cree_le DESC;
|
||
|
||
-- ============================================================
|
||
-- Vérifications d'intégrité (requêtes de contrôle)
|
||
-- ============================================================
|
||
\echo '=== 12) Orphelins potentiels (doivent renvoyer 0 ligne) ======='
|
||
|
||
-- Messages orphelins (dossier manquant)
|
||
SELECT m.*
|
||
FROM messages m
|
||
LEFT JOIN dossiers d ON d.id = m.id_dossier
|
||
WHERE d.id IS NULL;
|
||
|
||
-- Liaisons enfants_parents orphelines
|
||
SELECT ep.*
|
||
FROM enfants_parents ep
|
||
LEFT JOIN parents p ON p.id_utilisateur = ep.id_parent
|
||
LEFT JOIN enfants e ON e.id = ep.id_enfant
|
||
WHERE p.id_utilisateur IS NULL OR e.id IS NULL;
|
||
|
||
-- Contrats sans dossier
|
||
SELECT c.*
|
||
FROM contrats c
|
||
LEFT JOIN dossiers d ON d.id = c.id_dossier
|
||
WHERE d.id IS NULL;
|
||
|
||
-- Avenants sans contrat
|
||
SELECT a.*
|
||
FROM avenants_contrats a
|
||
LEFT JOIN contrats c ON c.id = a.id_contrat
|
||
WHERE c.id IS NULL;
|
||
|
||
-- Evénements sans enfant
|
||
SELECT ev.*
|
||
FROM evenements ev
|
||
LEFT JOIN enfants e ON e.id = ev.id_enfant
|
||
WHERE e.id IS NULL;
|
||
|
||
\echo '=== 13) Performance : EXPLAIN sur requêtes clés ==============='
|
||
|
||
-- Messages par dossier (doit utiliser idx_messages_id_dossier_cree_le)
|
||
EXPLAIN ANALYZE
|
||
SELECT m.*
|
||
FROM messages m
|
||
WHERE m.id_dossier = 'dddddddd-dddd-dddd-dddd-dddddddddddd'
|
||
ORDER BY m.cree_le DESC
|
||
LIMIT 20;
|
||
|
||
-- Evénements par enfant et période (idx_evenements_id_enfant_date_debut)
|
||
EXPLAIN ANALYZE
|
||
SELECT ev.*
|
||
FROM evenements ev
|
||
WHERE ev.id_enfant = 'aaaaaaaa-aaaa-aaaa-aaaa-aaaaaaaaaaaa'
|
||
AND ev.date_debut >= '2025-01-01';
|
||
|
||
-- Notifications non lues (idx_notifications_user_lu_cree_le)
|
||
EXPLAIN ANALYZE
|
||
SELECT n.*
|
||
FROM notifications n
|
||
WHERE n.id_utilisateur = '33333333-3333-3333-3333-333333333333'
|
||
AND n.lu = false
|
||
ORDER BY n.cree_le DESC
|
||
LIMIT 20;
|
||
|
||
-- Dossiers par parent/enfant (idx_dossiers_id_parent/id_enfant/statut)
|
||
EXPLAIN ANALYZE
|
||
SELECT d.*
|
||
FROM dossiers d
|
||
WHERE d.id_parent = '33333333-3333-3333-3333-333333333333'
|
||
AND d.id_enfant = 'aaaaaaaa-aaaa-aaaa-aaaa-aaaaaaaaaaaa'
|
||
ORDER BY d.cree_le DESC;
|
||
|
||
\echo '=== 14) JSONB : exemples de filtrage ==========================='
|
||
-- Recherche de dossiers où planning_souhaite contient midi=true un jour ouvré
|
||
-- (Index GIN recommandé si usage intensif : cf. 02_indexes.sql)
|
||
SELECT d.id, d.planning_souhaite
|
||
FROM dossiers d
|
||
WHERE d.planning_souhaite @> '{"lun_ven":{"midi":true}}';
|
||
|
||
-- Contrats : présence d’un créneau donné
|
||
SELECT c.id, c.planning
|
||
FROM contrats c
|
||
WHERE c.planning @> '{"lun_ven":{"17h-19h":true}}';
|
||
|
||
\echo '=== 15) Sanity check final ===================================='
|
||
-- Quelques totaux utiles
|
||
SELECT
|
||
(SELECT COUNT(*) FROM utilisateurs) AS nb_utilisateurs,
|
||
(SELECT COUNT(*) FROM parents) AS nb_parents,
|
||
(SELECT COUNT(*) FROM assistantes_maternelles) AS nb_am,
|
||
(SELECT COUNT(*) FROM enfants) AS nb_enfants,
|
||
(SELECT COUNT(*) FROM enfants_parents) AS nb_liens_parent_enfant,
|
||
(SELECT COUNT(*) FROM dossiers) AS nb_dossiers,
|
||
(SELECT COUNT(*) FROM messages) AS nb_messages,
|
||
(SELECT COUNT(*) FROM contrats) AS nb_contrats,
|
||
(SELECT COUNT(*) FROM avenants_contrats) AS nb_avenants,
|
||
(SELECT COUNT(*) FROM evenements) AS nb_evenements,
|
||
(SELECT COUNT(*) FROM uploads) AS nb_uploads,
|
||
(SELECT COUNT(*) FROM notifications) AS nb_notifications,
|
||
(SELECT COUNT(*) FROM validations) AS nb_validations;
|