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.
 
 

281 lines
13 KiB

return: text
lang: plpgsql
src: |
DECLARE
_marge_erreur numeric;
_ignorer_reglements text;
result TEXT;
BEGIN
RAISE NOTICE 'Initialisations';
-- marge de validation automatique
INSERT INTO activite.t_divers (code, texte, valeur, description, valeur2)
SELECT
'CHIFERRMAX',
'Marge d'' erreur pour validation automatique chiffrier',
'0',
'Montant',
''
WHERE 'CHIFERRMAX' NOT IN (SELECT code FROM activite.t_divers);
_marge_erreur = base.cti_to_number((SELECT valeur FROM activite.t_divers WHERE code = 'CHIFERRMAX')) ;
-- Controle des règlements ?
INSERT INTO activite.t_divers (code, texte, valeur, description, valeur2)
SELECT
'CHIFERRREG',
'Ignorer les règlements pour la validation automatique',
'0',
'0=Tenir compte des règlements, 1=Ignorer',
''
WHERE 'CHIFERRREG' NOT IN (SELECT code FROM activite.t_divers);
_ignorer_reglements = (SELECT valeur FROM activite.t_divers WHERE code = 'CHIFERRREG') ;
-- Ne pas controler le mois en cours;
UPDATE activite.p_chiffrier_comptable
SET montant_ventes_c = 0,
montant_ventes_h = 0,
montant_reglements_c = 0,
montant_reglements_h = 0
WHERE date_comptable >= date(date_trunc('month', now()));
-- table de travail
DROP TABLE IF EXISTS w_chiffrier_comptable;
CREATE TEMP TABLE w_chiffrier_comptable
(
date_comptable date,
provider_id bigint,
montant_comptabilise_d_c numeric(13,2) DEFAULT 0,
montant_comptabilise_t_c numeric(13,2) DEFAULT 0,
montant_comptabilise_s_c numeric(13,2) DEFAULT 0,
montant_comptabilise_c_c numeric(13,2) DEFAULT 0,
montant_regle_s_c numeric(13,2) DEFAULT 0,
montant_regle_c_c numeric(13,2) DEFAULT 0,
montant_comptabilise_d_h numeric(13,2) DEFAULT 0,
montant_comptabilise_t_h numeric(13,2) DEFAULT 0,
montant_comptabilise_s_h numeric(13,2) DEFAULT 0,
montant_comptabilise_c_h numeric(13,2) DEFAULT 0,
montant_regle_s_h numeric(13,2) DEFAULT 0,
montant_regle_c_h numeric(13,2) DEFAULT 0
) ;
RAISE NOTICE 'Lignes facturées CLINIQUE';
INSERT INTO w_chiffrier_comptable(date_comptable, provider_id, montant_comptabilise_d_c)
SELECT date_trunc('month',p_factures.date_vente) AS date_comptable, p_factures.provider_id,
SUM(p_factures_lignes_c.montant_comptabilise) AS montant_comptabilise_d_c
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 AND p_sejours.etat = ''
WHERE p_factures.date_vente BETWEEN '20090101' AND date(now()) AND
p_factures.code_vente = '1'
GROUP BY 1,2;
RAISE NOTICE 'Lignes facturées HONORAIRES';
INSERT INTO w_chiffrier_comptable(date_comptable, provider_id, montant_comptabilise_d_h)
SELECT date_trunc('month',p_factures.date_vente) AS date_comptable, p_factures.provider_id,
SUM(p_factures_lignes_h.montant_comptabilise) AS montant_comptabilise_d_h
FROM activite.p_factures_lignes_h
JOIN activite.p_factures ON p_factures_lignes_h.no_facture = p_factures.no_facture
JOIN activite.p_sejours ON p_factures.no_sejour = p_sejours.no_sejour AND p_sejours.etat = ''
WHERE date_vente BETWEEN '20090101' AND date(now()) AND
p_factures.code_vente = '1'
GROUP BY 1,2;
RAISE NOTICE 'Factures';
INSERT INTO w_chiffrier_comptable(date_comptable, provider_id, montant_comptabilise_t_c, montant_comptabilise_t_h)
SELECT date_trunc('month',date_vente) AS date_comptable, p_factures.provider_id,
SUM(p_factures.montant_comptabilise_c) AS montant_comptabilise_t_c,
SUM(p_factures.montant_comptabilise_h) AS montant_comptabilise_t_h
FROM activite.p_factures
JOIN activite.p_sejours ON p_factures.no_sejour = p_sejours.no_sejour AND p_sejours.etat = ''
WHERE date_vente BETWEEN '20090101' AND date(now()) AND
code_vente = '1'
GROUP BY 1,2;
RAISE NOTICE 'Comptabilisation CLINIQUE';
INSERT INTO w_chiffrier_comptable(date_comptable, provider_id, montant_comptabilise_s_c, montant_regle_s_c)
SELECT date_trunc('month',p_facture_solde_tiers_c.date_comptable) AS date_comptable, p_factures.provider_id,
SUM(CASE WHEN p_factures.code_vente = '1' THEN montant_comptabilise ELSE 0 END) AS montant_comptabilise_s_c,
SUM(CASE WHEN od_avoir <> '1' AND od_non_comptabilise IS DISTINCT FROM '1' THEN montant_regle ELSE 0 END) AS montant_regle_s_c
FROM activite.p_facture_solde_tiers_c
JOIN activite.p_factures ON p_facture_solde_tiers_c.no_facture = p_factures.no_facture
JOIN activite.p_sejours ON p_factures.no_sejour = p_sejours.no_sejour AND p_sejours.etat = ''
WHERE date_comptable BETWEEN '20090101' AND date(now())
GROUP BY 1,2 ;
RAISE NOTICE 'Comptabilisation HONORAIRE';
INSERT INTO w_chiffrier_comptable(date_comptable, provider_id, montant_comptabilise_s_h, montant_regle_s_h)
SELECT date_trunc('month',date_comptable) AS date_comptable, p_factures.provider_id,
SUM(CASE WHEN p_factures.code_vente = '1' THEN montant_comptabilise ELSE 0 END) AS montant_comptabilise_s_h,
SUM(CASE WHEN od_avoir <> '1' AND od_non_comptabilise IS DISTINCT FROM '1' THEN montant_regle ELSE 0 END) AS montant_regle_s_h
FROM activite.p_factures_soldes_h
JOIN activite.p_factures ON p_factures_soldes_h.no_facture = p_factures.no_facture
JOIN activite.p_sejours ON p_factures.no_sejour = p_sejours.no_sejour AND p_sejours.etat = ''
WHERE date_comptable BETWEEN '20090101' AND date(now())
GROUP BY 1,2 ;
RAISE NOTICE 'Chiffrier production';
INSERT INTO w_chiffrier_comptable(date_comptable, provider_id, montant_comptabilise_c_c, montant_comptabilise_c_h, montant_regle_c_c, montant_regle_c_h)
SELECT date_trunc('month',date_comptable) AS date_comptable, provider_id,
SUM(montant_ventes_c) AS montant_comptabilise_c_c,
SUM(montant_ventes_h) AS montant_comptabilise_c_h,
SUM(montant_reglements_c) AS montant_regle_c_c,
SUM(montant_reglements_h) AS montant_regle_c_h
FROM activite.p_chiffrier_comptable
WHERE date_comptable BETWEEN '20090101' AND date(now())
GROUP BY 1,2 ;
RAISE NOTICE 'Controles';
DROP TABLE IF EXISTS w_controle_chiffrier;
CREATE TEMP TABLE w_controle_chiffrier AS
SELECT
date_comptable AS w_date_comptable,
COALESCE(provider_id,0) AS w_provider_id,
SUM(montant_comptabilise_d_c) AS w_montant_comptabilise_d_c,
SUM(montant_comptabilise_t_c) AS w_montant_comptabilise_t_c,
SUM(montant_comptabilise_s_c) AS w_montant_comptabilise_s_c,
SUM(montant_comptabilise_c_c) AS w_montant_comptabilise_c_c,
SUM(montant_regle_s_c) AS w_montant_regle_s_c,
SUM(montant_regle_c_c) AS w_montant_regle_c_c,
SUM(montant_comptabilise_d_h) AS w_montant_comptabilise_d_h,
SUM(montant_comptabilise_t_h) AS w_montant_comptabilise_t_h,
SUM(montant_comptabilise_s_h) AS w_montant_comptabilise_s_h,
SUM(montant_comptabilise_c_h) AS w_montant_comptabilise_c_h,
SUM(montant_regle_s_h) AS w_montant_regle_s_h,
SUM(montant_regle_c_h) AS w_montant_regle_c_h
FROM w_chiffrier_comptable
GROUP BY 1,2;
-- Suppression lignes antérieures (si changement de date début)
DELETE
FROM activite.t_controle_chiffrier
WHERE date_comptable < (SELECT date(MIN(date_trunc('month',date_comptable))) FROM activite.p_chiffrier_comptable);
-- Ajout nouvelles lignes
INSERT INTO activite.t_controle_chiffrier
(date_comptable,
provider_id,
montant_comptabilise_d_c,
montant_comptabilise_t_c,
montant_comptabilise_s_c,
montant_comptabilise_c_c,
montant_regle_s_c,
montant_regle_c_c,
montant_comptabilise_d_h,
montant_comptabilise_t_h,
montant_comptabilise_s_h,
montant_comptabilise_c_h,
montant_regle_s_h,
montant_regle_c_h,
valide
)
SELECT
w_date_comptable,
w_provider_id,
w_montant_comptabilise_d_c,
w_montant_comptabilise_t_c,
w_montant_comptabilise_s_c,
w_montant_comptabilise_c_c,
w_montant_regle_s_c,
w_montant_regle_c_c,
w_montant_comptabilise_d_h,
w_montant_comptabilise_t_h,
w_montant_comptabilise_s_h,
w_montant_comptabilise_c_h,
w_montant_regle_s_h,
w_montant_regle_c_h,
CASE WHEN w_montant_comptabilise_d_c <> w_montant_comptabilise_t_c OR
w_montant_comptabilise_s_c <> w_montant_comptabilise_s_c OR
w_montant_comptabilise_d_c <> w_montant_comptabilise_c_c AND w_montant_comptabilise_c_c <> 0 OR
w_montant_regle_s_c <> w_montant_regle_c_c AND w_montant_regle_c_c <> 0 OR
w_montant_comptabilise_d_h <> w_montant_comptabilise_t_h OR
w_montant_comptabilise_s_h <> w_montant_comptabilise_s_h OR
w_montant_comptabilise_d_h <> w_montant_comptabilise_c_h AND w_montant_comptabilise_c_c <> 0 OR
w_montant_regle_s_h <> w_montant_regle_c_h AND w_montant_regle_c_h <> 0 THEN 0 ELSE 1 END
FROM w_controle_chiffrier
LEFT JOIN activite.t_controle_chiffrier ON w_date_comptable = date_comptable AND w_provider_id = provider_id
WHERE date_comptable IS NULL;
UPDATE activite.t_controle_chiffrier SET
montant_comptabilise_d_c = w_montant_comptabilise_d_c,
montant_comptabilise_t_c = w_montant_comptabilise_t_c,
montant_comptabilise_s_c = w_montant_comptabilise_s_c,
montant_comptabilise_c_c = w_montant_comptabilise_c_c,
montant_regle_s_c = w_montant_regle_s_c,
montant_regle_c_c = w_montant_regle_c_c,
montant_comptabilise_d_h = w_montant_comptabilise_d_h,
montant_comptabilise_t_h = w_montant_comptabilise_t_h,
montant_comptabilise_s_h = w_montant_comptabilise_s_h,
montant_comptabilise_c_h = w_montant_comptabilise_c_h,
montant_regle_s_h = w_montant_regle_s_h,
montant_regle_c_h = w_montant_regle_c_h,
valide = CASE WHEN w_montant_comptabilise_d_c <> w_montant_comptabilise_t_c OR
w_montant_comptabilise_s_c <> w_montant_comptabilise_s_c OR
w_montant_comptabilise_d_c <> w_montant_comptabilise_c_c AND w_montant_comptabilise_c_c <> 0 OR
w_montant_regle_s_c <> w_montant_regle_c_c AND w_montant_regle_c_c <> 0 OR
w_montant_comptabilise_d_h <> w_montant_comptabilise_t_h OR
w_montant_comptabilise_s_h <> w_montant_comptabilise_s_h OR
w_montant_comptabilise_d_h <> w_montant_comptabilise_c_h AND w_montant_comptabilise_c_c <> 0 OR
w_montant_regle_s_h <> w_montant_regle_c_h AND w_montant_regle_c_h <> 0 THEN 0 ELSE 1 END
FROM w_controle_chiffrier
WHERE w_date_comptable = date_comptable AND w_provider_id = provider_id
AND (
montant_comptabilise_d_c IS DISTINCT FROM w_montant_comptabilise_d_c OR
montant_comptabilise_t_c IS DISTINCT FROM w_montant_comptabilise_t_c OR
montant_comptabilise_s_c IS DISTINCT FROM w_montant_comptabilise_s_c OR
montant_comptabilise_c_c IS DISTINCT FROM w_montant_comptabilise_c_c OR
montant_regle_s_c IS DISTINCT FROM w_montant_regle_s_c OR
montant_regle_c_c IS DISTINCT FROM w_montant_regle_c_c OR
montant_comptabilise_d_h IS DISTINCT FROM w_montant_comptabilise_d_h OR
montant_comptabilise_t_h IS DISTINCT FROM w_montant_comptabilise_t_h OR
montant_comptabilise_s_h IS DISTINCT FROM w_montant_comptabilise_s_h OR
montant_comptabilise_c_h IS DISTINCT FROM w_montant_comptabilise_c_h OR
montant_regle_s_h IS DISTINCT FROM w_montant_regle_s_h OR
montant_regle_c_h IS DISTINCT FROM w_montant_regle_c_h
);
UPDATE activite.t_controle_chiffrier
SET valide = 1
WHERE valide <> 1 AND
NOT
(montant_comptabilise_d_c IS DISTINCT FROM montant_comptabilise_c_c AND montant_comptabilise_c_c <> 0 OR
montant_comptabilise_t_c IS DISTINCT FROM montant_comptabilise_c_c AND montant_comptabilise_c_c <> 0 OR
montant_comptabilise_s_c IS DISTINCT FROM montant_comptabilise_c_c AND montant_comptabilise_c_c <> 0 OR
montant_comptabilise_c_c IS DISTINCT FROM montant_comptabilise_c_c AND montant_comptabilise_c_c <> 0 OR
montant_regle_s_c IS DISTINCT FROM montant_regle_c_c AND montant_regle_c_c <> 0 OR
montant_comptabilise_d_h IS DISTINCT FROM montant_comptabilise_c_h AND montant_comptabilise_c_h <> 0 OR
montant_comptabilise_t_h IS DISTINCT FROM montant_comptabilise_c_h AND montant_comptabilise_c_h <> 0 OR
montant_comptabilise_s_h IS DISTINCT FROM montant_comptabilise_c_h AND montant_comptabilise_c_h <> 0 OR
montant_comptabilise_c_h IS DISTINCT FROM montant_comptabilise_c_h AND montant_comptabilise_c_h <> 0 OR
montant_regle_s_h IS DISTINCT FROM montant_regle_c_h AND montant_regle_c_h <> 0
) OR
(CASE WHEN montant_comptabilise_c_c <> 0 THEN
ABS(montant_comptabilise_d_c - montant_comptabilise_c_c) +
ABS(montant_comptabilise_t_c - montant_comptabilise_c_c) +
ABS(montant_comptabilise_s_c - montant_comptabilise_c_c)
ELSE
0
END
+
CASE WHEN montant_comptabilise_c_h <> 0 THEN
ABS(montant_comptabilise_d_h - montant_comptabilise_c_h) +
ABS(montant_comptabilise_t_h - montant_comptabilise_c_h) +
ABS(montant_comptabilise_s_h - montant_comptabilise_c_h)
ELSE
0
END
+
CASE WHEN montant_regle_c_c <> 0 AND _ignorer_reglements IS DISTINCT FROM '1' THEN
ABS(montant_regle_s_c - montant_regle_c_c)
ELSE
0
END
+
CASE WHEN montant_regle_c_h <> 0 AND _ignorer_reglements IS DISTINCT FROM '1' THEN
ABS(montant_regle_s_h - montant_regle_c_h)
ELSE
0
END
) <= _marge_erreur
;
RETURN 'OK';
END;