|
|
return: text
|
|
|
lang: plpgsql
|
|
|
src: |
|
|
|
DECLARE
|
|
|
result TEXT;
|
|
|
BEGIN
|
|
|
|
|
|
|
|
|
-- Pour initialiser l'identification des factures sans montant établissement
|
|
|
INSERT INTO activite.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'0ETS',
|
|
|
'Génération ligne facture sans montant établissement',
|
|
|
'0',
|
|
|
'Génération d''une rubrique fictive pour identifier les factures sans montant établissement. 0=Non, 1=Oui '
|
|
|
WHERE '0ETS' NOT IN (SELECT code FROM activite.t_divers);
|
|
|
-- Mise à jour données
|
|
|
IF EXISTS (SELECT *
|
|
|
FROM activite.t_divers
|
|
|
WHERE t_divers.code = '0ETS' AND
|
|
|
t_divers.valeur = '1'
|
|
|
LIMIT 1) THEN
|
|
|
-- Codes Prestations.
|
|
|
INSERT INTO activite.t_prestations (code_original, code, texte, texte_court)
|
|
|
SELECT '*CTI_0ETS', '0ETS', 'Sans facturation établissement', 'Sans facturation établissement'
|
|
|
WHERE '*CTI_0ETS' NOT IN (SELECT code_original FROM activite.t_prestations WHERE code_original IS NOT NULL);
|
|
|
-- Codes Rubriques facturation. Attention à loid si fusion de plusieurs sources
|
|
|
IF NOT EXISTS (SELECT *
|
|
|
FROM activite.t_rubriques_facturation
|
|
|
WHERE t_rubriques_facturation.code_original = '*CTI_0ETS'
|
|
|
LIMIT 1) THEN
|
|
|
PERFORM
|
|
|
setval((sequence_schema||'.'||sequence_name)::regclass,
|
|
|
(SELECT (MAX(ARRAY[CASE WHEN sequence_schema = 'activite' then 0 ELSE 1 END,
|
|
|
nextval((sequence_schema||'.'||sequence_name)::regclass)]))[2]
|
|
|
FROM information_schema.sequences
|
|
|
WHERE sequence_name = 's_rubriques_facturation' AND
|
|
|
sequence_schema LIKE 'activite%'
|
|
|
))
|
|
|
FROM information_schema.sequences
|
|
|
WHERE sequence_name = 's_rubriques_facturation' AND
|
|
|
sequence_schema LIKE 'activite%';
|
|
|
|
|
|
INSERT INTO activite.t_rubriques_facturation(code_original, code, texte, texte_court)
|
|
|
SELECT '*CTI_0ETS', '0ETS', 'Sans facturation établissement', 'Sans facturation établissement'
|
|
|
WHERE '*CTI_0ETS' NOT IN (SELECT code_original FROM activite.t_rubriques_facturation WHERE code_original IS NOT NULL);
|
|
|
PERFORM
|
|
|
setval((sequence_schema||'.'||sequence_name)::regclass,
|
|
|
(SELECT MAX(oid) FROM activite.t_rubriques_facturation WHERE oid < 200000000))
|
|
|
FROM information_schema.sequences
|
|
|
WHERE sequence_name = 's_rubriques_facturation' AND
|
|
|
sequence_schema LIKE 'activite%';
|
|
|
END IF;
|
|
|
|
|
|
RAISE NOTICE '%' , 'RAZ precedente generation';
|
|
|
|
|
|
-- Ajout des lignes
|
|
|
DELETE FROM activite.p_factures_lignes_c
|
|
|
WHERE origine_facturation_id IN (8,9);
|
|
|
|
|
|
|
|
|
-- Identification dates facturées par séjour
|
|
|
RAISE NOTICE '%' , 'Identification dates factures';
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_c_date;
|
|
|
CREATE TEMP TABLE w_factures_lignes_c_date AS
|
|
|
SELECT
|
|
|
p_factures.no_sejour,
|
|
|
p_factures_lignes_c.date_fin,
|
|
|
MIN(p_factures_lignes_c.date_debut) AS date_debut,
|
|
|
SUM(p_factures_lignes_c.montant_facture + p_factures_lignes_c.montant_encours) AS montant
|
|
|
FROM activite.p_factures_lignes_c
|
|
|
JOIN activite.p_factures ON p_factures_lignes_c.no_facture = p_factures.no_facture
|
|
|
JOIN activite.p_sejours ON p_factures.no_sejour = p_sejours.no_sejour
|
|
|
WHERE type_sejour <> '9' AND
|
|
|
p_sejours.est_sans_facturation <> '1'
|
|
|
GROUP BY 1,2
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Identification dates de mouvements
|
|
|
RAISE NOTICE '%' , 'Identification dates mouvements';
|
|
|
DROP TABLE IF EXISTS w_mouvements_sejour_date;
|
|
|
CREATE TEMP TABLE w_mouvements_sejour_date AS
|
|
|
SELECT
|
|
|
p_mouvements_sejour.no_sejour,
|
|
|
p_mouvements_sejour.date,
|
|
|
p_factures_reference.no_facture_reference,
|
|
|
MAX(p_sejours.type_sejour) AS type_sejour,
|
|
|
MAX(p_sejours.code_sorti) AS code_sorti,
|
|
|
MAX(p_factures_reference.facture_reference_id) AS facture_reference_id,
|
|
|
MAX(p_factures_reference.date_debut_facture) AS date_debut_facture,
|
|
|
MAX(p_factures_reference.date_fin_facture) AS date_fin_facture,
|
|
|
MAX(p_factures_reference.code_facture) AS code_facture,
|
|
|
(MAX(Array[heure_fin,lieu_id]))[2]::bigint AS lieu_id
|
|
|
FROM activite.p_mouvements_sejour
|
|
|
JOIN activite.p_sejours ON p_mouvements_sejour.no_sejour = p_sejours.no_sejour
|
|
|
JOIN activite.p_factures_reference ON
|
|
|
p_mouvements_sejour.no_sejour = p_factures_reference.no_sejour AND
|
|
|
p_mouvements_sejour.date BETWEEN p_factures_reference.date_debut_facture AND p_factures_reference.date_fin_facture
|
|
|
WHERE p_sejours.type_sejour <> '9' AND
|
|
|
p_sejours.est_sans_facturation <> '1' AND
|
|
|
p_mouvements_sejour.date <= now() AND
|
|
|
p_factures_reference.no_facture_reference <> ''
|
|
|
GROUP BY 1,2,3
|
|
|
;
|
|
|
|
|
|
ANALYSE w_mouvements_sejour_date;
|
|
|
ANALYSE w_factures_lignes_c_date;
|
|
|
|
|
|
RAISE NOTICE '%' , 'Identification dates manquantes';
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_0ets;
|
|
|
CREATE TEMP TABLE w_factures_lignes_0ets AS
|
|
|
SELECT
|
|
|
w_mouvements_sejour_date.no_facture_reference,
|
|
|
w_mouvements_sejour_date.type_sejour,
|
|
|
w_mouvements_sejour_date.code_sorti,
|
|
|
w_mouvements_sejour_date.facture_reference_id,
|
|
|
w_mouvements_sejour_date.date,
|
|
|
0 AS nb_rubrique,
|
|
|
0 AS nb_prestation,
|
|
|
t_rubriques_facturation.oid AS rubrique_facturation_id,
|
|
|
t_rubriques_facturation.oid AS rubrique_comptabilisation_id,
|
|
|
t_prestations.oid AS prestation_id,
|
|
|
100 AS taux_0,
|
|
|
w_mouvements_sejour_date.lieu_id,
|
|
|
9::bigint AS origine_facturation_id,
|
|
|
CASE WHEN w_mouvements_sejour_date.code_facture = '1' THEN 0.0001 ELSE 0 END AS montant_facture,
|
|
|
CASE WHEN w_mouvements_sejour_date.code_facture <> '1' THEN 0.0001 ELSE 0 END AS montant_encours
|
|
|
FROM w_mouvements_sejour_date
|
|
|
LEFT JOIN w_factures_lignes_c_date ON
|
|
|
w_mouvements_sejour_date.no_sejour = w_factures_lignes_c_date.no_sejour AND
|
|
|
w_mouvements_sejour_date.date BETWEEN w_factures_lignes_c_date.date_debut AND w_factures_lignes_c_date.date_fin
|
|
|
JOIN activite.t_rubriques_facturation ON t_rubriques_facturation.code_original = '*CTI_0ETS'
|
|
|
JOIN activite.t_prestations ON t_prestations.code_original = '*CTI_0ETS'
|
|
|
WHERE w_factures_lignes_c_date.no_sejour IS NULL
|
|
|
;
|
|
|
|
|
|
-- Si la date de fin seule n'est pas facturée, ne pas générer
|
|
|
DELETE FROM w_factures_lignes_0ets
|
|
|
WHERE no_facture_reference IN
|
|
|
(
|
|
|
SELECT w_factures_lignes_0ets.no_facture_reference
|
|
|
FROM w_factures_lignes_0ets
|
|
|
JOIN activite.p_factures_reference ON w_factures_lignes_0ets.no_facture_reference = p_factures_reference.no_facture_reference
|
|
|
WHERE p_factures_reference.date_fin_facture > p_factures_reference.date_debut_facture
|
|
|
GROUP BY 1
|
|
|
having count(*) = SUM(CASE WHEN w_factures_lignes_0ets.date = p_factures_reference.date_fin_facture THEN 1 ELSE 0 END)
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- Ajout des lignes
|
|
|
RAISE NOTICE '%' , 'Ajout dates manquantes';
|
|
|
INSERT INTO activite.p_factures_lignes_c(
|
|
|
no_facture,
|
|
|
facture_id,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
nb_prestation,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
taux_0,
|
|
|
lieu_id,
|
|
|
origine_facturation_id,
|
|
|
montant_facture,
|
|
|
montant_encours
|
|
|
)
|
|
|
SELECT
|
|
|
w_factures_lignes_0ets.no_facture_reference,
|
|
|
w_factures_lignes_0ets.facture_reference_id,
|
|
|
w_factures_lignes_0ets.date,
|
|
|
w_factures_lignes_0ets.date,
|
|
|
w_factures_lignes_0ets.nb_rubrique,
|
|
|
w_factures_lignes_0ets.nb_prestation,
|
|
|
w_factures_lignes_0ets.rubrique_facturation_id,
|
|
|
w_factures_lignes_0ets.rubrique_comptabilisation_id,
|
|
|
w_factures_lignes_0ets.prestation_id,
|
|
|
w_factures_lignes_0ets.taux_0,
|
|
|
w_factures_lignes_0ets.lieu_id,
|
|
|
w_factures_lignes_0ets.origine_facturation_id,
|
|
|
montant_facture,
|
|
|
montant_encours
|
|
|
FROM w_factures_lignes_0ets
|
|
|
|
|
|
;
|
|
|
|
|
|
END IF;
|
|
|
|
|
|
RETURN 'OK';
|
|
|
END;
|