|
|
<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
|
<ROOT>
|
|
|
|
|
|
|
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
|
|
|
|
<NODE label="Identification des séjours">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_DOSSIERS_atraiter;
|
|
|
|
|
|
CREATE TEMP TABLE w_DOSSIERS_atraiter AS
|
|
|
SELECT NDOSSIER AS NDOSSIER_T,
|
|
|
''::text AS type_sejour_force,
|
|
|
SUBSTR(to_char(NDOSSIER,'FM00000000'),1,1) AS prefixe,
|
|
|
''::text AS type_sejour_defaut
|
|
|
FROM prod_qsp.DOSSIER
|
|
|
WHERE DOSSIER.DATE_ENTREE BETWEEN '[ENV_ADM_ANNEEDEBUT]0101' AND now() AND date_sortie IS NULL OR date_sortie BETWEEN '[ENV_ADM_ANNEEDEBUT]0101' AND now() + interval '1 year';
|
|
|
|
|
|
ALTER TABLE w_DOSSIERS_atraiter
|
|
|
ADD CONSTRAINT w_DOSSIERS_atraiter_pk_ndossier PRIMARY KEY(NDOSSIER_T);
|
|
|
|
|
|
INSERT INTO w_DOSSIERS_atraiter
|
|
|
SELECT FACTURE.N_HOSPI,
|
|
|
''::text AS type_sejour_force,
|
|
|
SUBSTR(to_char(FACTURE.N_HOSPI,'FM00000000'),1,1) AS prefixe,
|
|
|
''::text AS type_sejour_defaut
|
|
|
FROM prod_qsp.FACTURE
|
|
|
JOIN prod_qsp.HOSPI ON FACTURE.N_HOSPI= HOSPI.N_HOSPI
|
|
|
LEFT JOIN w_DOSSIERS_atraiter ON FACTURE.N_HOSPI = NDOSSIER_T
|
|
|
WHERE DT_FACT >= '[ENV_ADM_ANNEEDEBUT]0101' AND NDOSSIER_T IS NULL
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
INSERT INTO w_DOSSIERS_atraiter
|
|
|
SELECT VENTIL_PAIEMENT.N_HOSPI,
|
|
|
''::text AS type_sejour_force,
|
|
|
SUBSTR(to_char(VENTIL_PAIEMENT.N_HOSPI,'FM00000000'),1,1) AS prefixe,
|
|
|
''::text AS type_sejour_defaut
|
|
|
FROM prod_qsp.VENTIL_PAIEMENT
|
|
|
JOIN prod_qsp.HOSPI ON VENTIL_PAIEMENT.N_HOSPI= HOSPI.N_HOSPI
|
|
|
LEFT JOIN w_DOSSIERS_atraiter ON VENTIL_PAIEMENT.N_HOSPI = NDOSSIER_T
|
|
|
WHERE DT_VENT >= '[ENV_ADM_ANNEEDEBUT]0101' AND NDOSSIER_T IS NULL AND TRANS_CPTA <> 0
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
-- Type de séjour forcé selon actes saisis
|
|
|
DROP TABLE IF EXISTS w_DOSSIER_type;
|
|
|
CREATE TEMP TABLE w_DOSSIER_type AS
|
|
|
SELECT SAISIE.N_HOSPI,
|
|
|
CASE
|
|
|
WHEN SUM(CASE WHEN CODE_NORM IN ('GHS','PJ','FJ') THEN QTE ELSE 0 END) > 0 THEN '12'
|
|
|
WHEN SUM(CASE WHEN CODE_NORM IN ('D09','D10','D11','D12','D13') THEN QTE ELSE 0 END) > 0 THEN '5'
|
|
|
WHEN SUM(CASE WHEN CODE_NORM IN ('SE1','SE2','SE3','SE4','SE5', 'SE6', 'SE7','ATU', 'FPU','FFM') THEN QTE ELSE 0 END) > 0 THEN '3'
|
|
|
ELSE '' END AS type_sejour_selon_saisie
|
|
|
FROM prod_qsp.SAISIE
|
|
|
JOIN w_DOSSIERS_atraiter ON SAISIE.N_HOSPI = NDOSSIER_T
|
|
|
JOIN prod_qsp.PRESTATION ON SAISIE.CODE_PREST = PRESTATION.CODE_PREST
|
|
|
WHERE SUPPRIME <> 1
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
UPDATE w_DOSSIERS_atraiter
|
|
|
SET type_sejour_force = type_sejour_selon_saisie
|
|
|
FROM w_DOSSIER_type
|
|
|
WHERE w_DOSSIER_type.N_HOSPI = NDOSSIER_T AND
|
|
|
type_sejour_selon_saisie <> ''
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_DOSSIERS_atraiter
|
|
|
SET type_sejour_defaut = t_divers.valeur
|
|
|
FROM activite.t_divers
|
|
|
WHERE t_divers.code = 'QSP_TYPESEJ_'||prefixe AND
|
|
|
type_sejour_force = '' AND
|
|
|
t_divers.valeur <> ''
|
|
|
;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Détection modifications">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Forcage etage selon lit
|
|
|
DROP TABLE IF EXISTS w_lit_force;
|
|
|
CREATE TEMP TABLE w_lit_force AS
|
|
|
SELECT t_etages.code_original AS etage_code,
|
|
|
etage_id, string_to_array(replace(replace(lit_force,'*','%'),' ',''),',') AS lit_force_array
|
|
|
FROM activite[PX].t_etages_historique
|
|
|
JOIN activite[PX].t_etages ON etage_id = t_etages.oid
|
|
|
WHERE trim(lit_force) <> '';
|
|
|
|
|
|
UPDATE cti_histolit
|
|
|
SET C_SECT = etage_code
|
|
|
FROM w_lit_force
|
|
|
WHERE NUM_LIT ILIKE ANY (lit_force_array);
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Correction des dates actes hors séjour">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- En premier lieu, correction des dates de sortie si antérieures aux dates d'entre ou trop éloignées dans le futur
|
|
|
UPDATE prod_qsp.DOSSIER SET
|
|
|
DATE_SORTIE = DATE_ENTREE
|
|
|
WHERE
|
|
|
(date_trunc('day', DATE_SORTIE) < date_trunc('day', DATE_ENTREE)) OR (DATE_SORTIE > now() + interval '5 year');
|
|
|
|
|
|
UPDATE prod_qsp.SAISIE
|
|
|
SET D_DEB = date(DATE_SORTIE), D_FIN = date(DATE_SORTIE)
|
|
|
FROM prod_qsp.DOSSIER
|
|
|
WHERE SAISIE.N_HOSPI = DOSSIER.NDOSSIER AND
|
|
|
date(D_DEB) > date(DATE_SORTIE) AND
|
|
|
DATE_SORTIE IS NOT NULL AND QTE = 1
|
|
|
;
|
|
|
UPDATE prod_qsp.SAISIE
|
|
|
SET D_DEB = date(DATE_ENTREE), D_FIN = date(DATE_ENTREE)
|
|
|
FROM prod_qsp.DOSSIER
|
|
|
WHERE SAISIE.N_HOSPI = DOSSIER.NDOSSIER AND
|
|
|
date(D_DEB) < date(DATE_ENTREE) AND QTE = 1
|
|
|
;
|
|
|
UPDATE prod_qsp.SAISIE
|
|
|
SET D_FIN = date(DATE_SORTIE)
|
|
|
FROM prod_qsp.DOSSIER
|
|
|
WHERE SAISIE.N_HOSPI = DOSSIER.NDOSSIER AND
|
|
|
date(D_FIN) > date(DATE_SORTIE) AND
|
|
|
DATE_SORTIE IS NOT NULL
|
|
|
;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="SEJOUR" label="RECUPERATION DES SEJOURS">
|
|
|
|
|
|
<NODE label="Patients">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
INSERT INTO activite[PX].p_patients(finess, no_patient, nom, nom_naissance, prenom, date_naissance)
|
|
|
SELECT DISTINCT '', npatient, NOM_PAT, MAR_PAT, PRE_PAT, base.date(nai_pat)
|
|
|
FROM prod_qsp.patient
|
|
|
LEFT JOIN activite[PX].p_patients ON (npatient = p_patients.no_patient)
|
|
|
WHERE p_patients.no_patient IS NULL;
|
|
|
|
|
|
UPDATE activite[PX].p_patients
|
|
|
SET
|
|
|
nom = NOM_PAT,
|
|
|
nom_naissance = MAR_PAT,
|
|
|
prenom = PRE_PAT,
|
|
|
date_naissance = base.date(nai_pat)
|
|
|
FROM prod_qsp.PATIENT
|
|
|
WHERE p_patients.no_patient = npatient
|
|
|
AND (
|
|
|
nom IS DISTINCT FROM NOM_PAT OR
|
|
|
nom_naissance IS DISTINCT FROM MAR_PAT OR
|
|
|
prenom IS DISTINCT FROM PRE_PAT OR
|
|
|
date_naissance IS DISTINCT FROM base.date(nai_pat)
|
|
|
);
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Séjours">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_HISTOLIT_SERVICE;
|
|
|
CREATE TEMP TABLE w_HISTOLIT_SERVICE AS
|
|
|
SELECT NDOSSIER, MAX(C_SERV_CTI) AS C_SERV_CTI
|
|
|
,MAX(C_UF_CTI) AS C_UF_CTI
|
|
|
,MAX(MODE_TRAIT_CTI) AS MODE_TRAIT_CTI
|
|
|
FROM cti_histolit
|
|
|
GROUP BY 1;
|
|
|
|
|
|
CREATE INDEX w_HISTOLIT_SERVICE_i1
|
|
|
ON w_HISTOLIT_SERVICE
|
|
|
USING btree
|
|
|
(NDOSSIER);
|
|
|
|
|
|
CREATE INDEX w_HISTOLIT_SERVICE_i2
|
|
|
ON w_HISTOLIT_SERVICE
|
|
|
USING btree
|
|
|
(C_SERV_CTI);
|
|
|
|
|
|
CREATE INDEX w_HISTOLIT_SERVICE_i3
|
|
|
ON w_HISTOLIT_SERVICE
|
|
|
USING btree
|
|
|
(C_SERV_CTI);
|
|
|
|
|
|
DROP TABLE IF EXISTS W_PMSI_RESULT;
|
|
|
CREATE TEMP TABLE W_PMSI_RESULT AS
|
|
|
SELECT
|
|
|
PMSI_RESULT.NDOSSIER,
|
|
|
MAX(COALESCE(t_ghs.oid,0)) AS ghs_id,
|
|
|
MAX(COALESCE(t_ghm.oid,0)) AS ghm_id,
|
|
|
date(MAX(COALESCE(PMSI_RESULT.DATE_SAIS,'20991231'))) AS date_groupage,
|
|
|
(MIN(ARRAY[PMSI_RUM.N_RUM::text, substr(PMSI_RUM.MODE_ENT, 1,1)::text]))[2] as mode_entree,
|
|
|
(MIN(ARRAY[PMSI_RUM.N_RUM::text, substr(PMSI_RUM.MODE_ENT, 2,1)::text]))[2] as provenance,
|
|
|
(MAX(ARRAY[PMSI_RUM.N_RUM::text, substr(PMSI_RUM.MODE_SOR, 1,1)::text]))[2] as mode_sortie,
|
|
|
(MAX(ARRAY[PMSI_RUM.N_RUM::text, substr(PMSI_RUM.MODE_SOR, 2,1)::text]))[2] as destination
|
|
|
FROM prod_qsp.PMSI_RESULT
|
|
|
JOIN prod_qsp.PMSI_RUM ON PMSI_RESULT.NDOSSIER = PMSI_RUM.NDOSSIER AND PMSI_RESULT.N_SEQ = PMSI_RUM.N_SEQ
|
|
|
LEFT JOIN base.t_ghs ON PMSI_RESULT.GHS = t_ghs.code AND PMSI_RESULT.GHS <> 9999
|
|
|
LEFT JOIN base.t_ghm ON PMSI_RESULT.GHM = t_ghm.code AND t_ghm.code NOT LIKE '90%'
|
|
|
WHERE PMSI_RESULT.N_SEQ = 0
|
|
|
GROUP BY 1;
|
|
|
|
|
|
CREATE INDEX W_PMSI_RESULT_i1
|
|
|
ON W_PMSI_RESULT
|
|
|
USING btree
|
|
|
(NDOSSIER);
|
|
|
|
|
|
-- Type de séjour forcé selon actes saisis
|
|
|
DROP TABLE IF EXISTS w_DOSSIER_type;
|
|
|
CREATE TEMP TABLE w_DOSSIER_type AS
|
|
|
SELECT SAISIE.N_HOSPI,
|
|
|
CASE
|
|
|
WHEN SUM(CASE WHEN CODE_NORM IN ('GHS','PJ','FJ') THEN QTE ELSE 0 END) > 0 THEN '12'
|
|
|
WHEN SUM(CASE WHEN CODE_NORM IN ('D09','D10','D11','D12','D13') THEN QTE ELSE 0 END) > 0 THEN '5'
|
|
|
WHEN SUM(CASE WHEN CODE_NORM IN ('SE1','SE2','SE3','SE4','SE5', 'SE6', 'SE7','ATU', 'FPU','FFM') THEN QTE ELSE 0 END) > 0 THEN '3'
|
|
|
ELSE '' END AS type_sejour_selon_saisie
|
|
|
FROM prod_qsp.SAISIE
|
|
|
JOIN prod_qsp.PRESTATION ON SAISIE.CODE_PREST = PRESTATION.CODE_PREST
|
|
|
WHERE SUPPRIME <> 1
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_sejours;
|
|
|
CREATE TEMP TABLE w_sejours AS
|
|
|
SELECT
|
|
|
DOSSIER.NDOSSIER as no_sejour,
|
|
|
DOSSIER.NDOSSIER as code_original,
|
|
|
DOSSIER.NPATIENT as no_patient,
|
|
|
date(DOSSIER.DATE_ENTREE) as date_entree,
|
|
|
extract('hour' FROM DOSSIER.DATE_ENTREE) * 10000 + extract('minute' FROM DOSSIER.DATE_ENTREE) * 100 + extract('second' FROM DOSSIER.DATE_ENTREE) as heure_entree,
|
|
|
CASE WHEN DOSSIER.DATE_SORTIE IS NOT NULL THEN date(DOSSIER.DATE_SORTIE) ELSE '20991231' END::date as date_sortie,
|
|
|
CASE WHEN DOSSIER.DATE_SORTIE IS NOT NULL THEN extract('hour' FROM DOSSIER.DATE_SORTIE) * 10000 + extract('minute' FROM DOSSIER.DATE_SORTIE) * 100 + extract('second' FROM DOSSIER.DATE_SORTIE) ELSE 0 END as heure_sortie,
|
|
|
CASE WHEN PATIENT.SEXE = '2' THEN '2' ELSE '1' END as code_sexe,
|
|
|
0 AS age,
|
|
|
CASE WHEN DOSSIER.DATE_SORTIE IS NOT NULL THEN 1 ELSE 0 END as code_sorti,
|
|
|
0 as code_prevu,
|
|
|
CASE
|
|
|
WHEN DOSSIER.IN_TRANSIT = 1 OR HOSPI.ADMISSION = 1 THEN '9'
|
|
|
WHEN t_services_facturation.type_sejour IN ('1','2','3','5') THEN t_services_facturation.type_sejour
|
|
|
WHEN w_DOSSIERS_atraiter.type_sejour_force = '12' AND date(DOSSIER.DATE_ENTREE) = date(DOSSIER.DATE_SORTIE) THEN '2'
|
|
|
WHEN w_DOSSIERS_atraiter.type_sejour_force = '12' THEN '1'
|
|
|
WHEN w_DOSSIERS_atraiter.type_sejour_force = '3' AND date(DOSSIER.DATE_ENTREE) = date(DOSSIER.DATE_SORTIE) THEN '3'
|
|
|
WHEN w_DOSSIERS_atraiter.type_sejour_force = '5' AND date(DOSSIER.DATE_ENTREE) = date(DOSSIER.DATE_SORTIE) THEN '5'
|
|
|
WHEN w_DOSSIERS_atraiter.type_sejour_defaut = '1' AND date(DOSSIER.DATE_ENTREE) = date(DOSSIER.DATE_SORTIE) THEN '2'
|
|
|
WHEN w_DOSSIERS_atraiter.type_sejour_defaut = '1' THEN '1'
|
|
|
WHEN w_DOSSIERS_atraiter.type_sejour_defaut = '2' AND date(DOSSIER.DATE_ENTREE) = date(DOSSIER.DATE_SORTIE) THEN '2'
|
|
|
WHEN w_DOSSIERS_atraiter.type_sejour_defaut = '2' AND DOSSIER.DATE_SORTIE IS NULL THEN '2'
|
|
|
WHEN w_DOSSIERS_atraiter.type_sejour_defaut = '2' THEN '1'
|
|
|
WHEN w_DOSSIERS_atraiter.type_sejour_defaut = '3' AND date(DOSSIER.DATE_ENTREE) = date(DOSSIER.DATE_SORTIE) THEN '3'
|
|
|
WHEN w_DOSSIERS_atraiter.type_sejour_defaut = '3' AND DOSSIER.DATE_SORTIE IS NULL THEN '3'
|
|
|
WHEN w_DOSSIERS_atraiter.type_sejour_defaut = '5' AND date(DOSSIER.DATE_ENTREE) = date(DOSSIER.DATE_SORTIE) THEN '5'
|
|
|
WHEN w_DOSSIERS_atraiter.type_sejour_defaut = '5' AND DOSSIER.DATE_SORTIE IS NULL THEN '5'
|
|
|
WHEN t_modes_traitement.code IN ('07') OR t_dmt.code In ('958') THEN '3'
|
|
|
WHEN t_modes_traitement.code IN ('19', '23') AND date(DOSSIER.DATE_ENTREE) = date(DOSSIER.DATE_SORTIE) THEN '2'
|
|
|
WHEN t_modes_traitement.code IN ('04') AND date(DOSSIER.DATE_ENTREE) = date(DOSSIER.DATE_SORTIE) THEN '2'
|
|
|
WHEN t_modes_traitement.code IN ('03') AND date(DOSSIER.DATE_ENTREE) = date(DOSSIER.DATE_SORTIE) THEN '2'
|
|
|
WHEN date(DOSSIER.DATE_ENTREE) = date(DOSSIER.DATE_SORTIE) THEN '2'
|
|
|
ELSE '1' END as type_sejour,
|
|
|
COALESCE(t_medecins_administratifs.oid,0) as medecin_sejour_id,
|
|
|
COALESCE(w_PMSI_RESULT.ghs_id,0) AS ghs_id,
|
|
|
COALESCE(w_PMSI_RESULT.ghm_id,0) AS ghm_id,
|
|
|
COALESCE(w_PMSI_RESULT.date_groupage, '20991231') AS date_groupage,
|
|
|
CASE WHEN DOSSIER.DEM_CHP = 'O' THEN '1' ELSE '0' END as code_cp_demandee,
|
|
|
COALESCE(t_modes_traitement.oid,0) as mode_traitement_id,
|
|
|
COALESCE(w_PMSI_RESULT.mode_entree,'8') AS mode_entree,
|
|
|
COALESCE(w_PMSI_RESULT.provenance,'') AS provenance,
|
|
|
COALESCE(w_PMSI_RESULT.mode_sortie,'8') AS mode_sortie,
|
|
|
COALESCE(w_PMSI_RESULT.destination,'') AS destination,
|
|
|
COALESCE(t_tiers_payant_0.oid,0) AS tiers_payant_0_id,
|
|
|
COALESCE(t_tiers_payant_1.oid,0) AS tiers_payant_1_id,
|
|
|
COALESCE(t_tiers_payant_2.oid,0) AS tiers_payant_2_id,
|
|
|
0 AS tiers_payant_22_id,
|
|
|
COALESCE(t_codes_postaux.oid, 0) AS code_postal_id
|
|
|
|
|
|
FROM prod_qsp.DOSSIER
|
|
|
JOIN w_DOSSIERS_atraiter ON DOSSIER.NDOSSIER = NDOSSIER_T
|
|
|
JOIN prod_qsp.HOSPI ON DOSSIER.NDOSSIER = HOSPI.N_HOSPI
|
|
|
LEFT JOIN w_HISTOLIT_SERVICE ON DOSSIER.NDOSSIER = w_HISTOLIT_SERVICE.NDOSSIER
|
|
|
LEFT JOIN activite[PX].t_services_facturation ON w_HISTOLIT_SERVICE.C_SERV_CTI = t_services_facturation.code_original
|
|
|
LEFT JOIN base.t_modes_traitement ON t_services_facturation.mode_traitement_id = t_modes_traitement.oid
|
|
|
LEFT JOIN base.t_dmt ON t_services_facturation.dmt_id = t_dmt.oid
|
|
|
LEFT JOIN prod_qsp.PATIENT ON DOSSIER.NPATIENT = PATIENT.NPATIENT
|
|
|
LEFT JOIN base.t_codes_postaux on t_codes_postaux.code = PATIENT.CPO_PAT
|
|
|
LEFT JOIN w_PMSI_RESULT ON DOSSIER.NDOSSIER = w_PMSI_RESULT.NDOSSIER
|
|
|
LEFT JOIN activite[PX].t_medecins_administratifs ON MEDSUIV = t_medecins_administratifs.code_original
|
|
|
LEFT JOIN activite[PX].t_tiers_payant t_tiers_payant_0 ON 'PATIENT' = t_tiers_payant_0.code
|
|
|
LEFT JOIN activite[PX].t_tiers_payant t_tiers_payant_1 ON HOSPI.CAISSE_DESTINATAIRE = t_tiers_payant_1.code_original
|
|
|
LEFT JOIN activite[PX].t_tiers_payant t_tiers_payant_2 ON HOSPI.MUT_CODE = t_tiers_payant_2.code_original
|
|
|
WHERE DOSSIER.ANNULE = 0;
|
|
|
|
|
|
UPDATE w_sejours
|
|
|
SET no_patient = subview.NPATIENT_GARDE
|
|
|
FROM (
|
|
|
SELECT NPATIENT_FUSIONE, MAX(NPATIENT_GARDE) AS NPATIENT_GARDE FROM prod_qsp.HISTORIQUE_FUSIONS GROUP BY 1
|
|
|
) subview
|
|
|
WHERE w_sejours.no_patient = subview.NPATIENT_FUSIONE;
|
|
|
|
|
|
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_sejours_2');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_sejours_3');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_sejours_4');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_sejours_5');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_sejours_6');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_sejours_7');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_sejours_8');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_sejours_9');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_sejours_10');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_sejours_11');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_sejours_12');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_sejours_13');
|
|
|
|
|
|
-- Forcage type selon séjour
|
|
|
UPDATE w_sejours
|
|
|
SET type_sejour = t_sejour.type_sejour
|
|
|
FROM activite.t_sejour
|
|
|
WHERE t_sejour.no_sejour = '[CPX]' || w_sejours.no_sejour AND
|
|
|
t_sejour.type_sejour IN ('1','2','3','4','5','6','9');
|
|
|
|
|
|
UPDATE w_sejours
|
|
|
SET type_sejour = t_sejour.type_sejour
|
|
|
FROM activite.t_sejour
|
|
|
WHERE t_sejour.no_sejour ILIKE ('QS_' || w_sejours.no_sejour) AND
|
|
|
t_sejour.type_sejour IN ('1','2','3','4','5','6','9');
|
|
|
|
|
|
UPDATE activite[PX].p_sejours SET
|
|
|
code_original = w_sejours.code_original,
|
|
|
no_patient = w_sejours.no_patient,
|
|
|
date_entree = w_sejours.date_entree,
|
|
|
heure_entree = w_sejours.heure_entree,
|
|
|
date_sortie = w_sejours.date_sortie,
|
|
|
heure_sortie = w_sejours.heure_sortie,
|
|
|
code_sexe = w_sejours.code_sexe,
|
|
|
age = w_sejours.age,
|
|
|
code_sorti = w_sejours.code_sorti,
|
|
|
code_prevu = w_sejours.code_prevu,
|
|
|
type_sejour = w_sejours.type_sejour,
|
|
|
medecin_sejour_id = w_sejours.medecin_sejour_id,
|
|
|
code_cp_demandee = w_sejours.code_cp_demandee,
|
|
|
mode_traitement_id = w_sejours.mode_traitement_id,
|
|
|
mode_entree = w_sejours.mode_entree,
|
|
|
provenance = w_sejours.provenance,
|
|
|
mode_sortie = w_sejours.mode_sortie,
|
|
|
destination = w_sejours.destination,
|
|
|
tiers_payant_0_id = w_sejours.tiers_payant_0_id,
|
|
|
tiers_payant_1_id = w_sejours.tiers_payant_1_id,
|
|
|
tiers_payant_2_id = w_sejours.tiers_payant_2_id,
|
|
|
tiers_payant_22_id = w_sejours.tiers_payant_22_id,
|
|
|
ghs_id = w_sejours.ghs_id,
|
|
|
ghm_id = w_sejours.ghm_id,
|
|
|
date_groupage = w_sejours.date_groupage,
|
|
|
code_postal_id = w_sejours.code_postal_id
|
|
|
FROM w_sejours
|
|
|
WHERE w_sejours.no_sejour = p_sejours.no_sejour
|
|
|
AND (
|
|
|
w_sejours.code_original IS DISTINCT FROM p_sejours.code_original OR
|
|
|
w_sejours.no_patient IS DISTINCT FROM p_sejours.no_patient OR
|
|
|
w_sejours.date_entree IS DISTINCT FROM p_sejours.date_entree OR
|
|
|
w_sejours.heure_entree IS DISTINCT FROM p_sejours.heure_entree OR
|
|
|
w_sejours.date_sortie IS DISTINCT FROM p_sejours.date_sortie OR
|
|
|
w_sejours.heure_sortie IS DISTINCT FROM p_sejours.heure_sortie OR
|
|
|
w_sejours.code_sexe IS DISTINCT FROM p_sejours.code_sexe OR
|
|
|
w_sejours.age IS DISTINCT FROM p_sejours.age OR
|
|
|
w_sejours.code_sorti IS DISTINCT FROM p_sejours.code_sorti OR
|
|
|
w_sejours.code_prevu IS DISTINCT FROM p_sejours.code_prevu OR
|
|
|
w_sejours.type_sejour IS DISTINCT FROM p_sejours.type_sejour OR
|
|
|
w_sejours.medecin_sejour_id IS DISTINCT FROM p_sejours.medecin_sejour_id OR
|
|
|
w_sejours.code_cp_demandee IS DISTINCT FROM p_sejours.code_cp_demandee OR
|
|
|
w_sejours.mode_traitement_id IS DISTINCT FROM p_sejours.mode_traitement_id OR
|
|
|
w_sejours.mode_entree IS DISTINCT FROM p_sejours.mode_entree OR
|
|
|
w_sejours.provenance IS DISTINCT FROM p_sejours.provenance OR
|
|
|
w_sejours.mode_sortie IS DISTINCT FROM p_sejours.mode_sortie OR
|
|
|
w_sejours.destination IS DISTINCT FROM p_sejours.destination OR
|
|
|
w_sejours.tiers_payant_0_id IS DISTINCT FROM p_sejours.tiers_payant_0_id OR
|
|
|
w_sejours.tiers_payant_1_id IS DISTINCT FROM p_sejours.tiers_payant_1_id OR
|
|
|
w_sejours.tiers_payant_2_id IS DISTINCT FROM p_sejours.tiers_payant_2_id OR
|
|
|
w_sejours.tiers_payant_22_id IS DISTINCT FROM p_sejours.tiers_payant_22_id OR
|
|
|
w_sejours.ghs_id IS DISTINCT FROM p_sejours.ghs_id OR
|
|
|
w_sejours.ghm_id IS DISTINCT FROM p_sejours.ghm_id OR
|
|
|
w_sejours.date_groupage IS DISTINCT FROM p_sejours.date_groupage OR
|
|
|
w_sejours.code_postal_id IS DISTINCT FROM p_sejours.code_postal_id
|
|
|
);
|
|
|
|
|
|
INSERT INTO activite[PX].p_sejours (
|
|
|
no_sejour,
|
|
|
code_original,
|
|
|
no_patient,
|
|
|
date_entree,
|
|
|
heure_entree,
|
|
|
date_sortie,
|
|
|
heure_sortie,
|
|
|
code_sexe,
|
|
|
age,
|
|
|
code_sorti,
|
|
|
code_prevu,
|
|
|
type_sejour,
|
|
|
medecin_sejour_id,
|
|
|
ghs_id,
|
|
|
ghm_id,
|
|
|
date_groupage,
|
|
|
code_cp_demandee,
|
|
|
mode_traitement_id,
|
|
|
mode_entree,
|
|
|
provenance,
|
|
|
mode_sortie,
|
|
|
destination,
|
|
|
tiers_payant_0_id,
|
|
|
tiers_payant_1_id,
|
|
|
tiers_payant_2_id,
|
|
|
tiers_payant_22_id,
|
|
|
code_postal_id
|
|
|
)
|
|
|
SELECT
|
|
|
w_sejours.no_sejour,
|
|
|
w_sejours.code_original,
|
|
|
w_sejours.no_patient,
|
|
|
w_sejours.date_entree,
|
|
|
w_sejours.heure_entree,
|
|
|
w_sejours.date_sortie,
|
|
|
w_sejours.heure_sortie,
|
|
|
w_sejours.code_sexe,
|
|
|
w_sejours.age,
|
|
|
w_sejours.code_sorti,
|
|
|
w_sejours.code_prevu,
|
|
|
w_sejours.type_sejour,
|
|
|
w_sejours.medecin_sejour_id,
|
|
|
w_sejours.ghs_id,
|
|
|
w_sejours.ghm_id,
|
|
|
w_sejours.date_groupage,
|
|
|
w_sejours.code_cp_demandee,
|
|
|
w_sejours.mode_traitement_id,
|
|
|
w_sejours.mode_entree,
|
|
|
w_sejours.provenance,
|
|
|
w_sejours.mode_sortie,
|
|
|
w_sejours.destination,
|
|
|
w_sejours.tiers_payant_0_id,
|
|
|
w_sejours.tiers_payant_1_id,
|
|
|
w_sejours.tiers_payant_2_id,
|
|
|
w_sejours.tiers_payant_22_id,
|
|
|
w_sejours.code_postal_id
|
|
|
|
|
|
FROM w_sejours LEFT JOIN activite[PX].p_sejours ON (w_sejours.no_sejour = p_sejours.no_sejour)
|
|
|
WHERE p_sejours.no_sejour IS NULL;
|
|
|
|
|
|
|
|
|
DELETE FROM activite[PX].p_sejours WHERE no_sejour NOT IN (SELECT no_sejour FROM w_sejours);
|
|
|
|
|
|
-- Séjours ignorés
|
|
|
UPDATE activite[PX].p_sejours
|
|
|
SET etat = 'I'
|
|
|
FROM activite.t_sejour
|
|
|
WHERE t_sejour.no_sejour = p_sejours.no_sejour AND
|
|
|
est_ignore = '1' AND
|
|
|
etat <> 'I' AND
|
|
|
'[PX]' = '';
|
|
|
|
|
|
UPDATE activite[PX].p_sejours
|
|
|
SET etat = ''
|
|
|
WHERE etat = 'I' AND
|
|
|
no_sejour NOT IN (SELECT no_sejour FROM activite.t_sejour WHERE est_ignore = '1') AND
|
|
|
'[PX]' = '';
|
|
|
|
|
|
-- Médecin séjour forcé
|
|
|
UPDATE activite[PX].p_sejours
|
|
|
SET medecin_sejour_id = t_sejour.medecin_sejour_id
|
|
|
FROM activite.t_sejour
|
|
|
WHERE t_sejour.no_sejour = p_sejours.no_sejour AND
|
|
|
t_sejour.medecin_sejour_id <> 0 AND
|
|
|
p_sejours.medecin_sejour_id IS DISTINCT FROM t_sejour.medecin_sejour_id AND
|
|
|
'[PX]' = '';
|
|
|
|
|
|
|
|
|
-- recréation index
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_sejours_2');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_sejours_3');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_sejours_4');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_sejours_5');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_sejours_6');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_sejours_7');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_sejours_8');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_sejours_9');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_sejours_10');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_sejours_11');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_sejours_12');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_sejours_13');
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Mouvements">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
UPDATE cti_histolit
|
|
|
SET NUM_LIT = '0'
|
|
|
WHERE NUM_LIT = '';
|
|
|
|
|
|
DROP TABLE IF EXISTS w_HISTOLIT_DOUBLONS;
|
|
|
CREATE TEMP TABLE w_HISTOLIT_DOUBLONS AS
|
|
|
SELECT cti_histolit.NDOSSIER, CASE WHEN cti_histolit.DATECHG >= DOSSIER.DATE_ENTREE THEN cti_histolit.DATECHG ELSE DOSSIER.DATE_ENTREE END AS DATECHG, MAX(N_UNIQUE) AS N_UNIQUE
|
|
|
FROM cti_histolit JOIN prod_qsp.DOSSIER ON DOSSIER.NDOSSIER = cti_histolit.NDOSSIER
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
CREATE INDEX w_HISTOLIT_DOUBLONS_i1
|
|
|
ON w_HISTOLIT_DOUBLONS
|
|
|
USING btree
|
|
|
(N_UNIQUE);
|
|
|
|
|
|
DROP SEQUENCE IF EXISTS w_HISTOLIT_seq;
|
|
|
|
|
|
CREATE TEMP SEQUENCE w_HISTOLIT_seq
|
|
|
INCREMENT 1
|
|
|
MINVALUE 1;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_HISTOLIT;
|
|
|
|
|
|
CREATE TEMP TABLE w_HISTOLIT AS
|
|
|
SELECT nextval('w_HISTOLIT_seq'::regclass) AS sequence,
|
|
|
subview.NDOSSIER,
|
|
|
subview.DATE_ENTREE_DOSSIER,
|
|
|
'1'::text AS CODE_ENTREE,
|
|
|
subview.DATE_SORTIE_DOSSIER,
|
|
|
CASE WHEN date(DATE_SORTIE_DOSSIER) <> '20991231' THEN '1'::text ELSE '0' END AS CODE_SORTIE,
|
|
|
subview.DATECHG,
|
|
|
date(subview.DATECHG) AS DATECHG_DAT,
|
|
|
extract('hour' FROM DATECHG) * 10000 + extract('minute' FROM DATECHG) * 100 + extract('second' FROM DATECHG) AS DATECHG_TIM,
|
|
|
date(subview.DATECHG) AS DATECHG_FIN,
|
|
|
date(DATE_SORTIE_DOSSIER) AS DATECHG_FIN_DAT,
|
|
|
extract('hour' FROM DATE_SORTIE_DOSSIER) * 10000 + extract('minute' FROM DATE_SORTIE_DOSSIER) * 100 + extract('second' FROM DATE_SORTIE_DOSSIER) AS DATECHG_FIN_TIM,
|
|
|
subview.C_SERV_CTI,
|
|
|
subview.C_UF_CTI,
|
|
|
subview.C_SECT,
|
|
|
subview.NUM_LIT,
|
|
|
subview.NUM_LIT_LIT,
|
|
|
subview.C_SERV_CTI AS C_SERV_before,
|
|
|
subview.C_SECT AS C_SECT_before,
|
|
|
subview.NUM_LIT AS NUM_LIT_before,
|
|
|
subview.C_SERV_CTI AS C_SERV_next,
|
|
|
subview.C_SECT AS C_SECT_next,
|
|
|
subview.NUM_LIT AS NUM_LIT_next,
|
|
|
medecin_sejour_id
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
DOSSIER.NDOSSIER,
|
|
|
DOSSIER.DATE_ENTREE AS DATE_ENTREE_DOSSIER,
|
|
|
CASE WHEN DOSSIER.DATE_SORTIE IS NOT NULL THEN DOSSIER.DATE_SORTIE ELSE '20991231' END AS DATE_SORTIE_DOSSIER,
|
|
|
CASE WHEN cti_histolit.DATECHG >= DOSSIER.DATE_ENTREE THEN cti_histolit.DATECHG ELSE DOSSIER.DATE_ENTREE END AS DATECHG,
|
|
|
C_SERV_CTI,
|
|
|
C_UF_CTI,
|
|
|
CASE WHEN C_SECT <> '' THEN COALESCE(C_SECT, C_SERV_CTI) ELSE C_SERV_CTI END AS C_SECT,
|
|
|
CASE WHEN NUM_LIT <> '' THEN CASE WHEN C_SECT <> '' THEN COALESCE(C_SECT, C_SERV_CTI) ELSE C_SERV_CTI END || '|' || REPLACE(UPPER(COALESCE(NUM_LIT,'')),' ', '') ELSE '' END AS NUM_LIT,
|
|
|
REPLACE(UPPER(COALESCE(NUM_LIT,'')),' ', '') AS NUM_LIT_LIT,
|
|
|
N_PREAD,
|
|
|
medecin_sejour_id
|
|
|
FROM cti_histolit, w_HISTOLIT_DOUBLONS, activite[PX].p_sejours, prod_qsp.DOSSIER
|
|
|
JOIN prod_qsp.HOSPI ON DOSSIER.NDOSSIER = HOSPI.N_HOSPI
|
|
|
JOIN w_DOSSIERS_atraiter ON DOSSIER.NDOSSIER = NDOSSIER_T
|
|
|
WHERE cti_histolit.N_UNIQUE = w_HISTOLIT_DOUBLONS.N_UNIQUE AND
|
|
|
cti_histolit.NDOSSIER = p_sejours.code_original AND
|
|
|
DOSSIER.NDOSSIER = cti_histolit.NDOSSIER AND ANNULE = 0
|
|
|
ORDER BY DOSSIER.NDOSSIER, CASE WHEN cti_histolit.DATECHG >= DOSSIER.DATE_ENTREE THEN cti_histolit.DATECHG ELSE DOSSIER.DATE_ENTREE END
|
|
|
|
|
|
) subview;
|
|
|
|
|
|
|
|
|
CREATE INDEX w_HISTOLIT_i1
|
|
|
ON w_HISTOLIT
|
|
|
USING btree
|
|
|
(NDOSSIER);
|
|
|
|
|
|
UPDATE w_HISTOLIT
|
|
|
SET
|
|
|
CODE_SORTIE = '0',
|
|
|
DATECHG_FIN = w_HISTOLIT_next.DATECHG - interval '1 second',
|
|
|
DATECHG_FIN_DAT = date(w_HISTOLIT_next.DATECHG - interval '1 second'),
|
|
|
DATECHG_FIN_TIM = extract('hour' FROM w_HISTOLIT_next.DATECHG - interval '1 second') * 10000 +
|
|
|
extract('minute' FROM w_HISTOLIT_next.DATECHG - interval '1 second') * 100 +
|
|
|
extract('second' FROM w_HISTOLIT_next.DATECHG - interval '1 second'),
|
|
|
C_SERV_next = w_HISTOLIT_next.C_SERV_CTI,
|
|
|
C_SECT_next = w_HISTOLIT_next.C_SECT,
|
|
|
NUM_LIT_next = w_HISTOLIT_next.NUM_LIT
|
|
|
FROM w_HISTOLIT w_HISTOLIT_next
|
|
|
WHERE w_HISTOLIT.NDOSSIER = w_HISTOLIT_next.NDOSSIER
|
|
|
AND w_HISTOLIT.sequence = w_HISTOLIT_next.sequence - 1;
|
|
|
|
|
|
UPDATE w_HISTOLIT
|
|
|
SET
|
|
|
CODE_ENTREE = '0',
|
|
|
C_SERV_before = w_HISTOLIT_before.C_SERV_CTI,
|
|
|
C_SECT_before = w_HISTOLIT_before.C_SECT,
|
|
|
NUM_LIT_before = w_HISTOLIT_before.NUM_LIT
|
|
|
FROM w_HISTOLIT w_HISTOLIT_before
|
|
|
WHERE w_HISTOLIT.NDOSSIER = w_HISTOLIT_before.NDOSSIER
|
|
|
AND w_HISTOLIT.sequence = w_HISTOLIT_before.sequence + 1;
|
|
|
|
|
|
CREATE INDEX w_HISTOLIT_i2
|
|
|
ON w_HISTOLIT
|
|
|
USING btree
|
|
|
(NUM_LIT);
|
|
|
|
|
|
CREATE INDEX w_HISTOLIT_i3
|
|
|
ON w_HISTOLIT
|
|
|
USING btree
|
|
|
(C_SERV_CTI);
|
|
|
|
|
|
INSERT INTO activite[PX].t_etages(code_original, code, texte, texte_court)
|
|
|
SELECT DISTINCT C_SECT, C_SECT, C_SECT, C_SECT
|
|
|
FROM w_histolit
|
|
|
WHERE C_SECT <> '' AND C_SECT NOT IN (SELECT code_original FROM activite[PX].t_etages);
|
|
|
|
|
|
INSERT INTO activite[PX].t_lits(code_original, code, texte, texte_court, etage_id, chambre_particuliere)
|
|
|
SELECT DISTINCT NUM_LIT, NUM_LIT_LIT, NUM_LIT_LIT, NUM_LIT_LIT, COALESCE(t_etages.oid,0), 'N'
|
|
|
FROM w_histolit LEFT JOIN activite[PX].t_etages ON C_SECT = t_etages.code_original
|
|
|
WHERE NUM_LIT NOT IN (SELECT code_original FROM activite[PX].t_lits) ORDER BY 1;
|
|
|
|
|
|
ANALYSE w_HISTOLIT;
|
|
|
|
|
|
DELETE
|
|
|
FROM activite[PX].t_lieux
|
|
|
USING
|
|
|
(
|
|
|
SELECT
|
|
|
code_original_1, code_original_2, code_original_3, code_original_4, code_original_5 , code_original_6 , code_original_7 , count(*), min(ctid) AS keep_ctid from activite[PX].t_lieux
|
|
|
group by 1,2,3,4,5,6,7
|
|
|
HAVING count(*) > 1
|
|
|
) subview
|
|
|
WHERE t_lieux.code_original_1 = subview.code_original_1 AND
|
|
|
t_lieux.code_original_2 = subview.code_original_2 AND
|
|
|
t_lieux.code_original_3 = subview.code_original_3 AND
|
|
|
t_lieux.code_original_4 = subview.code_original_4 AND
|
|
|
t_lieux.code_original_5 = subview.code_original_5 AND
|
|
|
t_lieux.code_original_6 = subview.code_original_6 AND
|
|
|
t_lieux.code_original_7 = subview.code_original_7 AND
|
|
|
t_lieux.CTID <> subview.keep_CTID
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_mouvements_sejour;
|
|
|
|
|
|
CREATE TEMP TABLE w_mouvements_sejour AS
|
|
|
SELECT
|
|
|
w_HISTOLIT.NDOSSIER AS no_sejour,
|
|
|
sequence,
|
|
|
p_calendrier.date,
|
|
|
p_calendrier.jour_semaine,
|
|
|
p_calendrier.is_weekend,
|
|
|
CASE WHEN p_calendrier.date = DATECHG_DAT THEN DATECHG_TIM ELSE 0 END AS heure_debut,
|
|
|
CASE WHEN p_calendrier.date = DATECHG_FIN_DAT THEN DATECHG_FIN_TIM ELSE 240000 END AS heure_fin,
|
|
|
CASE WHEN p_calendrier.date = DATECHG_DAT AND CODE_ENTREE = '1' AND p_sejours.type_sejour = '1' THEN 1 ELSE 0 END AS nb_entrees_directes,
|
|
|
CASE WHEN p_calendrier.date = DATECHG_FIN_DAT AND CODE_SORTIE = '1' AND p_sejours.type_sejour = '1' THEN 1 ELSE 0 END AS nb_sorties_directes,
|
|
|
CASE WHEN p_calendrier.date = DATECHG_DAT AND CODE_ENTREE = '1' AND p_sejours.type_sejour = '1' THEN '1' ELSE '0' END AS est_jour_entree,
|
|
|
CASE WHEN p_calendrier.date = DATECHG_FIN_DAT AND CODE_SORTIE = '1' AND p_sejours.type_sejour = '1' THEN '1' ELSE '0' END AS est_jour_sortie,
|
|
|
CASE WHEN p_sejours.type_sejour = '1' THEN '1' ELSE '0' END AS est_jour_hospitalisation,
|
|
|
CASE WHEN p_calendrier.date = DATECHG_DAT AND CODE_ENTREE = '1' AND p_sejours.type_sejour = '2' THEN 1 ELSE 0 END AS nb_ambulatoires,
|
|
|
CASE WHEN p_calendrier.date = DATECHG_DAT AND CODE_ENTREE = '1' AND p_sejours.type_sejour = '3' THEN 1 ELSE 0 END AS nb_externes,
|
|
|
CASE WHEN p_calendrier.date = DATECHG_DAT AND CODE_ENTREE = '1' AND (t_dmt.code IN ('303', '307', '308', '401', '402', '403', '404', '405', '406', '407', '408', '409') OR DOSSIER.URGENCE > 1 OR HOSPI.ENTREE_URG = 1) THEN 1 ELSE 0 END AS nb_urgences,
|
|
|
0 as nb_seances,
|
|
|
0 as nb_bebes,
|
|
|
|
|
|
CASE WHEN p_calendrier.date = DATECHG_DAT AND p_sejours.type_sejour = '1' AND C_SERV_CTI <> C_SERV_before THEN 1 ELSE 0 END AS nb_entrees_mutation_service,
|
|
|
CASE WHEN p_calendrier.date = DATECHG_FIN_DAT AND p_sejours.type_sejour = '1' AND C_SERV_CTI <> C_SERV_next THEN 1 ELSE 0 END AS nb_sorties_mutation_service,
|
|
|
CASE WHEN p_calendrier.date = DATECHG_DAT AND p_sejours.type_sejour = '1' AND C_SECT <> C_SECT_before THEN 1 ELSE 0 END AS nb_entrees_mutation_etage,
|
|
|
CASE WHEN p_calendrier.date = DATECHG_FIN_DAT AND p_sejours.type_sejour = '1' AND C_SECT <> C_SECT_next THEN 1 ELSE 0 END AS nb_sorties_mutation_etage,
|
|
|
0 AS nb_entrees_mutation_activite,
|
|
|
0 AS nb_sorties_mutation_activite,
|
|
|
0 AS nb_entrees_mutation_unite_medicale,
|
|
|
0 AS nb_sorties_mutation_unite_medicale,
|
|
|
|
|
|
CASE WHEN p_sejours.type_sejour = '1' AND (p_calendrier.date <> DATECHG_FIN_DAT OR CODE_SORTIE = '1') THEN 1 ELSE 0 END AS nb_jours_js_inclus,
|
|
|
CASE WHEN p_sejours.type_sejour = '1' AND p_calendrier.date <> DATECHG_FIN_DAT THEN 1 ELSE 0 END AS nb_jours_js_non_inclus,
|
|
|
|
|
|
CASE WHEN p_sejours.type_sejour = '1' AND t_lits.chambre_particuliere = 'O' THEN '1' ELSE '0' END AS est_chambre_particuliere,
|
|
|
CASE WHEN p_sejours.type_sejour = '1' AND t_lits.chambre_particuliere = 'O' AND (p_calendrier.date <> DATECHG_FIN_DAT OR CODE_SORTIE = '1') THEN 1 ELSE 0 END AS nb_chambres_particulieres,
|
|
|
|
|
|
C_SERV_CTI,
|
|
|
C_UF_CTI,
|
|
|
C_SECT,
|
|
|
NUM_LIT,
|
|
|
|
|
|
COALESCE(t_lieux.oid,0) AS lieu_id,
|
|
|
|
|
|
p_sejours.medecin_sejour_id as medecin_sejour_id,
|
|
|
|
|
|
CASE WHEN p_sejours.code_prevu = '1' OR p_calendrier.date > date(now()) THEN '1' ELSE '0' END AS est_mouvement_previsionnel,
|
|
|
|
|
|
p_sejours.oid as sejour_id
|
|
|
|
|
|
FROM w_HISTOLIT
|
|
|
JOIN activite[PX].p_sejours ON w_HISTOLIT.NDOSSIER = p_sejours.no_sejour AND p_sejours.etat = ''
|
|
|
LEFT JOIN activite[PX].t_lieux ON (t_lieux.code_original_1 = C_SERV_CTI AND t_lieux.code_original_4 = NUM_LIT )
|
|
|
, prod_qsp.DOSSIER, prod_qsp.HOSPI, base.p_calendrier, activite[PX].t_lits, activite[PX].t_services_facturation, base.t_dmt
|
|
|
WHERE
|
|
|
w_HISTOLIT.NDOSSIER = DOSSIER.NDOSSIER
|
|
|
AND w_HISTOLIT.NDOSSIER = HOSPI.N_HOSPI
|
|
|
AND NUM_LIT = t_lits.code_original
|
|
|
AND C_SERV_CTI = t_services_facturation.code_original
|
|
|
AND t_services_facturation.dmt_id = t_dmt.oid
|
|
|
AND (p_calendrier.date BETWEEN DATECHG_DAT AND DATECHG_FIN_DAT AND p_calendrier.date <= now() OR (p_calendrier.date = p_sejours.date_entree AND CODE_ENTREE = '1'))
|
|
|
AND p_calendrier.date <= now()
|
|
|
AND p_sejours.code_prevu <> '1'
|
|
|
ORDER BY sequence, p_calendrier.date;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- seances
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SAISIE_seances;
|
|
|
CREATE TEMP TABLE w_SAISIE_seances AS
|
|
|
SELECT
|
|
|
SAISIE.N_HOSPI,
|
|
|
date(D_DEB) AS D_DEB,
|
|
|
1 AS nb_seances
|
|
|
FROM prod_qsp.SAISIE
|
|
|
JOIN w_DOSSIERS_atraiter ON (SAISIE.N_HOSPI = w_DOSSIERS_atraiter.NDOSSIER_T )
|
|
|
WHERE SUPPRIME <> 1 AND
|
|
|
(CODE_PREST = 'GHS' AND N_GHS IN
|
|
|
(
|
|
|
SELECT code FROM base.t_ghs WHERE ghm_id IN (SELECT oid FROM base.t_ghm WHERE code like '28%')
|
|
|
)
|
|
|
) OR
|
|
|
CODE_PREST IN ('D01', 'D02', 'D03', 'D04', 'D05', 'D06', 'D07', 'D08', 'D09', 'D10', 'D11', 'D12', 'D13', 'D14', 'D15', 'D16', 'D17', 'D18', 'D19')
|
|
|
GROUP BY 1,2
|
|
|
HAVING SUM(QTE) > 0;
|
|
|
|
|
|
|
|
|
CREATE INDEX w_SAISIE_seances_i1
|
|
|
ON w_SAISIE_seances
|
|
|
USING btree
|
|
|
(N_HOSPI);
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO w_SAISIE_seances
|
|
|
SELECT * FROM (
|
|
|
SELECT
|
|
|
SAISIE.N_HOSPI,
|
|
|
date(D_DEB) AS D_DEB,
|
|
|
1 AS nb_seances
|
|
|
FROM prod_qsp.SAISIE
|
|
|
JOIN w_DOSSIERS_atraiter ON (SAISIE.N_HOSPI = w_DOSSIERS_atraiter.NDOSSIER_T )
|
|
|
WHERE SUPPRIME <> 1 AND CODE_PREST IN ('K15')
|
|
|
GROUP BY 1,2
|
|
|
HAVING SUM(QTE) > 0) subview
|
|
|
WHERE N_HOSPI NOT IN (SELECT N_HOSPI FROM w_SAISIE_seances);
|
|
|
|
|
|
|
|
|
UPDATE w_mouvements_sejour
|
|
|
SET nb_seances = w_SAISIE_seances.nb_seances
|
|
|
FROM w_SAISIE_seances
|
|
|
WHERE w_SAISIE_seances.N_HOSPI = w_mouvements_sejour.no_sejour AND D_DEB = w_mouvements_sejour.date;
|
|
|
|
|
|
|
|
|
|
|
|
-- bébés
|
|
|
|
|
|
DROP TABLE IF EXISTS w_DOSSIER_CCAM_bebes;
|
|
|
|
|
|
CREATE TEMP TABLE w_DOSSIER_CCAM_bebes AS
|
|
|
SELECT
|
|
|
NDOSSIER,
|
|
|
MAX(CASE WHEN t_actes.texte ILIKE '%multiple%' THEN 2 ELSE 1 END) AS nb_bebes
|
|
|
FROM prod_qsp.DOSSIER_CCAM
|
|
|
JOIN w_DOSSIERS_atraiter ON NDOSSIER = NDOSSIER_T
|
|
|
JOIN base.t_actes ON substring(CODE_ACTE, 1, 7) = t_actes.code AND
|
|
|
CODE_ACTE LIKE 'JQG%' AND
|
|
|
t_actes.texte ILIKE 'accouchement%'
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
CREATE INDEX w_DOSSIER_CCAM_bebes_i1
|
|
|
ON w_DOSSIER_CCAM_bebes
|
|
|
USING btree
|
|
|
(NDOSSIER);
|
|
|
|
|
|
|
|
|
UPDATE w_mouvements_sejour
|
|
|
SET nb_bebes = w_DOSSIER_CCAM_bebes.nb_bebes
|
|
|
FROM w_DOSSIER_CCAM_bebes
|
|
|
WHERE w_DOSSIER_CCAM_bebes.NDOSSIER = w_mouvements_sejour.no_sejour AND
|
|
|
(nb_entrees_directes = 1 OR nb_externes = 1 OR nb_ambulatoires = 1);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
service_facturation_id = t_services_facturation.oid,
|
|
|
lit_id = t_lits.oid,
|
|
|
unite_fonctionnelle_id = t_unites_fonctionnelles.oid,
|
|
|
mode_traitement_id = t_services_facturation.mode_traitement_id
|
|
|
FROM activite[PX].t_services_facturation, activite[PX].t_lits, activite[PX].t_unites_fonctionnelles
|
|
|
WHERE
|
|
|
code_original_1 = t_services_facturation.code_original
|
|
|
AND code_original_4 = t_lits.code_original
|
|
|
AND code_original_6 = t_unites_fonctionnelles.code_original;
|
|
|
|
|
|
INSERT INTO activite[PX].t_lieux(
|
|
|
code_original_1,
|
|
|
code_original_2,
|
|
|
code_original_3,
|
|
|
code_original_4,
|
|
|
code_original_5,
|
|
|
code_original_6,
|
|
|
code_original_7,
|
|
|
service_facturation_id,
|
|
|
activite_id,
|
|
|
lit_id,
|
|
|
unite_medicale_id,
|
|
|
unite_fonctionnelle_id,
|
|
|
mode_traitement_id)
|
|
|
SELECT DISTINCT
|
|
|
C_SERV_CTI,
|
|
|
'',
|
|
|
'',
|
|
|
NUM_LIT,
|
|
|
'',
|
|
|
C_UF_CTI,
|
|
|
'',
|
|
|
t_services_facturation.oid,
|
|
|
0,
|
|
|
t_lits.oid,
|
|
|
0,
|
|
|
t_unites_fonctionnelles.oid,
|
|
|
t_services_facturation.mode_traitement_id
|
|
|
FROM w_mouvements_sejour
|
|
|
LEFT JOIN activite[PX].t_lieux ON (t_lieux.code_original_1 = C_SERV_CTI AND t_lieux.code_original_4 = NUM_LIT AND t_lieux.code_original_6 = C_UF_CTI )
|
|
|
, activite[PX].t_services_facturation, activite[PX].t_lits, activite[PX].t_unites_fonctionnelles
|
|
|
WHERE
|
|
|
C_SERV_CTI = t_services_facturation.code_original
|
|
|
AND NUM_LIT = t_lits.code_original
|
|
|
AND C_UF_CTI = t_unites_fonctionnelles.code_original
|
|
|
AND t_lieux.oid IS NULL;
|
|
|
|
|
|
UPDATE w_mouvements_sejour SET lieu_id = t_lieux.oid
|
|
|
FROM activite[PX].t_lieux
|
|
|
WHERE t_lieux.code_original_1 = C_SERV_CTI
|
|
|
AND t_lieux.code_original_4 = NUM_LIT
|
|
|
AND t_lieux.code_original_6 = C_UF_CTI
|
|
|
AND w_mouvements_sejour.lieu_id = 0;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_mouvements_sejour_key;
|
|
|
CREATE TEMP TABLE w_mouvements_sejour_key AS
|
|
|
SELECT
|
|
|
no_sejour,
|
|
|
SUM(1 +
|
|
|
extract('day' FROM date) * 2 +
|
|
|
heure_debut * 3 +
|
|
|
heure_fin * 4 +
|
|
|
medecin_sejour_id * 5 +
|
|
|
lieu_id * 6 +
|
|
|
nb_jours_js_non_inclus * 7 +
|
|
|
nb_entrees_directes * 8 +
|
|
|
nb_entrees_directes * 9 +
|
|
|
nb_sorties_directes * 10 +
|
|
|
nb_urgences * 11 +
|
|
|
nb_externes * 12 +
|
|
|
nb_ambulatoires * 13 +
|
|
|
nb_jours_js_inclus * 14 +
|
|
|
nb_seances * 15 +
|
|
|
nb_entrees_mutation_service * 16 +
|
|
|
nb_sorties_mutation_service * 17 +
|
|
|
nb_entrees_mutation_activite * 18 +
|
|
|
nb_sorties_mutation_activite * 19 +
|
|
|
nb_entrees_mutation_etage * 20 +
|
|
|
nb_sorties_mutation_etage * 21 +
|
|
|
nb_chambres_particulieres * 22 +
|
|
|
nb_entrees_mutation_unite_medicale * 23 +
|
|
|
nb_sorties_mutation_unite_medicale * 24
|
|
|
) AS key
|
|
|
FROM w_mouvements_sejour
|
|
|
GROUP BY 1;
|
|
|
|
|
|
CREATE INDEX w_mouvements_sejour_key_i1
|
|
|
ON w_mouvements_sejour_key
|
|
|
USING btree
|
|
|
(no_sejour);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS p_mouvements_sejour_key;
|
|
|
CREATE TEMP TABLE p_mouvements_sejour_key AS
|
|
|
SELECT
|
|
|
no_sejour,
|
|
|
SUM(1 +
|
|
|
extract('day' FROM date) * 2 +
|
|
|
heure_debut * 3 +
|
|
|
heure_fin * 4 +
|
|
|
medecin_sejour_id * 5 +
|
|
|
lieu_id * 6 +
|
|
|
nb_jours_js_non_inclus * 7 +
|
|
|
nb_entrees_directes * 8 +
|
|
|
nb_entrees_directes * 9 +
|
|
|
nb_sorties_directes * 10 +
|
|
|
nb_urgences * 11 +
|
|
|
nb_externes * 12 +
|
|
|
nb_ambulatoires * 13 +
|
|
|
nb_jours_js_inclus * 14 +
|
|
|
nb_seances * 15 +
|
|
|
nb_entrees_mutation_service * 16 +
|
|
|
nb_sorties_mutation_service * 17 +
|
|
|
nb_entrees_mutation_activite * 18 +
|
|
|
nb_sorties_mutation_activite * 19 +
|
|
|
nb_entrees_mutation_etage * 20 +
|
|
|
nb_sorties_mutation_etage * 21 +
|
|
|
nb_chambres_particulieres * 22 +
|
|
|
nb_entrees_mutation_unite_medicale * 23 +
|
|
|
nb_sorties_mutation_unite_medicale * 24
|
|
|
) AS key
|
|
|
FROM activite[PX].p_mouvements_sejour
|
|
|
GROUP BY 1;
|
|
|
|
|
|
CREATE INDEX p_mouvements_sejour_key_i1
|
|
|
ON p_mouvements_sejour_key
|
|
|
USING btree
|
|
|
(no_sejour);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ecarts_mouvements;
|
|
|
|
|
|
CREATE TEMP TABLE w_ecarts_mouvements AS
|
|
|
SELECT w_mouvements_sejour_key.no_sejour
|
|
|
FROM w_mouvements_sejour_key LEFT JOIN p_mouvements_sejour_key ON p_mouvements_sejour_key.no_sejour = w_mouvements_sejour_key.no_sejour
|
|
|
WHERE p_mouvements_sejour_key.key IS DISTINCT FROM w_mouvements_sejour_key.key;
|
|
|
|
|
|
DELETE FROM activite[PX].p_mouvements_sejour WHERE no_sejour IN (SELECt no_sejour FROM w_ecarts_mouvements);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- generation
|
|
|
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_mouvements_sejour_1');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_mouvements_sejour_2');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_mouvements_sejour_3');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_mouvements_sejour_4');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_mouvements_sejour_5');
|
|
|
|
|
|
INSERT INTO activite[PX].p_mouvements_sejour(
|
|
|
sejour_id, no_sejour, date, nb_jours_js_non_inclus,
|
|
|
lieu_id, nb_entrees_directes, nb_sorties_directes,
|
|
|
nb_urgences, nb_externes, nb_ambulatoires, medecin_sejour_id,
|
|
|
nb_jours_js_inclus, nb_seances, nb_entrees_mutation_service,
|
|
|
nb_sorties_mutation_service, nb_entrees_mutation_activite, nb_sorties_mutation_activite,
|
|
|
nb_entrees_mutation_etage, nb_sorties_mutation_etage, nb_chambres_particulieres,
|
|
|
heure_debut, heure_fin, est_jour_entree, est_jour_sortie, est_jour_hospitalisation,
|
|
|
est_chambre_particuliere,
|
|
|
nb_entrees_mutation_unite_medicale, nb_sorties_mutation_unite_medicale, nb_bebes, jour_semaine, is_weekend, est_mouvement_previsionnel)
|
|
|
SELECT sejour_id, no_sejour, date,nb_jours_js_non_inclus,
|
|
|
lieu_id, nb_entrees_directes, nb_sorties_directes,
|
|
|
nb_urgences, nb_externes, nb_ambulatoires, medecin_sejour_id,
|
|
|
nb_jours_js_inclus, nb_seances, nb_entrees_mutation_service,
|
|
|
nb_sorties_mutation_service, nb_entrees_mutation_activite, nb_sorties_mutation_activite,
|
|
|
nb_entrees_mutation_etage, nb_sorties_mutation_etage, nb_chambres_particulieres,
|
|
|
heure_debut, heure_fin, est_jour_entree, est_jour_sortie, est_jour_hospitalisation,
|
|
|
est_chambre_particuliere,
|
|
|
nb_entrees_mutation_unite_medicale, nb_sorties_mutation_unite_medicale, nb_bebes, jour_semaine, is_weekend, est_mouvement_previsionnel
|
|
|
FROM w_mouvements_sejour WHERE no_sejour IN (SELECT no_sejour FROM w_ecarts_mouvements)
|
|
|
ORDER BY no_sejour, sequence;
|
|
|
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_mouvements_sejour_1');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_mouvements_sejour_2');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_mouvements_sejour_3');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_mouvements_sejour_4');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_mouvements_sejour_5');
|
|
|
|
|
|
UPDATE activite[PX].p_sejours SET lieu_sortie_id = p_mouvements_sejour.lieu_id
|
|
|
FROM activite[PX].p_mouvements_sejour
|
|
|
WHERE p_sejours.no_sejour = p_mouvements_sejour.no_sejour
|
|
|
AND p_mouvements_sejour.date = p_sejours.date_sortie
|
|
|
AND lieu_sortie_id IS DISTINCT FROM p_mouvements_sejour.lieu_id;
|
|
|
|
|
|
UPDATE activite[PX].p_sejours SET lieu_sortie_id = p_mouvements_sejour.lieu_id
|
|
|
FROM activite[PX].p_mouvements_sejour
|
|
|
WHERE p_sejours.no_sejour = p_mouvements_sejour.no_sejour
|
|
|
AND p_mouvements_sejour.date = p_sejours.date_sortie AND p_mouvements_sejour.nb_sorties_directes = 1
|
|
|
AND (lieu_sortie_id <> p_mouvements_sejour.lieu_id OR lieu_sortie_id IS NULL);
|
|
|
|
|
|
UPDATE activite[PX].p_sejours SET lieu_sortie_id = p_mouvements_sejour.lieu_id
|
|
|
FROM activite[PX].p_mouvements_sejour
|
|
|
WHERE p_sejours.no_sejour = p_mouvements_sejour.no_sejour
|
|
|
AND (p_sejours.lieu_sortie_id = 0 OR lieu_sortie_id IS NULL);
|
|
|
|
|
|
UPDATE activite[PX].p_sejours SET lieu_sortie_id = 0
|
|
|
WHERE lieu_sortie_id IS NULL;
|
|
|
|
|
|
UPDATE activite[PX].p_sejours SET lieu_sortie_id = 0
|
|
|
WHERE p_sejours.code_prevu = '1' AND (p_sejours.lieu_sortie_id = 0 OR lieu_sortie_id IS NULL);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_sejours
|
|
|
SET type_sejour = '5'
|
|
|
WHERE type_sejour <> '5' AND
|
|
|
type_sejour <> '1' AND
|
|
|
type_sejour <> '9' AND
|
|
|
no_sejour IN (
|
|
|
SELECT no_sejour
|
|
|
FROM activite[PX].p_mouvements_sejour
|
|
|
WHERE nb_seances > 0);
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_mouvements_sejour
|
|
|
SET nb_externes = 0, nb_ambulatoires = 0
|
|
|
FROM activite[PX].p_sejours
|
|
|
WHERE p_mouvements_sejour.no_sejour = p_sejours.no_sejour AND
|
|
|
p_sejours.type_sejour = '5' AND
|
|
|
(
|
|
|
nb_externes <> 0 OR
|
|
|
nb_ambulatoires <> 0
|
|
|
)
|
|
|
;
|
|
|
|
|
|
-- Présence HDJ
|
|
|
UPDATE activite.p_mouvements_sejour
|
|
|
SET est_jour_hospitalisation = '0'
|
|
|
FROM
|
|
|
(
|
|
|
SELECT no_sejour, date
|
|
|
FROM activite.p_mouvements_sejour
|
|
|
LEFT JOIN prod_qsp.HOSPI_PLANNING ON no_sejour = N_HOSPI AND
|
|
|
code_journee = 'P' AND
|
|
|
code_calendrier = 'HDJ' AND
|
|
|
date = date(date_jour)
|
|
|
WHERE no_sejour IN (SELECT N_HOSPI FROM prod_qsp.HOSPI_PLANNING WHERE code_journee = 'P' AND code_calendrier = 'HDJ') AND
|
|
|
est_jour_hospitalisation = '1' AND
|
|
|
N_HOSPI IS NULL
|
|
|
ORDER BY 1,2
|
|
|
) subview
|
|
|
WHERE p_mouvements_sejour.no_sejour = subview.no_sejour AND
|
|
|
p_mouvements_sejour.date = subview.date
|
|
|
;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="FACTURE" label="RECUPERATION DES FACTURES">
|
|
|
|
|
|
<NODE label="Entêtes">
|
|
|
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_1');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_2');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_3');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_4');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_5');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_6');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_7');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_8');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_9');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_10');
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_sejours_orga CASCADE;
|
|
|
|
|
|
CREATE TEMP TABLE w_sejours_orga AS
|
|
|
SELECT no_sejour,
|
|
|
p_sejours.oid as sejour_id,
|
|
|
p_sejours.code_original,
|
|
|
p_sejours.date_entree,
|
|
|
p_sejours.date_sortie,
|
|
|
p_sejours.ghs_id,
|
|
|
p_sejours.lieu_sortie_id,
|
|
|
p_sejours.tiers_payant_0_id,
|
|
|
p_sejours.tiers_payant_1_id,
|
|
|
p_sejours.tiers_payant_2_id,
|
|
|
p_sejours.tiers_payant_22_id,
|
|
|
t_tiers_payant_1.code_original as tiers_payant_1_orga_code,
|
|
|
t_tiers_payant_2.code_original as tiers_payant_2_orga_code,
|
|
|
t_tiers_payant_22.code_original as tiers_payant_22_orga_code
|
|
|
FROM activite[PX].p_sejours, activite[PX].t_tiers_payant t_tiers_payant_1, activite[PX].t_tiers_payant t_tiers_payant_2, activite[PX].t_tiers_payant t_tiers_payant_22
|
|
|
WHERE p_sejours.etat = ''
|
|
|
AND tiers_payant_1_id = t_tiers_payant_1.oid
|
|
|
AND tiers_payant_2_id = t_tiers_payant_2.oid
|
|
|
AND tiers_payant_22_id = t_tiers_payant_22.oid;
|
|
|
|
|
|
CREATE INDEX w_sejours_orga_i1
|
|
|
ON w_sejours_orga
|
|
|
USING btree
|
|
|
(code_original);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_FACTURE_QSP_LOT;
|
|
|
CREATE TEMP TABLE w_FACTURE_QSP_LOT AS
|
|
|
SELECt NUM_FACT, MAX(N_LOT) AS N_LOT
|
|
|
FROM prod_qsp.FACTURE_LOT
|
|
|
GROUP BY 1;
|
|
|
|
|
|
CREATE INDEX w_FACTURE_QSP_LOT_i1
|
|
|
ON w_FACTURE_QSP_LOT
|
|
|
USING btree
|
|
|
(NUM_FACT);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_FACTURE_QSP_REG;
|
|
|
CREATE TEMP TABLE w_FACTURE_QSP_REG AS
|
|
|
SELECT
|
|
|
NUM_FACT,
|
|
|
MAX(CASE WHEN PRESTATION.TYPE_PREST <> 'H' THEN DT_VENT ELSE '00010101' END) AS DT_VENT_C,
|
|
|
MAX(CASE WHEN PRESTATION.TYPE_PREST = 'H' THEN DT_VENT ELSE '00010101' END) AS DT_VENT_H
|
|
|
FROM prod_qsp.VENTIL_PAIEMENT
|
|
|
JOIN prod_qsp.DET_VENT ON VENTIL_PAIEMENT.PAIEMENT_LIG = DET_VENT.PAIEMENT_LIG
|
|
|
JOIN prod_qsp.SAISIE ON DET_VENT.N_SAISIE = SAISIE.N_SAISIE
|
|
|
JOIN prod_qsp.PRESTATION ON SAISIE.CODE_PREST = PRESTATION.CODE_PREST
|
|
|
WHERE TRANS_CPTA <> 0
|
|
|
GROUP BY 1;
|
|
|
|
|
|
CREATE INDEX w_FACTURE_QSP_REG_i1
|
|
|
ON w_FACTURE_QSP_REG
|
|
|
USING btree
|
|
|
(NUM_FACT);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_FACTURE_QSP_DATES;
|
|
|
|
|
|
CREATE TEMP TABLE w_FACTURE_QSP_DATES AS
|
|
|
(SELECT NUM_FACT_AMO AS NUM_FACT, MIN(SAISIE.D_DEB) AS D_DEB, MAX(GREATEST(SAISIE.D_FIN,SAISIE.D_DEB)) AS D_FIN
|
|
|
FROM prod_qsp.FACT_LIGNE JOIN prod_qsp.SAISIE ON FACT_LIGNE.N_SAISIE = SAISIE.N_SAISIE
|
|
|
WHERE NUM_FACT_AMO <> 0
|
|
|
GROUP BY 1);
|
|
|
|
|
|
INSERT INTO w_FACTURE_QSP_DATES
|
|
|
(SELECT NUM_FACT_AMC AS NUM_FACT, MIN(SAISIE.D_DEB) AS D_DEB, MAX(GREATEST(SAISIE.D_FIN,SAISIE.D_DEB)) AS D_FIN
|
|
|
FROM prod_qsp.FACT_LIGNE JOIN prod_qsp.SAISIE ON FACT_LIGNE.N_SAISIE = SAISIE.N_SAISIE
|
|
|
WHERE NUM_FACT_AMC <> 0
|
|
|
GROUP BY 1);
|
|
|
|
|
|
INSERT INTO w_FACTURE_QSP_DATES
|
|
|
(SELECT NUM_FACT_ASS AS NUM_FACT, MIN(SAISIE.D_DEB) AS D_DEB, MAX(GREATEST(SAISIE.D_FIN,SAISIE.D_DEB)) AS D_FIN
|
|
|
FROM prod_qsp.FACT_LIGNE JOIN prod_qsp.SAISIE ON FACT_LIGNE.N_SAISIE = SAISIE.N_SAISIE
|
|
|
WHERE NUM_FACT_ASS <> 0
|
|
|
GROUP BY 1);
|
|
|
|
|
|
CREATE INDEX w_FACTURE_QSP_DATES_i1
|
|
|
ON w_FACTURE_QSP_DATES
|
|
|
USING btree
|
|
|
(NUM_FACT);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_FACTURE_QSP_AVOIR;
|
|
|
|
|
|
CREATE TEMP TABLE w_FACTURE_QSP_AVOIR AS
|
|
|
SELECT
|
|
|
N_HOSPI,
|
|
|
NUM_FACT,
|
|
|
trim(to_char(to_number(substr(FACTURE.NUM_FACT,2,7),999999999), '00000000')) AS no_facture_od_avoir
|
|
|
FROM prod_qsp.FACTURE
|
|
|
JOIN w_sejours_orga ON FACTURE.N_HOSPI = w_sejours_orga.code_original
|
|
|
WHERE NUM_FACT > 90000000
|
|
|
UNION ALL
|
|
|
SELECT
|
|
|
N_HOSPI,
|
|
|
to_number(substr(FACTURE.NUM_FACT,2,7),999999999) AS NUM_FACT,
|
|
|
trim(to_char(FACTURE.NUM_FACT, '00000000')) AS no_facture_od_avoir
|
|
|
FROM prod_qsp.FACTURE
|
|
|
JOIN w_sejours_orga ON FACTURE.N_HOSPI = w_sejours_orga.code_original
|
|
|
WHERE NUM_FACT > 90000000;
|
|
|
|
|
|
CREATE INDEX w_FACTURE_QSP_AVOIR_i1
|
|
|
ON w_FACTURE_QSP_AVOIR
|
|
|
USING btree
|
|
|
(NUM_FACT);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_FACTURE_QSP_REF;
|
|
|
CREATE TEMP TABLE w_FACTURE_QSP_REF AS
|
|
|
SELECT
|
|
|
FACTURE.N_HOSPI,
|
|
|
MAX(CASE WHEN TIERS = '1' AND w_FACTURE_QSP_AVOIR IS NULL THEN FACTURE.NUM_FACT ELSE NULL END) AS NUM_FACT_REFERENCE,
|
|
|
MAX(CASE WHEN TIERS = '1' AND w_FACTURE_QSP_AVOIR IS NULL THEN FACTURE.NUM_FACT ELSE NULL END) AS NUM_FACT_1,
|
|
|
MAX(CASE WHEN TIERS = '2' AND w_FACTURE_QSP_AVOIR IS NULL THEN FACTURE.NUM_FACT ELSE NULL END) AS NUM_FACT_2,
|
|
|
MAX(CASE WHEN TIERS = '3' AND w_FACTURE_QSP_AVOIR IS NULL THEN FACTURE.NUM_FACT ELSE NULL END) AS NUM_FACT_0,
|
|
|
MAX(CASE WHEN TIERS = '1' AND ETAT IN (1, 2) THEN FACTURE.NUM_FACT ELSE NULL END) AS NUM_FACT_1_B,
|
|
|
MAX(CASE WHEN TIERS = '2' AND ETAT IN (1, 2) THEN FACTURE.NUM_FACT ELSE NULL END) AS NUM_FACT_2_B,
|
|
|
MAX(CASE WHEN TIERS = '3' AND ETAT IN (1, 2) THEN FACTURE.NUM_FACT ELSE NULL END) AS NUM_FACT_0_B
|
|
|
FROM prod_qsp.FACTURE
|
|
|
LEFT JOIN w_FACTURE_QSP_AVOIR ON FACTURE.NUM_FACT = w_FACTURE_QSP_AVOIR.NUM_FACT
|
|
|
GROUP BY 1;
|
|
|
|
|
|
UPDATE w_FACTURE_QSP_REF SET NUM_FACT_REFERENCE = NUM_FACT_2 WHERE NUM_FACT_REFERENCE IS NULL AND NUM_FACT_2 IS NOT NULL;
|
|
|
UPDATE w_FACTURE_QSP_REF SET NUM_FACT_REFERENCE = NUM_FACT_0 WHERE NUM_FACT_REFERENCE IS NULL AND NUM_FACT_0 IS NOT NULL;
|
|
|
UPDATE w_FACTURE_QSP_REF SET NUM_FACT_REFERENCE = NUM_FACT_1_B WHERE NUM_FACT_REFERENCE IS NULL AND NUM_FACT_1_B IS NOT NULL;
|
|
|
UPDATE w_FACTURE_QSP_REF SET NUM_FACT_REFERENCE = NUM_FACT_2_B WHERE NUM_FACT_REFERENCE IS NULL AND NUM_FACT_2_B IS NOT NULL;
|
|
|
UPDATE w_FACTURE_QSP_REF SET NUM_FACT_REFERENCE = NUM_FACT_0_B WHERE NUM_FACT_REFERENCE IS NULL AND NUM_FACT_0_B IS NOT NULL;
|
|
|
|
|
|
CREATE INDEX w_FACTURE_QSP_REF_i1
|
|
|
ON w_FACTURE_QSP_REF
|
|
|
USING btree
|
|
|
(N_HOSPI);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_FACTURE_QSP;
|
|
|
CREATE TEMP TABLE w_FACTURE_QSP AS
|
|
|
SELECT
|
|
|
trim(to_char(FACTURE.NUM_FACT, '00000000')) AS no_facture,
|
|
|
|
|
|
CASE
|
|
|
WHEN ETAT IN (1, 2) AND w_FACTURE_QSP_AVOIR.no_facture_od_avoir IS NOT NULL THEN 'X'
|
|
|
WHEN ETAT IN (1) THEN '0'
|
|
|
WHEN ETAT IN (2) THEN '2'
|
|
|
WHEN ETAT IN (3) THEN '1'
|
|
|
ELSE '0' END AS type_facture,
|
|
|
|
|
|
'1'::text AS code_facture,
|
|
|
date(FACTURE.DATE_SYS) AS date_facture,
|
|
|
|
|
|
trim(to_char(NUM_FACT_REFERENCE, '00000000')) AS no_facture_reference,
|
|
|
COALESCE(w_FACTURE_QSP_AVOIR.no_facture_od_avoir,'') AS no_facture_od_avoir,
|
|
|
|
|
|
CASE WHEN TRANS_CMPTA = '1' THEN '1' ELSE '0' END AS code_vente,
|
|
|
CASE WHEN TRANS_CMPTA = '1' THEN date(FACTURE.DT_FACT) ELSE COALESCE(date(FACTURE.DT_FACT),'20991231') END AS date_vente,
|
|
|
CASE WHEN TRANS_CMPTA = '1' THEN extract('year' FROM FACTURE.DT_FACT) * 100 + extract('month' FROM FACTURE.DT_FACT) ELSE 209912 END AS mois_vente,
|
|
|
|
|
|
TOT_SEJ AS montant_facture_c,
|
|
|
CASE WHEN tiers = '1' THEN TOT_SEJ ELSE 0 END AS montant_facture_1_c,
|
|
|
CASE WHEN tiers = '2' THEN TOT_SEJ ELSE 0 END AS montant_facture_2_c,
|
|
|
0::numeric AS montant_facture_22_c,
|
|
|
CASE WHEN tiers = '3' THEN TOT_SEJ ELSE 0 END AS montant_facture_0_c,
|
|
|
|
|
|
TOT_HON AS montant_facture_h,
|
|
|
CASE WHEN tiers = '1' THEN TOT_HON ELSE 0 END AS montant_facture_1_h,
|
|
|
CASE WHEN tiers = '2' THEN TOT_HON ELSE 0 END AS montant_facture_2_h,
|
|
|
0::numeric AS montant_facture_22_h,
|
|
|
CASE WHEN tiers = '3' THEN TOT_HON ELSE 0 END AS montant_facture_0_h,
|
|
|
|
|
|
TOT_SEJ AS montant_comptabilise_c,
|
|
|
CASE WHEN tiers = '1' THEN TOT_SEJ ELSE 0 END AS montant_comptabilise_1_c,
|
|
|
CASE WHEN tiers = '2' THEN TOT_SEJ ELSE 0 END AS montant_comptabilise_2_c,
|
|
|
0::numeric AS montant_comptabilise_22_c,
|
|
|
CASE WHEN tiers = '3' THEN TOT_SEJ ELSE 0 END AS montant_comptabilise_0_c,
|
|
|
|
|
|
TOT_HON AS montant_comptabilise_h,
|
|
|
CASE WHEN tiers = '1' THEN TOT_HON ELSE 0 END AS montant_comptabilise_1_h,
|
|
|
CASE WHEN tiers = '2' THEN TOT_HON ELSE 0 END AS montant_comptabilise_2_h,
|
|
|
0::numeric AS montant_comptabilise_22_h,
|
|
|
CASE WHEN tiers = '3' THEN TOT_HON ELSE 0 END AS montant_comptabilise_0_h,
|
|
|
|
|
|
ENC_SEJ AS montant_regle_c,
|
|
|
CASE WHEN tiers = '1' THEN ENC_SEJ ELSE 0 END AS montant_regle_1_c,
|
|
|
CASE WHEN tiers = '2' THEN ENC_SEJ ELSE 0 END AS montant_regle_2_c,
|
|
|
0::numeric AS montant_regle_22_c,
|
|
|
CASE WHEN tiers = '3' THEN ENC_SEJ ELSE 0 END AS montant_regle_0_c,
|
|
|
|
|
|
ENC_HON AS montant_regle_h,
|
|
|
CASE WHEN tiers = '1' THEN ENC_HON ELSE 0 END AS montant_regle_1_h,
|
|
|
CASE WHEN tiers = '2' THEN ENC_HON ELSE 0 END AS montant_regle_2_h,
|
|
|
0::numeric AS montant_regle_22_h,
|
|
|
CASE WHEN tiers = '3' THEN ENC_HON ELSE 0 END AS montant_regle_0_h,
|
|
|
|
|
|
CASE WHEN ghs_id <> 0 THEN date_entree
|
|
|
WHEN date_sortie - date_entree < 8 THEN date_entree
|
|
|
ELSE date(D_DEB) END AS date_debut,
|
|
|
CASE WHEN ghs_id <> 0 THEN date_sortie
|
|
|
WHEN date_sortie - date_entree < 8 THEN date_sortie
|
|
|
ELSE date(D_FIN) END AS date_fin,
|
|
|
|
|
|
|
|
|
CASE WHEN tiers = '1' THEN COALESCE(LOT.DATE_BORD,'00010101') ELSE '00010101' END AS date_expedition,
|
|
|
CASE WHEN tiers = '1' THEN COALESCE(LOT.DATE_BORD,'00010101') ELSE '00010101' END AS date_expedition_1,
|
|
|
CASE WHEN tiers = '2' THEN COALESCE(LOT.DATE_BORD,'00010101') ELSE '00010101' END AS date_expedition_2,
|
|
|
'00010101'::date AS date_expedition_22,
|
|
|
CASE WHEN tiers = '3' THEN COALESCE(LOT.DATE_BORD,'00010101') ELSE '00010101' END AS date_expedition_0,
|
|
|
CASE WHEN tiers = '1' THEN COALESCE(w_FACTURE_QSP_LOT.N_LOT::text,'') ELSE '' END AS no_bordereau_1,
|
|
|
CASE WHEN tiers = '2' THEN COALESCE(w_FACTURE_QSP_LOT.N_LOT::text,'') ELSE '' END AS no_bordereau_2,
|
|
|
''::text AS no_bordereau_22,
|
|
|
CASE WHEN tiers = '3' THEN COALESCE(w_FACTURE_QSP_LOT.N_LOT::text,'') ELSE '' END AS no_bordereau_0,
|
|
|
CASE WHEN tiers = '1' AND w_FACTURE_QSP_LOT.N_LOT IS NOT NULL THEN '1' ELSE '0' END AS code_expedie_1,
|
|
|
CASE WHEN tiers = '2' AND w_FACTURE_QSP_LOT.N_LOT IS NOT NULL THEN '1' ELSE '0' END AS code_expedie_2,
|
|
|
'0'::text AS code_expedie_22,
|
|
|
CASE WHEN tiers = '3' AND w_FACTURE_QSP_LOT.N_LOT IS NOT NULL THEN '1' ELSE '0' END AS code_expedie_0,
|
|
|
|
|
|
GREATEST(COALESCE(w_FACTURE_QSP_REG.DT_VENT_C,'00010101'), COALESCE(w_FACTURE_QSP_REG.DT_VENT_H,'00010101')) AS date_solde,
|
|
|
COALESCE(w_FACTURE_QSP_REG.DT_VENT_C,'00010101') AS date_solde_c,
|
|
|
COALESCE(w_FACTURE_QSP_REG.DT_VENT_H,'00010101') AS date_solde_h,
|
|
|
CASE WHEN tiers = '1' THEN COALESCE(w_FACTURE_QSP_REG.DT_VENT_C,'00010101') ELSE '00010101' END AS date_solde_1_c,
|
|
|
CASE WHEN tiers = '1' THEN COALESCE(w_FACTURE_QSP_REG.DT_VENT_H,'00010101') ELSE '00010101' END AS date_solde_1_h,
|
|
|
CASE WHEN tiers = '2' THEN COALESCE(w_FACTURE_QSP_REG.DT_VENT_C,'00010101') ELSE '00010101' END AS date_solde_2_c,
|
|
|
CASE WHEN tiers = '2' THEN COALESCE(w_FACTURE_QSP_REG.DT_VENT_H,'00010101') ELSE '00010101' END AS date_solde_2_h,
|
|
|
'00010101'::date AS date_solde_22_c,
|
|
|
'00010101'::date AS date_solde_22_h,
|
|
|
CASE WHEN tiers = '3' THEN COALESCE(w_FACTURE_QSP_REG.DT_VENT_C,'00010101') ELSE '00010101' END AS date_solde_0_c,
|
|
|
CASE WHEN tiers = '3' THEN COALESCE(w_FACTURE_QSP_REG.DT_VENT_H,'00010101') ELSE '00010101' END AS date_solde_0_h,
|
|
|
|
|
|
|
|
|
GREATEST(COALESCE(w_FACTURE_QSP_REG.DT_VENT_C,'00010101'), COALESCE(w_FACTURE_QSP_REG.DT_VENT_H,'00010101')) AS date_solde_reference,
|
|
|
COALESCE(w_FACTURE_QSP_REG.DT_VENT_C,'00010101') AS date_solde_reference_c,
|
|
|
COALESCE(w_FACTURE_QSP_REG.DT_VENT_H,'00010101') AS date_solde_reference_h,
|
|
|
CASE WHEN tiers = '1' THEN COALESCE(w_FACTURE_QSP_REG.DT_VENT_C,'00010101') ELSE '00010101' END AS date_solde_reference_1_c,
|
|
|
CASE WHEN tiers = '1' THEN COALESCE(w_FACTURE_QSP_REG.DT_VENT_H,'00010101') ELSE '00010101' END AS date_solde_reference_1_h,
|
|
|
CASE WHEN tiers = '2' THEN COALESCE(w_FACTURE_QSP_REG.DT_VENT_C,'00010101') ELSE '00010101' END AS date_solde_reference_2_c,
|
|
|
CASE WHEN tiers = '2' THEN COALESCE(w_FACTURE_QSP_REG.DT_VENT_H,'00010101') ELSE '00010101' END AS date_solde_reference_2_h,
|
|
|
'00010101'::date AS date_solde_reference_22_c,
|
|
|
'00010101'::date AS date_solde_reference_22_h,
|
|
|
CASE WHEN tiers = '3' THEN COALESCE(w_FACTURE_QSP_REG.DT_VENT_C,'00010101') ELSE '00010101' END AS date_solde_reference_0_c,
|
|
|
CASE WHEN tiers = '3' THEN COALESCE(w_FACTURE_QSP_REG.DT_VENT_H,'00010101') ELSE '00010101' END AS date_solde_reference_0_h,
|
|
|
|
|
|
|
|
|
|
|
|
FACTURE.*,
|
|
|
w_sejours_orga.*
|
|
|
|
|
|
FROM prod_qsp.FACTURE
|
|
|
JOIN w_sejours_orga ON FACTURE.N_HOSPI = w_sejours_orga.code_original
|
|
|
LEFT JOIN w_FACTURE_QSP_DATES ON FACTURE.NUM_FACT = w_FACTURE_QSP_DATES.NUM_FACT
|
|
|
LEFT JOIN w_FACTURE_QSP_LOT ON FACTURE.NUM_FACT = w_FACTURE_QSP_LOT.NUM_FACT
|
|
|
LEFT JOIN w_FACTURE_QSP_REG ON FACTURE.NUM_FACT = w_FACTURE_QSP_REG.NUM_FACT
|
|
|
LEFT JOIN prod_qsp.LOT ON w_FACTURE_QSP_LOT.N_LOT = LOT.N_LOT
|
|
|
LEFT JOIN w_FACTURE_QSP_AVOIR ON FACTURE.NUM_FACT = w_FACTURE_QSP_AVOIR.NUM_FACT
|
|
|
JOIN w_FACTURE_QSP_REF ON FACTURE.N_HOSPI = w_FACTURE_QSP_REF.N_HOSPI;
|
|
|
|
|
|
CREATE INDEX w_FACTURE_QSP_i1
|
|
|
ON w_FACTURE_QSP
|
|
|
USING btree
|
|
|
(NUM_FACT);
|
|
|
|
|
|
CREATE INDEX w_FACTURE_QSP_i2
|
|
|
ON w_FACTURE_QSP
|
|
|
USING btree
|
|
|
(no_facture);
|
|
|
|
|
|
CREATE INDEX w_FACTURE_QSP_i3
|
|
|
ON w_FACTURE_QSP
|
|
|
USING btree
|
|
|
(no_facture_od_avoir);
|
|
|
|
|
|
CREATE INDEX w_FACTURE_QSP_i4
|
|
|
ON w_FACTURE_QSP
|
|
|
USING btree
|
|
|
(no_facture_reference);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ods_avoir;
|
|
|
|
|
|
CREATE TEMP TABLE w_ods_avoir AS
|
|
|
SELECT p_factures.no_facture, p_factures.no_facture_od_avoir, p_factures_avoir.date_facture AS date_od_avoir,
|
|
|
SUM(p_factures.montant_comptabilise_c + p_factures.montant_comptabilise_h) AS montant_comptabilise,
|
|
|
SUM(p_factures.montant_regle_c + p_factures.montant_regle_h) AS montant_regle,
|
|
|
SUM(p_factures_avoir.montant_comptabilise_c + p_factures_avoir.montant_comptabilise_h) AS montant_facture_avoir,
|
|
|
SUM(p_factures_avoir.montant_regle_c + p_factures_avoir.montant_regle_h) AS montant_regle_avoir
|
|
|
FROM w_FACTURE_QSP p_factures JOIN w_FACTURE_QSP p_factures_avoir ON p_factures.no_facture = p_factures_avoir.no_facture_od_avoir
|
|
|
WHERE p_factures.type_facture = 'X' AND p_factures_avoir.type_facture = '1'
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING SUM(p_factures.montant_comptabilise_c + p_factures.montant_comptabilise_h) = 0 - SUM(p_factures_avoir.montant_comptabilise_c + p_factures_avoir.montant_comptabilise_h)
|
|
|
AND SUM(p_factures.montant_regle_c + p_factures.montant_regle_h) = 0
|
|
|
AND SUM(p_factures_avoir.montant_regle_c + p_factures_avoir.montant_regle_h) = 0;
|
|
|
|
|
|
CREATE INDEX w_ods_avoir_i1
|
|
|
ON w_ods_avoir
|
|
|
USING btree
|
|
|
(no_facture);
|
|
|
|
|
|
CREATE INDEX w_ods_avoir_i2
|
|
|
ON w_ods_avoir
|
|
|
USING btree
|
|
|
(no_facture_od_avoir);
|
|
|
|
|
|
UPDATE w_FACTURE_QSP SET
|
|
|
date_solde_c = date_od_avoir,
|
|
|
date_solde_0_c = date_od_avoir,
|
|
|
date_solde_1_c = date_od_avoir,
|
|
|
date_solde_2_c = date_od_avoir,
|
|
|
date_solde_22_c = date_od_avoir,
|
|
|
date_solde_h = date_od_avoir,
|
|
|
date_solde_0_h = date_od_avoir,
|
|
|
date_solde_1_h = date_od_avoir,
|
|
|
date_solde_2_h = date_od_avoir,
|
|
|
date_solde_22_h = date_od_avoir,
|
|
|
montant_regle_c = montant_comptabilise_c,
|
|
|
montant_regle_0_c = montant_comptabilise_0_c,
|
|
|
montant_regle_1_c = montant_comptabilise_1_c,
|
|
|
montant_regle_2_c = montant_comptabilise_2_c,
|
|
|
montant_regle_22_c = montant_comptabilise_22_c,
|
|
|
montant_regle_h = montant_comptabilise_h,
|
|
|
montant_regle_0_h = montant_comptabilise_0_h,
|
|
|
montant_regle_1_h = montant_comptabilise_1_h,
|
|
|
montant_regle_2_h = montant_comptabilise_2_h,
|
|
|
montant_regle_22_h = montant_comptabilise_22_h
|
|
|
FROM w_ods_avoir
|
|
|
WHERE w_FACTURE_QSP.no_facture = w_ods_avoir.no_facture AND w_FACTURE_QSP.no_facture_od_avoir <> '';
|
|
|
|
|
|
UPDATE w_FACTURE_QSP SET
|
|
|
date_solde_c = date_od_avoir,
|
|
|
date_solde_0_c = date_od_avoir,
|
|
|
date_solde_1_c = date_od_avoir,
|
|
|
date_solde_2_c = date_od_avoir,
|
|
|
date_solde_22_c = date_od_avoir,
|
|
|
date_solde_h = date_od_avoir,
|
|
|
date_solde_0_h = date_od_avoir,
|
|
|
date_solde_1_h = date_od_avoir,
|
|
|
date_solde_2_h = date_od_avoir,
|
|
|
date_solde_22_h = date_od_avoir,
|
|
|
montant_regle_c = montant_comptabilise_c,
|
|
|
montant_regle_0_c = montant_comptabilise_0_c,
|
|
|
montant_regle_1_c = montant_comptabilise_1_c,
|
|
|
montant_regle_2_c = montant_comptabilise_2_c,
|
|
|
montant_regle_22_c = montant_comptabilise_22_c,
|
|
|
montant_regle_h = montant_comptabilise_h,
|
|
|
montant_regle_0_h = montant_comptabilise_0_h,
|
|
|
montant_regle_1_h = montant_comptabilise_1_h,
|
|
|
montant_regle_2_h = montant_comptabilise_2_h,
|
|
|
montant_regle_22_h = montant_comptabilise_22_h
|
|
|
FROM w_ods_avoir
|
|
|
WHERE w_FACTURE_QSP.no_facture = w_ods_avoir.no_facture_od_avoir AND w_FACTURE_QSP.no_facture_od_avoir <> '';
|
|
|
|
|
|
UPDATE w_FACTURE_QSP
|
|
|
SET
|
|
|
date_solde_0_c = CASE WHEN montant_comptabilise_0_c = 0 THEN '00010101' WHEN montant_comptabilise_0_c = montant_regle_0_c THEN date_solde_0_c ELSE '00010101' END,
|
|
|
date_solde_0_h = CASE WHEN montant_comptabilise_0_h = 0 THEN '00010101' WHEN montant_comptabilise_0_h = montant_regle_0_h THEN date_solde_0_h ELSE '00010101' END,
|
|
|
date_solde_1_c = CASE WHEN montant_comptabilise_1_c = 0 THEN '00010101' WHEN montant_comptabilise_1_c = montant_regle_1_c THEN date_solde_1_c ELSE '00010101' END,
|
|
|
date_solde_1_h = CASE WHEN montant_comptabilise_1_h = 0 THEN '00010101' WHEN montant_comptabilise_1_h = montant_regle_1_h THEN date_solde_1_h ELSE '00010101' END,
|
|
|
date_solde_2_c = CASE WHEN montant_comptabilise_2_c = 0 THEN '00010101' WHEN montant_comptabilise_2_c = montant_regle_2_c THEN date_solde_2_c ELSE '00010101' END,
|
|
|
date_solde_2_h = CASE WHEN montant_comptabilise_2_h = 0 THEN '00010101' WHEN montant_comptabilise_2_h = montant_regle_2_h THEN date_solde_2_h ELSE '00010101' END,
|
|
|
date_solde_22_c = CASE WHEN montant_comptabilise_22_c = 0 THEN '00010101' WHEN montant_comptabilise_22_c = montant_regle_22_c THEN date_solde_22_c ELSE '00010101' END,
|
|
|
date_solde_22_h = CASE WHEN montant_comptabilise_22_h = 0 THEN '00010101' WHEN montant_comptabilise_22_h = montant_regle_22_h THEN date_solde_22_h ELSE '00010101' END
|
|
|
WHERE
|
|
|
(
|
|
|
date_solde_0_c <> CASE WHEN montant_comptabilise_0_c = 0 THEN '00010101' WHEN montant_comptabilise_0_c = montant_regle_0_c THEN date_solde_0_c ELSE '00010101' END OR
|
|
|
date_solde_0_h <> CASE WHEN montant_comptabilise_0_h = 0 THEN '00010101' WHEN montant_comptabilise_0_h = montant_regle_0_h THEN date_solde_0_h ELSE '00010101' END OR
|
|
|
date_solde_1_c <> CASE WHEN montant_comptabilise_1_c = 0 THEN '00010101' WHEN montant_comptabilise_1_c = montant_regle_1_c THEN date_solde_1_c ELSE '00010101' END OR
|
|
|
date_solde_1_h <> CASE WHEN montant_comptabilise_1_h = 0 THEN '00010101' WHEN montant_comptabilise_1_h = montant_regle_1_h THEN date_solde_1_h ELSE '00010101' END OR
|
|
|
date_solde_2_c <> CASE WHEN montant_comptabilise_2_c = 0 THEN '00010101' WHEN montant_comptabilise_2_c = montant_regle_2_c THEN date_solde_2_c ELSE '00010101' END OR
|
|
|
date_solde_2_h <> CASE WHEN montant_comptabilise_2_h = 0 THEN '00010101' WHEN montant_comptabilise_2_h = montant_regle_2_h THEN date_solde_2_h ELSE '00010101' END OR
|
|
|
date_solde_22_c <> CASE WHEN montant_comptabilise_22_c = 0 THEN '00010101' WHEN montant_comptabilise_22_c = montant_regle_22_c THEN date_solde_22_c ELSE '00010101' END OR
|
|
|
date_solde_22_h <> CASE WHEN montant_comptabilise_22_h = 0 THEN '00010101' WHEN montant_comptabilise_22_h = montant_regle_22_h THEN date_solde_22_h ELSE '00010101' END
|
|
|
)
|
|
|
;
|
|
|
|
|
|
UPDATE w_FACTURE_QSP
|
|
|
SET
|
|
|
date_solde = GREATEST(date_solde_0_c, date_solde_0_h, date_solde_1_c, date_solde_1_h, date_solde_2_c, date_solde_2_h, date_solde_22_c, date_solde_22_h),
|
|
|
date_solde_c = GREATEST(date_solde_0_c, date_solde_1_c, date_solde_2_c, date_solde_22_c),
|
|
|
date_solde_h = GREATEST(date_solde_0_h, date_solde_1_h, date_solde_2_h, date_solde_22_h)
|
|
|
|
|
|
WHERE (
|
|
|
date_solde IS DISTINCT FROM GREATEST(date_solde_0_c, date_solde_0_h, date_solde_1_c, date_solde_1_h, date_solde_2_c, date_solde_2_h, date_solde_22_c, date_solde_22_h) OR
|
|
|
date_solde_c IS DISTINCT FROM GREATEST(date_solde_0_c, date_solde_1_c, date_solde_2_c, date_solde_22_c) OR
|
|
|
date_solde_h IS DISTINCT FROM GREATEST(date_solde_0_h, date_solde_1_h, date_solde_2_h, date_solde_22_h)
|
|
|
)
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_FACTURE_QSP_REF;
|
|
|
|
|
|
CREATE TEMP TABLE w_FACTURE_QSP_REF AS
|
|
|
SELECT
|
|
|
no_facture_reference,
|
|
|
MAX(date_solde) AS date_solde_reference,
|
|
|
MAX(date_solde_c) AS date_solde_reference_c,
|
|
|
MAX(date_solde_h) AS date_solde_reference_h,
|
|
|
MAX(date_solde_0_c) AS date_solde_reference_0_c,
|
|
|
MAX(date_solde_0_h) AS date_solde_reference_0_h,
|
|
|
MAX(date_solde_1_c) AS date_solde_reference_1_c,
|
|
|
MAX(date_solde_1_h) AS date_solde_reference_1_h,
|
|
|
MAX(date_solde_2_c) AS date_solde_reference_2_c,
|
|
|
MAX(date_solde_2_h) AS date_solde_reference_2_h,
|
|
|
MAX(date_solde_22_c) AS date_solde_reference_22_c,
|
|
|
MAX(date_solde_22_h) AS date_solde_reference_22_h
|
|
|
FROM w_FACTURE_QSP
|
|
|
GROUP BY no_facture_reference;
|
|
|
|
|
|
CREATE INDEX w_FACTURE_QSP_REF_1
|
|
|
ON w_FACTURE_QSP_REF
|
|
|
USING btree
|
|
|
(no_facture_reference);
|
|
|
|
|
|
UPDATE w_FACTURE_QSP
|
|
|
SET
|
|
|
date_expedition = CASE WHEN date_expedition <> '00010101' THEN date_expedition ELSE '20991231' END,
|
|
|
date_expedition_0 = CASE WHEN date_expedition_0 <> '00010101' THEN date_expedition_0 ELSE '20991231' END,
|
|
|
date_expedition_1 = CASE WHEN date_expedition_1 <> '00010101' THEN date_expedition_1 ELSE '20991231' END,
|
|
|
date_expedition_2 = CASE WHEN date_expedition_2 <> '00010101' THEN date_expedition_2 ELSE '20991231' END,
|
|
|
date_expedition_22 = CASE WHEN date_expedition_22 <> '00010101' THEN date_expedition_22 ELSE '20991231' END,
|
|
|
|
|
|
date_solde = CASE WHEN date_solde <> '00010101' THEN date_solde ELSE '20991231' END,
|
|
|
date_solde_c = CASE WHEN date_solde_c <> '00010101' THEN date_solde_c ELSE '20991231' END,
|
|
|
date_solde_h = CASE WHEN date_solde_h <> '00010101' THEN date_solde_h ELSE '20991231' END,
|
|
|
date_solde_0_c = CASE WHEN date_solde_0_c <> '00010101' THEN date_solde_0_c ELSE '20991231' END,
|
|
|
date_solde_0_h = CASE WHEN date_solde_0_h <> '00010101' THEN date_solde_0_h ELSE '20991231' END,
|
|
|
date_solde_1_c = CASE WHEN date_solde_1_c <> '00010101' THEN date_solde_1_c ELSE '20991231' END,
|
|
|
date_solde_1_h = CASE WHEN date_solde_1_h <> '00010101' THEN date_solde_1_h ELSE '20991231' END,
|
|
|
date_solde_2_c = CASE WHEN date_solde_2_c <> '00010101' THEN date_solde_2_c ELSE '20991231' END,
|
|
|
date_solde_2_h = CASE WHEN date_solde_2_h <> '00010101' THEN date_solde_2_h ELSE '20991231' END,
|
|
|
date_solde_22_c = CASE WHEN date_solde_22_c <> '00010101' THEN date_solde_22_c ELSE '20991231' END,
|
|
|
date_solde_22_h = CASE WHEN date_solde_22_h <> '00010101' THEN date_solde_22_h ELSE '20991231' END,
|
|
|
|
|
|
|
|
|
date_solde_reference = CASE WHEN w_FACTURE_QSP_REF.date_solde_reference <> '00010101' THEN w_FACTURE_QSP_REF.date_solde_reference ELSE '20991231' END,
|
|
|
date_solde_reference_c = CASE WHEN w_FACTURE_QSP_REF.date_solde_reference_c <> '00010101' THEN w_FACTURE_QSP_REF.date_solde_reference_c ELSE '20991231' END,
|
|
|
date_solde_reference_h = CASE WHEN w_FACTURE_QSP_REF.date_solde_reference_h <> '00010101' THEN w_FACTURE_QSP_REF.date_solde_reference_h ELSE '20991231' END,
|
|
|
date_solde_reference_0_c = CASE WHEN w_FACTURE_QSP_REF.date_solde_reference_0_c <> '00010101' THEN w_FACTURE_QSP_REF.date_solde_reference_0_c ELSE '20991231' END,
|
|
|
date_solde_reference_0_h = CASE WHEN w_FACTURE_QSP_REF.date_solde_reference_0_h <> '00010101' THEN w_FACTURE_QSP_REF.date_solde_reference_0_h ELSE '20991231' END,
|
|
|
date_solde_reference_1_c = CASE WHEN w_FACTURE_QSP_REF.date_solde_reference_1_c <> '00010101' THEN w_FACTURE_QSP_REF.date_solde_reference_1_c ELSE '20991231' END,
|
|
|
date_solde_reference_1_h = CASE WHEN w_FACTURE_QSP_REF.date_solde_reference_1_h <> '00010101' THEN w_FACTURE_QSP_REF.date_solde_reference_1_h ELSE '20991231' END,
|
|
|
date_solde_reference_2_c = CASE WHEN w_FACTURE_QSP_REF.date_solde_reference_2_c <> '00010101' THEN w_FACTURE_QSP_REF.date_solde_reference_2_c ELSE '20991231' END,
|
|
|
date_solde_reference_2_h = CASE WHEN w_FACTURE_QSP_REF.date_solde_reference_2_h <> '00010101' THEN w_FACTURE_QSP_REF.date_solde_reference_2_h ELSE '20991231' END,
|
|
|
date_solde_reference_22_c = CASE WHEN w_FACTURE_QSP_REF.date_solde_reference_22_c <> '00010101' THEN w_FACTURE_QSP_REF.date_solde_reference_22_c ELSE '20991231' END,
|
|
|
date_solde_reference_22_h = CASE WHEN w_FACTURE_QSP_REF.date_solde_reference_22_h <> '00010101' THEN w_FACTURE_QSP_REF.date_solde_reference_22_h ELSE '20991231' END
|
|
|
FROM w_FACTURE_QSP_REF
|
|
|
WHERE w_FACTURE_QSP.no_facture_reference = w_FACTURE_QSP_REF.no_facture_reference;
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures(
|
|
|
no_sejour,
|
|
|
sejour_id,
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
type_facture,
|
|
|
code_facture,
|
|
|
date_facture,
|
|
|
code_vente,
|
|
|
date_vente,
|
|
|
mois_vente,
|
|
|
montant_facture_c,
|
|
|
montant_facture_h,
|
|
|
montant_regle_c,
|
|
|
montant_regle_h,
|
|
|
delai_facture,
|
|
|
delai_solde,
|
|
|
date_expedition,
|
|
|
delai_expedition,
|
|
|
tiers_payant_0_id,
|
|
|
tiers_payant_1_id,
|
|
|
tiers_payant_2_id,
|
|
|
tiers_payant_22_id,
|
|
|
date_solde,
|
|
|
date_solde_c,
|
|
|
date_solde_h,
|
|
|
date_solde_0_c,
|
|
|
date_solde_0_h,
|
|
|
date_solde_1_c,
|
|
|
date_solde_1_h,
|
|
|
date_solde_2_c,
|
|
|
date_solde_2_h,
|
|
|
date_solde_22_c,
|
|
|
date_solde_22_h,
|
|
|
date_expedition_0,
|
|
|
date_expedition_1,
|
|
|
date_expedition_2,
|
|
|
date_expedition_22,
|
|
|
code_expedie_0,
|
|
|
code_expedie_1,
|
|
|
code_expedie_2,
|
|
|
code_expedie_22,
|
|
|
no_bordereau_0,
|
|
|
no_bordereau_1,
|
|
|
no_bordereau_2,
|
|
|
no_bordereau_22,
|
|
|
montant_facture_0_c,
|
|
|
montant_facture_0_h,
|
|
|
montant_facture_1_c,
|
|
|
montant_facture_1_h,
|
|
|
montant_facture_2_c,
|
|
|
montant_facture_2_h,
|
|
|
montant_facture_22_c,
|
|
|
montant_facture_22_h,
|
|
|
montant_regle_0_c,
|
|
|
montant_regle_0_h,
|
|
|
montant_regle_1_c,
|
|
|
montant_regle_1_h,
|
|
|
montant_regle_2_c,
|
|
|
montant_regle_2_h,
|
|
|
montant_regle_22_c,
|
|
|
montant_regle_22_h,
|
|
|
delai_expedition_0,
|
|
|
delai_expedition_1,
|
|
|
delai_expedition_2,
|
|
|
delai_expedition_22,
|
|
|
delai_solde_0_c,
|
|
|
delai_solde_0_h,
|
|
|
delai_solde_1_c,
|
|
|
delai_solde_1_h,
|
|
|
delai_solde_2_c,
|
|
|
delai_solde_2_h,
|
|
|
delai_solde_22_c,
|
|
|
delai_solde_22_h,
|
|
|
ghs_id,
|
|
|
particularite_t2a,
|
|
|
code_cloture,
|
|
|
code_cp_demandee,
|
|
|
ghs_bebe1_id,
|
|
|
ghs_bebe2_id,
|
|
|
ghs_bebe3_id,
|
|
|
|
|
|
montant_comptabilise_c,
|
|
|
montant_comptabilise_h,
|
|
|
montant_comptabilise_0_c,
|
|
|
montant_comptabilise_0_h,
|
|
|
montant_comptabilise_1_c,
|
|
|
montant_comptabilise_1_h,
|
|
|
montant_comptabilise_2_c,
|
|
|
montant_comptabilise_2_h,
|
|
|
montant_comptabilise_22_c,
|
|
|
montant_comptabilise_22_h,
|
|
|
|
|
|
nb_rejets,
|
|
|
no_facture_od_avoir,
|
|
|
|
|
|
no_facture_reference,
|
|
|
date_solde_reference,
|
|
|
date_solde_reference_c,
|
|
|
date_solde_reference_h,
|
|
|
date_solde_reference_0_c,
|
|
|
date_solde_reference_0_h,
|
|
|
date_solde_reference_1_c,
|
|
|
date_solde_reference_1_h,
|
|
|
date_solde_reference_2_c,
|
|
|
date_solde_reference_2_h,
|
|
|
date_solde_reference_22_c,
|
|
|
date_solde_reference_22_h
|
|
|
)
|
|
|
SELECT
|
|
|
no_sejour,
|
|
|
sejour_id,
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
type_facture,
|
|
|
code_facture,
|
|
|
date_facture,
|
|
|
code_vente,
|
|
|
date_vente,
|
|
|
mois_vente,
|
|
|
|
|
|
montant_facture_c,
|
|
|
montant_facture_h,
|
|
|
montant_regle_c,
|
|
|
montant_regle_h,
|
|
|
0::numeric as delai_facture,
|
|
|
0::numeric as delai_solde,
|
|
|
date_expedition,
|
|
|
0::numeric as delai_expedition,
|
|
|
tiers_payant_0_id,
|
|
|
tiers_payant_1_id,
|
|
|
tiers_payant_2_id,
|
|
|
tiers_payant_22_id,
|
|
|
date_solde,
|
|
|
date_solde_c,
|
|
|
date_solde_h,
|
|
|
date_solde_0_c,
|
|
|
date_solde_0_h,
|
|
|
date_solde_1_c,
|
|
|
date_solde_1_h,
|
|
|
date_solde_2_c,
|
|
|
date_solde_2_h,
|
|
|
date_solde_22_c,
|
|
|
date_solde_22_h,
|
|
|
|
|
|
date_expedition_0,
|
|
|
date_expedition_1,
|
|
|
date_expedition_2,
|
|
|
date_expedition_22,
|
|
|
code_expedie_0,
|
|
|
code_expedie_1,
|
|
|
code_expedie_2,
|
|
|
'0'::text AS code_expedie_22,
|
|
|
no_bordereau_0,
|
|
|
no_bordereau_1,
|
|
|
no_bordereau_2,
|
|
|
''::text AS no_bordereau_22,
|
|
|
|
|
|
montant_facture_0_c,
|
|
|
montant_facture_0_h,
|
|
|
montant_facture_1_c,
|
|
|
montant_facture_1_h,
|
|
|
montant_facture_2_c,
|
|
|
montant_facture_2_h,
|
|
|
0::numeric AS montant_facture_22_c,
|
|
|
0::numeric AS montant_facture_22_h,
|
|
|
|
|
|
montant_regle_0_c,
|
|
|
montant_regle_0_h,
|
|
|
montant_regle_1_c,
|
|
|
montant_regle_1_h,
|
|
|
montant_regle_2_c,
|
|
|
montant_regle_2_h,
|
|
|
0::numeric AS montant_regle_22_c,
|
|
|
0::numeric AS montant_regle_22_h,
|
|
|
|
|
|
|
|
|
0 AS delai_expedition_0,
|
|
|
0 AS delai_expedition_1,
|
|
|
0 AS delai_expedition_2,
|
|
|
0 AS delai_expedition_22,
|
|
|
0 AS delai_solde_0_c,
|
|
|
0 AS delai_solde_0_h,
|
|
|
0 AS delai_solde_1_c,
|
|
|
0 AS delai_solde_1_h,
|
|
|
0 AS delai_solde_2_c,
|
|
|
0 AS delai_solde_2_h,
|
|
|
0 AS delai_solde_22_c,
|
|
|
0 AS delai_solde_22_h,
|
|
|
|
|
|
ghs_id,
|
|
|
'' as particularite_t2a,
|
|
|
|
|
|
'0' as code_cloture,
|
|
|
'0' as code_cp_demandee,
|
|
|
0 AS ghs_bebe1_id,
|
|
|
0 AS ghs_bebe2_id,
|
|
|
0 AS ghs_bebe3_id,
|
|
|
|
|
|
montant_comptabilise_c,
|
|
|
montant_comptabilise_h,
|
|
|
montant_comptabilise_0_c,
|
|
|
montant_comptabilise_0_h,
|
|
|
montant_comptabilise_1_c,
|
|
|
montant_comptabilise_1_h,
|
|
|
montant_comptabilise_2_c,
|
|
|
montant_comptabilise_2_h,
|
|
|
0::numeric AS montant_comptabilise_22_c,
|
|
|
0::numeric AS montant_comptabilise_22_h,
|
|
|
|
|
|
COALESCE(w_FACTURE_QSP.REJET,0) AS nb_rejets,
|
|
|
no_facture_od_avoir,
|
|
|
|
|
|
no_facture_reference,
|
|
|
date_solde_reference,
|
|
|
date_solde_reference_c,
|
|
|
date_solde_reference_h,
|
|
|
date_solde_reference_0_c,
|
|
|
date_solde_reference_0_h,
|
|
|
date_solde_reference_1_c,
|
|
|
date_solde_reference_1_h,
|
|
|
date_solde_reference_2_c,
|
|
|
date_solde_reference_2_h,
|
|
|
date_solde_reference_22_c,
|
|
|
date_solde_reference_22_h
|
|
|
|
|
|
|
|
|
FROM w_FACTURE_QSP;
|
|
|
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_1');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_2');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_3');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_4');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_5');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_6');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_7');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_8');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_9');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_10');
|
|
|
|
|
|
-- Séjours sans facturation
|
|
|
UPDATE activite[PX].p_sejours
|
|
|
SET est_sans_facturation = '1'
|
|
|
WHERE lieu_sortie_id IN
|
|
|
(SELECT oid FROM activite[PX].t_lieux WHERE
|
|
|
service_facturation_id IN
|
|
|
(SELECT oid FROM activite[PX].t_services_facturation WHERE est_sans_facturation = '1') OR
|
|
|
unite_fonctionnelle_id IN
|
|
|
(SELECT oid FROM activite[PX].t_unites_fonctionnelles WHERE est_sans_facturation = '1')
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
-- Séjours facturés partiellement
|
|
|
CREATE TEMP TABLE w_sejours_factures_partiellement AS
|
|
|
SELECT no_sejour
|
|
|
FROM activite[PX].p_sejours
|
|
|
JOIN activite[PX].t_lieux ON p_sejours.lieu_sortie_id = t_lieux.oid
|
|
|
JOIN activite[PX].t_services_facturation ON t_lieux.service_facturation_id = t_services_facturation.oid
|
|
|
JOIN base.t_ghm ON p_sejours.ghm_id = t_ghm.oid
|
|
|
WHERE tiers_payant_1_id <> 0 AND
|
|
|
no_sejour in (select no_sejour from activite[PX].p_factures where code_facture = '1') AND
|
|
|
no_sejour not in (select no_sejour from activite[PX].p_factures where montant_facture_1_c <> 0 OR montant_facture_1_h <> 0) AND
|
|
|
date_sortie >= '20130101' AND
|
|
|
p_sejours.type_sejour IN ('1','2') AND
|
|
|
t_services_facturation.texte NOT ILIKE '%ESTHETIQUE%'AND
|
|
|
t_ghm.code <> '09Z02A'
|
|
|
ORDER BY 1;
|
|
|
|
|
|
DELETE FROM w_sejours_factures_partiellement
|
|
|
USING prod_qsp.FACT_LIGNE
|
|
|
JOIN prod_qsp.SAISIE ON SAISIE.N_SAISIE = fact_ligne.N_SAISIE AND CODE_PREST IN ('GHS','PJ') AND (NUM_FACT_AMO <> 0 OR NUM_FACT_AMC <> 0 OR NUM_FACT_ASS <> 0 AND TAUX = 0)
|
|
|
WHERE FACT_LIGNE.N_HOSPI = w_sejours_factures_partiellement.no_sejour;
|
|
|
|
|
|
|
|
|
-- Séjours sans facture
|
|
|
DROP TABLE IF EXISTS w_factures_trous;
|
|
|
CREATE TEMP TABLE w_factures_trous AS
|
|
|
SELECT
|
|
|
p_sejours.finess,
|
|
|
p_sejours.no_sejour,
|
|
|
p_sejours.oid as sejour_id,
|
|
|
p_sejours.date_entree,
|
|
|
p_sejours.ghs_id,
|
|
|
p_sejours.tiers_payant_0_id,
|
|
|
p_sejours.tiers_payant_1_id,
|
|
|
p_sejours.tiers_payant_2_id,
|
|
|
p_sejours.tiers_payant_22_id,
|
|
|
p_sejours.code_cp_demandee,
|
|
|
COALESCE(t_services_facturation.avec_facturation_intermediaire,'') AS avec_facturation_intermediaire,
|
|
|
p_sejours.code_sorti,
|
|
|
CASE WHEN code_sorti = '1' THEN date_sortie ELSE date(now()) END AS date_sortie,
|
|
|
MAX(
|
|
|
CASE
|
|
|
WHEN p_factures.date_fin IS NOT NULL AND date_sortie - date_entree < 30 THEN date_sortie
|
|
|
ELSE p_factures.date_fin
|
|
|
END
|
|
|
) AS date_fin_facture,
|
|
|
date(MAX(COALESCE(
|
|
|
CASE
|
|
|
WHEN w_sejours_factures_partiellement.no_sejour IS NOT NULL THEN NULL
|
|
|
WHEN p_factures.date_fin IS NOT NULL AND date_sortie - date_entree < 30 THEN date_sortie
|
|
|
ELSE p_factures.date_fin
|
|
|
END + interval '1 day', p_sejours.date_entree))) AS date_debut_encours,
|
|
|
CASE WHEN code_sorti = '1' THEN date_sortie ELSE date(now()) END AS date_fin_encours
|
|
|
FROM activite[PX].p_sejours
|
|
|
LEFT JOIN activite[PX].p_factures ON p_sejours.no_sejour = p_factures.no_sejour AND no_facture NOT LIKE 'E%'
|
|
|
LEFT JOIN w_sejours_factures_partiellement ON p_sejours.no_sejour = w_sejours_factures_partiellement.no_sejour
|
|
|
JOIN activite[PX].t_lieux ON lieu_sortie_id = t_lieux.oid
|
|
|
JOIN activite[PX].t_services_facturation ON t_lieux.service_facturation_id = t_services_facturation.oid
|
|
|
WHERE p_sejours.etat = '' AND
|
|
|
p_sejours.est_sans_facturation IS DISTINCT FROM '1' AND
|
|
|
date_entree <= now() AND
|
|
|
p_sejours.type_sejour <> '6' AND
|
|
|
p_sejours.type_sejour <> '9'
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures(
|
|
|
finess,
|
|
|
no_sejour,
|
|
|
sejour_id,
|
|
|
no_facture,
|
|
|
no_facture_reference,
|
|
|
type_facture,
|
|
|
code_facture,
|
|
|
date_facture,
|
|
|
ghs_id,
|
|
|
tiers_payant_0_id, tiers_payant_1_id, tiers_payant_2_id, tiers_payant_22_id,
|
|
|
code_cp_demandee,
|
|
|
date_debut,
|
|
|
date_fin)
|
|
|
SELECT finess,
|
|
|
no_sejour,
|
|
|
sejour_id,
|
|
|
'E' || no_sejour || CASE WHEN avec_facturation_intermediaire = '1' THEN '_' || p_calendrier.mois ELSE '' END,
|
|
|
'E' || no_sejour || CASE WHEN avec_facturation_intermediaire = '1' THEN '_' || p_calendrier.mois ELSE '' END,
|
|
|
'E',
|
|
|
'0',
|
|
|
'20991231'::date,
|
|
|
ghs_id,
|
|
|
tiers_payant_0_id, tiers_payant_1_id, tiers_payant_2_id, tiers_payant_22_id,
|
|
|
code_cp_demandee ,
|
|
|
MIN(GREATEST(date_debut_encours, p_calendrier.date)),
|
|
|
MAX(LEAST(date_fin_encours, p_calendrier.date))
|
|
|
FROM w_factures_trous
|
|
|
JOIN base.p_calendrier ON p_calendrier.date BETWEEN date_debut_encours AND date_fin_encours
|
|
|
WHERE (date_debut_encours <= date_fin_encours or date_fin_facture is null)
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures SET
|
|
|
date_debut = date_entree,
|
|
|
date_fin = CASE WHEN code_sorti = '1' THEN date_sortie ELSE date_fin END
|
|
|
FROM activite[PX].p_sejours
|
|
|
JOIN activite[PX].t_lieux ON lieu_sortie_id = t_lieux.oid
|
|
|
JOIN activite[PX].t_services_facturation ON t_lieux.service_facturation_id = t_services_facturation.oid AND
|
|
|
avec_facturation_intermediaire IS DISTINCT FROM '1'
|
|
|
WHERE p_factures.no_sejour = p_sejours.no_sejour AND
|
|
|
CASE WHEN code_sorti = '1' THEN date_sortie ELSE date(now()) END - date_entree < 30 AND
|
|
|
(
|
|
|
p_factures.date_debut <> date_entree OR
|
|
|
p_factures.date_fin <> CASE WHEN code_sorti = '1' THEN date_sortie ELSE date_fin END
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Rejets">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_REJETS;
|
|
|
CREATE TEMP TABLE w_REJETS AS
|
|
|
SELECT no_facture,
|
|
|
GREATEST(
|
|
|
CASE WHEN date_expedition_1 <> '20991231' THEN date_expedition_1 ELSE '00010101' END,
|
|
|
CASE WHEN date_facture <> '20991231' THEN date_facture ELSE '00010101' END,
|
|
|
date_sortie
|
|
|
) AS date_rejet,
|
|
|
''::text AS code_rejet,
|
|
|
TRIM(MOTIF_REJ) AS texte_rejet
|
|
|
FROM w_FACTURE_QSP
|
|
|
WHERE REJET <> 0
|
|
|
ORDER BY MOTIF_REJ;
|
|
|
|
|
|
UPDATE w_REJETS SET
|
|
|
code_rejet = split_part(texte_rejet, ' ', 1),
|
|
|
texte_rejet = trim(substr(texte_rejet, length(split_part(texte_rejet, ' ', 1))+1, 9999));
|
|
|
|
|
|
UPDATE w_REJETS SET
|
|
|
texte_rejet = trim(substr(texte_rejet, 4, 9999))
|
|
|
WHERE split_part(texte_rejet, ' ', 1) = '000';
|
|
|
|
|
|
UPDATE w_REJETS SET
|
|
|
code_rejet = code_rejet || '-' || split_part(texte_rejet, ' ', 1),
|
|
|
texte_rejet = trim(substr(texte_rejet, length(split_part(texte_rejet, ' ', 1))+1, 9999))
|
|
|
WHERE split_part(texte_rejet, ' ', 1) BETWEEN '0' AND '9';
|
|
|
|
|
|
UPDATE w_REJETS SET
|
|
|
texte_rejet = trim(replace(texte_rejet, ':', ''))
|
|
|
WHERE texte_rejet like '%:%';
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_rejets(
|
|
|
no_facture, date_rejet, rejet_id, rejet_code, rejet_texte)
|
|
|
SELECT
|
|
|
no_facture ,
|
|
|
date_rejet ,
|
|
|
0,
|
|
|
code_rejet ,
|
|
|
texte_rejet
|
|
|
|
|
|
FROM w_REJETS;
|
|
|
|
|
|
INSERT INTO activite.t_rejets_noemie (texte, code)
|
|
|
SELECT DISTINCT rejet_texte, MAX(rejet_code)
|
|
|
FROM activite[PX].p_factures_rejets
|
|
|
LEFT JOIN activite.t_rejets_noemie ON (rejet_texte = t_rejets_noemie.texte)
|
|
|
WHERE t_rejets_noemie.oid IS NULL
|
|
|
GROUP BY 1;
|
|
|
|
|
|
UPDATE activite[PX].p_factures_rejets SET rejet_id = t_rejets_noemie.oid
|
|
|
FROM activite.t_rejets_noemie
|
|
|
WHERE rejet_texte = t_rejets_noemie.texte;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Lignes non facturées Clinique">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_PRIX_PREST;
|
|
|
CREATE TEMP TABLE w_PRIX_PREST AS
|
|
|
SELECT N_DIS, CODE_PREST, date(DATE_PRIX) AS DATE_PRIX, '20991231'::date AS DATE_PRIX_fin,
|
|
|
PRIX_PREST,
|
|
|
ROW_NUMBER() OVER (partition by N_DIS, CODE_PREST ORDER BY DATE_PRIX) AS prix_sequence
|
|
|
FROM prod_qsp.PRIX_PREST
|
|
|
ORDER BY N_DIS, CODE_PREST, DATE_PRIX
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_PRIX_PREST
|
|
|
SET DATE_PRIX_fin = w_PRIX_PREST_2.DATE_PRIX - interval '1 day'
|
|
|
FROM w_PRIX_PREST w_PRIX_PREST_2
|
|
|
WHERE w_PRIX_PREST.N_DIS = w_PRIX_PREST_2.N_DIS AND
|
|
|
w_PRIX_PREST.CODE_PREST = w_PRIX_PREST_2.CODE_PREST AND
|
|
|
w_PRIX_PREST.prix_sequence = w_PRIX_PREST_2.prix_sequence -1
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_lignes_non_facturees_c(
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
coefficient,
|
|
|
rubrique_facturation_id,
|
|
|
prestation_id,
|
|
|
prix_unitaire,
|
|
|
lieu_id)
|
|
|
SELECT
|
|
|
p_factures.no_facture,
|
|
|
date(SAISIE.D_DEB) AS date_debut,
|
|
|
date(COALESCE(SAISIE.D_FIN, SAISIE.D_DEB)) AS date_fin,
|
|
|
SAISIE.QTE * SAISIE.COEFF AS nb_rubrique,
|
|
|
1 AS coefficient,
|
|
|
t_rubriques_facturation.oid AS rubrique_facturation_id,
|
|
|
t_prestations.oid AS prestation_id,
|
|
|
COALESCE(CASE WHEN DET_TIPS.PU <> 0 THEN DET_TIPS.PU ELSE DET_TIPS.PU_TTC_TIPS END, PRIX_PREST, 0) AS prix_unitaire,
|
|
|
p_sejours.lieu_sortie_id AS lieu_id
|
|
|
FROM prod_qsp.SAISIE
|
|
|
LEFT JOIN prod_qsp.DET_TIPS ON DET_TIPS.N_SAISIE = SAISIE.N_SAISIE
|
|
|
LEFT JOIN w_PRIX_PREST ON
|
|
|
SAISIE.N_DIS = w_PRIX_PREST.N_DIS AND
|
|
|
SAISIE.CODE_PREST = w_PRIX_PREST.CODE_PREST AND
|
|
|
date(SAISIE.D_DEB) BETWEEN w_PRIX_PREST.DATE_PRIX AND w_PRIX_PREST.DATE_PRIX_fin
|
|
|
LEFT JOIN prod_qsp.FACT_LIGNE ON FACT_LIGNE.N_SAISIE = SAISIE.N_SAISIE AND
|
|
|
(
|
|
|
NUM_FACT_AMO <> 0 OR
|
|
|
NUM_FACT_AMC <> 0 OR
|
|
|
NUM_FACT_ASS <> 0
|
|
|
)
|
|
|
JOIN activite[PX].p_factures ON SAISIE.N_HOSPI = p_factures.no_sejour AND
|
|
|
date(SAISIE.D_DEB) BETWEEN p_factures.date_debut AND p_factures.date_fin
|
|
|
JOIN activite[PX].p_sejours ON p_factures.no_sejour = p_sejours.code_original AND p_sejours.etat = ''
|
|
|
JOIN prod_qsp.PRESTATION ON SAISIE.CODE_PREST = PRESTATION.CODE_PREST
|
|
|
LEFT JOIN activite[PX].t_rubriques_facturation ON PRESTATION.CODE_PREST = t_rubriques_facturation.code_original
|
|
|
LEFT JOIN activite.t_prestations ON PRESTATION.CODE_NORM = t_prestations.code_original
|
|
|
WHERE type_facture = 'E' AND
|
|
|
SUPPRIME <> '1' AND
|
|
|
SAISIE.CODE_PREST <> 'GHS' AND
|
|
|
PRESTATION.TYPE_PREST <> 'H' AND
|
|
|
FACT_LIGNE.N_SAISIE IS NULL AND
|
|
|
NOT (SAISIE.QTE > 1 AND
|
|
|
(
|
|
|
(date(SAISIE.D_FIN) - date(SAISIE.D_DEB) + 1) = SAISIE.QTE OR
|
|
|
(date(SAISIE.D_FIN) - date(SAISIE.D_DEB) ) = SAISIE.QTE
|
|
|
)
|
|
|
);
|
|
|
|
|
|
-- Multi prestations
|
|
|
INSERT INTO activite[PX].p_factures_lignes_non_facturees_c(
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
coefficient,
|
|
|
rubrique_facturation_id,
|
|
|
prestation_id,
|
|
|
prix_unitaire,
|
|
|
lieu_id)
|
|
|
SELECT
|
|
|
p_factures.no_facture,
|
|
|
p_calendrier.date AS date_debut,
|
|
|
p_calendrier.date AS date_fin,
|
|
|
1 * SAISIE.COEFF AS nb_rubrique,
|
|
|
1 AS coefficient,
|
|
|
t_rubriques_facturation.oid AS rubrique_facturation_id,
|
|
|
t_prestations.oid AS prestation_id,
|
|
|
COALESCE(CASE WHEN DET_TIPS.PU <> 0 THEN DET_TIPS.PU ELSE DET_TIPS.PU_TTC_TIPS END, PRIX_PREST, 0) AS prix_unitaire,
|
|
|
p_sejours.lieu_sortie_id AS lieu_id
|
|
|
FROM prod_qsp.SAISIE
|
|
|
LEFT JOIN prod_qsp.DET_TIPS ON DET_TIPS.N_SAISIE = SAISIE.N_SAISIE
|
|
|
JOIN base.p_calendrier ON p_calendrier.date BETWEEN date(SAISIE.D_DEB) AND date(SAISIE.D_FIN)
|
|
|
LEFT JOIN w_PRIX_PREST ON
|
|
|
SAISIE.N_DIS = w_PRIX_PREST.N_DIS AND
|
|
|
SAISIE.CODE_PREST = w_PRIX_PREST.CODE_PREST AND
|
|
|
date(SAISIE.D_DEB) BETWEEN w_PRIX_PREST.DATE_PRIX AND w_PRIX_PREST.DATE_PRIX_fin
|
|
|
LEFT JOIN prod_qsp.FACT_LIGNE ON FACT_LIGNE.N_SAISIE = SAISIE.N_SAISIE AND
|
|
|
(
|
|
|
NUM_FACT_AMO <> 0 OR
|
|
|
NUM_FACT_AMC <> 0 OR
|
|
|
NUM_FACT_ASS <> 0
|
|
|
)
|
|
|
JOIN activite[PX].p_factures ON SAISIE.N_HOSPI = p_factures.no_sejour AND
|
|
|
p_calendrier.date BETWEEN date_debut AND date_fin
|
|
|
JOIN activite.p_sejours ON p_factures.no_sejour = p_sejours.code_original AND p_sejours.etat = ''
|
|
|
JOIN prod_qsp.PRESTATION ON SAISIE.CODE_PREST = PRESTATION.CODE_PREST
|
|
|
LEFT JOIN activite[PX].t_rubriques_facturation ON PRESTATION.CODE_PREST = t_rubriques_facturation.code_original
|
|
|
LEFT JOIN activite.t_prestations ON PRESTATION.CODE_NORM = t_prestations.code_original
|
|
|
WHERE type_facture = 'E' AND
|
|
|
SUPPRIME <> '1' AND
|
|
|
SAISIE.CODE_PREST <> 'GHS' AND
|
|
|
PRESTATION.TYPE_PREST <> 'H' AND
|
|
|
FACT_LIGNE.N_SAISIE IS NULL AND
|
|
|
SAISIE.QTE > 1 AND
|
|
|
date(SAISIE.D_FIN) - date(SAISIE.D_DEB) + 1 = SAISIE.QTE
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_lignes_non_facturees_c(
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
coefficient,
|
|
|
rubrique_facturation_id,
|
|
|
prestation_id,
|
|
|
prix_unitaire,
|
|
|
lieu_id)
|
|
|
SELECT
|
|
|
p_factures.no_facture,
|
|
|
p_calendrier.date AS date_debut,
|
|
|
p_calendrier.date AS date_fin,
|
|
|
1 * SAISIE.COEFF AS nb_rubrique,
|
|
|
1 AS coefficient,
|
|
|
t_rubriques_facturation.oid AS rubrique_facturation_id,
|
|
|
t_prestations.oid AS prestation_id,
|
|
|
COALESCE(CASE WHEN DET_TIPS.PU <> 0 THEN DET_TIPS.PU ELSE DET_TIPS.PU_TTC_TIPS END, PRIX_PREST, 0) AS prix_unitaire,
|
|
|
p_sejours.lieu_sortie_id AS lieu_id
|
|
|
FROM prod_qsp.SAISIE
|
|
|
LEFT JOIN prod_qsp.DET_TIPS ON DET_TIPS.N_SAISIE = SAISIE.N_SAISIE
|
|
|
JOIN base.p_calendrier ON p_calendrier.date BETWEEN date(SAISIE.D_DEB) AND date(SAISIE.D_FIN - interval '1 day')
|
|
|
LEFT JOIN w_PRIX_PREST ON
|
|
|
SAISIE.N_DIS = w_PRIX_PREST.N_DIS AND
|
|
|
SAISIE.CODE_PREST = w_PRIX_PREST.CODE_PREST AND
|
|
|
date(SAISIE.D_DEB) BETWEEN w_PRIX_PREST.DATE_PRIX AND w_PRIX_PREST.DATE_PRIX_fin
|
|
|
LEFT JOIN prod_qsp.FACT_LIGNE ON FACT_LIGNE.N_SAISIE = SAISIE.N_SAISIE AND
|
|
|
(
|
|
|
NUM_FACT_AMO <> 0 OR
|
|
|
NUM_FACT_AMC <> 0 OR
|
|
|
NUM_FACT_ASS <> 0
|
|
|
)
|
|
|
JOIN activite[PX].p_factures ON SAISIE.N_HOSPI = p_factures.no_sejour AND
|
|
|
p_calendrier.date BETWEEN date_debut AND date_fin
|
|
|
JOIN activite.p_sejours ON p_factures.no_sejour = p_sejours.code_original AND p_sejours.etat = ''
|
|
|
JOIN prod_qsp.PRESTATION ON SAISIE.CODE_PREST = PRESTATION.CODE_PREST
|
|
|
LEFT JOIN activite[PX].t_rubriques_facturation ON PRESTATION.CODE_PREST = t_rubriques_facturation.code_original
|
|
|
LEFT JOIN activite.t_prestations ON PRESTATION.CODE_NORM = t_prestations.code_original
|
|
|
WHERE type_facture = 'E' AND
|
|
|
SUPPRIME <> '1' AND
|
|
|
SAISIE.CODE_PREST <> 'GHS' AND
|
|
|
PRESTATION.TYPE_PREST <> 'H' AND
|
|
|
FACT_LIGNE.N_SAISIE IS NULL AND
|
|
|
SAISIE.QTE > 1 AND
|
|
|
date(SAISIE.D_FIN) - date(SAISIE.D_DEB) = SAISIE.QTE
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Lignes facturées Clinique">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_HOS_DIS;
|
|
|
CREATE TEMP TABLE w_HOS_DIS AS
|
|
|
SELECT
|
|
|
N_HOSPI,
|
|
|
MAX(N_DIS) AS N_DIS
|
|
|
FROM prod_qsp.HOS_DIS
|
|
|
GROUP BY 1;
|
|
|
|
|
|
CREATE INDEX w_HOS_DIS_I1
|
|
|
ON w_HOS_DIS
|
|
|
USING btree
|
|
|
(N_HOSPI);
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_FACT_LIGNE;
|
|
|
CREATE TEMP TABLE w_FACT_LIGNE AS
|
|
|
|
|
|
SELECT
|
|
|
W_FACTURE_QSP.date_vente AS date_vente,
|
|
|
W_FACTURE_QSP.lieu_sortie_id AS lieu_id,
|
|
|
W_FACTURE_QSP.no_facture AS no_facture,
|
|
|
W_FACTURE_QSP.ETAT,
|
|
|
W_FACTURE_QSP.NUM_FACT,
|
|
|
W_FACTURE_QSP.TRANS_CMPTA,
|
|
|
FACT_LIGNE.N_HOSPI,
|
|
|
CASE WHEN FACT_LIGNE.NUM_FACT_AMO = W_FACTURE_QSP.NUM_FACT THEN FACT_LIGNE.NUM_FACT_AMO ELSE 0 END AS NUM_FACT_AMO,
|
|
|
CASE WHEN FACT_LIGNE.NUM_FACT_AMC = W_FACTURE_QSP.NUM_FACT THEN FACT_LIGNE.NUM_FACT_AMC ELSE 0 END AS NUM_FACT_AMC,
|
|
|
CASE WHEN FACT_LIGNE.NUM_FACT_ASS = W_FACTURE_QSP.NUM_FACT THEN FACT_LIGNE.NUM_FACT_ASS ELSE 0 END AS NUM_FACT_ASS,
|
|
|
CASE WHEN FACT_LIGNE.NUM_FACT_AMO <> 0 THEN FACT_LIGNE.AMO ELSE 0 END AS AMO,
|
|
|
CASE WHEN FACT_LIGNE.NUM_FACT_AMC <> 0 THEN FACT_LIGNE.AMC ELSE 0 END AS AMC,
|
|
|
CASE WHEN FACT_LIGNE.NUM_FACT_ASS <> 0 THEN FACT_LIGNE.ASS ELSE 0 END AS ASS,
|
|
|
CASE WHEN FACT_LIGNE.NUM_FACT_AMO <> 0 THEN COALESCE(FACT_LIGNE.SOL_AMO,0) ELSE 0 END AS SOL_AMO,
|
|
|
CASE WHEN FACT_LIGNE.NUM_FACT_AMC <> 0 THEN COALESCE(FACT_LIGNE.SOL_AMC,0) ELSE 0 END AS SOL_AMC,
|
|
|
CASE WHEN FACT_LIGNE.NUM_FACT_ASS <> 0 THEN COALESCE(FACT_LIGNE.SOL_ASS,0) ELSE 0 END AS SOL_ASS,
|
|
|
FACT_LIGNE.PU,
|
|
|
FACT_LIGNE.TAUX,
|
|
|
FACT_LIGNE.ENC_AMO,
|
|
|
FACT_LIGNE.ENC_AMC,
|
|
|
FACT_LIGNE.ENC_ASS,
|
|
|
SAISIE.CODE_PREST,
|
|
|
PRESTATION.TYPE_PREST,
|
|
|
PRESTATION.CODE_NORM,
|
|
|
COALESCE(SAISIE.C_PRAT,'') AS C_PRAT,
|
|
|
SAISIE.D_DEB,
|
|
|
GREATEST(SAISIE.D_FIN,SAISIE.D_DEB) AS D_FIN,
|
|
|
SAISIE.QTE,
|
|
|
SAISIE.COEFF,
|
|
|
SAISIE.MT_DP,
|
|
|
SAISIE.SUPPRIME,
|
|
|
SAISIE.GRATUIT,
|
|
|
SAISIE.N_GHS,
|
|
|
CASE WHEN SAISIE.COEFF_MCO = 0 THEN 1 ELSE COEFF_MCO END,
|
|
|
SAISIE.TAUX_ASS,
|
|
|
SAISIE.TAUX_AMC,
|
|
|
COALESCE(DOSSIER_CCAM.CODE_ACTE,SAISIE.CODE_PREST) AS CODE_ACTE,
|
|
|
DOSSIER_CCAM.EXT_DOC,
|
|
|
DOSSIER_CCAM.CODE_ACTIV,
|
|
|
DOSSIER_CCAM.PHASE_TRAIT,
|
|
|
DOSSIER_CCAM.MODIF_1,
|
|
|
DOSSIER_CCAM.MODIF_2,
|
|
|
DOSSIER_CCAM.MODIF_3,
|
|
|
DOSSIER_CCAM.MODIF_4,
|
|
|
DOSSIER_CCAM.ASSOC_NONP,
|
|
|
DOSSIER_CCAM.REMB_EXCEPT,
|
|
|
COALESCE(t_rubriques_facturation.oid::bigint, 0) AS rubrique_facturation_id,
|
|
|
COALESCE(t_rubriques_facturation.oid::bigint, 0) AS rubrique_comptabilisation_id,
|
|
|
COALESCE(t_prestations.oid::bigint, 0) AS prestation_id,
|
|
|
COALESCE(t_medecins_administratifs.oid::bigint, 0) AS medecin_facture_id,
|
|
|
COALESCE(t_medecins_administratifs.oid::bigint, 0) AS medecin_comptabilise_id,
|
|
|
COALESCE(t_actes.oid::bigint, 0) AS acte_id,
|
|
|
COALESCE(t_medecins_administratifs.est_medecin_salarie, '0') AS est_medecin_salarie,
|
|
|
COALESCE(w_HOS_DIS.N_DIS,0) AS N_DIS,
|
|
|
0::bigint AS compte_produit_id,
|
|
|
CASE WHEN COMPTE <> 0 THEN to_char(PRESTATION.COMPTE,'FM9999999999') ELSE '' END AS COMPTE
|
|
|
|
|
|
FROM prod_qsp.FACT_LIGNE
|
|
|
JOIN W_FACTURE_QSP ON (FACT_LIGNE.NUM_FACT_AMO = W_FACTURE_QSP.NUM_FACT OR FACT_LIGNE.NUM_FACT_AMC = W_FACTURE_QSP.NUM_FACT OR FACT_LIGNE.NUM_FACT_ASS = W_FACTURE_QSP.NUM_FACT)
|
|
|
JOIN prod_qsp.SAISIE ON SAISIE.N_SAISIE = fact_ligne.N_SAISIE
|
|
|
LEFT JOIN w_HOS_DIS ON FACT_LIGNE.N_HOSPI = w_HOS_DIS.N_HOSPI
|
|
|
JOIN prod_qsp.PRESTATION ON SAISIE.CODE_PREST = PRESTATION.CODE_PREST
|
|
|
LEFT JOIN activite[PX].t_rubriques_facturation ON PRESTATION.CODE_PREST = t_rubriques_facturation.code_original
|
|
|
LEFT JOIN activite.t_prestations ON PRESTATION.CODE_NORM = t_prestations.code_original
|
|
|
LEFT JOIN prod_qsp.SAISIE_CCAM ON FACT_LIGNE.N_SAISIE = SAISIE_CCAM.N_SAISIE
|
|
|
LEFT JOIN prod_qsp.DOSSIER_CCAM ON SAISIE_CCAM.N_UNIQUE_CCAM = DOSSIER_CCAM.N_UNIQUE_CCAM AND SAISIE_CCAM.N_SEQ_CCAM = DOSSIER_CCAM.N_SEQ_CCAM AND
|
|
|
SAISIE_CCAM.N_HOSPI = DOSSIER_CCAM.NDOSSIER
|
|
|
LEFT JOIN activite[PX].t_medecins_administratifs ON SAISIE.C_PRAT = t_medecins_administratifs.code_original
|
|
|
LEFT JOIN base.t_actes ON (substring(COALESCE(DOSSIER_CCAM.CODE_ACTE,SAISIE.CODE_PREST), 1, 7) = t_actes.code);
|
|
|
|
|
|
CREATE INDEX w_FACT_LIGNE_I1
|
|
|
ON w_FACT_LIGNE
|
|
|
USING btree
|
|
|
(C_PRAT);
|
|
|
|
|
|
CREATE INDEX w_FACT_LIGNE_I2
|
|
|
ON w_FACT_LIGNE
|
|
|
USING btree
|
|
|
(CODE_PREST);
|
|
|
|
|
|
CREATE INDEX w_FACT_LIGNE_I3
|
|
|
ON w_FACT_LIGNE
|
|
|
USING btree
|
|
|
(N_HOSPI);
|
|
|
|
|
|
UPDATE w_FACT_LIGNE
|
|
|
SET CODE_NORM = CODE_PREST,
|
|
|
prestation_id = t_prestations.oid
|
|
|
FROM activite.t_prestations
|
|
|
WHERE (CODE_NORM IS NULL OR CODE_NORM = '') AND
|
|
|
CODE_PREST = t_prestations.code_original
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
-- Compte produit
|
|
|
UPDATE w_FACT_LIGNE
|
|
|
SET COMPTE = PRESTATION_DISCIPLINE.COMPTE
|
|
|
FROM prod_qsp.PRESTATION_DISCIPLINE
|
|
|
WHERE w_FACT_LIGNE.CODE_PREST = PRESTATION_DISCIPLINE.CODE_PREST AND
|
|
|
w_FACT_LIGNE.N_DIS = PRESTATION_DISCIPLINE.N_DIS AND
|
|
|
PRESTATION_DISCIPLINE.COMPTE > 0;
|
|
|
|
|
|
|
|
|
UPDATE w_FACT_LIGNE
|
|
|
SET COMPTE = PRESTATION_GHS_GHS.COMPTE
|
|
|
FROM prod_qsp.PRESTATION_GHS_GHS
|
|
|
WHERE w_FACT_LIGNE.CODE_PREST = PRESTATION_GHS_GHS.CODE_PREST AND
|
|
|
w_FACT_LIGNE.N_GHS = PRESTATION_GHS_GHS.GHS AND
|
|
|
PRESTATION_GHS_GHS.COMPTE > 0;
|
|
|
|
|
|
|
|
|
UPDATE w_FACT_LIGNE
|
|
|
SET compte_produit_id = t_compte.oid
|
|
|
FROM activite[PX].t_compte
|
|
|
WHERE t_compte.code = w_FACT_LIGNE.COMPTE AND
|
|
|
w_FACT_LIGNE.COMPTE <> '';
|
|
|
|
|
|
-- Lieu
|
|
|
UPDATE w_FACT_LIGNE
|
|
|
SET lieu_id = p_mouvements_sejour.lieu_id
|
|
|
FROM
|
|
|
activite[PX].p_mouvements_sejour
|
|
|
WHERE
|
|
|
w_FACT_LIGNE.N_HOSPI = p_mouvements_sejour.no_sejour AND
|
|
|
date(W_FACT_LIGNE.D_FIN) = p_mouvements_sejour.date AND
|
|
|
(230000 BETWEEN p_mouvements_sejour.heure_debut AND p_mouvements_sejour.heure_fin OR
|
|
|
nb_entrees_directes = 1 AND heure_fin = 240000 OR
|
|
|
nb_sorties_directes = 1 ) AND
|
|
|
w_FACT_LIGNE.lieu_id <> p_mouvements_sejour.lieu_id;
|
|
|
|
|
|
|
|
|
-- Mise à jour totaux comptabilisés pour médecins salariés
|
|
|
DROP TABLE IF EXISTS W_FACT_LIGNE_SALARIE;
|
|
|
CREATE TEMP TABLE W_FACT_LIGNE_SALARIE AS
|
|
|
SELECT
|
|
|
W_FACT_LIGNE.no_facture,
|
|
|
SUM(W_FACT_LIGNE.AMO) AS montant_comptabilise
|
|
|
FROM w_FACT_LIGNE
|
|
|
WHERE NUM_FACT_AMO <> 0 AND AMO <> 0 AND
|
|
|
est_medecin_salarie = '1'
|
|
|
GROUP BY 1;
|
|
|
|
|
|
CREATE INDEX W_FACT_LIGNE_SALARIE_I1
|
|
|
ON W_FACT_LIGNE_SALARIE
|
|
|
USING btree
|
|
|
(no_facture);
|
|
|
|
|
|
UPDATE activite[PX].p_factures
|
|
|
SET
|
|
|
montant_comptabilise_c = montant_comptabilise_c + W_FACT_LIGNE_SALARIE.montant_comptabilise,
|
|
|
montant_comptabilise_h = montant_comptabilise_h - W_FACT_LIGNE_SALARIE.montant_comptabilise,
|
|
|
montant_comptabilise_1_c = montant_comptabilise_1_c + W_FACT_LIGNE_SALARIE.montant_comptabilise,
|
|
|
montant_comptabilise_1_h = montant_comptabilise_1_h - W_FACT_LIGNE_SALARIE.montant_comptabilise
|
|
|
FROM W_FACT_LIGNE_SALARIE
|
|
|
WHERE W_FACT_LIGNE_SALARIE.no_facture = p_factures.no_facture;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS W_FACT_LIGNE_SALARIE;
|
|
|
CREATE TEMP TABLE W_FACT_LIGNE_SALARIE AS
|
|
|
SELECT
|
|
|
W_FACT_LIGNE.no_facture,
|
|
|
SUM(W_FACT_LIGNE.AMC) AS montant_comptabilise
|
|
|
FROM w_FACT_LIGNE
|
|
|
WHERE NUM_FACT_AMC <> 0 AND AMC <> 0 AND
|
|
|
est_medecin_salarie = '1'
|
|
|
GROUP BY 1;
|
|
|
|
|
|
CREATE INDEX W_FACT_LIGNE_SALARIE_I1
|
|
|
ON W_FACT_LIGNE_SALARIE
|
|
|
USING btree
|
|
|
(no_facture);
|
|
|
|
|
|
UPDATE activite[PX].p_factures
|
|
|
SET
|
|
|
montant_comptabilise_c = montant_comptabilise_c + W_FACT_LIGNE_SALARIE.montant_comptabilise,
|
|
|
montant_comptabilise_h = montant_comptabilise_h - W_FACT_LIGNE_SALARIE.montant_comptabilise,
|
|
|
montant_comptabilise_2_c = montant_comptabilise_2_c + W_FACT_LIGNE_SALARIE.montant_comptabilise,
|
|
|
montant_comptabilise_2_h = montant_comptabilise_2_h - W_FACT_LIGNE_SALARIE.montant_comptabilise
|
|
|
FROM W_FACT_LIGNE_SALARIE
|
|
|
WHERE W_FACT_LIGNE_SALARIE.no_facture = p_factures.no_facture;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS W_FACT_LIGNE_SALARIE;
|
|
|
CREATE TEMP TABLE W_FACT_LIGNE_SALARIE AS
|
|
|
SELECT
|
|
|
W_FACT_LIGNE.no_facture,
|
|
|
SUM(W_FACT_LIGNE.ASS) AS montant_comptabilise
|
|
|
FROM w_FACT_LIGNE
|
|
|
WHERE NUM_FACT_ASS <> 0 AND ASS <> 0 AND
|
|
|
est_medecin_salarie = '1'
|
|
|
GROUP BY 1;
|
|
|
|
|
|
CREATE INDEX W_FACT_LIGNE_SALARIE_I1
|
|
|
ON W_FACT_LIGNE_SALARIE
|
|
|
USING btree
|
|
|
(no_facture);
|
|
|
|
|
|
UPDATE activite[PX].p_factures
|
|
|
SET
|
|
|
montant_comptabilise_c = montant_comptabilise_c + W_FACT_LIGNE_SALARIE.montant_comptabilise,
|
|
|
montant_comptabilise_h = montant_comptabilise_h - W_FACT_LIGNE_SALARIE.montant_comptabilise,
|
|
|
montant_comptabilise_0_c = montant_comptabilise_0_c + W_FACT_LIGNE_SALARIE.montant_comptabilise,
|
|
|
montant_comptabilise_0_h = montant_comptabilise_0_h - W_FACT_LIGNE_SALARIE.montant_comptabilise
|
|
|
FROM W_FACT_LIGNE_SALARIE
|
|
|
WHERE W_FACT_LIGNE_SALARIE.no_facture = p_factures.no_facture;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- Génération lignes détail
|
|
|
|
|
|
DROP TABLE IF EXISTS W_FACT_LIGNE_C_1;
|
|
|
CREATE TEMP TABLE W_FACT_LIGNE_C_1 AS
|
|
|
SELECT
|
|
|
W_FACT_LIGNE.N_HOSPI,
|
|
|
W_FACT_LIGNE.date_vente,
|
|
|
W_FACT_LIGNE.lieu_id,
|
|
|
W_FACT_LIGNE.no_facture,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
compte_produit_id,
|
|
|
W_FACT_LIGNE.D_DEB AS date_debut,
|
|
|
W_FACT_LIGNE.D_FIN AS date_fin,
|
|
|
CASE WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE < 0 AND W_FACT_LIGNE.CODE_NORM = 'GHS' THEN -1
|
|
|
WHEN W_FACT_LIGNE.ETAT <> 3 AND W_FACT_LIGNE.CODE_NORM = 'GHS' THEN 1
|
|
|
WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE > 0 THEN 0 - W_FACT_LIGNE.QTE
|
|
|
ELSE W_FACT_LIGNE.QTE END AS nb_rubrique,
|
|
|
CASE WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE < 0 AND W_FACT_LIGNE.CODE_NORM = 'GHS' THEN -1
|
|
|
WHEN W_FACT_LIGNE.ETAT <> 3 AND W_FACT_LIGNE.CODE_NORM = 'GHS' THEN 1
|
|
|
WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE > 0 THEN 0 - W_FACT_LIGNE.QTE
|
|
|
ELSE W_FACT_LIGNE.QTE END AS nb_prestations,
|
|
|
W_FACT_LIGNE.COEFF AS coefficient,
|
|
|
W_FACT_LIGNE.GRATUIT,
|
|
|
W_FACT_LIGNE.N_GHS,
|
|
|
W_FACT_LIGNE.COEFF_MCO AS coefficient_mco,
|
|
|
W_FACT_LIGNE.PU AS prix_unitaire,
|
|
|
W_FACT_LIGNE.TAUX AS taux_1,
|
|
|
0::numeric AS taux_2,
|
|
|
0::numeric AS taux_0,
|
|
|
CASE WHEN est_medecin_salarie <> '1' THEN W_FACT_LIGNE.AMO ELSE 0 END AS montant_facture,
|
|
|
CASE WHEN est_medecin_salarie <> '1' THEN W_FACT_LIGNE.AMO ELSE 0 END AS montant_facture_1,
|
|
|
0::numeric AS montant_facture_2,
|
|
|
0::numeric AS montant_facture_0,
|
|
|
CASE WHEN W_FACT_LIGNE.SOL_AMO <> 2 THEN W_FACT_LIGNE.AMO ELSE 0 END AS montant_comptabilise,
|
|
|
CASE WHEN W_FACT_LIGNE.SOL_AMO <> 2 THEN W_FACT_LIGNE.AMO ELSE 0 END AS montant_comptabilise_1,
|
|
|
0::numeric AS montant_comptabilise_2,
|
|
|
0::numeric AS montant_comptabilise_0,
|
|
|
W_FACT_LIGNE.ENC_AMO AS montant_regle_1,
|
|
|
0::numeric AS montant_regle_2,
|
|
|
0::numeric AS montant_regle_0,
|
|
|
0::numeric AS rubrique_facture_id
|
|
|
|
|
|
FROM w_FACT_LIGNE
|
|
|
WHERE NUM_FACT_AMO <> 0
|
|
|
AND W_FACT_LIGNE.AMO <> 0
|
|
|
AND (W_FACT_LIGNE.TYPE_PREST <> 'H' OR est_medecin_salarie = '1');
|
|
|
|
|
|
DROP TABLE IF EXISTS W_FACT_LIGNE_C_2;
|
|
|
|
|
|
CREATE TEMP TABLE W_FACT_LIGNE_C_2 AS
|
|
|
|
|
|
SELECT
|
|
|
W_FACT_LIGNE.N_HOSPI,
|
|
|
W_FACT_LIGNE.date_vente,
|
|
|
W_FACT_LIGNE.lieu_id,
|
|
|
W_FACT_LIGNE.no_facture,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
compte_produit_id,
|
|
|
W_FACT_LIGNE.D_DEB AS date_debut,
|
|
|
W_FACT_LIGNE.D_FIN AS date_fin,
|
|
|
CASE
|
|
|
WHEN AMO <> 0 THEN 0
|
|
|
WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE < 0 AND W_FACT_LIGNE.CODE_NORM = 'GHS' THEN -1
|
|
|
WHEN W_FACT_LIGNE.ETAT <> 3 AND W_FACT_LIGNE.CODE_NORM = 'GHS' THEN 1
|
|
|
WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE > 0 THEN 0 - W_FACT_LIGNE.QTE
|
|
|
ELSE W_FACT_LIGNE.QTE END AS nb_rubrique,
|
|
|
CASE
|
|
|
WHEN AMO <> 0 THEN 0
|
|
|
WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE < 0 AND W_FACT_LIGNE.CODE_NORM = 'GHS' THEN -1
|
|
|
WHEN W_FACT_LIGNE.ETAT <> 3 AND W_FACT_LIGNE.CODE_NORM = 'GHS' THEN 1
|
|
|
WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE > 0 THEN 0 - W_FACT_LIGNE.QTE
|
|
|
ELSE W_FACT_LIGNE.QTE END AS nb_prestations,
|
|
|
W_FACT_LIGNE.COEFF AS coefficient,
|
|
|
W_FACT_LIGNE.GRATUIT,
|
|
|
W_FACT_LIGNE.N_GHS,
|
|
|
W_FACT_LIGNE.COEFF_MCO AS coefficient_mco,
|
|
|
W_FACT_LIGNE.PU AS prix_unitaire,
|
|
|
0::numeric AS taux_1,
|
|
|
0::numeric AS taux_2,
|
|
|
0::numeric AS taux_0,
|
|
|
CASE WHEN est_medecin_salarie <> '1' THEN W_FACT_LIGNE.AMC ELSE 0 END AS montant_facture,
|
|
|
0::numeric AS montant_facture_1,
|
|
|
CASE WHEN est_medecin_salarie <> '1' THEN W_FACT_LIGNE.AMC ELSE 0 END AS montant_facture_2,
|
|
|
0::numeric AS montant_facture_0,
|
|
|
CASE WHEN W_FACT_LIGNE.SOL_AMC <> 2 THEN W_FACT_LIGNE.AMC ELSE 0 END AS montant_comptabilise,
|
|
|
0::numeric AS montant_comptabilise_1,
|
|
|
CASE WHEN W_FACT_LIGNE.SOL_AMC <> 2 THEN W_FACT_LIGNE.AMC ELSE 0 END AS montant_comptabilise_2,
|
|
|
0::numeric AS montant_comptabilise_0,
|
|
|
0::numeric AS montant_regle_1,
|
|
|
W_FACT_LIGNE.ENC_AMC AS montant_regle_2,
|
|
|
0::numeric AS montant_regle_0,
|
|
|
0::numeric AS rubrique_facture_id
|
|
|
|
|
|
FROM W_FACT_LIGNE
|
|
|
WHERE NUM_FACT_AMC <> 0
|
|
|
AND W_FACT_LIGNE.AMC <> 0
|
|
|
AND (W_FACT_LIGNE.TYPE_PREST <> 'H' OR est_medecin_salarie = '1');
|
|
|
|
|
|
DROP TABLE IF EXISTS W_FACT_LIGNE_C_0;
|
|
|
|
|
|
CREATE TEMP TABLE W_FACT_LIGNE_C_0 AS
|
|
|
|
|
|
SELECT
|
|
|
W_FACT_LIGNE.N_HOSPI,
|
|
|
W_FACT_LIGNE.date_vente,
|
|
|
W_FACT_LIGNE.lieu_id,
|
|
|
W_FACT_LIGNE.no_facture,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
compte_produit_id,
|
|
|
W_FACT_LIGNE.D_DEB AS date_debut,
|
|
|
W_FACT_LIGNE.D_FIN AS date_fin,
|
|
|
CASE
|
|
|
WHEN AMO <> 0 THEN 0
|
|
|
WHEN AMC <> 0 THEN 0
|
|
|
WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE < 0 AND W_FACT_LIGNE.CODE_NORM = 'GHS' THEN -1
|
|
|
WHEN W_FACT_LIGNE.ETAT <> 3 AND W_FACT_LIGNE.CODE_NORM = 'GHS' THEN 1
|
|
|
WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE > 0 THEN 0 - W_FACT_LIGNE.QTE
|
|
|
ELSE W_FACT_LIGNE.QTE END AS nb_rubrique,
|
|
|
CASE
|
|
|
WHEN AMO <> 0 THEN 0
|
|
|
WHEN AMC <> 0 THEN 0
|
|
|
WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE < 0 AND W_FACT_LIGNE.CODE_NORM = 'GHS' THEN -1
|
|
|
WHEN W_FACT_LIGNE.ETAT <> 3 AND W_FACT_LIGNE.CODE_NORM = 'GHS' THEN 1
|
|
|
WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE > 0 THEN 0 - W_FACT_LIGNE.QTE
|
|
|
ELSE W_FACT_LIGNE.QTE END AS nb_prestations,
|
|
|
W_FACT_LIGNE.COEFF AS coefficient,
|
|
|
W_FACT_LIGNE.GRATUIT,
|
|
|
W_FACT_LIGNE.N_GHS,
|
|
|
W_FACT_LIGNE.COEFF_MCO AS coefficient_mco,
|
|
|
W_FACT_LIGNE.PU AS prix_unitaire,
|
|
|
0::numeric AS taux_1,
|
|
|
0::numeric AS taux_2,
|
|
|
0::numeric AS taux_0,
|
|
|
CASE WHEN est_medecin_salarie <> '1' THEN W_FACT_LIGNE.ASS ELSE 0 END AS montant_facture,
|
|
|
0::numeric AS montant_facture_1,
|
|
|
0::numeric AS montant_facture_2,
|
|
|
CASE WHEN est_medecin_salarie <> '1' THEN W_FACT_LIGNE.ASS ELSE 0 END AS montant_facture_0,
|
|
|
CASE WHEN W_FACT_LIGNE.SOL_ASS <> 2 THEN W_FACT_LIGNE.ASS ELSE 0 END AS montant_comptabilise,
|
|
|
0::numeric AS montant_comptabilise_1,
|
|
|
0::numeric AS montant_comptabilise_2,
|
|
|
CASE WHEN W_FACT_LIGNE.SOL_ASS <> 2 THEN W_FACT_LIGNE.ASS ELSE 0 END AS montant_comptabilise_0,
|
|
|
0::numeric AS montant_regle_1,
|
|
|
0::numeric AS montant_regle_2,
|
|
|
W_FACT_LIGNE.ENC_ASS AS montant_regle_0,
|
|
|
0::numeric AS rubrique_facture_id
|
|
|
|
|
|
FROM W_FACT_LIGNE
|
|
|
WHERE NUM_FACT_ASS <> 0
|
|
|
AND W_FACT_LIGNE.ASS <> 0
|
|
|
AND (W_FACT_LIGNE.TYPE_PREST <> 'H' OR est_medecin_salarie = '1');
|
|
|
|
|
|
|
|
|
-- Rubriques internes cti
|
|
|
SELECT activite[PX].cti_reorganize_rubrique_facture_c('W_FACT_LIGNE_C_1');
|
|
|
SELECT activite[PX].cti_reorganize_rubrique_facture_c('W_FACT_LIGNE_C_2');
|
|
|
SELECT activite[PX].cti_reorganize_rubrique_facture_c('W_FACT_LIGNE_C_0');
|
|
|
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_c_1');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_c_2');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_c_3');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_c_4');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_c_5');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_c_6');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_c_7');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_c_8');
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_lignes_c(
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
nb_prestation,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facture_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
compte_produit_id,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
montant_facture_22,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
|
|
|
montant_encours,
|
|
|
montant_encours_0,
|
|
|
montant_encours_1,
|
|
|
montant_encours_2,
|
|
|
montant_encours_22)
|
|
|
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
nb_prestations,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facture_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
compte_produit_id,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
0 AS montant_facture_22,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
0 AS taux_22,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
0 AS montant_comptabilise_22,
|
|
|
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0
|
|
|
|
|
|
FROM W_FACT_LIGNE_C_1
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
nb_prestations,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facture_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
compte_produit_id,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
0 AS montant_facture_22,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
0 AS taux_22,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
0 AS montant_comptabilise_22,
|
|
|
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0
|
|
|
|
|
|
FROM W_FACT_LIGNE_C_2
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
nb_prestations,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facture_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
compte_produit_id,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
0 AS montant_facture_22,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
0 AS taux_22,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
0 AS montant_comptabilise_22,
|
|
|
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0
|
|
|
|
|
|
FROM W_FACT_LIGNE_C_0;
|
|
|
|
|
|
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_c_1');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_c_2');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_c_6');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_c_7');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_c_8');
|
|
|
|
|
|
|
|
|
|
|
|
-- Eclatement des supplements par jour
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_sup_c;
|
|
|
|
|
|
CREATE TEMP TABLE w_factures_lignes_sup_c AS
|
|
|
SELECT
|
|
|
p_factures_lignes_c.CTID AS from_CTID,
|
|
|
t_prestations.code AS prestation_code,
|
|
|
date(p_sejours.date_entree) AS date_debut_ghs,
|
|
|
date(p_sejours.date_sortie - interval '1 day') AS date_fin_ghs,
|
|
|
(date(date_sortie) - date(date_entree)) * CASE WHEN nb_prestation < 0 THEN -1 ELSE 1 END AS nb_prestation_ghs,
|
|
|
CASE WHEN t_prestations.code = 'GHS' THEN date(date_entree + interval '1 day') ELSE date(p_factures_lignes_c.date_debut + interval '1 day') END AS date_debut_det,
|
|
|
CASE WHEN t_prestations.code = 'GHS' THEN date(p_sejours.date_sortie - interval '1 day') ELSE date(p_factures_lignes_c.date_debut + ((ABS(nb_prestation)-1) || ' day')::interval) END AS date_fin_det,
|
|
|
ABS(CASE WHEN t_prestations.code = 'GHS' THEN date(date_sortie) - date(date_entree) ELSE nb_prestation END) AS nb_det,
|
|
|
p_factures_lignes_c.*
|
|
|
FROM activite[PX].p_factures_lignes_c
|
|
|
JOIN activite[PX].p_factures ON p_factures_lignes_c.no_facture = p_factures.no_facture
|
|
|
JOIN activite[PX].p_sejours ON p_factures.no_sejour = p_sejours.no_sejour
|
|
|
JOIN activite.t_prestations ON prestation_id = t_prestations.oid AND
|
|
|
(
|
|
|
code IN ('PJ', 'PJ1', 'PJ2', 'FJ', 'SSM', 'GHS', 'EXH', 'SRC', 'REA', 'STF', 'NN1', 'NN2', 'NN3', 'CP', 'CPC', 'SHO') OR
|
|
|
t_prestations.type_ventilation_jour = '1'
|
|
|
)
|
|
|
WHERE (nb_prestation > 1 or nb_prestation < -1 OR (t_prestations.code = 'GHS' AND date(date_sortie) - date(date_entree) > 1)) ;
|
|
|
|
|
|
|
|
|
UPDATE w_factures_lignes_sup_c SET
|
|
|
date_fin_ghs = date(date_debut_exh - interval '1 day'),
|
|
|
date_fin_det = date(date_debut_exh - interval '1 day'),
|
|
|
nb_prestation_ghs = date(date_debut_exh - interval '1 day') - date_debut_ghs + 1,
|
|
|
nb_det = date(date_debut_exh - interval '1 day') - date_debut_ghs + 1
|
|
|
FROM (
|
|
|
SELECT no_facture, date(MIN(date_debut)) AS date_debut_exh
|
|
|
FROM activite[PX].p_factures_lignes_c
|
|
|
JOIN activite.t_prestations ON prestation_id = t_prestations.oid AND code = 'EXH'
|
|
|
GROUP BY 1) subview
|
|
|
WHERE w_factures_lignes_sup_c.no_facture = subview.no_facture AND
|
|
|
w_factures_lignes_sup_c.prestation_code = 'GHS';
|
|
|
|
|
|
CREATE INDEX w_factures_lignes_sup_c_i1
|
|
|
ON w_factures_lignes_sup_c
|
|
|
USING btree
|
|
|
(date_debut);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_sup_c_sup;
|
|
|
|
|
|
CREATE TEMP TABLE w_factures_lignes_sup_c_sup AS
|
|
|
SELECT
|
|
|
from_CTID,
|
|
|
no_facture,
|
|
|
date AS date_debut,
|
|
|
date AS date_fin,
|
|
|
CASE WHEN prestation_code = 'GHS' AND date <> date_fin_ghs THEN 0 WHEN nb_prestation < 0 THEN -1 ELSE 1 END AS nb_rubrique,
|
|
|
CASE WHEN prestation_code = 'GHS' AND date <> date_fin_ghs THEN 0 WHEN nb_prestation < 0 THEN -1 ELSE 1 END AS nb_prestation,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
compte_produit_id,
|
|
|
prestation_id,
|
|
|
round(montant_facture / ABS(nb_det),2) AS montant_facture,
|
|
|
round(montant_facture_0 / ABS(nb_det),2) AS montant_facture_0,
|
|
|
round(montant_facture_1 / ABS(nb_det),2) AS montant_facture_1,
|
|
|
round(montant_facture_2 / ABS(nb_det),2) AS montant_facture_2,
|
|
|
round(montant_facture_22 / ABS(nb_det),2) AS montant_facture_22,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
finess,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
round(montant_comptabilise / ABS(nb_det),2) AS montant_comptabilise,
|
|
|
round(montant_comptabilise_0 / ABS(nb_det),2) AS montant_comptabilise_0,
|
|
|
round(montant_comptabilise_1 / ABS(nb_det),2) AS montant_comptabilise_1,
|
|
|
round(montant_comptabilise_2 / ABS(nb_det),2) AS montant_comptabilise_2,
|
|
|
round(montant_comptabilise_22 / ABS(nb_det),2) AS montant_comptabilise_22,
|
|
|
round(montant_encours / ABS(nb_det),2) AS montant_encours,
|
|
|
round(montant_encours_0 / ABS(nb_det),2) AS montant_encours_0,
|
|
|
round(montant_encours_1 / ABS(nb_det),2) AS montant_encours_1,
|
|
|
round(montant_encours_2 / ABS(nb_det),2) AS montant_encours_2,
|
|
|
round(montant_encours_22 / ABS(nb_det),2) AS montant_encours_22,
|
|
|
round(montant_facture_actes_inclus_dans_sejour / ABS(nb_det),2) AS montant_facture_actes_inclus_dans_sejour,
|
|
|
round(montant_facture_0_actes_inclus_dans_sejour / ABS(nb_det),2) AS montant_facture_0_actes_inclus_dans_sejour,
|
|
|
round(montant_facture_1_actes_inclus_dans_sejour / ABS(nb_det),2) AS montant_facture_1_actes_inclus_dans_sejour,
|
|
|
round(montant_facture_2_actes_inclus_dans_sejour / ABS(nb_det),2) AS montant_facture_2_actes_inclus_dans_sejour,
|
|
|
round(montant_facture_22_actes_inclus_dans_sejour / ABS(nb_det),2) AS montant_facture_22_actes_inclus_dans_sejour,
|
|
|
origine_facturation_id,
|
|
|
round(montant_comptabilise_budget_global_1 / ABS(nb_det),2) AS montant_comptabilise_budget_global_1,
|
|
|
facture_id
|
|
|
FROM w_factures_lignes_sup_c
|
|
|
JOIN base.p_calendrier ON p_calendrier.date BETWEEN date_debut_det AND date_fin_det
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_sup_c_sup_tot;
|
|
|
|
|
|
CREATE TEMP TABLE w_factures_lignes_sup_c_sup_tot AS
|
|
|
|
|
|
SELECT from_CTID,
|
|
|
SUM(nb_rubrique) AS nb_rubrique,
|
|
|
SUM(nb_prestation) AS nb_prestation,
|
|
|
SUM(montant_facture) AS montant_facture,
|
|
|
SUM(montant_facture_0) AS montant_facture_0,
|
|
|
SUM(montant_facture_1) AS montant_facture_1,
|
|
|
SUM(montant_facture_2) AS montant_facture_2,
|
|
|
SUM(montant_facture_22) AS montant_facture_22,
|
|
|
SUM(montant_comptabilise) AS montant_comptabilise,
|
|
|
SUM(montant_comptabilise_0) AS montant_comptabilise_0,
|
|
|
SUM(montant_comptabilise_1) AS montant_comptabilise_1,
|
|
|
SUM(montant_comptabilise_2) AS montant_comptabilise_2,
|
|
|
SUM(montant_comptabilise_22) AS montant_comptabilise_22,
|
|
|
SUM(montant_encours) AS montant_encours,
|
|
|
SUM(montant_encours_0) AS montant_encours_0,
|
|
|
SUM(montant_encours_1) AS montant_encours_1,
|
|
|
SUM(montant_encours_2) AS montant_encours_2,
|
|
|
SUM(montant_encours_22) AS montant_encours_22,
|
|
|
SUM(montant_facture_actes_inclus_dans_sejour) AS montant_facture_actes_inclus_dans_sejour,
|
|
|
SUM(montant_facture_0_actes_inclus_dans_sejour) AS montant_facture_0_actes_inclus_dans_sejour,
|
|
|
SUM(montant_facture_1_actes_inclus_dans_sejour) AS montant_facture_1_actes_inclus_dans_sejour,
|
|
|
SUM(montant_facture_2_actes_inclus_dans_sejour) AS montant_facture_2_actes_inclus_dans_sejour,
|
|
|
SUM(montant_facture_22_actes_inclus_dans_sejour) AS montant_facture_22_actes_inclus_dans_sejour,
|
|
|
SUM(montant_comptabilise_budget_global_1) AS montant_comptabilise_budget_global_1
|
|
|
FROM w_factures_lignes_sup_c_sup
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures_lignes_c
|
|
|
SET
|
|
|
date_fin = p_factures_lignes_c.date_debut,
|
|
|
nb_rubrique = p_factures_lignes_c.nb_rubrique - w_factures_lignes_sup_c_sup_tot.nb_rubrique,
|
|
|
nb_prestation = p_factures_lignes_c.nb_prestation - w_factures_lignes_sup_c_sup_tot.nb_prestation,
|
|
|
montant_facture = p_factures_lignes_c.montant_facture - w_factures_lignes_sup_c_sup_tot.montant_facture,
|
|
|
montant_facture_0 = p_factures_lignes_c.montant_facture_0 - w_factures_lignes_sup_c_sup_tot.montant_facture_0,
|
|
|
montant_facture_1 = p_factures_lignes_c.montant_facture_1 - w_factures_lignes_sup_c_sup_tot.montant_facture_1,
|
|
|
montant_facture_2 = p_factures_lignes_c.montant_facture_2 - w_factures_lignes_sup_c_sup_tot.montant_facture_2,
|
|
|
montant_facture_22 = p_factures_lignes_c.montant_facture_22 - w_factures_lignes_sup_c_sup_tot.montant_facture_22,
|
|
|
montant_comptabilise = p_factures_lignes_c.montant_comptabilise - w_factures_lignes_sup_c_sup_tot.montant_comptabilise,
|
|
|
montant_comptabilise_0 = p_factures_lignes_c.montant_comptabilise_0 - w_factures_lignes_sup_c_sup_tot.montant_comptabilise_0,
|
|
|
montant_comptabilise_1 = p_factures_lignes_c.montant_comptabilise_1 - w_factures_lignes_sup_c_sup_tot.montant_comptabilise_1,
|
|
|
montant_comptabilise_2 = p_factures_lignes_c.montant_comptabilise_2 - w_factures_lignes_sup_c_sup_tot.montant_comptabilise_2,
|
|
|
montant_comptabilise_22 = p_factures_lignes_c.montant_comptabilise_22 - w_factures_lignes_sup_c_sup_tot.montant_comptabilise_22,
|
|
|
montant_encours = p_factures_lignes_c.montant_encours - w_factures_lignes_sup_c_sup_tot.montant_encours,
|
|
|
montant_encours_0 = p_factures_lignes_c.montant_encours_0 - w_factures_lignes_sup_c_sup_tot.montant_encours_0,
|
|
|
montant_encours_1 = p_factures_lignes_c.montant_encours_1 - w_factures_lignes_sup_c_sup_tot.montant_encours_1,
|
|
|
montant_encours_2 = p_factures_lignes_c.montant_encours_2 - w_factures_lignes_sup_c_sup_tot.montant_encours_2,
|
|
|
montant_encours_22 = p_factures_lignes_c.montant_encours_22 - w_factures_lignes_sup_c_sup_tot.montant_encours_22,
|
|
|
montant_facture_actes_inclus_dans_sejour = p_factures_lignes_c.montant_facture_actes_inclus_dans_sejour - w_factures_lignes_sup_c_sup_tot.montant_facture_actes_inclus_dans_sejour,
|
|
|
montant_facture_0_actes_inclus_dans_sejour = p_factures_lignes_c.montant_facture_0_actes_inclus_dans_sejour - w_factures_lignes_sup_c_sup_tot.montant_facture_0_actes_inclus_dans_sejour,
|
|
|
montant_facture_1_actes_inclus_dans_sejour = p_factures_lignes_c.montant_facture_1_actes_inclus_dans_sejour - w_factures_lignes_sup_c_sup_tot.montant_facture_1_actes_inclus_dans_sejour,
|
|
|
montant_facture_2_actes_inclus_dans_sejour = p_factures_lignes_c.montant_facture_2_actes_inclus_dans_sejour - w_factures_lignes_sup_c_sup_tot.montant_facture_2_actes_inclus_dans_sejour,
|
|
|
montant_facture_22_actes_inclus_dans_sejour = p_factures_lignes_c.montant_facture_22_actes_inclus_dans_sejour - w_factures_lignes_sup_c_sup_tot.montant_facture_22_actes_inclus_dans_sejour,
|
|
|
montant_comptabilise_budget_global_1 = p_factures_lignes_c.montant_comptabilise_budget_global_1 - w_factures_lignes_sup_c_sup_tot.montant_comptabilise_budget_global_1
|
|
|
FROM w_factures_lignes_sup_c_sup_tot
|
|
|
WHERE p_factures_lignes_c.CTID = from_CTID;
|
|
|
|
|
|
-- Rubriques internes cti
|
|
|
SELECT activite[PX].cti_reorganize_rubrique_facture_c('w_factures_lignes_sup_c_sup');
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_lignes_c(
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facture_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
compte_produit_id,
|
|
|
prestation_id,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
montant_facture_22,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
finess,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
nb_prestation,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
montant_encours,
|
|
|
montant_encours_0,
|
|
|
montant_encours_1,
|
|
|
montant_encours_2,
|
|
|
montant_encours_22,
|
|
|
montant_facture_actes_inclus_dans_sejour,
|
|
|
montant_facture_0_actes_inclus_dans_sejour,
|
|
|
montant_facture_1_actes_inclus_dans_sejour,
|
|
|
montant_facture_2_actes_inclus_dans_sejour,
|
|
|
montant_facture_22_actes_inclus_dans_sejour,
|
|
|
origine_facturation_id,
|
|
|
montant_comptabilise_budget_global_1,
|
|
|
facture_id)
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facture_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
compte_produit_id,
|
|
|
prestation_id,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
montant_facture_22,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
finess,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
nb_prestation,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
montant_encours,
|
|
|
montant_encours_0,
|
|
|
montant_encours_1,
|
|
|
montant_encours_2,
|
|
|
montant_encours_22,
|
|
|
montant_facture_actes_inclus_dans_sejour,
|
|
|
montant_facture_0_actes_inclus_dans_sejour,
|
|
|
montant_facture_1_actes_inclus_dans_sejour,
|
|
|
montant_facture_2_actes_inclus_dans_sejour,
|
|
|
montant_facture_22_actes_inclus_dans_sejour,
|
|
|
origine_facturation_id,
|
|
|
montant_comptabilise_budget_global_1,
|
|
|
facture_id
|
|
|
FROM w_factures_lignes_sup_c_sup;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures_lignes_c
|
|
|
SET lieu_id = p_mouvements_sejour.lieu_id
|
|
|
FROM activite[PX].p_factures, activite[PX].p_mouvements_sejour
|
|
|
WHERE p_factures_lignes_c.no_facture = p_factures.no_facture AND
|
|
|
p_factures.no_sejour = p_mouvements_sejour.no_sejour AND
|
|
|
activite[PX].p_factures_lignes_c.date_debut = p_mouvements_sejour.date AND
|
|
|
(p_mouvements_sejour.heure_fin = 240000 OR p_mouvements_sejour.nb_sorties_directes = 1) AND
|
|
|
p_factures_lignes_c.lieu_id <> p_mouvements_sejour.lieu_id;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_c_3');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_c_4');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_c_5');
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
|
|
|
<NODE label="Compte client Clinique">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_soldes_c_1');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_soldes_c_2');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_soldes_c_3');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_soldes_c_4');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_soldes_c_8');
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_soldes_c(
|
|
|
no_facture,
|
|
|
date_comptable,
|
|
|
rubrique_comptabilisee_id,
|
|
|
prestation_id,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
montant_regle,
|
|
|
montant_regle_0,
|
|
|
montant_regle_1,
|
|
|
montant_regle_2,
|
|
|
montant_regle_22
|
|
|
)
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
date_vente,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
SUM(montant_comptabilise),
|
|
|
SUM(montant_comptabilise_0),
|
|
|
SUM(montant_comptabilise_1),
|
|
|
SUM(montant_comptabilise_2),
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0
|
|
|
FROM W_FACT_LIGNE_C_1
|
|
|
GROUP BY 1,2,3,4
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
date_vente,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
SUM(montant_comptabilise),
|
|
|
SUM(montant_comptabilise_0),
|
|
|
SUM(montant_comptabilise_1),
|
|
|
SUM(montant_comptabilise_2),
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0
|
|
|
FROM W_FACT_LIGNE_C_2
|
|
|
GROUP BY 1,2,3,4
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
date_vente,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
SUM(montant_comptabilise),
|
|
|
SUM(montant_comptabilise_0),
|
|
|
SUM(montant_comptabilise_1),
|
|
|
SUM(montant_comptabilise_2),
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0
|
|
|
FROM W_FACT_LIGNE_C_0
|
|
|
GROUP BY 1,2,3,4;
|
|
|
|
|
|
|
|
|
-- Modification montants réglés factures pour salariés
|
|
|
|
|
|
DROP TABLE IF EXISTS w_VENTIL_PAIEMENT_SALARIE;
|
|
|
CREATE TEMP TABLE w_VENTIL_PAIEMENT_SALARIE AS
|
|
|
SELECT
|
|
|
W_FACTURE_QSP.no_facture,
|
|
|
SUM(DET_VENT.VERSE_CONV + DET_VENT.VERSE_DP) AS montant_regle,
|
|
|
SUM(CASE WHEN tiers = '3' THEN DET_VENT.VERSE_CONV + DET_VENT.VERSE_DP ELSE 0 END) AS montant_regle_0,
|
|
|
SUM(CASE WHEN tiers = '1' THEN DET_VENT.VERSE_CONV + DET_VENT.VERSE_DP ELSE 0 END) AS montant_regle_1,
|
|
|
SUM(CASE WHEN tiers = '2' THEN DET_VENT.VERSE_CONV + DET_VENT.VERSE_DP ELSE 0 END) AS montant_regle_2,
|
|
|
0 AS montant_regle_22
|
|
|
FROM prod_qsp.VENTIL_PAIEMENT
|
|
|
JOIN prod_qsp.DET_VENT ON VENTIL_PAIEMENT.PAIEMENT_LIG = DET_VENT.PAIEMENT_LIG
|
|
|
JOIN prod_qsp.SAISIE ON DET_VENT.N_SAISIE = SAISIE.N_SAISIE
|
|
|
JOIN W_FACTURE_QSP ON W_FACTURE_QSP.NUM_FACT = VENTIL_PAIEMENT.NUM_FACT
|
|
|
LEFT JOIN activite[PX].t_medecins_administratifs ON SAISIE.C_PRAT = t_medecins_administratifs.code_original
|
|
|
WHERE COALESCE(t_medecins_administratifs.est_medecin_salarie,'0') = '1' AND
|
|
|
TRANS_CPTA <> 0
|
|
|
GROUP BY 1;
|
|
|
|
|
|
CREATE INDEX w_VENTIL_PAIEMENT_SALARIE_I1
|
|
|
ON w_VENTIL_PAIEMENT_SALARIE
|
|
|
USING btree
|
|
|
(no_facture);
|
|
|
|
|
|
UPDATE activite[PX].p_factures
|
|
|
SET
|
|
|
montant_regle_c = montant_regle_c + w_VENTIL_PAIEMENT_SALARIE.montant_regle,
|
|
|
montant_regle_h = montant_regle_h - w_VENTIL_PAIEMENT_SALARIE.montant_regle,
|
|
|
montant_regle_1_c = montant_regle_1_c + w_VENTIL_PAIEMENT_SALARIE.montant_regle_1,
|
|
|
montant_regle_1_h = montant_regle_1_h - w_VENTIL_PAIEMENT_SALARIE.montant_regle_1,
|
|
|
montant_regle_2_c = montant_regle_2_c + w_VENTIL_PAIEMENT_SALARIE.montant_regle_2,
|
|
|
montant_regle_2_h = montant_regle_2_h - w_VENTIL_PAIEMENT_SALARIE.montant_regle_2,
|
|
|
montant_regle_0_c = montant_regle_0_c + w_VENTIL_PAIEMENT_SALARIE.montant_regle_0,
|
|
|
montant_regle_0_h = montant_regle_0_h - w_VENTIL_PAIEMENT_SALARIE.montant_regle_0
|
|
|
FROM w_VENTIL_PAIEMENT_SALARIE
|
|
|
WHERE w_VENTIL_PAIEMENT_SALARIE.no_facture = p_factures.no_facture;
|
|
|
|
|
|
-- génération règlements
|
|
|
|
|
|
DROP TABLE IF EXISTS w_VENTIL_PAIEMENT_C;
|
|
|
|
|
|
CREATE TEMP TABLE w_VENTIL_PAIEMENT_C AS
|
|
|
SELECT
|
|
|
W_FACTURE_QSP.no_facture,
|
|
|
date(DT_VENT) AS date_comptable,
|
|
|
COALESCE(t_rubriques_facturation.oid,0) AS rubrique_comptabilisee_id,
|
|
|
COALESCE(t_prestations.oid,0) AS prestation_id,
|
|
|
0 AS montant_comptabilise,
|
|
|
0 AS montant_comptabilise_0,
|
|
|
0 AS montant_comptabilise_1,
|
|
|
0 AS montant_comptabilise_2,
|
|
|
0 AS montant_comptabilise_22,
|
|
|
SUM(DET_VENT.VERSE_CONV + DET_VENT.VERSE_DP) AS montant_regle,
|
|
|
SUM(CASE WHEN tiers = '3' THEN DET_VENT.VERSE_CONV + DET_VENT.VERSE_DP ELSE 0 END) AS montant_regle_0,
|
|
|
SUM(CASE WHEN tiers = '1' THEN DET_VENT.VERSE_CONV + DET_VENT.VERSE_DP ELSE 0 END) AS montant_regle_1,
|
|
|
SUM(CASE WHEN tiers = '2' THEN DET_VENT.VERSE_CONV + DET_VENT.VERSE_DP ELSE 0 END) AS montant_regle_2,
|
|
|
0 AS montant_regle_22
|
|
|
FROM prod_qsp.VENTIL_PAIEMENT
|
|
|
JOIN prod_qsp.DET_VENT ON VENTIL_PAIEMENT.PAIEMENT_LIG = DET_VENT.PAIEMENT_LIG
|
|
|
JOIN prod_qsp.SAISIE ON DET_VENT.N_SAISIE = SAISIE.N_SAISIE
|
|
|
JOIN W_FACTURE_QSP ON W_FACTURE_QSP.NUM_FACT = VENTIL_PAIEMENT.NUM_FACT
|
|
|
JOIN prod_qsp.PRESTATION ON SAISIE.CODE_PREST = PRESTATION.CODE_PREST
|
|
|
LEFT JOIN activite[PX].t_rubriques_facturation ON PRESTATION.CODE_PREST = t_rubriques_facturation.code_original
|
|
|
LEFT JOIN activite.t_prestations ON PRESTATION.CODE_NORM = t_prestations.code_original
|
|
|
LEFT JOIN activite[PX].t_medecins_administratifs ON SAISIE.C_PRAT = t_medecins_administratifs.code_original
|
|
|
WHERE (PRESTATION.TYPE_PREST <> 'H' OR COALESCE(t_medecins_administratifs.est_medecin_salarie,'0') = '1') AND
|
|
|
TRANS_CPTA <> 0
|
|
|
GROUP BY 1,2,3,4;
|
|
|
|
|
|
CREATE INDEX w_VENTIL_PAIEMENT_C_i1
|
|
|
ON w_VENTIL_PAIEMENT_C
|
|
|
USING btree
|
|
|
(no_facture, date_comptable, rubrique_comptabilisee_id, prestation_id);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_soldes_c(
|
|
|
no_facture,
|
|
|
date_comptable,
|
|
|
rubrique_comptabilisee_id,
|
|
|
prestation_id,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
montant_regle,
|
|
|
montant_regle_0,
|
|
|
montant_regle_1,
|
|
|
montant_regle_2,
|
|
|
montant_regle_22
|
|
|
)
|
|
|
SELECT
|
|
|
w_VENTIL_PAIEMENT_C.no_facture,
|
|
|
w_VENTIL_PAIEMENT_C.date_comptable,
|
|
|
w_VENTIL_PAIEMENT_C.rubrique_comptabilisee_id,
|
|
|
w_VENTIL_PAIEMENT_C.prestation_id,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
w_VENTIL_PAIEMENT_C.montant_regle,
|
|
|
w_VENTIL_PAIEMENT_C.montant_regle_0,
|
|
|
w_VENTIL_PAIEMENT_C.montant_regle_1,
|
|
|
w_VENTIL_PAIEMENT_C.montant_regle_2,
|
|
|
w_VENTIL_PAIEMENT_C.montant_regle_22
|
|
|
FROM w_VENTIL_PAIEMENT_C
|
|
|
WHERE w_VENTIL_PAIEMENT_C.date_comptable IS NOT NULL;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_soldes_c(
|
|
|
no_facture,
|
|
|
date_comptable,
|
|
|
rubrique_comptabilisee_id,
|
|
|
prestation_id,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
montant_regle,
|
|
|
montant_regle_0,
|
|
|
montant_regle_1,
|
|
|
montant_regle_2,
|
|
|
montant_regle_22,
|
|
|
od_avoir)
|
|
|
SELECT
|
|
|
p_factures_soldes_c.no_facture,
|
|
|
date_od_avoir,
|
|
|
rubrique_comptabilisee_id,
|
|
|
prestation_id,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
p_factures_soldes_c.montant_comptabilise,
|
|
|
p_factures_soldes_c.montant_comptabilise_0,
|
|
|
p_factures_soldes_c.montant_comptabilise_1,
|
|
|
p_factures_soldes_c.montant_comptabilise_2,
|
|
|
p_factures_soldes_c.montant_comptabilise_22,
|
|
|
'1'
|
|
|
FROM activite[PX].p_factures_soldes_c
|
|
|
JOIN w_ods_avoir ON p_factures_soldes_c.no_facture = w_ods_avoir.no_facture
|
|
|
WHERE p_factures_soldes_c.montant_comptabilise <> 0;
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_soldes_c(
|
|
|
no_facture,
|
|
|
date_comptable,
|
|
|
rubrique_comptabilisee_id,
|
|
|
prestation_id,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
montant_regle,
|
|
|
montant_regle_0,
|
|
|
montant_regle_1,
|
|
|
montant_regle_2,
|
|
|
montant_regle_22,
|
|
|
od_avoir)
|
|
|
SELECT
|
|
|
p_factures_soldes_c.no_facture,
|
|
|
date_od_avoir,
|
|
|
rubrique_comptabilisee_id,
|
|
|
prestation_id,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
p_factures_soldes_c.montant_comptabilise,
|
|
|
p_factures_soldes_c.montant_comptabilise_0,
|
|
|
p_factures_soldes_c.montant_comptabilise_1,
|
|
|
p_factures_soldes_c.montant_comptabilise_2,
|
|
|
p_factures_soldes_c.montant_comptabilise_22,
|
|
|
'1'
|
|
|
FROM activite[PX].p_factures_soldes_c JOIN w_ods_avoir ON p_factures_soldes_c.no_facture = w_ods_avoir.no_facture_od_avoir
|
|
|
WHERE p_factures_soldes_c.montant_comptabilise <> 0;
|
|
|
|
|
|
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_soldes_c_1');
|
|
|
|
|
|
|
|
|
|
|
|
-- Correction avoirs qui ne sont pas des od
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_soldes_c_reg;
|
|
|
CREATE TEMP TABLE w_factures_soldes_c_reg AS
|
|
|
SELECT p_factures.no_sejour, p_factures.no_facture, no_facture_od_avoir,
|
|
|
SUM(montant_regle) AS montant_regle_s,
|
|
|
SUM(montant_regle_1) AS montant_regle_1_s,
|
|
|
SUM(montant_regle_2) AS montant_regle_2_s,
|
|
|
SUM(montant_regle_0) AS montant_regle_0_s,
|
|
|
MAX(p_factures.montant_regle_c) AS montant_regle_f ,
|
|
|
MAX(CASE WHEN od_avoir = '1' THEN date_comptable ELSE NULL END) AS date_comptable_s
|
|
|
FROM activite[PX].p_factures_soldes_c
|
|
|
JOIN activite[PX].p_factures ON p_factures_soldes_c.no_facture = p_factures.no_facture
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING SUM(montant_regle) <> 0 AND SUM(montant_regle) = MAX(p_factures.montant_regle_c) * 2 ;
|
|
|
|
|
|
CREATE INDEX w_factures_soldes_c_reg_i1
|
|
|
ON w_factures_soldes_c_reg
|
|
|
USING btree
|
|
|
(no_facture);
|
|
|
|
|
|
UPDATE activite[PX].p_factures_soldes_c
|
|
|
SET montant_regle = 0,
|
|
|
montant_regle_1 = 0,
|
|
|
montant_regle_2 = 0,
|
|
|
montant_regle_0 = 0
|
|
|
FROM w_factures_soldes_c_reg
|
|
|
WHERE p_factures_soldes_c.no_facture = w_factures_soldes_c_reg.no_facture AND
|
|
|
p_factures_soldes_c.date_comptable = w_factures_soldes_c_reg.date_comptable_s AND
|
|
|
od_avoir = '1' AND
|
|
|
montant_regle_s = montant_regle_f * 2;
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures_soldes_c
|
|
|
SET od_avoir = '0'
|
|
|
FROM w_factures_soldes_c_reg
|
|
|
WHERE p_factures_soldes_c.no_facture = w_factures_soldes_c_reg.no_facture_od_avoir AND
|
|
|
p_factures_soldes_c.date_comptable = w_factures_soldes_c_reg.date_comptable_s AND
|
|
|
od_avoir = '1' AND
|
|
|
montant_regle_s = montant_regle_f * 2;
|
|
|
|
|
|
-- Correction discordance total réglé / détail régle
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_soldes_c_ecartreg;
|
|
|
CREATE TEMP TABLE w_factures_soldes_c_ecartreg AS
|
|
|
SELECT p_factures.no_sejour, p_factures.no_facture,
|
|
|
SUM(montant_regle) AS montant_regle_s,
|
|
|
SUM(montant_regle_1) AS montant_regle_1_s,
|
|
|
SUM(montant_regle_2) AS montant_regle_2_s,
|
|
|
SUM(montant_regle_0) AS montant_regle_0_s,
|
|
|
MAX(p_factures.montant_regle_c) AS montant_regle_f ,
|
|
|
MAX(p_factures.montant_regle_1_c) AS montant_regle_1_f ,
|
|
|
MAX(p_factures.montant_regle_2_c) AS montant_regle_2_f ,
|
|
|
MAX(p_factures.montant_regle_0_c) AS montant_regle_0_f ,
|
|
|
COALESCE(MAX(CASE WHEN montant_regle <> 0 THEN date_comptable ELSE NULL END),MAX(date_comptable)) AS date_comptable
|
|
|
FROM activite[PX].p_factures_soldes_c
|
|
|
JOIN activite[PX].p_factures ON p_factures_soldes_c.no_facture = p_factures.no_facture
|
|
|
GROUP BY 1,2
|
|
|
HAVING SUM(montant_regle) <> MAX(p_factures.montant_regle_c);
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_soldes_c(
|
|
|
no_facture,
|
|
|
date_comptable,
|
|
|
rubrique_comptabilisee_id,
|
|
|
prestation_id,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
montant_regle,
|
|
|
montant_regle_0,
|
|
|
montant_regle_1,
|
|
|
montant_regle_2,
|
|
|
montant_regle_22
|
|
|
)
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
date_comptable,
|
|
|
0::bigint AS rubrique_comptabilisee_id,
|
|
|
0::bigint AS prestation_id,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
montant_regle_f - montant_regle_s AS montant_regle,
|
|
|
montant_regle_1_f - montant_regle_1_s AS montant_regle_0,
|
|
|
montant_regle_2_f - montant_regle_2_s AS montant_regle_1,
|
|
|
montant_regle_0_f - montant_regle_0_s AS montant_regle_2,
|
|
|
0::numeric AS montant_regle_22
|
|
|
FROM w_factures_soldes_c_ecartreg
|
|
|
WHERE date_comptable IS NOT NULL;
|
|
|
|
|
|
|
|
|
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_soldes_c_2');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_soldes_c_3');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_soldes_c_4');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_soldes_c_8');
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Lignes non facturées Honoraires">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Lignes factures Honoraires">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
INSERT INTO base.t_actes(
|
|
|
code, texte, texte_court, nomenclature, ccam_regroupement_id_1, ccam_regroupement_id_4,
|
|
|
geste_marqueur_id)
|
|
|
SELECT
|
|
|
CODE_PREST,
|
|
|
MIN(t_rubriques_facturation.texte),
|
|
|
MIN(t_rubriques_facturation.texte_court),
|
|
|
'NGAP',
|
|
|
0,
|
|
|
0,
|
|
|
0
|
|
|
FROM prod_qsp.SAISIE
|
|
|
LEFT JOIN activite[PX].t_rubriques_facturation ON CODE_PREST = t_rubriques_facturation.code_original
|
|
|
LEFT JOIN base.t_actes ON (trim(CODE_PREST) = trim(t_actes.code))
|
|
|
WHERE COALESCE(SAISIE.C_PRAT,'') <> '' AND t_actes.oid is NULL
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS W_FACT_LIGNE_H_1;
|
|
|
|
|
|
CREATE TEMP TABLE W_FACT_LIGNE_H_1 AS
|
|
|
SELECT
|
|
|
W_FACT_LIGNE.N_HOSPI,
|
|
|
date_vente,
|
|
|
lieu_id,
|
|
|
no_facture,
|
|
|
W_FACT_LIGNE.ETAT,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
medecin_facture_id,
|
|
|
medecin_comptabilise_id,
|
|
|
|
|
|
acte_id,
|
|
|
extract('hour' FROM W_FACT_LIGNE.D_DEB) AS heure_debut,
|
|
|
W_FACT_LIGNE.PHASE_TRAIT AS phase_ccam,
|
|
|
W_FACT_LIGNE.CODE_ACTIV AS activite_ccam,
|
|
|
W_FACT_LIGNE.EXT_DOC AS extension_ccam,
|
|
|
W_FACT_LIGNE.MODIF_1 AS modificateur_ccam_1,
|
|
|
W_FACT_LIGNE.MODIF_2 AS modificateur_ccam_2,
|
|
|
W_FACT_LIGNE.MODIF_3 AS modificateur_ccam_3,
|
|
|
W_FACT_LIGNE.MODIF_4 AS modificateur_ccam_4,
|
|
|
|
|
|
date(W_FACT_LIGNE.D_DEB) AS date_debut,
|
|
|
date(W_FACT_LIGNE.D_DEB) AS date_fin,
|
|
|
CASE WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE > 0 THEN 0 - W_FACT_LIGNE.QTE
|
|
|
ELSE W_FACT_LIGNE.QTE END AS nb_rubrique,
|
|
|
CASE WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE > 0 THEN 0 - W_FACT_LIGNE.QTE
|
|
|
ELSE W_FACT_LIGNE.QTE END AS nb_prestations,
|
|
|
W_FACT_LIGNE.COEFF AS coefficient,
|
|
|
W_FACT_LIGNE.GRATUIT,
|
|
|
W_FACT_LIGNE.N_GHS,
|
|
|
W_FACT_LIGNE.COEFF_MCO AS coefficient_mco,
|
|
|
W_FACT_LIGNE.PU AS prix_unitaire,
|
|
|
|
|
|
CASE WHEN amc = 0 AND ass = 0 AND W_FACT_LIGNE.etat <> 3 THEN W_FACT_LIGNE.MT_DP
|
|
|
WHEN amc = 0 AND ass = 0 AND W_FACT_LIGNE.etat = 3 THEN 0 - W_FACT_LIGNE.MT_DP
|
|
|
ELSE 0 END AS montant_depassement,
|
|
|
|
|
|
W_FACT_LIGNE.TAUX AS taux_1,
|
|
|
0::numeric AS taux_2,
|
|
|
0::numeric AS taux_0,
|
|
|
W_FACT_LIGNE.AMO AS montant_facture,
|
|
|
W_FACT_LIGNE.AMO AS montant_facture_1,
|
|
|
0::numeric AS montant_facture_2,
|
|
|
0::numeric AS montant_facture_0,
|
|
|
CASE WHEN est_medecin_salarie <> '1' AND SOL_AMO <> 2 THEN W_FACT_LIGNE.AMO ELSE 0 END AS montant_comptabilise,
|
|
|
CASE WHEN est_medecin_salarie <> '1' AND SOL_AMO <> 2 THEN W_FACT_LIGNE.AMO ELSE 0 END AS montant_comptabilise_1,
|
|
|
0::numeric AS montant_comptabilise_2,
|
|
|
0::numeric AS montant_comptabilise_0,
|
|
|
W_FACT_LIGNE.ENC_AMO AS montant_regle_1,
|
|
|
0::numeric AS montant_regle_2,
|
|
|
0::numeric AS montant_regle_0
|
|
|
|
|
|
FROM W_FACT_LIGNE
|
|
|
WHERE NUM_FACT_AMO <> 0
|
|
|
AND W_FACT_LIGNE.TYPE_PREST = 'H' ;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS W_FACT_LIGNE_H_2;
|
|
|
|
|
|
CREATE TEMP TABLE W_FACT_LIGNE_H_2 AS
|
|
|
|
|
|
SELECT
|
|
|
W_FACT_LIGNE.N_HOSPI,
|
|
|
W_FACT_LIGNE.date_vente AS date_vente,
|
|
|
W_FACT_LIGNE.lieu_id,
|
|
|
W_FACT_LIGNE.no_facture AS no_facture,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
medecin_facture_id,
|
|
|
medecin_comptabilise_id,
|
|
|
acte_id,
|
|
|
extract('hour' FROM W_FACT_LIGNE.D_DEB) AS heure_debut,
|
|
|
W_FACT_LIGNE.PHASE_TRAIT AS phase_ccam,
|
|
|
W_FACT_LIGNE.CODE_ACTIV AS activite_ccam,
|
|
|
W_FACT_LIGNE.EXT_DOC AS extension_ccam,
|
|
|
W_FACT_LIGNE.MODIF_1 AS modificateur_ccam_1,
|
|
|
W_FACT_LIGNE.MODIF_2 AS modificateur_ccam_2,
|
|
|
W_FACT_LIGNE.MODIF_3 AS modificateur_ccam_3,
|
|
|
W_FACT_LIGNE.MODIF_4 AS modificateur_ccam_4,
|
|
|
|
|
|
date(W_FACT_LIGNE.D_DEB) AS date_debut,
|
|
|
date(W_FACT_LIGNE.D_FIN) AS date_fin,
|
|
|
CASE
|
|
|
WHEN AMO <> 0 THEN 0
|
|
|
WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE > 0 THEN 0 - W_FACT_LIGNE.QTE
|
|
|
ELSE W_FACT_LIGNE.QTE END AS nb_rubrique,
|
|
|
CASE
|
|
|
WHEN AMO <> 0 THEN 0
|
|
|
WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE > 0 THEN 0 - W_FACT_LIGNE.QTE
|
|
|
ELSE W_FACT_LIGNE.QTE END AS nb_prestations,
|
|
|
W_FACT_LIGNE.COEFF AS coefficient,
|
|
|
W_FACT_LIGNE.GRATUIT,
|
|
|
W_FACT_LIGNE.N_GHS,
|
|
|
W_FACT_LIGNE.COEFF_MCO AS coefficient_mco,
|
|
|
W_FACT_LIGNE.PU AS prix_unitaire,
|
|
|
|
|
|
CASE WHEN amc = 0 AND ass = 0 THEN 0
|
|
|
WHEN ass = 0 AND W_FACT_LIGNE.etat <> 3 THEN W_FACT_LIGNE.MT_DP
|
|
|
WHEN ass = 0 AND W_FACT_LIGNE.etat = 3 THEN 0 - W_FACT_LIGNE.MT_DP
|
|
|
ELSE 0 END AS montant_depassement,
|
|
|
|
|
|
0::numeric AS taux_1,
|
|
|
0::numeric AS taux_2,
|
|
|
0::numeric AS taux_0,
|
|
|
W_FACT_LIGNE.AMC AS montant_facture,
|
|
|
0::numeric AS montant_facture_1,
|
|
|
W_FACT_LIGNE.AMC AS montant_facture_2,
|
|
|
0::numeric AS montant_facture_0,
|
|
|
CASE WHEN est_medecin_salarie <> '1' AND SOL_AMC <> 2 THEN W_FACT_LIGNE.AMC ELSE 0 END AS montant_comptabilise,
|
|
|
0::numeric AS montant_comptabilise_1,
|
|
|
CASE WHEN est_medecin_salarie <> '1' AND SOL_AMC <> 2 THEN W_FACT_LIGNE.AMC ELSE 0 END AS montant_comptabilise_2,
|
|
|
0::numeric AS montant_comptabilise_0,
|
|
|
0::numeric AS montant_regle_1,
|
|
|
W_FACT_LIGNE.ENC_AMC AS montant_regle_2,
|
|
|
0::numeric AS montant_regle_0
|
|
|
|
|
|
FROM W_FACT_LIGNE
|
|
|
WHERE NUM_FACT_AMC <> 0
|
|
|
AND W_FACT_LIGNE.TYPE_PREST = 'H';
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS W_FACT_LIGNE_H_0;
|
|
|
|
|
|
CREATE TEMP TABLE W_FACT_LIGNE_H_0 AS
|
|
|
|
|
|
SELECT
|
|
|
W_FACT_LIGNE.N_HOSPI,
|
|
|
W_FACT_LIGNE.date_vente AS date_vente,
|
|
|
W_FACT_LIGNE.lieu_id,
|
|
|
W_FACT_LIGNE.no_facture AS no_facture,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
medecin_facture_id,
|
|
|
medecin_comptabilise_id,
|
|
|
acte_id,
|
|
|
extract('hour' FROM W_FACT_LIGNE.D_DEB) AS heure_debut,
|
|
|
W_FACT_LIGNE.PHASE_TRAIT AS phase_ccam,
|
|
|
W_FACT_LIGNE.CODE_ACTIV AS activite_ccam,
|
|
|
W_FACT_LIGNE.EXT_DOC AS extension_ccam,
|
|
|
W_FACT_LIGNE.MODIF_1 AS modificateur_ccam_1,
|
|
|
W_FACT_LIGNE.MODIF_2 AS modificateur_ccam_2,
|
|
|
W_FACT_LIGNE.MODIF_3 AS modificateur_ccam_3,
|
|
|
W_FACT_LIGNE.MODIF_4 AS modificateur_ccam_4,
|
|
|
|
|
|
date(W_FACT_LIGNE.D_DEB) AS date_debut,
|
|
|
date(W_FACT_LIGNE.D_FIN) AS date_fin,
|
|
|
CASE
|
|
|
WHEN AMO <> 0 THEN 0
|
|
|
WHEN AMC <> 0 THEN 0
|
|
|
WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE > 0 THEN 0 - W_FACT_LIGNE.QTE
|
|
|
ELSE W_FACT_LIGNE.QTE END AS nb_rubrique,
|
|
|
CASE
|
|
|
WHEN AMO <> 0 THEN 0
|
|
|
WHEN AMC <> 0 THEN 0
|
|
|
WHEN W_FACT_LIGNE.ETAT = 3 AND W_FACT_LIGNE.QTE > 0 THEN 0 - W_FACT_LIGNE.QTE
|
|
|
ELSE W_FACT_LIGNE.QTE END AS nb_prestations,
|
|
|
W_FACT_LIGNE.COEFF AS coefficient,
|
|
|
W_FACT_LIGNE.GRATUIT,
|
|
|
W_FACT_LIGNE.N_GHS,
|
|
|
W_FACT_LIGNE.COEFF_MCO AS coefficient_mco,
|
|
|
W_FACT_LIGNE.PU AS prix_unitaire,
|
|
|
|
|
|
CASE WHEN amc = 0 AND ass = 0 THEN 0
|
|
|
WHEN ass = 0 THEN 0
|
|
|
WHEN W_FACT_LIGNE.etat <> 3 THEN W_FACT_LIGNE.MT_DP
|
|
|
WHEN W_FACT_LIGNE.etat = 3 THEN 0 - W_FACT_LIGNE.MT_DP
|
|
|
ELSE 0 END AS montant_depassement,
|
|
|
|
|
|
0::numeric AS taux_1,
|
|
|
0::numeric AS taux_2,
|
|
|
0::numeric AS taux_0,
|
|
|
W_FACT_LIGNE.ASS AS montant_facture,
|
|
|
0::numeric AS montant_facture_1,
|
|
|
0::numeric AS montant_facture_2,
|
|
|
W_FACT_LIGNE.ASS AS montant_facture_0,
|
|
|
CASE WHEN est_medecin_salarie <> '1' AND SOL_ASS <> 2 THEN W_FACT_LIGNE.ASS ELSE 0 END AS montant_comptabilise,
|
|
|
0::numeric AS montant_comptabilise_1,
|
|
|
0::numeric AS montant_comptabilise_2,
|
|
|
CASE WHEN est_medecin_salarie <> '1' AND SOL_ASS <> 2 THEN W_FACT_LIGNE.ASS ELSE 0 END AS montant_comptabilise_0,
|
|
|
0::numeric AS montant_regle_1,
|
|
|
0::numeric AS montant_regle_2,
|
|
|
W_FACT_LIGNE.ENC_ASS AS montant_regle_0
|
|
|
FROM W_FACT_LIGNE
|
|
|
WHERE NUM_FACT_ASS <> 0
|
|
|
AND TYPE_PREST = 'H';
|
|
|
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_h_1');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_h_2');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_h_3');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_h_4');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_h_5');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_h_6');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_h_7');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_h_8');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_h_9');
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_lignes_h(
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
nb_prestation,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
medecin_facture_id,
|
|
|
medecin_comptabilise_id,
|
|
|
prestation_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
montant_facture_22,
|
|
|
montant_depassement,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
|
|
|
montant_encours,
|
|
|
montant_encours_0,
|
|
|
montant_encours_1,
|
|
|
montant_encours_2,
|
|
|
montant_encours_22,
|
|
|
|
|
|
acte_id,
|
|
|
activite_ccam
|
|
|
)
|
|
|
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
nb_prestations,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
medecin_facture_id,
|
|
|
medecin_comptabilise_id,
|
|
|
prestation_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
0 AS montant_facture_22,
|
|
|
montant_depassement,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
0 AS taux_22,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
0 AS montant_comptabilise_22,
|
|
|
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
|
|
|
acte_id,
|
|
|
activite_ccam
|
|
|
|
|
|
FROM W_FACT_LIGNE_H_1
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
nb_prestations,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
medecin_facture_id,
|
|
|
medecin_comptabilise_id,
|
|
|
prestation_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
0 AS montant_facture_22,
|
|
|
montant_depassement,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
0 AS taux_22,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
0 AS montant_comptabilise_22,
|
|
|
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
|
|
|
acte_id,
|
|
|
activite_ccam
|
|
|
|
|
|
FROM W_FACT_LIGNE_H_2
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
nb_prestations,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
medecin_facture_id,
|
|
|
medecin_comptabilise_id,
|
|
|
prestation_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
0 AS montant_facture_22,
|
|
|
montant_depassement,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
0 AS taux_22,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
0 AS montant_comptabilise_22,
|
|
|
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
|
|
|
acte_id,
|
|
|
activite_ccam
|
|
|
|
|
|
FROM W_FACT_LIGNE_H_0;
|
|
|
|
|
|
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_h_1');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_h_2');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_h_3');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_h_4');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_h_5');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_h_6');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_h_7');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_h_8');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_h_9');
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Compte client Honoraires">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_soldes_h_1');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_soldes_h_3');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_soldes_h_4');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_soldes_h_8');
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_soldes_h(
|
|
|
no_facture,
|
|
|
date_comptable,
|
|
|
medecin_comptabilise_id,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
montant_regle,
|
|
|
montant_regle_0,
|
|
|
montant_regle_1,
|
|
|
montant_regle_2,
|
|
|
montant_regle_22
|
|
|
)
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
date_vente,
|
|
|
medecin_comptabilise_id,
|
|
|
SUM(montant_comptabilise),
|
|
|
SUM(montant_comptabilise_0),
|
|
|
SUM(montant_comptabilise_1),
|
|
|
SUM(montant_comptabilise_2),
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0
|
|
|
FROM W_FACT_LIGNE_H_1
|
|
|
GROUP BY 1,2,3
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
date_vente,
|
|
|
medecin_comptabilise_id,
|
|
|
SUM(montant_comptabilise),
|
|
|
SUM(montant_comptabilise_0),
|
|
|
SUM(montant_comptabilise_1),
|
|
|
SUM(montant_comptabilise_2),
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0
|
|
|
FROM W_FACT_LIGNE_H_2
|
|
|
GROUP BY 1,2,3
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
date_vente,
|
|
|
medecin_comptabilise_id,
|
|
|
SUM(montant_comptabilise),
|
|
|
SUM(montant_comptabilise_0),
|
|
|
SUM(montant_comptabilise_1),
|
|
|
SUM(montant_comptabilise_2),
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0
|
|
|
FROM W_FACT_LIGNE_H_0
|
|
|
GROUP BY 1,2,3;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_VENTIL_PAIEMENT_H;
|
|
|
CREATE TEMP TABLE w_VENTIL_PAIEMENT_H AS
|
|
|
SELECT
|
|
|
W_FACTURE_QSP.no_facture,
|
|
|
date(DT_VENT) AS date_comptable,
|
|
|
COALESCE(t_medecins_administratifs.oid,0) AS medecin_comptabilise_id,
|
|
|
0 AS montant_comptabilise,
|
|
|
0 AS montant_comptabilise_0,
|
|
|
0 AS montant_comptabilise_1,
|
|
|
0 AS montant_comptabilise_2,
|
|
|
0 AS montant_comptabilise_22,
|
|
|
SUM(DET_VENT.VERSE_CONV + DET_VENT.VERSE_DP) AS montant_regle,
|
|
|
SUM(CASE WHEN tiers = '3' THEN DET_VENT.VERSE_CONV + DET_VENT.VERSE_DP ELSE 0 END) AS montant_regle_0,
|
|
|
SUM(CASE WHEN tiers = '1' THEN DET_VENT.VERSE_CONV + DET_VENT.VERSE_DP ELSE 0 END) AS montant_regle_1,
|
|
|
SUM(CASE WHEN tiers = '2' THEN DET_VENT.VERSE_CONV + DET_VENT.VERSE_DP ELSE 0 END) AS montant_regle_2,
|
|
|
0 AS montant_regle_22
|
|
|
FROM prod_qsp.VENTIL_PAIEMENT
|
|
|
JOIN prod_qsp.DET_VENT ON VENTIL_PAIEMENT.PAIEMENT_LIG = DET_VENT.PAIEMENT_LIG
|
|
|
JOIN prod_qsp.SAISIE ON DET_VENT.N_SAISIE = SAISIE.N_SAISIE
|
|
|
JOIN prod_qsp.PRESTATION ON SAISIE.CODE_PREST = PRESTATION.CODE_PREST
|
|
|
JOIN W_FACTURE_QSP ON W_FACTURE_QSP.NUM_FACT = VENTIL_PAIEMENT.NUM_FACT
|
|
|
LEFT JOIN activite[PX].t_medecins_administratifs ON SAISIE.C_PRAT = t_medecins_administratifs.code_original
|
|
|
WHERE PRESTATION.TYPE_PREST = 'H' AND COALESCE(est_medecin_salarie,'0') <> '1' AND
|
|
|
TRANS_CPTA <> 0
|
|
|
GROUP BY 1,2,3;
|
|
|
|
|
|
|
|
|
CREATE INDEX w_VENTIL_PAIEMENT_H_i1
|
|
|
ON w_VENTIL_PAIEMENT_H
|
|
|
USING btree
|
|
|
(no_facture, date_comptable, medecin_comptabilise_id);
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_soldes_h(
|
|
|
no_facture,
|
|
|
date_comptable,
|
|
|
medecin_comptabilise_id,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
montant_regle,
|
|
|
montant_regle_0,
|
|
|
montant_regle_1,
|
|
|
montant_regle_2,
|
|
|
montant_regle_22
|
|
|
)
|
|
|
SELECT
|
|
|
w_VENTIL_PAIEMENT_H.no_facture,
|
|
|
w_VENTIL_PAIEMENT_H.date_comptable,
|
|
|
w_VENTIL_PAIEMENT_H.medecin_comptabilise_id,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
w_VENTIL_PAIEMENT_H.montant_regle,
|
|
|
w_VENTIL_PAIEMENT_H.montant_regle_0,
|
|
|
w_VENTIL_PAIEMENT_H.montant_regle_1,
|
|
|
w_VENTIL_PAIEMENT_H.montant_regle_2,
|
|
|
w_VENTIL_PAIEMENT_H.montant_regle_22
|
|
|
FROM w_VENTIL_PAIEMENT_H
|
|
|
WHERE w_VENTIL_PAIEMENT_H.date_comptable IS NOT NULL ;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_soldes_h(
|
|
|
no_facture,
|
|
|
date_comptable,
|
|
|
medecin_comptabilise_id,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
montant_regle,
|
|
|
montant_regle_0,
|
|
|
montant_regle_1,
|
|
|
montant_regle_2,
|
|
|
montant_regle_22,
|
|
|
od_avoir)
|
|
|
SELECT
|
|
|
p_factures_soldes_h.no_facture,
|
|
|
date_od_avoir,
|
|
|
medecin_comptabilise_id,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
p_factures_soldes_h.montant_comptabilise,
|
|
|
p_factures_soldes_h.montant_comptabilise_0,
|
|
|
p_factures_soldes_h.montant_comptabilise_1,
|
|
|
p_factures_soldes_h.montant_comptabilise_2,
|
|
|
p_factures_soldes_h.montant_comptabilise_22,
|
|
|
'1'
|
|
|
FROM activite[PX].p_factures_soldes_h JOIN w_ods_avoir ON p_factures_soldes_h.no_facture = w_ods_avoir.no_facture
|
|
|
WHERE p_factures_soldes_h.montant_comptabilise <> 0;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_soldes_h(
|
|
|
no_facture,
|
|
|
date_comptable,
|
|
|
medecin_comptabilise_id,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
montant_regle,
|
|
|
montant_regle_0,
|
|
|
montant_regle_1,
|
|
|
montant_regle_2,
|
|
|
montant_regle_22,
|
|
|
od_avoir)
|
|
|
SELECT
|
|
|
p_factures_soldes_h.no_facture,
|
|
|
date_od_avoir,
|
|
|
medecin_comptabilise_id,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
p_factures_soldes_h.montant_comptabilise,
|
|
|
p_factures_soldes_h.montant_comptabilise_0,
|
|
|
p_factures_soldes_h.montant_comptabilise_1,
|
|
|
p_factures_soldes_h.montant_comptabilise_2,
|
|
|
p_factures_soldes_h.montant_comptabilise_22,
|
|
|
'1'
|
|
|
FROM activite[PX].p_factures_soldes_h JOIN w_ods_avoir ON p_factures_soldes_h.no_facture = w_ods_avoir.no_facture_od_avoir
|
|
|
WHERE p_factures_soldes_h.montant_comptabilise <> 0;
|
|
|
|
|
|
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_soldes_h_1');
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- Avoirs qui ne sont pas des OD
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_soldes_h_reg;
|
|
|
CREATE TEMP TABLE w_factures_soldes_h_reg AS
|
|
|
SELECT p_factures.no_sejour, p_factures.no_facture, no_facture_od_avoir,
|
|
|
SUM(montant_regle) AS montant_regle_s,
|
|
|
SUM(montant_regle_1) AS montant_regle_1_s,
|
|
|
SUM(montant_regle_2) AS montant_regle_2_s,
|
|
|
SUM(montant_regle_0) AS montant_regle_0_s,
|
|
|
MAX(p_factures.montant_regle_h) AS montant_regle_f ,
|
|
|
MAX(CASE WHEN od_avoir = '1' THEN date_comptable ELSE NULL END) AS date_comptable_s
|
|
|
FROM activite[PX].p_factures_soldes_h
|
|
|
JOIN activite[PX].p_factures ON p_factures_soldes_h.no_facture = p_factures.no_facture
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING SUM(montant_regle) <> 0 AND SUM(montant_regle) = MAX(p_factures.montant_regle_h) * 2 ;
|
|
|
|
|
|
|
|
|
CREATE INDEX w_factures_soldes_h_reg_i1
|
|
|
ON w_factures_soldes_h_reg
|
|
|
USING btree
|
|
|
(no_facture);
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures_soldes_h
|
|
|
SET montant_regle = 0,
|
|
|
montant_regle_1 = 0,
|
|
|
montant_regle_2 = 0,
|
|
|
montant_regle_0 = 0
|
|
|
FROM w_factures_soldes_h_reg
|
|
|
WHERE p_factures_soldes_h.no_facture = w_factures_soldes_h_reg.no_facture AND
|
|
|
p_factures_soldes_h.date_comptable = w_factures_soldes_h_reg.date_comptable_s AND
|
|
|
od_avoir = '1' AND
|
|
|
montant_regle_s = montant_regle_f * 2;
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures_soldes_h
|
|
|
SET od_avoir = '0'
|
|
|
FROM w_factures_soldes_h_reg
|
|
|
WHERE p_factures_soldes_h.no_facture = w_factures_soldes_h_reg.no_facture_od_avoir AND
|
|
|
p_factures_soldes_h.date_comptable = w_factures_soldes_h_reg.date_comptable_s AND
|
|
|
od_avoir = '1' AND
|
|
|
montant_regle_s = montant_regle_f * 2;
|
|
|
|
|
|
|
|
|
|
|
|
-- discordance total detail reglement
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_soldes_h_reg;
|
|
|
CREATE TEMP TABLE w_factures_soldes_h_reg AS
|
|
|
SELECT p_factures.no_sejour, p_factures.no_facture, no_facture_od_avoir,
|
|
|
SUM(montant_regle) AS montant_regle_s,
|
|
|
SUM(montant_regle_1) AS montant_regle_1_s,
|
|
|
SUM(montant_regle_2) AS montant_regle_2_s,
|
|
|
SUM(montant_regle_0) AS montant_regle_0_s,
|
|
|
MAX(p_factures.montant_regle_h) AS montant_regle_f ,
|
|
|
MAX(CASE WHEN od_avoir = '1' THEN date_comptable ELSE NULL END) AS date_comptable_s
|
|
|
FROM activite[PX].p_factures_soldes_h
|
|
|
JOIN activite[PX].p_factures ON p_factures_soldes_h.no_facture = p_factures.no_facture
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING SUM(montant_regle) <> MAX(p_factures.montant_regle_h);
|
|
|
|
|
|
|
|
|
CREATE INDEX w_factures_soldes_h_reg_i1
|
|
|
ON w_factures_soldes_h_reg
|
|
|
USING btree
|
|
|
(no_facture);
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures SET
|
|
|
montant_regle_h = montant_regle_s,
|
|
|
montant_regle_1_h = montant_regle_1_s,
|
|
|
montant_regle_2_h = montant_regle_2_s,
|
|
|
montant_regle_0_h = montant_regle_0_s
|
|
|
FROM w_factures_soldes_h_reg
|
|
|
WHERE p_factures.no_facture = w_factures_soldes_h_reg.no_facture;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_soldes_h_3');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_soldes_h_4');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_soldes_h_8');
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="CHIFFRIER" label="CREATION DU CHIFFRIER">
|
|
|
|
|
|
<NODE label="Récupération chiffrier QSP">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
INSERT INTO activite.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'CHIFFIERCPTOMIT',
|
|
|
'Comptes à exclure du controle chiffrier',
|
|
|
'',
|
|
|
'Comptes à exclure du controle chiffrier séparés par une virgule '
|
|
|
WHERE 'CHIFFIERCPTOMIT' NOT IN (SELECT code FROM activite.t_divers);
|
|
|
|
|
|
TRUNCATE activite[PX].p_chiffrier_comptable;
|
|
|
|
|
|
INSERT INTO activite[PX].p_chiffrier_comptable(
|
|
|
date_comptable,
|
|
|
montant_ventes_c,
|
|
|
montant_reglements_c,
|
|
|
montant_solde_client_c,
|
|
|
montant_ventes_h,
|
|
|
montant_reglements_h,
|
|
|
montant_solde_client_h)
|
|
|
SELECT
|
|
|
date(D_ECR),
|
|
|
SUM(CASE WHEN C_JAL = JN_VENTES THEN DEBIT - CREDIT ELSE 0 END) ,
|
|
|
SUM(CASE WHEN C_JAL <> JN_VENTES THEN CREDIT - DEBIT ELSE 0 END) ,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0
|
|
|
FROM prod_qsp.COMPTA_MVT
|
|
|
JOIN prod_qsp.ETABLISSEMENT ON ETABLISSEMENT.N_ETAB = COMPTA_MVT.N_ETAB
|
|
|
LEFT JOIN activite.t_divers ON t_divers.code = 'CHIFFIERCPTOMIT'
|
|
|
WHERE (N_CPT LIKE CPT_CL_SEJ_AMO || '%' OR
|
|
|
N_CPT LIKE CPT_CL_SEJ_AMC || '%' OR
|
|
|
N_CPT LIKE CPT_CL_SEJ_ASS || '%'
|
|
|
) AND
|
|
|
D_ECR >= '[ENV_ADM_ANNEEDEBUT]0101' AND
|
|
|
(C_JAL = JN_VENTES OR C_JAL = JN_ENC OR C_JAL = JN_CAI OR C_JAL = C_JAL_SEJ) AND
|
|
|
piece BETWEEN '1' AND '999999' AND
|
|
|
piece = piece_int AND
|
|
|
N_CPT <> ALL(string_to_array(t_divers.valeur,','))
|
|
|
GROUP BY 1
|
|
|
UNION ALL
|
|
|
SELECT
|
|
|
date(D_ECR),
|
|
|
SUM(CASE WHEN C_JAL = JN_VENTES THEN DEBIT - CREDIT ELSE 0 END) ,
|
|
|
SUM(CASE WHEN C_JAL <> JN_VENTES THEN CREDIT - DEBIT ELSE 0 END) ,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0
|
|
|
FROM prod_qsp.COMPTA_MVT_HIST
|
|
|
JOIN prod_qsp.ETABLISSEMENT ON ETABLISSEMENT.N_ETAB = COMPTA_MVT_HIST.N_ETAB
|
|
|
LEFT JOIN activite.t_divers ON t_divers.code = 'CHIFFIERCPTOMIT'
|
|
|
WHERE (N_CPT LIKE CPT_CL_SEJ_AMO || '%' OR
|
|
|
N_CPT LIKE CPT_CL_SEJ_AMC || '%' OR
|
|
|
N_CPT LIKE CPT_CL_SEJ_ASS || '%'
|
|
|
) AND
|
|
|
D_ECR >= '[ENV_ADM_ANNEEDEBUT]0101' AND
|
|
|
(C_JAL = JN_VENTES OR C_JAL = JN_ENC OR C_JAL = JN_CAI OR C_JAL = C_JAL_SEJ) AND
|
|
|
piece BETWEEN '1' AND '999999' AND
|
|
|
piece = piece_int AND
|
|
|
N_CPT <> ALL(string_to_array(t_divers.valeur,','))
|
|
|
GROUP BY 1;
|
|
|
|
|
|
TRUNCATE activite[PX].p_factures_comptables;
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_comptables(
|
|
|
no_facture,
|
|
|
date_comptable,
|
|
|
montant_ventes_c,
|
|
|
montant_reglements_c,
|
|
|
montant_ventes_h,
|
|
|
montant_reglements_h)
|
|
|
SELECT
|
|
|
trim(to_char(to_number('0' || COALESCE(piece,''),'000000000'), '00000000')) AS no_facture,
|
|
|
date(D_ECR),
|
|
|
SUM(CASE WHEN C_JAL = JN_VENTES THEN DEBIT - CREDIT ELSE 0 END) ,
|
|
|
SUM(CASE WHEN C_JAL <> JN_VENTES THEN CREDIT - DEBIT ELSE 0 END) ,
|
|
|
0,
|
|
|
0
|
|
|
FROM prod_qsp.COMPTA_MVT
|
|
|
JOIN prod_qsp.ETABLISSEMENT ON ETABLISSEMENT.N_ETAB = COMPTA_MVT.N_ETAB
|
|
|
LEFT JOIN activite.t_divers ON t_divers.code = 'CHIFFIERCPTOMIT'
|
|
|
WHERE (N_CPT LIKE CPT_CL_SEJ_AMO || '%' OR
|
|
|
N_CPT LIKE CPT_CL_SEJ_AMC || '%' OR
|
|
|
N_CPT LIKE CPT_CL_SEJ_ASS || '%'
|
|
|
) AND
|
|
|
D_ECR >= '[ENV_ADM_ANNEEDEBUT]0101' AND
|
|
|
(C_JAL = JN_VENTES OR C_JAL = JN_ENC OR C_JAL = JN_CAI OR C_JAL = C_JAL_SEJ) AND
|
|
|
piece BETWEEN '1' AND '999999' AND
|
|
|
piece = piece_int AND
|
|
|
N_CPT <> ALL(string_to_array(t_divers.valeur,','))
|
|
|
GROUP BY 1,2
|
|
|
UNION ALL
|
|
|
SELECT
|
|
|
trim(to_char(to_number('0' || COALESCE(piece,''),'000000000'), '00000000')) AS no_facture,
|
|
|
date(D_ECR),
|
|
|
SUM(CASE WHEN C_JAL = JN_VENTES THEN DEBIT - CREDIT ELSE 0 END) ,
|
|
|
SUM(CASE WHEN C_JAL <> JN_VENTES THEN CREDIT - DEBIT ELSE 0 END) ,
|
|
|
0,
|
|
|
0
|
|
|
FROM prod_qsp.COMPTA_MVT_HIST
|
|
|
JOIN prod_qsp.ETABLISSEMENT ON ETABLISSEMENT.N_ETAB = COMPTA_MVT_HIST.N_ETAB
|
|
|
LEFT JOIN activite.t_divers ON t_divers.code = 'CHIFFIERCPTOMIT'
|
|
|
WHERE (N_CPT LIKE CPT_CL_SEJ_AMO || '%' OR
|
|
|
N_CPT LIKE CPT_CL_SEJ_AMC || '%' OR
|
|
|
N_CPT LIKE CPT_CL_SEJ_ASS || '%'
|
|
|
) AND
|
|
|
D_ECR >= '[ENV_ADM_ANNEEDEBUT]0101' AND
|
|
|
(C_JAL = JN_VENTES OR C_JAL = JN_ENC OR C_JAL = JN_CAI OR C_JAL = C_JAL_SEJ) AND
|
|
|
piece BETWEEN '1' AND '999999' AND
|
|
|
piece = piece_int AND
|
|
|
N_CPT <> ALL(string_to_array(t_divers.valeur,','))
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="PARAM" label="RECUPERATION DES PARAMETRES">
|
|
|
|
|
|
|
|
|
<NODE label="Initialisation divers">
|
|
|
<sqlcmd><![CDATA[
|
|
|
INSERT INTO activite.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'QSP_TYPESEJ_'||prefixe, 'QSP. Type séjour selon préfixe '||prefixe, '',
|
|
|
''
|
|
|
FROM (SELECT '1' AS prefixe UNION SELECT '2' UNION SELECT '3' UNION SELECT '4' UNION SELECT '5' UNION SELECT '6' UNION SELECT '7' UNION SELECT '8' UNION SELECT '9') subview
|
|
|
WHERE 'QSP_TYPESEJ_'||prefixe NOT IN (SELECT code FROM activite.t_divers)
|
|
|
;
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
<NODE label="Tiers payant">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
INSERT INTO activite[PX].t_types_tiers_payant(code, texte, texte_court)
|
|
|
SELECT code, texte, texte FROM
|
|
|
(
|
|
|
SELECT '0' AS code, 'Patients' AS texte
|
|
|
UNION
|
|
|
SELECT '1','Régime général'
|
|
|
UNION
|
|
|
SELECT '2','Mutuelles'
|
|
|
) subview
|
|
|
WHERE code NOT IN (SELECT code FROM activite[PX].t_types_tiers_payant);
|
|
|
|
|
|
INSERT INTO activite[PX].t_tiers_payant(code_original, code, type_tiers_payant, texte, texte_court)
|
|
|
SELECT C_CAI, C_CAI, MAX(CASE WHEN TP_CAI = 'C' THEN '1' WHEN TP_CAI = 'M' THEN '2' ELSE '0' END), MAX(NOM), MAX(NOM)
|
|
|
FROM prod_qsp.CAI_CAISSE
|
|
|
WHERE C_CAI NOT IN (SELECT code_original FROM activite[PX].t_tiers_payant)
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
INSERT INTO activite[PX].t_tiers_payant(oid, code, code_original, type_tiers_payant, texte, texte_court)
|
|
|
SELECT 0, '', '0', '0', 'Non saisi', 'Non saisi' WHERE 0 NOT IN (SELECT oid FROM activite[PX].t_tiers_payant);
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_tiers_payant(code, code_original, type_tiers_payant, texte, texte_court)
|
|
|
SELECT 'PATIENT', 'PATIENT', '0', 'Patients', 'Patients' WHERE 'PATIENT' NOT IN (SELECT code_original FROM activite[PX].t_tiers_payant);
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Médecins">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
INSERT INTO base.t_specialites_medecin(code_original, code, texte, texte_court)
|
|
|
SELECT
|
|
|
TRIM(to_char(CODE_SPE,'00')),
|
|
|
TRIM(to_char(CODE_SPE,'00')),
|
|
|
LIB_SPE,
|
|
|
LIB_SPE
|
|
|
FROM prod_qsp.SPECIALITE
|
|
|
LEFT JOIN base.t_specialites_medecin ON TRIM(to_char(CODE_SPE,'00')) = code
|
|
|
WHERE code_original IS NULL;
|
|
|
|
|
|
INSERT INTO activite[PX].t_specialites_medecin(oid, code, code_original, texte, texte_court)
|
|
|
SELECT 0, '', '0', 'Non saisie', 'Non saisie'
|
|
|
WHERE 0 NOT IN (SELECT oid FROM activite[PX].t_specialites_medecin);
|
|
|
|
|
|
INSERT INTO base.t_specialites_medecin(oid, code, code_original, texte, texte_court)
|
|
|
SELECT 0, '', '0', 'Non saisie', 'Non saisie'
|
|
|
WHERE 0 NOT IN (SELECT oid FROM base.t_specialites_medecin);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO base.t_medecins(oid, nom, prenom, numero_ordre, specialite_id )
|
|
|
SELECT 0, 'Non renseigné', '', '', 0 WHERE 0 NOT IN (SELECT oid FROM base.t_medecins);
|
|
|
|
|
|
INSERT INTO activite[PX].t_medecins_administratifs(oid, code_original, code, nom, prenom, specialite_id, medecin_id)
|
|
|
SELECT 0, '0', '****', 'Non renseigné', '', 0, 0 WHERE 0 NOT IN (SELECT oid FROM activite[PX].t_medecins_administratifs);
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_medecins;
|
|
|
|
|
|
CREATE TEMP TABLE w_medecins AS
|
|
|
SELECT C_PRAT AS C_PRAT_ORIGINAL,
|
|
|
C_PRAT,
|
|
|
base.cti_soundex_nom(CASE WHEN strpos(NOM_PRATICIEN, '*') > 10 THEN trim(substr(NOM_PRATICIEN, 1, strpos(NOM_PRATICIEN, '*')-1)) ELSE NOM_PRATICIEN END) AS NOM_PRATICIEN_SOUNDEX,
|
|
|
''::text AS PRENOM_PRATICIEN_SOUNDEX,
|
|
|
NOM_PRATICIEN,
|
|
|
''::text AS PRENOM_PRATICIEN,
|
|
|
COALESCE(NUMID,'') AS NUMID,
|
|
|
TRIM(to_char(SPECIALITE,'00')) AS SPECIALITE,
|
|
|
COALESCE(t_medecins_administratifs.medecin_id,0) as medecin_id
|
|
|
FROM prod_qsp.DPRATICIEN
|
|
|
LEFT JOIN activite[PX].t_medecins_administratifs ON C_PRAT = t_medecins_administratifs.code_original
|
|
|
WHERE C_PRAT = ANY(ARRAY(
|
|
|
SELECT MEDSUIV::text FROM prod_qsp.DOSSIER
|
|
|
UNION
|
|
|
SELECT C_PRAT::text FROM prod_qsp.SAISIE
|
|
|
GROUP BY 1)::text[]
|
|
|
);
|
|
|
|
|
|
UPDATE w_medecins SET NOM_PRATICIEN_SOUNDEX = NOM_PRATICIEN WHERE NOM_PRATICIEN_SOUNDEX = '';
|
|
|
|
|
|
|
|
|
INSERT INTO base.t_medecins(nom, prenom, numero_ordre, specialite_id,code)
|
|
|
SELECT w_medecins.NOM_PRATICIEN, w_medecins.PRENOM_PRATICIEN, w_medecins.NUMID, 0, w_medecins.C_PRAT_ORIGINAL FROM
|
|
|
(SELECT SUBSTR(NOM_PRATICIEN_SOUNDEX, 1, 8) AS NOM_PRATICIEN_SOUNDEX,
|
|
|
SUBSTR(PRENOM_PRATICIEN_SOUNDEX, 1, 8) AS PRENOM_PRATICIEN_SOUNDEX,
|
|
|
NUMID,
|
|
|
C_PRAT_ORIGINAL
|
|
|
FROM w_medecins
|
|
|
GROUP BY 1,2,3,4) subview, w_medecins
|
|
|
WHERE w_medecins.C_PRAT_ORIGINAL = subview.C_PRAT_ORIGINAL
|
|
|
AND w_medecins.NUMID <> ''
|
|
|
AND substr(subview.NOM_PRATICIEN_SOUNDEX,1,8) || ',' || substr(subview.PRENOM_PRATICIEN_SOUNDEX,1,8) || ',' || subview.NUMID || ',' ||subview.C_PRAT_ORIGINAL NOT IN
|
|
|
(SELECT substr(base.cti_soundex_nom(nom),1,8) || ',' || substr(base.cti_soundex_nom(prenom),1,8) || ',' || numero_ordre|| ',' || code FROM base.t_medecins);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO base.t_medecins(nom, prenom, numero_ordre, specialite_id)
|
|
|
SELECT w_medecins.NOM_PRATICIEN, w_medecins.PRENOM_PRATICIEN, w_medecins.NUMID, 0 FROM
|
|
|
(SELECT NOM_PRATICIEN_SOUNDEX, PRENOM_PRATICIEN_SOUNDEX, MIN(C_PRAT_ORIGINAL) AS MEDE_ID_MEDE
|
|
|
FROM w_medecins
|
|
|
GROUP BY 1,2) subview, w_medecins
|
|
|
WHERE w_medecins.C_PRAT_ORIGINAL = subview.MEDE_ID_MEDE
|
|
|
AND subview.NOM_PRATICIEN_SOUNDEX || ',' || subview.PRENOM_PRATICIEN_SOUNDEX NOT IN
|
|
|
(SELECT base.cti_soundex_nom(nom) || ',' || base.cti_soundex_nom(prenom) FROM base.t_medecins);;
|
|
|
|
|
|
|
|
|
UPDATE w_medecins SET medecin_id = subview.medecin_id
|
|
|
FROM
|
|
|
(SELECT substr(base.cti_soundex_nom(nom),1,8) as nom , substr(base.cti_soundex_nom(prenom),1,8) as prenom, numero_ordre, MIN(oid) AS medecin_id FROM base.t_medecins GROUP BY 1,2,3) subview
|
|
|
WHERE SUBSTR(NOM_PRATICIEN_SOUNDEX, 1, 8) = SUBSTR(subview.nom,1,8)
|
|
|
AND SUBSTR(PRENOM_PRATICIEN_SOUNDEX, 1, 8) = SUBSTR(subview.prenom,1,8)
|
|
|
AND NUMID = subview.numero_ordre
|
|
|
AND NUMID <> ''
|
|
|
AND w_medecins.medecin_id = 0;
|
|
|
|
|
|
UPDATE w_medecins SET medecin_id = subview.medecin_id
|
|
|
FROM
|
|
|
(SELECT base.cti_soundex_nom(nom) as nom , base.cti_soundex_nom(prenom) as prenom, MIN(oid) AS medecin_id FROM base.t_medecins GROUP BY 1,2) subview
|
|
|
WHERE NOM_PRATICIEN_SOUNDEX = subview.nom
|
|
|
AND PRENOM_PRATICIEN_SOUNDEX = subview.prenom
|
|
|
AND w_medecins.medecin_id = 0;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_medecins_administratifs(code_original, code, nom, prenom, specialite_id, medecin_id)
|
|
|
SELECT DISTINCT C_PRAT_ORIGINAL, C_PRAT, NOM_PRATICIEN, PRENOM_PRATICIEN, COALESCE(t_specialites_medecin.oid,0), medecin_id
|
|
|
FROM w_medecins
|
|
|
LEFT JOIN base.t_specialites_medecin ON (SPECIALITE = t_specialites_medecin.code_original)
|
|
|
WHERE C_PRAT_ORIGINAL NOT IN (SELECT code_original FROM activite[PX].t_medecins_administratifs);
|
|
|
|
|
|
UPDATE activite[PX].t_medecins_administratifs
|
|
|
SET nom = NOM_PRATICIEN,
|
|
|
prenom = PRENOM_PRATICIEN,
|
|
|
specialite_id = COALESCE(t_specialites_medecin.oid,0),
|
|
|
medecin_id = w_medecins.medecin_id
|
|
|
FROM w_medecins LEFT JOIN base.t_specialites_medecin ON (SPECIALITE = t_specialites_medecin.code_original)
|
|
|
WHERE w_medecins.C_PRAT_ORIGINAL = t_medecins_administratifs.code_original
|
|
|
AND (
|
|
|
t_medecins_administratifs.nom <> NOM_PRATICIEN OR
|
|
|
t_medecins_administratifs.prenom <> PRENOM_PRATICIEN OR
|
|
|
t_medecins_administratifs.specialite_id <> COALESCE(t_specialites_medecin.oid,0) OR
|
|
|
t_medecins_administratifs.medecin_id <> w_medecins.medecin_id
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE base.t_medecins SET specialite_id = subview.specialite_id FROM
|
|
|
(SELECT t_medecins.oid, MIN(t_medecins_administratifs.specialite_id) as specialite_id
|
|
|
FROM base.t_medecins, activite[PX].t_medecins_administratifs , base.t_specialites_medecin
|
|
|
WHERE t_medecins.oid = t_medecins_administratifs.medecin_id
|
|
|
AND t_medecins_administratifs.specialite_id = t_specialites_medecin.oid
|
|
|
GROUP BY t_medecins.oid) subview
|
|
|
WHERE t_medecins.oid = subview.oid AND t_medecins.oid <> 0 AND t_medecins.specialite_id = 0
|
|
|
;
|
|
|
|
|
|
-- NO ADELI
|
|
|
UPDATE activite[PX].t_medecins_administratifs
|
|
|
SET no_adeli = NUMID
|
|
|
FROM prod_qsp.DPRATICIEN
|
|
|
WHERE t_medecins_administratifs.code_original = C_PRAT AND
|
|
|
t_medecins_administratifs.NO_ADELI IS DISTINCT FROM NUMID
|
|
|
;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Hébergement">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Selon le paramètre QSP_MDT_SERVICE, le service correspond au code du champ DSERVICE.C_SERV
|
|
|
-- ou à ce même code suffixé du mode de traitement
|
|
|
|
|
|
INSERT INTO activite.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'QSP_MDT_SERVICE',
|
|
|
'Générer les codes de services avec le mode de traitement',
|
|
|
'0',
|
|
|
'Prendre en compte le mode de traitement dans la génération des codes de services : 1=oui, 0=non'
|
|
|
WHERE 'QSP_MDT_SERVICE' NOT IN (SELECT code FROM activite.t_divers);
|
|
|
|
|
|
INSERT INTO activite.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'QSP_SECT=SERV',
|
|
|
'QSP. Remplacer étage par service',
|
|
|
'0',
|
|
|
'Remplacer Secteur (SECT:etage) par Service (SERV) : 1=oui, 0=non'
|
|
|
WHERE 'QSP_SECT=SERV' NOT IN (SELECT code FROM activite.t_divers);
|
|
|
|
|
|
DROP TABLE IF EXISTS cti_histolit;
|
|
|
CREATE TEMP TABLE cti_histolit AS
|
|
|
SELECT
|
|
|
HISTOLIT.*
|
|
|
,CASE
|
|
|
WHEN NUM_LIT LIKE '%P' THEN replace(NUM_LIT,'P','')
|
|
|
WHEN NUM_LIT LIKE '%F' THEN replace(NUM_LIT,'F','')
|
|
|
WHEN NUM_LIT LIKE '%p' THEN replace(NUM_LIT,'p','')
|
|
|
WHEN NUM_LIT LIKE '%f' THEN replace(NUM_LIT,'f','')
|
|
|
ELSE NUM_LIT END AS NUM_CHAMBRE
|
|
|
,HISTOLIT.C_SERV::text || CASE WHEN t_divers.valeur = '1' THEN '_'::text || lpad(DOSSIER.MODE_TRAIT, 2, '0') ELSE ''::text END as C_SERV_CTI
|
|
|
,HISTOLIT.C_SERV as C_UF_CTI
|
|
|
,CASE WHEN t_divers.valeur = '1' THEN lpad(DOSSIER.MODE_TRAIT, 2, '0') ELSE null END as MODE_TRAIT_CTI
|
|
|
FROM
|
|
|
prod_qsp.HISTOLIT
|
|
|
JOIN prod_QSP.DOSSIER ON DOSSIER.NDOSSIER = HISTOLIT.NDOSSIER
|
|
|
JOIN activite.t_divers ON t_divers.code = 'QSP_MDT_SERVICE';
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- Minuscules dans lit
|
|
|
UPDATE cti_histolit
|
|
|
SET NUM_LIT = UPPER(NUM_LIT)
|
|
|
WHERE NUM_LIT <> '0' AND
|
|
|
NUM_LIT NOT IN (SELECT NUM_LIT FROM prod_qsp.DLIT) AND
|
|
|
UPPER(NUM_LIT) IN (SELECT NUM_LIT FROM prod_qsp.DLIT) AND
|
|
|
UPPER(NUM_LIT) <> NUM_LIT
|
|
|
;
|
|
|
|
|
|
-- Etage = service si parametre QSP_MDT_SERVICE = 1
|
|
|
UPDATE cti_histolit
|
|
|
SET C_SECT = C_SERV
|
|
|
FROM activite.t_divers
|
|
|
WHERE t_divers.code = 'QSP_MDT_SERVICE' AND t_divers.valeur = '1'
|
|
|
;
|
|
|
|
|
|
-- Etage non renseigné, prendre le max par service et chambre
|
|
|
UPDATE cti_histolit
|
|
|
SET C_SECT = C_SECT_DEFAULT
|
|
|
FROM
|
|
|
(
|
|
|
SELECT C_SERV, NUM_CHAMBRE, (MAX(Array[to_char(nb,'FM000000000'),C_SECT]))[2] AS C_SECT_DEFAULT
|
|
|
FROM
|
|
|
(
|
|
|
SELECT C_SERV,NUM_CHAMBRE,C_SECT,count(*) aS nb
|
|
|
FROM cti_histolit
|
|
|
WHERE C_SECT <> '' AND NUM_LIT <> '0' AND
|
|
|
NUM_CHAMBRE IN (SELECT NUM_CHAMBRE FROM cti_histolit WHERE C_SECT = '')
|
|
|
GROUP BY 1,2,3
|
|
|
ORDER BY 1,2,4 DESC
|
|
|
) subview
|
|
|
GROUP BY 1,2
|
|
|
) subview
|
|
|
WHERE cti_histolit.C_SERV = subview.C_SERV AND
|
|
|
cti_histolit.NUM_CHAMBRE = subview.NUM_CHAMBRE AND
|
|
|
cti_histolit.C_SECT = '' AND
|
|
|
cti_histolit.NUM_LIT <> '0'
|
|
|
;
|
|
|
|
|
|
-- Etage non renseigné, prendre le max par service (si significatif = 95%)
|
|
|
UPDATE cti_histolit
|
|
|
SET C_SECT = C_SECT_DEFAULT, TRANSF_QSP = 'T'
|
|
|
FROM
|
|
|
(
|
|
|
SELECT C_SERV, (MAX(Array[to_char(nb,'FM000000000'),C_SECT]))[2] AS C_SECT_DEFAULT, MAX(nb) / SUM(nb)
|
|
|
FROM
|
|
|
(
|
|
|
SELECT C_SERV,C_SECT,count(*) aS nb
|
|
|
FROM cti_histolit
|
|
|
WHERE C_SECT <> '' AND NUM_LIT <> '0' AND NUM_LIT <> ''
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,3 DESC
|
|
|
) subview
|
|
|
GROUP BY 1
|
|
|
HAVING MAX(nb) / SUM(nb) >= 0.95
|
|
|
) subview
|
|
|
WHERE cti_histolit.C_SERV = subview.C_SERV AND
|
|
|
cti_histolit.C_SECT = '' AND
|
|
|
cti_histolit.NUM_LIT <> '0' AND
|
|
|
cti_histolit.NUM_LIT <> ''
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_DSERVICE;
|
|
|
CREATE TEMP TABLE w_DSERVICE AS
|
|
|
SELECT
|
|
|
DSERVICE.C_SERV::text || CASE WHEN t_divers.valeur = '1' THEN '_'::text || lpad(DOSSIER.MODE_TRAIT, 2, '0') ELSE ''::text END as C_SERV
|
|
|
,CASE WHEN t_divers.valeur = '1' THEN lpad(DOSSIER.MODE_TRAIT, 2, '0') ELSE lpad(DSERVICE.N_TRAIT, 2, '0') END as MODE_TRAIT
|
|
|
,DSERVICE.L_DSERVICE || CASE WHEN t_divers.valeur = '1' THEN ' (' || lpad(DOSSIER.MODE_TRAIT, 2, '0') || ')' ELSE ''::text END as L_DSERVICE
|
|
|
,DSERVICE.C_SERV as C_UF
|
|
|
,DSERVICE.PMSI_SERV
|
|
|
,DSERVICE.NB_LITS
|
|
|
,DSERVICE.N_TRAIT
|
|
|
,DSERVICE.N_DIS
|
|
|
,DSERVICE.L_DSERVICE AS L_DUF
|
|
|
FROM
|
|
|
cti_histolit
|
|
|
JOIN prod_QSP.DOSSIER ON DOSSIER.NDOSSIER = cti_histolit.NDOSSIER
|
|
|
AND DOSSIER.N_CLINI = cti_histolit.N_CLINI
|
|
|
JOIN prod_QSP.DSERVICE ON DSERVICE.C_SERV = cti_histolit.C_SERV
|
|
|
AND DSERVICE.N_CLINI = cti_histolit.N_CLINI,
|
|
|
activite.t_divers
|
|
|
WHERE t_divers.code = 'QSP_MDT_SERVICE'
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9
|
|
|
ORDER BY 1;
|
|
|
|
|
|
-- Modes de traitement
|
|
|
|
|
|
INSERT INTO base.t_modes_traitement(code, texte, texte_court)
|
|
|
SELECT trim(to_char(n_trait,'00')), libelle, libelle FROM prod_qsp.MODE_TRAIT
|
|
|
WHERE trim(to_char(n_trait,'00')) NOT IN (SELECt code FROM base.t_modes_traitement);
|
|
|
|
|
|
INSERT INTO base.t_modes_traitement(oid, code, texte, texte_court)
|
|
|
SELECT 0, '**', 'Non renseigné', 'Non renseigné'
|
|
|
WHERE 0 NOT IN (SELECT oid FROM base.t_modes_traitement);
|
|
|
|
|
|
-- DMT
|
|
|
|
|
|
INSERT INTO base.t_dmt(code, texte, texte_court)
|
|
|
SELECT trim(to_char(n_dis,'000')), libelle, libelle FROM prod_qsp.discipline
|
|
|
WHERE n_dis <> 0 AND trim(to_char(n_dis,'000')) NOT IN (SELECt code FROM base.t_dmt);
|
|
|
|
|
|
INSERT INTO base.t_dmt(oid, code, texte, texte_court)
|
|
|
SELECT 0, '***', 'Non renseignée', 'Non renseignée'
|
|
|
WHERE 0 NOT IN (SELECT oid FROM base.t_dmt);
|
|
|
|
|
|
-- Services
|
|
|
|
|
|
INSERT INTO activite[PX].t_services_facturation(oid, code_original, code, texte, texte_court)
|
|
|
SELECT 0, 0, '****', 'Non renseigné', 'Non renseigné' WHERE 0 NOT IN (SELECt oid FROM activite[PX].t_services_facturation);
|
|
|
|
|
|
INSERT INTO activite[PX].t_services_facturation(code_original, code, texte, texte_court, type_t2a, nb_lits, mode_traitement_id, dmt_id)
|
|
|
SELECT
|
|
|
w_DSERVICE.C_SERV,
|
|
|
substr(translate(w_DSERVICE.C_SERV,' ',''),1,10),
|
|
|
w_DSERVICE.L_DSERVICE,
|
|
|
w_DSERVICE.L_DSERVICE,
|
|
|
CASE WHEN w_DSERVICE.PMSI_SERV <> '' THEN '1' ELSE '0' END,
|
|
|
w_DSERVICE.NB_LITS,
|
|
|
COALESCE(t_modes_traitement.oid,0),
|
|
|
COALESCE(t_dmt.oid,0)
|
|
|
FROM
|
|
|
w_DSERVICE
|
|
|
LEFT JOIN base.t_modes_traitement ON t_modes_traitement.code = w_DSERVICE.MODE_TRAIT
|
|
|
LEFT JOIN base.t_dmt ON (t_dmt.code = trim(to_char(w_DSERVICE.N_DIS,'000')))
|
|
|
LEFT JOIN activite[PX].t_services_facturation ON t_services_facturation.code_original = w_DSERVICE.C_SERV
|
|
|
WHERE t_services_facturation.code_original IS NULL;
|
|
|
|
|
|
|
|
|
|
|
|
-- Unités fonctionnelles
|
|
|
|
|
|
INSERT INTO activite[PX].t_unites_fonctionnelles(oid, code_original, code, texte, texte_court)
|
|
|
SELECT 0, 0, '', 'Non renseignée', 'Non renseignée' WHERE 0 NOT IN (SELECt oid FROM activite[PX].t_unites_fonctionnelles);
|
|
|
|
|
|
INSERT INTO activite[PX].t_unites_fonctionnelles(code_original, code, texte, texte_court)
|
|
|
SELECT w_DSERVICE.C_UF, substr(translate(C_UF,' ',''),1,10) , w_DSERVICE.L_DUF, w_DSERVICE.L_DUF
|
|
|
FROM w_DSERVICE
|
|
|
LEFT JOIN base.t_modes_traitement ON (t_modes_traitement.code = trim(to_char(w_DSERVICE.N_TRAIT,'00')))
|
|
|
LEFT JOIN base.t_dmt ON (t_dmt.code = trim(to_char(w_DSERVICE.N_DIS,'000')))
|
|
|
LEFT JOIN activite[PX].t_unites_fonctionnelles ON t_unites_fonctionnelles.code_original = w_DSERVICE.C_UF
|
|
|
WHERE t_unites_fonctionnelles.code_original IS NULL
|
|
|
GROUP BY 1,2,3,4;
|
|
|
|
|
|
|
|
|
-- Unités médicales
|
|
|
|
|
|
INSERT INTO activite[PX].t_unites_medicales(oid, code_original, code, texte, texte_court)
|
|
|
SELECT 0, 0, '', 'Non renseignée', 'Non renseignée' WHERE 0 NOT IN (SELECt oid FROM activite[PX].t_unites_medicales);
|
|
|
|
|
|
INSERT INTO activite[PX].t_unites_medicales(code_original, code, texte, texte_court)
|
|
|
SELECT C_SERV, C_SERV, LIBELLE, LIBELLE
|
|
|
FROM prod_qsp.PMSI_SERVICE
|
|
|
WHERE C_SERV NOT IN (SELECT code_original FROM activite[PX].t_unites_medicales);
|
|
|
|
|
|
|
|
|
-- Activités
|
|
|
|
|
|
INSERT INTO activite[PX].t_activites(oid, code_original, code, texte, texte_court)
|
|
|
SELECT 0, 0, '', 'Non renseignée', 'Non renseignée' WHERE 0 NOT IN (SELECt oid FROM activite[PX].t_activites);
|
|
|
|
|
|
|
|
|
|
|
|
-- Etages et lits
|
|
|
|
|
|
INSERT INTO activite[PX].t_etages(oid, code_original, code, texte, texte_court, nb_lits)
|
|
|
SELECT 0, 0, '', 'Non renseigné', 'Non renseigné', 0 WHERE 0 NOT IN (SELECT oid FROM activite[PX].t_etages);
|
|
|
|
|
|
INSERT INTO activite[PX].t_etages(code_original, code, texte, texte_court)
|
|
|
SELECT C_SECT, C_SECT, NOM_SECT, NOM_SECT
|
|
|
FROM prod_qsp.SECTEUR
|
|
|
WHERE C_SECT NOT IN (SELECT code_original FROM activite[PX].t_etages);
|
|
|
|
|
|
INSERT INTO activite[PX].t_etages(code_original, code, texte, texte_court)
|
|
|
SELECT C_SERV, C_SERV, LIBELLE, LIBELLE
|
|
|
FROM prod_qsp.PMSI_SERVICE
|
|
|
WHERE C_SERV NOT IN (SELECT code_original FROM activite[PX].t_etages);
|
|
|
|
|
|
DELETE FROM activite[PX].t_lits WHERE code_original IS NULL;
|
|
|
|
|
|
INSERT INTO activite[PX].t_lits(code_original, code, texte, texte_court, etage_id, chambre_particuliere)
|
|
|
SELECT CASE WHEN C_SECT <> '' THEN COALESCE(C_SECT, C_SERV) ELSE C_SERV END || '|' || NUM_LIT, NUM_LIT, NUM_LIT, NUM_LIT, COALESCE(t_etages.oid,0), CASE WHEN SEULE = 'O' THEN 'O' ELSE 'N' END
|
|
|
FROM prod_qsp.DLIT
|
|
|
LEFT JOIN activite[PX].t_etages ON C_SECT = t_etages.code_original
|
|
|
WHERE CASE WHEN C_SECT <> '' THEN COALESCE(C_SECT, C_SERV) ELSE C_SERV END || '|' || NUM_LIT NOT IN (SELECT code_original FROM activite[PX].t_lits);
|
|
|
|
|
|
INSERT INTO activite[PX].t_lits(code_original, code, texte, texte_court, etage_id, chambre_particuliere)
|
|
|
SELECT t_etages.code_original || '|' , '****', 'Non renseigné', 'Non renseigné', t_etages.oid, 'N'
|
|
|
FROM activite[PX].t_etages
|
|
|
WHERE t_etages.code_original <> '' AND (t_etages.code_original || '|') NOT IN (SELECT code_original FROM activite[PX].t_lits);
|
|
|
|
|
|
UPDATE activite[PX].t_lits SET code = '*****' WHERE code = '';
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Facturation">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Doublons dans PRESTATION
|
|
|
SELECT base.cti_execute(
|
|
|
'UPDATE prod_qsp.PRESTATION SET
|
|
|
TYPE_PREST = ''*'',
|
|
|
CODE_PREST = PRESTATION.CODE_PREST || ''*'' || subview.nb
|
|
|
FROM
|
|
|
(
|
|
|
SELECT CODE_PREST, MAX(CTID) AS DELCTID, count(*) AS nb
|
|
|
FROM prod_qsp.PRESTATION
|
|
|
WHERE TYPE_PREST <> ''*''
|
|
|
GROUP BY 1
|
|
|
HAVING count(*) > 1
|
|
|
) subview
|
|
|
WHERE PRESTATION.CODE_PREST = subview.CODE_PREST AND
|
|
|
PRESTATION.CTID = DELCTID',10);
|
|
|
|
|
|
-- Rubriques et prestations
|
|
|
|
|
|
INSERT INTO activite[PX].t_rubriques_facturation(oid, code_original, code, texte, texte_court)
|
|
|
SELECT 0, 0, '', 'Non renseignée', 'Non renseignée' WHERE 0 NOT IN (SELECT oid FROM activite[PX].t_rubriques_facturation);
|
|
|
|
|
|
INSERT INTO activite[PX].t_rubriques_facturation(code_original, code, texte, texte_court)
|
|
|
SELECT CODE_PREST, CODE_PREST, LIBELLE, LIBELLE
|
|
|
FROM prod_qsp.PRESTATION
|
|
|
WHERE TYPE_PREST <> '*' AND
|
|
|
CODE_PREST <> '' AND
|
|
|
CODE_PREST NOT IN (SELECT code_original FROM activite[PX].t_rubriques_facturation)
|
|
|
ORDER BY CODE_PREST;
|
|
|
|
|
|
-- Mise à jour préalable du code original si absent ain d'éviter les erreurs de contrainte d'unicité sur la requête d'insertion suivante
|
|
|
UPDATE activite[PX].t_prestations SET
|
|
|
code_original = CODE_NORM
|
|
|
FROM
|
|
|
prod_qsp.PRESTATION
|
|
|
WHERE 1=1
|
|
|
AND t_prestations.code = PRESTATION.CODE_NORM
|
|
|
AND TYPE_PREST <> '*'
|
|
|
AND CODE_NORM <> ''
|
|
|
AND t_prestations.code_original IS NULL;
|
|
|
|
|
|
INSERT INTO activite[PX].t_prestations(code_original, code, texte, texte_court)
|
|
|
SELECT CODE_NORM, CODE_NORM,
|
|
|
TRIM(MAX(CASE WHEN CODE_NORM = CODE_PREST AND LIBELLE <> '' THEN LIBELLE ELSE ' ' || CODE_NORM END)),
|
|
|
TRIM(MAX(CASE WHEN CODE_NORM = CODE_PREST AND LIBELLE <> '' THEN LIBELLE ELSE ' ' || CODE_NORM END))
|
|
|
FROM prod_qsp.PRESTATION
|
|
|
WHERE TYPE_PREST <> '*' AND
|
|
|
CODE_NORM NOT IN (SELECT code_original FROM activite[PX].t_prestations WHERE oid <> 0 AND code_original IS NOT NULL) AND
|
|
|
CODE_NORM <> ''
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO activite[PX].t_prestations(code_original, code, texte, texte_court)
|
|
|
SELECT CODE_PREST, CODE_PREST,
|
|
|
TRIM(MAX(CASE WHEN CODE_NORM = CODE_PREST AND LIBELLE <> '' THEN LIBELLE ELSE ' ' || CODE_NORM END)),
|
|
|
TRIM(MAX(CASE WHEN CODE_NORM = CODE_PREST AND LIBELLE <> '' THEN LIBELLE ELSE ' ' || CODE_NORM END))
|
|
|
FROM prod_qsp.PRESTATION
|
|
|
WHERE TYPE_PREST <> '*' AND
|
|
|
CODE_PREST <> '' AND
|
|
|
COALESCE(CODE_NORM,'') = '' AND CODE_PREST NOT IN (SELECT code_original FROM activite[PX].t_prestations WHERE oid <> 0 AND code_original IS NOT NULL) AND
|
|
|
CODE_PREST <> ''
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1;
|
|
|
|
|
|
-- Comptes
|
|
|
|
|
|
INSERT INTO activite[PX].t_compte(oid, code_original, code, texte, texte_court)
|
|
|
SELECT 0, 0, '', 'Non renseigné', 'Non renseigné' WHERE 0 NOT IN (SELECt oid FROM activite[PX].t_compte);
|
|
|
|
|
|
INSERT INTO activite[PX].t_compte(code_original, code, texte, texte_court)
|
|
|
SELECT N_CPT, N_CPT, MAX(LIB_CPT), MAX(LIB_CPT)
|
|
|
FROM prod_qsp.PLAN_C
|
|
|
JOIN prod_qsp.PRESTATION ON N_CPT = COMPTE::text
|
|
|
WHERE N_CPT <> '' AND N_CPT NOT IN (SELECT code FROM activite[PX].t_compte)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_compte(code_original, code, texte, texte_court)
|
|
|
SELECT N_CPT, N_CPT, MAX(LIB_CPT), MAX(LIB_CPT)
|
|
|
FROM prod_qsp.PLAN_C
|
|
|
JOIN prod_qsp.PRESTATION_DISCIPLINE ON N_CPT = COMPTE::text
|
|
|
WHERE N_CPT <> '' AND N_CPT NOT IN (SELECT code FROM activite[PX].t_compte)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_compte(code_original, code, texte, texte_court)
|
|
|
SELECT N_CPT, N_CPT, MAX(LIB_CPT), MAX(LIB_CPT)
|
|
|
FROM prod_qsp.PLAN_C
|
|
|
JOIN prod_qsp.PRESTATION_GHS ON N_CPT = COMPTE::text
|
|
|
WHERE N_CPT <> '' AND N_CPT NOT IN (SELECT code FROM activite[PX].t_compte)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO activite[PX].t_compte(code_original, code, texte, texte_court)
|
|
|
SELECT N_CPT, N_CPT, MAX(LIB_CPT), MAX(LIB_CPT)
|
|
|
FROM prod_qsp.PLAN_C
|
|
|
JOIN prod_qsp.PRESTATION_GHS_GHS ON N_CPT = COMPTE::text
|
|
|
WHERE N_CPT <> '' AND N_CPT NOT IN (SELECT code FROM activite[PX].t_compte)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO activite[PX].t_compte(code_original, code, texte, texte_court)
|
|
|
SELECT COMPTE, COMPTE, COMPTE, COMPTE
|
|
|
FROM prod_qsp.PRESTATION
|
|
|
WHERE COMPTE <> 0 AND to_char(COMPTE,'FM999999999') NOT IN (SELECT code FROM activite[PX].t_compte)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO activite[PX].t_compte(code_original, code, texte, texte_court)
|
|
|
SELECT COMPTE, COMPTE, COMPTE, COMPTE
|
|
|
FROM prod_qsp.PRESTATION_GHS_GHS
|
|
|
WHERE COMPTE <> '' AND COMPTE NOT IN (SELECT code FROM activite[PX].t_compte)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="POST" label="TRAITEMENTS COMPLEMENTAIRES">
|
|
|
|
|
|
<NODE name="Calcul -10% SSR">
|
|
|
<sqlcmd><![CDATA[
|
|
|
DROP TABLE IF EXISTS w_moins10;
|
|
|
CREATE TEMP TABLE w_moins10 AS
|
|
|
SELECT p_factures_lignes_c.*,
|
|
|
p_factures_lignes_c.CTID AS CTID_orig,
|
|
|
CASE
|
|
|
WHEN (t_prestations.code = 'PJ' OR type_valorisation_non_facture = 'PJ') AND
|
|
|
montant_comptabilise_0=0 AND
|
|
|
montant_comptabilise_2=0 AND
|
|
|
montant_comptabilise_22=0 AND
|
|
|
ABS(round(((prix_unitaire*nb_prestation*0.9)-montant_comptabilise_1)/nb_prestation,0)) BETWEEN 17 AND 37
|
|
|
THEN round(((prix_unitaire*nb_prestation*0.9)-montant_comptabilise_1)/ABS(nb_prestation),2)
|
|
|
ELSE 0::numeric END AS montant_fj,
|
|
|
t_prestations.code AS prestation_code,
|
|
|
'M'::text || CASE WHEN t_prestations.code <> 'PJ' THEN t_prestations.code ELSE 'PJS' END AS prestation_mcode,
|
|
|
type_valorisation_non_facture
|
|
|
FROM activite[PX].p_factures_lignes_c
|
|
|
JOIN activite[PX].t_lieux ON lieu_id = t_lieux.oid
|
|
|
JOIN activite[PX].t_services_facturation ON t_services_facturation.oid = service_facturation_id
|
|
|
JOIN activite.t_prestations ON prestation_id = t_prestations.oid
|
|
|
WHERE date_fin >= '20170701' AND
|
|
|
date_debut >= '20170701' AND
|
|
|
type_t2a = '2' AND
|
|
|
prestation_id = ANY (SELECT to_id FROM activite.t_listes_contenu JOIN activite.t_listes ON liste_id = t_listes.oid AND t_listes.code = 'DMAP_MFS') AND
|
|
|
montant_comptabilise <> 0 AND
|
|
|
montant_comptabilise_1 <> 0 AND
|
|
|
round(prix_unitaire * nb_prestation,2) <> montant_comptabilise AND
|
|
|
abs(round(prix_unitaire * nb_prestation,2)) <> abs(montant_comptabilise)+(nb_prestation*18)
|
|
|
ORDER BY no_facture, prestation_id
|
|
|
;
|
|
|
|
|
|
-- Calcul tarif plein
|
|
|
UPDATE w_moins10 SET
|
|
|
montant_facture_1 =
|
|
|
CASE WHEN prestation_code = 'PJ' OR type_valorisation_non_facture = 'PJ' THEN round(prix_unitaire * nb_prestation * taux_1 / 100,2) - montant_fj
|
|
|
ELSE round(prix_unitaire * nb_prestation * taux_1 / 100,2) END,
|
|
|
montant_facture =
|
|
|
CASE WHEN prestation_code = 'PJ' OR type_valorisation_non_facture = 'PJ' THEN round(prix_unitaire * nb_prestation * taux_1 / 100,2) - montant_fj
|
|
|
ELSE round(prix_unitaire * nb_prestation * taux_1 / 100,2) END +
|
|
|
(montant_facture_2+montant_facture_22+montant_facture_0)
|
|
|
;
|
|
|
|
|
|
-- Génération prestations spécifiques
|
|
|
INSERT INTO activite.t_prestations (code, texte, texte_court)
|
|
|
SELECT prestation_mcode, t_prestations.texte || ' (-10%)', t_prestations.texte || ' (-10%)'
|
|
|
FROM w_moins10
|
|
|
JOIN activite.t_prestations on prestation_id = t_prestations.oid
|
|
|
WHERE prestation_mcode NOT IN (SELECT code FROM activite.t_prestations WHERE code IS NOT NULL)
|
|
|
GROUP BY 1,2,3
|
|
|
;
|
|
|
|
|
|
-- Maj tarif plein
|
|
|
UPDATE activite[PX].p_factures_lignes_c
|
|
|
SET montant_facture = w_moins10.montant_facture, montant_facture_1 = w_moins10.montant_facture_1
|
|
|
FROM w_moins10
|
|
|
WHERE p_factures_lignes_c.CTID = w_moins10.CTID_orig;
|
|
|
;
|
|
|
|
|
|
-- Génération -10%
|
|
|
UPDATE w_moins10 SET
|
|
|
nb_rubrique = 0,
|
|
|
montant_facture = montant_comptabilise - montant_facture,
|
|
|
montant_facture_1 = montant_comptabilise_1 - montant_facture_1,
|
|
|
montant_facture_2 = montant_comptabilise_2 - montant_facture_2,
|
|
|
montant_facture_22 = montant_comptabilise_22 - montant_facture_22,
|
|
|
montant_facture_0 = montant_comptabilise_0 - montant_facture_0,
|
|
|
montant_comptabilise = 0,
|
|
|
montant_comptabilise_1 = 0,
|
|
|
montant_comptabilise_2 = 0,
|
|
|
montant_comptabilise_22 = 0,
|
|
|
montant_comptabilise_0 = 0,
|
|
|
prestation_id = t_prestations.oid
|
|
|
FROM activite.t_prestations
|
|
|
WHERE t_prestations.code = prestation_mcode
|
|
|
;
|
|
|
|
|
|
ALTER TABLE w_moins10 DROP COLUMN CTID_orig;
|
|
|
ALTER TABLE w_moins10 DROP COLUMN montant_fj;
|
|
|
ALTER TABLE w_moins10 DROP COLUMN prestation_code;
|
|
|
ALTER TABLE w_moins10 DROP COLUMN prestation_mcode;
|
|
|
ALTER TABLE w_moins10 DROP COLUMN type_valorisation_non_facture;
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_lignes_c
|
|
|
SELECT *
|
|
|
FROM w_moins10
|
|
|
WHERE montant_facture <> 0
|
|
|
;
|
|
|
|
|
|
|
|
|
SELECT activite[PX].cti_reorganize_rubrique_facture_c('activite[PX].p_factures_lignes_c');
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="Compléments patient">
|
|
|
<sqlcmd><![CDATA[
|
|
|
DROP TABLE IF EXISTS w_CORRESPONDANTS;
|
|
|
CREATE TEMP TABLE w_CORRESPONDANTS AS
|
|
|
SELECT
|
|
|
MED_TRAIT_NOM || ' ' || MED_TRAIT_PREN AS MED_TRAIT_CODE,
|
|
|
MED_TRAIT_NOM,
|
|
|
MED_TRAIT_PREN,
|
|
|
''::text AS MEDN_RPPS,
|
|
|
0::bigint AS medecin_cti_id
|
|
|
FROM prod_QSP.HOSPI
|
|
|
WHERE MED_TRAIT_NOM <> ''
|
|
|
GROUP BY 1,2,3
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_medecins_traitants_administratifs(code_original, code, nom, prenom, specialite_id, no_rpps)
|
|
|
SELECT
|
|
|
MED_TRAIT_CODE,
|
|
|
MED_TRAIT_CODE,
|
|
|
MAX(MED_TRAIT_NOM),
|
|
|
MAX(MED_TRAIT_PREN),
|
|
|
0,
|
|
|
''
|
|
|
FROM w_CORRESPONDANTS
|
|
|
LEFT JOIN activite[PX].t_medecins_traitants_administratifs ON
|
|
|
MED_TRAIT_CODE = t_medecins_traitants_administratifs.code_original
|
|
|
WHERE t_medecins_traitants_administratifs.oid IS NULL
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
UPDATE w_CORRESPONDANTS
|
|
|
SET medecin_cti_id = t_medecins_traitants_administratifs.oid
|
|
|
FROM activite[PX].t_medecins_traitants_administratifs
|
|
|
WHERE t_medecins_traitants_administratifs.code_original = MED_TRAIT_CODE
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_sejours;
|
|
|
CREATE TEMP TABLE w_sejours AS
|
|
|
SELECT no_sejour,
|
|
|
date_entree,
|
|
|
p_sejours.no_patient,
|
|
|
p_patients.nom,
|
|
|
''::text AS MED_TRAIT_NOM,
|
|
|
''::text AS MED_TRAIT_PREN
|
|
|
FROM activite[PX].p_sejours
|
|
|
JOIN activite[PX].p_patients ON p_sejours.no_patient = p_patients.no_patient
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_sejours
|
|
|
SET MED_TRAIT_NOM = HOSPI.MED_TRAIT_NOM,
|
|
|
MED_TRAIT_PREN = HOSPI.MED_TRAIT_PREN
|
|
|
FROM prod_QSP.HOSPI
|
|
|
WHERE to_char(N_HOSPI,'FM999999999') = no_sejour AND
|
|
|
date(HOSPI.DATE_ENTREE) = w_sejours.date_entree AND
|
|
|
HOSPI.MED_TRAIT_NOM <> ''
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_sejours
|
|
|
SET medecin_traitant_id = medecin_cti_id
|
|
|
FROM w_sejours
|
|
|
JOIN w_CORRESPONDANTS ON w_sejours.MED_TRAIT_NOM = w_CORRESPONDANTS.MED_TRAIT_NOM AND
|
|
|
w_sejours.MED_TRAIT_PREN = w_CORRESPONDANTS.MED_TRAIT_PREN
|
|
|
WHERE p_sejours.no_sejour = w_sejours.no_sejour AND
|
|
|
w_sejours.MED_TRAIT_NOM <> '' AND
|
|
|
medecin_cti_id <> 0
|
|
|
;
|
|
|
|
|
|
-- ajout des coordonnées par séjour
|
|
|
INSERT INTO activite[PX].p_coordonnees_patient (
|
|
|
sejour_id,
|
|
|
adresse,
|
|
|
code_postal_id,
|
|
|
commune,
|
|
|
telephone_fixe,
|
|
|
telephone_portable,
|
|
|
email
|
|
|
)
|
|
|
SELECT
|
|
|
p_sejours.oid,
|
|
|
ADR1_PAT || CASE WHEN ADR2_PAT != '' THEN ' - ' || ADR2_PAT ELSE '' END,
|
|
|
COALESCE(t_codes_postaux.oid,0),
|
|
|
VIL_PAT,
|
|
|
TEL1_PAT,
|
|
|
TEL2_PAT,
|
|
|
EMAIL
|
|
|
FROM activite[PX].p_sejours
|
|
|
LEFT JOIN prod_qsp.PATIENT ON no_patient = PATIENT.NPATIENT
|
|
|
LEFT JOIN base.t_codes_postaux ON t_codes_postaux.code = CPO_PAT
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Transferts
|
|
|
DROP TABLE IF EXISTS w_PROVENANCE;
|
|
|
CREATE TEMP TABLE w_PROVENANCE AS
|
|
|
SELECT SEQ_PROV, N_FINESS, LIB_PROV, CPO, ''::text AS A_FINESS, 0::bigint AS provenance_id
|
|
|
FROM prod_qsp.PROVENANCE
|
|
|
WHERE N_FINESS > 0 AND SEQ_PROV IN (SELECT HOSPI.SEQ_PROV FROM prod_qsp.HOSPI)
|
|
|
;
|
|
|
|
|
|
UPDATE w_PROVENANCE
|
|
|
SET A_FINESS = N_FINESS
|
|
|
WHERE N_FINESS BETWEEN 100000000 AND 999999999
|
|
|
;
|
|
|
|
|
|
UPDATE w_PROVENANCE
|
|
|
SET A_FINESS = '0'||N_FINESS
|
|
|
WHERE N_FINESS BETWEEN 10000000 AND 99999999 AND
|
|
|
CPO LIKE '0%' AND
|
|
|
substr(CPO,2,1) = SUBSTR(N_FINESS,1,1)
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO base.t_etablissements(code, texte, texte_court)
|
|
|
SELECT A_FINESS, MIN(LIB_PROV), MIN(LIB_PROV)
|
|
|
FROM w_PROVENANCE
|
|
|
WHERE A_FINESS <> '' AND
|
|
|
A_FINESS NOT IN (SELECT code FROM base.t_etablissements WHERE code IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
UPDATE base.t_etablissements SET
|
|
|
texte = subview.texte,
|
|
|
texte_court = subview.texte
|
|
|
FROM
|
|
|
(
|
|
|
SELECT A_FINESS, MIN(LIB_PROV) AS texte
|
|
|
FROM w_PROVENANCE
|
|
|
WHERE A_FINESS <> '' AND LIB_PROV <> ''
|
|
|
GROUP BY 1
|
|
|
) subview
|
|
|
WHERE t_etablissements.code = A_FINESS AND
|
|
|
(
|
|
|
t_etablissements.texte = t_etablissements.code OR
|
|
|
t_etablissements.texte = ''
|
|
|
)
|
|
|
;
|
|
|
|
|
|
UPDATE w_PROVENANCE
|
|
|
SET provenance_id = t_etablissements.oid
|
|
|
FROM base.t_etablissements
|
|
|
WHERE A_FINESS = t_etablissements.code AND
|
|
|
A_FINESS <> ''
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_DESTINATION;
|
|
|
CREATE TEMP TABLE w_DESTINATION AS
|
|
|
SELECT SEQ_DEST, N_FINESS, LIB_DEST, CPO, ''::text AS A_FINESS, 0::bigint AS destination_id
|
|
|
FROM prod_qsp.DESTINATION
|
|
|
WHERE N_FINESS > 0 AND SEQ_DEST IN (SELECT HOSPI.SEQ_DEST FROM prod_qsp.HOSPI)
|
|
|
;
|
|
|
|
|
|
UPDATE w_DESTINATION
|
|
|
SET A_FINESS = N_FINESS
|
|
|
WHERE N_FINESS BETWEEN 100000000 AND 999999999
|
|
|
;
|
|
|
|
|
|
UPDATE w_DESTINATION
|
|
|
SET A_FINESS = '0'||N_FINESS
|
|
|
WHERE N_FINESS BETWEEN 10000000 AND 99999999 AND
|
|
|
CPO LIKE '0%' AND
|
|
|
substr(CPO,2,1) = SUBSTR(N_FINESS,1,1)
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO base.t_etablissements(code, texte, texte_court)
|
|
|
SELECT A_FINESS, MIN(LIB_DEST), MIN(LIB_DEST)
|
|
|
FROM w_DESTINATION
|
|
|
WHERE A_FINESS <> '' AND
|
|
|
A_FINESS NOT IN (SELECT code FROM base.t_etablissements WHERE code IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
UPDATE base.t_etablissements SET
|
|
|
texte = subview.texte,
|
|
|
texte_court = subview.texte
|
|
|
FROM
|
|
|
(
|
|
|
SELECT A_FINESS, MIN(LIB_DEST) AS texte
|
|
|
FROM w_DESTINATION
|
|
|
WHERE A_FINESS <> '' AND
|
|
|
LIB_DEST <> ''
|
|
|
GROUP BY 1
|
|
|
) subview
|
|
|
WHERE t_etablissements.code = A_FINESS AND
|
|
|
(
|
|
|
t_etablissements.texte = t_etablissements.code OR
|
|
|
t_etablissements.texte = ''
|
|
|
)
|
|
|
;
|
|
|
|
|
|
UPDATE w_DESTINATION
|
|
|
SET destination_id = t_etablissements.oid
|
|
|
FROM base.t_etablissements
|
|
|
WHERE A_FINESS = t_etablissements.code AND
|
|
|
A_FINESS <> ''
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_sejours_transferts (sejour_id, provenance_id, destination_id)
|
|
|
SELECT p_sejours.oid, MAX(COALESCE(provenance_id,0)), MAX(COALESCE(destination_id,0))
|
|
|
FROM prod_QSP.HOSPI
|
|
|
JOIN activite.p_sejours ON N_HOSPI = p_sejours.code_original
|
|
|
LEFT JOIN w_PROVENANCE ON HOSPI.SEQ_PROV = w_PROVENANCE.SEQ_PROV AND provenance_id > 0
|
|
|
LEFT JOIN w_DESTINATION ON HOSPI.SEQ_DEST = w_DESTINATION.SEQ_DEST AND destination_id > 0
|
|
|
WHERE p_sejours.oid NOT IN (SELECT p_sejours_transferts.sejour_id FROM activite[PX].p_sejours_transferts) AND
|
|
|
(
|
|
|
provenance_id > 0 OR
|
|
|
destination_id > 0
|
|
|
)
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Compléments facture">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures
|
|
|
SET
|
|
|
date_solde_0_c = CASE WHEN montant_comptabilise_0_c = 0 THEN '00010101' WHEN montant_comptabilise_0_c = montant_regle_0_c THEN date_solde_0_c ELSE '20991231' END,
|
|
|
date_solde_0_h = CASE WHEN montant_comptabilise_0_h = 0 THEN '00010101' WHEN montant_comptabilise_0_h = montant_regle_0_h THEN date_solde_0_h ELSE '20991231' END,
|
|
|
date_solde_1_c = CASE WHEN montant_comptabilise_1_c = 0 THEN '00010101' WHEN montant_comptabilise_1_c = montant_regle_1_c THEN date_solde_1_c ELSE '20991231' END,
|
|
|
date_solde_1_h = CASE WHEN montant_comptabilise_1_h = 0 THEN '00010101' WHEN montant_comptabilise_1_h = montant_regle_1_h THEN date_solde_1_h ELSE '20991231' END,
|
|
|
date_solde_2_c = CASE WHEN montant_comptabilise_2_c = 0 THEN '00010101' WHEN montant_comptabilise_2_c = montant_regle_2_c THEN date_solde_2_c ELSE '20991231' END,
|
|
|
date_solde_2_h = CASE WHEN montant_comptabilise_2_h = 0 THEN '00010101' WHEN montant_comptabilise_2_h = montant_regle_2_h THEN date_solde_2_h ELSE '20991231' END,
|
|
|
date_solde_22_c = CASE WHEN montant_comptabilise_22_c = 0 THEN '00010101' WHEN montant_comptabilise_22_c = montant_regle_22_c THEN date_solde_22_c ELSE '20991231' END,
|
|
|
date_solde_22_h = CASE WHEN montant_comptabilise_22_h = 0 THEN '00010101' WHEN montant_comptabilise_22_h = montant_regle_22_h THEN date_solde_22_h ELSE '20991231' END
|
|
|
WHERE
|
|
|
(
|
|
|
date_solde_0_c <> CASE WHEN montant_comptabilise_0_c = 0 THEN '00010101' WHEN montant_comptabilise_0_c = montant_regle_0_c THEN date_solde_0_c ELSE '20991231' END OR
|
|
|
date_solde_0_h <> CASE WHEN montant_comptabilise_0_h = 0 THEN '00010101' WHEN montant_comptabilise_0_h = montant_regle_0_h THEN date_solde_0_h ELSE '20991231' END OR
|
|
|
date_solde_1_c <> CASE WHEN montant_comptabilise_1_c = 0 THEN '00010101' WHEN montant_comptabilise_1_c = montant_regle_1_c THEN date_solde_1_c ELSE '20991231' END OR
|
|
|
date_solde_1_h <> CASE WHEN montant_comptabilise_1_h = 0 THEN '00010101' WHEN montant_comptabilise_1_h = montant_regle_1_h THEN date_solde_1_h ELSE '20991231' END OR
|
|
|
date_solde_2_c <> CASE WHEN montant_comptabilise_2_c = 0 THEN '00010101' WHEN montant_comptabilise_2_c = montant_regle_2_c THEN date_solde_2_c ELSE '20991231' END OR
|
|
|
date_solde_2_h <> CASE WHEN montant_comptabilise_2_h = 0 THEN '00010101' WHEN montant_comptabilise_2_h = montant_regle_2_h THEN date_solde_2_h ELSE '20991231' END OR
|
|
|
date_solde_22_c <> CASE WHEN montant_comptabilise_22_c = 0 THEN '00010101' WHEN montant_comptabilise_22_c = montant_regle_22_c THEN date_solde_22_c ELSE '20991231' END OR
|
|
|
date_solde_22_h <> CASE WHEN montant_comptabilise_22_h = 0 THEN '00010101' WHEN montant_comptabilise_22_h = montant_regle_22_h THEN date_solde_22_h ELSE '20991231' END
|
|
|
);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_soldes;
|
|
|
CREATE TEMP TABLE w_factures_soldes AS
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
GREATEST(date_solde_0_c, date_solde_0_h, date_solde_1_c, date_solde_1_h, date_solde_2_c, date_solde_2_h, date_solde_22_c, date_solde_22_h) AS date_solde,
|
|
|
GREATEST(date_solde_0_c, date_solde_1_c, date_solde_2_c, date_solde_22_c) AS date_solde_c,
|
|
|
GREATEST(date_solde_0_h, date_solde_1_h, date_solde_2_h, date_solde_22_h) AS date_solde_h
|
|
|
FROM activite[PX].p_factures;
|
|
|
|
|
|
CREATE INDEX i_factures_soldes_1
|
|
|
ON w_factures_soldes
|
|
|
USING btree
|
|
|
(no_facture);
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures
|
|
|
SET
|
|
|
date_solde = w_factures_soldes.date_solde,
|
|
|
date_solde_c = w_factures_soldes.date_solde_c,
|
|
|
date_solde_h = w_factures_soldes.date_solde_h
|
|
|
FROM w_factures_soldes
|
|
|
WHERE p_factures.no_facture = w_factures_soldes.no_facture AND
|
|
|
(
|
|
|
p_factures.date_solde IS DISTINCT FROM w_factures_soldes.date_solde OR
|
|
|
p_factures.date_solde_c IS DISTINCT FROM w_factures_soldes.date_solde_c OR
|
|
|
p_factures.date_solde_h IS DISTINCT FROM w_factures_soldes.date_solde_h
|
|
|
);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_references_soldes;
|
|
|
|
|
|
CREATE TEMP TABLE w_factures_references_soldes AS
|
|
|
SELECT
|
|
|
no_facture_reference,
|
|
|
MAX(date_solde) AS date_solde_reference,
|
|
|
MAX(date_solde_c) AS date_solde_reference_c,
|
|
|
MAX(date_solde_h) AS date_solde_reference_h,
|
|
|
MAX(date_solde_0_c) AS date_solde_reference_0_c,
|
|
|
MAX(date_solde_0_h) AS date_solde_reference_0_h,
|
|
|
MAX(date_solde_1_c) AS date_solde_reference_1_c,
|
|
|
MAX(date_solde_1_h) AS date_solde_reference_1_h,
|
|
|
MAX(date_solde_2_c) AS date_solde_reference_2_c,
|
|
|
MAX(date_solde_2_h) AS date_solde_reference_2_h,
|
|
|
MAX(date_solde_22_c) AS date_solde_reference_22_c,
|
|
|
MAX(date_solde_22_h) AS date_solde_reference_22_h
|
|
|
FROM activite[PX].p_factures
|
|
|
GROUP BY no_facture_reference;
|
|
|
|
|
|
CREATE INDEX i_factures_references_soldes_1
|
|
|
ON w_factures_references_soldes
|
|
|
USING btree
|
|
|
(no_facture_reference);
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures
|
|
|
SET
|
|
|
date_solde_reference = w_factures_references_soldes.date_solde_reference,
|
|
|
date_solde_reference_c = w_factures_references_soldes.date_solde_reference_c,
|
|
|
date_solde_reference_h = w_factures_references_soldes.date_solde_reference_h,
|
|
|
date_solde_reference_0_c = w_factures_references_soldes.date_solde_reference_0_c,
|
|
|
date_solde_reference_0_h = w_factures_references_soldes.date_solde_reference_0_h,
|
|
|
date_solde_reference_1_c = w_factures_references_soldes.date_solde_reference_1_c,
|
|
|
date_solde_reference_1_h = w_factures_references_soldes.date_solde_reference_1_h,
|
|
|
date_solde_reference_2_c = w_factures_references_soldes.date_solde_reference_2_c,
|
|
|
date_solde_reference_2_h = w_factures_references_soldes.date_solde_reference_2_h,
|
|
|
date_solde_reference_22_c = w_factures_references_soldes.date_solde_reference_22_c,
|
|
|
date_solde_reference_22_h = w_factures_references_soldes.date_solde_reference_22_h
|
|
|
FROM w_factures_references_soldes
|
|
|
WHERE p_factures.no_facture_reference = w_factures_references_soldes.no_facture_reference
|
|
|
AND (
|
|
|
p_factures.date_solde_reference IS DISTINCT FROM w_factures_references_soldes.date_solde_reference OR
|
|
|
p_factures.date_solde_reference_c IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_c OR
|
|
|
p_factures.date_solde_reference_h IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_h OR
|
|
|
p_factures.date_solde_reference_0_c IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_0_c OR
|
|
|
p_factures.date_solde_reference_0_h IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_0_h OR
|
|
|
p_factures.date_solde_reference_1_c IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_1_c OR
|
|
|
p_factures.date_solde_reference_1_h IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_1_h OR
|
|
|
p_factures.date_solde_reference_2_c IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_2_c OR
|
|
|
p_factures.date_solde_reference_2_h IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_2_h OR
|
|
|
p_factures.date_solde_reference_22_c IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_22_c OR
|
|
|
p_factures.date_solde_reference_22_h IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_22_h
|
|
|
);
|
|
|
|
|
|
DELETE
|
|
|
FROM activite[PX].p_factures_lignes_c
|
|
|
USING activite[PX].p_factures
|
|
|
WHERE p_factures_lignes_c.no_facture = p_factures.no_facture AND
|
|
|
code_facture = '1' AND montant_facture_c = 0 AND montant_comptabilise_c = 0 AND
|
|
|
taux_0 + taux_1 + taux_2 + taux_22 = 0 AND
|
|
|
p_factures_lignes_c.montant_facture = 0 AND
|
|
|
p_factures_lignes_c.montant_comptabilise = 0
|
|
|
;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Compléments séjours">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
UPDATE activite[PX].p_sejours
|
|
|
SET date_groupage = date_facture
|
|
|
WHERE (date_groupage IS null OR date_groupage = '20991231') AND
|
|
|
date_facture <> '2099-12-31';
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_sejours_total;
|
|
|
CREATE TEMP TABLE w_sejours_total AS
|
|
|
SELECT
|
|
|
p_sejours.no_sejour AS no_sejour,
|
|
|
|
|
|
MAX(COALESCE(p_factures.date_facture,'20991231')) AS date_facture,
|
|
|
MAX(COALESCE(p_factures.date_expedition,'20991231')) AS date_expedition,
|
|
|
MAX(COALESCE(p_factures.date_solde,'20991231')) AS date_solde,
|
|
|
SUM(COALESCE(p_factures.montant_facture_c,0)) AS montant_facture_c,
|
|
|
SUM(COALESCE(p_factures.montant_facture_h,0)) AS montant_facture_h,
|
|
|
SUM(COALESCE(p_factures.montant_regle_c,0)) AS montant_regle_c,
|
|
|
SUM(COALESCE(p_factures.montant_regle_h,0)) AS montant_regle_h,
|
|
|
SUM(COALESCE(CASE WHEN p_factures.type_facture <> 'P' AND p_factures.type_facture <> 'E' AND p_factures.type_facture <> 'G' THEN 1 ELSE 0 END,0)) AS nb_factures,
|
|
|
SUM(COALESCE(CASE WHEN p_factures.type_facture = '0' THEN 0 ELSE 1 END,0)) AS nb_factures_regularisation,
|
|
|
SUM(COALESCE(p_factures.nb_rejets,0)) AS nb_rejets,
|
|
|
|
|
|
SUM(COALESCE(p_factures.montant_facture_0_c,0)) AS montant_facture_0_c,
|
|
|
SUM(COALESCE(p_factures.montant_facture_0_h,0)) AS montant_facture_0_h,
|
|
|
SUM(COALESCE(p_factures.montant_regle_0_c,0)) AS montant_regle_0_c,
|
|
|
SUM(COALESCE(p_factures.montant_regle_0_h,0)) AS montant_regle_0_h,
|
|
|
MAX(COALESCE(CASE WHEN (p_factures.montant_facture_0_c <> 0 OR p_factures.montant_facture_0_h <> 0) THEN p_factures.date_expedition_0 ELSE '0001-01-01' END,'20991231' )) AS date_expedition_0,
|
|
|
MAX(COALESCE(CASE WHEN p_factures.date_solde_0_c < '2099-12-31' AND p_factures.date_solde_0_c > p_factures.date_solde_0_h THEN p_factures.date_solde_0_c ELSE p_factures.date_solde_0_h END,'20991231' )) AS date_solde_0,
|
|
|
|
|
|
|
|
|
SUM(COALESCE(p_factures.montant_facture_1_c,0)) AS montant_facture_1_c,
|
|
|
SUM(COALESCE(p_factures.montant_facture_1_h,0)) AS montant_facture_1_h,
|
|
|
SUM(COALESCE(p_factures.montant_regle_1_c,0)) AS montant_regle_1_c,
|
|
|
SUM(COALESCE(p_factures.montant_regle_1_h,0)) AS montant_regle_1_h,
|
|
|
MAX(COALESCE(CASE WHEN (p_factures.montant_facture_1_c <> 0 OR p_factures.montant_facture_1_h <> 0) THEN p_factures.date_expedition_1 ELSE '0001-01-01' END,'20991231' )) AS date_expedition_1,
|
|
|
MAX(COALESCE(CASE WHEN p_factures.date_solde_1_c < '2099-12-31' AND p_factures.date_solde_1_c > p_factures.date_solde_1_h THEN p_factures.date_solde_1_c ELSE p_factures.date_solde_1_h END,'20991231' )) AS date_solde_1,
|
|
|
|
|
|
SUM(COALESCE(p_factures.montant_facture_2_c,0)) AS montant_facture_2_c,
|
|
|
SUM(COALESCE(p_factures.montant_facture_2_h,0)) AS montant_facture_2_h,
|
|
|
SUM(COALESCE(p_factures.montant_regle_2_c,0)) AS montant_regle_2_c,
|
|
|
SUM(COALESCE(p_factures.montant_regle_2_h,0)) AS montant_regle_2_h,
|
|
|
MAX(COALESCE(CASE WHEN (p_factures.montant_facture_2_c <> 0 OR p_factures.montant_facture_2_h <> 0) THEN p_factures.date_expedition_2 ELSE '0001-01-01' END,'20991231' )) AS date_expedition_2,
|
|
|
MAX(COALESCE(CASE WHEN p_factures.date_solde_2_c < '2099-12-31' AND p_factures.date_solde_2_c > p_factures.date_solde_2_h THEN p_factures.date_solde_2_c ELSE p_factures.date_solde_2_h END,'20991231' )) AS date_solde_2,
|
|
|
|
|
|
SUM(COALESCE(p_factures.montant_facture_22_c,0)) AS montant_facture_22_c,
|
|
|
SUM(COALESCE(p_factures.montant_facture_22_h,0)) AS montant_facture_22_h,
|
|
|
SUM(COALESCE(p_factures.montant_regle_22_c,0)) AS montant_regle_22_c,
|
|
|
SUM(COALESCE(p_factures.montant_regle_22_h,0)) AS montant_regle_22_h,
|
|
|
MAX(COALESCE(CASE WHEN (p_factures.montant_facture_22_c <> 0 OR p_factures.montant_facture_22_h <> 0) THEN p_factures.date_expedition_22 ELSE '0001-01-01' END,'20991231' )) AS date_expedition_22,
|
|
|
MAX(COALESCE(CASE WHEN p_factures.date_solde_22_c < '2099-12-31' AND p_factures.date_solde_22_c > p_factures.date_solde_22_h THEN p_factures.date_solde_22_c ELSE p_factures.date_solde_22_h END,'20991231' )) AS date_solde_22 ,
|
|
|
|
|
|
|
|
|
SUM(COALESCE(p_factures.montant_comptabilise_c,0)) AS montant_comptabilise_c,
|
|
|
SUM(COALESCE(p_factures.montant_comptabilise_h,0)) AS montant_comptabilise_h,
|
|
|
SUM(COALESCE(p_factures.montant_comptabilise_0_c,0)) AS montant_comptabilise_0_c,
|
|
|
SUM(COALESCE(p_factures.montant_comptabilise_0_h,0)) AS montant_comptabilise_0_h,
|
|
|
SUM(COALESCE(p_factures.montant_comptabilise_1_c,0)) AS montant_comptabilise_1_c,
|
|
|
SUM(COALESCE(p_factures.montant_comptabilise_1_h,0)) AS montant_comptabilise_1_h,
|
|
|
SUM(COALESCE(p_factures.montant_comptabilise_2_c,0)) AS montant_comptabilise_2_c,
|
|
|
SUM(COALESCE(p_factures.montant_comptabilise_2_h,0)) AS montant_comptabilise_2_h,
|
|
|
SUM(COALESCE(p_factures.montant_comptabilise_22_c,0)) AS montant_comptabilise_22_c,
|
|
|
SUM(COALESCE(p_factures.montant_comptabilise_22_h,0)) AS montant_comptabilise_22_h,
|
|
|
|
|
|
SUM(COALESCE(p_factures.montant_comptabilise_budget_global_c,0)) AS montant_comptabilise_budget_global_c,
|
|
|
|
|
|
SUM(COALESCE(p_factures.montant_facture_c_actes_inclus_dans_sejour,0)) AS montant_facture_c_actes_inclus_dans_sejour,
|
|
|
SUM(COALESCE(p_factures.montant_facture_h_actes_inclus_dans_sejour,0)) AS montant_facture_h_actes_inclus_dans_sejour
|
|
|
|
|
|
FROM activite[PX].p_sejours LEFT JOIN activite[PX].p_factures ON p_sejours.no_sejour = p_factures.no_sejour AND type_facture <> 'P'
|
|
|
GROUP BY p_sejours.no_sejour;
|
|
|
|
|
|
ALTER TABLE w_sejours_total ADD CONSTRAINT w_sejours_total_pkey PRIMARY KEY(no_sejour);
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_sejours SET
|
|
|
|
|
|
date_facture = w_sejours_total.date_facture,
|
|
|
date_expedition = w_sejours_total.date_expedition,
|
|
|
date_solde = w_sejours_total.date_solde,
|
|
|
montant_facture_c = w_sejours_total.montant_facture_c,
|
|
|
montant_facture_h = w_sejours_total.montant_facture_h,
|
|
|
montant_regle_c = w_sejours_total.montant_regle_c,
|
|
|
montant_regle_h = w_sejours_total.montant_regle_h,
|
|
|
nb_factures = w_sejours_total.nb_factures,
|
|
|
nb_factures_regularisation = w_sejours_total.nb_factures_regularisation,
|
|
|
nb_factures_rejet = w_sejours_total.nb_rejets,
|
|
|
|
|
|
montant_facture_0_c = w_sejours_total.montant_facture_0_c,
|
|
|
montant_facture_0_h = w_sejours_total.montant_facture_0_h,
|
|
|
montant_regle_0_c = w_sejours_total.montant_regle_0_c,
|
|
|
montant_regle_0_h = w_sejours_total.montant_regle_0_h,
|
|
|
date_expedition_0 = CASE WHEN w_sejours_total.date_expedition_0 <> '0001-01-01' THEN w_sejours_total.date_expedition_0 ELSE '2099-12-31' END,
|
|
|
date_solde_0 = w_sejours_total.date_solde_0,
|
|
|
|
|
|
montant_facture_1_c = w_sejours_total.montant_facture_1_c,
|
|
|
montant_facture_1_h = w_sejours_total.montant_facture_1_h,
|
|
|
montant_regle_1_c = w_sejours_total.montant_regle_1_c,
|
|
|
montant_regle_1_h = w_sejours_total.montant_regle_1_h,
|
|
|
date_expedition_1 = CASE WHEN w_sejours_total.date_expedition_1 <> '0001-01-01' THEN w_sejours_total.date_expedition_1 ELSE '2099-12-31' END,
|
|
|
date_solde_1 = w_sejours_total.date_solde_1,
|
|
|
|
|
|
montant_facture_2_c = w_sejours_total.montant_facture_2_c,
|
|
|
montant_facture_2_h = w_sejours_total.montant_facture_2_h,
|
|
|
montant_regle_2_c = w_sejours_total.montant_regle_2_c,
|
|
|
montant_regle_2_h = w_sejours_total.montant_regle_2_h,
|
|
|
date_expedition_2 = CASE WHEN w_sejours_total.date_expedition_2 <> '0001-01-01' THEN w_sejours_total.date_expedition_2 ELSE '2099-12-31' END,
|
|
|
date_solde_2 = w_sejours_total.date_solde_2,
|
|
|
|
|
|
montant_facture_22_c = w_sejours_total.montant_facture_22_c,
|
|
|
montant_facture_22_h = w_sejours_total.montant_facture_22_h,
|
|
|
montant_regle_22_c = w_sejours_total.montant_regle_22_c,
|
|
|
montant_regle_22_h = w_sejours_total.montant_regle_22_h,
|
|
|
date_expedition_22 = CASE WHEN w_sejours_total.date_expedition_22 <> '0001-01-01' THEN w_sejours_total.date_expedition_22 ELSE '2099-12-31' END,
|
|
|
date_solde_22 = w_sejours_total.date_solde_22,
|
|
|
|
|
|
montant_comptabilise_c = w_sejours_total.montant_comptabilise_c,
|
|
|
montant_comptabilise_h = w_sejours_total.montant_comptabilise_h,
|
|
|
montant_comptabilise_0_c = w_sejours_total.montant_comptabilise_0_c,
|
|
|
montant_comptabilise_0_h = w_sejours_total.montant_comptabilise_0_h,
|
|
|
montant_comptabilise_1_c = w_sejours_total.montant_comptabilise_1_c,
|
|
|
montant_comptabilise_1_h = w_sejours_total.montant_comptabilise_1_h,
|
|
|
montant_comptabilise_2_c = w_sejours_total.montant_comptabilise_2_c,
|
|
|
montant_comptabilise_2_h = w_sejours_total.montant_comptabilise_2_h,
|
|
|
montant_comptabilise_22_c = w_sejours_total.montant_comptabilise_22_c,
|
|
|
montant_comptabilise_22_h = w_sejours_total.montant_comptabilise_22_h,
|
|
|
|
|
|
montant_comptabilise_budget_global_c = w_sejours_total.montant_comptabilise_budget_global_c,
|
|
|
|
|
|
montant_facture_c_actes_inclus_dans_sejour = w_sejours_total.montant_facture_c_actes_inclus_dans_sejour,
|
|
|
montant_facture_h_actes_inclus_dans_sejour = w_sejours_total.montant_facture_h_actes_inclus_dans_sejour
|
|
|
|
|
|
FROM w_sejours_total
|
|
|
WHERE w_sejours_total.no_sejour = p_sejours.no_sejour
|
|
|
|
|
|
AND (
|
|
|
p_sejours.date_facture IS DISTINCT FROM w_sejours_total.date_facture OR
|
|
|
p_sejours.date_expedition IS DISTINCT FROM w_sejours_total.date_expedition OR
|
|
|
p_sejours.date_solde IS DISTINCT FROM w_sejours_total.date_solde OR
|
|
|
p_sejours.montant_facture_c IS DISTINCT FROM w_sejours_total.montant_facture_c OR
|
|
|
p_sejours.montant_facture_h IS DISTINCT FROM w_sejours_total.montant_facture_h OR
|
|
|
p_sejours.montant_regle_c IS DISTINCT FROM w_sejours_total.montant_regle_c OR
|
|
|
p_sejours.montant_regle_h IS DISTINCT FROM w_sejours_total.montant_regle_h OR
|
|
|
p_sejours.nb_factures IS DISTINCT FROM w_sejours_total.nb_factures OR
|
|
|
p_sejours.nb_factures_regularisation IS DISTINCT FROM w_sejours_total.nb_factures_regularisation OR
|
|
|
p_sejours.nb_factures_rejet IS DISTINCT FROM w_sejours_total.nb_rejets OR
|
|
|
|
|
|
p_sejours.montant_facture_0_c IS DISTINCT FROM w_sejours_total.montant_facture_0_c OR
|
|
|
p_sejours.montant_facture_0_h IS DISTINCT FROM w_sejours_total.montant_facture_0_h OR
|
|
|
p_sejours.montant_regle_0_c IS DISTINCT FROM w_sejours_total.montant_regle_0_c OR
|
|
|
p_sejours.montant_regle_0_h IS DISTINCT FROM w_sejours_total.montant_regle_0_h OR
|
|
|
p_sejours.date_expedition_0 IS DISTINCT FROM CASE WHEN w_sejours_total.date_expedition_0 <> '0001-01-01' THEN w_sejours_total.date_expedition_0 ELSE '2099-12-31' END OR
|
|
|
p_sejours.date_solde_0 IS DISTINCT FROM w_sejours_total.date_solde_0 OR
|
|
|
|
|
|
p_sejours.montant_facture_1_c IS DISTINCT FROM w_sejours_total.montant_facture_1_c OR
|
|
|
p_sejours.montant_facture_1_h IS DISTINCT FROM w_sejours_total.montant_facture_1_h OR
|
|
|
p_sejours.montant_regle_1_c IS DISTINCT FROM w_sejours_total.montant_regle_1_c OR
|
|
|
p_sejours.montant_regle_1_h IS DISTINCT FROM w_sejours_total.montant_regle_1_h OR
|
|
|
p_sejours.date_expedition_1 IS DISTINCT FROM CASE WHEN w_sejours_total.date_expedition_1 <> '0001-01-01' THEN w_sejours_total.date_expedition_1 ELSE '2099-12-31' END OR
|
|
|
p_sejours.date_solde_1 IS DISTINCT FROM w_sejours_total.date_solde_1 OR
|
|
|
|
|
|
p_sejours.montant_facture_2_c IS DISTINCT FROM w_sejours_total.montant_facture_2_c OR
|
|
|
p_sejours.montant_facture_2_h IS DISTINCT FROM w_sejours_total.montant_facture_2_h OR
|
|
|
p_sejours.montant_regle_2_c IS DISTINCT FROM w_sejours_total.montant_regle_2_c OR
|
|
|
p_sejours.montant_regle_2_h IS DISTINCT FROM w_sejours_total.montant_regle_2_h OR
|
|
|
p_sejours.date_expedition_2 IS DISTINCT FROM CASE WHEN w_sejours_total.date_expedition_2 <> '0001-01-01' THEN w_sejours_total.date_expedition_2 ELSE '2099-12-31' END OR
|
|
|
p_sejours.date_solde_2 IS DISTINCT FROM w_sejours_total.date_solde_2 OR
|
|
|
|
|
|
p_sejours.montant_facture_22_c IS DISTINCT FROM w_sejours_total.montant_facture_22_c OR
|
|
|
p_sejours.montant_facture_22_h IS DISTINCT FROM w_sejours_total.montant_facture_22_h OR
|
|
|
p_sejours.montant_regle_22_c IS DISTINCT FROM w_sejours_total.montant_regle_22_c OR
|
|
|
p_sejours.montant_regle_22_h IS DISTINCT FROM w_sejours_total.montant_regle_22_h OR
|
|
|
p_sejours.date_expedition_22 IS DISTINCT FROM CASE WHEN w_sejours_total.date_expedition_22 <> '0001-01-01' THEN w_sejours_total.date_expedition_22 ELSE '2099-12-31' END OR
|
|
|
p_sejours.date_solde_22 IS DISTINCT FROM w_sejours_total.date_solde_22 OR
|
|
|
|
|
|
p_sejours.montant_comptabilise_c IS DISTINCT FROM w_sejours_total.montant_comptabilise_c OR
|
|
|
p_sejours.montant_comptabilise_h IS DISTINCT FROM w_sejours_total.montant_comptabilise_h OR
|
|
|
p_sejours.montant_comptabilise_0_c IS DISTINCT FROM w_sejours_total.montant_comptabilise_0_c OR
|
|
|
p_sejours.montant_comptabilise_0_h IS DISTINCT FROM w_sejours_total.montant_comptabilise_0_h OR
|
|
|
p_sejours.montant_comptabilise_1_c IS DISTINCT FROM w_sejours_total.montant_comptabilise_1_c OR
|
|
|
p_sejours.montant_comptabilise_1_h IS DISTINCT FROM w_sejours_total.montant_comptabilise_1_h OR
|
|
|
p_sejours.montant_comptabilise_2_c IS DISTINCT FROM w_sejours_total.montant_comptabilise_2_c OR
|
|
|
p_sejours.montant_comptabilise_2_h IS DISTINCT FROM w_sejours_total.montant_comptabilise_2_h OR
|
|
|
p_sejours.montant_comptabilise_22_c IS DISTINCT FROM w_sejours_total.montant_comptabilise_22_c OR
|
|
|
p_sejours.montant_comptabilise_22_h IS DISTINCT FROM w_sejours_total.montant_comptabilise_22_h OR
|
|
|
|
|
|
p_sejours.montant_comptabilise_budget_global_c IS DISTINCT FROM w_sejours_total.montant_comptabilise_budget_global_c OR
|
|
|
|
|
|
p_sejours.montant_facture_c_actes_inclus_dans_sejour IS DISTINCT FROM w_sejours_total.montant_facture_c_actes_inclus_dans_sejour OR
|
|
|
p_sejours.montant_facture_h_actes_inclus_dans_sejour IS DISTINCT FROM w_sejours_total.montant_facture_h_actes_inclus_dans_sejour
|
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_sejours SET
|
|
|
|
|
|
delai_groupage = CASE WHEN code_sorti = '1' AND date_groupage > date_sortie AND date_groupage < '2099-12-31' AND ghs_id <> 0
|
|
|
THEN date_groupage - date_sortie ELSE 0 END,
|
|
|
delai_facture = CASE WHEN code_sorti = '1' AND date_facture > date_sortie AND date_facture < '2099-12-31' AND date_facture > date_sortie
|
|
|
THEN date_facture - date_sortie ELSE 0 END,
|
|
|
delai_expedition = CASE WHEN code_sorti = '1' AND date_expedition > date_sortie AND date_facture < '2099-12-31' AND date_expedition < '2099-12-31'
|
|
|
THEN date_expedition - date_sortie ELSE 0 END,
|
|
|
delai_solde = CASE WHEN code_sorti = '1' AND date_solde > date_sortie AND date_facture < '2099-12-31' AND date_solde < '2099-12-31'
|
|
|
THEN date_solde - date_sortie ELSE 0 END,
|
|
|
|
|
|
delai_expedition_0 = CASE WHEN code_sorti = '1' AND date_expedition_0 > date_sortie AND date_facture < '2099-12-31' AND date_expedition_0 < '2099-12-31'
|
|
|
THEN date_expedition_0 - date_sortie ELSE 0 END,
|
|
|
delai_solde_0 = CASE WHEN code_sorti = '1'AND date_solde_0 > date_sortie AND date_facture < '2099-12-31' AND date_solde_0 < '2099-12-31'
|
|
|
THEN date_solde_0 - date_sortie ELSE 0 END,
|
|
|
|
|
|
delai_expedition_1 = CASE WHEN code_sorti = '1' AND date_expedition_1 > date_sortie AND date_facture < '2099-12-31' AND date_expedition_1 < '2099-12-31'
|
|
|
THEN date_expedition_1 - date_sortie ELSE 0 END,
|
|
|
delai_solde_1 = CASE WHEN code_sorti = '1' AND date_solde_1 > date_sortie AND date_facture < '2099-12-31' AND date_solde_1 < '2099-12-31'
|
|
|
THEN date_solde_1 - date_sortie ELSE 0 END,
|
|
|
|
|
|
delai_expedition_2 = CASE WHEN code_sorti = '1' AND date_expedition_2 > date_sortie AND date_facture < '2099-12-31' AND date_expedition_2 < '2099-12-31'
|
|
|
THEN date_expedition_2 - date_sortie ELSE 0 END,
|
|
|
delai_solde_2 = CASE WHEN code_sorti = '1' AND date_solde_2 > date_sortie AND date_facture < '2099-12-31' AND date_solde_2 < '2099-12-31'
|
|
|
THEN date_solde_2 - date_sortie ELSE 0 END,
|
|
|
|
|
|
delai_expedition_22 = CASE WHEN code_sorti = '1' AND date_expedition_22 > date_sortie AND date_facture < '2099-12-31' AND date_expedition_22 < '2099-12-31'
|
|
|
THEN date_expedition_22 - date_sortie ELSE 0 END,
|
|
|
delai_solde_22 = CASE WHEN code_sorti = '1' AND date_solde_22 > date_sortie AND date_facture < '2099-12-31' AND date_solde_22 < '2099-12-31'
|
|
|
THEN date_solde_22 - date_sortie ELSE 0 END
|
|
|
|
|
|
WHERE
|
|
|
|
|
|
delai_groupage IS DISTINCT FROM CASE WHEN code_sorti = '1' AND date_groupage > date_sortie AND date_groupage < '2099-12-31' AND ghs_id <> 0
|
|
|
THEN date_groupage - date_sortie ELSE 0 END
|
|
|
OR
|
|
|
delai_facture IS DISTINCT FROM CASE WHEN code_sorti = '1' AND date_facture > date_sortie AND date_facture < '2099-12-31' AND date_facture > date_sortie
|
|
|
THEN date_facture - date_sortie ELSE 0 END
|
|
|
OR
|
|
|
delai_expedition IS DISTINCT FROM CASE WHEN code_sorti = '1' AND date_expedition > date_sortie AND date_facture < '2099-12-31' AND date_expedition < '2099-12-31'
|
|
|
THEN date_expedition - date_sortie ELSE 0 END
|
|
|
OR
|
|
|
delai_solde IS DISTINCT FROM CASE WHEN code_sorti = '1' AND date_solde > date_sortie AND date_facture < '2099-12-31' AND date_solde < '2099-12-31'
|
|
|
THEN date_solde - date_sortie ELSE 0 END
|
|
|
OR
|
|
|
|
|
|
delai_expedition_0 IS DISTINCT FROM CASE WHEN code_sorti = '1' AND date_expedition_0 > date_sortie AND date_facture < '2099-12-31' AND date_expedition_0 < '2099-12-31'
|
|
|
THEN date_expedition_0 - date_sortie ELSE 0 END
|
|
|
OR
|
|
|
delai_solde_0 IS DISTINCT FROM CASE WHEN code_sorti = '1'AND date_solde_0 > date_sortie AND date_facture < '2099-12-31' AND date_solde_0 < '2099-12-31'
|
|
|
THEN date_solde_0 - date_sortie ELSE 0 END
|
|
|
OR
|
|
|
|
|
|
delai_expedition_1 IS DISTINCT FROM CASE WHEN code_sorti = '1' AND date_expedition_1 > date_sortie AND date_facture < '2099-12-31' AND date_expedition_1 < '2099-12-31'
|
|
|
THEN date_expedition_1 - date_sortie ELSE 0 END
|
|
|
OR
|
|
|
delai_solde_1 IS DISTINCT FROM CASE WHEN code_sorti = '1' AND date_solde_1 > date_sortie AND date_facture < '2099-12-31' AND date_solde_1 < '2099-12-31'
|
|
|
THEN date_solde_1 - date_sortie ELSE 0 END
|
|
|
OR
|
|
|
|
|
|
delai_expedition_2 IS DISTINCT FROM CASE WHEN code_sorti = '1' AND date_expedition_2 > date_sortie AND date_facture < '2099-12-31' AND date_expedition_2 < '2099-12-31'
|
|
|
THEN date_expedition_2 - date_sortie ELSE 0 END
|
|
|
OR
|
|
|
delai_solde_2 IS DISTINCT FROM CASE WHEN code_sorti = '1' AND date_solde_2 > date_sortie AND date_facture < '2099-12-31' AND date_solde_2 < '2099-12-31'
|
|
|
THEN date_solde_2 - date_sortie ELSE 0 END
|
|
|
OR
|
|
|
|
|
|
delai_expedition_22 IS DISTINCT FROM CASE WHEN code_sorti = '1' AND date_expedition_22 > date_sortie AND date_facture < '2099-12-31' AND date_expedition_22 < '2099-12-31'
|
|
|
THEN date_expedition_22 - date_sortie ELSE 0 END
|
|
|
OR
|
|
|
delai_solde_22 IS DISTINCT FROM CASE WHEN code_sorti = '1' AND date_solde_22 > date_sortie AND date_facture < '2099-12-31' AND date_solde_22 < '2099-12-31'
|
|
|
THEN date_solde_22 - date_sortie ELSE 0 END;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Tables répliquées">
|
|
|
<condition><![CDATA[
|
|
|
"[PX]" == ""
|
|
|
]]></condition>
|
|
|
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
|
|
|
<NODE name="VACUUM" label="REORGANISATION BASE DE DONNEES">
|
|
|
|
|
|
<NODE label="Réorganisation tables">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
VACUUM ANALYSE activite[PX].p_chiffrier;
|
|
|
VACUUM ANALYSE activite[PX].p_chiffrier_comptable;
|
|
|
VACUUM ANALYSE activite[PX].p_chiffrier_shs;
|
|
|
VACUUM ANALYSE activite[PX].p_factures;
|
|
|
VACUUM ANALYSE activite[PX].p_factures_comptables;
|
|
|
VACUUM ANALYSE activite[PX].p_factures_lignes_c;
|
|
|
VACUUM ANALYSE activite[PX].p_factures_lignes_h;
|
|
|
VACUUM ANALYSE activite[PX].p_factures_lignes_non_facturees_c;
|
|
|
VACUUM ANALYSE activite[PX].p_factures_lignes_non_facturees_h;
|
|
|
VACUUM ANALYSE activite[PX].p_factures_rejets;
|
|
|
VACUUM ANALYSE activite[PX].p_factures_soldes_c;
|
|
|
VACUUM ANALYSE activite[PX].p_factures_soldes_h;
|
|
|
VACUUM ANALYSE activite[PX].p_mouvements_sejour;
|
|
|
VACUUM ANALYSE activite[PX].p_oids;
|
|
|
VACUUM ANALYSE activite[PX].p_patients;
|
|
|
VACUUM ANALYSE activite[PX].p_sejours;
|
|
|
VACUUM ANALYSE activite[PX].t_activites;
|
|
|
VACUUM ANALYSE activite[PX].t_classes;
|
|
|
VACUUM ANALYSE activite[PX].t_classes_sections;
|
|
|
VACUUM ANALYSE activite[PX].t_classes_sections_elements;
|
|
|
VACUUM ANALYSE activite[PX].t_etages;
|
|
|
VACUUM ANALYSE activite[PX].t_ghs_c;
|
|
|
VACUUM ANALYSE activite[PX].t_indicateurs;
|
|
|
VACUUM ANALYSE activite[PX].t_lieux;
|
|
|
VACUUM ANALYSE activite[PX].t_lieux_c;
|
|
|
VACUUM ANALYSE activite[PX].t_listes;
|
|
|
VACUUM ANALYSE activite[PX].t_listes_contenu;
|
|
|
VACUUM ANALYSE activite[PX].t_listes_tables;
|
|
|
VACUUM ANALYSE activite[PX].t_lits;
|
|
|
VACUUM ANALYSE activite[PX].t_medecins_administratifs;
|
|
|
VACUUM ANALYSE activite[PX].t_medecins_administratifs_c;
|
|
|
VACUUM ANALYSE activite.t_prestations;
|
|
|
VACUUM ANALYSE activite[PX].t_rapports;
|
|
|
VACUUM ANALYSE activite[PX].t_rapports_rubriques;
|
|
|
VACUUM ANALYSE activite.t_rejets_noemie;
|
|
|
VACUUM ANALYSE activite[PX].t_rubriques_facturation;
|
|
|
VACUUM ANALYSE activite[PX].t_services_facturation;
|
|
|
VACUUM ANALYSE activite[PX].t_specialites_medecin;
|
|
|
VACUUM ANALYSE activite[PX].t_tiers_payant;
|
|
|
VACUUM ANALYSE activite[PX].t_types_tiers_payant;
|
|
|
VACUUM ANALYSE activite[PX].t_unites_fonctionnelles;
|
|
|
VACUUM ANALYSE activite[PX].t_unites_medicales;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Vide cache">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
SELECT cti_cache_reload as log from cache.cti_cache_reload('iCTI_activite', true);
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="RAZ" label="RAZ BASE">
|
|
|
|
|
|
<NODE label="Nettoyage des tables">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
TRUNCATE activite[PX].p_patients;
|
|
|
|
|
|
TRUNCATE activite[PX].p_sejours;
|
|
|
|
|
|
TRUNCATE activite[PX].p_mouvements_sejour;
|
|
|
|
|
|
TRUNCATE activite[PX].t_lieux;
|
|
|
|
|
|
TRUNCATE activite[PX].p_factures;
|
|
|
|
|
|
TRUNCATE activite[PX].p_factures_lignes_non_facturees_c;
|
|
|
|
|
|
TRUNCATE activite[PX].p_factures_lignes_non_facturees_h;
|
|
|
|
|
|
TRUNCATE activite[PX].p_factures_lignes_c;
|
|
|
|
|
|
TRUNCATE activite[PX].p_factures_lignes_h;
|
|
|
|
|
|
TRUNCATE activite[PX].p_factures_rejets;
|
|
|
|
|
|
TRUNCATE activite[PX].p_factures_soldes_c;
|
|
|
|
|
|
TRUNCATE activite[PX].p_factures_soldes_h;
|
|
|
|
|
|
TRUNCATE activite[PX].p_factures_comptables;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
</ROOT>
|