Skip to content
Snippets Groups Projects
Commit 87da5c35 authored by Bertrand Gauthier's avatar Bertrand Gauthier
Browse files

Elagage des données : utilisation d'une vue matérialisée pour sélectionner les...

Elagage des données : utilisation d'une vue matérialisée pour sélectionner les données centrales ; ajout d'un delete manuel complémentaire.
parent cb3cc5e8
No related branches found
No related tags found
No related merge requests found
Pipeline #31774 passed
......@@ -2,6 +2,124 @@
-- Elagage de la bdd
----------------------------------------------------------------------------------------------------------
-- insert into db_prune_tmp_central_data_params(table_name, fetch_ids_sql) values ('these',
-- '(select t.id
-- from these t
-- join doctorant d on t.doctorant_id = d.id and d.histo_destruction is null
-- join utilisateur u on u.individu_id = d.individu_id -- usurpable
-- where t.histo_destruction is null
-- and etat_these = ''S''
-- order by date_soutenance desc
-- limit 10)
-- union all
-- (select t.id
-- from these t
-- join doctorant d on t.doctorant_id = d.id and d.histo_destruction is null
-- join utilisateur u on u.individu_id = d.individu_id -- usurpable
-- join attestation a on t.id = a.these_id and a.histo_destruction is null
-- where t.histo_destruction is null
-- and etat_these = ''E''
-- and date_prev_soutenance < current_timestamp + interval ''6 months''
-- order by date_prev_soutenance desc
-- limit 10)'
-- )
-- on conflict on constraint db_prune_tmp_central_data_params_table_name_key
-- do update set fetch_ids_sql = excluded.fetch_ids_sql;
create materialized view mv_demo_these as
WITH doctorant_usurpable(id) AS (SELECT d.id
FROM doctorant d
JOIN utilisateur u ON u.individu_id = d.individu_id
WHERE d.histo_destruction IS NULL)
(SELECT t.id,
'Thèse soutenue, pas de demande de correction'::text AS description
FROM these t
JOIN doctorant_usurpable d ON t.doctorant_id = d.id
WHERE t.histo_destruction IS NULL
AND t.etat_these::text = 'S'::text
AND NOT (EXISTS (SELECT
FROM validation v
JOIN type_validation tv ON v.type_validation_id = tv.id
WHERE tv.code::text = 'CORRECTION_THESE'::text
AND v.histo_destruction IS NULL
AND v.these_id = t.id))
ORDER BY t.date_soutenance DESC
LIMIT 5)
UNION ALL
(SELECT t.id,
'Thèse soutenue, corrections demandées'::text AS description
FROM these t
JOIN doctorant_usurpable d ON t.doctorant_id = d.id
WHERE t.histo_destruction IS NULL
AND t.etat_these::text = 'S'::text
AND (EXISTS (SELECT
FROM validation v
JOIN type_validation tv ON v.type_validation_id = tv.id
WHERE tv.code::text = 'CORRECTION_THESE'::text
AND v.histo_destruction IS NULL
AND v.these_id = t.id))
ORDER BY t.date_soutenance DESC
LIMIT 5)
UNION ALL
(SELECT t.id,
'Thèse en cours, proposition de soutenance non validée'::text AS description
FROM these t
JOIN doctorant_usurpable d ON t.doctorant_id = d.id
WHERE t.histo_destruction IS NULL
AND t.etat_these::text = 'E'::text
AND EXTRACT(year FROM t.date_prem_insc) = (EXTRACT(year FROM CURRENT_TIMESTAMP) - 3::numeric)
AND NOT (EXISTS (SELECT
FROM validation v
JOIN type_validation tv ON v.type_validation_id = tv.id
WHERE tv.code::text = 'PROPOSITION_SOUTENANCE'::text
AND v.histo_destruction IS NULL
AND v.these_id = t.id))
ORDER BY t.date_prem_insc
LIMIT 5)
UNION ALL
(SELECT t.id,
'Thèse soutenue, proposition de soutenance validée, page de couverture validée, Rdv BU non validé'::text AS description
FROM these t
JOIN doctorant_usurpable d ON t.doctorant_id = d.id
WHERE t.histo_destruction IS NULL
AND t.etat_these::text = 'E'::text
AND EXTRACT(year FROM t.date_prem_insc) = (EXTRACT(year FROM CURRENT_TIMESTAMP) - 3::numeric)
AND (EXISTS (SELECT
FROM validation v
JOIN type_validation tv ON v.type_validation_id = tv.id
WHERE tv.code::text = 'PROPOSITION_SOUTENANCE'::text
AND v.histo_destruction IS NULL
AND v.these_id = t.id))
AND (EXISTS (SELECT
FROM validation v
JOIN type_validation tv ON v.type_validation_id = tv.id
WHERE tv.code::text = 'PAGE_DE_COUVERTURE'::text
AND v.histo_destruction IS NULL
AND v.these_id = t.id))
AND NOT (EXISTS (SELECT
FROM validation v
JOIN type_validation tv ON v.type_validation_id = tv.id
WHERE tv.code::text = 'RDV_BU'::text
AND v.histo_destruction IS NULL
AND v.these_id = t.id))
ORDER BY t.date_prem_insc
LIMIT 5);
insert into db_prune_tmp_central_data_params(table_name, fetch_ids_sql) values ('these', 'select id from mv_demo_these')
on conflict on constraint db_prune_tmp_central_data_params_table_name_key
do update set fetch_ids_sql = excluded.fetch_ids_sql;
-- Diminution du volume de données.
call db_prune_tmp_proc_prune();
delete from fichier f
where not exists (
select from fichier_these ft join these t on ft.these_id = t.id
where ft.fichier_id = f.id
) and not exists (
select from admission_document ad
where ad.fichier_id = f.id
) and not exists (
select from rapport rv
where rv.fichier_id = f.id
);
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Please register or to comment