|
|
<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
|
<ROOT>
|
|
|
|
|
|
|
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
|
|
|
|
<NODE label="Corrections diverses">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Service non renseigné
|
|
|
UPDATE prod_csis.SMV_MOUVEMENT_MVMT
|
|
|
SET MVMT_CHPNUM1 = subview.MVMT_CHPNUM1
|
|
|
FROM
|
|
|
(
|
|
|
SELECT MVMT_ID_DADM,
|
|
|
MIN(CASE WHEN MVMT_CHPNUM1 = 0 THEN MVMT_ID ELSE NULL END) AS MVMT_ID_0,
|
|
|
(MIN(CASE WHEN MVMT_CHPNUM1 <> 0 THEN ARRAY[MVMT_DATEHEURE::text,MVMT_CHPNUM1::text] ELSE NULL END))[2]::numeric AS MVMT_CHPNUM1
|
|
|
FROM prod_csis.SMV_MOUVEMENT_MVMT
|
|
|
JOIN prod_csis.SMV_TYPEMOUVEMENT_TMVT ON MVMT_ID_TMVT = TMVT_ID
|
|
|
WHERE TMVT_CODE = 'D'
|
|
|
GROUP BY 1
|
|
|
HAVING MIN(CASE WHEN MVMT_CHPNUM1 = 0 THEN MVMT_ID ELSE NULL END) > 0 AND
|
|
|
MIN(CASE WHEN MVMT_CHPNUM1 <> 0 THEN MVMT_ID ELSE NULL END) > 0
|
|
|
) subview
|
|
|
WHERE SMV_MOUVEMENT_MVMT.MVMT_ID = MVMT_ID_0
|
|
|
;
|
|
|
|
|
|
-- RSS en double sur Séjour
|
|
|
UPDATE prod_csis.sca_resumess_ress
|
|
|
SET RESS_ETATGRP = 'CTIDEL'
|
|
|
FROM (
|
|
|
SELECT RESS_ID_DADM, (MAX(ARRAY[RESS_DATEDERNGRP::text, RESS_ID::text]))[2]::bigint AS DEL_RESS_ID
|
|
|
FROM prod_csis.sca_resumess_ress
|
|
|
GROUP BY 1
|
|
|
HAVING count(*) > 1
|
|
|
) subview
|
|
|
WHERE SCA_RESUMESS_RESS.RESS_ID_DADM = subview.RESS_ID_DADM AND
|
|
|
RESS_ID <> DEL_RESS_ID;
|
|
|
|
|
|
-- Dotation globale
|
|
|
UPDATE prod_csis.MPM_RECUEILTIERS_RECT
|
|
|
SET RECT_DOTATION = '1'
|
|
|
WHERE RECT_DOTATION = '0' AND RECT_CPTADOTATION = '1'
|
|
|
;
|
|
|
|
|
|
UPDATE prod_csis.MPM_RECUEILTIERS_RECT
|
|
|
SET RECT_DOTATION = '1'
|
|
|
FROM prod_csis.SST_ORGANISME_ORGN
|
|
|
WHERE RECT_ID_ORGN = ORGN_ID AND
|
|
|
RECT_ID_ORGN <> 0 AND
|
|
|
RECT_DOTATION = '0' AND RECT_CPTADOTATION = '0' AND ORGN_DOTATION = '1'
|
|
|
;
|
|
|
|
|
|
UPDATE prod_csis.MPM_RECUEILTIERS_RECT
|
|
|
SET RECT_DOTATION = '0'
|
|
|
WHERE RECT_DOTATION = '1' AND RECT_CPTADOTATION = '2'
|
|
|
;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Identification des séjours">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Demarrage de la facturation (pour encours et BG)
|
|
|
DROP TABLE IF EXISTS w_start;
|
|
|
CREATE TEMP TABLE w_start AS
|
|
|
SELECT COALESCE(date(date_trunc('month',MIN(RECF_DATEGENERATION))),'20000101') AS date_start
|
|
|
FROM prod_csis.MPM_FACTURE_RECF
|
|
|
;
|
|
|
ANALYSE w_start
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_demarrage;
|
|
|
CREATE TEMP TABLE w_demarrage AS
|
|
|
SELECT date(MIN(RECF_DATEGENERATION)) AS date_demarrage
|
|
|
FROM prod_csis.MPM_FACTURE_RECF;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MPM_RECUEILTIERS_RECT_dadm;
|
|
|
CREATE TEMP TABLE w_MPM_RECUEILTIERS_RECT_dadm AS
|
|
|
SELECT RECF_ID, RECF_ID_DADM, SUM(CASE WHEN ETRC_CODE IS DISTINCT FROM 'A' THEN COALESCE(RECT_MONTANT,0) ELSE 0 END) AS RECT_MONTANT,
|
|
|
MAX(COALESCE(RECF_DATEFACTDEB, '20991231')) AS RECF_DATEFACTDEB,
|
|
|
MAX(COALESCE(RECF_DATEGENERATION, '20991231')) AS RECF_DATEGENERATION
|
|
|
FROM prod_csis.MPM_FACTURE_RECF
|
|
|
LEFT JOIN prod_csis.MPM_RECUEILTIERS_RECT ON RECT_ID_RECF = RECF_ID
|
|
|
LEFT JOIN prod_csis.SNO_ETATRECUEIL_ETRC SNO_ETATRECUEIL_ETRC_RECT ON RECT_ID_ETRC = SNO_ETATRECUEIL_ETRC_RECT.ETRC_ID
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
ALTER TABLE w_MPM_RECUEILTIERS_RECT_dadm
|
|
|
ADD CONSTRAINT w_MPM_RECUEILTIERS_RECT_dadm_pk_recf_id PRIMARY KEY(RECF_ID);
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MRC_REGLEMENTDETAIL_REGD_dadm;
|
|
|
CREATE TEMP TABLE w_MRC_REGLEMENTDETAIL_REGD_dadm AS
|
|
|
SELECT RECT_ID_RECF, SUM(REGD_MNTENCAIS) AS REGD_MNTENCAIS, MAX(REGD_DATEENCAIS) AS REGD_DATEENCAIS
|
|
|
FROM prod_csis.MPM_RECUEILTIERS_RECT
|
|
|
JOIN prod_csis.SNO_ETATRECUEIL_ETRC SNO_ETATRECUEIL_ETRC_RECT ON RECT_ID_ETRC = SNO_ETATRECUEIL_ETRC_RECT.ETRC_ID
|
|
|
JOIN prod_csis.MRC_REGLEMENTDETAIL_REGD ON REGD_ID_RECT = RECT_ID
|
|
|
WHERE SNO_ETATRECUEIL_ETRC_RECT.ETRC_CODE <> 'A' AND
|
|
|
REGD_CODETYOP NOT IN ('AC', 'MC')
|
|
|
GROUP BY 1;
|
|
|
|
|
|
ALTER TABLE w_MRC_REGLEMENTDETAIL_REGD_dadm
|
|
|
ADD CONSTRAINT w_MRC_REGLEMENTDETAIL_REGD_dadm_pk_recf_id PRIMARY KEY(RECT_ID_RECF);
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MPM_RECUEILTIERS_RECT_nonsoldes;
|
|
|
CREATE TEMP TABLE w_MPM_RECUEILTIERS_RECT_nonsoldes AS
|
|
|
SELECT
|
|
|
RECF_ID_DADM
|
|
|
FROM w_MPM_RECUEILTIERS_RECT_dadm
|
|
|
LEFT JOIN w_MRC_REGLEMENTDETAIL_REGD_dadm ON RECF_ID = RECT_ID_RECF
|
|
|
WHERE RECT_MONTANT IS DISTINCT FROM REGD_MNTENCAIS OR
|
|
|
RECF_DATEFACTDEB >= '[ENV_ADM_ANNEEDEBUT]0101' OR
|
|
|
REGD_DATEENCAIS >= '[ENV_ADM_ANNEEDEBUT]0101' OR
|
|
|
REGD_DATEENCAIS IS NULL
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SID_DOSSIERADMINISTRATIF_DADM;
|
|
|
CREATE TEMP TABLE w_SID_DOSSIERADMINISTRATIF_DADM AS
|
|
|
SELECT
|
|
|
SID_DOSSIERADMINISTRATIF_DADM.*,
|
|
|
DADM_NDA::text AS DADM_NDA_ETAB,
|
|
|
STDO_CODE,
|
|
|
STDO_NATUREENTREE,
|
|
|
ETAB_TYPE_PSPH,
|
|
|
ETAB_CODE,
|
|
|
ETAB_FINESS,
|
|
|
''::text AS DADM_GIR
|
|
|
FROM prod_csis.SID_DOSSIERADMINISTRATIF_DADM
|
|
|
JOIN w_SST_ETABLISSEMENT_ETAB ON DADM_ID_ETAB = ETAB_ID
|
|
|
JOIN prod_csis.SNO_STATUTDOSSIER_STDO ON DADM_ID_STDO = STDO_ID AND STDO_NATUREENTREE IN ('P','R')
|
|
|
JOIN prod_csis.SNO_ETATDOSSIER_ETDO ON DADM_ID_ETDO = ETDO_ID AND ETDO_ACTIF = '1'
|
|
|
LEFT JOIN w_MPM_RECUEILTIERS_RECT_nonsoldes ON DADM_ID = RECF_ID_DADM
|
|
|
|
|
|
WHERE
|
|
|
(
|
|
|
DADM_DATEDEBUT >= '[ENV_ADM_ANNEEDEBUT]0101' OR
|
|
|
DADM_DATEFIN >= '[ENV_ADM_ANNEEDEBUT]0101' OR
|
|
|
DADM_DATEFIN IS NULL OR
|
|
|
STDO_CODE IN ('P','R') OR
|
|
|
RECF_ID_DADM IS NOT NULL OR
|
|
|
DADM_ID IN (SELECT RECB_ID_DADM FROM prod_csis.MPM_BORDEREAU_RECB WHERE RECB_DATEENVOI >= '[ENV_ADM_ANNEEDEBUT]0101' GROUP BY 1)
|
|
|
);
|
|
|
|
|
|
ALTER TABLE w_SID_DOSSIERADMINISTRATIF_DADM
|
|
|
ADD CONSTRAINT w_SID_DOSSIERADMINISTRATIF_DADM_pk_dadm_id PRIMARY KEY(DADM_ID);
|
|
|
|
|
|
|
|
|
UPDATE w_SID_DOSSIERADMINISTRATIF_DADM
|
|
|
SET DADM_NDA_ETAB = w_SID_DOSSIERADMINISTRATIF_DADM.DADM_NDA_ETAB || '-' || ETAB_PREFIX
|
|
|
FROM
|
|
|
(
|
|
|
SELECT DADM_NDA_ETAB, count(*)
|
|
|
FROM w_SID_DOSSIERADMINISTRATIF_DADM
|
|
|
GROUP BY 1
|
|
|
HAVING count(*) > 1
|
|
|
) subview,
|
|
|
w_SST_ETABLISSEMENT_ETAB
|
|
|
WHERE w_SID_DOSSIERADMINISTRATIF_DADM.DADM_NDA_ETAB = subview.DADM_NDA_ETAB AND
|
|
|
DADM_ID_ETAB = ETAB_ID
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
]]></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, code_sexe, date_naissance)
|
|
|
SELECT
|
|
|
'',
|
|
|
PATI_IPP,
|
|
|
MAX(PATI_NOMUSAGE),
|
|
|
MAX(CASE WHEN PATI_NOMFAMILLE <> PATI_NOMMARITAL THEN PATI_NOMFAMILLE ELSE '' END) ,
|
|
|
MAX(PATI_PRENOMS),
|
|
|
MAX(PATI_CODESEXE),
|
|
|
MAX(PATI_DATENAISSANCE)
|
|
|
FROM prod_csis.SID_PATIENT_PATI
|
|
|
WHERE PATI_ID IN (SELECT DADM_ID_PATI FROM w_SID_DOSSIERADMINISTRATIF_DADM GROUP BY 1) AND
|
|
|
PATI_IPP NOT IN (SELECT no_patient FROM activite[PX].p_patients)
|
|
|
GROUP BY PATI_IPP
|
|
|
ORDER BY PATI_IPP;
|
|
|
|
|
|
UPDATE activite[PX].p_patients SET
|
|
|
nom = PATI_NOMUSAGE,
|
|
|
nom_naissance = CASE WHEN PATI_NOMFAMILLE <> PATI_NOMMARITAL THEN PATI_NOMFAMILLE ELSE '' END,
|
|
|
prenom = PATI_PRENOMS,
|
|
|
code_sexe = PATI_CODESEXE,
|
|
|
date_naissance = date(PATI_DATENAISSANCE)
|
|
|
FROM prod_csis.SID_PATIENT_PATI
|
|
|
WHERE p_patients.no_patient = PATI_IPP AND
|
|
|
PATI_ID_DOMA IN (SELECT ETAB_ID_DOMA FROM w_SST_ETABLISSEMENT_ETAB) AND
|
|
|
(
|
|
|
p_patients.nom IS DISTINCT FROM PATI_NOMUSAGE OR
|
|
|
p_patients.nom_naissance IS DISTINCT FROM CASE WHEN PATI_NOMFAMILLE <> PATI_NOMMARITAL THEN PATI_NOMFAMILLE ELSE '' END OR
|
|
|
p_patients.prenom IS DISTINCT FROM PATI_PRENOMS OR
|
|
|
p_patients.code_sexe IS DISTINCT FROM PATI_CODESEXE OR
|
|
|
p_patients.date_naissance IS DISTINCT FROM date(PATI_DATENAISSANCE)
|
|
|
);
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Préparation mouvements">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Mouvements
|
|
|
DROP TABLE IF EXISTS w_SMV_MOUVEMENT_MVMT_source;
|
|
|
CREATE TEMP TABLE w_SMV_MOUVEMENT_MVMT_source AS
|
|
|
SELECT MVMT_ID,
|
|
|
MVMT_ID_TMVT,
|
|
|
MVMT_ID_SMVT,
|
|
|
MVMT_ID_OMVT,
|
|
|
MVMT_ID_DADM,
|
|
|
MVMT_DATEHEURE,
|
|
|
MVMT_CHPNUM1,
|
|
|
TMVT_CODE,
|
|
|
SMVT_CODE,
|
|
|
MVMT_CHPNUM1::text AS MVMT_CHPNUM1_A
|
|
|
FROM prod_csis.SMV_MOUVEMENT_MVMT
|
|
|
JOIN prod_csis.SMV_TYPEMOUVEMENT_TMVT ON MVMT_ID_TMVT = TMVT_ID
|
|
|
JOIN prod_csis.SMV_STATUTMOUVEMENT_SMVT ON MVMT_ID_SMVT = SMVT_ID
|
|
|
;
|
|
|
|
|
|
-- Ajout des GIR
|
|
|
DROP SEQUENCE IF EXISTS w_SID_PATIENT_GIR_sequence;
|
|
|
CREATE TEMP SEQUENCE w_SID_PATIENT_GIR_sequence;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SID_PATIENT_GIR;
|
|
|
CREATE TEMP TABLE w_SID_PATIENT_GIR AS
|
|
|
SELECT PGIR_ID,
|
|
|
PGIR_ID_PATI,
|
|
|
PGIR_GIR,
|
|
|
date(COALESCE(PGIR_DATEDEBUT,'00010101')) AS PGIR_DATEDEBUT,
|
|
|
date(COALESCE(PGIR_DATEFIN,'20991231')) AS PGIR_DATEFIN,
|
|
|
nextval('w_SID_PATIENT_GIR_sequence'::regclass) AS PGIR_sequence
|
|
|
FROM
|
|
|
(
|
|
|
SELECT *
|
|
|
FROM prod_csis.SID_PATIENTGIR_PGIR
|
|
|
ORDER BY PGIR_ID_PATI, PGIR_DATEDEBUT
|
|
|
) subview
|
|
|
;
|
|
|
|
|
|
UPDATE w_SID_PATIENT_GIR
|
|
|
SET PGIR_DATEFIN = date(w_SID_PATIENT_GIR_next.PGIR_DATEDEBUT - interval '1 day')
|
|
|
FROM w_SID_PATIENT_GIR w_SID_PATIENT_GIR_next
|
|
|
WHERE w_SID_PATIENT_GIR.PGIR_ID_PATI = w_SID_PATIENT_GIR_next.PGIR_ID_PATI AND
|
|
|
w_SID_PATIENT_GIR.PGIR_sequence = w_SID_PATIENT_GIR_next.PGIR_sequence - 1 and
|
|
|
w_SID_PATIENT_GIR.PGIR_DATEFIN <> date(w_SID_PATIENT_GIR_next.PGIR_DATEDEBUT - interval '1 day')
|
|
|
;
|
|
|
|
|
|
INSERT INTO w_SMV_MOUVEMENT_MVMT_source
|
|
|
SELECT
|
|
|
-1::bigint AS MVMT_ID,
|
|
|
-1::bigint AS MVMT_ID_TMVT,
|
|
|
-1::bigint AS MVMT_ID_SMVT,
|
|
|
-1::bigint AS MVMT_ID_OMVT,
|
|
|
DADM_ID AS MVMT_ID_DADM,
|
|
|
PGIR_DATEDEBUT AS MVMT_DATEHEURE,
|
|
|
-1::bigint AS MVMT_CHPNUM1,
|
|
|
'GIR'::text AS TMVT_CODE,
|
|
|
''::text AS SMVT_CODE,
|
|
|
PGIR_GIR AS MVMT_CHPNUM1_A
|
|
|
FROM w_SID_DOSSIERADMINISTRATIF_DADM
|
|
|
JOIN w_SID_PATIENT_GIR ON DADM_ID_PATI = PGIR_ID_PATI AND
|
|
|
date(COALESCE(DADM_DATEFIN,now())) BETWEEN PGIR_DATEDEBUT AND PGIR_DATEFIN
|
|
|
;
|
|
|
|
|
|
CREATE INDEX w_SMV_MOUVEMENT_MVMT_source_i1
|
|
|
ON w_SMV_MOUVEMENT_MVMT_source
|
|
|
USING btree
|
|
|
(MVMT_ID);
|
|
|
|
|
|
CREATE INDEX w_SMV_MOUVEMENT_MVMT_source_i2
|
|
|
ON w_SMV_MOUVEMENT_MVMT_source
|
|
|
USING btree
|
|
|
(MVMT_ID_DADM);
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Séjours">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SCA_ENVELOPPERUM_ENVR_modes;
|
|
|
CREATE TEMP TABLE w_SCA_ENVELOPPERUM_ENVR_modes AS
|
|
|
SELECT
|
|
|
DADM_ID AS ENVR_ID_DADM,
|
|
|
(MIN(array[ENVR_DATEDEBUTRUM::text,ENVR_MODEENT::text]))[2] AS ENVR_MODEENT,
|
|
|
(MIN(array[ENVR_DATEDEBUTRUM::text,CASE WHEN ENVR_PROVENANCE = '' THEN '0' ELSE ENVR_PROVENANCE END::text]))[2] AS ENVR_PROVENANCE,
|
|
|
(MAX(array[ENVR_DATEFINRUM::text,ENVR_MODESOR::text]))[2] AS ENVR_MODESOR,
|
|
|
(MAX(array[ENVR_DATEFINRUM::text,CASE WHEN ENVR_DESTINATION = '' THEN '0' ELSE ENVR_DESTINATION END::text]))[2] AS ENVR_DESTINATION
|
|
|
FROM w_SID_DOSSIERADMINISTRATIF_DADM
|
|
|
LEFT JOIN prod_csis.SCA_ENVELOPPERUM_ENVR ON ENVR_ID_DADM = dadm_id
|
|
|
GROUP BY 1;
|
|
|
|
|
|
CREATE INDEX w_SCA_ENVELOPPERUM_ENVR_modes_i1
|
|
|
ON w_SCA_ENVELOPPERUM_ENVR_modes
|
|
|
USING btree
|
|
|
(ENVR_ID_DADM);
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SCA_RESUMESS_RESS_ump;
|
|
|
CREATE TEMP TABLE w_SCA_RESUMESS_RESS_ump AS
|
|
|
SELECT
|
|
|
DADM_ID AS RESS_ID_DADM,
|
|
|
MAX(MVMT_CHPNUM1) AS MVMT_CHPNUM1_activite
|
|
|
FROM w_SID_DOSSIERADMINISTRATIF_DADM
|
|
|
JOIN prod_csis.SCA_RESUMESS_RESS ON (w_SID_DOSSIERADMINISTRATIF_DADM.DADM_ID = RESS_ID_DADM)
|
|
|
JOIN prod_csis.SCA_ENVELOPPERUM_ENVR ON RESS_ID_ENVR = ENVR_ID
|
|
|
JOIN w_SMV_MOUVEMENT_MVMT_source SMV_MOUVEMENT_MVMT ON MVMT_ID = ENVR_ID1_MVMT AND MVMT_CHPNUM1 <> 0
|
|
|
WHERE RESS_ETATGRP <> 'CTIDEL' AND
|
|
|
TMVT_CODE = 'M' AND
|
|
|
(SMVT_CODE NOT IN ('A') OR TMVT_CODE = 'S')
|
|
|
GROUP BY 1;
|
|
|
|
|
|
CREATE INDEX w_SCA_RESUMESS_RESS_ump_i1
|
|
|
ON w_SCA_RESUMESS_RESS_ump
|
|
|
USING btree
|
|
|
(RESS_ID_DADM);
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SMV_MOUVEMENT_SEJOUR;
|
|
|
CREATE TEMP TABLE w_SMV_MOUVEMENT_SEJOUR AS
|
|
|
SELECT
|
|
|
DADM_ID AS MVMT_ID_DADM,
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'GIR' AND SMVT_CODE NOT IN ('A') THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1_A::text] ELSE NULL END))[2],'') AS MVMT_CHPNUM1_gir,
|
|
|
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'R' AND SMVT_CODE NOT IN ('A') AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_medecin,
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'D' AND SMVT_CODE NOT IN ('A') AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_service,
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'F' AND SMVT_CODE NOT IN ('A') AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_unite_fonctionnelle,
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'M' AND SMVT_CODE NOT IN ('A') AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_unite_medicale,
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'M' AND SMVT_CODE NOT IN ('A') AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,CASE WHEN MVMT_CHPNUM1_activite IS NOT NULL THEN MVMT_CHPNUM1_activite ELSE MVMT_CHPNUM1 END::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_activite,
|
|
|
''::text AS MVMT_CHPNUM1_etage,
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'L' AND SMVT_CODE NOT IN ('A') AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_lit,
|
|
|
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'GIR' AND SMVT_CODE NOT IN ('A') THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1_A::text] ELSE NULL END))[2],'') || '|' ||
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'R' AND SMVT_CODE NOT IN ('A') AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1::text] ELSE NULL END))[2],'0') || '|' ||
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'D' AND SMVT_CODE NOT IN ('A') AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1::text] ELSE NULL END))[2],'0') || '|' ||
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'F' AND SMVT_CODE NOT IN ('A') AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1::text] ELSE NULL END))[2],'0') || '|' ||
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'M' AND SMVT_CODE NOT IN ('A') AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1::text] ELSE NULL END))[2],'0') || '|' ||
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'M' AND SMVT_CODE NOT IN ('A') AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,CASE WHEN MVMT_CHPNUM1_activite IS NOT NULL THEN MVMT_CHPNUM1_activite ELSE MVMT_CHPNUM1 END::text] ELSE NULL END))[2],'0') || '|' ||
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'L' AND SMVT_CODE NOT IN ('A') AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1::text] ELSE NULL END))[2],'0') AS key
|
|
|
|
|
|
FROM w_SID_DOSSIERADMINISTRATIF_DADM
|
|
|
LEFT JOIN w_SMV_MOUVEMENT_MVMT_source SMV_MOUVEMENT_MVMT ON MVMT_ID_DADM = DADM_ID
|
|
|
LEFT JOIN w_SCA_RESUMESS_RESS_ump ON DADM_ID = RESS_ID_DADM
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SMV_MOUVEMENT_SEJOUR_keys;
|
|
|
CREATE TEMP TABLE w_SMV_MOUVEMENT_SEJOUR_keys AS
|
|
|
SELECT
|
|
|
key,
|
|
|
MVMT_CHPNUM1_gir,
|
|
|
MVMT_CHPNUM1_medecin,
|
|
|
MVMT_CHPNUM1_service,
|
|
|
MVMT_CHPNUM1_unite_fonctionnelle,
|
|
|
MVMT_CHPNUM1_unite_medicale,
|
|
|
MVMT_CHPNUM1_activite,
|
|
|
MVMT_CHPNUM1_etage,
|
|
|
MVMT_CHPNUM1_lit,
|
|
|
|
|
|
''::text AS mode_traitement_code,
|
|
|
''::text AS dmt_code,
|
|
|
'0'::text AS type_sejour_force,
|
|
|
|
|
|
0::bigint AS gir_id,
|
|
|
0::bigint AS medecin_sejour_id,
|
|
|
0::bigint AS service_facturation_id,
|
|
|
0::bigint AS mode_traitement_id,
|
|
|
0::bigint AS unite_fonctionnelle_id,
|
|
|
0::bigint AS unite_medicale_id,
|
|
|
0::bigint AS activite_id,
|
|
|
0::bigint AS etage_id,
|
|
|
0::bigint AS lit_id,
|
|
|
0::bigint AS lieu_id
|
|
|
FROM w_SMV_MOUVEMENT_SEJOUR
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9;
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_SEJOUR_keys
|
|
|
SET medecin_sejour_id = COALESCE(t_medecins_administratifs.oid,0)
|
|
|
FROM activite[PX].t_medecins_administratifs
|
|
|
WHERE t_medecins_administratifs.code_original = MVMT_CHPNUM1_medecin;
|
|
|
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_SEJOUR_keys
|
|
|
SET
|
|
|
service_facturation_id = COALESCE(t_services_facturation.oid,0),
|
|
|
mode_traitement_id = t_modes_traitement.oid,
|
|
|
mode_traitement_code = t_modes_traitement.code,
|
|
|
dmt_code = t_dmt.code,
|
|
|
type_sejour_force = CASE WHEN t_services_facturation.type_sejour IN ('1', '2', '3', '4', '5') THEN t_services_facturation.type_sejour ELSE '0' END
|
|
|
FROM activite[PX].t_services_facturation
|
|
|
JOIN base.t_modes_traitement ON t_services_facturation.mode_traitement_id = t_modes_traitement.oid
|
|
|
JOIN base.t_dmt ON t_services_facturation.dmt_id = t_dmt.oid
|
|
|
WHERE t_services_facturation.code_original = MVMT_CHPNUM1_service;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_SEJOUR_keys
|
|
|
SET unite_fonctionnelle_id = COALESCE(t_unites_fonctionnelles.oid,0)
|
|
|
FROM activite[PX].t_unites_fonctionnelles
|
|
|
WHERE t_unites_fonctionnelles.code_original = MVMT_CHPNUM1_unite_fonctionnelle;
|
|
|
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_SEJOUR_keys
|
|
|
SET unite_medicale_id = COALESCE(t_unites_medicales.oid,0)
|
|
|
FROM activite[PX].t_unites_medicales
|
|
|
WHERE t_unites_medicales.code_original = MVMT_CHPNUM1_unite_medicale;
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_SEJOUR_keys
|
|
|
SET activite_id = COALESCE(t_activites.oid,0)
|
|
|
FROM activite[PX].t_activites
|
|
|
WHERE t_activites.code_original = MVMT_CHPNUM1_activite;
|
|
|
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_SEJOUR_keys
|
|
|
SET lit_id = COALESCE(t_lits.oid,0),
|
|
|
MVMT_CHPNUM1_etage = CASE WHEN t_lits.etage_id <> 0 THEN COALESCE(t_etages.code_original,'0') ELSE '0' END,
|
|
|
etage_id = COALESCE(t_lits.etage_id,0)
|
|
|
FROM activite[PX].t_lits
|
|
|
JOIN activite[PX].t_etages ON t_lits.etage_id = t_etages.oid
|
|
|
WHERE t_lits.code_original = MVMT_CHPNUM1_lit;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_lieux(
|
|
|
code_original_1,
|
|
|
code_original_2,
|
|
|
code_original_3,
|
|
|
code_original_4,
|
|
|
code_original_5,
|
|
|
code_original_6,
|
|
|
gir_code_original)
|
|
|
SELECT
|
|
|
MVMT_CHPNUM1_service,
|
|
|
MVMT_CHPNUM1_activite,
|
|
|
MVMT_CHPNUM1_etage,
|
|
|
MVMT_CHPNUM1_lit,
|
|
|
MVMT_CHPNUM1_unite_medicale,
|
|
|
MVMT_CHPNUM1_unite_fonctionnelle,
|
|
|
MVMT_CHPNUM1_gir
|
|
|
FROM w_SMV_MOUVEMENT_SEJOUR_keys
|
|
|
LEFT JOIN activite[PX].t_lieux ON (
|
|
|
code_original_1 = MVMT_CHPNUM1_service AND
|
|
|
code_original_2 = MVMT_CHPNUM1_activite AND
|
|
|
code_original_3 = MVMT_CHPNUM1_etage AND
|
|
|
code_original_4 = MVMT_CHPNUM1_lit AND
|
|
|
code_original_5 = MVMT_CHPNUM1_unite_medicale AND
|
|
|
code_original_6 = MVMT_CHPNUM1_unite_fonctionnelle AND
|
|
|
gir_code_original = MVMT_CHPNUM1_gir
|
|
|
)
|
|
|
WHERE t_lieux.oid IS NULL
|
|
|
GROUP BY 1,2,3,4,5,6,7;
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
service_facturation_id = COALESCE(t_services_facturation.oid,0),
|
|
|
mode_traitement_id = COALESCE(t_services_facturation.mode_traitement_id,0)
|
|
|
FROM activite[PX].t_services_facturation
|
|
|
WHERE code_original_1 = t_services_facturation.code_original
|
|
|
AND (t_lieux.service_facturation_id <> COALESCE(t_services_facturation.oid,0) OR
|
|
|
t_lieux.mode_traitement_id <> COALESCE(t_services_facturation.mode_traitement_id,0)
|
|
|
)
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
activite_id = COALESCE(t_activites.oid,0)
|
|
|
FROM activite[PX].t_activites
|
|
|
WHERE code_original_2 = t_activites.code_original
|
|
|
AND activite_id <> COALESCE(t_activites.oid,0);
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
lit_id = COALESCE(t_lits.oid,0)
|
|
|
FROM activite[PX].t_lits
|
|
|
WHERE code_original_4 = t_lits.code_original AND
|
|
|
t_lieux.lit_id <> COALESCE(t_lits.oid,0)
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
unite_medicale_id = COALESCE(t_unites_medicales.oid,0)
|
|
|
FROM activite[PX].t_unites_medicales
|
|
|
WHERE code_original_5 = t_unites_medicales.code_original
|
|
|
AND unite_medicale_id <> COALESCE(t_unites_medicales.oid,0);
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
unite_fonctionnelle_id = COALESCE(t_unites_fonctionnelles.oid,0)
|
|
|
FROM activite[PX].t_unites_fonctionnelles
|
|
|
WHERE code_original_6 = t_unites_fonctionnelles.code_original
|
|
|
AND unite_fonctionnelle_id <> COALESCE(t_unites_fonctionnelles.oid,0);
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
gir_id = t_gir.oid
|
|
|
FROM base.t_gir
|
|
|
WHERE gir_code_original = t_gir.code
|
|
|
AND gir_id <> t_gir.oid
|
|
|
;
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
gir_id = 0
|
|
|
WHERE gir_code_original = ''
|
|
|
AND gir_id <> 0
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_SEJOUR_keys
|
|
|
set lieu_id = t_lieux.oid
|
|
|
FROM activite[PX].t_lieux
|
|
|
WHERE code_original_1 = MVMT_CHPNUM1_service AND
|
|
|
code_original_2 = MVMT_CHPNUM1_activite AND
|
|
|
code_original_3 = MVMT_CHPNUM1_etage AND
|
|
|
code_original_4 = MVMT_CHPNUM1_lit AND
|
|
|
code_original_5 = MVMT_CHPNUM1_unite_medicale AND
|
|
|
code_original_6 = MVMT_CHPNUM1_unite_fonctionnelle AND
|
|
|
gir_code_original = MVMT_CHPNUM1_gir;
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MPE_ASSURANCE_ASSU;
|
|
|
CREATE TEMP TABLE w_MPE_ASSURANCE_ASSU AS
|
|
|
SELECT
|
|
|
DADM_ID AS ASSU_ID_DADM,
|
|
|
MIN((SELECT MIN(oid) FROM activite[PX].t_tiers_payant WHERE code = 'PATIENTS')) as tiers_payant_0_id,
|
|
|
MIN(CASE WHEN assu_type = 'O' THEN t_tiers_payant.oid ELSE null END) as tiers_payant_1_id,
|
|
|
MIN(CASE WHEN assu_type = 'C' AND assu_distinctif = 1 THEN t_tiers_payant.oid ELSE null END) as tiers_payant_2_id,
|
|
|
MIN(CASE WHEN assu_type = 'C' AND assu_distinctif <> 1 THEN t_tiers_payant.oid ELSE null END) as tiers_payant_22_id
|
|
|
FROM w_SID_DOSSIERADMINISTRATIF_DADM
|
|
|
LEFT JOIN prod_csis.MPE_ASSURANCE_ASSU ON ASSU_ID_DADM = DADM_ID
|
|
|
LEFT JOIN activite[PX].t_tiers_payant ON assu_id_orgn::bigint = t_tiers_payant.code_original AND t_tiers_payant.code <> 'PATIENTS'
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MPM_RECUEIL_RECG_type_sejour;
|
|
|
CREATE TEMP TABLE w_MPM_RECUEIL_RECG_type_sejour AS
|
|
|
SELECT
|
|
|
DADM_NDA_ETAB,
|
|
|
DADM_ID,
|
|
|
DATE(RECG_DATEDEBUT) AS RECG_DATEDEBUT, to_number('0' || RECG_GHS,'00000') AS ghs_code,
|
|
|
NULL::text AS type_sejour_force,
|
|
|
0::numeric AS nb_seances,
|
|
|
SUM(CASE WHEN RECG_PRESTATION = 'GHS' THEN RECG_QUANTITE ELSE 0 END) AS RECG_QUANTITE_ghs,
|
|
|
SUM(CASE WHEN RECG_PRESTATION = 'K' THEN RECG_QUANTITE ELSE 0 END) AS RECG_QUANTITE_k,
|
|
|
SUM(CASE WHEN RECG_PRESTATION IN ('SE1', 'SE2', 'SE3', 'SE4','SE5', 'SE6', 'SE7', 'FFM', 'ATU', 'FPU') THEN RECG_QUANTITE ELSE 0 END) AS RECG_QUANTITE_ext
|
|
|
FROM prod_csis.MPM_RECUEIL_RECG
|
|
|
JOIN w_SID_DOSSIERADMINISTRATIF_DADM ON DADM_ID = RECG_ID_DADM
|
|
|
JOIN prod_csis.SNO_ETATRECUEIL_ETRC ON RECG_ID_ETRC = ETRC_ID AND ETRC_CODE <> 'A'
|
|
|
WHERE RECG_PRESTATION = 'GHS' OR
|
|
|
(RECG_PRESTATION = 'K' AND RECG_COEFFICIENT = 15) OR
|
|
|
(RECG_PRESTATION IN ('SE1', 'SE2', 'SE3', 'SE4','SE5', 'SE6', 'SE7', 'FFM', 'ATU', 'FPU'))
|
|
|
GROUP BY 1,2,3,4
|
|
|
HAVING SUM(CASE WHEN RECG_PRESTATION = 'GHS' THEN RECG_QUANTITE ELSE 0 END) > 0 OR
|
|
|
SUM(CASE WHEN RECG_PRESTATION = 'K' THEN RECG_QUANTITE ELSE 0 END) > 0 OR
|
|
|
SUM(CASE WHEN RECG_PRESTATION IN ('SE1', 'SE2', 'SE3', 'SE4','SE5', 'SE6', 'SE7', 'FFM', 'ATU', 'FPU') THEN RECG_QUANTITE ELSE 0 END) > 0;
|
|
|
|
|
|
|
|
|
CREATE INDEX w_MPM_RECUEIL_RECG_type_sejour_i1
|
|
|
ON w_MPM_RECUEIL_RECG_type_sejour
|
|
|
USING btree
|
|
|
(DADM_NDA_ETAB);
|
|
|
|
|
|
CREATE INDEX w_MPM_RECUEIL_RECG_type_sejour_i2
|
|
|
ON w_MPM_RECUEIL_RECG_type_sejour
|
|
|
USING btree
|
|
|
(DADM_ID);
|
|
|
|
|
|
UPDATE w_MPM_RECUEIL_RECG_type_sejour
|
|
|
SET type_sejour_force = '3'
|
|
|
WHERE type_sejour_force IS NULL AND
|
|
|
RECG_QUANTITE_ext <> 0 AND
|
|
|
RECG_QUANTITE_ghs = 0;
|
|
|
|
|
|
|
|
|
UPDATE w_MPM_RECUEIL_RECG_type_sejour
|
|
|
SET type_sejour_force = '5'
|
|
|
FROM base.t_ghs
|
|
|
WHERE type_sejour_force IS NULL AND
|
|
|
ghs_code = t_ghs.code AND
|
|
|
t_ghs.texte like '%séance%' AND
|
|
|
RECG_QUANTITE_ghs <> 0;
|
|
|
|
|
|
UPDATE w_MPM_RECUEIL_RECG_type_sejour
|
|
|
SET nb_seances = GREATEST(RECG_QUANTITE_ghs,RECG_QUANTITE_k)
|
|
|
FROM base.t_ghs
|
|
|
WHERE ghs_code = t_ghs.code AND
|
|
|
t_ghs.texte ilike '%séance%' AND
|
|
|
((ghs_code <> 0 AND t_ghs.oid IS NOT NULL) OR RECG_QUANTITE_k > 0);
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MPM_RECUEIL_RECG_type_sejour_force;
|
|
|
CREATE TEMP TABLE w_MPM_RECUEIL_RECG_type_sejour_force AS
|
|
|
SELECT DADM_ID, DADM_NDA_ETAB, MAX(type_sejour_force) AS type_sejour_force
|
|
|
FROM w_MPM_RECUEIL_RECG_type_sejour
|
|
|
WHERE type_sejour_force IS NOT NULL
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_sejours;
|
|
|
|
|
|
CREATE TEMP TABLE w_sejours AS
|
|
|
SELECT
|
|
|
ETAB_FINESS AS finess,
|
|
|
w_SID_DOSSIERADMINISTRATIF_DADM.DADM_NDA_ETAB as no_sejour,
|
|
|
w_SID_DOSSIERADMINISTRATIF_DADM.DADM_ID::bigint as code_original,
|
|
|
PATI_IPP as no_patient,
|
|
|
date(DADM_DATEDEBUT) as date_entree,
|
|
|
extract('hour' FROM DADM_DATEDEBUT) * 10000 + extract('minute' FROM DADM_DATEDEBUT) * 100 + extract('second' FROM DADM_DATEDEBUT) as heure_entree,
|
|
|
CASE WHEN DADM_DATEFIN IS NOT NULL THEN date(DADM_DATEFIN) ELSE '20991231' END::date as date_sortie,
|
|
|
CASE WHEN DADM_DATEFIN IS NOT NULL THEN extract('hour' FROM DADM_DATEFIN) * 10000 + extract('minute' FROM DADM_DATEFIN) * 100 + extract('second' FROM DADM_DATEFIN) ELSE 0 END as heure_sortie,
|
|
|
PATI_CODESEXE AS code_sexe,
|
|
|
0 AS age,
|
|
|
CASE WHEN STDO_CODE IN ('S', 'C') THEN 1 ELSE 0 END as code_sorti,
|
|
|
CASE WHEN STDO_CODE IN ('R', 'P') THEN 1 ELSE 0 END as code_prevu,
|
|
|
CASE
|
|
|
WHEN w_MPM_RECUEIL_RECG_type_sejour_force.type_sejour_force IS NOT NULL THEN w_MPM_RECUEIL_RECG_type_sejour_force.type_sejour_force
|
|
|
WHEN w_SMV_MOUVEMENT_SEJOUR_keys.type_sejour_force <> '0' THEN w_SMV_MOUVEMENT_SEJOUR_keys.type_sejour_force
|
|
|
WHEN mode_traitement_code IN ('07') OR dmt_code IN ('958') THEN '3'
|
|
|
WHEN mode_traitement_code IN ('19', '23') THEN '2'
|
|
|
WHEN mode_traitement_code IN ('04') AND STDO_CODE IN ('S', 'C') AND date(DADM_DATEFIN) = date(DADM_DATEDEBUT) THEN '2'
|
|
|
WHEN mode_traitement_code IN ('03') AND STDO_CODE IN ('S', 'C') AND date(DADM_DATEFIN) = date(DADM_DATEDEBUT) THEN '2'
|
|
|
WHEN mode_traitement_code IN ('10') AND STDO_CODE IN ('S', 'C') AND date(DADM_DATEFIN) <= date(DADM_DATEDEBUT) + interval '1 day' THEN '3'
|
|
|
WHEN mode_traitement_code IN ('03') THEN '1'
|
|
|
ELSE '1' END as type_sejour,
|
|
|
medecin_sejour_id,
|
|
|
lieu_id AS lieu_sortie_id,
|
|
|
CASE WHEN DADM_DATEDEMCHAMBRESEULE IS NOT NULL THEN '1' ELSE '0' END as code_cp_demandee,
|
|
|
mode_traitement_id,
|
|
|
COALESCE(ENVR_MODEENT,'8') as mode_entree,
|
|
|
COALESCE(ENVR_PROVENANCE,'0') as provenance,
|
|
|
COALESCE(ENVR_MODESOR,'8') as mode_sortie,
|
|
|
COALESCE(ENVR_DESTINATION,'0') as destination,
|
|
|
COALESCE(tiers_payant_0_id,0) AS tiers_payant_0_id,
|
|
|
COALESCE(tiers_payant_1_id,0) AS tiers_payant_1_id,
|
|
|
COALESCE(tiers_payant_2_id,0) AS tiers_payant_2_id,
|
|
|
CASE WHEN COALESCE(tiers_payant_22_id,0) <> COALESCE(tiers_payant_2_id,0) THEN COALESCE(tiers_payant_22_id,0) ELSE 0 END AS tiers_payant_22_id,
|
|
|
ETAB_TYPE_PSPH AS est_budget_global,
|
|
|
COALESCE(t_ghs.oid,0) as ghs_id,
|
|
|
COALESCE(t_ghm.oid,0) as ghm_id,
|
|
|
CASE WHEN DPMS_ETATDOSSIER = 'V' THEN RESS_DATEDERNGRP ELSE '20991231'::date END as date_groupage,
|
|
|
0::bigint AS ghs_bebe1_id,
|
|
|
0::bigint AS ghs_bebe2_id,
|
|
|
0::bigint AS ghs_bebe3_id,
|
|
|
COALESCE(t_codes_postaux.oid, 0) as code_postal_id
|
|
|
|
|
|
FROM w_SID_DOSSIERADMINISTRATIF_DADM
|
|
|
JOIN prod_csis.sid_patient_pati ON pati_id = dadm_id_pati
|
|
|
JOIN prod_csis.sst_modeetab_mdtb ON dadm_id_mdtb = mdtb_id
|
|
|
JOIN prod_csis.sno_mode_mode ON mdtb_id_mode = mode_id
|
|
|
JOIN w_SMV_MOUVEMENT_SEJOUR ON MVMT_ID_DADM = w_SID_DOSSIERADMINISTRATIF_DADM.DADM_ID
|
|
|
JOIN w_SMV_MOUVEMENT_SEJOUR_keys ON w_SMV_MOUVEMENT_SEJOUR.key = w_SMV_MOUVEMENT_SEJOUR_keys.key
|
|
|
JOIN w_MPE_ASSURANCE_ASSU ON w_SID_DOSSIERADMINISTRATIF_DADM.DADM_ID = ASSU_ID_DADM
|
|
|
JOIN w_SCA_ENVELOPPERUM_ENVR_modes ON ENVR_ID_DADM = w_SID_DOSSIERADMINISTRATIF_DADM.DADM_ID
|
|
|
LEFT JOIN prod_csis.sca_resumess_ress ON w_SID_DOSSIERADMINISTRATIF_DADM.dadm_id = ress_id_dadm AND RESS_ETATGRP <> 'CTIDEL'
|
|
|
LEFT JOIN prod_csis.sca_dossierpmsi_dpms ON (w_SID_DOSSIERADMINISTRATIF_DADM.dadm_id = dpms_id_dadm)
|
|
|
LEFT JOIN base.t_ghs ON to_number('0' || RESS_NUMERO_GGHS, '00000') = t_ghs.code
|
|
|
LEFT JOIN base.t_ghm ON (RESS_CODEGHM = t_ghm.code AND t_ghm.code NOT LIKE '90%')
|
|
|
LEFT JOIN base.t_codes_postaux ON PATI_CODEPOSTAL = t_codes_postaux.code
|
|
|
LEFT JOIN w_MPM_RECUEIL_RECG_type_sejour_force ON w_MPM_RECUEIL_RECG_type_sejour_force.DADM_ID = w_SID_DOSSIERADMINISTRATIF_DADM.DADM_ID;
|
|
|
|
|
|
-- Modes e/s selon medsphere
|
|
|
UPDATE w_sejours SET
|
|
|
mode_entree = MODE_CODEENTREESORTIE,
|
|
|
provenance = COALESCE(PROV_CODE, '0')
|
|
|
FROM prod_csis.SMV_DOSSIERMVT_DMVT
|
|
|
JOIN prod_csis.SID_DOSSIERADMINISTRATIF_DADM ON DMVT_ID_DADM = DADM_ID
|
|
|
JOIN prod_csis.SNO_MODE_MODE ON DMVT_ID_MODE_ENTREE = MODE_ID
|
|
|
LEFT JOIN prod_csis.SNO_PROVENANCE_PROV ON DMVT_ID_PROV = PROV_ID
|
|
|
WHERE w_sejours.code_original = DADM_ID AND
|
|
|
length(MODE_CODEENTREESORTIE) <= 1 AND
|
|
|
(
|
|
|
mode_entree <> MODE_CODEENTREESORTIE OR
|
|
|
provenance <> PROV_CODE
|
|
|
)
|
|
|
;
|
|
|
|
|
|
UPDATE w_sejours SET
|
|
|
mode_sortie = MODE_CODEENTREESORTIE,
|
|
|
destination = COALESCE(DEST_CODE, '0')
|
|
|
FROM prod_csis.SMV_DOSSIERMVT_DMVT
|
|
|
JOIN prod_csis.SID_DOSSIERADMINISTRATIF_DADM ON DMVT_ID_DADM = DADM_ID
|
|
|
JOIN prod_csis.SNO_MODE_MODE ON DMVT_ID_MODE_SORTIE = MODE_ID
|
|
|
LEFT JOIN prod_csis.SNO_DESTINATION_DEST ON DMVT_ID_DEST = DEST_ID
|
|
|
WHERE w_sejours.code_original = DADM_ID AND
|
|
|
length(MODE_CODEENTREESORTIE) <= 1 AND
|
|
|
(
|
|
|
mode_sortie <> MODE_CODEENTREESORTIE OR
|
|
|
destination <> DEST_CODE
|
|
|
)
|
|
|
;
|
|
|
|
|
|
-- Forcage type selon séjour
|
|
|
UPDATE w_sejours
|
|
|
SET type_sejour = t_sejour.type_sejour
|
|
|
FROM activite.t_sejour
|
|
|
WHERE t_sejour.no_sejour = w_sejours.no_sejour AND
|
|
|
t_sejour.type_sejour IN ('1','2','3','4','5','6','9');
|
|
|
|
|
|
UPDATE w_sejours
|
|
|
SET date_sortie = date_sortie - interval '100 years'
|
|
|
WHERE code_sorti = '1' AND date_sortie BETWEEN '21010101' AND '21991231';
|
|
|
|
|
|
-- Demande CP selon supplémnt lit
|
|
|
UPDATE w_sejours
|
|
|
SET code_cp_demandee = '1'
|
|
|
FROM prod_csis.SID_DOSSIERADMINISTRATIF_DADM
|
|
|
JOIN prod_csis.SMV_DOSSIERMVT_DMVT ON DMVT_ID_DADM = DADM_ID
|
|
|
WHERE DADM_ID = code_original AND
|
|
|
DMVT_ID_SPLT > 1 AND
|
|
|
code_cp_demandee <> '1';
|
|
|
|
|
|
-- Validation
|
|
|
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');
|
|
|
|
|
|
UPDATE activite[PX].p_sejours SET
|
|
|
code_original = w_sejours.code_original,
|
|
|
finess = w_sejours.finess,
|
|
|
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,
|
|
|
lieu_sortie_id = w_sejours.lieu_sortie_id,
|
|
|
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,
|
|
|
est_budget_global = w_sejours.est_budget_global,
|
|
|
date_groupage = w_sejours.date_groupage,
|
|
|
ghs_id = w_sejours.ghs_id,
|
|
|
ghm_id = w_sejours.ghm_id,
|
|
|
ghs_bebe1_id = w_sejours.ghs_bebe1_id,
|
|
|
ghs_bebe2_id = w_sejours.ghs_bebe2_id,
|
|
|
ghs_bebe3_id = w_sejours.ghs_bebe3_id,
|
|
|
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.finess IS DISTINCT FROM p_sejours.finess 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.lieu_sortie_id IS DISTINCT FROM p_sejours.lieu_sortie_id 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.est_budget_global IS DISTINCT FROM p_sejours.est_budget_global OR
|
|
|
w_sejours.date_groupage IS DISTINCT FROM p_sejours.date_groupage 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.ghs_bebe1_id IS DISTINCT FROM p_sejours.ghs_bebe1_id OR
|
|
|
w_sejours.ghs_bebe2_id IS DISTINCT FROM p_sejours.ghs_bebe2_id OR
|
|
|
w_sejours.ghs_bebe3_id IS DISTINCT FROM p_sejours.ghs_bebe3_id OR
|
|
|
w_sejours.code_postal_id IS DISTINCT FROM p_sejours.code_postal_id
|
|
|
);
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_sejours (
|
|
|
finess,
|
|
|
no_sejour,
|
|
|
code_original,
|
|
|
no_patient,
|
|
|
date_entree,
|
|
|
heure_entree,
|
|
|
date_sortie,
|
|
|
heure_sortie,
|
|
|
code_sexe,
|
|
|
age,
|
|
|
code_sorti,
|
|
|
code_prevu,
|
|
|
type_sejour,
|
|
|
lieu_sortie_id,
|
|
|
medecin_sejour_id,
|
|
|
ghs_id,
|
|
|
ghm_id,
|
|
|
ghs_bebe1_id,
|
|
|
ghs_bebe2_id,
|
|
|
ghs_bebe3_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,
|
|
|
est_budget_global,
|
|
|
code_postal_id
|
|
|
)
|
|
|
SELECT
|
|
|
w_sejours.finess,
|
|
|
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.lieu_sortie_id,
|
|
|
w_sejours.medecin_sejour_id,
|
|
|
w_sejours.ghs_id,
|
|
|
w_sejours.ghm_id,
|
|
|
w_sejours.ghs_bebe1_id,
|
|
|
w_sejours.ghs_bebe2_id,
|
|
|
w_sejours.ghs_bebe3_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.est_budget_global,
|
|
|
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);
|
|
|
|
|
|
-- Sejours ignores alors qu'il y a de la facturation, transformer en fictif
|
|
|
UPDATE activite.t_sejour
|
|
|
SET est_ignore = '0', type_sejour = '9'
|
|
|
WHERE est_ignore = '1' AND
|
|
|
no_sejour = ANY
|
|
|
(
|
|
|
SELECT no_sejour
|
|
|
FROM prod_csis.SCP_CPTATRANSFERT_CPTF
|
|
|
JOIN prod_csis.MPM_FACTURE_RECF ON RECF_ID = CPTF_ID_RECF
|
|
|
JOIN prod_csis.SID_DOSSIERADMINISTRATIF_DADM ON RECF_ID_DADM = DADM_ID
|
|
|
JOIN activite.t_sejour ON DADM_NDA = t_sejour.no_sejour
|
|
|
WHERE est_ignore = '1'
|
|
|
GROUP BY 1
|
|
|
)
|
|
|
;
|
|
|
|
|
|
-- 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');
|
|
|
|
|
|
|
|
|
-- transferts d'établissements
|
|
|
INSERT INTO base.t_etablissements(code, texte, texte_court)
|
|
|
SELECT
|
|
|
ETBS_FINESS,
|
|
|
MAX(ETBS_RAISONSOCIALE),
|
|
|
MAX(ETBS_RAISONSOCIALE)
|
|
|
FROM prod_csis.SNO_ETABLISSEMENT_ETBS
|
|
|
WHERE ETBS_FINESS NOT IN (SELECT code FROM base.t_etablissements)
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite[PX].p_sejours_transferts (sejour_id, provenance_id, destination_id)
|
|
|
SELECT
|
|
|
p_sejours.oid,
|
|
|
MAX(provenance.oid),
|
|
|
MAX(destination.oid)
|
|
|
FROM
|
|
|
activite[PX].p_sejours
|
|
|
JOIN prod_csis.SID_DOSSIERADMINISTRATIF_DADM ON DADM_NDA = no_sejour
|
|
|
JOIN prod_csis.SMV_DOSSIERMVT_DMVT ON DMVT_ID_DADM = DADM_ID
|
|
|
LEFT JOIN prod_csis.vil_smv_modeentreeprov SER_PROV ON MVMT_ID_DADM = DMVT_ID_DADM
|
|
|
LEFT JOIN prod_csis.SNO_SERVICEETABLISSEMENT_SVET SER_DEST ON DMVT_ID_SVET_DEST = SER_DEST.SVET_ID
|
|
|
LEFT JOIN prod_csis.SNO_ETABLISSEMENT_ETBS DEST ON DEST.ETBS_ID = SER_DEST.SVET_ID_ETBS
|
|
|
LEFT JOIN base.t_etablissements provenance ON SER_PROV.ETABFINESS = provenance.code
|
|
|
LEFT JOIN base.t_etablissements destination ON DEST.ETBS_FINESS = destination.code
|
|
|
WHERE 1=1 AND
|
|
|
(IDETBS_PROVENANCE != 0 OR DMVT_ID_SVET_DEST != 0)
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
-- Assurance
|
|
|
INSERT INTO activite[PX].p_sejours_assurance(
|
|
|
sejour_id,
|
|
|
nom_assure,
|
|
|
prenom_assure,
|
|
|
tiers_payant_0_id,
|
|
|
tiers_payant_1_id,
|
|
|
matricule_1,
|
|
|
tiers_payant_2_id,
|
|
|
matricule_2,
|
|
|
tiers_payant_22_id,
|
|
|
matricule_22
|
|
|
)
|
|
|
SELECT
|
|
|
p_sejours.oid AS sejour_id,
|
|
|
MAX(ASSU_NOMUSUEL) AS nom_assure,
|
|
|
MAX(ASSU_PRENOM) prenom_assure,
|
|
|
MAX(p_sejours.tiers_payant_0_id),
|
|
|
MAX(p_sejours.tiers_payant_1_id),
|
|
|
MAX(CASE WHEN ASSU_TYPE = 'O' THEN substr(ASSU_NOSS,1,13) ELSE '' END) AS matricule_1,
|
|
|
MAX(p_sejours.tiers_payant_2_id),
|
|
|
MAX(CASE WHEN ASSU_TYPE = 'C' AND ASSU_DISTINCTIF = 1 THEN CASE WHEN ASSU_NOADHERENT <> '' THEN ASSU_NOADHERENT ELSE substr(ASSU_NOSS,1,13) END ELSE '' END) AS matricule_2,
|
|
|
MAX(p_sejours.tiers_payant_22_id),
|
|
|
MAX(CASE WHEN ASSU_TYPE = 'C' AND ASSU_DISTINCTIF <> 1 THEN CASE WHEN ASSU_NOADHERENT <> '' THEN ASSU_NOADHERENT ELSE substr(ASSU_NOSS,1,13) END ELSE '' END) AS matricule_22
|
|
|
FROM prod_csis.MPE_ASSURANCE_ASSU
|
|
|
JOIN activite[PX].p_sejours ON code_original = ASSU_ID_DADM
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Mouvements">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP SEQUENCE IF EXISTS w_SMV_MOUVEMENT_MVMT_seq;
|
|
|
CREATE TEMP SEQUENCE w_SMV_MOUVEMENT_MVMT_seq;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SMV_MOUVEMENT_MVMT;
|
|
|
CREATE TEMP TABLE w_SMV_MOUVEMENT_MVMT AS
|
|
|
SELECT *, nextval('w_SMV_MOUVEMENT_MVMT_seq'::regclass) AS sequence FROM
|
|
|
(
|
|
|
SELECT DADM_ID,
|
|
|
CASE
|
|
|
WHEN MVMT_dateheure IS NULL AND TMVT_CODE = 'S'
|
|
|
THEN to_timestamp(COALESCE(DADM_DATEFIN, (now() + '1 day'::interval )::date - '1 second'::interval), 'YYYY-MM-DD HH24:MI:SS')
|
|
|
WHEN to_timestamp(MVMT_dateheure, 'YYYY-MM-DD HH24:MI:SS') >= to_timestamp(DADM_DATEDEBUT, 'YYYY-MM-DD HH24:MI:SS')
|
|
|
THEN to_timestamp(MVMT_dateheure, 'YYYY-MM-DD HH24:MI:SS')
|
|
|
ELSE to_timestamp(DADM_DATEDEBUT, 'YYYY-MM-DD HH24:MI:SS')
|
|
|
END AS MVMT_dateheure,
|
|
|
null::date AS MVMT_date,
|
|
|
null::numeric AS MVMT_heure,
|
|
|
'0'::text AS est_entree,
|
|
|
null::timestamp AS MVMT_dateheure_fin,
|
|
|
null::date AS MVMT_date_fin,
|
|
|
null::numeric AS MVMT_heure_fin,
|
|
|
'0'::text AS est_sortie,
|
|
|
MAX(CASE WHEN TMVT_CODE = 'S' THEN TMVT_CODE ELSE '' END) AS TMVT_CODE_S,
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'GIR' THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1_A::text] ELSE NULL END))[2],'') AS MVMT_CHPNUM1_gir,
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'R' AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_med,
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'D' AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_ser,
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'F' AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_uf,
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'M' AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_um,
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'M' AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,CASE WHEN MVMT_CHPNUM1_activite IS NOT NULL THEN MVMT_CHPNUM1_activite ELSE MVMT_CHPNUM1 END::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_activite,
|
|
|
'0'::text AS MVMT_CHPNUM1_eta,
|
|
|
COALESCE((MAX(CASE WHEN TMVT_CODE = 'L' AND MVMT_CHPNUM1 <> 0 THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_lit,
|
|
|
'0'::text AS MVMT_CHPNUM1_ser_before,
|
|
|
'0'::text AS MVMT_CHPNUM1_eta_before,
|
|
|
'0'::text AS MVMT_CHPNUM1_uf_before,
|
|
|
'0'::text AS MVMT_CHPNUM1_um_before,
|
|
|
'0'::text AS MVMT_CHPNUM1_ser_after,
|
|
|
'0'::text AS MVMT_CHPNUM1_eta_after,
|
|
|
'0'::text AS MVMT_CHPNUM1_uf_after,
|
|
|
'0'::text AS MVMT_CHPNUM1_um_after,
|
|
|
|
|
|
''::text AS key
|
|
|
FROM w_SID_DOSSIERADMINISTRATIF_DADM
|
|
|
LEFT JOIN w_SMV_MOUVEMENT_MVMT_source SMV_MOUVEMENT_MVMT ON MVMT_ID_DADM = dadm_id
|
|
|
LEFT JOIN w_SCA_RESUMESS_RESS_ump ON DADM_ID = RESS_ID_DADM
|
|
|
WHERE SMVT_CODE NOT IN ('A') OR TMVT_CODE = 'S'
|
|
|
GROUP BY 1,2,3,4
|
|
|
ORDER BY 1,2
|
|
|
) subview;
|
|
|
|
|
|
DELETE FROM w_SMV_MOUVEMENT_MVMT
|
|
|
USING w_SID_DOSSIERADMINISTRATIF_DADM
|
|
|
WHERE w_SMV_MOUVEMENT_MVMT.DADM_ID = w_SID_DOSSIERADMINISTRATIF_DADM.DADM_ID AND
|
|
|
STDO_CODE IN ('S', 'C') AND
|
|
|
TMVT_CODE_S <> 'S' AND
|
|
|
MVMT_DATEHEURE > DADM_DATEFIN;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_MVMT
|
|
|
SET MVMT_CHPNUM1_eta = t_lits.etage_id
|
|
|
FROM activite[PX].t_lits
|
|
|
WHERE t_lits.code_original = MVMT_CHPNUM1_lit AND MVMT_CHPNUM1_lit <> '0';
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SMV_MOUVEMENT_MVMT_2;
|
|
|
CREATE TEMP TABLE w_SMV_MOUVEMENT_MVMT_2 AS
|
|
|
SELECT DADM_ID,
|
|
|
MIN(sequence) AS sequence_first,
|
|
|
MAX(sequence) AS sequence_last,
|
|
|
COALESCE((MIN(CASE WHEN MVMT_CHPNUM1_gir <> '' THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1_gir::text] ELSE NULL END))[2],'') AS MVMT_CHPNUM1_gir_first,
|
|
|
COALESCE((MIN(CASE WHEN MVMT_CHPNUM1_med <> '0' THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1_med::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_med_first,
|
|
|
COALESCE((MIN(CASE WHEN MVMT_CHPNUM1_ser <> '0' THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1_ser::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_ser_first,
|
|
|
COALESCE((MIN(CASE WHEN MVMT_CHPNUM1_uf <> '0' THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1_uf::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_uf_first,
|
|
|
COALESCE((MIN(CASE WHEN MVMT_CHPNUM1_um <> '0' THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1_um::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_um_first,
|
|
|
COALESCE((MIN(CASE WHEN MVMT_CHPNUM1_activite <> '0' THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1_activite::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_activite_first,
|
|
|
COALESCE((MIN(CASE WHEN MVMT_CHPNUM1_eta <> '0' THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1_eta::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_eta_first,
|
|
|
COALESCE((MIN(CASE WHEN MVMT_CHPNUM1_lit <> '0' THEN array[MVMT_DATEHEURE::text,MVMT_CHPNUM1_lit::text] ELSE NULL END))[2],'0') AS MVMT_CHPNUM1_lit_first
|
|
|
FROM w_SMV_MOUVEMENT_MVMT
|
|
|
WHERE TMVT_CODE_S <> 'S'
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_MVMT SET
|
|
|
est_entree = '1',
|
|
|
MVMT_CHPNUM1_gir = MVMT_CHPNUM1_gir_first,
|
|
|
MVMT_CHPNUM1_med = MVMT_CHPNUM1_med_first,
|
|
|
MVMT_CHPNUM1_ser = MVMT_CHPNUM1_ser_first,
|
|
|
MVMT_CHPNUM1_uf = MVMT_CHPNUM1_uf_first,
|
|
|
MVMT_CHPNUM1_um = MVMT_CHPNUM1_um_first,
|
|
|
MVMT_CHPNUM1_activite = MVMT_CHPNUM1_activite_first,
|
|
|
MVMT_CHPNUM1_eta = MVMT_CHPNUM1_eta_first,
|
|
|
MVMT_CHPNUM1_lit = MVMT_CHPNUM1_lit_first
|
|
|
FROM w_SMV_MOUVEMENT_MVMT_2
|
|
|
WHERE w_SMV_MOUVEMENT_MVMT.DADM_ID = w_SMV_MOUVEMENT_MVMT_2.DADM_ID AND
|
|
|
sequence = sequence_first AND
|
|
|
(MVMT_CHPNUM1_gir IS DISTINCT FROM MVMT_CHPNUM1_gir_first OR
|
|
|
MVMT_CHPNUM1_med IS DISTINCT FROM MVMT_CHPNUM1_med_first OR
|
|
|
MVMT_CHPNUM1_ser IS DISTINCT FROM MVMT_CHPNUM1_ser_first OR
|
|
|
MVMT_CHPNUM1_uf IS DISTINCT FROM MVMT_CHPNUM1_uf_first OR
|
|
|
MVMT_CHPNUM1_um IS DISTINCT FROM MVMT_CHPNUM1_um_first OR
|
|
|
MVMT_CHPNUM1_activite IS DISTINCT FROM MVMT_CHPNUM1_activite_first OR
|
|
|
MVMT_CHPNUM1_eta IS DISTINCT FROM MVMT_CHPNUM1_eta_first OR
|
|
|
MVMT_CHPNUM1_lit IS DISTINCT FROM MVMT_CHPNUM1_lit_first OR
|
|
|
est_entree = '0'
|
|
|
)
|
|
|
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
SELECT base.cti_execute(
|
|
|
'UPDATE w_SMV_MOUVEMENT_MVMT SET
|
|
|
MVMT_CHPNUM1_gir = CASE WHEN w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_gir = '''' THEN w_SMV_MOUVEMENT_MVMT_prev.MVMT_CHPNUM1_gir ELSE w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_gir END,
|
|
|
MVMT_CHPNUM1_med = CASE WHEN w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_med = ''0'' THEN w_SMV_MOUVEMENT_MVMT_prev.MVMT_CHPNUM1_med ELSE w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_med END,
|
|
|
MVMT_CHPNUM1_ser = CASE WHEN w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_ser = ''0'' THEN w_SMV_MOUVEMENT_MVMT_prev.MVMT_CHPNUM1_ser ELSE w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_ser END,
|
|
|
MVMT_CHPNUM1_uf = CASE WHEN w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_uf = ''0'' THEN w_SMV_MOUVEMENT_MVMT_prev.MVMT_CHPNUM1_uf ELSE w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_uf END,
|
|
|
MVMT_CHPNUM1_um = CASE WHEN w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_um = ''0'' THEN w_SMV_MOUVEMENT_MVMT_prev.MVMT_CHPNUM1_um ELSE w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_um END,
|
|
|
MVMT_CHPNUM1_activite = CASE WHEN w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_activite = ''0'' THEN w_SMV_MOUVEMENT_MVMT_prev.MVMT_CHPNUM1_um ELSE w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_activite END,
|
|
|
MVMT_CHPNUM1_eta = CASE WHEN w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_eta = ''0'' THEN w_SMV_MOUVEMENT_MVMT_prev.MVMT_CHPNUM1_eta ELSE w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_eta END,
|
|
|
MVMT_CHPNUM1_lit = CASE WHEN w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_lit = ''0'' THEN w_SMV_MOUVEMENT_MVMT_prev.MVMT_CHPNUM1_lit ELSE w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_lit END
|
|
|
FROM w_SMV_MOUVEMENT_MVMT w_SMV_MOUVEMENT_MVMT_prev
|
|
|
WHERE w_SMV_MOUVEMENT_MVMT.DADM_ID = w_SMV_MOUVEMENT_MVMT_prev.DADM_ID AND
|
|
|
w_SMV_MOUVEMENT_MVMT.sequence = w_SMV_MOUVEMENT_MVMT_prev.sequence + 1 AND
|
|
|
w_SMV_MOUVEMENT_MVMT.TMVT_CODE_S <> ''S'' AND
|
|
|
(
|
|
|
w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_gir = '''' AND w_SMV_MOUVEMENT_MVMT_prev.MVMT_CHPNUM1_gir <> '''' OR
|
|
|
w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_med = ''0'' AND w_SMV_MOUVEMENT_MVMT_prev.MVMT_CHPNUM1_med <> ''0'' OR
|
|
|
w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_ser = ''0'' AND w_SMV_MOUVEMENT_MVMT_prev.MVMT_CHPNUM1_ser <> ''0'' OR
|
|
|
w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_uf = ''0'' AND w_SMV_MOUVEMENT_MVMT_prev.MVMT_CHPNUM1_uf <> ''0'' OR
|
|
|
w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_um = ''0'' AND w_SMV_MOUVEMENT_MVMT_prev.MVMT_CHPNUM1_um <> ''0'' OR
|
|
|
w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_activite = ''0'' AND w_SMV_MOUVEMENT_MVMT_prev.MVMT_CHPNUM1_activite <> ''0'' OR
|
|
|
w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_eta = ''0'' AND w_SMV_MOUVEMENT_MVMT_prev.MVMT_CHPNUM1_eta <> ''0'' OR
|
|
|
w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_lit = ''0'' AND w_SMV_MOUVEMENT_MVMT_prev.MVMT_CHPNUM1_lit <> ''0''
|
|
|
)
|
|
|
',5000);
|
|
|
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_MVMT SET
|
|
|
MVMT_dateheure_fin = CASE WHEN w_SMV_MOUVEMENT_MVMT_next.TMVT_CODE_S = 'S' THEN w_SMV_MOUVEMENT_MVMT_next.MVMT_dateheure ELSE w_SMV_MOUVEMENT_MVMT_next.MVMT_dateheure - interval '1 second' END ,
|
|
|
est_sortie = CASE WHEN w_SMV_MOUVEMENT_MVMT_next.TMVT_CODE_S = 'S' THEN '1' ELSE '0' END
|
|
|
FROM w_SMV_MOUVEMENT_MVMT w_SMV_MOUVEMENT_MVMT_next
|
|
|
WHERE w_SMV_MOUVEMENT_MVMT.DADM_ID = w_SMV_MOUVEMENT_MVMT_next.DADM_ID AND
|
|
|
w_SMV_MOUVEMENT_MVMT.sequence = w_SMV_MOUVEMENT_MVMT_next.sequence - 1 ;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_MVMT SET
|
|
|
MVMT_date = date(MVMT_dateheure),
|
|
|
MVMT_heure = extract('hour' FROM MVMT_dateheure) * 10000 + extract('minute' FROM MVMT_dateheure) * 100 + extract('second' FROM MVMT_dateheure),
|
|
|
MVMT_date_fin = date(MVMT_dateheure_fin),
|
|
|
MVMT_heure_fin = extract('hour' FROM MVMT_dateheure_fin) * 10000 + extract('minute' FROM MVMT_dateheure_fin) * 100 + extract('second' FROM MVMT_dateheure_fin) ;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- calcul mvt avant
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_MVMT
|
|
|
SET
|
|
|
MVMT_CHPNUM1_ser_before = w_SMV_MOUVEMENT_MVMT_before.MVMT_CHPNUM1_ser,
|
|
|
MVMT_CHPNUM1_uf_before = w_SMV_MOUVEMENT_MVMT_before.MVMT_CHPNUM1_uf,
|
|
|
MVMT_CHPNUM1_um_before = w_SMV_MOUVEMENT_MVMT_before.MVMT_CHPNUM1_um,
|
|
|
MVMT_CHPNUM1_eta_before = w_SMV_MOUVEMENT_MVMT_before.MVMT_CHPNUM1_eta
|
|
|
FROM w_SMV_MOUVEMENT_MVMT w_SMV_MOUVEMENT_MVMT_before
|
|
|
WHERE w_SMV_MOUVEMENT_MVMT.DADM_ID = w_SMV_MOUVEMENT_MVMT_before.DADM_ID AND
|
|
|
w_SMV_MOUVEMENT_MVMT.sequence = w_SMV_MOUVEMENT_MVMT_before.sequence + 1 AND
|
|
|
w_SMV_MOUVEMENT_MVMT.TMVT_CODE_S <> 'S';
|
|
|
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_MVMT
|
|
|
SET
|
|
|
MVMT_CHPNUM1_ser_before = MVMT_CHPNUM1_ser,
|
|
|
MVMT_CHPNUM1_uf_before = MVMT_CHPNUM1_uf,
|
|
|
MVMT_CHPNUM1_um_before = MVMT_CHPNUM1_um,
|
|
|
MVMT_CHPNUM1_eta_before = MVMT_CHPNUM1_eta
|
|
|
WHERE w_SMV_MOUVEMENT_MVMT.est_entree = '1';
|
|
|
|
|
|
-- calcul mvt après
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_MVMT
|
|
|
SET
|
|
|
MVMT_CHPNUM1_ser_after = w_SMV_MOUVEMENT_MVMT_after.MVMT_CHPNUM1_ser,
|
|
|
MVMT_CHPNUM1_uf_after = w_SMV_MOUVEMENT_MVMT_after.MVMT_CHPNUM1_uf,
|
|
|
MVMT_CHPNUM1_um_after = w_SMV_MOUVEMENT_MVMT_after.MVMT_CHPNUM1_um,
|
|
|
MVMT_CHPNUM1_eta_after = w_SMV_MOUVEMENT_MVMT_after.MVMT_CHPNUM1_eta
|
|
|
FROM w_SMV_MOUVEMENT_MVMT w_SMV_MOUVEMENT_MVMT_after
|
|
|
WHERE w_SMV_MOUVEMENT_MVMT.DADM_ID = w_SMV_MOUVEMENT_MVMT_after.DADM_ID AND
|
|
|
w_SMV_MOUVEMENT_MVMT.sequence = w_SMV_MOUVEMENT_MVMT_after.sequence - 1 AND
|
|
|
w_SMV_MOUVEMENT_MVMT.TMVT_CODE_S <> 'S';
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_MVMT
|
|
|
SET
|
|
|
MVMT_CHPNUM1_ser_after = MVMT_CHPNUM1_ser,
|
|
|
MVMT_CHPNUM1_uf_after = MVMT_CHPNUM1_uf,
|
|
|
MVMT_CHPNUM1_um_after = MVMT_CHPNUM1_um,
|
|
|
MVMT_CHPNUM1_eta_after = MVMT_CHPNUM1_eta
|
|
|
FROM w_SMV_MOUVEMENT_MVMT_2
|
|
|
WHERE w_SMV_MOUVEMENT_MVMT.DADM_ID = w_SMV_MOUVEMENT_MVMT_2.DADM_ID AND
|
|
|
sequence = sequence_last;
|
|
|
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_MVMT
|
|
|
SET key = MVMT_CHPNUM1_gir || '|' || MVMT_CHPNUM1_ser || '|' || MVMT_CHPNUM1_uf || '|' || MVMT_CHPNUM1_um || '|' || MVMT_CHPNUM1_activite || '|' || MVMT_CHPNUM1_eta || '|' || MVMT_CHPNUM1_lit;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SMV_MOUVEMENT_MVMT_keys;
|
|
|
CREATE TEMP TABLE w_SMV_MOUVEMENT_MVMT_keys AS
|
|
|
SELECT
|
|
|
key,
|
|
|
MVMT_CHPNUM1_gir,
|
|
|
MVMT_CHPNUM1_ser,
|
|
|
MVMT_CHPNUM1_uf,
|
|
|
MVMT_CHPNUM1_um,
|
|
|
MVMT_CHPNUM1_activite,
|
|
|
MVMT_CHPNUM1_eta,
|
|
|
MVMT_CHPNUM1_lit,
|
|
|
|
|
|
''::text AS mode_traitement_code,
|
|
|
''::text AS dmt_code,
|
|
|
'0'::text AS type_sejour_force,
|
|
|
'0'::text AS chambre_particuliere,
|
|
|
|
|
|
0::bigint AS gir_id,
|
|
|
0::bigint AS service_facturation_id,
|
|
|
0::bigint AS mode_traitement_id,
|
|
|
0::bigint AS unite_fonctionnelle_id,
|
|
|
0::bigint AS unite_medicale_id,
|
|
|
0::bigint AS activite_id,
|
|
|
0::bigint AS etage_id,
|
|
|
0::bigint AS lit_id,
|
|
|
0::bigint AS lieu_id
|
|
|
FROM w_SMV_MOUVEMENT_MVMT
|
|
|
GROUP BY 1,2,3,4,5,6,7,8;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_MVMT_keys
|
|
|
SET
|
|
|
service_facturation_id = COALESCE(t_services_facturation.oid,0),
|
|
|
mode_traitement_id = t_modes_traitement.oid,
|
|
|
mode_traitement_code = t_modes_traitement.code,
|
|
|
dmt_code = t_dmt.code,
|
|
|
type_sejour_force = CASE WHEN t_services_facturation.type_sejour IN ('1', '2', '3', '4', '5') THEN t_services_facturation.type_sejour ELSE '0' END
|
|
|
FROM activite[PX].t_services_facturation
|
|
|
JOIN base.t_modes_traitement ON t_services_facturation.mode_traitement_id = t_modes_traitement.oid
|
|
|
JOIN base.t_dmt ON t_services_facturation.dmt_id = t_dmt.oid
|
|
|
WHERE t_services_facturation.code_original = MVMT_CHPNUM1_ser;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_MVMT_keys
|
|
|
SET unite_fonctionnelle_id = COALESCE(t_unites_fonctionnelles.oid,0)
|
|
|
FROM activite[PX].t_unites_fonctionnelles
|
|
|
WHERE t_unites_fonctionnelles.code_original = MVMT_CHPNUM1_uf;
|
|
|
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_MVMT_keys
|
|
|
SET unite_medicale_id = COALESCE(t_unites_medicales.oid,0)
|
|
|
FROM activite[PX].t_unites_medicales
|
|
|
WHERE t_unites_medicales.code_original = MVMT_CHPNUM1_um;
|
|
|
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_MVMT_keys
|
|
|
SET activite_id = COALESCE(t_activites.oid,0)
|
|
|
FROM activite[PX].t_activites
|
|
|
WHERE t_activites.code_original = MVMT_CHPNUM1_activite;
|
|
|
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_MVMT_keys
|
|
|
SET lit_id = COALESCE(t_lits.oid,0),
|
|
|
MVMT_CHPNUM1_eta = CASE WHEN t_lits.etage_id <> 0 THEN COALESCE(t_etages.code_original,'0') ELSE '0' END,
|
|
|
etage_id = COALESCE(t_lits.etage_id,0),
|
|
|
chambre_particuliere = t_lits.chambre_particuliere
|
|
|
FROM activite[PX].t_lits
|
|
|
JOIN activite[PX].t_etages ON t_lits.etage_id = t_etages.oid
|
|
|
WHERE t_lits.code_original = MVMT_CHPNUM1_lit;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_lieux(
|
|
|
code_original_1,
|
|
|
code_original_2,
|
|
|
code_original_3,
|
|
|
code_original_4,
|
|
|
code_original_5,
|
|
|
code_original_6,
|
|
|
gir_code_original)
|
|
|
SELECT
|
|
|
MVMT_CHPNUM1_ser,
|
|
|
MVMT_CHPNUM1_activite,
|
|
|
MVMT_CHPNUM1_eta,
|
|
|
MVMT_CHPNUM1_lit,
|
|
|
MVMT_CHPNUM1_um,
|
|
|
MVMT_CHPNUM1_uf,
|
|
|
MVMT_CHPNUM1_gir
|
|
|
FROM w_SMV_MOUVEMENT_MVMT_keys
|
|
|
LEFT JOIN activite[PX].t_lieux ON (
|
|
|
code_original_1 = MVMT_CHPNUM1_ser AND
|
|
|
code_original_2 = MVMT_CHPNUM1_activite AND
|
|
|
code_original_3 = MVMT_CHPNUM1_eta AND
|
|
|
code_original_4 = MVMT_CHPNUM1_lit AND
|
|
|
code_original_5 = MVMT_CHPNUM1_um AND
|
|
|
code_original_6 = MVMT_CHPNUM1_uf AND
|
|
|
gir_code_original = MVMT_CHPNUM1_gir
|
|
|
)
|
|
|
WHERE t_lieux.oid IS NULL
|
|
|
GROUP BY 1,2,3,4,5,6,7;
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
service_facturation_id = COALESCE(t_services_facturation.oid,0),
|
|
|
mode_traitement_id = COALESCE(t_services_facturation.mode_traitement_id,0)
|
|
|
FROM activite[PX].t_services_facturation
|
|
|
WHERE code_original_1 = t_services_facturation.code_original
|
|
|
AND (t_lieux.service_facturation_id <> COALESCE(t_services_facturation.oid,0) OR
|
|
|
t_lieux.mode_traitement_id <> COALESCE(t_services_facturation.mode_traitement_id,0)
|
|
|
)
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
activite_id = COALESCE(t_activites.oid,0)
|
|
|
FROM activite[PX].t_activites
|
|
|
WHERE code_original_2 = t_activites.code_original
|
|
|
AND activite_id <> COALESCE(t_activites.oid,0);
|
|
|
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
lit_id = COALESCE(t_lits.oid,0)
|
|
|
FROM activite[PX].t_lits
|
|
|
WHERE code_original_4 = t_lits.code_original AND
|
|
|
t_lieux.lit_id <> COALESCE(t_lits.oid,0)
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
unite_medicale_id = COALESCE(t_unites_medicales.oid,0)
|
|
|
FROM activite[PX].t_unites_medicales
|
|
|
WHERE code_original_5 = t_unites_medicales.code_original
|
|
|
AND unite_medicale_id <> COALESCE(t_unites_medicales.oid,0);
|
|
|
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
unite_fonctionnelle_id = COALESCE(t_unites_fonctionnelles.oid,0)
|
|
|
FROM activite[PX].t_unites_fonctionnelles
|
|
|
WHERE code_original_6 = t_unites_fonctionnelles.code_original
|
|
|
AND unite_fonctionnelle_id <> COALESCE(t_unites_fonctionnelles.oid,0);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE w_SMV_MOUVEMENT_MVMT_keys
|
|
|
set lieu_id = t_lieux.oid
|
|
|
FROM activite[PX].t_lieux
|
|
|
WHERE code_original_1 = MVMT_CHPNUM1_ser AND
|
|
|
code_original_2 = MVMT_CHPNUM1_activite AND
|
|
|
code_original_3 = MVMT_CHPNUM1_eta AND
|
|
|
code_original_4 = MVMT_CHPNUM1_lit AND
|
|
|
code_original_5 = MVMT_CHPNUM1_um AND
|
|
|
code_original_6 = MVMT_CHPNUM1_uf AND
|
|
|
gir_code_original = MVMT_CHPNUM1_gir;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_mouvements_sejour;
|
|
|
|
|
|
CREATE TEMP TABLE w_mouvements_sejour AS
|
|
|
SELECT
|
|
|
w_SMV_MOUVEMENT_MVMT.DADM_ID,
|
|
|
p_sejours.no_sejour AS no_sejour,
|
|
|
p_sejours.oid AS sejour_id,
|
|
|
sequence,
|
|
|
p_calendrier.date,
|
|
|
p_calendrier.jour_semaine,
|
|
|
p_calendrier.is_weekend,
|
|
|
CASE WHEN p_calendrier.date = MVMT_date THEN MVMT_heure ELSE 0 END AS heure_debut,
|
|
|
CASE WHEN p_calendrier.date = MVMT_date_fin THEN MVMT_heure_fin ELSE 240000 END AS heure_fin,
|
|
|
CASE WHEN p_calendrier.date = MVMT_date AND est_entree = '1' AND p_sejours.type_sejour = '1' THEN 1 ELSE 0 END AS nb_entrees_directes,
|
|
|
CASE WHEN p_calendrier.date = MVMT_date_fin AND est_sortie = '1' AND p_sejours.code_sorti = '1' AND p_sejours.type_sejour = '1' THEN 1 ELSE 0 END AS nb_sorties_directes,
|
|
|
CASE WHEN p_calendrier.date = MVMT_date AND est_entree = '1' AND p_sejours.type_sejour = '1' THEN '1' ELSE '0' END AS est_jour_entree,
|
|
|
CASE WHEN p_calendrier.date = MVMT_date_fin AND est_sortie = '1' AND p_sejours.code_sorti = '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 = MVMT_date AND est_entree = '1' AND p_sejours.type_sejour = '2' THEN 1 ELSE 0 END AS nb_ambulatoires,
|
|
|
CASE WHEN p_calendrier.date = MVMT_date AND est_entree = '1' AND p_sejours.type_sejour = '3' THEN 1 ELSE 0 END AS nb_externes,
|
|
|
CASE WHEN p_calendrier.date = MVMT_date AND est_entree = '1' AND p_sejours.type_sejour <> '9' AND dmt_code IN ('303', '307', '308', '401', '402', '403', '404', '405', '406', '407', '408', '409') THEN 1 ELSE 0 END AS nb_urgences,
|
|
|
0 as nb_seances,
|
|
|
|
|
|
CASE WHEN p_calendrier.date = MVMT_date AND p_sejours.type_sejour = '1' AND w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_ser <> MVMT_CHPNUM1_ser_before THEN 1 ELSE 0 END AS nb_entrees_mutation_service,
|
|
|
CASE WHEN p_calendrier.date = MVMT_date_fin AND p_sejours.type_sejour = '1' AND w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_ser <> MVMT_CHPNUM1_ser_after THEN 1 ELSE 0 END AS nb_sorties_mutation_service,
|
|
|
CASE WHEN p_calendrier.date = MVMT_date AND p_sejours.type_sejour = '1' AND w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_eta <> MVMT_CHPNUM1_eta_before THEN 1 ELSE 0 END AS nb_entrees_mutation_etage,
|
|
|
CASE WHEN p_calendrier.date = MVMT_date_fin AND p_sejours.type_sejour = '1' AND w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_eta <> MVMT_CHPNUM1_eta_after THEN 1 ELSE 0 END AS nb_sorties_mutation_etage,
|
|
|
0 AS nb_entrees_mutation_activite,
|
|
|
0 AS nb_sorties_mutation_activite,
|
|
|
CASE WHEN p_calendrier.date = MVMT_date AND p_sejours.type_sejour = '1' AND w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_um <> MVMT_CHPNUM1_um_before THEN 1 ELSE 0 END AS nb_entrees_mutation_unite_medicale,
|
|
|
CASE WHEN p_calendrier.date = MVMT_date_fin AND p_sejours.type_sejour = '1' AND w_SMV_MOUVEMENT_MVMT.MVMT_CHPNUM1_um <> MVMT_CHPNUM1_um_after THEN 1 ELSE 0 END AS nb_sorties_mutation_unite_medicale,
|
|
|
|
|
|
CASE WHEN p_sejours.type_sejour = '1' AND (p_calendrier.date <> MVMT_date_fin OR est_sortie = '1') THEN 1 ELSE 0 END AS nb_jours_js_inclus,
|
|
|
CASE WHEN p_sejours.type_sejour = '1' AND p_calendrier.date <> MVMT_date_fin THEN 1 ELSE 0 END AS nb_jours_js_non_inclus,
|
|
|
|
|
|
CASE WHEN p_sejours.type_sejour = '1' AND chambre_particuliere = 'O' THEN '1' ELSE '0' END AS est_chambre_particuliere,
|
|
|
CASE WHEN p_sejours.type_sejour = '1' AND chambre_particuliere = 'O' AND (p_calendrier.date <> MVMT_date_fin OR est_sortie = '1') THEN 1 ELSE 0 END AS nb_chambres_particulieres,
|
|
|
|
|
|
0::numeric AS nb_bebes,
|
|
|
|
|
|
|
|
|
lieu_id,
|
|
|
|
|
|
p_sejours.medecin_sejour_id as medecin_sejour_id,
|
|
|
'0'::text AS est_premier_mouvement_jour,
|
|
|
'0'::text AS est_dernier_mouvement_jour,
|
|
|
|
|
|
CASE WHEN p_sejours.code_prevu = '1' OR p_calendrier.date > date(now()) THEN '1' ELSE '0' END AS est_mouvement_previsionnel
|
|
|
|
|
|
FROM w_SMV_MOUVEMENT_MVMT
|
|
|
JOIN activite[PX].p_sejours ON w_SMV_MOUVEMENT_MVMT.DADM_ID = p_sejours.code_original AND p_sejours.etat = ''
|
|
|
JOIN w_SMV_MOUVEMENT_MVMT_keys ON w_SMV_MOUVEMENT_MVMT.key = w_SMV_MOUVEMENT_MVMT_keys.key
|
|
|
JOIN base.p_calendrier ON (p_calendrier.date BETWEEN MVMT_date AND MVMT_date_fin AND p_calendrier.date <= now() OR (p_calendrier.date = p_sejours.date_entree AND est_entree = '1'))
|
|
|
WHERE w_SMV_MOUVEMENT_MVMT.TMVT_CODE_S <> 'S'
|
|
|
AND (p_sejours.type_sejour NOT IN ('2', '3') OR (p_sejours.type_sejour IN ('2', '3') AND est_entree = '1' AND p_calendrier.date = MVMT_date))
|
|
|
AND p_sejours.code_prevu <> '1'
|
|
|
ORDER BY sequence, p_calendrier.date;
|
|
|
|
|
|
|
|
|
UPDATE w_mouvements_sejour p_mouvements_sejour
|
|
|
SET est_jour_entree = '1'
|
|
|
FROM activite[PX].p_sejours
|
|
|
WHERE p_mouvements_sejour.no_sejour = p_sejours.no_sejour AND
|
|
|
date_entree = date and est_jour_entree <> '1';
|
|
|
|
|
|
UPDATE w_mouvements_sejour p_mouvements_sejour
|
|
|
SET est_jour_sortie = '1'
|
|
|
FROM activite[PX].p_sejours
|
|
|
WHERE p_mouvements_sejour.no_sejour = p_sejours.no_sejour AND
|
|
|
code_sorti = '1' AND
|
|
|
date_sortie = date and est_jour_sortie <> '1'
|
|
|
;
|
|
|
|
|
|
UPDATE w_mouvements_sejour
|
|
|
SET nb_seances = w_MPM_RECUEIL_RECG_type_sejour.nb_seances
|
|
|
FROM w_MPM_RECUEIL_RECG_type_sejour
|
|
|
WHERE w_MPM_RECUEIL_RECG_type_sejour.DADM_NDA_ETAB = w_mouvements_sejour.no_sejour AND
|
|
|
w_MPM_RECUEIL_RECG_type_sejour.RECG_DATEDEBUT = w_mouvements_sejour.date AND
|
|
|
w_MPM_RECUEIL_RECG_type_sejour.nb_seances > 0;
|
|
|
|
|
|
|
|
|
-- Séances d'après GHM
|
|
|
DROP TABLE IF EXISTS w_correction_seance;
|
|
|
CREATE TEMP TABLE w_correction_seance AS
|
|
|
SELECT p_sejours.no_sejour,
|
|
|
MIN(p_mouvements_sejour.date) AS date_seance,
|
|
|
(MIN(ARRAY[p_mouvements_sejour.date::text,heure_debut::text]))[2]::numeric AS heure_seance
|
|
|
FROM activite[PX].p_sejours
|
|
|
JOIN activite[PX].t_lieux ON lieu_sortie_id = t_lieux.oid
|
|
|
JOIN activite[PX].t_services_facturation ON service_facturation_id = t_services_facturation.oid
|
|
|
LEFT JOIN w_mouvements_sejour p_mouvements_sejour ON p_sejours.no_sejour = p_mouvements_sejour.no_sejour
|
|
|
LEFT JOIN base.t_ghm ON ghm_id = t_ghm.oid
|
|
|
WHERE p_sejours.type_sejour <> '9' AND
|
|
|
(
|
|
|
t_ghm.code LIKE '28%' AND t_services_facturation.type_sejour IS DISTINCT FROM '0sauf5' OR
|
|
|
t_services_facturation.type_sejour = '5'
|
|
|
)
|
|
|
GROUP BY 1
|
|
|
HAVING
|
|
|
(
|
|
|
SUM(nb_seances) = 0
|
|
|
)
|
|
|
;
|
|
|
|
|
|
UPDATE w_mouvements_sejour
|
|
|
SET nb_seances = 1
|
|
|
FROM w_correction_seance
|
|
|
WHERE w_correction_seance.no_sejour = w_mouvements_sejour.no_sejour AND
|
|
|
w_correction_seance.date_seance = w_mouvements_sejour.date AND
|
|
|
w_correction_seance.heure_seance = w_mouvements_sejour.heure_debut
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Génération
|
|
|
DELETE FROM w_mouvements_sejour
|
|
|
WHERE
|
|
|
nb_entrees_directes = 0 AND
|
|
|
nb_sorties_directes = 0 AND
|
|
|
est_jour_hospitalisation <> '1' AND
|
|
|
nb_ambulatoires = 0 AND
|
|
|
nb_externes = 0 AND
|
|
|
nb_urgences = 0 AND
|
|
|
nb_seances = 0 AND
|
|
|
nb_entrees_mutation_service = 0 AND
|
|
|
nb_sorties_mutation_service = 0 AND
|
|
|
nb_entrees_mutation_etage = 0 AND
|
|
|
nb_sorties_mutation_etage = 0 AND
|
|
|
nb_entrees_mutation_activite = 0 AND
|
|
|
nb_sorties_mutation_activite = 0 AND
|
|
|
nb_entrees_mutation_unite_medicale = 0 AND
|
|
|
nb_sorties_mutation_unite_medicale = 0 AND
|
|
|
nb_jours_js_inclus = 0 AND
|
|
|
nb_jours_js_non_inclus = 0 AND
|
|
|
est_chambre_particuliere <> '1' AND
|
|
|
nb_chambres_particulieres = 0 AND
|
|
|
nb_bebes = 0;
|
|
|
|
|
|
-- Report des journées en HDJ (type mouvement D sur mode 04 à partir de la date de démarrage CSIS
|
|
|
UPDATE w_mouvements_sejour
|
|
|
SET heure_fin = 240000
|
|
|
WHERE heure_fin = 235959
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SMV_MOUVEMENT_MVMT_fhdj;
|
|
|
CREATE TEMP TABLE w_SMV_MOUVEMENT_MVMT_fhdj AS
|
|
|
SELECT MVMT_ID_DADM,
|
|
|
DADM_NDA,
|
|
|
date(DADM_DATEDEBUT) AS DADM_DATEDEBUT,
|
|
|
date(MIN(CASE WHEN TMVT_CODE = 'D' AND OMVT_CODE <> 'I' THEN MVMT_DATEHEURE ELSE NULL END)) AS date_premier_hdj,
|
|
|
date(CASE
|
|
|
WHEN t_divers.valeur = '1'
|
|
|
THEN DADM_DATEDEBUT
|
|
|
WHEN date(MIN(MVMT_DATEHEURE)) >= date_demarrage
|
|
|
THEN MIN(MVMT_DATEHEURE)
|
|
|
WHEN date(MAX(MVMT_DATEHEURE)) >= date_demarrage
|
|
|
THEN MIN(MVMT_DATEHEURE)
|
|
|
WHEN date(MIN(CASE WHEN TMVT_CODE = 'D' AND OMVT_CODE <> 'I' THEN MVMT_DATEHEURE ELSE NULL END)) IS NULL
|
|
|
THEN date_demarrage
|
|
|
WHEN date(MIN(CASE WHEN TMVT_CODE = 'D' AND OMVT_CODE <> 'I' THEN MVMT_DATEHEURE ELSE NULL END)) - date(DADM_DATEDEBUT) <= 5
|
|
|
THEN DADM_DATEDEBUT
|
|
|
ELSE date(MIN(CASE WHEN TMVT_CODE = 'D' AND OMVT_CODE <> 'I' THEN MVMT_DATEHEURE ELSE NULL END))
|
|
|
END) AS date_demarrage_sejour
|
|
|
FROM w_SMV_MOUVEMENT_MVMT_source SMV_MOUVEMENT_MVMT
|
|
|
JOIN prod_csis.SID_DOSSIERADMINISTRATIF_DADM ON MVMT_ID_DADM = DADM_ID
|
|
|
JOIN prod_csis.SST_DISCIPINTERNE_DSNT ON MVMT_CHPNUM1 = DSNT_ID
|
|
|
JOIN activite[PX].t_services_facturation ON DSNT_ID = t_services_facturation.code_original
|
|
|
JOIN prod_csis.SNO_MODE_MODE ON DSNT_ID_MODE = MODE_ID
|
|
|
JOIN activite[PX].p_sejours ON p_sejours.code_original = DADM_ID AND etat = ''
|
|
|
JOIN prod_csis.SMV_ORDREMOUVEMENT_OMVT ON OMVT_ID = MVMT_ID_OMVT
|
|
|
JOIN w_demarrage ON 1=1
|
|
|
JOIN activite.t_divers ON t_divers.code = 'CSIS_FACHISTOHDJ'
|
|
|
WHERE SMVT_CODE <> 'A' AND
|
|
|
MODE_CODE = '04' AND
|
|
|
t_services_facturation.type_t2a = '2'
|
|
|
GROUP BY 1,2,3,DADM_DATEDEBUT, date_demarrage, t_divers.valeur
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SMV_MOUVEMENT_MVMT_hdj;
|
|
|
CREATE TEMP TABLE w_SMV_MOUVEMENT_MVMT_hdj AS
|
|
|
SELECT SMV_MOUVEMENT_MVMT.MVMT_ID_DADM,
|
|
|
SID_DOSSIERADMINISTRATIF_DADM.DADM_NDA,
|
|
|
base.cti_group_array3(date(MVMT_DATEHEURE)) AS dates_hdj
|
|
|
FROM w_SMV_MOUVEMENT_MVMT_source SMV_MOUVEMENT_MVMT
|
|
|
JOIN prod_csis.SID_DOSSIERADMINISTRATIF_DADM ON MVMT_ID_DADM = DADM_ID
|
|
|
JOIN prod_csis.SST_DISCIPINTERNE_DSNT ON MVMT_CHPNUM1 = DSNT_ID
|
|
|
JOIN prod_csis.SNO_MODE_MODE ON DSNT_ID_MODE = MODE_ID
|
|
|
JOIN activite[PX].p_sejours ON code_original = DADM_ID AND etat = ''
|
|
|
JOIN w_SMV_MOUVEMENT_MVMT_fhdj ON w_SMV_MOUVEMENT_MVMT_fhdj.MVMT_ID_DADM = SMV_MOUVEMENT_MVMT.MVMT_ID_DADM AND
|
|
|
MVMT_DATEHEURE >= date_demarrage_sejour
|
|
|
WHERE TMVT_CODE = 'D' AND
|
|
|
SMVT_CODE <> 'A' AND
|
|
|
MODE_CODE = '04'
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_mouvements_hdj;
|
|
|
CREATE TEMP TABLE w_mouvements_hdj AS
|
|
|
SELECT p_mouvements_sejour.no_sejour, date, heure_debut, heure_fin,
|
|
|
CASE
|
|
|
WHEN est_jour_entree <> '1' AND
|
|
|
p_mouvements_sejour.date = ANY(dates_hdj) AND
|
|
|
(heure_fin = 240000 OR nb_sorties_directes = 1 OR est_dernier_mouvement_jour = '1')
|
|
|
THEN 1
|
|
|
WHEN est_jour_entree = '1' AND
|
|
|
p_mouvements_sejour.date = ANY(dates_hdj) AND
|
|
|
(nb_entrees_directes = 1)
|
|
|
THEN 1
|
|
|
ELSE 0 END AS ok_hdj
|
|
|
FROM w_mouvements_sejour p_mouvements_sejour
|
|
|
JOIN activite[PX].p_sejours ON p_mouvements_sejour.no_sejour = p_sejours.no_sejour AND type_sejour = '1'
|
|
|
JOIN w_SMV_MOUVEMENT_MVMT_hdj ON w_SMV_MOUVEMENT_MVMT_hdj.MVMT_ID_DADM = p_sejours.code_original
|
|
|
JOIN w_SMV_MOUVEMENT_MVMT_fhdj ON w_SMV_MOUVEMENT_MVMT_fhdj.MVMT_ID_DADM = p_sejours.code_original AND
|
|
|
date >= date_demarrage_sejour;
|
|
|
|
|
|
|
|
|
UPDATE w_mouvements_sejour p_mouvements_sejour SET
|
|
|
heure_fin = CASE WHEN p_mouvements_sejour.nb_sorties_directes <> 1 THEN 190000 ELSE p_mouvements_sejour.heure_fin END,
|
|
|
est_dernier_mouvement_jour = '1'
|
|
|
FROM w_mouvements_hdj
|
|
|
WHERE w_mouvements_hdj.no_sejour = p_mouvements_sejour.no_sejour AND
|
|
|
w_mouvements_hdj.date = p_mouvements_sejour.date AND
|
|
|
w_mouvements_hdj.heure_debut = p_mouvements_sejour.heure_debut AND
|
|
|
ok_hdj = 1;
|
|
|
|
|
|
DELETE
|
|
|
FROM w_mouvements_sejour p_mouvements_sejour
|
|
|
USING w_mouvements_hdj
|
|
|
WHERE w_mouvements_hdj.no_sejour = p_mouvements_sejour.no_sejour AND
|
|
|
w_mouvements_hdj.date = p_mouvements_sejour.date AND
|
|
|
w_mouvements_hdj.heure_debut = p_mouvements_sejour.heure_debut AND
|
|
|
ok_hdj = 0 AND
|
|
|
nb_entrees_directes <> 1 AND
|
|
|
nb_sorties_directes <> 1 ;
|
|
|
|
|
|
|
|
|
-- Mise en production des mouvements
|
|
|
|
|
|
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_premier_mouvement_jour, est_dernier_mouvement_jour,
|
|
|
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_premier_mouvement_jour, est_dernier_mouvement_jour,
|
|
|
est_mouvement_previsionnel
|
|
|
FROM w_mouvements_sejour
|
|
|
WHERE heure_fin >= heure_debut
|
|
|
ORDER BY no_sejour, sequence;
|
|
|
|
|
|
UPDATE activite[PX].p_sejours
|
|
|
SET type_sejour = '5'
|
|
|
WHERE type_sejour <> '5' AND
|
|
|
type_sejour <> '1' 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
|
|
|
);
|
|
|
|
|
|
UPDATE activite[PX].p_sejours
|
|
|
SET code_sorti = '1'
|
|
|
FROM activite[PX].p_mouvements_sejour
|
|
|
WHERE p_sejours.no_sejour = p_mouvements_sejour.no_sejour AND
|
|
|
code_sorti = '0' AND
|
|
|
(nb_ambulatoires > 0 OR nb_externes > 0) AND
|
|
|
date_sortie <= now();
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="FACTURE" label="RECUPERATION DES FACTURES">
|
|
|
|
|
|
<NODE label="Entêtes">
|
|
|
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Interrogation écritures comptabilisées pour définir compte (attention version de MedSphere)
|
|
|
DROP TABLE IF EXISTS w_MPM_CPTAVENTEPRESTATION_CPVP;
|
|
|
|
|
|
SELECT base.cti_execute(
|
|
|
'
|
|
|
CREATE TEMP TABLE w_MPM_CPTAVENTEPRESTATION_CPVP AS
|
|
|
SELECT RECG_ID AS CPVP_ID_RECG,
|
|
|
RECG_ID_PRTB AS CPVP_ID_PRTB,
|
|
|
MAX(COALESCE(CPVP_COMPTE,'''')) AS CPVP_COMPTE,
|
|
|
count(DISTINCT CPVP_COMPTE)
|
|
|
FROM prod_csis.MPM_RECUEIL_RECG
|
|
|
LEFT JOIN prod_csis.MPM_CPTAVENTEPRESTATION_CPVP ON CPVP_ID_RECG = RECG_ID
|
|
|
WHERE (CPVP_COMPTE NOT LIKE ''41%'' AND CPVP_COMPTE NOT LIKE ''445%'' AND CPVP_DATECLOTURE IS NOT NULL) OR CPVP_ID IS NULL
|
|
|
GROUP BY 1,2
|
|
|
',1)
|
|
|
WHERE 'cpvp_id_recg' IN (SELECT column_name FROM information_schema.columns WHERE table_name = 'mpm_cptaventeprestation_cpvp');
|
|
|
|
|
|
SELECT base.cti_execute(
|
|
|
'
|
|
|
CREATE TEMP TABLE w_MPM_CPTAVENTEPRESTATION_CPVP AS
|
|
|
SELECT RECG_ID AS CPVP_ID_RECG,
|
|
|
RECG_ID_PRTB AS CPVP_ID_PRTB,
|
|
|
''''::text AS CPVP_COMPTE
|
|
|
FROM prod_csis.MPM_RECUEIL_RECG
|
|
|
GROUP BY 1,2
|
|
|
',1)
|
|
|
WHERE 'cpvp_id_recg' NOT IN (SELECT column_name FROM information_schema.columns WHERE table_name = 'mpm_cptaventeprestation_cpvp');
|
|
|
|
|
|
ALTER TABLE w_MPM_CPTAVENTEPRESTATION_CPVP
|
|
|
ADD CONSTRAINT w_MPM_CPTAVENTEPRESTATION_CPVP_pkey PRIMARY KEY(CPVP_ID_RECG);
|
|
|
|
|
|
-- Si pas encore comptabilisé, voir paramétrage
|
|
|
UPDATE w_MPM_CPTAVENTEPRESTATION_CPVP
|
|
|
SET CPVP_COMPTE = CGRD_COMPTECG
|
|
|
FROM prod_csis.SST_CPTAGRILLEDETAIL_CGRD
|
|
|
WHERE CPVP_COMPTE = '' AND
|
|
|
CPVP_ID_PRTB = CGRD_ID_PRTB AND
|
|
|
CGRD_COMPTECG <> '' AND
|
|
|
CGRD_ID_PRTB <> 0;
|
|
|
|
|
|
-- Nouveaux comptes
|
|
|
INSERT INTO activite[PX].t_compte(code_original, code, texte, texte_court)
|
|
|
SELECT CCPT_CODE,CCPT_CODE, MAX(CCPT_LIBELLE), MAX(CCPT_LIBELLECOURT)
|
|
|
FROM prod_csis.SST_CPTACOMPTE_CCPT
|
|
|
WHERE CCPT_CODE <> '' AND
|
|
|
CCPT_CODE NOT IN (SELECT code_original FROM activite[PX].t_compte WHERE code IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO activite[PX].t_compte(code_original, code, texte, texte_court)
|
|
|
SELECT CPTF_COMPTE,CPTF_COMPTE, MAX(CPTF_COMPTE), MAX(CPTF_COMPTE)
|
|
|
FROM prod_csis.SCP_CPTATRANSFERT_CPTF
|
|
|
WHERE CPTF_COMPTE <> '' AND
|
|
|
CPTF_COMPTE NOT IN (SELECT code_original FROM activite[PX].t_compte WHERE code IS NOT NULL)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
UPDATE activite[PX].t_compte
|
|
|
SET texte = CCPT_LIBELLE, texte_court = CCPT_LIBELLECOURT
|
|
|
FROM prod_csis.SST_CPTACOMPTE_CCPT
|
|
|
WHERE code = texte AND
|
|
|
CCPT_CODE = t_compte.code
|
|
|
;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MPM_FACTURE_RECF ;
|
|
|
CREATE TEMP TABLE w_MPM_FACTURE_RECF AS
|
|
|
SELECT
|
|
|
*,
|
|
|
date(RECF_DATEFACTDEB) AS MPM_DATE_FACTURE,
|
|
|
date(RECF_DATEFACTDEB) AS MPM_DATE_VALIDATION,
|
|
|
date(RECF_DATEFACTDEB) AS MPM_DATE_VENTE,
|
|
|
RECF_NUMFACTALIAS::text AS RECF_NUMFACTALIAS_ETAB
|
|
|
FROM prod_csis.MPM_FACTURE_RECF ;
|
|
|
|
|
|
-- Prise en compte factures non validées
|
|
|
UPDATE w_MPM_FACTURE_RECF
|
|
|
SET MPM_DATE_VALIDATION = date(RECF_DATEGENERATION),
|
|
|
MPM_DATE_FACTURE = date(RECF_DATEGENERATION)
|
|
|
FROM activite.t_divers
|
|
|
WHERE t_divers.code = 'CSIS_FACNVAL' AND
|
|
|
t_divers.valeur = '1' AND
|
|
|
MPM_DATE_FACTURE IS NULL;
|
|
|
|
|
|
UPDATE w_MPM_FACTURE_RECF
|
|
|
SET MPM_DATE_FACTURE = date(RECF_DATEGENERATION)
|
|
|
FROM activite.t_divers
|
|
|
WHERE t_divers.code = 'CSIS_FACNVAL' AND
|
|
|
t_divers.valeur = '2' AND
|
|
|
MPM_DATE_FACTURE IS NULL;
|
|
|
|
|
|
UPDATE w_MPM_FACTURE_RECF
|
|
|
SET MPM_DATE_VENTE = date(CPCL_DATEFIN)
|
|
|
FROM activite.t_divers,
|
|
|
prod_csis.SCP_CPTACLOTURE_CPCL
|
|
|
WHERE t_divers.code = 'CSIS_FACDATVEN' AND
|
|
|
t_divers.valeur = '1' AND
|
|
|
RECF_ID_CPCL = CPCL_ID AND
|
|
|
RECF_ID_CPCL <> 0;
|
|
|
|
|
|
UPDATE w_MPM_FACTURE_RECF
|
|
|
SET MPM_DATE_VENTE = date(CPCL_DATEFIN)
|
|
|
FROM activite.t_divers,
|
|
|
prod_csis.SCP_CPTACLOTURE_CPCL
|
|
|
WHERE t_divers.code = 'CSIS_FACDATVEN' AND
|
|
|
t_divers.valeur = '1' AND
|
|
|
RECF_ID2_CPCL = CPCL_ID AND
|
|
|
RECF_ID2_CPCL <> 0;
|
|
|
|
|
|
-- Si facture non validée, raz dates
|
|
|
-- UPDATE w_MPM_FACTURE_RECF
|
|
|
-- SET MPM_DATE_VENTE = NULL,
|
|
|
-- MPM_DATE_FACTURE = NULL,
|
|
|
-- MPM_DATE_VALIDATION = NULL
|
|
|
-- WHERE RECF_STATUT <> 'V'
|
|
|
-- ;
|
|
|
|
|
|
UPDATE w_MPM_FACTURE_RECF
|
|
|
SET RECF_NUMFACTALIAS_ETAB = w_MPM_FACTURE_RECF.RECF_NUMFACTALIAS_ETAB || '-' || ETAB_PREFIX
|
|
|
FROM
|
|
|
(
|
|
|
SELECT RECF_NUMFACTALIAS_ETAB, count(*)
|
|
|
FROM w_MPM_FACTURE_RECF
|
|
|
GROUP BY 1
|
|
|
HAVING count(*) > 1
|
|
|
) subview,
|
|
|
w_SST_ETABLISSEMENT_ETAB
|
|
|
WHERE w_MPM_FACTURE_RECF.RECF_NUMFACTALIAS_ETAB = subview.RECF_NUMFACTALIAS_ETAB AND
|
|
|
RECF_ID_ETAB = ETAB_ID
|
|
|
;
|
|
|
|
|
|
-- Numéros de factures en double ?
|
|
|
SELECT base.cti_execute('
|
|
|
UPDATE w_MPM_FACTURE_RECF MPM_FACTURE_RECF
|
|
|
SET RECF_NUMFACTALIAS_ETAB = MPM_FACTURE_RECF.RECF_NUMFACTALIAS_ETAB || ''-''::text || nb::text
|
|
|
FROM
|
|
|
(
|
|
|
SELECT RECF_NUMFACTALIAS_ETAB, RECF_ID_ETAB, MAX(RECF_ID) AS RECF_ID_doublon, count(*) AS nb
|
|
|
FROM w_MPM_FACTURE_RECF MPM_FACTURE_RECF
|
|
|
GROUP BY 1,2
|
|
|
HAVING count(*) > 1
|
|
|
) subview
|
|
|
WHERE MPM_FACTURE_RECF.RECF_NUMFACTALIAS_ETAB = subview.RECF_NUMFACTALIAS_ETAB AND
|
|
|
MPM_FACTURE_RECF.RECF_ID_ETAB = subview.RECF_ID_ETAB AND
|
|
|
MPM_FACTURE_RECF.RECF_ID = RECF_ID_doublon
|
|
|
',10)
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MPM_RECUEILTIERS_RECT;
|
|
|
CREATE TEMP TABLE w_MPM_RECUEILTIERS_RECT AS
|
|
|
SELECT
|
|
|
DADM_ID,
|
|
|
DADM_ID_ETAB,
|
|
|
DADM_NDA_ETAB,
|
|
|
RECF_ID,
|
|
|
RECF_NUMFACTALIAS_ETAB,
|
|
|
ASSU_ID,
|
|
|
ASSU_TYPE,
|
|
|
ASSU_DISTINCTIF,
|
|
|
CASE WHEN ASSU_TYPE = 'O' THEN RECT_ID_ORGN ELSE 0 END as ASSU_ID_ORGN_1,
|
|
|
CASE WHEN ASSU_TYPE = 'C' AND ASSU_DISTINCTIF = 1 THEN RECT_ID_ORGN ELSE 0 END as ASSU_ID_ORGN_2,
|
|
|
CASE WHEN ASSU_TYPE = 'C' AND ASSU_DISTINCTIF <> 1 THEN RECT_ID_ORGN ELSE 0 END as ASSU_ID_ORGN_22,
|
|
|
CASE WHEN SNO_ETATRECUEIL_ETRC_RECT.ETRC_CODE <> 'A' OR SNO_ETATRECUEIL_ETRC_RECT.ETRC_CODE = 'A' AND RECT_ANNULEPARAVOIR = 1 THEN 1 ELSE 0 END::int AS RECT_OKFACTURE,
|
|
|
CASE WHEN SNO_ETATRECUEIL_ETRC_RECG.ETRC_CODE <> 'A' OR SNO_ETATRECUEIL_ETRC_RECG.ETRC_CODE = 'A' AND RECG_ANNULEPARAVOIR = 1 THEN 1 ELSE 0 END::int AS RECT_OKLIGNEFACTURE,
|
|
|
MPM_RECUEILTIERS_RECT.*,
|
|
|
MPM_RECUEIL_RECG.*,
|
|
|
MPM_RECUEILCCAM_RECC.*,
|
|
|
CASE WHEN RECT_TYPEDEBITEUR = 'D' OR ASSU_ID IS NULL THEN LEAST(COALESCE(RECT_TAUXREEL,RECT_TAUXPEC), 100.00) ELSE 0 END as RECT_TAUX_0,
|
|
|
CASE WHEN ASSU_TYPE = 'O' THEN LEAST(COALESCE(RECT_TAUXREEL,RECT_TAUXPEC), 100.00) ELSE 0 END as RECT_TAUX_1,
|
|
|
CASE WHEN ASSU_TYPE = 'C' AND ASSU_DISTINCTIF = 1 THEN LEAST(COALESCE(RECT_TAUXREEL,RECT_TAUXPEC), 100.00) ELSE 0 END as RECT_TAUX_2,
|
|
|
CASE WHEN ASSU_TYPE = 'C' AND ASSU_DISTINCTIF <> 1 THEN LEAST(COALESCE(RECT_TAUXREEL,RECT_TAUXPEC), 100.00) ELSE 0 END as RECT_TAUX_22,
|
|
|
CASE WHEN (MPM_DATE_VENTE IS NOT NULL OR MPM_DATE_FACTURE IS NOT NULL) THEN RECT_MONTANT ELSE 0 END AS RECT_MONTANT_FAC,
|
|
|
CASE WHEN (MPM_DATE_VENTE IS NOT NULL OR MPM_DATE_FACTURE IS NOT NULL) AND (RECT_TYPEDEBITEUR = 'D' OR ASSU_ID IS NULL) THEN RECT_MONTANT ELSE 0 END as RECT_MONTANT_FAC_0,
|
|
|
CASE WHEN (MPM_DATE_VENTE IS NOT NULL OR MPM_DATE_FACTURE IS NOT NULL) AND ASSU_TYPE = 'O' THEN RECT_MONTANT ELSE 0 END as RECT_MONTANT_FAC_1,
|
|
|
CASE WHEN (MPM_DATE_VENTE IS NOT NULL OR MPM_DATE_FACTURE IS NOT NULL) AND ASSU_TYPE = 'C' AND ASSU_DISTINCTIF = 1 THEN RECT_MONTANT ELSE 0 END as RECT_MONTANT_FAC_2,
|
|
|
CASE WHEN (MPM_DATE_VENTE IS NOT NULL OR MPM_DATE_FACTURE IS NOT NULL) AND ASSU_TYPE = 'C' AND ASSU_DISTINCTIF <> 1 THEN RECT_MONTANT ELSE 0 END as RECT_MONTANT_FAC_22,
|
|
|
CASE WHEN RECT_DOTATION IS DISTINCT FROM '1' AND MPM_DATE_VENTE IS NOT NULL THEN RECT_MONTANT ELSE 0 END as RECT_MONTANT_CPT,
|
|
|
CASE WHEN RECT_DOTATION IS DISTINCT FROM '1' AND MPM_DATE_VENTE IS NOT NULL AND (RECT_TYPEDEBITEUR = 'D' OR ASSU_ID IS NULL) THEN RECT_MONTANT ELSE 0 END as RECT_MONTANT_CPT_0,
|
|
|
CASE WHEN RECT_DOTATION IS DISTINCT FROM '1' AND MPM_DATE_VENTE IS NOT NULL AND ASSU_TYPE = 'O' THEN RECT_MONTANT ELSE 0 END as RECT_MONTANT_CPT_1,
|
|
|
CASE WHEN RECT_DOTATION IS DISTINCT FROM '1' AND MPM_DATE_VENTE IS NOT NULL AND ASSU_TYPE = 'C' AND ASSU_DISTINCTIF = 1 THEN RECT_MONTANT ELSE 0 END as RECT_MONTANT_CPT_2,
|
|
|
CASE WHEN RECT_DOTATION IS DISTINCT FROM '1' AND MPM_DATE_VENTE IS NOT NULL AND ASSU_TYPE = 'C' AND ASSU_DISTINCTIF <> 1 THEN RECT_MONTANT ELSE 0 END as RECT_MONTANT_CPT_22,
|
|
|
RECT_MONTANTREGLE AS RECT_MONTANT_REG,
|
|
|
CASE WHEN RECT_TYPEDEBITEUR = 'D' OR ASSU_ID IS NULL THEN RECT_MONTANTREGLE ELSE 0 END as RECT_MONTANT_REG_0,
|
|
|
CASE WHEN ASSU_TYPE = 'O' THEN RECT_MONTANTREGLE ELSE 0 END as RECT_MONTANT_REG_1,
|
|
|
CASE WHEN ASSU_TYPE = 'C' AND ASSU_DISTINCTIF = 1 THEN RECT_MONTANTREGLE ELSE 0 END as RECT_MONTANT_REG_2,
|
|
|
CASE WHEN ASSU_TYPE = 'C' AND ASSU_DISTINCTIF <> 1 THEN RECT_MONTANTREGLE ELSE 0 END as RECT_MONTANT_REG_22,
|
|
|
|
|
|
COALESCE(CPVP_COMPTE,'') AS CPVP_COMPTE,
|
|
|
|
|
|
RECG_TYPELIGNE AS RECG_TYPELIGNE_CPTA,
|
|
|
|
|
|
RECG_TYPELIGNE || '|' ||
|
|
|
RECG_ID_PRTB || '|' ||
|
|
|
COALESCE(CPVP_COMPTE,'') || '|' ||
|
|
|
CASE WHEN RECG_TYPELIGNE = 3 THEN COALESCE(RECG_GHS,'') ELSE '' END ||
|
|
|
CASE WHEN RECG_TYPELIGNE = 4 THEN COALESCE(RECC_CODECCAM,'') ELSE '' END || '|' ||
|
|
|
CASE WHEN RECG_TYPELIGNE = 4 THEN COALESCE(RECC_ID_MEDN,RECG_ID1_MEDN) ELSE 0 END
|
|
|
AS key,
|
|
|
|
|
|
CASE WHEN ASSU_TYPE = 'O' THEN RECT_ID_ORGN ELSE 0 END || '|' ||
|
|
|
CASE WHEN ASSU_TYPE = 'C' AND ASSU_DISTINCTIF = 1 THEN RECT_ID_ORGN ELSE 0 END || '|' ||
|
|
|
CASE WHEN ASSU_TYPE = 'C' AND ASSU_DISTINCTIF <> 1 THEN RECT_ID_ORGN ELSE 0 END
|
|
|
AS keytp
|
|
|
|
|
|
FROM prod_csis.MPM_RECUEILTIERS_RECT
|
|
|
JOIN w_SID_DOSSIERADMINISTRATIF_DADM ON DADM_ID = RECT_ID_DADM
|
|
|
JOIN w_MPM_FACTURE_RECF MPM_FACTURE_RECF ON RECT_ID_RECF = RECF_ID
|
|
|
JOIN prod_csis.MPM_RECUEIL_RECG ON RECT_ID_RECG = RECG_ID
|
|
|
LEFT JOIN w_MPM_CPTAVENTEPRESTATION_CPVP ON CPVP_ID_RECG = RECG_ID
|
|
|
JOIN prod_csis.SNO_ETATRECUEIL_ETRC SNO_ETATRECUEIL_ETRC_RECT ON RECT_ID_ETRC = SNO_ETATRECUEIL_ETRC_RECT.ETRC_ID
|
|
|
JOIN prod_csis.SNO_ETATRECUEIL_ETRC SNO_ETATRECUEIL_ETRC_RECG ON RECG_ID_ETRC = SNO_ETATRECUEIL_ETRC_RECG.ETRC_ID
|
|
|
LEFT JOIN prod_csis.MPM_RECUEILCCAM_RECC ON (RECC_ID_RECG = RECG_ID)
|
|
|
LEFT JOIN prod_csis.MPE_ASSURANCE_ASSU ON (RECT_ID_ASSU = ASSU_ID);
|
|
|
|
|
|
UPDATE w_MPM_RECUEILTIERS_RECT
|
|
|
SET RECG_TYPELIGNE_CPTA = 3, RECG_TYPELIGNE = 34
|
|
|
FROM w_SST_ETABLISSEMENT_ETAB
|
|
|
WHERE DADM_ID_ETAB = ETAB_ID AND
|
|
|
ETAB_TYPE_PSPH = 1 AND
|
|
|
RECG_TYPELIGNE = 4
|
|
|
;
|
|
|
|
|
|
UPDATE w_MPM_RECUEILTIERS_RECT
|
|
|
SET RECG_TYPELIGNE_CPTA = 3
|
|
|
FROM activite[PX].t_medecins_administratifs
|
|
|
WHERE RECG_TYPELIGNE = 4 AND
|
|
|
(
|
|
|
t_medecins_administratifs.code_original = RECC_ID_MEDN OR
|
|
|
t_medecins_administratifs.code_original = RECG_ID1_MEDN
|
|
|
) AND
|
|
|
est_medecin_salarie = 1
|
|
|
;
|
|
|
|
|
|
|
|
|
CREATE INDEX i_w_MPM_RECUEILTIERS_RECT_1
|
|
|
ON w_MPM_RECUEILTIERS_RECT
|
|
|
USING btree
|
|
|
(RECG_TYPELIGNE);
|
|
|
|
|
|
CREATE INDEX i_w_MPM_RECUEILTIERS_RECT_TYPELIGNE_CPTA
|
|
|
ON w_MPM_RECUEILTIERS_RECT
|
|
|
USING btree
|
|
|
(RECG_TYPELIGNE_CPTA);
|
|
|
|
|
|
CREATE INDEX i_w_MPM_RECUEILTIERS_RECT_2
|
|
|
ON w_MPM_RECUEILTIERS_RECT
|
|
|
USING btree
|
|
|
(RECG_ID);
|
|
|
|
|
|
CREATE INDEX i_w_MPM_RECUEILTIERS_RECT_3
|
|
|
ON w_MPM_RECUEILTIERS_RECT
|
|
|
USING btree
|
|
|
(key);
|
|
|
|
|
|
CREATE INDEX i_w_MPM_RECUEILTIERS_RECT_4
|
|
|
ON w_MPM_RECUEILTIERS_RECT
|
|
|
USING btree
|
|
|
(keytp);
|
|
|
|
|
|
CREATE INDEX i_w_MPM_RECUEILTIERS_RECG_ID
|
|
|
ON w_MPM_RECUEILTIERS_RECT
|
|
|
USING btree
|
|
|
(RECG_ID);
|
|
|
|
|
|
ANALYSE w_MPM_RECUEILTIERS_RECT
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MPM_RECUEILTIERS_RECT_keys;
|
|
|
CREATE TEMP TABLE w_MPM_RECUEILTIERS_RECT_keys AS
|
|
|
SELECT
|
|
|
key,
|
|
|
MAX(RECG_TYPELIGNE) AS key_TYPELIGNE,
|
|
|
MAX(RECG_ID_PRTB) AS key_ID_PRTB,
|
|
|
MAX(CPVP_COMPTE) AS key_COMPTE,
|
|
|
MAX(CASE WHEN RECG_TYPELIGNE IN (3,34) THEN RECG_GHS ELSE '' END) AS key_GHS,
|
|
|
MAX(CASE WHEN RECG_TYPELIGNE IN (4,34) THEN COALESCE(RECC_CODECCAM,'') ELSE '' END) AS key_CODECCAM,
|
|
|
MAX(CASE WHEN RECG_TYPELIGNE IN (4,34) THEN COALESCE(RECC_ID_MEDN,RECG_ID1_MEDN) ELSE 0 END) AS key_ID_MEDN,
|
|
|
''::text AS acte_ngap_code_original,
|
|
|
0::bigint AS rubrique_facturation_id,
|
|
|
0::bigint AS prestation_id,
|
|
|
0::bigint AS compte_produit_id,
|
|
|
0::bigint AS ghs_id,
|
|
|
0::bigint AS acte_id,
|
|
|
0::bigint AS medecin_id
|
|
|
FROM w_MPM_RECUEILTIERS_RECT
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
UPDATE w_MPM_RECUEILTIERS_RECT_keys
|
|
|
SET rubrique_facturation_id = w_SST_PRESTATIONETAB_PRTB.rubrique_facturation_id
|
|
|
FROM w_SST_PRESTATIONETAB_PRTB
|
|
|
WHERE key_ID_PRTB = PRTB_ID
|
|
|
;
|
|
|
|
|
|
UPDATE w_MPM_RECUEILTIERS_RECT_keys
|
|
|
SET prestation_id = t_prestations.oid ,
|
|
|
acte_ngap_code_original = PRES_CODE
|
|
|
FROM w_SST_PRESTATIONETAB_PRTB
|
|
|
JOIN prod_csis.SST_PRESTATION_PRES ON PRTB_ID_PRES = PRES_ID
|
|
|
JOIN activite.t_prestations ON PRES_CODE = t_prestations.code
|
|
|
WHERE key_ID_PRTB = PRTB_ID;
|
|
|
|
|
|
UPDATE w_MPM_RECUEILTIERS_RECT_keys
|
|
|
SET compte_produit_id = t_compte.oid
|
|
|
FROM activite[PX].t_compte
|
|
|
WHERE key_COMPTE = t_compte.code;
|
|
|
|
|
|
UPDATE w_MPM_RECUEILTIERS_RECT_keys
|
|
|
SET ghs_id = t_ghs.oid
|
|
|
FROM base.t_ghs
|
|
|
WHERE key_TYPELIGNE = 3 AND key_GHS <> '' AND key_GHS <> '0' AND to_number('0' || key_GHS,'00000') = t_ghs.code;
|
|
|
|
|
|
INSERT INTO base.t_actes(code,texte,texte_court,nomenclature)
|
|
|
SELECT CASE WHEN key_CODECCAM <> '' THEN substring(key_CODECCAM, 1, 7) ELSE acte_ngap_code_original END,
|
|
|
CASE WHEN key_CODECCAM <> '' THEN substring(key_CODECCAM, 1, 7) ELSE acte_ngap_code_original END,
|
|
|
CASE WHEN key_CODECCAM <> '' THEN substring(key_CODECCAM, 1, 7) ELSE acte_ngap_code_original END,
|
|
|
CASE WHEN key_CODECCAM <> '' THEN 'CCAM' ELSE 'NGAP' END
|
|
|
FROM w_MPM_RECUEILTIERS_RECT_keys
|
|
|
WHERE key_TYPELIGNE IN (4,34) AND CASE WHEN key_CODECCAM <> '' THEN substring(key_CODECCAM, 1, 7) ELSE acte_ngap_code_original END NOT IN (SELECT code FROM base.t_actes WHERE code IS NOT NULL)
|
|
|
GROUP BY 1,2,3,4;
|
|
|
|
|
|
|
|
|
UPDATE w_MPM_RECUEILTIERS_RECT_keys
|
|
|
SET acte_id = t_actes.oid
|
|
|
FROM base.t_actes
|
|
|
WHERE key_TYPELIGNE IN (4,34) AND CASE WHEN key_CODECCAM <> '' THEN substring(key_CODECCAM, 1, 7) ELSE acte_ngap_code_original END = t_actes.code;
|
|
|
|
|
|
UPDATE w_MPM_RECUEILTIERS_RECT_keys
|
|
|
SET medecin_id = t_medecins_administratifs.oid
|
|
|
FROM activite[PX].t_medecins_administratifs
|
|
|
WHERE key_TYPELIGNE IN (4,34) AND t_medecins_administratifs.code_original = key_ID_MEDN;
|
|
|
|
|
|
|
|
|
ALTER TABLE w_MPM_RECUEILTIERS_RECT_keys
|
|
|
ADD CONSTRAINT w_MPM_RECUEILTIERS_RECT_keys_pkey PRIMARY KEY(key);
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MPM_RECUEILTIERS_RECT_keystp;
|
|
|
CREATE TEMP TABLE w_MPM_RECUEILTIERS_RECT_keystp AS
|
|
|
SELECT
|
|
|
keytp,
|
|
|
ASSU_ID_ORGN_1,
|
|
|
ASSU_ID_ORGN_2,
|
|
|
ASSU_ID_ORGN_22,
|
|
|
|
|
|
0::bigint AS tiers_payant_0_id,
|
|
|
0::bigint AS tiers_payant_1_id,
|
|
|
0::bigint AS tiers_payant_2_id,
|
|
|
0::bigint AS tiers_payant_22_id
|
|
|
FROM w_MPM_RECUEILTIERS_RECT
|
|
|
GROUP BY 1,2,3,4;
|
|
|
|
|
|
|
|
|
UPDATE w_MPM_RECUEILTIERS_RECT_keystp
|
|
|
SET tiers_payant_0_id = (SELECT MIN(oid) FROM activite[PX].t_tiers_payant WHERE code = 'PATIENTS');
|
|
|
|
|
|
UPDATE w_MPM_RECUEILTIERS_RECT_keystp
|
|
|
SET tiers_payant_1_id = t_tiers_payant.oid
|
|
|
FROM activite[PX].t_tiers_payant
|
|
|
WHERE ASSU_ID_ORGN_1 = t_tiers_payant.code_original;
|
|
|
|
|
|
UPDATE w_MPM_RECUEILTIERS_RECT_keystp
|
|
|
SET tiers_payant_2_id = t_tiers_payant.oid
|
|
|
FROM activite[PX].t_tiers_payant
|
|
|
WHERE ASSU_ID_ORGN_2 = t_tiers_payant.code_original;
|
|
|
|
|
|
UPDATE w_MPM_RECUEILTIERS_RECT_keystp
|
|
|
SET tiers_payant_22_id = t_tiers_payant.oid
|
|
|
FROM activite[PX].t_tiers_payant
|
|
|
WHERE ASSU_ID_ORGN_22 = t_tiers_payant.code_original;
|
|
|
|
|
|
ALTER TABLE w_MPM_RECUEILTIERS_RECT_keystp
|
|
|
ADD CONSTRAINT w_MPM_RECUEILTIERS_RECT_keystp_pkey PRIMARY KEY(keytp);
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MPM_FACTURE_RECF_exp;
|
|
|
CREATE TEMP TABLE w_MPM_FACTURE_RECF_exp AS
|
|
|
SELECT
|
|
|
RECF_ID,
|
|
|
MAX(CASE WHEN ETRC_CODE <> 'A' AND ASSU_TYPE = 'O' AND RECB_DATEENVOI IS NOT NULL THEN '1' ELSE '0' END) as code_expedie_1,
|
|
|
MAX(CASE WHEN ETRC_CODE <> 'A' AND ASSU_TYPE = 'C' AND RECB_DATEENVOI IS NOT NULL AND ASSU_DISTINCTIF = 1 THEN '1' ELSE '0' END) as code_expedie_2,
|
|
|
MAX(CASE WHEN ETRC_CODE <> 'A' AND ASSU_TYPE = 'C' AND RECB_DATEENVOI IS NOT NULL AND ASSU_DISTINCTIF <> 1 THEN '1' ELSE '0' END) as code_expedie_22,
|
|
|
MAX(CASE WHEN ETRC_CODE <> 'A' AND (RECB_TYPEDEBITEUR = 'D' OR ASSU_ID IS NULL) AND RECB_DATEENVOI IS NOT NULL THEN '1' ELSE '0' END) as code_expedie_0,
|
|
|
MAX(CASE WHEN ETRC_CODE <> 'A' AND ASSU_TYPE = 'O' THEN RECB_DATEENVOI ELSE null END) as date_expedition_1,
|
|
|
MAX(CASE WHEN ETRC_CODE <> 'A' AND ASSU_TYPE = 'C' AND ASSU_DISTINCTIF = 1 THEN RECB_DATEENVOI ELSE null END) as date_expedition_2,
|
|
|
MAX(CASE WHEN ETRC_CODE <> 'A' AND ASSU_TYPE = 'C' AND ASSU_DISTINCTIF <> 1 THEN RECB_DATEENVOI ELSE null END) as date_expedition_22,
|
|
|
MAX(CASE WHEN ETRC_CODE <> 'A' AND (RECB_TYPEDEBITEUR = 'D' OR ASSU_ID IS NULL) THEN RECB_DATEENVOI ELSE null END) as date_expedition_0,
|
|
|
MAX(CASE WHEN ETRC_CODE <> 'A' AND ASSU_TYPE = 'O' THEN RECB_NOBORD ELSE null END) as no_bordereau_1,
|
|
|
MAX(CASE WHEN ETRC_CODE <> 'A' AND ASSU_TYPE = 'C' AND ASSU_DISTINCTIF = 1 THEN RECB_NOBORD ELSE null END) as no_bordereau_2,
|
|
|
MAX(CASE WHEN ETRC_CODE <> 'A' AND ASSU_TYPE = 'C' AND ASSU_DISTINCTIF <> 1 THEN RECB_NOBORD ELSE null END) as no_bordereau_22,
|
|
|
MAX(CASE WHEN ETRC_CODE <> 'A' AND (RECB_TYPEDEBITEUR = 'D' OR ASSU_ID IS NULL) THEN RECB_NOBORD ELSE null END) as no_bordereau_0
|
|
|
FROM w_MPM_FACTURE_RECF MPM_FACTURE_RECF
|
|
|
JOIN prod_csis.MPM_BORDEREAU_RECB ON RECB_ID_RECF = RECF_ID
|
|
|
JOIN prod_csis.SNO_ETATRECUEIL_ETRC ON RECB_ID_ETRC = ETRC_id
|
|
|
JOIN w_SID_DOSSIERADMINISTRATIF_DADM ON RECF_ID_DADM = DADM_ID
|
|
|
LEFT JOIN prod_csis.MPE_ASSURANCE_ASSU ON (RECB_ID_ASSU = ASSU_ID)
|
|
|
GROUP BY RECF_ID
|
|
|
ORDER BY 1;
|
|
|
|
|
|
ALTER TABLE w_MPM_FACTURE_RECF_exp
|
|
|
ADD CONSTRAINT w_MPM_FACTURE_RECF_exp_pk_recf_id PRIMARY KEY(RECF_ID);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MPM_FACTURE_RECF_fac;
|
|
|
CREATE TEMP TABLE w_MPM_FACTURE_RECF_fac AS
|
|
|
SELECT
|
|
|
RECF_ID,
|
|
|
MAX(CASE WHEN RECG_PRESTATION = 'GHS' AND RECG_TYPEGHS = 'P' THEN ghs_id ELSE 0 END) as ghs_id,
|
|
|
MAX(CASE WHEN RECG_PRESTATION IN ('SE1', 'SE2', 'SE3', 'SE4','SE5', 'SE6', 'SE7') THEN RECG_PRESTATION ELSE null END) as RECG_PRESTATION_SEx,
|
|
|
MAX(tiers_payant_0_id) as tiers_payant_0_id,
|
|
|
MAX(tiers_payant_1_id) as tiers_payant_1_id,
|
|
|
MAX(tiers_payant_2_id) as tiers_payant_2_id,
|
|
|
MAX(tiers_payant_22_id) as tiers_payant_22_id,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (3,34) AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_FAC ELSE 0 END) as montant_facture_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (3,34) AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_FAC_1 ELSE 0 END) as montant_facture_1_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (3,34) AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_FAC_2 ELSE 0 END) as montant_facture_2_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (3,34) AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_FAC_22 ELSE 0 END) as montant_facture_22_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (3,34) AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_FAC_0 ELSE 0 END) as montant_facture_0_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (4,34) AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_FAC ELSE 0 END) as montant_facture_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (4,34) AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_FAC_1 ELSE 0 END) as montant_facture_1_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (4,34) AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_FAC_2 ELSE 0 END) as montant_facture_2_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (4,34) AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_FAC_22 ELSE 0 END) as montant_facture_22_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (4,34) AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_FAC_0 ELSE 0 END) as montant_facture_0_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_CPT ELSE 0 END) as montant_comptabilise_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_CPT_1 ELSE 0 END) as montant_comptabilise_1_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_CPT_2 ELSE 0 END) as montant_comptabilise_2_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_CPT_22 ELSE 0 END) as montant_comptabilise_22_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_CPT_0 ELSE 0 END) as montant_comptabilise_0_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_CPT ELSE 0 END) as montant_comptabilise_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_CPT_1 ELSE 0 END) as montant_comptabilise_1_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_CPT_2 ELSE 0 END) as montant_comptabilise_2_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_CPT_22 ELSE 0 END) as montant_comptabilise_22_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 THEN RECT_MONTANT_CPT_0 ELSE 0 END) as montant_comptabilise_0_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 THEN RECT_MONTANT_REG ELSE 0 END) as montant_regle_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 THEN RECT_MONTANT_REG_1 ELSE 0 END) as montant_regle_1_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 THEN RECT_MONTANT_REG_2 ELSE 0 END) as montant_regle_2_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 THEN RECT_MONTANT_REG_22 ELSE 0 END) as montant_regle_22_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 THEN RECT_MONTANT_REG_0 ELSE 0 END) as montant_regle_0_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 THEN RECT_MONTANT_REG ELSE 0 END) as montant_regle_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 THEN RECT_MONTANT_REG_1 ELSE 0 END) as montant_regle_1_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 THEN RECT_MONTANT_REG_2 ELSE 0 END) as montant_regle_2_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 THEN RECT_MONTANT_REG_22 ELSE 0 END) as montant_regle_22_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 THEN RECT_MONTANT_REG_0 ELSE 0 END) as montant_regle_0_h
|
|
|
FROM w_MPM_RECUEILTIERS_RECT
|
|
|
JOIN w_MPM_RECUEILTIERS_RECT_keys ON w_MPM_RECUEILTIERS_RECT.key = w_MPM_RECUEILTIERS_RECT_keys.key
|
|
|
JOIN w_MPM_RECUEILTIERS_RECT_keystp ON w_MPM_RECUEILTIERS_RECT.keytp = w_MPM_RECUEILTIERS_RECT_keystp.keytp
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
ALTER TABLE w_MPM_FACTURE_RECF_fac
|
|
|
ADD CONSTRAINT w_MPM_FACTURE_RECF_fac_pk_recf_id PRIMARY KEY(RECF_ID);
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MPM_FACTURE_RECF_reg;
|
|
|
CREATE TEMP TABLE w_MPM_FACTURE_RECF_reg AS
|
|
|
SELECT
|
|
|
RECF_ID,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 AND ASSU_TYPE = 'O' THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_1_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 AND ASSU_TYPE = 'C' AND ASSU_DISTINCTIF = 1 THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_2_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 AND ASSU_TYPE = 'C' AND ASSU_DISTINCTIF <> 1 THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_22_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 AND (RECT_TYPEDEBITEUR = 'D' OR ASSU_ID IS NULL) THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_0_c,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 AND ASSU_TYPE = 'O' THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_1_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 AND ASSU_TYPE = 'C' AND ASSU_DISTINCTIF = 1 THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_2_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 AND ASSU_TYPE = 'C' AND ASSU_DISTINCTIF <> 1 THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_22_h,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 AND (RECT_TYPEDEBITEUR = 'D' OR ASSU_ID IS NULL) THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_0_h,
|
|
|
|
|
|
MAX(CASE WHEN RECG_TYPELIGNE_CPTA = 3 AND ASSU_TYPE = 'O' THEN REGD_DATEENCAIS ELSE null END) as date_dernier_reglement_1_c,
|
|
|
MAX(CASE WHEN RECG_TYPELIGNE_CPTA = 3 AND ASSU_TYPE = 'C' AND ASSU_DISTINCTIF = 1 THEN REGD_DATEENCAIS ELSE NULL END) as date_dernier_reglement_2_c,
|
|
|
MAX(CASE WHEN RECG_TYPELIGNE_CPTA = 3 AND ASSU_TYPE = 'C' AND ASSU_DISTINCTIF <> 1 THEN REGD_DATEENCAIS ELSE NULL END) as date_dernier_reglement_22_c,
|
|
|
MAX(CASE WHEN RECG_TYPELIGNE_CPTA = 3 AND (RECT_TYPEDEBITEUR = 'D' OR ASSU_ID IS NULL) THEN REGD_DATEENCAIS ELSE NULL END) as date_dernier_reglement_0_c,
|
|
|
MAX(CASE WHEN RECG_TYPELIGNE_CPTA = 4 AND ASSU_TYPE = 'O' THEN REGD_DATEENCAIS ELSE null END) as date_dernier_reglement_1_h,
|
|
|
MAX(CASE WHEN RECG_TYPELIGNE_CPTA = 4 AND ASSU_TYPE = 'C' AND ASSU_DISTINCTIF = 1 THEN REGD_DATEENCAIS ELSE NULL END) as date_dernier_reglement_2_h,
|
|
|
MAX(CASE WHEN RECG_TYPELIGNE_CPTA = 4 AND ASSU_TYPE = 'C' AND ASSU_DISTINCTIF <> 1 THEN REGD_DATEENCAIS ELSE NULL END) as date_dernier_reglement_22_h,
|
|
|
MAX(CASE WHEN RECG_TYPELIGNE_CPTA = 4 AND (RECT_TYPEDEBITEUR = 'D' OR ASSU_ID IS NULL) THEN REGD_DATEENCAIS ELSE NULL END) as date_dernier_reglement_0_h
|
|
|
|
|
|
FROM w_MPM_RECUEILTIERS_RECT
|
|
|
JOIN prod_csis.MRC_REGLEMENTDETAIL_REGD ON REGD_ID_RECT = RECT_id
|
|
|
WHERE REGD_CODETYOP NOT IN ('AC', 'MC', 'BG')
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
ALTER TABLE w_MPM_FACTURE_RECF_reg
|
|
|
ADD CONSTRAINT w_MPM_FACTURE_RECF_reg_pk_recf_id PRIMARY KEY(RECF_ID);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MPM_FACTURE_RECF_ann;
|
|
|
CREATE TEMP TABLE w_MPM_FACTURE_RECF_ann AS
|
|
|
SELECT
|
|
|
MPM_FACTURE_RECF.RECF_ID AS RECF_ID_annulee,
|
|
|
MPM_FACTURE_RECF.RECF_NUMFACTALIAS_ETAB AS RECF_NUMFACTALIAS_ETAB_annulee,
|
|
|
MAX(MPM_FACTURE_RECF_avoir.RECF_ID) AS RECF_ID_avoir,
|
|
|
(MAX(ARRAY[MPM_FACTURE_RECF_avoir.RECF_ID::text, MPM_FACTURE_RECF_avoir.RECF_NUMFACTALIAS_ETAB]))[2] AS RECF_NUMFACTALIAS_ETAB_avoir
|
|
|
FROM w_MPM_FACTURE_RECF MPM_FACTURE_RECF
|
|
|
JOIN prod_csis.SNO_ETATRECUEIL_ETRC ON RECF_ID_ETRC = ETRC_ID AND ETRC_CODE = 'A'
|
|
|
LEFT JOIN w_MPM_FACTURE_RECF MPM_FACTURE_RECF_avoir
|
|
|
ON to_number('0' || MPM_FACTURE_RECF.recf_numfactalias , '000000000000') = MPM_FACTURE_RECF_avoir.recf_facturemere AND
|
|
|
MPM_FACTURE_RECF.RECF_ID_ETAB = MPM_FACTURE_RECF_avoir.RECF_ID_ETAB AND
|
|
|
MPM_FACTURE_RECF_avoir.recf_natureoperation = '5'
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
ALTER SEQUENCE activite[PX].s_factures RESTART WITH 1;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures;
|
|
|
CREATE TEMP TABLE w_factures AS
|
|
|
SELECT
|
|
|
nextval('activite[PX].s_factures'::regclass) AS oid,
|
|
|
DADM_NDA_ETAB as no_sejour,
|
|
|
p_sejours.oid AS sejour_id,
|
|
|
RECF_NUMFACTALIAS_ETAB AS no_facture,
|
|
|
date(RECF_DATEDEBUT) AS date_debut,
|
|
|
date(RECF_DATEFIN) AS date_fin,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_ann.RECF_NUMFACTALIAS_ETAB_avoir IS NOT NULL THEN 'X'
|
|
|
WHEN RECF_TYPEFACTURE IN ('2') THEN '2'
|
|
|
WHEN RECF_TYPEFACTURE IN ('3') THEN '2'
|
|
|
WHEN RECF_NATUREOPERATION IN ('5') THEN '1'
|
|
|
WHEN RECF_NATUREOPERATION NOT IN ('1') THEN '2'
|
|
|
ELSE '0' END AS type_facture,
|
|
|
p_sejours.code_cp_demandee,
|
|
|
CASE WHEN MPM_DATE_VENTE IS NOT NULL OR MPM_DATE_VALIDATION IS NOT NULL THEN '1' WHEN MPM_DATE_FACTURE IS NOT NULL THEN '3' ELSE '0' END AS code_facture,
|
|
|
CASE WHEN MPM_DATE_VENTE IS NOT NULL THEN date(MPM_DATE_VENTE) WHEN MPM_DATE_FACTURE IS NOT NULL THEN date(MPM_DATE_FACTURE) ELSE '20991231' END AS date_facture,
|
|
|
CASE WHEN MPM_DATE_VENTE IS NOT NULL THEN '1' ELSE '0' END AS code_vente,
|
|
|
CASE WHEN MPM_DATE_VENTE IS NOT NULL THEN date(MPM_DATE_VENTE) ELSE '20991231'::date END AS date_vente,
|
|
|
CASE WHEN MPM_DATE_VENTE IS NOT NULL THEN extract('year' FROM MPM_DATE_VENTE) * 100 + extract('month' FROM MPM_DATE_VENTE) ELSE extract('year' FROM '20991231'::date) * 100 + extract('month' FROM '20991231'::date) END AS mois_vente,
|
|
|
'0'::text as code_cloture,
|
|
|
0::numeric AS nb_rejets,
|
|
|
RECF_NUMFACTALIAS_ETAB AS no_facture_reference,
|
|
|
0::bigint AS facture_reference_id,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_ann.RECF_NUMFACTALIAS_ETAB_avoir,w_MPM_FACTURE_RECF_avo.RECF_NUMFACTALIAS_ETAB_annulee,''::text) AS no_facture_od_avoir,
|
|
|
0::bigint AS facture_od_avoir_id,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.ghs_id, p_sejours.ghs_id) AS ghs_id,
|
|
|
0::bigint AS ghs_bebe1_id,
|
|
|
0::bigint AS ghs_bebe2_id,
|
|
|
0::bigint AS ghs_bebe3_id,
|
|
|
''::text as particularite_t2a,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.tiers_payant_1_id, p_sejours.tiers_payant_1_id) AS tiers_payant_1_id,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.tiers_payant_2_id, p_sejours.tiers_payant_2_id) AS tiers_payant_2_id,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.tiers_payant_22_id, p_sejours.tiers_payant_22_id) AS tiers_payant_22_id,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.tiers_payant_0_id, p_sejours.tiers_payant_0_id) AS tiers_payant_0_id,
|
|
|
|
|
|
LEAST(w_MPM_FACTURE_RECF_exp.date_expedition_1, w_MPM_FACTURE_RECF_exp.date_expedition_2) as date_expedition,
|
|
|
w_MPM_FACTURE_RECF_exp.date_expedition_0,
|
|
|
w_MPM_FACTURE_RECF_exp.date_expedition_1,
|
|
|
w_MPM_FACTURE_RECF_exp.date_expedition_2,
|
|
|
w_MPM_FACTURE_RECF_exp.date_expedition_22,
|
|
|
w_MPM_FACTURE_RECF_exp.code_expedie_0,
|
|
|
w_MPM_FACTURE_RECF_exp.code_expedie_1,
|
|
|
w_MPM_FACTURE_RECF_exp.code_expedie_2,
|
|
|
w_MPM_FACTURE_RECF_exp.code_expedie_22,
|
|
|
w_MPM_FACTURE_RECF_exp.no_bordereau_0,
|
|
|
w_MPM_FACTURE_RECF_exp.no_bordereau_1,
|
|
|
w_MPM_FACTURE_RECF_exp.no_bordereau_2,
|
|
|
w_MPM_FACTURE_RECF_exp.no_bordereau_22,
|
|
|
|
|
|
COALESCE(
|
|
|
GREATEST(
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_0_c = 0 THEN date(RECF_DATEFIN) ELSE date_dernier_reglement_0_c END,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_0_h = 0 THEN date(RECF_DATEFIN) ELSE date_dernier_reglement_0_h END,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_1_c = 0 THEN date(RECF_DATEFIN) ELSE date_dernier_reglement_1_c END,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_1_h = 0 THEN date(RECF_DATEFIN) ELSE date_dernier_reglement_1_h END,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_2_c = 0 THEN date(RECF_DATEFIN) ELSE date_dernier_reglement_2_c END,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_2_h = 0 THEN date(RECF_DATEFIN) ELSE date_dernier_reglement_2_h END,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_22_c = 0 THEN date(RECF_DATEFIN) ELSE date_dernier_reglement_22_c END,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_22_h = 0 THEN date(RECF_DATEFIN) ELSE date_dernier_reglement_22_h END)
|
|
|
, '20991231') as date_solde,
|
|
|
COALESCE(
|
|
|
GREATEST(
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_0_c = 0 THEN date(RECF_DATEFIN) ELSE date_dernier_reglement_0_c END,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_1_c = 0 THEN date(RECF_DATEFIN) ELSE date_dernier_reglement_1_c END,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_2_c = 0 THEN date(RECF_DATEFIN) ELSE date_dernier_reglement_2_c END,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_22_c = 0 THEN date(RECF_DATEFIN) ELSE date_dernier_reglement_22_c END)
|
|
|
, '20991231') as date_solde_c,
|
|
|
|
|
|
COALESCE(
|
|
|
GREATEST(
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_0_h = 0 THEN date(RECF_DATEFIN) ELSE date_dernier_reglement_0_h END,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_1_h = 0 THEN date(RECF_DATEFIN) ELSE date_dernier_reglement_1_h END,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_2_h = 0 THEN date(RECF_DATEFIN) ELSE date_dernier_reglement_2_h END,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_22_h = 0 THEN date(RECF_DATEFIN) ELSE date_dernier_reglement_22_h END)
|
|
|
, '20991231') as date_solde_h,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_0_c = 0 THEN date(RECF_DATEFIN)
|
|
|
WHEN date_dernier_reglement_0_c IS NOT NULL THEN date_dernier_reglement_0_c ELSE '20991231' END as date_solde_0_c,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_0_h = 0 THEN date(RECF_DATEFIN)
|
|
|
WHEN date_dernier_reglement_0_h IS NOT NULL THEN date_dernier_reglement_0_h ELSE '20991231' END as date_solde_0_h,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_1_c = 0 THEN date(RECF_DATEFIN)
|
|
|
WHEN date_dernier_reglement_1_c IS NOT NULL THEN date_dernier_reglement_1_c ELSE '20991231' END as date_solde_1_c,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_1_h = 0 THEN date(RECF_DATEFIN)
|
|
|
WHEN date_dernier_reglement_1_h IS NOT NULL THEN date_dernier_reglement_1_h ELSE '20991231' END as date_solde_1_h,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_2_c = 0 THEN date(RECF_DATEFIN)
|
|
|
WHEN date_dernier_reglement_2_c IS NOT NULL THEN date_dernier_reglement_2_c ELSE '20991231' END as date_solde_2_c,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_2_h = 0 THEN date(RECF_DATEFIN)
|
|
|
WHEN date_dernier_reglement_2_h IS NOT NULL THEN date_dernier_reglement_2_h ELSE '20991231' END as date_solde_2_h,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_22_c = 0 THEN date(RECF_DATEFIN)
|
|
|
WHEN date_dernier_reglement_22_c IS NOT NULL THEN date_dernier_reglement_22_c ELSE '20991231' END as date_solde_22_c,
|
|
|
CASE
|
|
|
WHEN w_MPM_FACTURE_RECF_fac.montant_comptabilise_22_h = 0 THEN date(RECF_DATEFIN)
|
|
|
WHEN date_dernier_reglement_22_h IS NOT NULL THEN date_dernier_reglement_22_h ELSE '20991231' END as date_solde_22_h,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_facture_c,0) AS montant_facture_c,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_facture_h,0) AS montant_facture_h,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_facture_0_c,0) AS montant_facture_0_c,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_facture_0_h,0) AS montant_facture_0_h,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_facture_1_c,0) AS montant_facture_1_c,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_facture_1_h,0) AS montant_facture_1_h,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_facture_2_c,0) AS montant_facture_2_c,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_facture_2_h,0) AS montant_facture_2_h,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_facture_22_c,0) AS montant_facture_22_c,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_facture_22_h,0) AS montant_facture_22_h,
|
|
|
0::numeric AS montant_facture_c_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_h_actes_inclus_dans_sejour,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_comptabilise_c,0) AS montant_comptabilise_c,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_comptabilise_h,0) AS montant_comptabilise_h,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_comptabilise_0_c,0) AS montant_comptabilise_0_c,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_comptabilise_0_h,0) AS montant_comptabilise_0_h,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_comptabilise_1_c,0) AS montant_comptabilise_1_c,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_comptabilise_1_h,0) AS montant_comptabilise_1_h,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_comptabilise_2_c,0) AS montant_comptabilise_2_c,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_comptabilise_2_h,0) AS montant_comptabilise_2_h,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_comptabilise_22_c,0) AS montant_comptabilise_22_c,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_fac.montant_comptabilise_22_h,0) AS montant_comptabilise_22_h,
|
|
|
0::numeric AS montant_comptabilise_budget_global_c,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_reg.montant_regle_c,0) AS montant_regle_c,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_reg.montant_regle_h,0) AS montant_regle_h,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_reg.montant_regle_0_c,0) AS montant_regle_0_c,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_reg.montant_regle_0_h,0) AS montant_regle_0_h,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_reg.montant_regle_1_c,0) AS montant_regle_1_c,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_reg.montant_regle_1_h,0) AS montant_regle_1_h,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_reg.montant_regle_2_c,0) AS montant_regle_2_c,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_reg.montant_regle_2_h,0) AS montant_regle_2_h,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_reg.montant_regle_22_c,0) AS montant_regle_22_c,
|
|
|
COALESCE(w_MPM_FACTURE_RECF_reg.montant_regle_22_h,0) AS montant_regle_22_h,
|
|
|
|
|
|
|
|
|
0::numeric AS delai_facture,
|
|
|
|
|
|
0::numeric AS delai_expedition,
|
|
|
0::numeric AS delai_expedition_0,
|
|
|
0::numeric AS delai_expedition_1,
|
|
|
0::numeric AS delai_expedition_2,
|
|
|
0::numeric AS delai_expedition_22,
|
|
|
0::numeric AS delai_solde,
|
|
|
0::numeric AS delai_solde_0_c,
|
|
|
0::numeric AS delai_solde_0_h,
|
|
|
0::numeric AS delai_solde_1_c,
|
|
|
0::numeric AS delai_solde_1_h,
|
|
|
0::numeric AS delai_solde_2_c,
|
|
|
0::numeric AS delai_solde_2_h,
|
|
|
0::numeric AS delai_solde_22_c,
|
|
|
0::numeric AS delai_solde_22_h
|
|
|
|
|
|
FROM w_MPM_FACTURE_RECF MPM_FACTURE_RECF
|
|
|
JOIN w_SID_DOSSIERADMINISTRATIF_DADM ON RECF_ID_DADM = DADM_ID
|
|
|
JOIN activite[PX].p_sejours ON DADM_ID = p_sejours.code_original AND p_sejours.etat = ''
|
|
|
LEFT JOIN w_MPM_FACTURE_RECF_exp ON w_MPM_FACTURE_RECF_exp.RECF_ID = MPM_FACTURE_RECF.RECF_ID
|
|
|
LEFT JOIN w_MPM_FACTURE_RECF_fac ON w_MPM_FACTURE_RECF_fac.RECF_ID = MPM_FACTURE_RECF.RECF_ID
|
|
|
LEFT JOIN w_MPM_FACTURE_RECF_reg ON w_MPM_FACTURE_RECF_reg.RECF_ID = MPM_FACTURE_RECF.RECF_ID
|
|
|
LEFT JOIN w_MPM_FACTURE_RECF_ann ON w_MPM_FACTURE_RECF_ann.RECF_ID_annulee = MPM_FACTURE_RECF.RECF_ID
|
|
|
LEFT JOIN w_MPM_FACTURE_RECF_ann w_MPM_FACTURE_RECF_avo ON w_MPM_FACTURE_RECF_avo.RECF_ID_avoir = MPM_FACTURE_RECF.RECF_ID
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
-- Correction des numéros de factures avec code en double
|
|
|
|
|
|
UPDATE w_factures
|
|
|
SET no_facture = w_factures.no_facture || '2',
|
|
|
no_facture_reference = w_factures.no_facture_reference || '2'
|
|
|
FROM
|
|
|
(SELECT no_facture, MAX(oid) AS oid FROM w_factures GROUP BY 1 HAVING count(*) > 1) subview
|
|
|
WHERE w_factures.oid = subview.oid;
|
|
|
|
|
|
UPDATE w_factures
|
|
|
SET no_facture = w_factures.no_facture || '3',
|
|
|
no_facture_reference = w_factures.no_facture_reference || '3'
|
|
|
FROM
|
|
|
(SELECT no_facture, MAX(oid) AS oid FROM w_factures GROUP BY 1 HAVING count(*) > 1) subview
|
|
|
WHERE w_factures.oid = subview.oid;
|
|
|
|
|
|
|
|
|
ALTER TABLE w_factures
|
|
|
ADD CONSTRAINT w_factures_pk PRIMARY KEY(no_facture);
|
|
|
|
|
|
|
|
|
|
|
|
-- Facture de référence
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_references;
|
|
|
CREATE TEMP TABLE w_factures_references AS
|
|
|
SELECT no_sejour, date_debut,
|
|
|
MIN(CASE WHEN type_facture = '0' THEN no_facture ELSE NULL END) AS no_facture_0,
|
|
|
MIN(CASE WHEN type_facture = '2' THEN no_facture ELSE NULL END) AS no_facture_2,
|
|
|
MIN(no_facture) AS no_facture_x
|
|
|
FROM w_factures
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE w_factures
|
|
|
SET no_facture_reference = COALESCE(no_facture_0,no_facture_2,no_facture_x)
|
|
|
FROM w_factures_references
|
|
|
WHERE w_factures.no_sejour = w_factures_references.no_sejour AND
|
|
|
w_factures.date_debut = w_factures_references.date_debut AND
|
|
|
no_facture_reference IS DISTINCT FROM COALESCE(no_facture_0,no_facture_2,no_facture_x);
|
|
|
|
|
|
|
|
|
UPDATE w_factures
|
|
|
SET facture_reference_id = w_factures_references.oid
|
|
|
FROM w_factures w_factures_references
|
|
|
WHERE w_factures.no_facture_reference = w_factures_references.no_facture AND
|
|
|
w_factures.facture_reference_id IS DISTINCT FROM w_factures_references.oid;
|
|
|
|
|
|
|
|
|
UPDATE w_factures
|
|
|
SET facture_od_avoir_id = w_factures_od_avoir.oid
|
|
|
FROM w_factures w_factures_od_avoir
|
|
|
WHERE w_factures.no_facture_od_avoir = w_factures_od_avoir.no_facture AND
|
|
|
w_factures.no_facture_od_avoir <> '';
|
|
|
|
|
|
|
|
|
|
|
|
-- Ajout des factures
|
|
|
|
|
|
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');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_11');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_12');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_13');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_14');
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures (
|
|
|
oid,
|
|
|
no_sejour,
|
|
|
sejour_id,
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
type_facture,
|
|
|
code_cp_demandee,
|
|
|
code_facture,
|
|
|
date_facture,
|
|
|
code_vente,
|
|
|
date_vente,
|
|
|
mois_vente,
|
|
|
code_cloture,
|
|
|
nb_rejets,
|
|
|
no_facture_reference,
|
|
|
facture_reference_id,
|
|
|
no_facture_od_avoir,
|
|
|
facture_od_avoir_id,
|
|
|
ghs_id,
|
|
|
ghs_bebe1_id,
|
|
|
ghs_bebe2_id,
|
|
|
ghs_bebe3_id,
|
|
|
particularite_t2a,
|
|
|
tiers_payant_1_id,
|
|
|
tiers_payant_2_id,
|
|
|
tiers_payant_22_id,
|
|
|
tiers_payant_0_id,
|
|
|
date_expedition,
|
|
|
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,
|
|
|
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,
|
|
|
montant_facture_c,
|
|
|
montant_facture_h,
|
|
|
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_facture_c_actes_inclus_dans_sejour,
|
|
|
montant_facture_h_actes_inclus_dans_sejour,
|
|
|
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,
|
|
|
montant_comptabilise_budget_global_c,
|
|
|
montant_regle_c,
|
|
|
montant_regle_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_facture,
|
|
|
delai_expedition,
|
|
|
delai_expedition_0,
|
|
|
delai_expedition_1,
|
|
|
delai_expedition_2,
|
|
|
delai_expedition_22,
|
|
|
delai_solde,
|
|
|
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
|
|
|
)
|
|
|
SELECT
|
|
|
oid,
|
|
|
no_sejour,
|
|
|
sejour_id,
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
type_facture,
|
|
|
code_cp_demandee,
|
|
|
code_facture,
|
|
|
date_facture,
|
|
|
code_vente,
|
|
|
date_vente,
|
|
|
mois_vente,
|
|
|
code_cloture,
|
|
|
nb_rejets,
|
|
|
no_facture_reference,
|
|
|
facture_reference_id,
|
|
|
no_facture_od_avoir,
|
|
|
facture_od_avoir_id,
|
|
|
ghs_id,
|
|
|
ghs_bebe1_id,
|
|
|
ghs_bebe2_id,
|
|
|
ghs_bebe3_id,
|
|
|
particularite_t2a,
|
|
|
tiers_payant_1_id,
|
|
|
tiers_payant_2_id,
|
|
|
tiers_payant_22_id,
|
|
|
tiers_payant_0_id,
|
|
|
date_expedition,
|
|
|
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,
|
|
|
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,
|
|
|
montant_facture_c,
|
|
|
montant_facture_h,
|
|
|
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_facture_c_actes_inclus_dans_sejour,
|
|
|
montant_facture_h_actes_inclus_dans_sejour,
|
|
|
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,
|
|
|
montant_comptabilise_budget_global_c,
|
|
|
montant_regle_c,
|
|
|
montant_regle_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_facture,
|
|
|
delai_expedition,
|
|
|
delai_expedition_0,
|
|
|
delai_expedition_1,
|
|
|
delai_expedition_2,
|
|
|
delai_expedition_22,
|
|
|
delai_solde,
|
|
|
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
|
|
|
FROM w_factures;
|
|
|
|
|
|
|
|
|
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');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_11');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_12');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_13');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_14');
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures
|
|
|
SET facture_od_avoir_id = p_factures_od_avoir.oid
|
|
|
FROM activite[PX].p_factures p_factures_od_avoir
|
|
|
WHERE p_factures.no_facture_od_avoir = p_factures_od_avoir.no_facture AND
|
|
|
p_factures.no_facture_od_avoir <> '';
|
|
|
|
|
|
|
|
|
-- Etat séjour non facturable
|
|
|
INSERT INTO activite.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'CSIS_STDO_SANSFACTURE',
|
|
|
'CSIS-MEDSPHERE. Etat des sejour sans facturation (pas d''encours) ',
|
|
|
'',
|
|
|
'Codes separes par virgule'
|
|
|
WHERE 'CSIS_STDO_SANSFACTURE' NOT IN (SELECT code FROM activite.t_divers)
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].p_sejours
|
|
|
SET est_sans_facturation = '1'
|
|
|
FROM prod_csis.SID_DOSSIERADMINISTRATIF_DADM
|
|
|
JOIN prod_csis.SNO_STATUTDOSSIER_STDO ON DADM_ID_STDO = STDO_ID
|
|
|
JOIN activite.t_divers ON t_divers.code = 'CSIS_STDO_SANSFACTURE'
|
|
|
WHERE t_divers.valeur <> '' AND
|
|
|
STDO_CODE = ANY(string_to_array(t_divers.valeur,',')) AND
|
|
|
p_sejours.code_original = DADM_ID
|
|
|
;
|
|
|
|
|
|
|
|
|
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')
|
|
|
);
|
|
|
|
|
|
-- Spécial bébés
|
|
|
UPDATE activite[PX].p_sejours
|
|
|
SET est_sans_facturation = '1', type_sejour = '6'
|
|
|
FROM prod_csis.SID_DOSSIERADMINISTRATIF_DADM
|
|
|
WHERE p_sejours.code_original = DADM_ID AND
|
|
|
DADM_NOUVEAUNE = '1' AND
|
|
|
p_sejours.no_sejour NOT IN (SELECT no_sejour FROM activite[PX].p_factures WHERE code_facture = '1')
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].p_mouvements_sejour
|
|
|
SET nb_bebes = 1
|
|
|
FROM activite[PX].p_sejours
|
|
|
WHERE p_mouvements_sejour.no_sejour = p_sejours.no_sejour AND
|
|
|
type_sejour = '6' AND
|
|
|
(nb_entrees_directes = 1 OR nb_ambulatoires = 1)
|
|
|
;
|
|
|
|
|
|
|
|
|
-- 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.date_entree,
|
|
|
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 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%'
|
|
|
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;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures(
|
|
|
finess,
|
|
|
no_sejour,
|
|
|
no_facture,
|
|
|
no_facture_reference,
|
|
|
type_facture,
|
|
|
code_facture,
|
|
|
date_facture,
|
|
|
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,
|
|
|
'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,
|
|
|
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
|
|
|
JOIN w_start ON 1=1
|
|
|
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
|
|
|
HAVING MAX(LEAST(date_fin_encours, p_calendrier.date)) >= '[ENV_ADM_ANNEEDEBUT]0101' AND
|
|
|
MAX(LEAST(date_fin_encours, p_calendrier.date)) >= MAX(date_start)
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].p_factures
|
|
|
SET facture_reference_id = p_factures_references.oid
|
|
|
FROM activite[PX].p_factures p_factures_references
|
|
|
WHERE p_factures.no_facture_reference = p_factures_references.no_facture AND
|
|
|
p_factures.facture_reference_id IS DISTINCT FROM p_factures_references.oid;
|
|
|
|
|
|
|
|
|
|
|
|
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>
|
|
|
|
|
|
<NODEx label="Rejets">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODEx>
|
|
|
|
|
|
<NODE label="Lignes non facturées Clinique">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
TRUNCATE activite[PX].p_factures_lignes_non_facturees_c;
|
|
|
|
|
|
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,
|
|
|
ucd_id,
|
|
|
lpp_id)
|
|
|
SELECT
|
|
|
p_factures.no_facture,
|
|
|
date(RECG_DATEDEBUT) AS date_debut,
|
|
|
date(COALESCE(RECG_DATEFIN, RECG_DATEDEBUT)) AS date_fin,
|
|
|
COALESCE(RECD_QUANTITE,RECG_QUANTITE) AS nb_rubrique,
|
|
|
RECG_COEFFICIENT*COALESCE(RECD_COEFFRAC,1) AS coefficient,
|
|
|
w_SST_PRESTATIONETAB_PRTB.rubrique_facturation_id,
|
|
|
t_prestations.oid AS prestation_id,
|
|
|
COALESCE(RECD_PUFACTURE,RECG_PUFACTURE) AS prix_unitaire,
|
|
|
p_sejours.lieu_sortie_id AS lieu_id,
|
|
|
COALESCE(t_ucd.oid,0) AS ucd_id,
|
|
|
COALESCE(t_lpp.oid,0) AS lpp_id
|
|
|
FROM prod_csis.MPM_RECUEIL_RECG
|
|
|
LEFT JOIN prod_csis.MPM_RECUEILDETAIL_RECD ON RECD_ID_RECG = RECG_ID AND recd_naturedetail IN ('ph. CIP','ph. UCD','lpp')
|
|
|
JOIN prod_csis.SID_DOSSIERADMINISTRATIF_DADM ON RECG_ID_DADM = DADM_ID
|
|
|
JOIN w_SST_PRESTATIONETAB_PRTB ON RECG_ID_PRTB = PRTB_ID
|
|
|
JOIN prod_csis.SST_PRESTATION_PRES ON PRTB_ID_PRES = PRES_ID
|
|
|
JOIN activite[PX].p_sejours ON RECG_ID_DADM = p_sejours.code_original AND p_sejours.etat = ''
|
|
|
JOIN activite[PX].p_factures ON p_sejours.no_sejour = p_factures.no_sejour AND type_facture IN ('E','0') AND code_facture <> '1' AND
|
|
|
date(RECG_DATEDEBUT) BETWEEN p_factures.date_debut AND p_factures.date_fin
|
|
|
JOIN activite.t_prestations ON PRES_CODE = t_prestations.code
|
|
|
LEFT JOIN base.t_ucd ON RECD_CODEAFFINE = t_ucd.code AND RECD_NATUREDETAIL IN ('ph. CIP','ph. UCD')
|
|
|
LEFT JOIN base.t_lpp ON RECD_CODEAFFINE = t_lpp.code AND RECD_NATUREDETAIL = 'lpp'
|
|
|
WHERE RECG_TYPELIGNE IN (3,34) AND t_prestations.code <> 'GHS'
|
|
|
;
|
|
|
|
|
|
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,
|
|
|
ucd_id,
|
|
|
lpp_id)
|
|
|
SELECT
|
|
|
p_factures.no_facture,
|
|
|
date(PRET_DATEDEBUT) AS date_debut,
|
|
|
date(COALESCE(PRET_DATEFIN, PRET_DATEDEBUT)) AS date_fin,
|
|
|
PRET_QUANTITE AS nb_rubrique,
|
|
|
PRET_COEFFICIENT AS coefficient,
|
|
|
w_SST_PRESTATIONETAB_PRTB.rubrique_facturation_id,
|
|
|
t_prestations.oid AS prestation_id,
|
|
|
PRET_PUFACTURE AS prix_unitaire,
|
|
|
p_sejours.lieu_sortie_id AS lieu_id,
|
|
|
0::bigint AS ucd_id,
|
|
|
0::bigint AS lpp_id
|
|
|
FROM prod_csis.SCA_PRESTATION_PRET
|
|
|
LEFT JOIN prod_csis.MPM_RECUEIL_RECG ON
|
|
|
RECG_ID_DADM = PRET_ID_DADM AND
|
|
|
PRET_DATEDEBUT = RECG_DATEDEBUT AND
|
|
|
PRET_QUANTITE = RECG_QUANTITE AND
|
|
|
PRET_COEFFICIENT = RECG_COEFFICIENT
|
|
|
JOIN prod_csis.SID_DOSSIERADMINISTRATIF_DADM ON PRET_ID_DADM = DADM_ID
|
|
|
JOIN w_SST_PRESTATIONETAB_PRTB ON PRET_ID_PRTB = PRTB_ID
|
|
|
JOIN prod_csis.SST_PRESTATION_PRES ON PRTB_ID_PRES = PRES_ID
|
|
|
JOIN activite[PX].p_sejours ON PRET_ID_DADM = p_sejours.code_original AND p_sejours.etat = ''
|
|
|
JOIN activite[PX].p_factures ON p_sejours.no_sejour = p_factures.no_sejour AND type_facture IN ('E','0') AND code_facture <> '1' AND
|
|
|
date(PRET_DATEDEBUT) BETWEEN p_factures.date_debut AND p_factures.date_fin
|
|
|
JOIN activite.t_prestations ON PRES_CODE = t_prestations.code
|
|
|
WHERE PRET_TYPELIGNE = 3 AND t_prestations.code <> 'GHS' AND
|
|
|
RECG_ID_DADM IS NULL;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Lignes facturées Clinique">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Préparation pour ucd/lpp
|
|
|
DROP TABLE IF EXISTS w_MPM_RECUEILDETAIL_RECD_ucdlpp;
|
|
|
CREATE TEMP TABLE w_MPM_RECUEILDETAIL_RECD_ucdlpp AS
|
|
|
SELECT MPM_RECUEILDETAIL_RECD.*,
|
|
|
round(RECD_MONTANTFACTURE * RECT_TAUX_FAC_0,2) AS RECD_MONTANT_FAC_0,
|
|
|
round(RECD_MONTANTFACTURE * RECT_TAUX_FAC_1,2) AS RECD_MONTANT_FAC_1,
|
|
|
round(RECD_MONTANTFACTURE * RECT_TAUX_FAC_2,2) AS RECD_MONTANT_FAC_2,
|
|
|
round(RECD_MONTANTFACTURE * RECT_TAUX_FAC_22,2) AS RECD_MONTANT_FAC_22,
|
|
|
round(RECD_MONTANTFACTURE * RECT_TAUX_CPT,2) AS RECD_MONTANT_CPT,
|
|
|
round(RECD_MONTANTFACTURE * RECT_TAUX_CPT_0,2) AS RECD_MONTANT_CPT_0,
|
|
|
round(RECD_MONTANTFACTURE * RECT_TAUX_CPT_1,2) AS RECD_MONTANT_CPT_1,
|
|
|
round(RECD_MONTANTFACTURE * RECT_TAUX_CPT_2,2) AS RECD_MONTANT_CPT_2,
|
|
|
round(RECD_MONTANTFACTURE * RECT_TAUX_CPT_22,2) AS RECD_MONTANT_CPT_22,
|
|
|
COALESCE(t_ucd.oid,0) AS ucd_id,
|
|
|
COALESCE(t_lpp.oid,0) AS lpp_id
|
|
|
FROM prod_csis.MPM_RECUEILDETAIL_RECD
|
|
|
JOIN
|
|
|
(
|
|
|
SELECT RECD_ID_RECG, count(*),
|
|
|
SUM(RECD_MONTANTFACTURE),
|
|
|
MAX(RECT_MONTANT_FAC) AS RECT_MONTANT_FAC,
|
|
|
base.cti_division(MAX(RECT_MONTANT_FAC_0),MAX(RECT_MONTANT_FAC)) AS RECT_TAUX_FAC_0,
|
|
|
base.cti_division(MAX(RECT_MONTANT_FAC_1),MAX(RECT_MONTANT_FAC)) AS RECT_TAUX_FAC_1,
|
|
|
base.cti_division(MAX(RECT_MONTANT_FAC_2),MAX(RECT_MONTANT_FAC)) AS RECT_TAUX_FAC_2,
|
|
|
base.cti_division(MAX(RECT_MONTANT_FAC_22),MAX(RECT_MONTANT_FAC)) AS RECT_TAUX_FAC_22,
|
|
|
base.cti_division(MAX(RECT_MONTANT_CPT),MAX(RECT_MONTANT_FAC)) AS RECT_TAUX_CPT,
|
|
|
base.cti_division(MAX(RECT_MONTANT_CPT_0),MAX(RECT_MONTANT_FAC)) AS RECT_TAUX_CPT_0,
|
|
|
base.cti_division(MAX(RECT_MONTANT_CPT_1),MAX(RECT_MONTANT_FAC)) AS RECT_TAUX_CPT_1,
|
|
|
base.cti_division(MAX(RECT_MONTANT_CPT_2),MAX(RECT_MONTANT_FAC)) AS RECT_TAUX_CPT_2,
|
|
|
base.cti_division(MAX(RECT_MONTANT_CPT_22),MAX(RECT_MONTANT_FAC)) AS RECT_TAUX_CPT_22
|
|
|
FROM prod_csis.MPM_RECUEILDETAIL_RECD
|
|
|
JOIN w_MPM_RECUEILTIERS_RECT ON RECD_ID_RECG = RECG_ID
|
|
|
WHERE recd_naturedetail IN ('ph. CIP','ph. UCD','lpp')
|
|
|
GROUP BY 1
|
|
|
HAVING SUM(RECD_MONTANTFACTURE) = MAX(RECT_MONTANT_FAC)
|
|
|
) subview ON MPM_RECUEILDETAIL_RECD.RECD_ID_RECG = subview.RECD_ID_RECG
|
|
|
LEFT JOIN base.t_ucd ON RECD_CODEAFFINE = t_ucd.code AND RECD_NATUREDETAIL IN ('ph. CIP','ph. UCD')
|
|
|
LEFT JOIN base.t_lpp ON RECD_CODEAFFINE = t_lpp.code AND RECD_NATUREDETAIL = 'lpp'
|
|
|
;
|
|
|
|
|
|
ANALYSE w_MPM_RECUEILDETAIL_RECD_ucdlpp
|
|
|
;
|
|
|
CREATE INDEX w_MPM_RECUEILDETAIL_RECD_ucdlpp_i1
|
|
|
ON w_MPM_RECUEILDETAIL_RECD_ucdlpp
|
|
|
USING btree
|
|
|
(RECD_ID_RECG)
|
|
|
;
|
|
|
|
|
|
DROP SEQUENCE IF EXISTS w_factures_lignes_c_sequence;
|
|
|
CREATE TEMP SEQUENCE w_factures_lignes_c_sequence;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_c;
|
|
|
CREATE TEMP TABLE w_factures_lignes_c AS
|
|
|
SELECT
|
|
|
''::text AS finess,
|
|
|
p_sejours.no_sejour,
|
|
|
RECF_NUMFACTALIAS_ETAB AS no_facture,
|
|
|
COALESCE(p_factures.oid,0) AS facture_id,
|
|
|
RECG_DATEDEBUT AS date_debut,
|
|
|
COALESCE(RECG_DATEFIN,RECG_DATEDEBUT) AS date_fin,
|
|
|
COALESCE(p_sejours.lieu_sortie_id,0) AS lieu_id,
|
|
|
1::bigint AS origine_facturation_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_facturation_id AS rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
w_MPM_RECUEILDETAIL_RECD_ucdlpp.ucd_id,
|
|
|
w_MPM_RECUEILDETAIL_RECD_ucdlpp.lpp_id,
|
|
|
compte_produit_id,
|
|
|
COALESCE(RECD_QUANTITE,RECG_QUANTITE) AS nb_rubrique,
|
|
|
COALESCE(RECD_QUANTITE,RECG_QUANTITE) AS nb_prestation,
|
|
|
CASE WHEN RECG_COEFFICIENT <> 0 THEN RECG_COEFFICIENT ELSE 1 END AS coefficient,
|
|
|
CASE WHEN RECG_COEFFICIENTMCO <> 0 THEN RECG_COEFFICIENTMCO ELSE 1 END AS coefficient_mco,
|
|
|
COALESCE(RECD_PUFACTURE,RECG_PUFACTURE) AS prix_unitaire,
|
|
|
MAX(nextval('w_factures_lignes_c_sequence'::regclass)) AS oid,
|
|
|
MAX(RECT_TAUX_0) as taux_0,
|
|
|
MAX(RECT_TAUX_1) as taux_1,
|
|
|
MAX(RECT_TAUX_2) as taux_2,
|
|
|
MAX(RECT_TAUX_22) as taux_22,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (3,34) THEN COALESCE(RECD_MONTANTFACTURE,RECT_MONTANT_FAC) ELSE 0 END) as montant_facture,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (3,34) THEN COALESCE(RECD_MONTANT_FAC_0,RECT_MONTANT_FAC_0) ELSE 0 END) as montant_facture_0,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (3,34) THEN COALESCE(RECD_MONTANT_FAC_1,RECT_MONTANT_FAC_1) ELSE 0 END) as montant_facture_1,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (3,34) THEN COALESCE(RECD_MONTANT_FAC_2,RECT_MONTANT_FAC_2) ELSE 0 END) as montant_facture_2,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (3,34) THEN COALESCE(RECD_MONTANT_FAC_22,RECT_MONTANT_FAC_22) ELSE 0 END) as montant_facture_22,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 THEN COALESCE(RECD_MONTANT_CPT,RECT_MONTANT_CPT) ELSE 0 END) as montant_comptabilise,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 THEN COALESCE(RECD_MONTANT_CPT_0,RECT_MONTANT_CPT_0) ELSE 0 END) as montant_comptabilise_0,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 THEN COALESCE(RECD_MONTANT_CPT_1,RECT_MONTANT_CPT_1) ELSE 0 END) as montant_comptabilise_1,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 THEN COALESCE(RECD_MONTANT_CPT_2,RECT_MONTANT_CPT_2) ELSE 0 END) as montant_comptabilise_2,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 3 THEN COALESCE(RECD_MONTANT_CPT_22,RECT_MONTANT_CPT_22) ELSE 0 END) as montant_comptabilise_22,
|
|
|
0::numeric AS montant_encours,
|
|
|
0::numeric AS montant_encours_0,
|
|
|
0::numeric AS montant_encours_1,
|
|
|
0::numeric AS montant_encours_2,
|
|
|
0::numeric AS montant_encours_22,
|
|
|
0::numeric AS montant_facture_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_0_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_1_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_2_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_22_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_comptabilise_budget_global_1,
|
|
|
0::numeric AS rubrique_facture_id
|
|
|
FROM w_MPM_RECUEILTIERS_RECT
|
|
|
JOIN w_MPM_RECUEILTIERS_RECT_keys ON w_MPM_RECUEILTIERS_RECT.key = w_MPM_RECUEILTIERS_RECT_keys.key
|
|
|
LEFT JOIN w_MPM_RECUEILDETAIL_RECD_ucdlpp ON RECD_ID_RECG = RECG_ID
|
|
|
JOIN activite[PX].p_factures ON no_facture = RECF_NUMFACTALIAS_ETAB
|
|
|
JOIN activite[PX].p_sejours ON p_sejours.oid = p_factures.sejour_id AND p_sejours.etat = ''
|
|
|
WHERE
|
|
|
(w_MPM_RECUEILTIERS_RECT.RECG_TYPELIGNE IN (3,34) OR w_MPM_RECUEILTIERS_RECT.RECG_TYPELIGNE_CPTA = 3) AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 AND code_facture <> '0'
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19;
|
|
|
|
|
|
|
|
|
ALTER TABLE w_factures_lignes_c
|
|
|
ADD CONSTRAINT w_factures_lignes_c_pk PRIMARY KEY(oid);
|
|
|
|
|
|
CREATE INDEX w_factures_lignes_c_i1
|
|
|
ON w_factures_lignes_c
|
|
|
USING btree
|
|
|
(no_sejour);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- Eclatement des supplements par jour
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_sup_c;
|
|
|
CREATE TEMP TABLE w_factures_lignes_sup_c AS
|
|
|
SELECT
|
|
|
w_factures_lignes_c.oid AS from_oid,
|
|
|
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,
|
|
|
w_factures_lignes_c.*
|
|
|
FROM w_factures_lignes_c
|
|
|
JOIN activite[PX].p_sejours ON w_factures_lignes_c.no_sejour = p_sejours.no_sejour
|
|
|
JOIN activite.t_prestations ON prestation_id = t_prestations.oid
|
|
|
WHERE (nb_prestation > 1 or nb_prestation < -1 OR (t_prestations.code = 'GHS' AND date(date_sortie) - date(date_entree) > 1)) AND
|
|
|
(
|
|
|
t_prestations.code IN ('PJ', 'FJ', 'PHJ','SSM', 'GHS', 'EXH', 'SRC', 'REA', 'STF', 'NN1', 'NN2', 'NN3', 'CP', 'CPC', 'CPM', 'CPS', 'SHO') OR
|
|
|
t_prestations.type_ventilation_jour = '1' OR
|
|
|
(date(w_factures_lignes_c.date_fin) - date(w_factures_lignes_c.date_debut)) = abs(nb_rubrique) OR
|
|
|
(date(w_factures_lignes_c.date_fin) - date(w_factures_lignes_c.date_debut)) = (abs(nb_rubrique)-1)
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE w_factures_lignes_sup_c SET
|
|
|
date_fin_ghs = date(date_debut_exh - interval '1 day'),
|
|
|
nb_prestation_ghs = date(date_debut_exh - interval '1 day') - date_debut_ghs + 1
|
|
|
FROM (
|
|
|
SELECT no_facture, date(MIN(date_debut)) AS date_debut_exh
|
|
|
FROM w_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;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_sup_c_gen;
|
|
|
CREATE TEMP TABLE w_factures_lignes_sup_c_gen AS
|
|
|
SELECT
|
|
|
from_oid,
|
|
|
''::text AS finess,
|
|
|
no_sejour,
|
|
|
no_facture,
|
|
|
facture_id,
|
|
|
date AS date_debut,
|
|
|
date AS date_fin,
|
|
|
lieu_id,
|
|
|
origine_facturation_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
compte_produit_id,
|
|
|
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,
|
|
|
prix_unitaire,
|
|
|
oid,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
round(montant_facture / ABS(CASE WHEN prestation_code <> 'GHS' THEN nb_prestation ELSE nb_prestation_ghs END),2) AS montant_facture,
|
|
|
round(montant_facture_0 / ABS(CASE WHEN prestation_code <> 'GHS' THEN nb_prestation ELSE nb_prestation_ghs END),2) AS montant_facture_0,
|
|
|
round(montant_facture_1 / ABS(CASE WHEN prestation_code <> 'GHS' THEN nb_prestation ELSE nb_prestation_ghs END),2) AS montant_facture_1,
|
|
|
round(montant_facture_2 / ABS(CASE WHEN prestation_code <> 'GHS' THEN nb_prestation ELSE nb_prestation_ghs END),2) AS montant_facture_2,
|
|
|
round(montant_facture_22 / ABS(CASE WHEN prestation_code <> 'GHS' THEN nb_prestation ELSE nb_prestation_ghs END),2) AS montant_facture_22,
|
|
|
round(montant_comptabilise / ABS(CASE WHEN prestation_code <> 'GHS' THEN nb_prestation ELSE nb_prestation_ghs END),2) AS montant_comptabilise,
|
|
|
round(montant_comptabilise_0 / ABS(CASE WHEN prestation_code <> 'GHS' THEN nb_prestation ELSE nb_prestation_ghs END),2) AS montant_comptabilise_0,
|
|
|
round(montant_comptabilise_1 / ABS(CASE WHEN prestation_code <> 'GHS' THEN nb_prestation ELSE nb_prestation_ghs END),2) AS montant_comptabilise_1,
|
|
|
round(montant_comptabilise_2 / ABS(CASE WHEN prestation_code <> 'GHS' THEN nb_prestation ELSE nb_prestation_ghs END),2) AS montant_comptabilise_2,
|
|
|
round(montant_comptabilise_22 / ABS(CASE WHEN prestation_code <> 'GHS' THEN nb_prestation ELSE nb_prestation_ghs END),2) AS 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,
|
|
|
montant_comptabilise_budget_global_1
|
|
|
FROM w_factures_lignes_sup_c
|
|
|
JOIN base.p_calendrier ON date_debut BETWEEN p_calendrier.date - ABS(CASE WHEN prestation_code <> 'GHS' THEN nb_prestation ELSE nb_prestation_ghs END)::integer + 1 AND p_calendrier.date AND
|
|
|
p_calendrier.date <> date_debut ;
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_sup_c_gen_tot;
|
|
|
CREATE TEMP TABLE w_factures_lignes_sup_c_gen_tot AS
|
|
|
SELECT from_oid,
|
|
|
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
|
|
|
FROM w_factures_lignes_sup_c_gen
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE w_factures_lignes_c
|
|
|
SET
|
|
|
date_fin = w_factures_lignes_c.date_debut,
|
|
|
nb_rubrique = w_factures_lignes_c.nb_rubrique - w_factures_lignes_sup_c_gen_tot.nb_rubrique,
|
|
|
nb_prestation = w_factures_lignes_c.nb_prestation - w_factures_lignes_sup_c_gen_tot.nb_prestation,
|
|
|
montant_facture = w_factures_lignes_c.montant_facture - w_factures_lignes_sup_c_gen_tot.montant_facture,
|
|
|
montant_facture_0 = w_factures_lignes_c.montant_facture_0 - w_factures_lignes_sup_c_gen_tot.montant_facture_0,
|
|
|
montant_facture_1 = w_factures_lignes_c.montant_facture_1 - w_factures_lignes_sup_c_gen_tot.montant_facture_1,
|
|
|
montant_facture_2 = w_factures_lignes_c.montant_facture_2 - w_factures_lignes_sup_c_gen_tot.montant_facture_2,
|
|
|
montant_facture_22 = w_factures_lignes_c.montant_facture_22 - w_factures_lignes_sup_c_gen_tot.montant_facture_22,
|
|
|
montant_comptabilise = w_factures_lignes_c.montant_comptabilise - w_factures_lignes_sup_c_gen_tot.montant_comptabilise,
|
|
|
montant_comptabilise_0 = w_factures_lignes_c.montant_comptabilise_0 - w_factures_lignes_sup_c_gen_tot.montant_comptabilise_0,
|
|
|
montant_comptabilise_1 = w_factures_lignes_c.montant_comptabilise_1 - w_factures_lignes_sup_c_gen_tot.montant_comptabilise_1,
|
|
|
montant_comptabilise_2 = w_factures_lignes_c.montant_comptabilise_2 - w_factures_lignes_sup_c_gen_tot.montant_comptabilise_2,
|
|
|
montant_comptabilise_22 = w_factures_lignes_c.montant_comptabilise_22 - w_factures_lignes_sup_c_gen_tot.montant_comptabilise_22
|
|
|
FROM w_factures_lignes_sup_c_gen_tot
|
|
|
WHERE w_factures_lignes_c.oid = from_oid;
|
|
|
|
|
|
|
|
|
INSERT INTO w_factures_lignes_c
|
|
|
SELECT
|
|
|
''::text AS finess,
|
|
|
no_sejour,
|
|
|
no_facture,
|
|
|
facture_id,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
lieu_id,
|
|
|
origine_facturation_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
compte_produit_id,
|
|
|
nb_rubrique,
|
|
|
nb_prestation,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
prix_unitaire,
|
|
|
nextval('w_factures_lignes_c_sequence'::regclass) AS oid,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
montant_facture_22,
|
|
|
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,
|
|
|
montant_comptabilise_budget_global_1,
|
|
|
0::numeric AS rubrique_facture_id
|
|
|
FROM w_factures_lignes_sup_c_gen;
|
|
|
|
|
|
|
|
|
-- Lieux d'exécution
|
|
|
|
|
|
|
|
|
UPDATE w_factures_lignes_c
|
|
|
SET lieu_id = p_mouvements_sejour.lieu_id
|
|
|
FROM activite[PX].p_mouvements_sejour
|
|
|
WHERE w_factures_lignes_c.no_sejour = p_mouvements_sejour.no_sejour AND
|
|
|
w_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
|
|
|
w_factures_lignes_c.lieu_id <> p_mouvements_sejour.lieu_id;
|
|
|
|
|
|
|
|
|
-- Rubriques internes cti
|
|
|
SELECT activite[PX].cti_reorganize_rubrique_facture_c('w_factures_lignes_c');
|
|
|
|
|
|
-- Génération
|
|
|
|
|
|
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(
|
|
|
finess,
|
|
|
no_facture,
|
|
|
facture_id,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
lieu_id,
|
|
|
origine_facturation_id,
|
|
|
rubrique_facture_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
compte_produit_id,
|
|
|
nb_rubrique,
|
|
|
nb_prestation,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
prix_unitaire,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
montant_facture_22,
|
|
|
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,
|
|
|
montant_comptabilise_budget_global_1
|
|
|
)
|
|
|
SELECT
|
|
|
finess,
|
|
|
no_facture,
|
|
|
facture_id,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
lieu_id,
|
|
|
origine_facturation_id,
|
|
|
rubrique_facture_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
ucd_id,
|
|
|
lpp_id,
|
|
|
compte_produit_id,
|
|
|
nb_rubrique,
|
|
|
nb_prestation,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
prix_unitaire,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
montant_facture_22,
|
|
|
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,
|
|
|
montant_comptabilise_budget_global_1
|
|
|
FROM w_factures_lignes_c;
|
|
|
|
|
|
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_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');
|
|
|
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');
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Budget global MCO">
|
|
|
<condition><![CDATA[
|
|
|
"[ENV_TYPEETS]" != "1" && "[ENV_WITHPMSI]" == "1"
|
|
|
]]></condition>
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Ajout des prestations PMSI aux prestations activité
|
|
|
DROP TABLE IF EXISTS w_prestations_pmsi;
|
|
|
CREATE TEMP TABLE w_prestations_pmsi AS
|
|
|
SELECT
|
|
|
t_prestations_pmsi.oid,
|
|
|
MAX(t_prestations_pmsi.code) AS code,
|
|
|
MAX(t_prestations_pmsi.texte) AS texte,
|
|
|
0::bigint AS prestation_id,
|
|
|
0::bigint AS rubrique_facturation_id
|
|
|
FROM pmsi.p_rsf_detail
|
|
|
JOIN pmsi.p_rss ON p_rss.oid = p_rsf_detail.rss_id AND p_rss.etat = '' AND p_rss.en_cours = '0'
|
|
|
JOIN pmsi.t_prestations t_prestations_pmsi ON t_prestations_pmsi.oid = p_rsf_detail.prestation_id
|
|
|
WHERE est_ligne_rss = '1' AND p_rss.en_cours = '0'
|
|
|
GROUP BY 1;
|
|
|
|
|
|
UPDATE w_prestations_pmsi
|
|
|
SET prestation_id = t_prestations.oid
|
|
|
FROM activite.t_prestations
|
|
|
WHERE w_prestations_pmsi.code = t_prestations.code
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite.t_prestations(code_original, code, texte, texte_court)
|
|
|
SELECT
|
|
|
w_prestations_pmsi.code,
|
|
|
w_prestations_pmsi.code,
|
|
|
MAX(w_prestations_pmsi.texte),
|
|
|
MAX(w_prestations_pmsi.texte)
|
|
|
FROM w_prestations_pmsi
|
|
|
WHERE prestation_id = 0
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
UPDATE w_prestations_pmsi
|
|
|
SET prestation_id = t_prestations.oid
|
|
|
FROM activite.t_prestations
|
|
|
WHERE w_prestations_pmsi.code = t_prestations.code
|
|
|
;
|
|
|
|
|
|
UPDATE w_prestations_pmsi
|
|
|
SET rubrique_facturation_id = t_rubriques_facturation.oid
|
|
|
FROM activite[PX].t_rubriques_facturation
|
|
|
WHERE w_prestations_pmsi.code = t_rubriques_facturation.code AND
|
|
|
t_rubriques_facturation.code <> code_original
|
|
|
;
|
|
|
|
|
|
UPDATE w_prestations_pmsi
|
|
|
SET rubrique_facturation_id = t_rubriques_facturation.oid
|
|
|
FROM activite[PX].t_rubriques_facturation
|
|
|
WHERE w_prestations_pmsi.code = t_rubriques_facturation.code AND
|
|
|
t_rubriques_facturation.code = code_original AND
|
|
|
rubrique_facturation_id = 0
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite[PX].t_rubriques_facturation(code_original, code, texte, texte_court)
|
|
|
SELECT
|
|
|
w_prestations_pmsi.code,
|
|
|
w_prestations_pmsi.code,
|
|
|
MAX(w_prestations_pmsi.texte),
|
|
|
MAX(w_prestations_pmsi.texte)
|
|
|
FROM w_prestations_pmsi
|
|
|
WHERE rubrique_facturation_id = 0
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
UPDATE w_prestations_pmsi
|
|
|
SET rubrique_facturation_id = t_rubriques_facturation.oid
|
|
|
FROM activite[PX].t_rubriques_facturation
|
|
|
WHERE w_prestations_pmsi.code = t_rubriques_facturation.code AND
|
|
|
t_rubriques_facturation.code = code_original AND
|
|
|
rubrique_facturation_id = 0
|
|
|
;
|
|
|
|
|
|
|
|
|
SELECT activite[PX].cti_reorganize_sejour_pmsi()
|
|
|
;
|
|
|
|
|
|
-- Suppression des prix de journée T2A MCO sur public
|
|
|
DROP TABLE IF EXISTS w_facture_t2amco_public;
|
|
|
CREATE TEMP TABLE w_facture_t2amco_public AS
|
|
|
SELECT p_factures.no_sejour,
|
|
|
p_factures.no_facture,
|
|
|
SUM(montant_facture_1) AS montant_facture_t2amco_public
|
|
|
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[PX].t_lieux ON lieu_sortie_id = t_lieux.oid
|
|
|
JOIN activite[PX].t_services_facturation ON service_facturation_id = t_services_facturation.oid
|
|
|
JOIN activite[PX].p_sejour_pmsi ON p_sejours.oid = p_sejour_pmsi.sejour_id
|
|
|
JOIN activite.t_prestations ON prestation_id = t_prestations.oid
|
|
|
WHERE p_sejours.est_budget_global = '1' AND
|
|
|
(p_sejour_pmsi.rss_id <> 0 OR type_t2a = '1') AND
|
|
|
code_facture = '1' AND
|
|
|
montant_facture_1 <> 0 AND
|
|
|
montant_comptabilise_1 = 0 AND
|
|
|
montant_comptabilise_budget_global_1 = 0
|
|
|
GROUP BY 1,2
|
|
|
HAVING SUM(montant_facture_1) <> 0 AND SUM(montant_comptabilise_1) = 0
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].p_factures SET
|
|
|
montant_facture_c = montant_facture_c - montant_facture_t2amco_public,
|
|
|
montant_facture_1_c = montant_facture_1_c - montant_facture_t2amco_public
|
|
|
FROM w_facture_t2amco_public
|
|
|
WHERE w_facture_t2amco_public.no_facture = p_factures.no_facture;
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures_lignes_c SET
|
|
|
montant_facture = montant_facture - montant_facture_1,
|
|
|
montant_facture_1 = 0
|
|
|
FROM w_facture_t2amco_public
|
|
|
WHERE w_facture_t2amco_public.no_facture = p_factures_lignes_c.no_facture
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
-- Génération des GHS
|
|
|
|
|
|
|
|
|
-- Lignes PMSI à ajouter
|
|
|
DROP TABLE IF EXISTS w_sejours_budget_global;
|
|
|
CREATE TEMP TABLE w_sejours_budget_global AS
|
|
|
SELECT
|
|
|
p_sejour_pmsi.rss_id,
|
|
|
MAX(p_sejour_pmsi.sejour_id) AS sejour_id,
|
|
|
(MAX(Array[to_char(p_sejour_pmsi.sejour_id,'FM000000000000'),p_sejours.no_sejour]))[2]::text AS no_sejour,
|
|
|
(MAX(CASE WHEN p_factures.montant_comptabilise_budget_global_c > 0 AND date_part('year',p_factures.date_facture) = date_part('year',p_sejours.date_sortie) THEN Array[to_char(p_sejour_pmsi.sejour_id,'FM000000000000'),p_factures.no_facture] ELSE NULL END))[2]::text AS no_facture_budget_global,
|
|
|
(MAX(CASE WHEN p_factures.montant_facture_c > 0 AND date_part('year',p_factures.date_facture) = date_part('year',p_sejours.date_sortie) THEN Array[to_char(p_sejour_pmsi.sejour_id,'FM000000000000'),p_factures.no_facture] ELSE NULL END))[2]::text AS no_facture_hors_budget_global,
|
|
|
(MAX(Array[p_sejour_pmsi.sejour_id,p_sejours.lieu_sortie_id]))[2] AS lieu_sortie_id
|
|
|
FROM activite[PX].p_sejour_pmsi
|
|
|
JOIN activite[PX].p_sejours ON p_sejour_pmsi.sejour_id = p_sejours.oid
|
|
|
LEFT JOIN activite[PX].p_factures ON p_factures.no_sejour = p_sejours.no_sejour
|
|
|
WHERE
|
|
|
p_sejour_pmsi.sejour_id IS NOT NULL AND
|
|
|
p_sejour_pmsi.sejour_id <> 0 AND
|
|
|
p_sejour_pmsi.rss_id <> 0
|
|
|
GROUP BY 1;
|
|
|
|
|
|
-- Suppression des lignes issues de la facturation
|
|
|
DELETE FROM activite[PX].p_factures_lignes_c
|
|
|
WHERE montant_comptabilise_budget_global_1 <> 0 AND
|
|
|
no_facture IN
|
|
|
(SELECT no_facture
|
|
|
FROM activite[PX].p_factures
|
|
|
JOIN w_sejours_budget_global ON p_factures.no_sejour = w_sejours_budget_global.no_sejour AND w_sejours_budget_global.rss_id <> 0
|
|
|
)
|
|
|
;
|
|
|
|
|
|
DELETE FROM activite[PX].p_factures_lignes_c
|
|
|
WHERE montant_comptabilise_budget_global_1 <> 0 AND
|
|
|
no_facture IN
|
|
|
(SELECT no_facture
|
|
|
FROM activite[PX].p_factures
|
|
|
JOIN activite[PX].p_sejours ON p_factures.no_sejour = p_sejours.no_sejour
|
|
|
JOIN activite[PX].t_lieux On lieu_sortie_id = t_lieux.oid
|
|
|
JOIN activite[PX].t_services_facturation ON t_services_facturation.oid = service_facturation_id AND type_t2a = '1'
|
|
|
)
|
|
|
;
|
|
|
|
|
|
-- Génération des lignes venant du pmsi
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_pmsi;
|
|
|
CREATE TEMP TABLE w_factures_lignes_pmsi AS
|
|
|
SELECT
|
|
|
w_sejours_budget_global.no_sejour,
|
|
|
w_sejours_budget_global.sejour_id,
|
|
|
COALESCE(w_sejours_budget_global.no_facture_budget_global,w_sejours_budget_global.no_sejour || '.BG') AS no_facture,
|
|
|
0::bigint AS facture_id,
|
|
|
CASE WHEN p_rsf_detail.type = 'C' THEN 'H' ELSE 'C' END AS clinique_honoraire,
|
|
|
p_rsf_detail.date_debut,
|
|
|
p_rsf_detail.date_fin,
|
|
|
p_rsf_detail.nombre AS nb_rubrique,
|
|
|
p_rsf_detail.nombre AS nb_prestation,
|
|
|
p_rsf_detail.coefficient AS coefficient,
|
|
|
p_rsf_detail.coefficient_mco,
|
|
|
w_prestations_pmsi.rubrique_facturation_id,
|
|
|
w_prestations_pmsi.rubrique_facturation_id AS rubrique_comptabilisation_id,
|
|
|
w_prestations_pmsi.prestation_id,
|
|
|
p_rsf_detail.sejour_remboursable AS montant_facture,
|
|
|
0::numeric AS montant_facture_0,
|
|
|
p_rsf_detail.sejour_remboursable AS montant_facture_1,
|
|
|
0::numeric AS montant_facture_2,
|
|
|
0::numeric AS montant_facture_22,
|
|
|
0::numeric AS taux_0,
|
|
|
p_rsf_detail.taux_remboursement AS taux_1,
|
|
|
0::numeric AS taux_2,
|
|
|
0::numeric AS taux_22,
|
|
|
p_rsf_detail.prix_unitaire,
|
|
|
w_sejours_budget_global.lieu_sortie_id AS lieu_id,
|
|
|
0::numeric AS montant_comptabilise,
|
|
|
0::numeric AS montant_comptabilise_0,
|
|
|
0::numeric AS montant_comptabilise_1,
|
|
|
0::numeric AS montant_comptabilise_2,
|
|
|
0::numeric AS montant_comptabilise_22,
|
|
|
0::numeric AS montant_encours,
|
|
|
0::numeric AS montant_encours_0,
|
|
|
0::numeric AS montant_encours_1,
|
|
|
0::numeric AS montant_encours_2,
|
|
|
0::numeric AS montant_encours_22,
|
|
|
0::numeric AS montant_facture_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_0_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_1_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_2_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_22_actes_inclus_dans_sejour,
|
|
|
1::bigint AS origine_facturation_id,
|
|
|
CASE WHEN traitement_epmsi IN ('30','31','32','33') THEN p_rsf_detail.sejour_remboursable ELSE 0 END AS montant_comptabilise_budget_global_1,
|
|
|
0::numeric AS protocole_id,
|
|
|
0::numeric AS compte_produit_id,
|
|
|
w_prestations_pmsi.code AS prestation_code,
|
|
|
''::text AS uf_code,
|
|
|
''::text AS dmt_code,
|
|
|
''::text AS mt_code
|
|
|
FROM pmsi.p_rsf_detail
|
|
|
JOIN pmsi.p_rss ON p_rss.oid = p_rsf_detail.rss_id AND p_rss.etat = '' AND p_rss.en_cours = '0'
|
|
|
JOIN w_start ON p_rss.date_sortie >= date_start
|
|
|
JOIN pmsi.p_rsf_total ON p_rss.oid = p_rsf_total.rss_id AND p_rsf_total.valorise_fides IS DISTINCT FROM 1
|
|
|
JOIN w_prestations_pmsi ON w_prestations_pmsi.oid = p_rsf_detail.prestation_id
|
|
|
JOIN base.t_finess ON p_rss.finess = t_finess.code AND t_finess.type_etablissement <> '1'
|
|
|
JOIN w_sejours_budget_global ON p_rss.oid = w_sejours_budget_global.rss_id
|
|
|
WHERE est_ligne_rss = '1' AND p_rss.en_cours = '0' AND
|
|
|
p_rss.date_sortie >= '20140101' AND
|
|
|
operation_lamda IS DISTINCT FROM '1' AND
|
|
|
operation_lamda IS DISTINCT FROM '2' AND
|
|
|
traitement_epmsi IN ('30','31','32','33') ;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- Factures à créer
|
|
|
DROP TABLE IF EXISTS w_factures_pmsi;
|
|
|
CREATE TEMP TABLE w_factures_pmsi AS
|
|
|
SELECT
|
|
|
w_factures_lignes_pmsi.no_sejour,
|
|
|
w_factures_lignes_pmsi.sejour_id,
|
|
|
w_factures_lignes_pmsi.no_facture,
|
|
|
p_sejours.date_entree AS date_debut,
|
|
|
p_sejours.date_sortie AS date_fin,
|
|
|
'0'::text AS type_facture,
|
|
|
'1'::text AS code_facture,
|
|
|
MAX(p_sejours.date_sortie) AS date_facture,
|
|
|
MAX('1') AS code_vente,
|
|
|
MAX(to_char(p_sejours.date_sortie,'YYYYMM')::numeric) AS mois_vente,
|
|
|
MAX(p_sejours.date_sortie) AS date_solde,
|
|
|
'0'::text AS particularite_t2a,
|
|
|
MAX(p_sejours.date_sortie) AS date_vente,
|
|
|
''::text AS code_cloture,
|
|
|
MAX(p_sejours.code_cp_demandee) AS code_cp_demandee,
|
|
|
'20991231'::date AS date_encours,
|
|
|
MAX(p_sejours.ghs_id) AS ghs_id,
|
|
|
MAX(p_sejours.ghs_bebe1_id) AS ghs_bebe1_id,
|
|
|
MAX(p_sejours.ghs_bebe2_id) AS ghs_bebe2_id,
|
|
|
MAX(p_sejours.ghs_bebe3_id) AS ghs_bebe3_id,
|
|
|
MAX(p_sejours.ghm_id) AS ghm_id,
|
|
|
SUM(montant_facture) AS montant_facture_c,
|
|
|
0::numeric AS montant_facture_h,
|
|
|
0::numeric AS montant_regle_c,
|
|
|
0::numeric AS montant_regle_h,
|
|
|
0::numeric AS delai_facture,
|
|
|
0::numeric AS delai_solde,
|
|
|
'20991231'::date AS date_expedition,
|
|
|
0::numeric AS delai_expedition,
|
|
|
MAX(p_sejours.tiers_payant_1_id) AS tiers_payant_1_id,
|
|
|
MAX(p_sejours.tiers_payant_2_id) AS tiers_payant_2_id,
|
|
|
MAX(p_sejours.tiers_payant_22_id) AS tiers_payant_22_id,
|
|
|
MAX(p_sejours.tiers_payant_0_id) AS tiers_payant_0_id,
|
|
|
'20991231'::date AS date_solde_0_c,
|
|
|
'20991231'::date AS date_solde_0_h,
|
|
|
'20991231'::date AS date_solde_1_c,
|
|
|
'20991231'::date AS date_solde_1_h,
|
|
|
'20991231'::date AS date_solde_2_c,
|
|
|
'20991231'::date AS date_solde_2_h,
|
|
|
'20991231'::date AS date_solde_22_c,
|
|
|
'20991231'::date AS date_solde_22_h,
|
|
|
'20991231'::date AS date_expedition_0,
|
|
|
'20991231'::date AS date_expedition_1,
|
|
|
'20991231'::date AS date_expedition_2,
|
|
|
'20991231'::date AS date_expedition_22,
|
|
|
'0'::text AS code_expedie_0,
|
|
|
'0'::text AS code_expedie_1,
|
|
|
'0'::text AS code_expedie_2,
|
|
|
'0'::text AS code_expedie_22,
|
|
|
''::text AS no_bordereau_0,
|
|
|
''::text AS no_bordereau_1,
|
|
|
''::text AS no_bordereau_2,
|
|
|
''::text AS no_bordereau_22,
|
|
|
0::numeric AS montant_facture_0_c,
|
|
|
0::numeric AS montant_facture_0_h,
|
|
|
SUM(montant_facture) AS montant_facture_1_c,
|
|
|
0::numeric AS montant_facture_1_h,
|
|
|
0::numeric AS montant_facture_2_c,
|
|
|
0::numeric AS montant_facture_2_h,
|
|
|
0::numeric AS montant_facture_22_c,
|
|
|
0::numeric AS montant_facture_22_h,
|
|
|
0::numeric AS montant_regle_0_c,
|
|
|
0::numeric AS montant_regle_0_h,
|
|
|
0::numeric AS montant_regle_1_c,
|
|
|
0::numeric AS montant_regle_1_h,
|
|
|
0::numeric AS montant_regle_2_c,
|
|
|
0::numeric AS montant_regle_2_h,
|
|
|
0::numeric AS montant_regle_22_c,
|
|
|
0::numeric AS montant_regle_22_h,
|
|
|
0::numeric AS delai_expedition_0,
|
|
|
0::numeric AS delai_expedition_1,
|
|
|
0::numeric AS delai_expedition_2,
|
|
|
0::numeric AS delai_expedition_22,
|
|
|
0::numeric AS delai_solde_0_c,
|
|
|
0::numeric AS delai_solde_0_h,
|
|
|
0::numeric AS delai_solde_1_c,
|
|
|
0::numeric AS delai_solde_1_h,
|
|
|
0::numeric AS delai_solde_2_c,
|
|
|
0::numeric AS delai_solde_2_h,
|
|
|
0::numeric AS delai_solde_22_c,
|
|
|
0::numeric AS delai_solde_22_h,
|
|
|
0::numeric AS montant_encours_c,
|
|
|
0::numeric AS montant_encours_0_c,
|
|
|
0::numeric AS montant_encours_1_c,
|
|
|
0::numeric AS montant_encours_2_c,
|
|
|
0::numeric AS montant_encours_22_c,
|
|
|
0::numeric AS montant_encours_h,
|
|
|
0::numeric AS montant_encours_0_h,
|
|
|
0::numeric AS montant_encours_1_h,
|
|
|
0::numeric AS montant_encours_2_h,
|
|
|
0::numeric AS montant_encours_22_h,
|
|
|
0::numeric AS nb_rejets,
|
|
|
0::numeric AS montant_comptabilise_c,
|
|
|
0::numeric AS montant_comptabilise_h,
|
|
|
0::numeric AS montant_comptabilise_0_c,
|
|
|
0::numeric AS montant_comptabilise_0_h,
|
|
|
0::numeric AS montant_comptabilise_1_c,
|
|
|
0::numeric AS montant_comptabilise_1_h,
|
|
|
0::numeric AS montant_comptabilise_2_c,
|
|
|
0::numeric AS montant_comptabilise_2_h,
|
|
|
0::numeric AS montant_comptabilise_22_c,
|
|
|
0::numeric AS montant_comptabilise_22_h,
|
|
|
w_factures_lignes_pmsi.no_facture AS no_facture_reference,
|
|
|
0::bigint AS facture_reference_id,
|
|
|
'20991231'::date AS date_solde_reference,
|
|
|
'20991231'::date AS date_solde_reference_c,
|
|
|
'20991231'::date AS date_solde_reference_h,
|
|
|
'20991231'::date AS date_solde_reference_0_c,
|
|
|
'20991231'::date AS date_solde_reference_1_c,
|
|
|
'20991231'::date AS date_solde_reference_2_c,
|
|
|
'20991231'::date AS date_solde_reference_22_c,
|
|
|
'20991231'::date AS date_solde_reference_0_h,
|
|
|
'20991231'::date AS date_solde_reference_1_h,
|
|
|
'20991231'::date AS date_solde_reference_2_h,
|
|
|
'20991231'::date AS date_solde_reference_22_h,
|
|
|
'20991231'::date AS date_solde_c,
|
|
|
'20991231'::date AS date_solde_h,
|
|
|
0::numeric AS montant_facture_c_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_h_actes_inclus_dans_sejour,
|
|
|
SUM(montant_comptabilise_budget_global_1) AS montant_comptabilise_budget_global_c,
|
|
|
''::text AS no_facture_od_avoir,
|
|
|
0::bigint AS facture_od_avoir_id
|
|
|
FROM w_factures_lignes_pmsi
|
|
|
JOIN activite[PX].p_sejours ON w_factures_lignes_pmsi.no_sejour = p_sejours.no_sejour
|
|
|
WHERE w_factures_lignes_pmsi.no_facture LIKE '%BG'
|
|
|
GROUP BY 1,2,3,4,5;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- Ajout des factures
|
|
|
INSERT INTO activite[PX].p_factures
|
|
|
(no_sejour, no_facture, date_debut, date_fin, type_facture,
|
|
|
code_facture, date_facture, code_vente, mois_vente, date_solde,
|
|
|
montant_facture_c, montant_facture_h, montant_regle_c, montant_regle_h,
|
|
|
delai_facture, delai_solde, date_expedition, delai_expedition,
|
|
|
tiers_payant_1_id, tiers_payant_2_id, tiers_payant_22_id, tiers_payant_0_id,
|
|
|
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, date_vente, code_cloture, montant_encours_c,
|
|
|
montant_encours_0_c, montant_encours_1_c, montant_encours_2_c,
|
|
|
montant_encours_22_c, montant_encours_h, montant_encours_0_h,
|
|
|
montant_encours_1_h, montant_encours_2_h, montant_encours_22_h,
|
|
|
code_cp_demandee, date_encours, ghs_bebe1_id, ghs_bebe2_id, ghs_bebe3_id,
|
|
|
nb_rejets, 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, no_facture_reference, date_solde_reference,
|
|
|
date_solde_reference_c, date_solde_reference_h, date_solde_reference_0_c,
|
|
|
date_solde_reference_1_c, date_solde_reference_2_c, date_solde_reference_22_c,
|
|
|
date_solde_reference_0_h, date_solde_reference_1_h, date_solde_reference_2_h,
|
|
|
date_solde_reference_22_h, date_solde_c, date_solde_h, montant_facture_c_actes_inclus_dans_sejour,
|
|
|
montant_facture_h_actes_inclus_dans_sejour, montant_comptabilise_budget_global_c,
|
|
|
no_facture_od_avoir, sejour_id, facture_reference_id, facture_od_avoir_id,
|
|
|
ghm_id)
|
|
|
SELECt no_sejour, no_facture, date_debut, date_fin, type_facture,
|
|
|
code_facture, date_facture, code_vente, mois_vente, date_solde,
|
|
|
montant_facture_c, montant_facture_h, montant_regle_c, montant_regle_h,
|
|
|
delai_facture, delai_solde, date_expedition, delai_expedition,
|
|
|
tiers_payant_1_id, tiers_payant_2_id, tiers_payant_22_id, tiers_payant_0_id,
|
|
|
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, 'PMSIMCO' AS 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, date_vente, code_cloture, montant_encours_c,
|
|
|
montant_encours_0_c, montant_encours_1_c, montant_encours_2_c,
|
|
|
montant_encours_22_c, montant_encours_h, montant_encours_0_h,
|
|
|
montant_encours_1_h, montant_encours_2_h, montant_encours_22_h,
|
|
|
code_cp_demandee, date_encours, ghs_bebe1_id, ghs_bebe2_id, ghs_bebe3_id,
|
|
|
nb_rejets, 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, no_facture_reference, date_solde_reference,
|
|
|
date_solde_reference_c, date_solde_reference_h, date_solde_reference_0_c,
|
|
|
date_solde_reference_1_c, date_solde_reference_2_c, date_solde_reference_22_c,
|
|
|
date_solde_reference_0_h, date_solde_reference_1_h, date_solde_reference_2_h,
|
|
|
date_solde_reference_22_h, date_solde_c, date_solde_h, montant_facture_c_actes_inclus_dans_sejour,
|
|
|
montant_facture_h_actes_inclus_dans_sejour, montant_comptabilise_budget_global_c,
|
|
|
no_facture_od_avoir, sejour_id, facture_reference_id, facture_od_avoir_id,
|
|
|
ghm_id
|
|
|
FROM w_factures_pmsi;
|
|
|
|
|
|
|
|
|
|
|
|
-- Ajout des lignes
|
|
|
INSERT INTO activite[PX].p_factures_lignes_c(
|
|
|
no_facture, date_debut, date_fin, nb_rubrique, coefficient, coefficient_mco,
|
|
|
rubrique_facturation_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, rubrique_comptabilisation_id,
|
|
|
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, protocole_id, compte_produit_id)
|
|
|
SELECT
|
|
|
p_factures.no_facture, w_factures_lignes_pmsi.date_debut, w_factures_lignes_pmsi.date_fin, nb_rubrique, coefficient, coefficient_mco,
|
|
|
rubrique_facturation_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, rubrique_comptabilisation_id,
|
|
|
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,
|
|
|
p_factures.oid AS facture_id, protocole_id, compte_produit_id
|
|
|
FROM w_factures_lignes_pmsi
|
|
|
JOIN activite[PX].p_factures ON w_factures_lignes_pmsi.no_facture = p_factures.no_facture ;
|
|
|
|
|
|
|
|
|
|
|
|
-- Eclatement des supplements par jour
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_sup_c
|
|
|
;
|
|
|
|
|
|
CREATE TEMP TABLE w_factures_lignes_sup_c AS
|
|
|
with prestation as (
|
|
|
select
|
|
|
oid as t_prestations_oid,
|
|
|
code as t_prestations_code
|
|
|
from activite.t_prestations
|
|
|
where false
|
|
|
OR code IN ('PJ', 'FJ', 'SSM', 'GHS', 'EXH', 'SRC', 'REA', 'STF', 'NN1', 'NN2', 'NN3', 'CP', 'CPC', 'SHO')
|
|
|
OR t_prestations.type_ventilation_jour = '1'
|
|
|
)
|
|
|
, joined_tables as (
|
|
|
select
|
|
|
p_factures_lignes_c.CTID AS from_CTID,
|
|
|
t_prestations_code AS prestation_code,
|
|
|
p_sejours.date_entree,
|
|
|
p_sejours.date_sortie,
|
|
|
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 AND p_sejours.etat = ''
|
|
|
JOIN prestation as t_prestations ON prestation_id = t_prestations_oid
|
|
|
)
|
|
|
select
|
|
|
joined_tables.*,
|
|
|
date(date_entree) AS date_debut_ghs,
|
|
|
date(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 prestation_code = 'GHS' THEN date(date_entree + interval '1 day') ELSE date(date_debut + interval '1 day') END AS date_debut_det,
|
|
|
CASE WHEN prestation_code = 'GHS' THEN date(date_sortie - interval '1 day') ELSE date(date_debut + ((ABS(nb_prestation)-1) || ' day')::interval) END AS date_fin_det,
|
|
|
ABS(CASE WHEN prestation_code = 'GHS' THEN date(date_sortie) - date(date_entree) ELSE nb_prestation END) AS nb_det
|
|
|
from joined_tables
|
|
|
WHERE (nb_prestation > 1 or nb_prestation < -1 OR (prestation_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,
|
|
|
prestation_id,
|
|
|
compte_produit_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,
|
|
|
rubrique_comptabilisation_id,
|
|
|
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 date_debut BETWEEN p_calendrier.date - ABS(nb_det)::integer + 1 AND p_calendrier.date AND
|
|
|
p_calendrier.date <> date_debut ;
|
|
|
;
|
|
|
|
|
|
|
|
|
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;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_lignes_c(
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facturation_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,
|
|
|
finess,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
nb_prestation,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
rubrique_comptabilisation_id,
|
|
|
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_facturation_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,
|
|
|
finess,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
nb_prestation,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
rubrique_comptabilisation_id,
|
|
|
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;
|
|
|
|
|
|
|
|
|
-- Lieu exécution
|
|
|
|
|
|
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
|
|
|
p_factures_lignes_c.date_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
|
|
|
p_factures_lignes_c.lieu_id <> p_mouvements_sejour.lieu_id
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- En cours PMSI public
|
|
|
INSERT INTO activite[PX].p_factures(
|
|
|
sejour_id,
|
|
|
no_sejour,
|
|
|
no_facture,
|
|
|
no_facture_reference,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
type_facture,
|
|
|
code_facture,
|
|
|
date_facture,
|
|
|
tiers_payant_0_id,
|
|
|
tiers_payant_1_id,
|
|
|
tiers_payant_2_id,
|
|
|
tiers_payant_22_id,
|
|
|
ghs_id,
|
|
|
ghs_bebe1_id,
|
|
|
ghs_bebe2_id,
|
|
|
ghs_bebe3_id)
|
|
|
SELECT
|
|
|
p_sejours.oid,
|
|
|
p_sejours.no_sejour,
|
|
|
p_sejours.no_sejour || '.BG',
|
|
|
p_sejours.no_sejour || '.BG',
|
|
|
p_sejours.date_entree,
|
|
|
p_sejours.date_sortie,
|
|
|
'0',
|
|
|
'0',
|
|
|
'20991231'::date,
|
|
|
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.ghs_id,
|
|
|
p_sejours.ghs_bebe1_id,
|
|
|
p_sejours.ghs_bebe2_id,
|
|
|
p_sejours.ghs_bebe3_id
|
|
|
FROM pmsi.p_rss
|
|
|
JOIN base.t_finess ON p_rss.finess = t_finess.code AND t_finess.type_etablissement <> '1'
|
|
|
JOIN activite[PX].p_sejours on no_sejour_administratif = p_sejours.no_sejour AND p_sejours.est_budget_global = '1'
|
|
|
LEFT JOIN activite[PX].p_factures ON p_sejours.no_sejour = p_factures.no_sejour AND p_factures.no_facture LIKE '%BG'
|
|
|
WHERE p_rss.en_cours = '1' AND p_factures.no_facture IS NULL
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17;
|
|
|
|
|
|
-- Sejours BG PMSi qui ne sont pas dans les RSS
|
|
|
INSERT INTO activite[PX].p_factures(
|
|
|
sejour_id,
|
|
|
no_sejour,
|
|
|
no_facture,
|
|
|
no_facture_reference,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
type_facture,
|
|
|
code_facture,
|
|
|
date_facture,
|
|
|
tiers_payant_0_id,
|
|
|
tiers_payant_1_id,
|
|
|
tiers_payant_2_id,
|
|
|
tiers_payant_22_id,
|
|
|
ghs_id,
|
|
|
ghs_bebe1_id,
|
|
|
ghs_bebe2_id,
|
|
|
ghs_bebe3_id)
|
|
|
SELECT p_sejours.oid,
|
|
|
p_sejours.no_sejour,
|
|
|
p_sejours.no_sejour || '.BG',
|
|
|
p_sejours.no_sejour || '.BG',
|
|
|
p_sejours.date_entree,
|
|
|
p_sejours.date_sortie,
|
|
|
'0',
|
|
|
'0',
|
|
|
'20991231'::date,
|
|
|
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.ghs_id,
|
|
|
p_sejours.ghs_bebe1_id,
|
|
|
p_sejours.ghs_bebe2_id,
|
|
|
p_sejours.ghs_bebe3_id
|
|
|
FROM activite[PX].p_sejours
|
|
|
JOIN activite[PX].t_lieux ON lieu_sortie_id = t_lieux.oid
|
|
|
JOIN activite[PX].t_services_facturation ON service_facturation_id = t_services_facturation.oid
|
|
|
WHERE p_sejours.est_budget_global = '1' AND
|
|
|
type_t2a = '1' AND
|
|
|
date_entree between now() - interval '1 year' AND now() AND
|
|
|
code_sorti = '1' AND
|
|
|
no_sejour NOT IN (SELECt no_sejour FROM activite[PX].p_factures where no_facture like '%BG') AND
|
|
|
no_sejour NOT IN (
|
|
|
SELECT p_factures.no_sejour
|
|
|
FROM activite[PX].p_factures
|
|
|
JOIN activite[PX].p_factures_lignes_c ON p_factures_lignes_c.no_facture = p_factures.no_facture
|
|
|
JOIN activite.t_prestations ON prestation_id = t_prestations.oid
|
|
|
WHERE t_prestations.code = 'GHS' AND montant_facture > 0
|
|
|
) AND
|
|
|
no_sejour NOT IN (
|
|
|
SELECT p_factures.no_sejour
|
|
|
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
|
|
|
WHERE p_sejours.est_budget_global = '1' AND
|
|
|
code_facture = '1' AND
|
|
|
(t_prestations.code = 'PJ' OR type_valorisation_non_facture = 'PJ') AND
|
|
|
(taux_2 = 100 OR taux_0 = 100)
|
|
|
GROUP BY 1
|
|
|
HAVING SUM(montant_facture_0+montant_facture_2) > 0
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
-- Factures non assurés ajoutées à tord (on trouve un 100% dans patient ou tp1
|
|
|
DROP TABLE IF EXISTS w_sejours_bg_24;
|
|
|
CREATE TEMP TABLE w_sejours_bg_24 AS
|
|
|
SELECT p_factures.no_sejour, SUM(montant_facture_0+montant_facture_1+montant_facture_2) AS montant_facture_100
|
|
|
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
|
|
|
JOIN activite[PX].p_sejour_pmsi ON p_sejour_pmsi.sejour_id = p_sejours.oid
|
|
|
JOIN pmsi.p_rss ON p_sejour_pmsi.rss_id = p_rss.oid
|
|
|
WHERE p_sejours.est_budget_global = '1' AND
|
|
|
code_facture = '1' AND
|
|
|
(t_prestations.code = 'PJ' OR type_valorisation_non_facture = 'PJ') AND
|
|
|
(taux_1 + taux_2 + taux_0 = 100 OR
|
|
|
taux_0+taux_1+taux_2=0 AND montant_facture_1 = montant_facture
|
|
|
) AND
|
|
|
p_rss.traitement_epmsi NOT IN ('30','31','32','33')
|
|
|
GROUP BY 1
|
|
|
HAVING SUM(montant_facture_0+montant_facture_1+montant_facture_2) > 0
|
|
|
ORDER BY 1;
|
|
|
|
|
|
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
|
|
|
p_factures.no_sejour IN (SELECT no_sejour FROM w_sejours_bg_24) AND
|
|
|
p_factures_lignes_c.no_facture LIKE '%BG' AND
|
|
|
origine_facturation_id = 1;
|
|
|
|
|
|
UPDATE activite[PX].p_factures SET
|
|
|
code_facture = '1',
|
|
|
montant_facture_c = 0,
|
|
|
montant_facture_1_c = 0,
|
|
|
montant_comptabilise_1_c =0,
|
|
|
montant_comptabilise_budget_global_c = 0
|
|
|
WHERE no_sejour IN (SELECT no_sejour FROM w_sejours_bg_24) AND
|
|
|
no_facture LIKE '%BG' AND
|
|
|
montant_comptabilise_budget_global_c = 0;
|
|
|
|
|
|
|
|
|
-- Suppression des factures encours externes ajoutées à tord
|
|
|
DROP TABLE IF EXISTS w_factures_externes_double_bg;
|
|
|
CREATE TEMP TABLE w_factures_externes_double_bg AS
|
|
|
SELECT p_factures.no_sejour,
|
|
|
MAX(CASE WHEN code_facture = '0' AND p_factures.montant_facture_c = 0 THEN no_facture ELSE '' END) AS no_facture_encours,
|
|
|
MAX(CASE WHEN code_facture = '1' AND no_facture LIKE '%BG%' THEN no_facture ELSE '' END) AS no_facture_bg
|
|
|
FROM activite[PX].p_factures
|
|
|
JOIN activite[PX].p_sejours ON p_factures.no_sejour = p_sejours.no_sejour
|
|
|
WHERE p_sejours.type_sejour = '3'
|
|
|
GROUP BY 1
|
|
|
HAVING MAX(CASE WHEN code_facture = '0' THEN no_facture ELSE '' END) <> '' AND MAX(CASE WHEN code_facture = '1' AND no_facture LIKE '%BG%' THEN no_facture ELSE '' END) <> ''
|
|
|
;
|
|
|
|
|
|
DELETE FROM activite[PX].p_factures
|
|
|
WHERE code_facture = '0' AND
|
|
|
montant_facture_c = 0 AND
|
|
|
no_facture IN (SELECT no_facture_encours FROM w_factures_externes_double_bg)
|
|
|
;
|
|
|
|
|
|
DELETE FROM activite[PX].p_factures_lignes_non_facturees_c
|
|
|
WHERE no_facture IN (SELECT no_facture_encours FROM w_factures_externes_double_bg)
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Affectation facture de reference pour lignes non facturées (surtout pour ESPIC car possibilite d'avoir deux factures non facturees)
|
|
|
-- Recopie depuis SHARE
|
|
|
DROP TABLE IF EXISTS w_sejours_facture_reference;
|
|
|
|
|
|
CREATE TEMP TABLE w_sejours_facture_reference AS
|
|
|
SELECT
|
|
|
p_sejours.no_sejour,
|
|
|
CASE WHEN avec_facturation_intermediaire IS DISTINCT FROM '1' THEN p_sejours.date_sortie ELSE p_factures.date_fin END AS date_fin,
|
|
|
MIN(CASE WHEN avec_facturation_intermediaire IS DISTINCT FROM '1' THEN p_sejours.date_entree ELSE p_factures.date_debut END) AS date_debut,
|
|
|
MAX(p_factures.no_facture) AS no_facture_last,
|
|
|
MAX(CASE WHEN p_factures.no_facture NOT LIKE '%.DMA' AND type_facture <> '1' AND type_facture <> 'X' AND type_facture <> 'P' THEN p_factures.no_facture ELSE null END) AS no_facture_reference_last,
|
|
|
(MAX(ARRAY[to_char(
|
|
|
CASE
|
|
|
WHEN p_factures.no_facture NOT LIKE '%.DMA' AND type_facture <> '1' AND type_facture <> 'X' AND type_facture <> 'P' AND (t_prestations.code IN ('GHS','PJ') OR (p_factures.no_facture LIKE '%BG' AND p_sejours.type_sejour IN ('1','2','5','6'))) THEN p_factures_lignes_c.taux_1
|
|
|
ELSE 0 END
|
|
|
,'FM00000'),
|
|
|
CASE
|
|
|
WHEN p_factures.no_facture NOT LIKE '%.DMA' AND type_facture <> '1' AND type_facture <> 'X' AND type_facture <> 'P' AND (t_prestations.code IN ('GHS','PJ') OR (p_factures.no_facture LIKE '%BG' AND p_sejours.type_sejour IN ('1','2','5','6'))) THEN p_factures.no_facture
|
|
|
ELSE NULL END
|
|
|
]
|
|
|
))[2] AS no_facture_reference_sejour_last,
|
|
|
COUNT(DISTINCT p_factures.no_facture) AS nb_factures,
|
|
|
MAX(avec_facturation_intermediaire) AS avec_facturation_intermediaire
|
|
|
FROM activite[PX].p_factures
|
|
|
JOIN activite[PX].p_sejours ON p_factures.no_sejour = p_sejours.no_sejour
|
|
|
JOIN activite[PX].t_lieux ON p_sejours.lieu_sortie_id = t_lieux.oid
|
|
|
JOIN activite[PX].t_services_facturation ON service_facturation_id = t_services_facturation.oid
|
|
|
LEFT JOIN activite[PX].p_factures_lignes_c ON p_factures.no_facture = p_factures_lignes_c.no_facture
|
|
|
LEFT JOIN activite.t_prestations ON p_factures_lignes_c.prestation_id = t_prestations.oid AND t_prestations.code IN ('GHS','PJ')
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
CREATE INDEX w_sejours_facture_reference_i1
|
|
|
ON w_sejours_facture_reference
|
|
|
USING btree
|
|
|
(no_sejour)
|
|
|
;
|
|
|
|
|
|
-- Cas d'une facture, d'un avoir et dune autre facture, il faut privilégier l'autre facture
|
|
|
UPDATE w_sejours_facture_reference
|
|
|
SET no_facture_reference_sejour_last = subview.no_facture_reference
|
|
|
FROM
|
|
|
(
|
|
|
SELECT p_factures.no_sejour,
|
|
|
CASE WHEN avec_facturation_intermediaire IS DISTINCT FROM '1' THEN p_sejours.date_sortie ELSE p_factures.date_fin END AS date_fin,
|
|
|
MAX(CASE WHEN type_facture <> '1' AND type_facture <> 'X' THEN no_facture ELSE NULL END) AS no_facture_reference
|
|
|
FROM activite[PX].p_factures
|
|
|
JOIN activite[PX].p_sejours ON p_factures.no_sejour = p_sejours.no_sejour
|
|
|
JOIN activite[PX].t_lieux ON p_sejours.lieu_sortie_id = t_lieux.oid
|
|
|
JOIN activite[PX].t_services_facturation ON service_facturation_id = t_services_facturation.oid
|
|
|
WHERE p_factures.no_facture NOT LIKE '%.DMA'
|
|
|
GROUP BY 1,2
|
|
|
HAVING SUM(CASE WHEN type_facture <> '1' AND type_facture <> 'X' THEN 1 ELSE 0 END) = 1 AND
|
|
|
SUM(CASE WHEN type_facture = '1' THEN 1 ELSE 0 END) = SUM(CASE WHEN type_facture = 'X' THEN 1 ELSE 0 END) AND
|
|
|
SUM(CASE WHEN type_facture = 'X' THEN 1 ELSE 0 END) > 0
|
|
|
) subview
|
|
|
WHERE w_sejours_facture_reference.no_sejour = subview.no_sejour AND
|
|
|
w_sejours_facture_reference.date_fin = subview.date_fin AND
|
|
|
no_facture_reference_sejour_last IS DISTINCT FROM subview.no_facture_reference
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].p_factures
|
|
|
SET no_facture_reference = COALESCE(no_facture_reference_sejour_last, no_facture_reference_last, no_facture_last)
|
|
|
FROM w_sejours_facture_reference
|
|
|
JOIN activite[PX].p_sejours ON p_sejours.no_sejour = w_sejours_facture_reference.no_sejour
|
|
|
WHERE p_factures.no_sejour = w_sejours_facture_reference.no_sejour AND
|
|
|
(
|
|
|
p_factures.date_fin = w_sejours_facture_reference.date_fin OR
|
|
|
p_factures.date_fin = p_sejours.date_sortie AND avec_facturation_intermediaire IS DISTINCT FROM '1'
|
|
|
|
|
|
) AND
|
|
|
p_factures.no_facture_reference <> COALESCE(no_facture_reference_sejour_last, no_facture_reference_last, no_facture_last);
|
|
|
|
|
|
UPDATE activite[PX].p_factures
|
|
|
SET facture_reference_id = p_factures_references.oid
|
|
|
FROM activite[PX].p_factures p_factures_references
|
|
|
WHERE p_factures.no_facture_reference = p_factures_references.no_facture
|
|
|
AND p_factures.facture_reference_id <> p_factures_references.oid
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
|
|
|
<NODE label="Compte client Clinique">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_soldes_c;
|
|
|
CREATE TEMP TABLE w_factures_soldes_c AS
|
|
|
SELECT
|
|
|
''::text AS finess,
|
|
|
RECF_NUMFACTALIAS_ETAB AS no_facture,
|
|
|
COALESCE(p_factures.oid,0) AS facture_id,
|
|
|
date_trunc('month',p_factures.date_vente) AS date_comptable,
|
|
|
rubrique_facturation_id AS rubrique_comptabilisee_id,
|
|
|
prestation_id,
|
|
|
'0'::text AS od_avoir,
|
|
|
'0'::text AS od_non_comptabilise,
|
|
|
SUM(RECT_MONTANT_CPT) as montant_comptabilise,
|
|
|
SUM(RECT_MONTANT_CPT_0) as montant_comptabilise_0,
|
|
|
SUM(RECT_MONTANT_CPT_1) as montant_comptabilise_1,
|
|
|
SUM(RECT_MONTANT_CPT_2) as montant_comptabilise_2,
|
|
|
SUM(RECT_MONTANT_CPT_22) as montant_comptabilise_22,
|
|
|
0::numeric AS montant_regle,
|
|
|
0::numeric AS montant_regle_0,
|
|
|
0::numeric AS montant_regle_1,
|
|
|
0::numeric AS montant_regle_2,
|
|
|
0::numeric AS montant_regle_22
|
|
|
FROM w_MPM_RECUEILTIERS_RECT
|
|
|
JOIN w_MPM_RECUEILTIERS_RECT_keys ON w_MPM_RECUEILTIERS_RECT.key = w_MPM_RECUEILTIERS_RECT_keys.key
|
|
|
JOIN activite[PX].p_factures ON no_facture = RECF_NUMFACTALIAS_ETAB
|
|
|
WHERE
|
|
|
w_MPM_RECUEILTIERS_RECT.RECG_TYPELIGNE_CPTA = 3 AND
|
|
|
RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 AND
|
|
|
p_factures.code_vente = '1'
|
|
|
GROUP BY 1,2,3,4,5,6;
|
|
|
|
|
|
INSERT INTO w_factures_soldes_c
|
|
|
SELECT
|
|
|
''::text AS finess,
|
|
|
RECF_NUMFACTALIAS_ETAB AS no_facture,
|
|
|
COALESCE(p_factures.oid,0) AS facture_id,
|
|
|
date_trunc('month',COALESCE(REGD_DATEECRITURE,REGD_DATEENCAIS)) AS date_comptable,
|
|
|
rubrique_facturation_id AS rubrique_comptabilisee_id,
|
|
|
prestation_id,
|
|
|
'0'::text AS od_avoir,
|
|
|
CASE WHEN REGD_DATEECRITURE IS NULL THEN '1'::text ELSE '0'::text END AS od_non_comptabilise,
|
|
|
0::numeric AS montant_comptabilise,
|
|
|
0::numeric AS montant_comptabilise_0,
|
|
|
0::numeric AS montant_comptabilise_1,
|
|
|
0::numeric AS montant_comptabilise_2,
|
|
|
0::numeric AS montant_comptabilise_22,
|
|
|
SUM(REGD_MNTENCAIS) as montant_regle,
|
|
|
SUM(CASE WHEN (RECT_TYPEDEBITEUR = 'D' OR ASSU_ID IS NULL) THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_0,
|
|
|
SUM(CASE WHEN ASSU_TYPE = 'O' THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_1_c,
|
|
|
SUM(CASE WHEN ASSU_TYPE = 'C' AND ASSU_DISTINCTIF = 1 THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_2,
|
|
|
SUM(CASE WHEN ASSU_TYPE = 'C' AND ASSU_DISTINCTIF <> 1 THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_22
|
|
|
FROM w_MPM_RECUEILTIERS_RECT
|
|
|
JOIN w_MPM_RECUEILTIERS_RECT_keys ON w_MPM_RECUEILTIERS_RECT.key = w_MPM_RECUEILTIERS_RECT_keys.key
|
|
|
JOIN activite[PX].p_factures ON no_facture = RECF_NUMFACTALIAS_ETAB
|
|
|
JOIN prod_csis.MRC_REGLEMENTDETAIL_REGD ON REGD_ID_RECT = RECT_ID
|
|
|
WHERE
|
|
|
w_MPM_RECUEILTIERS_RECT.RECG_TYPELIGNE_CPTA = 3 AND
|
|
|
REGD_CODETYOP NOT IN ('AC', 'MC', 'BG')
|
|
|
GROUP BY 1,2,3,4,5,6,7,8;
|
|
|
|
|
|
-- Acomptes NOEMIE
|
|
|
DROP TABLE IF EXISTS w_MRC_FACTNOEMIEENCAIS_FNOE;
|
|
|
CREATE TEMP TABLE w_MRC_FACTNOEMIEENCAIS_FNOE AS
|
|
|
SELECT RECF_NUMFACTALIAS_ETAB,
|
|
|
FNOE_MNTENCAIS,
|
|
|
FNOE_DATEENCAIS,
|
|
|
FNOE_DATEECRITURE
|
|
|
FROM prod_csis.MRC_FACTNOEMIEENCAIS_FNOE
|
|
|
JOIN w_MPM_FACTURE_RECF ON FNOE_ID_RECF = RECF_ID
|
|
|
JOIN w_SST_ETABLISSEMENT_ETAB ON FNOE_ID_ETAB = ETAB_ID
|
|
|
WHERE FNOE_ID_REGD = 0
|
|
|
;
|
|
|
|
|
|
ANALYSE w_MRC_FACTNOEMIEENCAIS_FNOE
|
|
|
;
|
|
|
|
|
|
-- Il y a quelquefois des reprises sans acompte initial
|
|
|
INSERT INTO w_MRC_FACTNOEMIEENCAIS_FNOE
|
|
|
SELECT RECF_NUMFACTALIAS_ETAB,
|
|
|
0-SUM(FNOE_MNTENCAIS) AS FNOE_MNTENCAIS,
|
|
|
MAX(FNOE_DATEENCAIS) AS FNOE_DATEENCAIS,
|
|
|
NULL::date AS FNOE_DATEECRITURE
|
|
|
FROM w_MRC_FACTNOEMIEENCAIS_FNOE
|
|
|
GROUP BY 1
|
|
|
HAVING SUM(FNOE_MNTENCAIS) < 0
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].p_factures SET
|
|
|
montant_regle_c = montant_regle_c + FNOE_MNTENCAIS,
|
|
|
montant_regle_1_c = montant_regle_1_c + + FNOE_MNTENCAIS
|
|
|
FROM
|
|
|
(
|
|
|
SELECT RECF_NUMFACTALIAS_ETAB,
|
|
|
0-SUM(FNOE_MNTENCAIS) AS FNOE_MNTENCAIS,
|
|
|
MAX(FNOE_DATEENCAIS) AS FNOE_DATEENCAIS,
|
|
|
NULL::date AS FNOE_DATEECRITURE
|
|
|
FROM w_MRC_FACTNOEMIEENCAIS_FNOE
|
|
|
GROUP BY 1
|
|
|
HAVING SUM(FNOE_MNTENCAIS) <> 0
|
|
|
) subview
|
|
|
WHERE p_factures.no_facture = RECF_NUMFACTALIAS_ETAB
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO w_factures_soldes_c
|
|
|
SELECT
|
|
|
''::text AS finess,
|
|
|
RECF_NUMFACTALIAS_ETAB AS no_facture,
|
|
|
COALESCE(p_factures.oid,0) AS facture_id,
|
|
|
date_trunc('month',COALESCE(FNOE_DATEECRITURE,FNOE_DATEENCAIS)) AS date_comptable,
|
|
|
0::bigint AS rubrique_comptabilisee_id,
|
|
|
0::bigint AS prestation_id,
|
|
|
'0'::text AS od_avoir,
|
|
|
CASE WHEN FNOE_DATEECRITURE IS NULL THEN '1'::text ELSE '0'::text END AS od_non_comptabilise,
|
|
|
0::numeric AS montant_comptabilise,
|
|
|
0::numeric AS montant_comptabilise_0,
|
|
|
0::numeric AS montant_comptabilise_1,
|
|
|
0::numeric AS montant_comptabilise_2,
|
|
|
0::numeric AS montant_comptabilise_22,
|
|
|
SUM(FNOE_MNTENCAIS) as montant_regle,
|
|
|
0::numeric as montant_regle_0,
|
|
|
SUM(FNOE_MNTENCAIS) as montant_regle_1_c,
|
|
|
0::numeric as montant_regle_2,
|
|
|
0::numeric as montant_regle_22
|
|
|
FROM w_MRC_FACTNOEMIEENCAIS_FNOE
|
|
|
JOIN activite.p_factures ON no_facture = RECF_NUMFACTALIAS_ETAB
|
|
|
GROUP BY 1,2,3,4,5,6,7,8
|
|
|
HAVING SUM(FNOE_MNTENCAIS) <> 0
|
|
|
;
|
|
|
|
|
|
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 (
|
|
|
finess,
|
|
|
no_facture,
|
|
|
facture_id,
|
|
|
date_comptable,
|
|
|
od_avoir,
|
|
|
od_non_comptabilise,
|
|
|
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
|
|
|
finess,
|
|
|
no_facture,
|
|
|
facture_id,
|
|
|
date_comptable,
|
|
|
od_avoir,
|
|
|
od_non_comptabilise,
|
|
|
rubrique_comptabilisee_id,
|
|
|
prestation_id,
|
|
|
SUM(montant_comptabilise),
|
|
|
SUM(montant_comptabilise_0),
|
|
|
SUM(montant_comptabilise_1),
|
|
|
SUM(montant_comptabilise_2),
|
|
|
SUM(montant_comptabilise_22),
|
|
|
SUM(montant_regle),
|
|
|
SUM(montant_regle_0),
|
|
|
SUM(montant_regle_1),
|
|
|
SUM(montant_regle_2),
|
|
|
SUM(montant_regle_22)
|
|
|
FROM w_factures_soldes_c
|
|
|
GROUP BY 1,2,3,4,5,6,7,8;
|
|
|
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_soldes_c_1');
|
|
|
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[
|
|
|
|
|
|
|
|
|
TRUNCATE activite[PX].p_factures_lignes_non_facturees_h;
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_lignes_non_facturees_h(
|
|
|
no_facture,
|
|
|
facture_id,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
heure_debut,
|
|
|
nb_rubrique,
|
|
|
coefficient,
|
|
|
medecin_facture_id,
|
|
|
prestation_id,
|
|
|
prix_unitaire,
|
|
|
montant_depassement,
|
|
|
lieu_id,
|
|
|
acte_id,
|
|
|
phase_ccam,
|
|
|
activite_ccam,
|
|
|
extension_ccam,
|
|
|
modificateur_ccam_1,
|
|
|
modificateur_ccam_2,
|
|
|
modificateur_ccam_3,
|
|
|
modificateur_ccam_4)
|
|
|
SELECT
|
|
|
p_factures.no_facture,
|
|
|
p_factures.oid AS facture_id,
|
|
|
date(RECG_DATEDEBUT) AS date_debut,
|
|
|
date(COALESCE(RECG_DATEFIN, RECG_DATEDEBUT)) AS date_fin,
|
|
|
extract('hour' FROM COALESCE(RECC_DATEACTE, RECG_DATEDEBUT)) AS heure_debut,
|
|
|
RECG_QUANTITE AS nb_rubrique,
|
|
|
RECG_COEFFICIENT AS coefficient,
|
|
|
COALESCE(t_medecins_administratifs.oid,0) AS medecin_facture_id,
|
|
|
t_prestations.oid AS prestation_id,
|
|
|
RECG_PUFACTURE AS prix_unitaire,
|
|
|
0::numeric AS montant_depassement,
|
|
|
p_sejours.lieu_sortie_id AS lieu_id,
|
|
|
t_actes.oid AS acte_id,
|
|
|
COALESCE(RECC_CODEPHASE,'') AS phase_ccam,
|
|
|
COALESCE(RECC_CODEACTIVITE,'') AS activite_ccam,
|
|
|
COALESCE(RECC_CODEEXTENSIONDOC,'') AS extension_ccam,
|
|
|
COALESCE(RECC_CODEMODIFICATEUR1,'') AS modificateur_ccam_1,
|
|
|
COALESCE(RECC_CODEMODIFICATEUR2,'') AS modificateur_ccam_2,
|
|
|
COALESCE(RECC_CODEMODIFICATEUR3,'') AS modificateur_ccam_3,
|
|
|
COALESCE(RECC_CODEMODIFICATEUR4,'') AS modificateur_ccam_4
|
|
|
FROM prod_csis.MPM_RECUEIL_RECG
|
|
|
LEFT JOIN prod_csis.MPM_RECUEILCCAM_RECC ON (RECC_ID_RECG = RECG_ID)
|
|
|
JOIN prod_csis.SID_DOSSIERADMINISTRATIF_DADM ON RECG_ID_DADM = DADM_ID
|
|
|
JOIN w_SST_PRESTATIONETAB_PRTB ON RECG_ID_PRTB = PRTB_ID
|
|
|
JOIN prod_csis.SST_PRESTATION_PRES ON PRTB_ID_PRES = PRES_ID
|
|
|
JOIN activite[PX].p_sejours ON RECG_ID_DADM = p_sejours.code_original AND p_sejours.etat = ''
|
|
|
JOIN activite[PX].p_factures ON
|
|
|
p_sejours.no_sejour = p_factures.no_sejour AND type_facture IN ('E','0') AND
|
|
|
code_facture <> '1' AND
|
|
|
date(RECG_DATEDEBUT) BETWEEN p_factures.date_debut AND p_factures.date_fin AND
|
|
|
p_factures.no_facture NOT LIKE '%BG'
|
|
|
JOIN activite.t_prestations ON PRES_CODE = t_prestations.code
|
|
|
JOIN base.t_actes ON COALESCE(RECC_CODECCAM,RECG_PRESTATION) = t_actes.code
|
|
|
LEFT JOIN activite[PX].t_medecins_administratifs ON t_medecins_administratifs.code_original = RECG_ID1_MEDN
|
|
|
WHERE RECG_TYPELIGNE IN (4)
|
|
|
;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Lignes factures Honoraires">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
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 (
|
|
|
finess,
|
|
|
no_facture,
|
|
|
facture_id,
|
|
|
date_debut,
|
|
|
heure_debut,
|
|
|
date_fin,
|
|
|
lieu_id,
|
|
|
acte_id,
|
|
|
phase_ccam,
|
|
|
activite_ccam,
|
|
|
extension_ccam,
|
|
|
modificateur_ccam_1,
|
|
|
modificateur_ccam_2,
|
|
|
modificateur_ccam_3,
|
|
|
modificateur_ccam_4,
|
|
|
medecin_facture_id,
|
|
|
medecin_comptabilise_id,
|
|
|
prestation_id,
|
|
|
nb_rubrique,
|
|
|
nb_prestation,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
prix_unitaire,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
montant_facture_22,
|
|
|
montant_depassement,
|
|
|
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
|
|
|
)
|
|
|
SELECT
|
|
|
''::text AS finess,
|
|
|
RECF_NUMFACTALIAS_ETAB AS no_facture,
|
|
|
p_factures.oid AS facture_id,
|
|
|
COALESCE(RECC_DATEACTE, RECG_DATEDEBUT) AS date_debut,
|
|
|
extract('hour' FROM COALESCE(RECC_DATEACTE, RECG_DATEDEBUT)) AS heure_debut,
|
|
|
COALESCE(RECG_DATEFIN,RECG_DATEDEBUT) AS date_fin,
|
|
|
p_sejours.lieu_sortie_id AS lieu_id,
|
|
|
w_MPM_RECUEILTIERS_RECT_keys.acte_id,
|
|
|
COALESCE(RECC_CODEPHASE,'') AS phase_ccam,
|
|
|
COALESCE(RECC_CODEACTIVITE,'') AS activite_ccam,
|
|
|
COALESCE(RECC_CODEEXTENSIONDOC,'') AS extension_ccam,
|
|
|
COALESCE(RECC_CODEMODIFICATEUR1,'') AS modificateur_ccam_1,
|
|
|
COALESCE(RECC_CODEMODIFICATEUR2,'') AS modificateur_ccam_2,
|
|
|
COALESCE(RECC_CODEMODIFICATEUR3,'') AS modificateur_ccam_3,
|
|
|
COALESCE(RECC_CODEMODIFICATEUR4,'') AS modificateur_ccam_4,
|
|
|
w_MPM_RECUEILTIERS_RECT_keys.medecin_id AS medecin_facture_id,
|
|
|
w_MPM_RECUEILTIERS_RECT_keys.medecin_id AS medecin_comptabilise_id,
|
|
|
w_MPM_RECUEILTIERS_RECT_keys.prestation_id,
|
|
|
RECG_QUANTITE AS nb_rubrique,
|
|
|
RECG_QUANTITE AS nb_prestation,
|
|
|
CASE WHEN RECG_COEFFICIENT <> 0 THEN RECG_COEFFICIENT ELSE 1 END AS coefficient,
|
|
|
CASE WHEN RECG_COEFFICIENTMCO <> 0 THEN RECG_COEFFICIENTMCO ELSE 1 END AS coefficient_mco,
|
|
|
RECG_PUFACTURE AS prix_unitaire,
|
|
|
MAX(RECT_TAUX_0) as taux_0,
|
|
|
MAX(RECT_TAUX_1) as taux_1,
|
|
|
MAX(RECT_TAUX_2) as taux_2,
|
|
|
MAX(RECT_TAUX_22) as taux_22,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (4,34) THEN RECT_MONTANT_FAC ELSE 0 END) as montant_facture,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (4,34) THEN RECT_MONTANT_FAC_0 ELSE 0 END) as montant_facture_0,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (4,34) THEN RECT_MONTANT_FAC_1 ELSE 0 END) as montant_facture_1,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (4,34) THEN RECT_MONTANT_FAC_2 ELSE 0 END) as montant_facture_2,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE IN (4,34) THEN RECT_MONTANT_FAC_22 ELSE 0 END) as montant_facture_22,
|
|
|
SUM(RECT_MONTANTDHO) as montant_depassement,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 THEN RECT_MONTANT_CPT ELSE 0 END) as montant_comptabilise,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 THEN RECT_MONTANT_CPT_0 ELSE 0 END) as montant_comptabilise_0,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 THEN RECT_MONTANT_CPT_1 ELSE 0 END) as montant_comptabilise_1,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 THEN RECT_MONTANT_CPT_2 ELSE 0 END) as montant_comptabilise_2,
|
|
|
SUM(CASE WHEN RECG_TYPELIGNE_CPTA = 4 THEN RECT_MONTANT_CPT_22 ELSE 0 END) as montant_comptabilise_22,
|
|
|
0::numeric AS montant_encours,
|
|
|
0::numeric AS montant_encours_0,
|
|
|
0::numeric AS montant_encours_1,
|
|
|
0::numeric AS montant_encours_2,
|
|
|
0::numeric AS montant_encours_22,
|
|
|
0::numeric AS montant_facture_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_0_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_1_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_2_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_22_actes_inclus_dans_sejour
|
|
|
|
|
|
FROM w_MPM_RECUEILTIERS_RECT
|
|
|
JOIN w_MPM_RECUEILTIERS_RECT_keys ON w_MPM_RECUEILTIERS_RECT.key = w_MPM_RECUEILTIERS_RECT_keys.key
|
|
|
JOIN activite[PX].p_factures ON no_facture = RECF_NUMFACTALIAS_ETAB
|
|
|
JOIN activite[PX].p_sejours ON p_sejours.oid = p_factures.sejour_id AND p_sejours.etat = ''
|
|
|
|
|
|
WHERE
|
|
|
w_MPM_RECUEILTIERS_RECT.RECG_TYPELIGNE IN (4,34) AND RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 AND code_facture <> '0'
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,14,15,16,17,18,19,20,21,22,23;
|
|
|
|
|
|
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');
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures_lignes_h
|
|
|
SET lieu_id = p_mouvements_sejour.lieu_id
|
|
|
FROM activite[PX].p_factures, activite[PX].p_mouvements_sejour
|
|
|
WHERE p_factures_lignes_h.no_facture = p_factures.no_facture AND
|
|
|
p_factures.no_sejour = p_mouvements_sejour.no_sejour AND
|
|
|
activite[PX].p_factures_lignes_h.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_h.lieu_id <> p_mouvements_sejour.lieu_id;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Actes inclus (Budget Global MCO)">
|
|
|
<condition><![CDATA[
|
|
|
"[ENV_TYPEETS]" != "1" && "[ENV_WITHPMSI]" == "1"
|
|
|
]]></condition>
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Pointage des actes en facturation
|
|
|
UPDATE prod_csis.SCA_PRESTATION_PRET
|
|
|
SET PRET_STATUT = 'F'
|
|
|
FROM
|
|
|
(
|
|
|
SELECT RECG_ID_DADM, RECG_ID_PRTB
|
|
|
FROM prod_csis.MPM_RECUEIL_RECG
|
|
|
WHERE RECG_TYPELIGNE = 4
|
|
|
GROUP BY 1,2
|
|
|
) subview
|
|
|
WHERE
|
|
|
PRET_ID_DADM = RECG_ID_DADM AND
|
|
|
PRET_ID_PRTB = RECG_ID_PRTB AND
|
|
|
PRET_STATUT = 'V'
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_lignes_h (
|
|
|
finess,
|
|
|
no_facture,
|
|
|
facture_id,
|
|
|
date_debut,
|
|
|
heure_debut,
|
|
|
date_fin,
|
|
|
lieu_id,
|
|
|
acte_id,
|
|
|
phase_ccam,
|
|
|
activite_ccam,
|
|
|
extension_ccam,
|
|
|
modificateur_ccam_1,
|
|
|
modificateur_ccam_2,
|
|
|
modificateur_ccam_3,
|
|
|
modificateur_ccam_4,
|
|
|
medecin_facture_id,
|
|
|
medecin_comptabilise_id,
|
|
|
prestation_id,
|
|
|
nb_rubrique,
|
|
|
nb_prestation,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
prix_unitaire,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
montant_facture_22,
|
|
|
montant_depassement,
|
|
|
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
|
|
|
)
|
|
|
SELECT
|
|
|
''::text AS finess,
|
|
|
p_factures.no_facture,
|
|
|
p_factures.oid AS facture_id,
|
|
|
date(PRET_DATEDEBUT) AS date_debut,
|
|
|
extract('hour' FROM PRET_DATEDEBUT) AS heure_debut,
|
|
|
date(COALESCE(PRET_DATEFIN, PRET_DATEDEBUT)) AS date_fin,
|
|
|
p_sejours.lieu_sortie_id AS lieu_id,
|
|
|
t_actes.oid AS acte_id,
|
|
|
''::text AS phase_ccam,
|
|
|
''::text AS activite_ccam,
|
|
|
''::text AS extension_ccam,
|
|
|
''::text AS modificateur_ccam_1,
|
|
|
''::text AS modificateur_ccam_2,
|
|
|
''::text AS modificateur_ccam_3,
|
|
|
''::text AS modificateur_ccam_4,
|
|
|
COALESCE(t_medecins_administratifs.oid,0) AS medecin_facture_id,
|
|
|
COALESCE(t_medecins_administratifs.oid,0) AS medecin_comptabilise_id,
|
|
|
t_prestations.oid AS prestation_id,
|
|
|
PRET_QUANTITE AS nb_rubrique,
|
|
|
PRET_QUANTITE AS nb_prestation,
|
|
|
CASE WHEN PRET_COEFFICIENT <> 0 THEN PRET_COEFFICIENT ELSE 1 END AS coefficient,
|
|
|
1::numeric AS coefficient_mco,
|
|
|
PRET_PUFACTURE AS prix_unitaire,
|
|
|
0::numeric as taux_0,
|
|
|
100::numeric as taux_1,
|
|
|
0::numeric as taux_2,
|
|
|
0::numeric as taux_22,
|
|
|
0::numeric as montant_facture,
|
|
|
0::numeric as montant_facture_0,
|
|
|
0::numeric as montant_facture_1,
|
|
|
0::numeric as montant_facture_2,
|
|
|
0::numeric as montant_facture_22,
|
|
|
0::numeric as montant_depassement,
|
|
|
0::numeric as montant_comptabilise,
|
|
|
0::numeric as montant_comptabilise_0,
|
|
|
0::numeric as montant_comptabilise_1,
|
|
|
0::numeric as montant_comptabilise_2,
|
|
|
0::numeric as montant_comptabilise_22,
|
|
|
0::numeric AS montant_encours,
|
|
|
0::numeric AS montant_encours_0,
|
|
|
0::numeric AS montant_encours_1,
|
|
|
0::numeric AS montant_encours_2,
|
|
|
0::numeric AS montant_encours_22,
|
|
|
PRET_QUANTITE * CASE WHEN PRET_COEFFICIENT <> 0 THEN PRET_COEFFICIENT ELSE 1 END * PRET_PUFACTURE AS montant_facture_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_0_actes_inclus_dans_sejour,
|
|
|
PRET_QUANTITE * CASE WHEN PRET_COEFFICIENT <> 0 THEN PRET_COEFFICIENT ELSE 1 END * PRET_PUFACTURE AS montant_facture_1_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_2_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_22_actes_inclus_dans_sejour
|
|
|
FROM prod_csis.SCA_PRESTATION_PRET
|
|
|
JOIN prod_csis.SID_DOSSIERADMINISTRATIF_DADM ON PRET_ID_DADM = DADM_ID
|
|
|
JOIN w_SST_PRESTATIONETAB_PRTB ON PRET_ID_PRTB = PRTB_ID
|
|
|
JOIN prod_csis.SST_PRESTATION_PRES ON PRTB_ID_PRES = PRES_ID
|
|
|
JOIN activite[PX].p_sejours ON PRET_ID_DADM = p_sejours.code_original AND p_sejours.etat = ''
|
|
|
JOIN activite[PX].p_factures ON
|
|
|
p_sejours.no_sejour = p_factures.no_sejour AND
|
|
|
date(PRET_DATEDEBUT) BETWEEN p_factures.date_debut AND p_factures.date_fin AND
|
|
|
p_factures.no_facture LIKE '%BG'
|
|
|
JOIN activite.t_prestations ON PRES_CODE = t_prestations.code
|
|
|
JOIN base.t_actes ON PRES_CODE = t_actes.code
|
|
|
LEFT JOIN activite[PX].t_medecins_administratifs ON t_medecins_administratifs.code_original = PRET_ID1_MEDN
|
|
|
WHERE PRET_TYPELIGNE IN (4) AND
|
|
|
PRET_STATUT = 'V'
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ACTECCAM;
|
|
|
CREATE TEMP TABLE w_ACTECCAM AS
|
|
|
SELECT *,
|
|
|
''::text AS ACCA_CODEPHASE,
|
|
|
''::text AS ACCA_CODEACTIVITE,
|
|
|
''::text AS ACCA_CODEEXTENSIONDOC,
|
|
|
''::text AS ACCA_CODEMODIFICATEUR1,
|
|
|
''::text AS ACCA_CODEMODIFICATEUR2,
|
|
|
''::text AS ACCA_CODEMODIFICATEUR3,
|
|
|
''::text AS ACCA_CODEMODIFICATEUR4,
|
|
|
''::text AS ACCA_PRESCODE,
|
|
|
0::bigint AS cti_acte_id,
|
|
|
0::bigint AS cti_prestation_id,
|
|
|
0::bigint AS cti_rubrique_facturation_id
|
|
|
FROM prod_csis.sca_acteccam_ccam
|
|
|
JOIN prod_csis.sca_activiteccam_acca ON ACCA_ID_CCAM = CCAM_ID
|
|
|
JOIN prod_csis.sca_intervention_inte ON ccam_id_inte = inte_id
|
|
|
JOIN prod_csis.SID_DOSSIERADMINISTRATIF_DADM ON INTE_ID_DADM = DADM_ID
|
|
|
JOIN prod_csis.sno_acte_acte ON CCAM_ID_ACTE = ACTE_ID
|
|
|
WHERE ACCA_REALISE = '1' AND
|
|
|
CCAM_STATUT = 0 AND
|
|
|
ACCA_ID NOT IN (SELECt RECC_ID_ACCA FROm prod_csis.MPM_RECUEILCCAM_RECC)
|
|
|
;
|
|
|
|
|
|
ANALYSE w_ACTECCAM
|
|
|
;
|
|
|
|
|
|
UPDATE w_ACTECCAM SET
|
|
|
ACCA_CODEPHASE = COALESCE(PHAS_CODE,'0'),
|
|
|
ACCA_CODEACTIVITE = COALESCE(LACT_CODE,'1'),
|
|
|
ACCA_CODEEXTENSIONDOC = COALESCE(XTSN_CODE,''),
|
|
|
ACCA_CODEMODIFICATEUR1 = COALESCE(TB11_CODE1,''),
|
|
|
ACCA_CODEMODIFICATEUR2 = COALESCE(TB11_CODE2,''),
|
|
|
ACCA_CODEMODIFICATEUR3 = COALESCE(TB11_CODE3,''),
|
|
|
ACCA_CODEMODIFICATEUR4 = COALESCE(TB11_CODE4,'')
|
|
|
FROM
|
|
|
(
|
|
|
SELECT *
|
|
|
FROM w_ACTECCAM
|
|
|
LEFT JOIN prod_csis.sno_activphase_accp ON ACCA_ID_ACCP = ACCP_ID
|
|
|
LEFT JOIN prod_csis.SNO_PHASE_PHAS ON ACCP_ID_PHAS = PHAS_ID
|
|
|
LEFT JOIN prod_csis.sno_activiteacte_acvt ON ACCA_ID_ACVT = ACVT_ID
|
|
|
LEFT JOIN prod_csis.sno_listactivite_lact ON ACVT_ID_LACT = LACT_ID
|
|
|
LEFT JOIN prod_csis.sno_extension_xtsn ON ACCA_ID_XTSN = XTSN_ID
|
|
|
LEFT JOIN
|
|
|
(
|
|
|
SELECT MCCA_ID_ACCA,
|
|
|
MAX(CASE WHEN MCCA_ORDRE = 1 THEN TB11_CODE ELSE '' END) AS TB11_CODE1,
|
|
|
MAX(CASE WHEN MCCA_ORDRE = 2 THEN TB11_CODE ELSE '' END) AS TB11_CODE2,
|
|
|
MAX(CASE WHEN MCCA_ORDRE = 3 THEN TB11_CODE ELSE '' END) AS TB11_CODE3,
|
|
|
MAX(CASE WHEN MCCA_ORDRE = 4 THEN TB11_CODE ELSE '' END) AS TB11_CODE4
|
|
|
FROM prod_csis.sca_modifccam_mcca
|
|
|
JOIN prod_csis.sno_modificateur_tb11 ON MCCA_ID_TB11 = TB11_ID
|
|
|
GROUP BY 1
|
|
|
) subview ON ACCA_ID = MCCA_ID_ACCA
|
|
|
) subview
|
|
|
WHERE w_ACTECCAM.ACCA_ID = subview.ACCA_ID
|
|
|
;
|
|
|
|
|
|
UPDATE w_ACTECCAM SET
|
|
|
cti_acte_id = t_actes.oid,
|
|
|
ACCA_PRESCODE = CASE WHEN ACCA_CODEACTIVITE <> '4' THEN COALESCE(t_ccam_regroupements.code,'ADC') ELSE 'ADA' END
|
|
|
FROM base.t_actes
|
|
|
LEFT JOIN base.t_ccam_regroupements ON ccam_regroupement_id_1 = t_ccam_regroupements.oid
|
|
|
WHERE t_actes.code = ACTE_CODE
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_lignes_h (
|
|
|
finess,
|
|
|
no_facture,
|
|
|
facture_id,
|
|
|
date_debut,
|
|
|
heure_debut,
|
|
|
date_fin,
|
|
|
lieu_id,
|
|
|
acte_id,
|
|
|
phase_ccam,
|
|
|
activite_ccam,
|
|
|
extension_ccam,
|
|
|
modificateur_ccam_1,
|
|
|
modificateur_ccam_2,
|
|
|
modificateur_ccam_3,
|
|
|
modificateur_ccam_4,
|
|
|
medecin_facture_id,
|
|
|
medecin_comptabilise_id,
|
|
|
prestation_id,
|
|
|
nb_rubrique,
|
|
|
nb_prestation,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
prix_unitaire,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
montant_facture_22,
|
|
|
montant_depassement,
|
|
|
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
|
|
|
)
|
|
|
SELECT
|
|
|
''::text AS finess,
|
|
|
p_factures.no_facture,
|
|
|
p_factures.oid AS facture_id,
|
|
|
date(ACCA_DATEHEUREREALISATION) AS date_debut,
|
|
|
extract('hour' FROM ACCA_DATEHEUREREALISATION) AS heure_debut,
|
|
|
date(ACCA_DATEHEUREREALISATION) AS date_fin,
|
|
|
p_sejours.lieu_sortie_id AS lieu_id,
|
|
|
cti_acte_id AS acte_id,
|
|
|
COALESCE(ACCA_CODEPHASE,'') AS phase_ccam,
|
|
|
COALESCE(ACCA_CODEACTIVITE,'') AS activite_ccam,
|
|
|
COALESCE(ACCA_CODEEXTENSIONDOC,'') AS extension_ccam,
|
|
|
COALESCE(ACCA_CODEMODIFICATEUR1,'') AS modificateur_ccam_1,
|
|
|
COALESCE(ACCA_CODEMODIFICATEUR2,'') AS modificateur_ccam_2,
|
|
|
COALESCE(ACCA_CODEMODIFICATEUR3,'') AS modificateur_ccam_3,
|
|
|
COALESCE(ACCA_CODEMODIFICATEUR4,'') AS modificateur_ccam_4,
|
|
|
COALESCE(t_medecins_administratifs.oid,0) AS medecin_facture_id,
|
|
|
COALESCE(t_medecins_administratifs.oid,0) AS medecin_comptabilise_id,
|
|
|
t_prestations.oid AS prestation_id,
|
|
|
1::numeric AS nb_rubrique,
|
|
|
1::numeric AS nb_prestation,
|
|
|
1::numeric AS coefficient,
|
|
|
1::numeric AS coefficient_mco,
|
|
|
ACCA_PUCONVENTIONNE AS prix_unitaire,
|
|
|
0::numeric as taux_0,
|
|
|
100::numeric as taux_1,
|
|
|
0::numeric as taux_2,
|
|
|
0::numeric as taux_22,
|
|
|
0::numeric as montant_facture,
|
|
|
0::numeric as montant_facture_0,
|
|
|
0::numeric as montant_facture_1,
|
|
|
0::numeric as montant_facture_2,
|
|
|
0::numeric as montant_facture_22,
|
|
|
0::numeric as montant_depassement,
|
|
|
0::numeric as montant_comptabilise,
|
|
|
0::numeric as montant_comptabilise_0,
|
|
|
0::numeric as montant_comptabilise_1,
|
|
|
0::numeric as montant_comptabilise_2,
|
|
|
0::numeric as montant_comptabilise_22,
|
|
|
0::numeric AS montant_encours,
|
|
|
0::numeric AS montant_encours_0,
|
|
|
0::numeric AS montant_encours_1,
|
|
|
0::numeric AS montant_encours_2,
|
|
|
0::numeric AS montant_encours_22,
|
|
|
ACCA_HONORAIRES AS montant_facture_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_0_actes_inclus_dans_sejour,
|
|
|
ACCA_HONORAIRES AS montant_facture_1_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_2_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_22_actes_inclus_dans_sejour
|
|
|
FROM w_ACTECCAM
|
|
|
JOIN activite[PX].p_sejours ON INTE_ID_DADM = p_sejours.code_original AND p_sejours.etat = ''
|
|
|
JOIN activite[PX].p_factures ON
|
|
|
p_sejours.no_sejour = p_factures.no_sejour AND
|
|
|
date(ACCA_DATEHEUREREALISATION) BETWEEN p_factures.date_debut AND p_factures.date_fin AND
|
|
|
p_factures.no_facture LIKE '%BG'
|
|
|
JOIN activite.t_prestations ON ACCA_PRESCODE = t_prestations.code
|
|
|
LEFT JOIN activite[PX].t_medecins_administratifs ON t_medecins_administratifs.code_original = ACCA_ID_MEDN
|
|
|
;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Actes inclus (Budget Global SSR)">
|
|
|
<condition><![CDATA[
|
|
|
"[ENV_TYPEETS]" != "1" && "[ENV_WITHPMSISSR]" == "1"
|
|
|
]]></condition>
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Pointage des actes en facturation
|
|
|
UPDATE prod_csis.SCA_PRESTATION_PRET
|
|
|
SET PRET_STATUT = 'F'
|
|
|
FROM
|
|
|
(
|
|
|
SELECT RECG_ID_DADM, RECG_ID_PRTB
|
|
|
FROM prod_csis.MPM_RECUEIL_RECG
|
|
|
WHERE RECG_TYPELIGNE = 4
|
|
|
GROUP BY 1,2
|
|
|
) subview
|
|
|
WHERE
|
|
|
PRET_ID_DADM = RECG_ID_DADM AND
|
|
|
PRET_ID_PRTB = RECG_ID_PRTB AND
|
|
|
PRET_STATUT = 'V'
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SCA_PRESTATION_PRET_ssr;
|
|
|
CREATE TEMP TABLE w_SCA_PRESTATION_PRET_ssr AS
|
|
|
SELECT SCA_PRESTATION_PRET.*,
|
|
|
p_sejours.no_sejour AS no_sejour,
|
|
|
p_sejours.lieu_sortie_id,
|
|
|
''::text AS no_facture,
|
|
|
0::bigint AS facture_id
|
|
|
FROM prod_csis.SCA_PRESTATION_PRET
|
|
|
JOIN prod_csis.SID_DOSSIERADMINISTRATIF_DADM ON PRET_ID_DADM = DADM_ID
|
|
|
JOIN activite[PX].p_sejours ON PRET_ID_DADM = p_sejours.code_original AND p_sejours.etat = ''
|
|
|
JOIN activite[PX].t_lieux ON p_sejours.lieu_sortie_id = t_lieux.oid
|
|
|
JOIN activite[PX].t_services_facturation ON service_facturation_id = t_services_facturation.oid
|
|
|
WHERE PRET_TYPELIGNE IN (4) AND
|
|
|
PRET_STATUT = 'V' AND
|
|
|
t_services_facturation.type_t2a = '2'
|
|
|
;
|
|
|
|
|
|
ANALYSE w_SCA_PRESTATION_PRET_ssr
|
|
|
;
|
|
|
|
|
|
UPDATE w_SCA_PRESTATION_PRET_ssr SET
|
|
|
no_facture = subview.no_facture,
|
|
|
facture_id = subview.facture_id
|
|
|
FROM
|
|
|
(
|
|
|
SELECT w_SCA_PRESTATION_PRET_ssr.CTID AS CTIDok,
|
|
|
w_SCA_PRESTATION_PRET_ssr.no_sejour ,
|
|
|
MIN(p_factures.no_facture) AS no_facture,
|
|
|
(MIN(ARRAY[p_factures.no_facture,p_factures.oid::text]))[2]::bigint AS facture_id
|
|
|
FROM w_SCA_PRESTATION_PRET_ssr
|
|
|
JOIN activite[PX].p_factures ON
|
|
|
w_SCA_PRESTATION_PRET_ssr.no_sejour = p_factures.no_sejour AND
|
|
|
date(PRET_DATEDEBUT) BETWEEN p_factures.date_debut AND p_factures.date_fin AND
|
|
|
p_factures.no_facture NOT LIKE '%BG'
|
|
|
GROUP BY 1,2
|
|
|
) subview
|
|
|
WHERE w_SCA_PRESTATION_PRET_ssr.no_sejour = subview.no_sejour AND
|
|
|
w_SCA_PRESTATION_PRET_ssr.CTID = CTIDok
|
|
|
;
|
|
|
|
|
|
UPDATE w_SCA_PRESTATION_PRET_ssr SET
|
|
|
no_facture = subview.no_facture,
|
|
|
facture_id = subview.facture_id
|
|
|
FROM
|
|
|
(
|
|
|
SELECT w_SCA_PRESTATION_PRET_ssr.CTID AS CTIDok,
|
|
|
w_SCA_PRESTATION_PRET_ssr.no_sejour ,
|
|
|
(MIN(ARRAY[CASE WHEN p_factures.code_facture = '1' THEN '0' ELSE '1' END, p_factures.no_facture]))[2] AS no_facture,
|
|
|
(MIN(ARRAY[p_factures.no_facture,p_factures.oid::text]))[2]::bigint AS facture_id
|
|
|
FROM w_SCA_PRESTATION_PRET_ssr
|
|
|
JOIN activite[PX].p_factures ON
|
|
|
w_SCA_PRESTATION_PRET_ssr.no_sejour = p_factures.no_sejour AND
|
|
|
p_factures.no_facture NOT LIKE '%BG' AND
|
|
|
w_SCA_PRESTATION_PRET_ssr.no_facture = ''
|
|
|
GROUP BY 1,2
|
|
|
) subview
|
|
|
WHERE w_SCA_PRESTATION_PRET_ssr.no_sejour = subview.no_sejour AND
|
|
|
w_SCA_PRESTATION_PRET_ssr.CTID = CTIDok
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_lignes_h (
|
|
|
finess,
|
|
|
no_facture,
|
|
|
facture_id,
|
|
|
date_debut,
|
|
|
heure_debut,
|
|
|
date_fin,
|
|
|
lieu_id,
|
|
|
acte_id,
|
|
|
phase_ccam,
|
|
|
activite_ccam,
|
|
|
extension_ccam,
|
|
|
modificateur_ccam_1,
|
|
|
modificateur_ccam_2,
|
|
|
modificateur_ccam_3,
|
|
|
modificateur_ccam_4,
|
|
|
medecin_facture_id,
|
|
|
medecin_comptabilise_id,
|
|
|
prestation_id,
|
|
|
nb_rubrique,
|
|
|
nb_prestation,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
prix_unitaire,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
montant_facture_22,
|
|
|
montant_depassement,
|
|
|
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
|
|
|
)
|
|
|
SELECT
|
|
|
''::text AS finess,
|
|
|
no_facture,
|
|
|
facture_id,
|
|
|
date(PRET_DATEDEBUT) AS date_debut,
|
|
|
extract('hour' FROM PRET_DATEDEBUT) AS heure_debut,
|
|
|
date(COALESCE(PRET_DATEFIN, PRET_DATEDEBUT)) AS date_fin,
|
|
|
lieu_sortie_id AS lieu_id,
|
|
|
t_actes.oid AS acte_id,
|
|
|
''::text AS phase_ccam,
|
|
|
''::text AS activite_ccam,
|
|
|
''::text AS extension_ccam,
|
|
|
''::text AS modificateur_ccam_1,
|
|
|
''::text AS modificateur_ccam_2,
|
|
|
''::text AS modificateur_ccam_3,
|
|
|
''::text AS modificateur_ccam_4,
|
|
|
COALESCE(t_medecins_administratifs.oid,0) AS medecin_facture_id,
|
|
|
COALESCE(t_medecins_administratifs.oid,0) AS medecin_comptabilise_id,
|
|
|
t_prestations.oid AS prestation_id,
|
|
|
PRET_QUANTITE AS nb_rubrique,
|
|
|
PRET_QUANTITE AS nb_prestation,
|
|
|
CASE WHEN PRET_COEFFICIENT <> 0 THEN PRET_COEFFICIENT ELSE 1 END AS coefficient,
|
|
|
1::numeric AS coefficient_mco,
|
|
|
PRET_PUFACTURE AS prix_unitaire,
|
|
|
0::numeric as taux_0,
|
|
|
100::numeric as taux_1,
|
|
|
0::numeric as taux_2,
|
|
|
0::numeric as taux_22,
|
|
|
0::numeric as montant_facture,
|
|
|
0::numeric as montant_facture_0,
|
|
|
0::numeric as montant_facture_1,
|
|
|
0::numeric as montant_facture_2,
|
|
|
0::numeric as montant_facture_22,
|
|
|
0::numeric as montant_depassement,
|
|
|
0::numeric as montant_comptabilise,
|
|
|
0::numeric as montant_comptabilise_0,
|
|
|
0::numeric as montant_comptabilise_1,
|
|
|
0::numeric as montant_comptabilise_2,
|
|
|
0::numeric as montant_comptabilise_22,
|
|
|
0::numeric AS montant_encours,
|
|
|
0::numeric AS montant_encours_0,
|
|
|
0::numeric AS montant_encours_1,
|
|
|
0::numeric AS montant_encours_2,
|
|
|
0::numeric AS montant_encours_22,
|
|
|
PRET_QUANTITE * CASE WHEN PRET_COEFFICIENT <> 0 THEN PRET_COEFFICIENT ELSE 1 END * PRET_PUFACTURE AS montant_facture_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_0_actes_inclus_dans_sejour,
|
|
|
PRET_QUANTITE * CASE WHEN PRET_COEFFICIENT <> 0 THEN PRET_COEFFICIENT ELSE 1 END * PRET_PUFACTURE AS montant_facture_1_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_2_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_22_actes_inclus_dans_sejour
|
|
|
FROM w_SCA_PRESTATION_PRET_ssr
|
|
|
JOIN w_SST_PRESTATIONETAB_PRTB ON PRET_ID_PRTB = PRTB_ID
|
|
|
JOIN prod_csis.SST_PRESTATION_PRES ON PRTB_ID_PRES = PRES_ID
|
|
|
JOIN activite.t_prestations ON PRES_CODE = t_prestations.code
|
|
|
JOIN base.t_actes ON PRES_CODE = t_actes.code
|
|
|
LEFT JOIN activite[PX].t_medecins_administratifs ON t_medecins_administratifs.code_original = PRET_ID1_MEDN
|
|
|
WHERE w_SCA_PRESTATION_PRET_ssr.no_facture <> ''
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Compte client Honoraires">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_soldes_h;
|
|
|
CREATE TEMP TABLE w_factures_soldes_h AS
|
|
|
SELECT
|
|
|
''::text AS finess,
|
|
|
RECF_NUMFACTALIAS_ETAB AS no_facture,
|
|
|
COALESCE(p_factures.oid,0) AS facture_id,
|
|
|
date_trunc('month',p_factures.date_vente) AS date_comptable,
|
|
|
w_MPM_RECUEILTIERS_RECT_keys.medecin_id AS medecin_comptabilise_id,
|
|
|
'0'::text AS od_avoir,
|
|
|
'0'::text AS od_non_comptabilise,
|
|
|
SUM(RECT_MONTANT_CPT) as montant_comptabilise,
|
|
|
SUM(RECT_MONTANT_CPT_0) as montant_comptabilise_0,
|
|
|
SUM(RECT_MONTANT_CPT_1) as montant_comptabilise_1,
|
|
|
SUM(RECT_MONTANT_CPT_2) as montant_comptabilise_2,
|
|
|
SUM(RECT_MONTANT_CPT_22) as montant_comptabilise_22,
|
|
|
0::numeric AS montant_regle,
|
|
|
0::numeric AS montant_regle_0,
|
|
|
0::numeric AS montant_regle_1,
|
|
|
0::numeric AS montant_regle_2,
|
|
|
0::numeric AS montant_regle_22
|
|
|
FROM w_MPM_RECUEILTIERS_RECT
|
|
|
JOIN w_MPM_RECUEILTIERS_RECT_keys ON w_MPM_RECUEILTIERS_RECT.key = w_MPM_RECUEILTIERS_RECT_keys.key
|
|
|
JOIN activite[PX].p_factures ON no_facture = RECF_NUMFACTALIAS_ETAB
|
|
|
WHERE
|
|
|
w_MPM_RECUEILTIERS_RECT.RECG_TYPELIGNE_CPTA = 4 AND
|
|
|
RECT_OKFACTURE = 1 AND RECT_OKLIGNEFACTURE = 1 AND
|
|
|
p_factures.code_vente = '1'
|
|
|
GROUP BY 1,2,3,4,5;
|
|
|
|
|
|
|
|
|
INSERT INTO w_factures_soldes_h
|
|
|
SELECT
|
|
|
''::text AS finess,
|
|
|
RECF_NUMFACTALIAS_ETAB AS no_facture,
|
|
|
COALESCE(p_factures.oid,0) AS facture_id,
|
|
|
date_trunc('month',COALESCE(REGD_DATEECRITURE,REGD_DATEENCAIS)) AS date_comptable,
|
|
|
w_MPM_RECUEILTIERS_RECT_keys.medecin_id AS medecin_comptabilise_id,
|
|
|
'0'::text AS od_avoir,
|
|
|
CASE WHEN REGD_DATEECRITURE IS NULL THEN '1'::text ELSE '0'::text END AS od_non_comptabilise,
|
|
|
0::numeric AS montant_comptabilise,
|
|
|
0::numeric AS montant_comptabilise_0,
|
|
|
0::numeric AS montant_comptabilise_1,
|
|
|
0::numeric AS montant_comptabilise_2,
|
|
|
0::numeric AS montant_comptabilise_22,
|
|
|
SUM(REGD_MNTENCAIS) as montant_regle,
|
|
|
SUM(CASE WHEN (RECT_TYPEDEBITEUR = 'D' OR ASSU_ID IS NULL) THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_0,
|
|
|
SUM(CASE WHEN ASSU_TYPE = 'O' THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_1_c,
|
|
|
SUM(CASE WHEN ASSU_TYPE = 'C' AND ASSU_DISTINCTIF = 1 THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_2,
|
|
|
SUM(CASE WHEN ASSU_TYPE = 'C' AND ASSU_DISTINCTIF <> 1 THEN REGD_MNTENCAIS ELSE 0 END) as montant_regle_22
|
|
|
FROM w_MPM_RECUEILTIERS_RECT
|
|
|
JOIN w_MPM_RECUEILTIERS_RECT_keys ON w_MPM_RECUEILTIERS_RECT.key = w_MPM_RECUEILTIERS_RECT_keys.key
|
|
|
JOIN activite[PX].p_factures ON no_facture = RECF_NUMFACTALIAS_ETAB
|
|
|
JOIN prod_csis.MRC_REGLEMENTDETAIL_REGD ON REGD_ID_RECT = RECT_ID
|
|
|
WHERE
|
|
|
w_MPM_RECUEILTIERS_RECT.RECG_TYPELIGNE_CPTA = 4 AND
|
|
|
REGD_CODETYOP NOT IN ('AC', 'MC', 'BG')
|
|
|
GROUP BY 1,2,3,4,5,6,7;
|
|
|
|
|
|
|
|
|
|
|
|
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 (
|
|
|
finess,
|
|
|
no_facture,
|
|
|
facture_id,
|
|
|
date_comptable,
|
|
|
od_avoir,
|
|
|
od_non_comptabilise,
|
|
|
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
|
|
|
finess,
|
|
|
no_facture,
|
|
|
facture_id,
|
|
|
date_comptable,
|
|
|
od_avoir,
|
|
|
od_non_comptabilise,
|
|
|
medecin_comptabilise_id,
|
|
|
SUM(montant_comptabilise),
|
|
|
SUM(montant_comptabilise_0),
|
|
|
SUM(montant_comptabilise_1),
|
|
|
SUM(montant_comptabilise_2),
|
|
|
SUM(montant_comptabilise_22),
|
|
|
SUM(montant_regle),
|
|
|
SUM(montant_regle_0),
|
|
|
SUM(montant_regle_1),
|
|
|
SUM(montant_regle_2),
|
|
|
SUM(montant_regle_22)
|
|
|
FROM w_factures_soldes_h
|
|
|
GROUP BY 1,2,3,4,5,6,7;
|
|
|
|
|
|
|
|
|
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_soldes_h_1');
|
|
|
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 occupation">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
TRUNCATE activite[PX].p_chiffrier_occupation;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_chiffrier;
|
|
|
CREATE TEMP TABLE w_chiffrier AS
|
|
|
SELECT
|
|
|
date(DADM_DATEDEBUT) AS date,
|
|
|
DADM_NDA::text AS no_sejour,
|
|
|
DADM_ID_ETAB,
|
|
|
DADM_NDA,
|
|
|
DADM_ID,
|
|
|
1::numeric AS nb_entrees_directes,
|
|
|
0::numeric AS nb_sorties_directes
|
|
|
FROM prod_csis.SID_DOSSIERADMINISTRATIF_DADM
|
|
|
WHERE DADM_ID_STDO NOT IN (1,2) AND
|
|
|
DADM_ID_ETDO NOT IN (4,6) AND
|
|
|
date(DADM_DATEDEBUT) >= '[ENV_ADM_ANNEEDEBUT]0101';
|
|
|
|
|
|
|
|
|
INSERT INTO w_chiffrier
|
|
|
SELECT
|
|
|
date(DADM_DATEFIN) AS date,
|
|
|
DADM_NDA AS no_sejour,
|
|
|
DADM_ID_ETAB,
|
|
|
DADM_NDA,
|
|
|
DADM_ID,
|
|
|
0::numeric AS nb_entrees_directes,
|
|
|
1::numeric AS nb_sorties_directes
|
|
|
FROM prod_csis.SID_DOSSIERADMINISTRATIF_DADM
|
|
|
JOIN prod_csis.SNO_STATUTDOSSIER_STDO ON DADM_ID_STDO = STDO_ID AND STDO_NATUREENTREE = 'R'
|
|
|
WHERE DADM_ID_STDO NOT IN (1,2) AND
|
|
|
DADM_ID_ETDO NOT IN (4,6) AND
|
|
|
DADM_DATEFIN IS NOT NULL AND
|
|
|
date(DADM_DATEFIN) >= '[ENV_ADM_ANNEEDEBUT]0101' AND
|
|
|
STDO_CODE IN ('S', 'C') ;
|
|
|
|
|
|
|
|
|
UPDATE w_chiffrier
|
|
|
SET no_sejour = w_SID_DOSSIERADMINISTRATIF_DADM.DADM_NDA_ETAB
|
|
|
FROM w_SID_DOSSIERADMINISTRATIF_DADM
|
|
|
WHERE w_chiffrier.DADM_ID = w_SID_DOSSIERADMINISTRATIF_DADM.DADM_ID AND
|
|
|
w_chiffrier.no_sejour <> DADM_NDA_ETAB
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite[PX].p_chiffrier_occupation (
|
|
|
date,
|
|
|
no_sejour,
|
|
|
nb_entrees_directes,
|
|
|
nb_sorties_directes)
|
|
|
SELECT
|
|
|
date,
|
|
|
no_sejour,
|
|
|
SUM(nb_entrees_directes),
|
|
|
SUM(nb_sorties_directes)
|
|
|
FROM w_chiffrier
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Ecritures comptables">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
INSERT INTO activite[PX].t_journal (code_original, code, texte)
|
|
|
SELECT CJRN_ID,
|
|
|
CJRN_CODE,
|
|
|
MAX(CJRN_LIBELLE)
|
|
|
FROM prod_csis.SST_CPTAJOURNAL_CJRN
|
|
|
WHERE CJRN_ID NOT IN (SELECT code_original FROM activite[PX].t_journal WHERE code_original IS NOT NULL)
|
|
|
GROUP BY 1,2
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].t_journal
|
|
|
SET type_journal = 'VE'
|
|
|
WHERE type_journal = '' AND
|
|
|
code_original IN (SELECT CJRN_ID FROM prod_csis.SST_CPTAJOURNAL_CJRN WHERE CJRN_DOMAINE = 'VE')
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SCP_CPTATRANSFERT_CPTF;
|
|
|
CREATE TEMP TABLE w_SCP_CPTATRANSFERT_CPTF AS
|
|
|
SELECT *,
|
|
|
''::text AS no_sejour,
|
|
|
0::bigint AS sejour_id,
|
|
|
''::text AS no_facture,
|
|
|
0::bigint AS facture_id,
|
|
|
0::bigint AS medecin_administratif_id,
|
|
|
0::bigint AS tiers_payant_id,
|
|
|
''::text AS mode_reglement_code,
|
|
|
'':: text AS type_ecriture,
|
|
|
'':: text AS type_piece
|
|
|
FROM prod_csis.SCP_CPTATRANSFERT_CPTF
|
|
|
JOIN prod_csis.SCP_CPTACLOTURE_CPCL ON CPTF_ID_CPCL = CPCL_ID
|
|
|
WHERE date(CPTF_DATEECRITURE) >= '[ENV_ADM_ANNEEDEBUT]0101' AND
|
|
|
CPTF_TYPE = 'CG'
|
|
|
;
|
|
|
|
|
|
ANALYSE w_SCP_CPTATRANSFERT_CPTF
|
|
|
;
|
|
|
|
|
|
UPDATE w_SCP_CPTATRANSFERT_CPTF SET
|
|
|
no_facture = RECF_NUMFACTALIAS,
|
|
|
no_sejour = p_factures.no_sejour,
|
|
|
facture_id = p_factures.oid,
|
|
|
sejour_id = p_factures.sejour_id
|
|
|
FROM prod_csis.MPM_FACTURE_RECF
|
|
|
JOIN activite[PX].p_factures ON RECF_NUMFACTALIAS = no_facture
|
|
|
WHERE CPTF_ID_RECF = RECF_ID
|
|
|
;
|
|
|
|
|
|
TRUNCATE activite[PX].p_ecriture_comptable;
|
|
|
INSERT INTO activite[PX].p_ecriture_comptable(
|
|
|
code_original,
|
|
|
date_comptable,
|
|
|
type_ecriture,
|
|
|
type_piece,
|
|
|
piece,
|
|
|
mode_reglement_code,
|
|
|
clinique_honoraire,
|
|
|
compte_id,
|
|
|
journal_id,
|
|
|
sejour_id,
|
|
|
no_sejour,
|
|
|
facture_id,
|
|
|
no_facture,
|
|
|
medecin_id,
|
|
|
tiers_payant_id,
|
|
|
texte,
|
|
|
montant_credit,
|
|
|
montant_debit,
|
|
|
est_comptabilise,
|
|
|
taux_tva)
|
|
|
SELECT
|
|
|
CPTF_ID::text AS code_original,
|
|
|
date(CPTF_DATEECRITURE) AS date_comptable,
|
|
|
CASE
|
|
|
WHEN t_journal.type_journal = 'VE' AND CPTF_COMPTE LIKE '411%' THEN 'VCLI'
|
|
|
WHEN t_journal.type_journal = 'VE' AND CPTF_COMPTE LIKE '412%' THEN 'VCLI'
|
|
|
WHEN t_journal.type_journal = 'VE' AND CPTF_COMPTE LIKE '445%' THEN 'VTVA'
|
|
|
WHEN t_journal.type_journal = 'VE' AND CPCL_NATURE <> 'HO' THEN 'VPRD'
|
|
|
WHEN t_journal.type_journal = 'VE' AND CPCL_NATURE = 'HO' THEN 'VHON'
|
|
|
WHEN CPTF_COMPTE LIKE '758%' THEN 'PEPR'
|
|
|
WHEN CPTF_COMPTE LIKE '658%' THEN 'PEPR'
|
|
|
WHEN t_journal.type_journal <> 'VE' AND CPTF_COMPTE LIKE '468%' THEN 'ATT'
|
|
|
WHEN t_journal.type_journal <> 'VE' AND CPTF_COMPTE LIKE '471%' THEN 'ATT'
|
|
|
WHEN t_journal.type_journal <> 'VE' AND CPTF_COMPTE LIKE '411%' THEN 'RCLI'
|
|
|
WHEN t_journal.type_journal <> 'VE' AND CPTF_COMPTE LIKE '412%' THEN 'RCLI'
|
|
|
WHEN t_journal.type_journal <> 'VE' AND CPTF_COMPTE LIKE '419%' THEN 'ACPT'
|
|
|
WHEN t_journal.type_journal <> 'VE' AND CPTF_COMPTE LIKE '51%' THEN 'BANQ'
|
|
|
WHEN t_journal.type_journal <> 'VE' AND CPTF_COMPTE LIKE '531%' THEN 'BANQ'
|
|
|
WHEN t_journal.type_journal <> 'VE' AND CPTF_COMPTE LIKE '466%' THEN 'PHON'
|
|
|
WHEN t_journal.type_journal <> 'VE' AND CPTF_COMPTE LIKE '7%' THEN 'XPRD'
|
|
|
WHEN t_journal.type_journal <> 'VE' AND CPTF_COMPTE LIKE '445%' THEN 'XTVA'
|
|
|
ELSE '?'||CPTF_JOURNAL END AS type_ecriture,
|
|
|
CASE
|
|
|
WHEN t_journal.type_journal = 'VE' THEN 'VENTE'
|
|
|
ELSE t_journal.type_journal END AS type_piece,
|
|
|
CPTF_ID_CPCL::text AS piece,
|
|
|
CASE
|
|
|
WHEN CPTF_MODEREGLEMENT ILIKE '%ESPECE%' THEN 'ESP'
|
|
|
WHEN CPTF_MODEREGLEMENT ILIKE '%CHEQUE%' THEN 'CHQ'
|
|
|
WHEN CPTF_MODEREGLEMENT ILIKE '%CARTE BANCAIRE%' THEN 'CB'
|
|
|
WHEN CPTF_MODEREGLEMENT ILIKE '%VIREMENT%' THEN 'VIR'
|
|
|
WHEN CPTF_MODEREGLEMENT ILIKE '%PRELEVEMENT%' THEN 'PLV'
|
|
|
ELSE CPTF_MODEREGLEMENT END AS mode_reglement_code,
|
|
|
CASE WHEN CPCL_NATURE = 'HO' THEN 'H' ELSE 'C' END AS clinique_honoraire,
|
|
|
COALESCE(t_compte.oid,0) AS compte_id,
|
|
|
COALESCE(t_journal.oid,0) AS journal_id,
|
|
|
w_SCP_CPTATRANSFERT_CPTF.sejour_id,
|
|
|
w_SCP_CPTATRANSFERT_CPTF.no_sejour,
|
|
|
w_SCP_CPTATRANSFERT_CPTF.facture_id,
|
|
|
w_SCP_CPTATRANSFERT_CPTF.no_facture,
|
|
|
w_SCP_CPTATRANSFERT_CPTF.medecin_administratif_id,
|
|
|
w_SCP_CPTATRANSFERT_CPTF.tiers_payant_id,
|
|
|
CPTF_LIBELLE AS texte,
|
|
|
CASE WHEN CPTF_SENS = 'C' THEN CPTF_MONTANT ELSE 0 END AS montant_credit,
|
|
|
CASE WHEN CPTF_SENS = 'D' THEN CPTF_MONTANT ELSE 0 END AS montant_debit,
|
|
|
'1'::text AS est_comptabilise,
|
|
|
CPTF_TVATX AS taux_tva
|
|
|
FROM w_SCP_CPTATRANSFERT_CPTF
|
|
|
LEFT JOIN activite[PX].t_compte ON CPTF_COMPTE = t_compte.code
|
|
|
LEFT JOIN activite[PX].t_journal ON CPTF_JOURNAL = t_journal.code
|
|
|
WHERE t_journal.type_journal IS DISTINCT FROM 'IGNORE'
|
|
|
;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Récupération chiffrier comptable">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
INSERT INTO activite.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'CSIS_COMPTAHON',
|
|
|
'CSIS-MEDSPHERE. Honoraires comptabilisés ',
|
|
|
'1',
|
|
|
'1 = Honoraires comptabilisés, 0=Honoraires non comptabilises. Pour alimentation chiffrier.'
|
|
|
WHERE 'CSIS_COMPTAHON' NOT IN (SELECT code FROM activite.t_divers)
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'CSIS_COMPTAVTEETSSRC',
|
|
|
'CSIS-MEDSPHERE. Source des ecritures ventes etablissement ',
|
|
|
'SCP_CPTATRANSFERT_CPTF',
|
|
|
'SCP_CPTATRANSFERT_CPTF (defaut), MPM_CPTAVENTEPRESTATION_CPVP'
|
|
|
WHERE 'CSIS_COMPTAVTEETSSRC' NOT IN (SELECT code FROM activite.t_divers)
|
|
|
;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_CPTATRANSFERT_CPTF_HONTOSEJ;
|
|
|
CREATE TEMP TABLE w_CPTATRANSFERT_CPTF_HONTOSEJ AS
|
|
|
SELECT CPTF_ID_RECF, CPTF_NIVEAUDETAIL, CPTF_COMPTE, CPTF_DATEECRITURE
|
|
|
FROM prod_csis.SCP_CPTATRANSFERT_CPTF
|
|
|
JOIN prod_csis.SST_CPTAJOURNAL_CJRN ON CPTF_JOURNAL = CJRN_CODE
|
|
|
JOIN prod_csis.SCP_CPTACLOTURE_CPCL ON CPTF_ID_CPCL = CPCL_ID
|
|
|
WHERE CPCL_DOMAINE = 'VE' AND
|
|
|
CPCL_NATURE = 'HO' AND
|
|
|
CPTF_COMPTE LIKE 'E%' AND
|
|
|
CPTF_LIBELLE LIKE 'Extourne %'
|
|
|
GROUP BY 1,2,3,4
|
|
|
;
|
|
|
|
|
|
ANALYSE w_CPTATRANSFERT_CPTF_HONTOSEJ
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SCP_CPTATRANSFERT_CPTF;
|
|
|
CREATE TEMP TABLE w_SCP_CPTATRANSFERT_CPTF AS
|
|
|
SELECT
|
|
|
CASE
|
|
|
WHEN MPM_FACTURE_RECF2.RECF_ID IS NOT NULL THEN MPM_FACTURE_RECF2.RECF_NUMFACTALIAS
|
|
|
WHEN MPM_FACTURE_RECF.RECF_ID IS NOT NULL THEN MPM_FACTURE_RECF.RECF_NUMFACTALIAS
|
|
|
WHEN split_part(CPTF_LIBELLEUTILISATEUR,' ',3) LIKE 'F%' AND
|
|
|
substr(split_part(CPTF_LIBELLEUTILISATEUR,' ',3)::text,2) NOT IN (SELECT RECF_FACTURE FROM prod_csis.MPM_FACTURE_RECF)
|
|
|
THEN substr(split_part(CPTF_LIBELLEUTILISATEUR,' ',3)::text,2)
|
|
|
ELSE CPTF_PIECE::text END AS CPTF_FACTURE,
|
|
|
SCP_CPTATRANSFERT_CPTF.*,
|
|
|
SCP_CPTACLOTURE_CPCL.*,
|
|
|
MPM_CPTAVENTEPRESTATION_CPVP.*,
|
|
|
w_SST_ETABLISSEMENT_ETAB.*,
|
|
|
CASE WHEN CPCL_DOMAINE = 'VE' AND CPCL_NATURE = 'HO' AND w_CPTATRANSFERT_CPTF_HONTOSEJ.CPTF_ID_RECF IS NOT NULL THEN '1' ELSE '0' END AS CPTF_HONTOSEJ
|
|
|
FROM prod_csis.SCP_CPTATRANSFERT_CPTF
|
|
|
JOIN prod_csis.SST_CPTAJOURNAL_CJRN ON SCP_CPTATRANSFERT_CPTF.CPTF_JOURNAL = CJRN_CODE
|
|
|
JOIN prod_csis.SCP_CPTACLOTURE_CPCL ON SCP_CPTATRANSFERT_CPTF.CPTF_ID_CPCL = CPCL_ID
|
|
|
LEFT JOIN prod_csis.MPM_FACTURE_RECF ON SCP_CPTATRANSFERT_CPTF.CPTF_ID_RECF <> 0 AND SCP_CPTATRANSFERT_CPTF.CPTF_ID_RECF = MPM_FACTURE_RECF.RECF_ID
|
|
|
LEFT JOIN prod_csis.MPM_CPTAVENTEPRESTATION_CPVP ON SCP_CPTATRANSFERT_CPTF.CPTF_ID_CPVP = CPVP_ID
|
|
|
LEFT JOIN prod_csis.MPM_FACTURE_RECF MPM_FACTURE_RECF2 ON CPVP_ID_RECF <> 0 AND CPVP_ID_RECF = MPM_FACTURE_RECF2.RECF_ID
|
|
|
JOIN w_SST_ETABLISSEMENT_ETAB ON SCP_CPTATRANSFERT_CPTF.CPTF_ID_ETAB = ETAB_ID
|
|
|
LEFT JOIN w_CPTATRANSFERT_CPTF_HONTOSEJ ON
|
|
|
SCP_CPTATRANSFERT_CPTF.CPTF_ID_RECF = w_CPTATRANSFERT_CPTF_HONTOSEJ.CPTF_ID_RECF AND
|
|
|
SCP_CPTATRANSFERT_CPTF.CPTF_NIVEAUDETAIL = w_CPTATRANSFERT_CPTF_HONTOSEJ.CPTF_NIVEAUDETAIL AND
|
|
|
SCP_CPTATRANSFERT_CPTF.CPTF_COMPTE = w_CPTATRANSFERT_CPTF_HONTOSEJ.CPTF_COMPTE AND
|
|
|
SCP_CPTATRANSFERT_CPTF.CPTF_DATEECRITURE = w_CPTATRANSFERT_CPTF_HONTOSEJ.CPTF_DATEECRITURE AND
|
|
|
SCP_CPTATRANSFERT_CPTF.CPTF_LIBELLE NOT LIKE 'Extourne %' AND
|
|
|
CPCL_DOMAINE = 'VE' AND
|
|
|
CPCL_NATURE = 'HO'
|
|
|
WHERE CPTF_TYPE = 'CG' AND
|
|
|
CJRN_ENCOURS <> '1' AND
|
|
|
SCP_CPTATRANSFERT_CPTF.CPTF_LIBELLE NOT LIKE 'Extourne %' AND
|
|
|
(
|
|
|
SCP_CPTATRANSFERT_CPTF.CPTF_COMPTE LIKE '41%' OR
|
|
|
CPCL_NATURE = 'HO' AND SCP_CPTATRANSFERT_CPTF.CPTF_COMPTE LIKE 'E%'
|
|
|
) AND
|
|
|
(
|
|
|
SCP_CPTATRANSFERT_CPTF.CPTF_COMPTE NOT LIKE '419%' OR
|
|
|
SCP_CPTATRANSFERT_CPTF.CPTF_COMPTE LIKE '419%' AND CPTF_JOURNAL LIKE 'NOE%'
|
|
|
) AND
|
|
|
date(SCP_CPTATRANSFERT_CPTF.CPTF_DATEECRITURE) >= '[ENV_ADM_ANNEEDEBUT]0101' AND
|
|
|
(CPCL_DOMAINE <> 'RE' OR CPCL_DOMAINE = 'RE' AND SCP_CPTATRANSFERT_CPTF.CPTF_ID_RECF <> 0)
|
|
|
;
|
|
|
|
|
|
ANALYSE w_SCP_CPTATRANSFERT_CPTF
|
|
|
;
|
|
|
|
|
|
UPDATE w_SCP_CPTATRANSFERT_CPTF
|
|
|
SET CPCL_NATURE = 'HO'
|
|
|
WHERE CPCL_NATURE <> 'HO' AND
|
|
|
CPTF_COMPTE IN (
|
|
|
SELECT CPTF_COMPTE
|
|
|
FROM w_SCP_CPTATRANSFERT_CPTF
|
|
|
WHERE CPCL_DOMAINE = 'VE'
|
|
|
GROUP BY 1
|
|
|
HAVING count(distinct CPCL_NATURE) = 1 AND
|
|
|
MAX(CPCL_NATURE) = 'HO'
|
|
|
)
|
|
|
;
|
|
|
|
|
|
UPDATE w_SCP_CPTATRANSFERT_CPTF SET
|
|
|
CPTF_COMPTE = '4111HONTOSEJ-'||CPTF_COMPTE,
|
|
|
CPCL_NATURE = 'PE'
|
|
|
WHERE CPTF_HONTOSEJ = '1'
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_SCP_CPTATRANSFERT_CPTF
|
|
|
SET CPCL_NATURE = CPCL_NATURE_VE
|
|
|
FROM
|
|
|
(
|
|
|
SELECT CPTF_PIECE,
|
|
|
CPTF_COMPTE,
|
|
|
MAX(CASE WHEN CPCL_DOMAINE = 'VE' THEN CPCL_NATURE ELSE '' END) AS CPCL_NATURE_VE,
|
|
|
MAX(CASE WHEN CPCL_DOMAINE <> 'VE' THEN CPCL_NATURE ELSE '' END) AS CPCL_NATURE_HO
|
|
|
FROM w_SCP_CPTATRANSFERT_CPTF
|
|
|
GROUP BY 1,2
|
|
|
HAVING MAX(CASE WHEN CPCL_DOMAINE = 'VE' THEN CPCL_NATURE ELSE '' END) <> MAX(CASE WHEN CPCL_DOMAINE <> 'VE' THEN CPCL_NATURE ELSE '' END) AND
|
|
|
MAX(CASE WHEN CPCL_DOMAINE = 'VE' THEN CPCL_NATURE ELSE '' END) <> '' AND
|
|
|
MAX(CASE WHEN CPCL_DOMAINE <> 'VE' THEN CPCL_NATURE ELSE '' END) <> '' order by 1
|
|
|
) subview
|
|
|
WHERE w_SCP_CPTATRANSFERT_CPTF.CPTF_PIECE = subview.CPTF_PIECE AND
|
|
|
w_SCP_CPTATRANSFERT_CPTF.CPTF_COMPTE = subview.CPTF_COMPTE AND
|
|
|
CPCL_NATURE <> CPCL_NATURE_VE AND
|
|
|
CPCL_NATURE <> 'VE'
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS SCP_CPTATRANSFERT_CPTF_param;
|
|
|
CREATE TEMP TABLE SCP_CPTATRANSFERT_CPTF_param AS
|
|
|
SELECT CPTF_NIVEAUDETAIL AS CPTF_NIVEAUDETAIL_param, (MAX(ARRAY[to_char(CPTF_MONTANT,'FM000000000000000'),CPTF_SENS]))[2] AS CPTF_SENS_positif
|
|
|
FROM
|
|
|
(
|
|
|
SELECT CPTF_NIVEAUDETAIL, CPTF_SENS, SUM(CPTF_MONTANT) AS CPTF_MONTANT
|
|
|
FROM w_SCP_CPTATRANSFERT_CPTF
|
|
|
WHERE CPCL_DOMAINE = 'VE'
|
|
|
GROUP BY 1,2
|
|
|
) subview
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_chiffrier_comptable;
|
|
|
CREATE TEMP TABLE w_chiffrier_comptable AS
|
|
|
SELECT date(date_trunc('month',CPTF_DATEECRITURE)) AS date_comptable,
|
|
|
SUM(CASE
|
|
|
WHEN CPCL_DOMAINE = 'VE' AND (CPCL_NATURE <> 'HO' OR ETAB_TYPE_PSPH = 1) THEN
|
|
|
CASE
|
|
|
WHEN CPTF_SENS = CPTF_SENS_positif THEN CPTF_MONTANT
|
|
|
ELSE 0-CPTF_MONTANT
|
|
|
END
|
|
|
ELSE 0 END
|
|
|
) AS montant_ventes_c,
|
|
|
SUM(CASE
|
|
|
WHEN CPCL_DOMAINE <> 'VE' AND (CPCL_NATURE <> 'HO' OR ETAB_TYPE_PSPH = 1) THEN
|
|
|
CASE WHEN CPTF_SENS = 'C' THEN CPTF_MONTANT ELSE 0-CPTF_MONTANT END
|
|
|
ELSE 0 END
|
|
|
) AS montant_reglements_c,
|
|
|
SUM(CASE
|
|
|
WHEN t_divers_cptahon.valeur = '1' AND CPCL_DOMAINE = 'VE' AND CPCL_NATURE = 'HO' AND ETAB_TYPE_PSPH <> 1 THEN
|
|
|
CASE
|
|
|
WHEN CPTF_SENS = CPTF_SENS_positif THEN CPTF_MONTANT
|
|
|
ELSE 0-CPTF_MONTANT
|
|
|
END
|
|
|
ELSE 0 END
|
|
|
) AS montant_ventes_h,
|
|
|
SUM(CASE
|
|
|
WHEN t_divers_cptahon.valeur = '1' AND CPCL_DOMAINE <> 'VE' AND CPCL_NATURE = 'HO' AND ETAB_TYPE_PSPH <> 1 THEN
|
|
|
CASE WHEN CPTF_SENS = 'C' THEN CPTF_MONTANT ELSE 0-CPTF_MONTANT END
|
|
|
ELSE 0 END
|
|
|
) AS montant_reglements_h
|
|
|
FROM w_SCP_CPTATRANSFERT_CPTF
|
|
|
JOIN activite.t_divers t_divers_cptahon ON t_divers_cptahon.code = 'CSIS_COMPTAHON'
|
|
|
JOIN activite.t_divers t_divers_srcvteets ON t_divers_srcvteets.code = 'CSIS_COMPTAVTEETSSRC'
|
|
|
LEFT JOIN SCP_CPTATRANSFERT_CPTF_param ON CPTF_NIVEAUDETAIL = CPTF_NIVEAUDETAIL_param
|
|
|
WHERE CPTF_FACTURE <> '0' AND (CPCL_DOMAINE <> 'VE' OR t_divers_srcvteets.VALEUR <> 'MPM_CPTAVENTEPRESTATION_CPVP')
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1
|
|
|
;
|
|
|
|
|
|
INSERT INTO w_chiffrier_comptable
|
|
|
SELECT date(date_trunc('month',CPVP_DATEECRITURE)) AS date_comptable,
|
|
|
SUM(CASE WHEN CPVP_SENS = 'D' THEN CPVP_MONTANT ELSE 0 - CPVP_MONTANT END) AS montant_ventes_c,
|
|
|
0::numeric AS montant_reglements_c,
|
|
|
0::numeric AS montant_ventes_h,
|
|
|
0::numeric AS montant_reglements_h
|
|
|
FROM prod_csis.MPM_CPTAVENTEPRESTATION_CPVP
|
|
|
JOIN activite.t_divers t_divers_srcvteets ON t_divers_srcvteets.code = 'CSIS_COMPTAVTEETSSRC'
|
|
|
JOIN prod_csis.SST_CPTAJOURNAL_CJRN ON CPVP_ID_CJRN = CJRN_ID
|
|
|
JOIN prod_csis.SCP_CPTACLOTURE_CPCL ON CPVP_ID_CPLC = CPCL_ID
|
|
|
LEFT JOIN activite.p_factures ON p_factures.no_facture = cpvp_facture
|
|
|
WHERE date(CPVP_DATEECRITURE) >= '[ENV_ADM_ANNEEDEBUT]0101' AND
|
|
|
CPVP_TYPE = 'CG' AND
|
|
|
CPVP_COMPTE LIKE '41%' AND
|
|
|
CPCL_DOMAINE = 'VE' AND
|
|
|
t_divers_srcvteets.VALEUR = 'MPM_CPTAVENTEPRESTATION_CPVP'
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1
|
|
|
;
|
|
|
|
|
|
TRUNCATE activite[PX].p_chiffrier_comptable;
|
|
|
INSERT INTO activite[PX].p_chiffrier_comptable(
|
|
|
date_comptable,
|
|
|
montant_ventes_c,
|
|
|
montant_reglements_c,
|
|
|
montant_ventes_h,
|
|
|
montant_reglements_h
|
|
|
)
|
|
|
SELECT
|
|
|
date_comptable,
|
|
|
SUM(montant_ventes_c),
|
|
|
SUM(montant_reglements_c),
|
|
|
SUM(montant_ventes_h),
|
|
|
SUM(montant_reglements_h)
|
|
|
FROM w_chiffrier_comptable
|
|
|
GROUP BY 1;
|
|
|
|
|
|
-- Detail par facture
|
|
|
DROP TABLE IF EXISTS w_chiffrier_comptable;
|
|
|
CREATE TEMP TABLE w_chiffrier_comptable AS
|
|
|
SELECT date(date_trunc('month',CPTF_DATEECRITURE)) AS date_comptable,
|
|
|
COALESCE(CPTF_FACTURE) AS no_facture,
|
|
|
SUM(CASE
|
|
|
WHEN CPCL_DOMAINE = 'VE' AND (CPCL_NATURE <> 'HO' OR ETAB_TYPE_PSPH = 1) THEN
|
|
|
CASE
|
|
|
WHEN CPTF_SENS = CPTF_SENS_positif THEN CPTF_MONTANT
|
|
|
ELSE 0-CPTF_MONTANT
|
|
|
END
|
|
|
ELSE 0 END
|
|
|
) AS montant_ventes_c,
|
|
|
SUM(CASE
|
|
|
WHEN CPCL_DOMAINE <> 'VE' AND (CPCL_NATURE <> 'HO' OR ETAB_TYPE_PSPH = 1) THEN
|
|
|
CASE WHEN CPTF_SENS = 'C' THEN CPTF_MONTANT ELSE 0-CPTF_MONTANT END
|
|
|
ELSE 0 END
|
|
|
) AS montant_reglements_c,
|
|
|
SUM(CASE
|
|
|
WHEN t_divers_cptahon.valeur = '1' AND CPCL_DOMAINE = 'VE' AND CPCL_NATURE = 'HO' AND ETAB_TYPE_PSPH <> 1 THEN
|
|
|
CASE
|
|
|
WHEN CPTF_SENS = CPTF_SENS_positif THEN CPTF_MONTANT
|
|
|
ELSE 0-CPTF_MONTANT
|
|
|
END
|
|
|
ELSE 0 END
|
|
|
) AS montant_ventes_h,
|
|
|
SUM(CASE
|
|
|
WHEN t_divers_cptahon.valeur = '1' AND CPCL_DOMAINE <> 'VE' AND CPCL_NATURE = 'HO' AND ETAB_TYPE_PSPH <> 1 THEN
|
|
|
CASE WHEN CPTF_SENS = 'C' THEN CPTF_MONTANT ELSE 0-CPTF_MONTANT END
|
|
|
ELSE 0 END
|
|
|
) AS montant_reglements_h
|
|
|
FROM w_SCP_CPTATRANSFERT_CPTF
|
|
|
JOIN activite.t_divers t_divers_cptahon ON t_divers_cptahon.code = 'CSIS_COMPTAHON'
|
|
|
JOIN activite.t_divers t_divers_srcvteets ON t_divers_srcvteets.code = 'CSIS_COMPTAVTEETSSRC'
|
|
|
LEFT JOIN SCP_CPTATRANSFERT_CPTF_param ON CPTF_NIVEAUDETAIL = CPTF_NIVEAUDETAIL_param
|
|
|
WHERE CPTF_FACTURE <> '0' AND (CPCL_DOMAINE <> 'VE' OR t_divers_srcvteets.VALEUR <> 'MPM_CPTAVENTEPRESTATION_CPVP')
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
INSERT INTO w_chiffrier_comptable
|
|
|
SELECT date(date_trunc('month',CPVP_DATEECRITURE)) AS date_comptable,
|
|
|
CPVP_FACTURE,
|
|
|
SUM(CASE WHEN CPVP_SENS = 'D' THEN CPVP_MONTANT ELSE 0 - CPVP_MONTANT END) AS montant_ventes_c,
|
|
|
0::numeric AS montant_reglements_c,
|
|
|
0::numeric AS montant_ventes_h,
|
|
|
0::numeric AS montant_reglements_h
|
|
|
FROM prod_csis.MPM_CPTAVENTEPRESTATION_CPVP
|
|
|
JOIN activite.t_divers t_divers_srcvteets ON t_divers_srcvteets.code = 'CSIS_COMPTAVTEETSSRC'
|
|
|
JOIN prod_csis.SST_CPTAJOURNAL_CJRN ON CPVP_ID_CJRN = CJRN_ID
|
|
|
JOIN prod_csis.SCP_CPTACLOTURE_CPCL ON CPVP_ID_CPLC = CPCL_ID
|
|
|
LEFT JOIN activite.p_factures ON p_factures.no_facture = cpvp_facture
|
|
|
WHERE date(CPVP_DATEECRITURE) >= '[ENV_ADM_ANNEEDEBUT]0101' AND
|
|
|
CPVP_TYPE = 'CG' AND
|
|
|
CPVP_COMPTE LIKE '41%' AND
|
|
|
CPCL_DOMAINE = 'VE' AND
|
|
|
t_divers_srcvteets.VALEUR = 'MPM_CPTAVENTEPRESTATION_CPVP'
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1
|
|
|
;
|
|
|
|
|
|
TRUNCATE activite[PX].p_factures_comptables;
|
|
|
INSERT INTO activite[PX].p_factures_comptables(
|
|
|
date_comptable,
|
|
|
no_facture,
|
|
|
montant_ventes_c,
|
|
|
montant_reglements_c,
|
|
|
montant_ventes_h,
|
|
|
montant_reglements_h
|
|
|
)
|
|
|
SELECT
|
|
|
date_comptable,
|
|
|
no_facture,
|
|
|
SUM(montant_ventes_c),
|
|
|
SUM(montant_reglements_c),
|
|
|
SUM(montant_ventes_h),
|
|
|
SUM(montant_reglements_h)
|
|
|
FROM w_chiffrier_comptable
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
-- Correction des numéros de facture en mode texte
|
|
|
UPDATE activite[PX].p_factures_comptables
|
|
|
SET no_facture = '0'||no_facture
|
|
|
WHERE '0'||no_facture IN (SELECT no_facture FROM activite[PX].p_factures) AND
|
|
|
no_facture NOT IN (SELECT no_facture FROM activite[PX].p_factures)
|
|
|
;
|
|
|
|
|
|
-- Ajustements du chiffrier dus au fait que certains honoraires comptabilisé en HON sont réglés en ETS
|
|
|
DROP TABLE IF EXISTS w_chiffrier_ajust;
|
|
|
CREATE TEMP TABLE w_chiffrier_ajust AS
|
|
|
SELECT no_facture,
|
|
|
facture_id,
|
|
|
date(date_trunc('month',date_comptable)) AS date_comptable,
|
|
|
SUM(montant_reglements_c) AS montant_regle_chiffrier_c,
|
|
|
SUM(montant_reglements_h) AS montant_regle_chiffrier_h
|
|
|
FROM activite[PX].p_factures_comptables
|
|
|
GROUP BY 1,2,3
|
|
|
;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_chiffrier_ajust_solde_c;
|
|
|
CREATE TEMP TABLE w_chiffrier_ajust_solde_c AS
|
|
|
SELECT no_facture,
|
|
|
date(date_trunc('month',date_comptable)) AS date_comptable,
|
|
|
SUM(montant_regle) AS montant_regle_solde_c
|
|
|
FROM activite[PX].p_factures_soldes_c
|
|
|
WHERE od_non_comptabilise <> '1'
|
|
|
GROUP BY 1,2
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_chiffrier_ajust_solde_h;
|
|
|
CREATE TEMP TABLE w_chiffrier_ajust_solde_h AS
|
|
|
SELECT no_facture,
|
|
|
date(date_trunc('month',date_comptable)) AS date_comptable,
|
|
|
SUM(montant_regle) AS montant_regle_solde_h
|
|
|
FROM activite[PX].p_factures_soldes_h
|
|
|
WHERE od_non_comptabilise <> '1'
|
|
|
GROUP BY 1,2
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_chiffrier_ajust_solde;
|
|
|
CREATE TEMP TABLE w_chiffrier_ajust_solde AS
|
|
|
SELECT w_chiffrier_ajust.no_facture,
|
|
|
w_chiffrier_ajust.facture_id,
|
|
|
w_chiffrier_ajust.date_comptable,
|
|
|
montant_regle_chiffrier_c - COALESCE(montant_regle_solde_c,0) AS ecart_montant_reglement_c,
|
|
|
montant_regle_chiffrier_h - COALESCE(montant_regle_solde_h,0) AS ecart_montant_reglement_h
|
|
|
FROM w_chiffrier_ajust
|
|
|
LEFT JOIN w_chiffrier_ajust_solde_c ON
|
|
|
w_chiffrier_ajust.no_facture = w_chiffrier_ajust_solde_c.no_facture AND
|
|
|
w_chiffrier_ajust.date_comptable = w_chiffrier_ajust_solde_c.date_comptable
|
|
|
LEFT JOIN w_chiffrier_ajust_solde_h ON
|
|
|
w_chiffrier_ajust.no_facture = w_chiffrier_ajust_solde_h.no_facture AND
|
|
|
w_chiffrier_ajust.date_comptable = w_chiffrier_ajust_solde_h.date_comptable
|
|
|
WHERE montant_regle_chiffrier_c + montant_regle_chiffrier_h = COALESCE(montant_regle_solde_c,0) + COALESCE(montant_regle_solde_h,0) AND
|
|
|
(
|
|
|
montant_regle_chiffrier_c <> COALESCE(montant_regle_solde_c,0)
|
|
|
)
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].p_factures_comptables SET
|
|
|
montant_reglements_c = montant_reglements_c - ecart_montant_reglement_c,
|
|
|
montant_reglements_h = montant_reglements_h - ecart_montant_reglement_h
|
|
|
FROM w_chiffrier_ajust_solde
|
|
|
WHERE w_chiffrier_ajust_solde.no_facture = p_factures_comptables.no_facture AND
|
|
|
w_chiffrier_ajust_solde.date_comptable = p_factures_comptables.date_comptable
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_comptables (
|
|
|
no_facture,
|
|
|
facture_id,
|
|
|
date_comptable,
|
|
|
montant_ventes_c,
|
|
|
montant_ventes_h,
|
|
|
montant_reglements_c,
|
|
|
montant_reglements_h
|
|
|
)
|
|
|
SELECT
|
|
|
w_chiffrier_ajust_solde.no_facture,
|
|
|
w_chiffrier_ajust_solde.facture_id,
|
|
|
w_chiffrier_ajust_solde.date_comptable,
|
|
|
0::numeric AS montant_ventes_c,
|
|
|
0::numeric AS montant_ventes_h,
|
|
|
0 - ecart_montant_reglement_c AS montant_reglements_c,
|
|
|
0 - ecart_montant_reglement_h AS montant_reglements_h
|
|
|
FROM w_chiffrier_ajust_solde
|
|
|
LEFT JOIN activite[PX].p_factures_comptables ON
|
|
|
w_chiffrier_ajust_solde.no_facture = p_factures_comptables.no_facture AND
|
|
|
w_chiffrier_ajust_solde.date_comptable = p_factures_comptables.date_comptable
|
|
|
WHERE p_factures_comptables.no_facture IS NULL
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].p_chiffrier_comptable SET
|
|
|
montant_reglements_c = montant_reglements_c - ecart_montant_reglement_c,
|
|
|
montant_reglements_h = montant_reglements_h - ecart_montant_reglement_h
|
|
|
FROM
|
|
|
(
|
|
|
SELECT date_comptable,
|
|
|
SUM(ecart_montant_reglement_c) AS ecart_montant_reglement_c,
|
|
|
SUM(ecart_montant_reglement_h) AS ecart_montant_reglement_h
|
|
|
FROM w_chiffrier_ajust_solde
|
|
|
GROUP BY 1
|
|
|
) subview
|
|
|
WHERE p_chiffrier_comptable.date_comptable = subview.date_comptable
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="PARAM" label="RECUPERATION DES PARAMETRES">
|
|
|
|
|
|
<NODE label="Type d'environnement">
|
|
|
<sqlcmd><![CDATA[
|
|
|
CTISELECT_PROPERTY_READ 'ENV_WITHPMSI', MAX(CASE WHEN schemaname = 'pmsi' AND tablename = 'p_rss' THEN 1 ELSE 0 END)
|
|
|
FROM pg_tables
|
|
|
WHERE schemaname = 'pmsi' AND tablename = 'p_rss'
|
|
|
;
|
|
|
|
|
|
CTISELECT_PROPERTY_READ 'ENV_WITHPMSISSR', MAX(CASE WHEN schemaname = 'pmsissr' AND tablename = 'p_ssr' THEN 1 ELSE 0 END)
|
|
|
FROM pg_tables
|
|
|
WHERE schemaname = 'pmsissr' AND tablename = 'p_ssr'
|
|
|
;
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Etablissements">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Paramètre de génération
|
|
|
INSERT INTO activite.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'CSIS_FACNVAL',
|
|
|
'CSIS-MEDSPHERE. Traitement factures non validées ',
|
|
|
'0',
|
|
|
'0 = Ne pas traiter la facturation, 1 = Récupérer montants facturés non comptabilisés, 2 = Récupérer comme en-cours'
|
|
|
WHERE 'CSIS_FACNVAL' NOT IN (SELECT code FROM activite.t_divers);
|
|
|
|
|
|
INSERT INTO activite.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'CSIS_FACDATVEN',
|
|
|
'CSIS-MEDSPHERE. Champ pour date des ventes',
|
|
|
'0',
|
|
|
'0 = RECF_DATEFACTDEB, 1 = RECF_ID_CPCL'
|
|
|
WHERE 'CSIS_FACDATVEN' NOT IN (SELECT code FROM activite.t_divers);
|
|
|
|
|
|
INSERT INTO activite.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'CSIS_ETAGE',
|
|
|
'CSIS-MEDSPHERE. Codification étage ',
|
|
|
'',
|
|
|
'AILE = Ajouter Aile à l''étage'
|
|
|
WHERE 'CSIS_ETAGE' NOT IN (SELECT code FROM activite.t_divers);
|
|
|
|
|
|
INSERT INTO activite.t_divers (code, texte, valeur, description)
|
|
|
SELECT
|
|
|
'CSIS_FACHISTOHDJ',
|
|
|
'CSIS-MEDSPHERE. Identification HDJ dans historique',
|
|
|
'0',
|
|
|
'0 = Identifier à partir de la date de démarrage MS, 1 = Identifier à partir du début de séjour'
|
|
|
WHERE 'CSIS_FACHISTOHDJ' NOT IN (SELECT code FROM activite.t_divers);
|
|
|
|
|
|
|
|
|
|
|
|
-- Etablissements
|
|
|
DROP TABLE IF EXISTS w_SST_ETABLISSEMENT_ETAB;
|
|
|
CREATE TEMP TABLE w_SST_ETABLISSEMENT_ETAB AS
|
|
|
SELECT ETAB_ID, ETAB_CODE, ETAB_FINESS, ''::text AS ETAB_PREFIX, ETAB_ID_DOMA,
|
|
|
CASE WHEN COALESCE(PSPH_CODE,'0') <> '0' AND COALESCE(PSPH_CODE,'0') <> '' THEN 1 ELSE 0 END::numeric AS ETAB_TYPE_PSPH
|
|
|
FROM prod_csis.SST_ETABLISSEMENT_ETAB
|
|
|
LEFT JOIN prod_csis.SNO_PARTICIPEPSPH_PSPH ON ETAB_ID_PSPH = PSPH_ID
|
|
|
WHERE ETAB_ID IN ([ID_ETAB]) OR '[ID_ETAB]' = '-1';
|
|
|
|
|
|
UPDATE w_SST_ETABLISSEMENT_ETAB
|
|
|
SET ETAB_CODE = NULL
|
|
|
WHERE (SELECT count(*) FROM w_SST_ETABLISSEMENT_ETAB) <= 1;
|
|
|
|
|
|
UPDATE w_SST_ETABLISSEMENT_ETAB
|
|
|
SET ETAB_PREFIX = ETAB_CODE
|
|
|
WHERE (SELECT count(*) FROM w_SST_ETABLISSEMENT_ETAB) > 1;
|
|
|
|
|
|
|
|
|
--UPDATE w_SST_ETABLISSEMENT_ETAB
|
|
|
--SET ETAB_CODE = substr(ETAB_CODE,1,2)
|
|
|
--WHERE ETAB_CODE IS NOT NULL;
|
|
|
]]></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 ALL
|
|
|
SELECT '1','Régime général'
|
|
|
UNION ALL
|
|
|
SELECT '2','Mutuelles'
|
|
|
) subview
|
|
|
WHERE code NOT IN (SELECT code FROM activite[PX].t_types_tiers_payant);
|
|
|
|
|
|
INSERT INTO activite[PX].t_tiers_payant(oid, code, code_original, type_tiers_payant, texte, texte_court)
|
|
|
SELECT 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 'PATIENTS', '0', '0', 'Patients', 'Patients'
|
|
|
WHERE '0' NOT IN (SELECT code_original FROM activite[PX].t_tiers_payant);
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_tiers_payant(code_original, code, type_tiers_payant, texte, texte_court)
|
|
|
SELECT orgn_id::bigint,
|
|
|
orgn_code, CASE WHEN orgn_type = 'O' THEN '1' ELSE '2' END,
|
|
|
orgn_nom,
|
|
|
orgn_nom
|
|
|
FROM prod_csis.sst_organisme_orgn
|
|
|
WHERE orgn_code IS NOT NULL AND
|
|
|
orgn_code <> '' AND
|
|
|
orgn_id::bigint NOT IN (SELECT code_original FROM activite[PX].t_tiers_payant);
|
|
|
|
|
|
UPDATE activite[PX].t_tiers_payant SET
|
|
|
code = orgn_code,
|
|
|
texte = orgn_nom,
|
|
|
texte_court = orgn_nom
|
|
|
FROM prod_csis.sst_organisme_orgn
|
|
|
WHERE orgn_id = code_original AND
|
|
|
(
|
|
|
code IS DISTINCT FROM orgn_code OR
|
|
|
texte IS DISTINCT FROM orgn_nom OR
|
|
|
texte_court IS DISTINCT FROM orgn_nom
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Médecins">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
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_specialites_medecin(code_original, code, texte, texte_court)
|
|
|
SELECT
|
|
|
SPEC_CODE,
|
|
|
SPEC_CODE,
|
|
|
MAX(SPEC_LIBELLE),
|
|
|
MAX(SPEC_LIBELLE)
|
|
|
FROM
|
|
|
prod_csis.SST_SPECIALITE_SPEC
|
|
|
LEFT JOIN base.t_specialites_medecin ON t_specialites_medecin.code = SPEC_CODE
|
|
|
WHERE 1=1
|
|
|
AND SPEC_CODE <> ''
|
|
|
AND SPEC_CODE IS NOT NULL
|
|
|
AND t_specialites_medecin.code IS NULL
|
|
|
GROUP BY SPEC_CODE
|
|
|
ORDER BY SPEC_CODE;
|
|
|
|
|
|
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_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 MEDN_ID::bigint,
|
|
|
MAX(CASE WHEN MEDN_CODE <> '' AND MEDN_CODE IS NOT NULL THEN MEDN_CODE ELSE 'W' || CAST(MEDN_ID AS char) END) AS MEDN_CODE,
|
|
|
MAX(base.cti_soundex_nom(MEDN_NOM)) AS MEDN_NOM_SOUNDEX,
|
|
|
MAX(base.cti_soundex_nom(COALESCE(MEDN_PRENOM,''))) AS MEDN_PRENOM_SOUNDEX,
|
|
|
MAX(MEDN_NOM) AS MEDN_NOM,
|
|
|
MAX(COALESCE(MEDN_PRENOM,'')) AS MEDN_PRENOM,
|
|
|
MAX(COALESCE(MEDN_CODEADELI,'')) AS MEDN_CODEADELI,
|
|
|
MAX(COALESCE(METB_ID_SPEC,0)::bigint) AS METB_ID_SPEC,
|
|
|
MAX(COALESCE(t_medecins_administratifs.medecin_id,0)) as medecin_id
|
|
|
FROM prod_csis.SST_MEDECIN_MEDN
|
|
|
LEFT JOIN prod_csis.SST_MEDETAB_METB ON METB_ID_MEDN = MEDN_ID
|
|
|
LEFT JOIN activite[PX].t_medecins_administratifs ON MEDN_ID = t_medecins_administratifs.code_original
|
|
|
JOIN w_SST_ETABLISSEMENT_ETAB ON METB_ID_ETAB = ETAB_ID
|
|
|
WHERE MEDN_TRAITANT <> '1'
|
|
|
OR
|
|
|
MEDN_ID IN (SELECT MVMT_CHPNUM1 FROM prod_csis.SMV_MOUVEMENT_MVMT
|
|
|
JOIN prod_csis.SMV_TYPEMOUVEMENT_TMVT ON mvmt_id_tmvt = tmvt_id AND TMVT_CODE = 'R' GROUP BY 1)
|
|
|
OR
|
|
|
MEDN_ID IN (SELECT RECG_ID1_MEDN FROM prod_csis.MPM_RECUEIL_RECG GROUP BY 1)
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO base.t_medecins(nom, prenom, numero_ordre, specialite_id)
|
|
|
SELECT w_medecins.MEDN_NOM, w_medecins.MEDN_PRENOM, w_medecins.MEDN_CODEADELI, 0 FROM
|
|
|
(SELECT SUBSTR(MEDN_NOM_SOUNDEX, 1, 8) AS MEDN_NOM_SOUNDEX, SUBSTR(MEDN_PRENOM_SOUNDEX, 1, 8) AS MEDN_PRENOM_SOUNDEX, MEDN_CODEADELI, MIN(MEDN_ID) AS MEDN_ID
|
|
|
FROM w_medecins
|
|
|
GROUP BY 1,2,3) subview, w_medecins
|
|
|
WHERE w_medecins.MEDN_ID = subview.MEDN_ID
|
|
|
AND subview.MEDN_NOM_SOUNDEX || ',' || subview.MEDN_PRENOM_SOUNDEX || ',' || subview.MEDN_CODEADELI NOT IN
|
|
|
(SELECT substr(base.cti_soundex_nom(nom),1,8) || ',' || substr(base.cti_soundex_nom(prenom),1,8) || ',' || numero_ordre FROM base.t_medecins);
|
|
|
|
|
|
|
|
|
INSERT INTO base.t_medecins(nom, prenom, numero_ordre, specialite_id)
|
|
|
SELECT w_medecins.MEDN_NOM, w_medecins.MEDN_PRENOM, w_medecins.MEDN_CODEADELI, 0 FROM
|
|
|
(SELECT MEDN_NOM_SOUNDEX, MEDN_PRENOM_SOUNDEX, MIN(MEDN_ID) AS MEDN_ID
|
|
|
FROM w_medecins
|
|
|
GROUP BY 1,2) subview, w_medecins
|
|
|
WHERE w_medecins.MEDN_ID = subview.MEDN_ID
|
|
|
AND subview.MEDN_NOM_SOUNDEX || ',' || subview.MEDN_PRENOM_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(MEDN_NOM_SOUNDEX, 1, 8) = subview.nom
|
|
|
AND SUBSTR(MEDN_PRENOM_SOUNDEX, 1, 8) = subview.prenom
|
|
|
AND MEDN_CODEADELI = subview.numero_ordre
|
|
|
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 SUBSTR(MEDN_NOM_SOUNDEX, 1, 8) = subview.nom
|
|
|
AND SUBSTR(MEDN_PRENOM_SOUNDEX, 1, 8) = 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 MEDN_ID, MEDN_CODE, MEDN_NOM, MEDN_PRENOM, COALESCE(t_specialites_medecin.oid,0), medecin_id
|
|
|
FROM w_medecins
|
|
|
LEFT JOIN prod_csis.SST_SPECIALITE_SPEC ON METB_ID_SPEC = SPEC_ID
|
|
|
LEFT JOIN base.t_specialites_medecin ON (SPEC_CODE = t_specialites_medecin.code)
|
|
|
WHERE MEDN_ID NOT IN (SELECT code_original FROM activite[PX].t_medecins_administratifs);
|
|
|
|
|
|
UPDATE activite[PX].t_medecins_administratifs
|
|
|
SET nom = MEDN_NOM,
|
|
|
prenom = MEDN_PRENOM,
|
|
|
specialite_id = COALESCE(t_specialites_medecin.oid,0),
|
|
|
medecin_id = w_medecins.medecin_id,
|
|
|
no_adeli = MEDN_CODEADELI
|
|
|
FROM w_medecins
|
|
|
LEFT JOIN prod_csis.SST_SPECIALITE_SPEC ON METB_ID_SPEC = SPEC_ID
|
|
|
LEFT JOIN base.t_specialites_medecin ON (SPEC_CODE = t_specialites_medecin.code)
|
|
|
WHERE w_medecins.MEDN_ID = t_medecins_administratifs.code_original
|
|
|
AND (
|
|
|
t_medecins_administratifs.nom IS DISTINCT FROM MEDN_NOM OR
|
|
|
t_medecins_administratifs.prenom IS DISTINCT FROM MEDN_PRENOM OR
|
|
|
t_medecins_administratifs.specialite_id IS DISTINCT FROM COALESCE(t_specialites_medecin.oid,0) OR
|
|
|
t_medecins_administratifs.medecin_id IS DISTINCT FROM w_medecins.medecin_id OR
|
|
|
t_medecins_administratifs.no_adeli IS DISTINCT FROM w_medecins.MEDN_CODEADELI
|
|
|
);
|
|
|
|
|
|
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;
|
|
|
|
|
|
|
|
|
-- Adresse et coordonnées
|
|
|
INSERT INTO base.t_codes_postaux(code, texte, texte_court, departement_id)
|
|
|
SELECT MEDN_CODEPOSTAL, MAX(MEDN_VILLE), MAX(MEDN_VILLE), MAX(t_departements.oid)
|
|
|
FROM prod_csis.SST_MEDECIN_MEDN
|
|
|
LEFT JOIN base.t_codes_postaux ON MEDN_CODEPOSTAL = t_codes_postaux.code
|
|
|
JOIN base.t_departements ON
|
|
|
MEDN_CODEPOSTAL NOT LIKE '97%' AND substr(MEDN_CODEPOSTAL,1,2) = t_departements.code OR
|
|
|
MEDN_CODEPOSTAL LIKE '97%' AND substr(MEDN_CODEPOSTAL,1,3) = t_departements.code
|
|
|
WHERE MEDN_CODEPOSTAL <> '' AND
|
|
|
length(MEDN_CODEPOSTAL) = 5 AND
|
|
|
t_codes_postaux.code IS NULL
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].t_medecins_administratifs SET
|
|
|
adresse = MEDN_ADRESSEx,
|
|
|
code_postal_id = subview.code_postal_id,
|
|
|
ville = MEDN_VILLE,
|
|
|
telephone = MEDN_TELEPHONEx,
|
|
|
fax = MEDN_FAX,
|
|
|
email = MEDN_EMAIL
|
|
|
FROM
|
|
|
(
|
|
|
SELECT t_medecins_administratifs.oid,
|
|
|
trim(MEDN_ADRESSE1 || ' ' || MEDN_ADRESSE2) AS MEDN_ADRESSEx,
|
|
|
trim(MEDN_VILLE) AS MEDN_VILLE,
|
|
|
trim(MEDN_CODEPOSTAL) AS MEDN_CODEPOSTAL,
|
|
|
COALESCE(t_codes_postaux.oid,0)::text::bigint AS code_postal_id,
|
|
|
trim(MEDN_TELEPHONE1 || ' ' || MEDN_TELEPHONE2 || ' ' || MEDN_TELEPHONE3) AS MEDN_TELEPHONEx,
|
|
|
trim(MEDN_FAX) AS MEDN_FAX,
|
|
|
trim(MEDN_EMAIL) AS MEDN_EMAIL
|
|
|
FROM activite[PX].t_medecins_administratifs
|
|
|
JOIN prod_csis.SST_MEDECIN_MEDN ON code_original = MEDN_ID
|
|
|
LEFT JOIN base.t_codes_postaux ON MEDN_CODEPOSTAL = t_codes_postaux.code
|
|
|
) subview
|
|
|
WHERE t_medecins_administratifs.oid = subview.oid AND
|
|
|
(
|
|
|
t_medecins_administratifs.adresse IS DISTINCT FROM MEDN_ADRESSEx OR
|
|
|
t_medecins_administratifs.code_postal_id IS DISTINCT FROM subview.code_postal_id OR
|
|
|
t_medecins_administratifs.ville IS DISTINCT FROM MEDN_VILLE OR
|
|
|
t_medecins_administratifs.telephone IS DISTINCT FROM MEDN_TELEPHONEx OR
|
|
|
t_medecins_administratifs.fax IS DISTINCT FROM MEDN_FAX OR
|
|
|
t_medecins_administratifs.email IS DISTINCT FROM MEDN_EMAIL
|
|
|
)
|
|
|
;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Hébergement">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
-- Modes de traitement
|
|
|
|
|
|
INSERT INTO base.t_modes_traitement(code, texte, texte_court)
|
|
|
SELECT MODE_CODE, MODE_LIBELLE, MODE_LIBELLE
|
|
|
FROM prod_csis.SNO_MODE_MODE
|
|
|
JOIN prod_csis.SNO_TYPEMODE_TYMO ON MODE_ID_TYMO = TYMO_ID AND TYMO_CODE = '3'
|
|
|
WHERE MODE_CODE NOT IN (SELECT code FROM base.t_modes_traitement)
|
|
|
ORDER BY MODE_CODE;
|
|
|
|
|
|
-- DMT
|
|
|
|
|
|
INSERT INTO base.t_dmt(code, texte, texte_court)
|
|
|
SELECT TB14_CODE, TB14_LIBELLE, TB14_LIBELLE
|
|
|
FROM prod_csis.SNO_DMT_TB14
|
|
|
WHERE TB14_CODE NOT IN (SELECT code FROM base.t_dmt)
|
|
|
ORDER BY TB14_CODE;
|
|
|
|
|
|
-- 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);
|
|
|
|
|
|
UPDATE activite[PX].t_services_facturation SET
|
|
|
code = DSNT_CODE,
|
|
|
texte = DSNT_LIBELLE,
|
|
|
texte_court = DSNT_LIBELLE
|
|
|
FROM prod_csis.SST_DISCIPINTERNE_DSNT
|
|
|
WHERE DSNT_ID = code_original AND
|
|
|
(
|
|
|
code IS DISTINCT FROM DSNT_CODE OR
|
|
|
texte IS DISTINCT FROM DSNT_LIBELLE OR
|
|
|
texte_court IS DISTINCT FROM DSNT_LIBELLE
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_services_facturation(code_original, code, texte, texte_court, type_t2a)
|
|
|
SELECT DSNT_ID::bigint,
|
|
|
DSNT_CODE ,
|
|
|
DSNT_LIBELLE,
|
|
|
DSNT_LIBELLE,
|
|
|
'0'::text AS type_t2a
|
|
|
FROM prod_csis.SST_DISCIPINTERNE_DSNT
|
|
|
WHERE DSNT_ID IN
|
|
|
(
|
|
|
SELECT DSTB_ID_DSNT
|
|
|
FROM prod_csis.SST_DISCIPLINEETAB_DSTB
|
|
|
JOIN w_SST_ETABLISSEMENT_ETAB ON DSTB_ID_ETAB = ETAB_ID
|
|
|
) AND
|
|
|
DSNT_ID::bigint NOT IN (SELECT code_original FROM activite[PX].t_services_facturation)
|
|
|
ORDER BY DSNT_CODE;
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].t_services_facturation
|
|
|
SET
|
|
|
mode_traitement_id = CASE WHEN t_services_facturation.mode_traitement_id = 0 THEN subview.mode_traitement_id ELSE t_services_facturation.mode_traitement_id END,
|
|
|
dmt_id = CASE WHEN t_services_facturation.dmt_id = 0 THEN subview.dmt_id ELSE t_services_facturation.dmt_id END
|
|
|
FROM (
|
|
|
SELECT DSNT_ID,
|
|
|
COALESCE(t_modes_traitement.oid,0) AS mode_traitement_id,
|
|
|
COALESCE(t_dmt.oid,0) AS dmt_id
|
|
|
FROM prod_csis.SST_DISCIPINTERNE_DSNT
|
|
|
LEFT JOIN prod_csis.SNO_MODE_MODE ON DSNT_id_MODE = MODE_id
|
|
|
LEFT JOIN prod_csis.SNO_DMT_TB14 ON DSNT_id_TB14 = TB14_id
|
|
|
LEFT JOIN base.t_modes_traitement ON MODE_CODE = t_modes_traitement.code
|
|
|
LEFT JOIN base.t_dmt ON TB14_CODE = t_dmt.code
|
|
|
ORDER BY DSNT_id
|
|
|
) subview
|
|
|
WHERE code_original = DSNT_ID AND (t_services_facturation.mode_traitement_id = 0 OR t_services_facturation.dmt_id = 0);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- 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);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SST_UNITEFONCT_NTFN;
|
|
|
CREATE TEMP TABLE w_SST_UNITEFONCT_NTFN AS
|
|
|
SELECT *
|
|
|
FROM prod_csis.SST_UNITEFONCT_NTFN
|
|
|
JOIN w_SST_ETABLISSEMENT_ETAB ON ETAB_ID = NTFN_ID_ETAB
|
|
|
;
|
|
|
|
|
|
UPDATE w_SST_UNITEFONCT_NTFN
|
|
|
SET NTFN_CODE = COALESCE(ETAB_PREFIX || '_','') || w_SST_UNITEFONCT_NTFN.NTFN_CODE
|
|
|
FROM
|
|
|
(
|
|
|
SELECT NTFN_CODE
|
|
|
FROM w_SST_UNITEFONCT_NTFN
|
|
|
GROUP BY 1
|
|
|
HAVING count(*) > 1
|
|
|
) subview
|
|
|
WHERE w_SST_UNITEFONCT_NTFN.NTFN_CODE = subview.NTFN_CODE
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].t_unites_fonctionnelles SET
|
|
|
code = NTFN_CODE,
|
|
|
texte = NTFN_LIBELLE,
|
|
|
texte_court = NTFN_LIBELLE
|
|
|
FROM prod_csis.SST_UNITEFONCT_NTFN
|
|
|
WHERE NTFN_ID = code_original AND
|
|
|
(
|
|
|
code IS DISTINCT FROM NTFN_CODE OR
|
|
|
texte IS DISTINCT FROM NTFN_LIBELLE OR
|
|
|
texte_court IS DISTINCT FROM NTFN_LIBELLE
|
|
|
)
|
|
|
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite[PX].t_unites_fonctionnelles(code_original, code, texte, texte_court)
|
|
|
SELECT
|
|
|
NTFN_ID::bigint,
|
|
|
NTFN_CODE,
|
|
|
NTFN_LIBELLE,
|
|
|
NTFN_LIBELLE
|
|
|
FROM w_SST_UNITEFONCT_NTFN
|
|
|
WHERE
|
|
|
NTFN_ID::bigint NOT IN (SELECT code_original FROM activite[PX].t_unites_fonctionnelles)
|
|
|
ORDER BY NTFN_CODE;
|
|
|
|
|
|
UPDATE activite[PX].t_unites_fonctionnelles
|
|
|
SET code = code || '-' || oid
|
|
|
FROM w_SST_UNITEFONCT_NTFN
|
|
|
WHERE code_original = NTFN_ID AND
|
|
|
NTFN_CODE <> code
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].t_unites_fonctionnelles
|
|
|
SET code = NTFN_CODE,
|
|
|
texte = NTFN_LIBELLE,
|
|
|
texte_court = NTFN_LIBELLE
|
|
|
FROM w_SST_UNITEFONCT_NTFN
|
|
|
WHERE code_original = NTFN_ID AND
|
|
|
(
|
|
|
code IS DISTINCT FROM NTFN_CODE OR
|
|
|
texte IS DISTINCT FROM NTFN_LIBELLE OR
|
|
|
texte_court IS DISTINCT FROM NTFN_LIBELLE
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
-- 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);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SST_UNITEMED_NTMD;
|
|
|
CREATE TEMP TABLE w_SST_UNITEMED_NTMD AS
|
|
|
SELECT *
|
|
|
FROM prod_csis.SST_UNITEMED_NTMD
|
|
|
JOIN w_SST_ETABLISSEMENT_ETAB ON ETAB_ID = NTMD_ID_ETAB
|
|
|
;
|
|
|
|
|
|
UPDATE w_SST_UNITEMED_NTMD
|
|
|
SET NTMD_CODE = COALESCE(ETAB_PREFIX || '_','') || w_SST_UNITEMED_NTMD.NTMD_CODE
|
|
|
FROM
|
|
|
(
|
|
|
SELECT NTMD_CODE
|
|
|
FROM w_SST_UNITEMED_NTMD
|
|
|
GROUP BY 1
|
|
|
HAVING count(*) > 1
|
|
|
) subview
|
|
|
WHERE w_SST_UNITEMED_NTMD.NTMD_CODE = subview.NTMD_CODE
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].t_unites_medicales SET
|
|
|
code = NTMD_CODE,
|
|
|
texte = NTMD_LIBELLE,
|
|
|
texte_court = NTMD_LIBELLE
|
|
|
FROM prod_csis.SST_UNITEMED_NTMD
|
|
|
WHERE NTMD_ID = code_original AND
|
|
|
(
|
|
|
code IS DISTINCT FROM NTMD_CODE OR
|
|
|
texte IS DISTINCT FROM NTMD_LIBELLE OR
|
|
|
texte_court IS DISTINCT FROM NTMD_LIBELLE
|
|
|
)
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite[PX].t_unites_medicales(code_original, code, texte, texte_court)
|
|
|
SELECT
|
|
|
NTMD_ID::bigint,
|
|
|
NTMD_CODE,
|
|
|
NTMD_LIBELLE,
|
|
|
NTMD_LIBELLE
|
|
|
FROM w_SST_UNITEMED_NTMD
|
|
|
WHERE
|
|
|
NTMD_ID::bigint NOT IN (SELECT code_original FROM activite[PX].t_unites_medicales)
|
|
|
ORDER BY NTMD_CODE;
|
|
|
|
|
|
UPDATE activite[PX].t_unites_medicales
|
|
|
SET code = code || '-' || oid
|
|
|
FROM w_SST_UNITEMED_NTMD
|
|
|
WHERE code_original = NTMD_ID AND
|
|
|
NTMD_CODE <> code
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].t_unites_medicales
|
|
|
SET code = NTMD_CODE,
|
|
|
texte = NTMD_LIBELLE,
|
|
|
texte_court = NTMD_LIBELLE
|
|
|
FROM w_SST_UNITEMED_NTMD
|
|
|
WHERE code_original = NTMD_ID AND
|
|
|
(
|
|
|
code IS DISTINCT FROM NTMD_CODE OR
|
|
|
texte IS DISTINCT FROM NTMD_LIBELLE OR
|
|
|
texte_court IS DISTINCT FROM NTMD_LIBELLE
|
|
|
)
|
|
|
;
|
|
|
|
|
|
-- Activités
|
|
|
TRUNCATE activite[PX].t_activites;
|
|
|
INSERT INTO activite[PX].t_activites(oid, code_original, code, texte, texte_court)
|
|
|
SELECT oid, code_original, substr(code,1,10), texte, texte_court
|
|
|
FROM activite[PX].t_unites_medicales
|
|
|
WHERE
|
|
|
oid NOT IN (SELECT oid FROM activite[PX].t_activites)
|
|
|
ORDER BY oid;
|
|
|
|
|
|
|
|
|
|
|
|
-- 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);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SST_ETAGE_ETAG;
|
|
|
CREATE TEMP TABLE w_SST_ETAGE_ETAG AS
|
|
|
SELECT ETAG_ID, ETAG_CODE, ETAG_LIBELLE,
|
|
|
BTMN_ID, BTMN_CODE, BTMN_LIBELLE,
|
|
|
AILE_ID, AILE_CODE, AILE_LIBELLE,
|
|
|
ETAB_PREFIX,
|
|
|
COALESCE(t_divers.valeur,'') AS divers_csis_etage,
|
|
|
0::bigint AS LINK_ID,
|
|
|
''::text AS LINK_CODE,
|
|
|
''::text AS LINK_LIBELLE
|
|
|
FROM prod_csis.SST_ETAGE_ETAG
|
|
|
JOIN prod_csis.SST_BATIMENT_BTMN ON ETAG_ID_BTMN = BTMN_ID
|
|
|
JOIN prod_csis.SST_AILE_AILE ON AILE_ID_ETAG = ETAG_ID
|
|
|
JOIN w_SST_ETABLISSEMENT_ETAB ON ETAB_ID = BTMN_ID_ETAB
|
|
|
LEFT JOIN activite.t_divers ON t_divers.code = 'CSIS_ETAGE'
|
|
|
;
|
|
|
|
|
|
UPDATE w_SST_ETAGE_ETAG SET
|
|
|
LINK_ID = ETAG_ID,
|
|
|
LINK_CODE = CASE WHEN BTMN_CODE <> '' THEN BTMN_CODE || '_' ELSE '' END || ETAG_CODE,
|
|
|
LINK_LIBELLE = trim(BTMN_LIBELLE || ' ' || ETAG_LIBELLE)
|
|
|
WHERE divers_csis_etage IS DISTINCT FROM 'AILE'
|
|
|
;
|
|
|
UPDATE w_SST_ETAGE_ETAG SET
|
|
|
LINK_ID = AILE_ID,
|
|
|
LINK_CODE = CASE WHEN BTMN_CODE <> '' THEN BTMN_CODE || '_' ELSE '' END || ETAG_CODE || CASE WHEN AILE_CODE <> '' THEN '_' || AILE_CODE ELSE '' END ,
|
|
|
LINK_LIBELLE = trim(BTMN_LIBELLE || ' ' || ETAG_LIBELLE || ' ' || AILE_LIBELLE)
|
|
|
WHERE divers_csis_etage = 'AILE'
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_SST_ETAGE_ETAG
|
|
|
SET LINK_CODE = COALESCE(ETAB_PREFIX || '_','') || w_SST_ETAGE_ETAG.LINK_CODE
|
|
|
FROM
|
|
|
(
|
|
|
SELECT LINK_CODE
|
|
|
FROM w_SST_ETAGE_ETAG
|
|
|
GROUP BY 1
|
|
|
HAVING count(*) > 1
|
|
|
) subview
|
|
|
WHERE w_SST_ETAGE_ETAG.LINK_CODE = subview.LINK_CODE
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite[PX].t_etages(code_original, code, texte, texte_court)
|
|
|
SELECT
|
|
|
LINK_ID::bigint,
|
|
|
LINK_CODE,
|
|
|
LINK_LIBELLE,
|
|
|
LINK_LIBELLE
|
|
|
FROM w_SST_ETAGE_ETAG
|
|
|
WHERE
|
|
|
LINK_ID::bigint NOT IN (SELECT code_original FROM activite[PX].t_etages)
|
|
|
ORDER BY LINK_CODE;
|
|
|
|
|
|
UPDATE activite[PX].t_etages
|
|
|
SET code = code || '-' || oid
|
|
|
FROM w_SST_ETAGE_ETAG
|
|
|
WHERE code_original = LINK_ID AND
|
|
|
LINK_CODE <> code
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].t_etages
|
|
|
SET code = LINK_CODE,
|
|
|
texte = LINK_LIBELLE,
|
|
|
texte_court = LINK_LIBELLE
|
|
|
FROM w_SST_ETAGE_ETAG
|
|
|
WHERE code_original = LINK_ID AND
|
|
|
(
|
|
|
code IS DISTINCT FROM LINK_CODE OR
|
|
|
texte IS DISTINCT FROM LINK_LIBELLE OR
|
|
|
texte_court IS DISTINCT FROM LINK_LIBELLE
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_LIT_LITS;
|
|
|
CREATE TEMP TABLE w_LIT_LITS AS
|
|
|
SELECT LITS_ID::bigint,
|
|
|
LITS_CODE,
|
|
|
LITS_LIBELLE,
|
|
|
t_etages.oid AS etage_id,
|
|
|
CASE WHEN PSTN_CODE = 'IND' THEN 'O' ELSE 'N' END AS chambre_particuliere
|
|
|
FROM prod_csis.sst_lit_lits
|
|
|
JOIN prod_csis.sst_piece_piec ON LITS_ID_PIEC = PIEC_ID
|
|
|
JOIN prod_csis.sst_aile_aile ON PIEC_ID_AILE = AILE_ID
|
|
|
JOIN prod_csis.SST_ETAGE_ETAG ON AILE_ID_ETAG = ETAG_ID
|
|
|
JOIN prod_csis.SST_BATIMENT_BTMN ON ETAG_ID_BTMN = BTMN_ID
|
|
|
JOIN w_SST_ETABLISSEMENT_ETAB ON ETAB_ID = BTMN_ID_ETAB
|
|
|
LEFT JOIN prod_csis.sst_position_pstn ON LITS_ID_PSTN = PSTN_ID
|
|
|
LEFT JOIN activite.t_divers ON t_divers.code = 'CSIS_ETAGE'
|
|
|
JOIN activite[PX].t_etages ON
|
|
|
(
|
|
|
AILE_ID_ETAG::bigint = t_etages.code_original AND t_divers.valeur IS DISTINCT FROM 'AILE' OR
|
|
|
AILE_ID::bigint = t_etages.code_original AND t_divers.valeur = 'AILE'
|
|
|
);
|
|
|
|
|
|
|
|
|
UPDATE w_LIT_LITS
|
|
|
SET LITS_CODE = w_LIT_LITS.LITS_CODE || '_' || indice
|
|
|
FROM
|
|
|
(
|
|
|
SELECT ETAGE_ID, LITS_CODE, MAX(LITS_ID) AS LITS_ID, count(*) AS indice
|
|
|
FROM w_LIT_LITS
|
|
|
GROUP BY 1,2
|
|
|
HAVING count(*) > 1
|
|
|
) subview
|
|
|
WHERE w_LIT_LITS.LITS_ID = subview.LITS_ID;
|
|
|
|
|
|
INSERT INTO activite[PX].t_lits(code_original, code, texte, texte_court, etage_id, chambre_particuliere)
|
|
|
SELECT LITS_ID,
|
|
|
LITS_CODE,
|
|
|
LITS_LIBELLE,
|
|
|
LITS_LIBELLE,
|
|
|
etage_id,
|
|
|
chambre_particuliere
|
|
|
FROM w_LIT_LITS
|
|
|
WHERE LITS_ID::bigint NOT IN (SELECT code_original FROM activite[PX].t_lits WHERE code_original IS NOT NULL);
|
|
|
|
|
|
UPDATE activite[PX].t_lits SET
|
|
|
code = code || oid,
|
|
|
etage_id = w_LIT_LITS.etage_id
|
|
|
FROM w_LIT_LITS
|
|
|
WHERE LITS_ID = t_lits.code_original AND
|
|
|
(
|
|
|
t_lits.code IS DISTINCT FROM LITS_CODE OR
|
|
|
t_lits.etage_id IS DISTINCT FROM w_LIT_LITS.etage_id
|
|
|
)
|
|
|
;
|
|
|
UPDATE activite[PX].t_lits SET
|
|
|
code = LITS_CODE,
|
|
|
etage_id = w_LIT_LITS.etage_id
|
|
|
FROM w_LIT_LITS
|
|
|
WHERE LITS_ID = t_lits.code_original AND
|
|
|
(
|
|
|
t_lits.code IS DISTINCT FROM LITS_CODE OR
|
|
|
t_lits.etage_id IS DISTINCT FROM w_LIT_LITS.etage_id
|
|
|
)
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite[PX].t_lits(code_original, code, texte, texte_court, etage_id, chambre_particuliere)
|
|
|
SELECT code_original || '-0' , '', 'Non renseigné', 'Non renseigné', oid, 'O'
|
|
|
FROM activite[PX].t_etages
|
|
|
WHERE oid > 0 AND
|
|
|
code_original || '-0' NOT IN (SELECT code_original FROM activite[PX].t_lits WHERE code_original IS NOT NULL);
|
|
|
|
|
|
UPDATE activite[PX].t_lits SET code = '*****' WHERE oid = 0;
|
|
|
|
|
|
UPDATE activite[PX].t_lits
|
|
|
SET code = t_etages.code || '***'
|
|
|
FROM activite[PX].t_etages
|
|
|
WHERE etage_id = t_etages.oid
|
|
|
AND (t_lits.code = '' OR t_lits.code LIKE '%***') AND
|
|
|
t_lits.code = t_etages.code || '***';
|
|
|
|
|
|
|
|
|
-- Récupération des places disponibles (verrouillé pour l'instant voir 1<>1 plus loin)
|
|
|
DROP TABLE IF EXISTS w_etages_historique;
|
|
|
CREATE TEMP TABLE w_etages_historique AS
|
|
|
SELECT etage_id,
|
|
|
CASE
|
|
|
WHEN (MAX(Array[date::text,nb_lits_theoriques::text]))[2]::numeric > 0 THEN '1'
|
|
|
WHEN (MAX(Array[date::text,nb_box_ambulatoires_theoriques::text]))[2]::numeric > 0 THEN '2'
|
|
|
WHEN (MAX(Array[date::text,nb_box_seances_theoriques::text]))[2]::numeric > 0 THEN '5'
|
|
|
ELSE '1' END AS type_sejour,
|
|
|
(MAX(Array[date::text,est_ouvert_1]))[2]::text AS est_ouvert_1,
|
|
|
(MAX(Array[date::text,est_ouvert_2]))[2]::text AS est_ouvert_2,
|
|
|
(MAX(Array[date::text,est_ouvert_3]))[2]::text AS est_ouvert_3,
|
|
|
(MAX(Array[date::text,est_ouvert_4]))[2]::text AS est_ouvert_4,
|
|
|
(MAX(Array[date::text,est_ouvert_5]))[2]::text AS est_ouvert_5,
|
|
|
(MAX(Array[date::text,est_ouvert_6]))[2]::text AS est_ouvert_6,
|
|
|
(MAX(Array[date::text,est_ouvert_7]))[2]::text AS est_ouvert_7
|
|
|
FROM activite[PX].t_etages_historique
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_STATEELEMENT;
|
|
|
CREATE TEMP TABLE w_STATEELEMENT AS
|
|
|
SELECT
|
|
|
AILE_ID,
|
|
|
GREATEST(date(STED_DATEDEBUT),'20070101') AS STED_DATEDEBUT,
|
|
|
COALESCE(STED_DATEFIN,'20991231') AS STED_DATEFIN,
|
|
|
STED_LITSAUTO,
|
|
|
STED_LITSINSTALL,
|
|
|
t_etages.oid AS etage_id,
|
|
|
CASE WHEN COALESCE(type_sejour,'1') = '1' THEN STED_LITSAUTO ELSE 0 END AS nb_lits_theoriques,
|
|
|
CASE WHEN COALESCE(type_sejour,'1') = '1' THEN STED_LITSINSTALL ELSE 0 END AS nb_lits_ouverts,
|
|
|
CASE WHEN COALESCE(type_sejour,'1') = '2' THEN STED_LITSAUTO ELSE 0 END AS nb_box_ambulatoires_theoriques,
|
|
|
CASE WHEN COALESCE(type_sejour,'1') = '2' THEN STED_LITSINSTALL ELSE 0 END AS nb_box_ambulatoires_ouverts,
|
|
|
CASE WHEN COALESCE(type_sejour,'1') = '5' THEN STED_LITSAUTO ELSE 0 END AS nb_box_seances_theoriques,
|
|
|
CASE WHEN COALESCE(type_sejour,'1') = '5' THEN STED_LITSINSTALL ELSE 0 END AS nb_box_seances_ouverts,
|
|
|
COALESCE(est_ouvert_1,'1') AS est_ouvert_1,
|
|
|
COALESCE(est_ouvert_2,'1') AS est_ouvert_2,
|
|
|
COALESCE(est_ouvert_3,'1') AS est_ouvert_3,
|
|
|
COALESCE(est_ouvert_4,'1') AS est_ouvert_4,
|
|
|
COALESCE(est_ouvert_5,'1') AS est_ouvert_5,
|
|
|
COALESCE(est_ouvert_6,'1') AS est_ouvert_6,
|
|
|
COALESCE(est_ouvert_7,'1') AS est_ouvert_7
|
|
|
FROM prod_csis.SST_STATELEMENT_STEL
|
|
|
JOIN prod_csis.SST_STATELEMENTDETAIL_STED ON STED_ID_STEL = STEL_ID
|
|
|
JOIN prod_csis.SST_AILE_AILE ON STEL_ID_PORTEE = AILE_ID AND STEL_PORTEE = 'aile'
|
|
|
JOIN prod_csis.SST_ETAGE_ETAG ON AILE_ID_ETAG = ETAG_ID
|
|
|
JOIN prod_csis.SST_BATIMENT_BTMN ON ETAG_ID_BTMN = BTMN_ID
|
|
|
JOIN w_SST_ETABLISSEMENT_ETAB ON ETAB_ID = BTMN_ID_ETAB
|
|
|
JOIN activite[PX].t_etages ON t_etages.code_original = AILE_ID
|
|
|
LEFT JOIN w_etages_historique ON w_etages_historique.etage_id = t_etages.oid
|
|
|
JOIN activite.t_divers ON t_divers.code = 'CSIS_ETAGE' AND t_divers.valeur = 'AILE'
|
|
|
WHERE (date(STED_DATEDEBUT) < '19010101' OR date(STED_DATEDEBUT) > '20070101') AND 1<>1
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite[PX].t_etages_historique(
|
|
|
etage_id,
|
|
|
date,
|
|
|
date_fin,
|
|
|
nb_lits_theoriques,
|
|
|
nb_lits_ouverts,
|
|
|
nb_box_ambulatoires_theoriques,
|
|
|
nb_box_ambulatoires_ouverts,
|
|
|
nb_box_seances_theoriques,
|
|
|
nb_box_seances_ouverts,
|
|
|
est_ouvert_1,
|
|
|
est_ouvert_2,
|
|
|
est_ouvert_3,
|
|
|
est_ouvert_4,
|
|
|
est_ouvert_5,
|
|
|
est_ouvert_6,
|
|
|
est_ouvert_7
|
|
|
)
|
|
|
SELECT
|
|
|
w_STATEELEMENT.etage_id,
|
|
|
w_STATEELEMENT.STED_DATEDEBUT,
|
|
|
w_STATEELEMENT.STED_DATEFIN,
|
|
|
w_STATEELEMENT.nb_lits_theoriques,
|
|
|
w_STATEELEMENT.nb_lits_ouverts,
|
|
|
w_STATEELEMENT.nb_box_ambulatoires_theoriques,
|
|
|
w_STATEELEMENT.nb_box_ambulatoires_ouverts,
|
|
|
w_STATEELEMENT.nb_box_seances_theoriques,
|
|
|
w_STATEELEMENT.nb_box_seances_ouverts,
|
|
|
w_STATEELEMENT.est_ouvert_1,
|
|
|
w_STATEELEMENT.est_ouvert_2,
|
|
|
w_STATEELEMENT.est_ouvert_3,
|
|
|
w_STATEELEMENT.est_ouvert_4,
|
|
|
w_STATEELEMENT.est_ouvert_5,
|
|
|
w_STATEELEMENT.est_ouvert_6,
|
|
|
w_STATEELEMENT.est_ouvert_7
|
|
|
FROM w_STATEELEMENT
|
|
|
LEFT JOIN activite[PX].t_etages_historique ON
|
|
|
w_STATEELEMENT.etage_id = t_etages_historique.etage_id AND
|
|
|
STED_DATEDEBUT = t_etages_historique.date
|
|
|
WHERE t_etages_historique.etage_id IS NULL
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].t_etages_historique SET
|
|
|
nb_lits_theoriques = w_STATEELEMENT.nb_lits_theoriques,
|
|
|
nb_lits_ouverts = w_STATEELEMENT.nb_lits_ouverts,
|
|
|
nb_box_ambulatoires_theoriques = w_STATEELEMENT.nb_box_ambulatoires_theoriques,
|
|
|
nb_box_ambulatoires_ouverts = w_STATEELEMENT.nb_box_ambulatoires_ouverts,
|
|
|
nb_box_seances_theoriques = w_STATEELEMENT.nb_box_seances_theoriques,
|
|
|
nb_box_seances_ouverts = w_STATEELEMENT.nb_box_seances_ouverts
|
|
|
FROM w_STATEELEMENT
|
|
|
WHERE w_STATEELEMENT.etage_id = t_etages_historique.etage_id AND
|
|
|
STED_DATEDEBUT = t_etages_historique.date AND
|
|
|
(
|
|
|
t_etages_historique.nb_lits_theoriques IS DISTINCT FROM w_STATEELEMENT.nb_lits_theoriques OR
|
|
|
t_etages_historique.nb_lits_ouverts IS DISTINCT FROM w_STATEELEMENT.nb_lits_ouverts OR
|
|
|
t_etages_historique.nb_box_ambulatoires_theoriques IS DISTINCT FROM w_STATEELEMENT.nb_box_ambulatoires_theoriques OR
|
|
|
t_etages_historique.nb_box_ambulatoires_ouverts IS DISTINCT FROM w_STATEELEMENT.nb_box_ambulatoires_ouverts OR
|
|
|
t_etages_historique.nb_box_seances_theoriques IS DISTINCT FROM w_STATEELEMENT.nb_box_seances_theoriques OR
|
|
|
t_etages_historique.nb_box_seances_ouverts IS DISTINCT FROM w_STATEELEMENT.nb_box_seances_ouverts
|
|
|
)
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Facturation">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- 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);
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SST_PRESTATIONETAB_PRTB ;
|
|
|
CREATE TEMP TABLE w_SST_PRESTATIONETAB_PRTB AS
|
|
|
SELECT SST_PRESTATIONETAB_PRTB.*, ETAB_PREFIX, PRTB_ID AS REGP_ID_PRTB, 0::bigint AS rubrique_facturation_id
|
|
|
FROM prod_csis.SST_PRESTATIONETAB_PRTB
|
|
|
JOIN w_SST_ETABLISSEMENT_ETAB ON ETAB_ID = PRTB_ID_ETAB
|
|
|
ORDER BY PRTB_CODE;
|
|
|
|
|
|
|
|
|
UPDATE w_SST_PRESTATIONETAB_PRTB
|
|
|
SET PRTB_CODE = PRTB_CODE || COALESCE('_' || ETAB_PREFIX,'')
|
|
|
WHERE PRTB_CODE IN
|
|
|
(
|
|
|
SELECT PRTB_CODE
|
|
|
FROM w_SST_PRESTATIONETAB_PRTB
|
|
|
GROUP BY 1
|
|
|
HAVING count(DISTINCT PRTB_LIBELLE) > 1
|
|
|
)
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_rubriques_facturation_cum;
|
|
|
CREATE TEMP TABLE w_rubriques_facturation_cum AS
|
|
|
SELECT PRTB_CODE, PRTB_LIBELLE, MIN(PRTB_LIBELLECOURT) AS PRTB_LIBELLECOURT, MIN(PRTB_ID) AS KEEP_PRTB_ID, 0::bigint AS rubrique_facturation_id
|
|
|
FROM w_SST_PRESTATIONETAB_PRTB
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,2
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].t_rubriques_facturation
|
|
|
SET code = w_rubriques_facturation_cum.PRTB_CODE || '-' || t_rubriques_facturation.oid
|
|
|
FROM w_rubriques_facturation_cum
|
|
|
WHERE w_rubriques_facturation_cum.KEEP_PRTB_ID = t_rubriques_facturation.code_original AND
|
|
|
(
|
|
|
t_rubriques_facturation.code IS DISTINCT FROM w_rubriques_facturation_cum.PRTB_CODE
|
|
|
)
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].t_rubriques_facturation
|
|
|
SET code = w_rubriques_facturation_cum.PRTB_CODE,
|
|
|
texte = w_rubriques_facturation_cum.PRTB_LIBELLE,
|
|
|
texte_court = w_rubriques_facturation_cum.PRTB_LIBELLECOURT
|
|
|
FROM w_rubriques_facturation_cum
|
|
|
WHERE w_rubriques_facturation_cum.KEEP_PRTB_ID = t_rubriques_facturation.code_original AND
|
|
|
(
|
|
|
t_rubriques_facturation.code IS DISTINCT FROM w_rubriques_facturation_cum.PRTB_CODE OR
|
|
|
texte IS DISTINCT FROM w_rubriques_facturation_cum.PRTB_LIBELLE OR
|
|
|
texte_court IS DISTINCT FROM w_rubriques_facturation_cum.PRTB_LIBELLECOURT
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_rubriques_facturation(code_original, code, texte, texte_court)
|
|
|
SELECT KEEP_PRTB_ID::bigint, PRTB_CODE, PRTB_LIBELLE, PRTB_LIBELLECOURT
|
|
|
FROM w_rubriques_facturation_cum
|
|
|
WHERE KEEP_PRTB_ID::bigint NOT IN (SELECT code_original FROM activite[PX].t_rubriques_facturation WHERE code_original IS NOT NULL)
|
|
|
ORDER BY PRTB_CODE
|
|
|
;
|
|
|
|
|
|
UPDATE w_rubriques_facturation_cum
|
|
|
SET rubrique_facturation_id = t_rubriques_facturation.oid
|
|
|
FROM activite[PX].t_rubriques_facturation WHERE KEEP_PRTB_ID = code_original
|
|
|
;
|
|
|
|
|
|
UPDATE w_SST_PRESTATIONETAB_PRTB
|
|
|
SET rubrique_facturation_id = w_rubriques_facturation_cum.rubrique_facturation_id
|
|
|
FROM w_rubriques_facturation_cum
|
|
|
WHERE w_SST_PRESTATIONETAB_PRTB.PRTB_CODE = w_rubriques_facturation_cum.PRTB_CODE AND
|
|
|
w_SST_PRESTATIONETAB_PRTB.PRTB_LIBELLE = w_rubriques_facturation_cum.PRTB_LIBELLE
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite.t_prestations(oid, code_original, code, texte, texte_court)
|
|
|
SELECT 0, 0, '', 'Non renseignée', 'Non renseignée' WHERE 0 NOT IN (SELECT oid FROM activite.t_prestations);
|
|
|
|
|
|
|
|
|
INSERT INTO activite.t_prestations(code_original, code, texte, texte_court)
|
|
|
SELECT PRES_CODE, PRES_CODE, MAX(PRES_LIBELLE), MAX(PRES_LIBELLECOURT)
|
|
|
FROM prod_csis.SST_PRESTATION_PRES
|
|
|
WHERE PRES_CODE <> '' AND PRES_CODE IS NOT NULl AND
|
|
|
PRES_CODE NOT IN (SELECT code FROM activite.t_prestations WHERE code IS NOT NULL)
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY PRES_CODE;
|
|
|
|
|
|
|
|
|
]]></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,
|
|
|
type_valorisation_non_facture,
|
|
|
'M'::text || CASE WHEN t_prestations.code <> 'PJ' THEN t_prestations.code ELSE 'PJS' END AS prestation_mcode
|
|
|
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
|
|
|
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 label="Compléments patients">
|
|
|
<sqlcmd><![CDATA[
|
|
|
DROP TABLE IF EXISTS w_CORRESPONDANTS;
|
|
|
CREATE TEMP TABLE w_CORRESPONDANTS AS
|
|
|
SELECT
|
|
|
MEDN_ID,
|
|
|
CASE WHEN MEDN_CODE <> '' THEN MEDN_CODE ELSE MEDN_NOM || ' ' || MEDN_PRENOM END AS MEDN_CODE,
|
|
|
MEDN_NOM,
|
|
|
MEDN_PRENOM,
|
|
|
''::text AS MEDN_RPPS,
|
|
|
0::bigint AS medecin_cti_id
|
|
|
FROM prod_csis.SID_MEDECINTRAITANT_MTRA
|
|
|
JOIN prod_csis.SST_MEDECIN_MEDN ON MTRA_ID_MEDN = MEDN_ID
|
|
|
GROUP BY 1,2,3,4
|
|
|
;
|
|
|
|
|
|
INSERT INTO w_CORRESPONDANTS
|
|
|
SELECT
|
|
|
MEDN_ID,
|
|
|
CASE WHEN MEDN_CODE <> '' THEN MEDN_CODE ELSE MEDN_NOM || ' ' || MEDN_PRENOM END AS MEDN_CODE,
|
|
|
MEDN_NOM,
|
|
|
MEDN_PRENOM,
|
|
|
''::text AS MEDN_RPPS,
|
|
|
0::bigint AS medecin_cti_id
|
|
|
FROM prod_csis.SST_MEDECIN_MEDN
|
|
|
WHERE MEDN_ID = ANY (ARRAY(SELECT DISTINCT DADM_ID1_MEDN FROM prod_csis.SID_DOSSIERADMINISTRATIF_DADM)::bigint[])
|
|
|
AND MEDN_ID != ALL(ARRAY(SELECT MEDN_ID FROM w_CORRESPONDANTS)::bigint[])
|
|
|
GROUP BY 1,2,3,4
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_medecins_traitants_administratifs(code_original, code, nom, prenom, specialite_id, no_rpps)
|
|
|
SELECT
|
|
|
MEDN_ID,
|
|
|
MEDN_CODE,
|
|
|
MAX(MEDN_NOM),
|
|
|
MAX(MEDN_PRENOM),
|
|
|
0,
|
|
|
''
|
|
|
FROM w_CORRESPONDANTS
|
|
|
LEFT JOIN activite[PX].t_medecins_traitants_administratifs ON
|
|
|
MEDN_ID = t_medecins_traitants_administratifs.code_original
|
|
|
WHERE t_medecins_traitants_administratifs.oid IS NULL
|
|
|
GROUP BY 1,2
|
|
|
;
|
|
|
|
|
|
DELETE
|
|
|
FROM activite[PX].t_medecins_traitants_administratifs
|
|
|
WHERE code_original NOT IN (SELECT MEDN_ID FROM w_CORRESPONDANTS)
|
|
|
;
|
|
|
|
|
|
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 = MEDN_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 no_patient_csis,
|
|
|
''::text AS nom_csis,
|
|
|
0::numeric AS MEDN_ID
|
|
|
FROM activite[PX].p_sejours
|
|
|
JOIN activite[PX].p_patients ON p_sejours.no_patient = p_patients.no_patient
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_sejours
|
|
|
SET no_patient_csis = PATI_IPP, nom_csis = PATI_NOMUSAGE, MEDN_ID = COALESCE(MTRA_ID_MEDN,DADM_ID1_MEDN,0)
|
|
|
FROM prod_csis.SID_DOSSIERADMINISTRATIF_DADM
|
|
|
JOIN prod_csis.SID_PATIENT_PATI ON DADM_ID_PATI = PATI_ID
|
|
|
LEFT JOIN prod_csis.SID_MEDECINTRAITANT_MTRA ON PATI_ID = MTRA_ID_PATI AND
|
|
|
date(DADM_DATEDEBUT) BETWEEN date(MTRA_DATEDEBUT) AND COALESCE(date(MTRA_DATEFIN),'20991231')
|
|
|
WHERE DADM_NDA = no_sejour AND
|
|
|
date(DADM_DATEDEBUT) = date_entree AND
|
|
|
COALESCE(MTRA_ID_MEDN,DADM_ID1_MEDN,0) <> 0
|
|
|
;
|
|
|
|
|
|
UPDATE w_sejours
|
|
|
SET no_patient_csis = PATI_IPP, nom_csis = PATI_NOMUSAGE, MEDN_ID = COALESCE(MTRA_ID_MEDN,DADM_ID1_MEDN,0)
|
|
|
FROM prod_csis.SID_DOSSIERADMINISTRATIF_DADM
|
|
|
JOIN prod_csis.SID_PATIENT_PATI ON DADM_ID_PATI = PATI_ID
|
|
|
JOIN prod_csis.SID_MEDECINTRAITANT_MTRA ON PATI_ID = MTRA_ID_PATI
|
|
|
WHERE DADM_NDA = no_sejour AND
|
|
|
date(DADM_DATEDEBUT) = date_entree AND
|
|
|
COALESCE(MTRA_ID_MEDN,DADM_ID1_MEDN,0) <> 0 AND
|
|
|
w_sejours.MEDN_ID = 0
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].p_sejours
|
|
|
SET medecin_traitant_id = medecin_cti_id
|
|
|
FROM w_sejours
|
|
|
JOIN w_CORRESPONDANTS ON w_sejours.MEDN_ID = w_CORRESPONDANTS.MEDN_ID
|
|
|
WHERE p_sejours.no_sejour = w_sejours.no_sejour AND
|
|
|
w_sejours.MEDN_ID <> 0 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,
|
|
|
pati_adresse1 || CASE WHEN pati_adresse2 != '' THEN ' - ' || pati_adresse2 ELSE '' END,
|
|
|
COALESCE(t_codes_postaux.oid,0),
|
|
|
PATI_VILLE,
|
|
|
pati_telephone1,
|
|
|
pati_telephone2,
|
|
|
pati_email
|
|
|
FROM activite[PX].p_sejours
|
|
|
LEFT JOIN prod_csis.SID_DOSSIERADMINISTRATIF_DADM ON SID_DOSSIERADMINISTRATIF_DADM.DADM_ID = code_original
|
|
|
JOIN prod_csis.sid_patient_pati ON pati_id = dadm_id_pati
|
|
|
LEFT JOIN base.t_codes_postaux ON PATI_CODEPOSTAL = t_codes_postaux.code
|
|
|
;
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Compléments facture">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Suppression factures provisoires pour les non facturables (cas des recuses)
|
|
|
|
|
|
-- Lignes
|
|
|
DELETE
|
|
|
FROM activite[PX].p_factures_lignes_c
|
|
|
WHERE no_facture IN
|
|
|
(
|
|
|
SELECT no_facture
|
|
|
FROM activite[PX].p_factures
|
|
|
JOIN activite[PX].p_sejours ON p_factures.no_sejour = p_sejours.no_sejour
|
|
|
WHERE p_sejours.est_sans_facturation ='1' AND
|
|
|
p_factures.code_facture = '0'
|
|
|
)
|
|
|
;
|
|
|
DELETE
|
|
|
FROM activite[PX].p_factures_lignes_h
|
|
|
WHERE no_facture IN
|
|
|
(
|
|
|
SELECT no_facture
|
|
|
FROM activite[PX].p_factures
|
|
|
JOIN activite[PX].p_sejours ON p_factures.no_sejour = p_sejours.no_sejour
|
|
|
WHERE p_sejours.est_sans_facturation ='1' AND
|
|
|
p_factures.code_facture = '0'
|
|
|
)
|
|
|
;
|
|
|
|
|
|
-- Entetes calculée fictivement (pour associer des règlements éventuels
|
|
|
UPDATE activite[PX].p_factures SET
|
|
|
code_facture = '1',
|
|
|
date_facture = p_factures.date_fin,
|
|
|
date_vente = p_factures.date_fin,
|
|
|
mois_vente = to_char(p_factures.date_fin,'YYYYMM')::numeric,
|
|
|
montant_facture_c = 0,
|
|
|
montant_facture_0_c = 0,
|
|
|
montant_facture_1_c = 0,
|
|
|
montant_facture_2_c = 0,
|
|
|
montant_facture_22_c = 0,
|
|
|
montant_comptabilise_c = 0,
|
|
|
montant_comptabilise_0_c = 0,
|
|
|
montant_comptabilise_1_c = 0,
|
|
|
montant_comptabilise_2_c = 0,
|
|
|
montant_comptabilise_22_c = 0,
|
|
|
montant_facture_h = 0,
|
|
|
montant_facture_0_h = 0,
|
|
|
montant_facture_1_h = 0,
|
|
|
montant_facture_2_h = 0,
|
|
|
montant_facture_22_h = 0,
|
|
|
montant_comptabilise_h = 0,
|
|
|
montant_comptabilise_0_h = 0,
|
|
|
montant_comptabilise_1_h = 0,
|
|
|
montant_comptabilise_2_h = 0,
|
|
|
montant_comptabilise_22_h = 0
|
|
|
FROM activite[PX].p_sejours
|
|
|
WHERE p_factures.no_sejour = p_sejours.no_sejour AND
|
|
|
p_sejours.est_sans_facturation ='1' AND
|
|
|
p_factures.code_facture = '0'
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures SET date_expedition_0 = date_facture WHERE date_expedition_0 < date_facture AND date_facture <> '2099-12-31';
|
|
|
|
|
|
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;
|
|
|
|
|
|
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 NULL OR p_factures.date_solde <> w_factures_soldes.date_solde OR
|
|
|
p_factures.date_solde_c IS NULL OR p_factures.date_solde_c <> w_factures_soldes.date_solde_c OR
|
|
|
p_factures.date_solde_h IS NULL OR p_factures.date_solde_h <> 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 NULL OR p_factures.date_solde_reference <> w_factures_references_soldes.date_solde_reference OR
|
|
|
p_factures.date_solde_reference_c IS NULL OR p_factures.date_solde_reference_c <> w_factures_references_soldes.date_solde_reference_c OR
|
|
|
p_factures.date_solde_reference_h IS NULL OR p_factures.date_solde_reference_h <> w_factures_references_soldes.date_solde_reference_h OR
|
|
|
p_factures.date_solde_reference_0_c IS NULL OR p_factures.date_solde_reference_0_c <> w_factures_references_soldes.date_solde_reference_0_c OR
|
|
|
p_factures.date_solde_reference_0_h IS NULL OR p_factures.date_solde_reference_0_h <> w_factures_references_soldes.date_solde_reference_0_h OR
|
|
|
p_factures.date_solde_reference_1_c IS NULL OR p_factures.date_solde_reference_1_c <> w_factures_references_soldes.date_solde_reference_1_c OR
|
|
|
p_factures.date_solde_reference_1_h IS NULL OR p_factures.date_solde_reference_1_h <> w_factures_references_soldes.date_solde_reference_1_h OR
|
|
|
p_factures.date_solde_reference_2_c IS NULL OR p_factures.date_solde_reference_2_c <> w_factures_references_soldes.date_solde_reference_2_c OR
|
|
|
p_factures.date_solde_reference_2_h IS NULL OR p_factures.date_solde_reference_2_h <> w_factures_references_soldes.date_solde_reference_2_h OR
|
|
|
p_factures.date_solde_reference_22_c IS NULL OR p_factures.date_solde_reference_22_c <> w_factures_references_soldes.date_solde_reference_22_c OR
|
|
|
p_factures.date_solde_reference_22_h IS NULL OR p_factures.date_solde_reference_22_h <> w_factures_references_soldes.date_solde_reference_22_h
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
]]></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>
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
</ROOT>
|