|
|
<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
|
<ROOT>
|
|
|
|
|
|
|
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
|
|
|
|
<NODE label="Identification des séjours">
|
|
|
<sqlcmd><![CDATA[
|
|
|
DROP TABLE IF EXISTS w_periode;
|
|
|
CREATE TEMP TABLE w_periode AS
|
|
|
SELECT date_trunc('month',date(MIN(CREATION))) AS date_debut_periode, '00010101'::timestamp without time zone AS date_extraction
|
|
|
FROM
|
|
|
prod_dai.FACTURES_615
|
|
|
;
|
|
|
|
|
|
UPDATE w_periode
|
|
|
SET date_extraction = MODIFICATION
|
|
|
FROM (
|
|
|
SELECT max(MODIFICATION) AS MODIFICATION FROM prod_dai.FACTURES_615
|
|
|
) subview
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SEJOUR_compta;
|
|
|
CREATE TEMP TABLE w_SEJOUR_compta AS
|
|
|
SELECT
|
|
|
NO_PATIENT
|
|
|
FROM prod_dai.FACTURES_615
|
|
|
WHERE
|
|
|
MODIFICATION >= '[ENV_ADM_ANNEEDEBUT]0101'
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_IDE_SEJOUR;
|
|
|
CREATE TEMP TABLE w_IDE_SEJOUR AS
|
|
|
SELECT
|
|
|
date_extraction,
|
|
|
NO_4D AS w_NO_4D,
|
|
|
CASE WHEN NO_ENTRANT > 0 THEN to_char(NO_ENTRANT,'FM9990000000')||REF_SEJOUR ELSE 'ID'||NO_4D::text END AS w_NO_ENTRANT
|
|
|
FROM w_periode , prod_dai.PATIENTS
|
|
|
LEFT JOIN (SELECT NO_PATIENT, CREATION FROM prod_dai.FACTURES_615 GROUP BY 1,2) subview
|
|
|
ON (NO_4D = NO_PATIENT)
|
|
|
WHERE
|
|
|
(date(DATE_ENTREE) BETWEEN date_debut_periode AND date(now()) + interval '2 day' OR date(DATE_SORTIE) >= date_debut_periode OR DATE_SORTIE = '0001-01-01') OR subview.CREATION >= '[ENV_ADM_ANNEEDEBUT]0101'
|
|
|
AND (date(DATE_SORTIE) <> '0001-01-01' AND date(DATE_SORTIE) <= '20201231' OR DATE_SORTIE= '0001-01-01' OR subview.NO_PATIENT IS NOT NULL) OR subview.CREATION >= '[ENV_ADM_ANNEEDEBUT]0101'
|
|
|
GROUP BY 1,2,3;
|
|
|
|
|
|
ALTER TABLE w_IDE_SEJOUR ADD CONSTRAINT w_IDE_SEJOUR_pk PRIMARY KEY(w_NO_4D);
|
|
|
|
|
|
INSERT INTO w_IDE_SEJOUR
|
|
|
SELECT
|
|
|
date_extraction,
|
|
|
NO_4D AS w_NO_4D,
|
|
|
CASE WHEN NO_ENTRANT > 0 THEN to_char(NO_ENTRANT,'FM9990000000')||REF_SEJOUR ELSE 'ID'||NO_4D::text END AS w_NO_ENTRANT
|
|
|
FROM w_periode , prod_dai.PATIENTS
|
|
|
WHERE
|
|
|
NO_4D IN (SELECT NO_PATIENT FROM w_SEJOUR_compta)
|
|
|
AND NO_4D NOT IN (SELECT w_NO_4D FROM w_IDE_SEJOUR)
|
|
|
GROUP BY 1,2,3;
|
|
|
|
|
|
|
|
|
DELETE FROM w_IDE_SEJOUR
|
|
|
USING activite.t_sejour
|
|
|
WHERE w_NO_ENTRANT = t_sejour.no_sejour AND
|
|
|
est_ignore = '1' AND
|
|
|
'[PX]' = '';
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_IDE_SEJOUR_complet;
|
|
|
CREATE TEMP TABLE w_IDE_SEJOUR_complet AS
|
|
|
SELECT
|
|
|
w_NO_4D,
|
|
|
w_NO_ENTRANT,
|
|
|
''::text AS NO_4D_patient,
|
|
|
0::bigint AS w_MEDECIN,
|
|
|
date_extraction,
|
|
|
PATIENTS.*,
|
|
|
0::numeric AS HEURE_ENTREE_cti,
|
|
|
'00:00:00'::time AS HEURE_ENTREE_time,
|
|
|
0::numeric AS HEURE_ENTREE_heure,
|
|
|
0::numeric AS HEURE_ENTREE_minute,
|
|
|
0::numeric AS HEURE_ENTREE_seconde,
|
|
|
0::numeric AS HEURE_SORTIE_cti,
|
|
|
'00:00:00'::time AS HEURE_SORTIE_time,
|
|
|
0::numeric AS HEURE_SORTIE_heure,
|
|
|
0::numeric AS HEURE_SORTIE_minute,
|
|
|
0::numeric AS HEURE_SORTIE_seconde
|
|
|
FROM w_IDE_SEJOUR
|
|
|
JOIN prod_dai.PATIENTS ON NO_4D = w_NO_4D;
|
|
|
|
|
|
|
|
|
-- NO_ENTRANT en double
|
|
|
UPDATE w_IDE_SEJOUR_complet
|
|
|
SET w_NO_ENTRANT = w_IDE_SEJOUR_complet.w_NO_ENTRANT || '-' || w_IDE_SEJOUR_complet.NO_4D::text
|
|
|
FROM
|
|
|
(
|
|
|
SELECT w_NO_ENTRANT
|
|
|
FROM w_IDE_SEJOUR_complet
|
|
|
GROUP BY 1
|
|
|
HAVING count(*) > 1
|
|
|
) subview
|
|
|
WHERE w_IDE_SEJOUR_complet.w_NO_ENTRANT = subview.w_NO_ENTRANT
|
|
|
;
|
|
|
|
|
|
-- Si date entrée = 0001-01-01, récupérer celle de la facture
|
|
|
UPDATE w_IDE_SEJOUR_complet SET
|
|
|
DATE_ENTREE = DEBUT,
|
|
|
DATE_SORTIE = FIN
|
|
|
FROM
|
|
|
(
|
|
|
SELECT NO_PATIENT, MIN(DEBUT) AS DEBUT, MAX(FIN) AS FIN
|
|
|
FROM prod_dai.FACTURES_615
|
|
|
JOIN w_IDE_SEJOUR_complet ON NO_4D = NO_PATIENT
|
|
|
WHERE DATE_ENTREE = '00010101'
|
|
|
GROUP BY 1
|
|
|
) subview
|
|
|
WHERE w_IDE_SEJOUR_complet.NO_4D = subview.NO_PATIENT
|
|
|
;
|
|
|
|
|
|
-- Type de rééducation Externe
|
|
|
UPDATE w_IDE_SEJOUR_complet
|
|
|
SET TYPE_REEDUCATIO = 'EXT',
|
|
|
DATE_SORTIE = CASE WHEN DATE_SORTIE > '00010101' THEN DATE_SORTIE ELSE DATE_ENTREE END
|
|
|
FROM prod_dai.FACTURES_615
|
|
|
WHERE NO_4D = NO_PATIENT AND
|
|
|
TYPE_REEDUCATIO IS NULL AND
|
|
|
LIBELLE LIKE 'CS%'
|
|
|
;
|
|
|
|
|
|
-- Dates E/S externes
|
|
|
UPDATE w_IDE_SEJOUR_complet SET
|
|
|
DATE_ENTREE = DEBUT,
|
|
|
DATE_SORTIE = FIN
|
|
|
FROM
|
|
|
(
|
|
|
SELECT NO_PATIENT, MIN(DEBUT) AS DEBUT, MIN(FIN) AS FIN
|
|
|
FROM prod_dai.FACTURES_615
|
|
|
JOIN w_IDE_SEJOUR_complet ON NO_4D = NO_PATIENT
|
|
|
WHERE TYPE_REEDUCATIO = 'EXT'
|
|
|
GROUP BY 1
|
|
|
) subview
|
|
|
WHERE w_IDE_SEJOUR_complet.NO_4D = subview.NO_PATIENT AND
|
|
|
(
|
|
|
DATE_ENTREE <> DEBUT OR
|
|
|
DATE_SORTIE <> FIN
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Ne pas prendre les date entrées 0001-01-01- qui restent
|
|
|
DELETE FROM w_IDE_SEJOUR_complet
|
|
|
WHERE DATE_ENTREE = '00010101'
|
|
|
;
|
|
|
|
|
|
UPDATE w_IDE_SEJOUR_complet
|
|
|
SET HEURE_ENTREE_CTI =
|
|
|
CASE WHEN HEURE_ENTREE LIKE '%:%'
|
|
|
THEN split_part(HEURE_ENTREE, ':', 1)::int * 10000 + split_part(HEURE_ENTREE, ':', 2)::int * 100
|
|
|
ELSE base.cti_to_number(HEURE_ENTREE)/1000
|
|
|
END
|
|
|
WHERE HEURE_ENTREE <> '' AND HEURE_ENTREE <> '0'
|
|
|
|
|
|
;
|
|
|
|
|
|
-- Mise à jour HEURE_ENTREE_...
|
|
|
UPDATE w_IDE_SEJOUR_complet SET
|
|
|
HEURE_ENTREE_heure =
|
|
|
CASE WHEN HEURE_ENTREE LIKE '%:%'
|
|
|
THEN split_part(HEURE_ENTREE, ':', 1)::int
|
|
|
ELSE floor(HEURE_ENTREE_CTI/3600)
|
|
|
END,
|
|
|
HEURE_ENTREE_minute =
|
|
|
CASE WHEN HEURE_ENTREE LIKE '%:%'
|
|
|
THEN split_part(HEURE_ENTREE, ':', 2)::int
|
|
|
ELSE floor((HEURE_ENTREE_CTI - (HEURE_ENTREE_heure*3600))/60)
|
|
|
END,
|
|
|
HEURE_ENTREE_time =
|
|
|
CASE WHEN HEURE_ENTREE LIKE '%:%'
|
|
|
THEN HEURE_ENTREE::time
|
|
|
ELSE (HEURE_ENTREE_heure||':'||HEURE_ENTREE_minute||':00')::time
|
|
|
END
|
|
|
WHERE HEURE_ENTREE <> '' AND HEURE_ENTREE <> '0'
|
|
|
|
|
|
;
|
|
|
|
|
|
UPDATE w_IDE_SEJOUR_complet
|
|
|
SET HEURE_SORTIE_CTI =
|
|
|
CASE WHEN HEURE_SORTIE LIKE '%:%'
|
|
|
THEN split_part(HEURE_SORTIE, ':', 1)::int * 10000 + split_part(HEURE_SORTIE, ':', 2)::int * 100
|
|
|
ELSE base.cti_to_number(HEURE_SORTIE)/1000
|
|
|
END
|
|
|
WHERE HEURE_SORTIE <> '' AND HEURE_SORTIE <> '0'
|
|
|
;
|
|
|
|
|
|
-- Mise à jour HEURE_SORTIE_...
|
|
|
UPDATE w_IDE_SEJOUR_complet SET
|
|
|
HEURE_SORTIE_heure =
|
|
|
CASE WHEN HEURE_SORTIE LIKE '%:%'
|
|
|
THEN split_part(HEURE_SORTIE, ':', 1)::int
|
|
|
ELSE floor(HEURE_SORTIE_CTI/3600)
|
|
|
END,
|
|
|
HEURE_SORTIE_minute =
|
|
|
CASE WHEN HEURE_SORTIE LIKE '%:%'
|
|
|
THEN split_part(HEURE_SORTIE, ':', 2)::int
|
|
|
ELSE floor((HEURE_SORTIE_CTI - (HEURE_SORTIE_heure*3600))/60)
|
|
|
END,
|
|
|
HEURE_SORTIE_time =
|
|
|
CASE WHEN HEURE_SORTIE LIKE '%:%'
|
|
|
THEN HEURE_SORTIE::time
|
|
|
ELSE (HEURE_SORTIE_heure||':'||HEURE_SORTIE_minute||':00')::time
|
|
|
END
|
|
|
WHERE HEURE_SORTIE <> '' AND HEURE_SORTIE <> '0'
|
|
|
|
|
|
;
|
|
|
|
|
|
-- Pourquoi les 4 lignes suivantes ???
|
|
|
--UPDATE w_IDE_SEJOUR_complet
|
|
|
--SET
|
|
|
-- HEURE_ENTREE = RIGHT(HEURE_ENTREE,-2),
|
|
|
-- HEURE_SORTIE = RIGHT(HEURE_SORTIE,-2);
|
|
|
|
|
|
ALTER TABLE w_IDE_SEJOUR_complet ADD CONSTRAINT w_IDE_SEJOUR_complet_pk PRIMARY KEY(NO_4D);
|
|
|
|
|
|
-- doublons ? (todo)
|
|
|
|
|
|
CREATE INDEX w_IDE_SEJOUR_complet_i1
|
|
|
ON w_IDE_SEJOUR_complet
|
|
|
USING btree
|
|
|
(NO_4D);
|
|
|
|
|
|
|
|
|
-- Numéros de factures en double ?
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Complément prod_dai - HGO">
|
|
|
<condition><![CDATA[
|
|
|
|
|
|
SELECT current_database() = 'icti_327'
|
|
|
;
|
|
|
|
|
|
]]></condition>
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Service Consultations
|
|
|
UPDATE w_IDE_SEJOUR_complet
|
|
|
SET SERVICE = 'Consultations'
|
|
|
FROM prod_dai.FACTURES_615
|
|
|
WHERE NO_4D = NO_PATIENT AND
|
|
|
SERVICE IS NULL AND
|
|
|
LIBELLE LIKE 'CS%'
|
|
|
;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Détection modifications">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="SEJOUR" label="RECUPERATION DES SEJOURS">
|
|
|
|
|
|
<NODE label="Patients">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
TRUNCATE activite[PX].p_patients
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite[PX].p_patients(nom, nom_naissance, prenom, date_naissance, code_sexe, no_patient)
|
|
|
SELECT NOM_PATIENT, COALESCE(NOM_JF,''), PRENOM_PATIENT, date(PATIENTS.DATE_NAISSANCE), CASE WHEN SEXE = 'F' THEN '2' ELSE '1' END, MIN(NO_4D)::text
|
|
|
FROM prod_dai.PATIENTS
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
;
|
|
|
|
|
|
ANALYSE activite[PX].p_patients
|
|
|
;
|
|
|
|
|
|
UPDATE w_IDE_SEJOUR_complet
|
|
|
SET NO_4D_patient = p_patients.no_patient
|
|
|
FROM activite[PX].p_patients
|
|
|
WHERE
|
|
|
w_IDE_SEJOUR_complet.NOM_PATIENT = p_patients.nom AND
|
|
|
COALESCE(w_IDE_SEJOUR_complet.NOM_JF,'') = p_patients.nom_naissance AND
|
|
|
w_IDE_SEJOUR_complet.PRENOM_PATIENT = p_patients.prenom AND
|
|
|
date(w_IDE_SEJOUR_complet.DATE_NAISSANCE) = p_patients.date_naissance AND
|
|
|
CASE WHEN w_IDE_SEJOUR_complet.SEXE = 'F' THEN '2' ELSE '1' END = p_patients.code_sexe
|
|
|
;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Séjours">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Pour les externes, éclater les journées selon facturation
|
|
|
DROP TABLE IF EXISTS w_FACTURES_615;
|
|
|
CREATE TEMP TABLE w_FACTURES_615 AS
|
|
|
SELECT *
|
|
|
FROM prod_dai.FACTURES_615
|
|
|
;
|
|
|
|
|
|
ANALYSE w_FACTURES_615
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SEJOUR_EXT;
|
|
|
CREATE TEMP TABLE w_SEJOUR_EXT AS
|
|
|
SELECT DEBUT AS EXT_DATE_ENTREE,
|
|
|
FIN AS EXT_DATE_SORTIE,
|
|
|
MEDECIN AS EXT_MEDECIN,
|
|
|
w_NO_ENTRANT || '-' || to_char(DEBUT,'YYMMDD') AS EXT_NO_ENTRANT,
|
|
|
to_char(DEBUT,'YYMMDD')::numeric * 10000000 + NO_4D AS EXT_NO_4D,
|
|
|
w_IDE_SEJOUR_complet.*
|
|
|
FROM w_IDE_SEJOUR_complet
|
|
|
JOIN (
|
|
|
SELECT NO_PATIENT, DEBUT, MAX(FIN) AS FIN, MAX(MEDECIN) AS MEDECIN
|
|
|
FROM w_FACTURES_615 FACTURES_615
|
|
|
WHERE DEBUT > '00010101'
|
|
|
GROUP BY 1,2
|
|
|
) FACTURES_615 ON NO_PATIENT = NO_4D
|
|
|
WHERE
|
|
|
w_no_entrant LIKE 'ID%' AND
|
|
|
TYPE_REEDUCATIO ='EXT'
|
|
|
;
|
|
|
|
|
|
UPDATE w_FACTURES_615 FACTURES_615
|
|
|
SET NO_PATIENT = EXT_NO_4D
|
|
|
FROM w_SEJOUR_EXT
|
|
|
WHERE NO_PATIENT = NO_4D AND
|
|
|
DEBUT = EXT_DATE_ENTREE
|
|
|
;
|
|
|
|
|
|
UPDATE w_IDE_SEJOUR_complet SET
|
|
|
NO_4D = EXT_NO_4D,
|
|
|
w_NO_4D = EXT_NO_4D,
|
|
|
w_NO_ENTRANT = EXT_NO_ENTRANT,
|
|
|
DATE_ENTREE = EXT_DATE_ENTREE,
|
|
|
DATE_SORTIE = EXT_DATE_SORTIE,
|
|
|
w_MEDECIN = w_SEJOUR_EXT.EXT_MEDECIN
|
|
|
FROM w_SEJOUR_EXT
|
|
|
WHERE w_IDE_SEJOUR_complet.NO_4D = w_SEJOUR_EXT.NO_4D AND
|
|
|
w_IDE_SEJOUR_complet.DATE_ENTREE = w_SEJOUR_EXT.EXT_DATE_ENTREE
|
|
|
;
|
|
|
|
|
|
UPDATE w_SEJOUR_EXT SET
|
|
|
w_NO_4D = EXT_NO_4D,
|
|
|
NO_4D = EXT_NO_4D,
|
|
|
w_NO_ENTRANT = EXT_NO_ENTRANT,
|
|
|
DATE_ENTREE = EXT_DATE_ENTREE,
|
|
|
DATE_SORTIE = EXT_DATE_SORTIE,
|
|
|
w_MEDECIN = EXT_MEDECIN
|
|
|
;
|
|
|
|
|
|
ALTER TABLE w_SEJOUR_EXT DROP COLUMN EXT_NO_4D;
|
|
|
ALTER TABLE w_SEJOUR_EXT DROP COLUMN EXT_NO_ENTRANT;
|
|
|
ALTER TABLE w_SEJOUR_EXT DROP COLUMN EXT_DATE_ENTREE;
|
|
|
ALTER TABLE w_SEJOUR_EXT DROP COLUMN EXT_DATE_SORTIE;
|
|
|
ALTER TABLE w_SEJOUR_EXT DROP COLUMN EXT_MEDECIN;
|
|
|
|
|
|
INSERT INTO w_IDE_SEJOUR_complet
|
|
|
SELECT *
|
|
|
FROM w_SEJOUR_EXT
|
|
|
WHERE w_SEJOUR_EXT.NO_4D NOT IN (SELECT NO_4D FROM w_IDE_SEJOUR_complet)
|
|
|
;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_IDE_PEC;
|
|
|
CREATE TEMP TABLE w_IDE_PEC AS
|
|
|
SELECT NO_4D AS PECH_ID_SEJO,
|
|
|
COALESCE(t_tiers_payant_0.oid)::bigint AS tiers_payant_0_id,
|
|
|
COALESCE(t_tiers_payant_1.oid)::bigint AS tiers_payant_1_id,
|
|
|
COALESCE(t_tiers_payant_2.oid)::bigint AS tiers_payant_2_id,
|
|
|
COALESCE(t_tiers_payant_2.oid)::bigint AS tiers_payant_22_id,
|
|
|
COALESCE(NUM_SS || CLE_SS) AS matricule_1,
|
|
|
AMC_NUM_ADHERENT AS matricule_2
|
|
|
FROM w_IDE_SEJOUR_complet
|
|
|
LEFT JOIN activite[PX].t_tiers_payant t_tiers_payant_1 ON (CAISSE_N::bigint = t_tiers_payant_1.code_original)
|
|
|
LEFT JOIN activite[PX].t_tiers_payant t_tiers_payant_2 ON (MUTUELLE::bigint = t_tiers_payant_2.code_original)
|
|
|
LEFT JOIN activite[PX].t_tiers_payant t_tiers_payant_0 ON (t_tiers_payant_0.type_tiers_payant = '0' AND t_tiers_payant_0.oid <> 0)
|
|
|
GROUP BY 1,2,3,4,5,6,7;
|
|
|
|
|
|
ALTER TABLE w_IDE_PEC ADD CONSTRAINT w_IDE_PEC_pkey PRIMARY KEY(PECH_ID_SEJO);
|
|
|
|
|
|
-- Médecins séjour
|
|
|
DROP TABLE IF EXISTS w_med_ssr
|
|
|
;
|
|
|
|
|
|
CREATE TEMP TABLE w_med_ssr AS
|
|
|
SELECT DISTINCT
|
|
|
NO_SEJOUR,
|
|
|
last_value(NO_PERSONNE) OVER (PARTITION BY NO_SEJOUR ORDER BY referents.NO_FICHE rows between unbounded preceding and unbounded following) as medecin_ssr
|
|
|
FROM prod_dai.REFERENTS
|
|
|
JOIN prod_dai.PERSONNEL ON NO_PERSONNE = PERSONNEL.NO_FICHE
|
|
|
WHERE PROFESSION LIKE '%decin'
|
|
|
;
|
|
|
|
|
|
ANALYSE w_med_ssr
|
|
|
;
|
|
|
|
|
|
UPDATE w_IDE_SEJOUR_complet
|
|
|
SET w_MEDECIN = w_med_ssr.medecin_ssr
|
|
|
FROM w_med_ssr
|
|
|
WHERE w_med_ssr.NO_SEJOUR = NO_4D
|
|
|
;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_IDE_MOUVEMENT_S;
|
|
|
CREATE TEMP TABLE w_IDE_MOUVEMENT_S AS
|
|
|
SELECT NO_4D AS MOUV_ID_SEJO, 'S'::text AS MOUV_STATUT
|
|
|
FROM prod_dai.PATIENTS
|
|
|
WHERE date(DATE_SORTIE) != '0001-01-01'
|
|
|
GROUP BY 1;
|
|
|
|
|
|
CREATE INDEX w_IDE_MOUVEMENT_S_i1
|
|
|
ON w_IDE_MOUVEMENT_S
|
|
|
USING btree
|
|
|
(MOUV_ID_SEJO);
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_sejours;
|
|
|
CREATE TEMP TABLE w_sejours AS
|
|
|
SELECT
|
|
|
w_NO_ENTRANT as no_sejour,
|
|
|
w_NO_4D::bigint as code_original,
|
|
|
NO_4D_patient as no_patient,
|
|
|
date(DATE_ENTREE) as date_entree,
|
|
|
HEURE_ENTREE_CTI as heure_entree,
|
|
|
CASE WHEN DATE_SORTIE IS NOT NULL AND DATE_SORTIE != '0001-01-01' THEN date(DATE_SORTIE) ELSE '20991231' END::date as date_sortie,
|
|
|
CASE WHEN DATE_SORTIE IS NOT NULL THEN HEURE_SORTIE_cti ELSE 0 END as heure_sortie,
|
|
|
CASE WHEN SEXE = 'F' THEN '2' ELSE '1' END as code_sexe,
|
|
|
0 AS age,
|
|
|
CASE WHEN DATE_SORTIE <= date(now()) AND DATE_SORTIE != '0001-01-01' THEN 1 ELSE 0 END as code_sorti,
|
|
|
0 as code_prevu, --patient est la table des séjours effectifs
|
|
|
CASE
|
|
|
WHEN t_services_facturation.type_sejour IN ('1', '2', '3', '4', '5') THEN t_services_facturation.type_sejour
|
|
|
WHEN t_modes_traitement.code IN ('07') OR t_dmt.code In ('958') THEN '3'
|
|
|
WHEN t_modes_traitement.code IN ('19', '23') AND date(DATE_SORTIE) = date(DATE_ENTREE) THEN '2'
|
|
|
WHEN t_modes_traitement.code IN ('04') AND date(DATE_SORTIE) = date(DATE_ENTREE) THEN '2'
|
|
|
WHEN t_modes_traitement.code IN ('03') AND date(DATE_SORTIE) = date(DATE_ENTREE) THEN '2'
|
|
|
WHEN t_modes_traitement.code IN ('10') AND date(DATE_SORTIE) <= date(DATE_ENTREE) + interval '1 day' THEN '3'
|
|
|
ELSE '1' END as type_sejour,
|
|
|
COALESCE(t_medecins_administratifs.oid,0) as medecin_sejour_id,
|
|
|
0 as ghs_id,
|
|
|
'20991231'::date as date_groupage,
|
|
|
CASE WHEN DEBUT_CHPART != '0001-01-01' THEN 1 ELSE 0 END as code_cp_demandee,
|
|
|
t_services_facturation.mode_traitement_id as mode_traitement_id,
|
|
|
MODE_ENTREE_PMSI::character(1) as mode_entree,
|
|
|
COALESCE(PROVENANCE_PMSI::character(1),'') as provenance,
|
|
|
COALESCE(MODE_SORTIE::character(1),'') as mode_sortie,
|
|
|
'0'::character(1) 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,
|
|
|
0 AS est_budget_global,
|
|
|
COALESCE(t_codes_postaux.oid, 0) AS code_postal_id
|
|
|
FROM w_IDE_SEJOUR_complet
|
|
|
LEFT JOIN w_IDE_PEC ON (PECH_ID_SEJO = NO_4D)
|
|
|
JOIN activite[PX].t_services_facturation ON TYPE_REEDUCATIO = t_services_facturation.code_original
|
|
|
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
|
|
|
LEFT JOIN activite[PX].t_medecins_administratifs ON w_MEDECIN::bigint = t_medecins_administratifs.code_original
|
|
|
LEFT JOIN w_IDE_MOUVEMENT_S ON w_NO_4D = MOUV_ID_SEJO
|
|
|
LEFT JOIN base.t_codes_postaux ON CODE_POSTAL = t_codes_postaux.code
|
|
|
;
|
|
|
|
|
|
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,
|
|
|
no_patient = w_sejours.no_patient,
|
|
|
date_entree = w_sejours.date_entree,
|
|
|
heure_entree = w_sejours.heure_entree,
|
|
|
date_sortie = w_sejours.date_sortie,
|
|
|
heure_sortie = w_sejours.heure_sortie,
|
|
|
code_sexe = w_sejours.code_sexe,
|
|
|
age = w_sejours.age,
|
|
|
code_sorti = w_sejours.code_sorti,
|
|
|
code_prevu = w_sejours.code_prevu,
|
|
|
type_sejour = w_sejours.type_sejour,
|
|
|
medecin_sejour_id = w_sejours.medecin_sejour_id,
|
|
|
code_cp_demandee = w_sejours.code_cp_demandee,
|
|
|
mode_traitement_id = w_sejours.mode_traitement_id,
|
|
|
mode_entree = w_sejours.mode_entree,
|
|
|
provenance = w_sejours.provenance,
|
|
|
mode_sortie = w_sejours.mode_sortie,
|
|
|
destination = w_sejours.destination,
|
|
|
tiers_payant_0_id = w_sejours.tiers_payant_0_id,
|
|
|
tiers_payant_1_id = w_sejours.tiers_payant_1_id,
|
|
|
tiers_payant_2_id = w_sejours.tiers_payant_2_id,
|
|
|
tiers_payant_22_id = w_sejours.tiers_payant_22_id,
|
|
|
est_budget_global = w_sejours.est_budget_global,
|
|
|
code_postal_id = w_sejours.code_postal_id
|
|
|
FROM w_sejours
|
|
|
WHERE w_sejours.no_sejour = p_sejours.no_sejour
|
|
|
AND (
|
|
|
w_sejours.code_original IS DISTINCT FROM p_sejours.code_original OR
|
|
|
w_sejours.no_patient IS DISTINCT FROM p_sejours.no_patient OR
|
|
|
w_sejours.date_entree IS DISTINCT FROM p_sejours.date_entree OR
|
|
|
w_sejours.heure_entree IS DISTINCT FROM p_sejours.heure_entree OR
|
|
|
w_sejours.date_sortie IS DISTINCT FROM p_sejours.date_sortie OR
|
|
|
w_sejours.heure_sortie IS DISTINCT FROM p_sejours.heure_sortie OR
|
|
|
w_sejours.code_sexe IS DISTINCT FROM p_sejours.code_sexe OR
|
|
|
w_sejours.age IS DISTINCT FROM p_sejours.age OR
|
|
|
w_sejours.code_sorti IS DISTINCT FROM p_sejours.code_sorti OR
|
|
|
w_sejours.code_prevu IS DISTINCT FROM p_sejours.code_prevu OR
|
|
|
w_sejours.type_sejour IS DISTINCT FROM p_sejours.type_sejour OR
|
|
|
w_sejours.medecin_sejour_id IS DISTINCT FROM p_sejours.medecin_sejour_id OR
|
|
|
w_sejours.code_cp_demandee IS DISTINCT FROM p_sejours.code_cp_demandee OR
|
|
|
w_sejours.mode_traitement_id IS DISTINCT FROM p_sejours.mode_traitement_id OR
|
|
|
w_sejours.mode_entree IS DISTINCT FROM p_sejours.mode_entree OR
|
|
|
w_sejours.provenance IS DISTINCT FROM p_sejours.provenance OR
|
|
|
w_sejours.mode_sortie IS DISTINCT FROM p_sejours.mode_sortie OR
|
|
|
w_sejours.destination IS DISTINCT FROM p_sejours.destination OR
|
|
|
w_sejours.tiers_payant_0_id IS DISTINCT FROM p_sejours.tiers_payant_0_id OR
|
|
|
w_sejours.tiers_payant_1_id IS DISTINCT FROM p_sejours.tiers_payant_1_id OR
|
|
|
w_sejours.tiers_payant_2_id IS DISTINCT FROM p_sejours.tiers_payant_2_id OR
|
|
|
w_sejours.tiers_payant_22_id IS DISTINCT FROM p_sejours.tiers_payant_22_id OR
|
|
|
w_sejours.est_budget_global IS DISTINCT FROM p_sejours.est_budget_global OR
|
|
|
w_sejours.code_postal_id IS DISTINCT FROM p_sejours.code_postal_id
|
|
|
);
|
|
|
|
|
|
INSERT INTO activite[PX].p_sejours (
|
|
|
no_sejour,
|
|
|
code_original,
|
|
|
no_patient,
|
|
|
date_entree,
|
|
|
heure_entree,
|
|
|
date_sortie,
|
|
|
heure_sortie,
|
|
|
code_sexe,
|
|
|
age,
|
|
|
code_sorti,
|
|
|
code_prevu,
|
|
|
type_sejour,
|
|
|
medecin_sejour_id,
|
|
|
ghs_id,
|
|
|
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.no_sejour,
|
|
|
w_sejours.code_original,
|
|
|
w_sejours.no_patient,
|
|
|
w_sejours.date_entree,
|
|
|
w_sejours.heure_entree,
|
|
|
w_sejours.date_sortie,
|
|
|
w_sejours.heure_sortie,
|
|
|
w_sejours.code_sexe,
|
|
|
w_sejours.age,
|
|
|
w_sejours.code_sorti,
|
|
|
w_sejours.code_prevu,
|
|
|
w_sejours.type_sejour,
|
|
|
w_sejours.medecin_sejour_id,
|
|
|
w_sejours.ghs_id,
|
|
|
w_sejours.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
|
|
|
USING activite[PX].p_sejours AS p_sejours_i LEFT JOIN w_sejours ON (w_sejours.no_sejour = p_sejours_i.no_sejour)
|
|
|
WHERE
|
|
|
p_sejours.no_sejour = p_sejours_i.no_sejour AND
|
|
|
w_sejours.no_sejour IS NULL;
|
|
|
|
|
|
-- Modes entrée sortie selon PMSI SSR
|
|
|
UPDATE activite[PX].p_sejours
|
|
|
SET mode_entree = PMSI_RHS.MODE_ENTREE,
|
|
|
provenance = COALESCE(PMSI_RHS.PROVENANCE,'')
|
|
|
FROM w_IDE_SEJOUR_complet, prod_dai.PMSI_RHS
|
|
|
WHERE
|
|
|
no_sejour = w_NO_ENTRANT AND
|
|
|
NO_4D = SEJOUR AND
|
|
|
date(DATE_DEBUT_RHS) = date(w_IDE_SEJOUR_complet.DATE_ENTREE) AND
|
|
|
(
|
|
|
p_sejours.mode_entree <> PMSI_RHS.MODE_ENTREE OR
|
|
|
p_sejours.provenance <> PMSI_RHS.PROVENANCE
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_sejours
|
|
|
SET mode_sortie = PMSI_RHS.MODE_SORTIE,
|
|
|
destination = PMSI_RHS.DESTINATION
|
|
|
FROM w_IDE_SEJOUR_complet, prod_dai.PMSI_RHS
|
|
|
WHERE
|
|
|
no_sejour = w_NO_ENTRANT AND
|
|
|
NO_4D = SEJOUR AND
|
|
|
date(PMSI_RHS.DATE_SORTIE) = date(w_IDE_SEJOUR_complet.DATE_SORTIE) AND
|
|
|
(
|
|
|
p_sejours.mode_sortie <> PMSI_RHS.MODE_SORTIE OR
|
|
|
p_sejours.destination <> PMSI_RHS.DESTINATION
|
|
|
);
|
|
|
|
|
|
|
|
|
-- Etablissements de provenance et destination
|
|
|
-- insertion nouveaux etablissements
|
|
|
DROP TABLE IF EXISTS w_ETAB;
|
|
|
CREATE TEMP TABLE w_ETAB AS
|
|
|
SELECT *
|
|
|
FROM prod_dai.ETABLISSEMENTS
|
|
|
LEFT JOIN base.t_etablissements ON FINESS = code
|
|
|
WHERE
|
|
|
FINESS != ''
|
|
|
AND
|
|
|
(NO_FICHE = ANY(array(SELECT ETABLISS_NO FROM prod_dai.PATIENTS)::bigint[])
|
|
|
OR NO_FICHE = ANY(array(SELECT ETABLISSEMENT_DESTINATAIRE FROM prod_dai.PATIENTS)::bigint[]))
|
|
|
;
|
|
|
|
|
|
INSERT INTO base.t_etablissements
|
|
|
(
|
|
|
code,
|
|
|
texte,
|
|
|
texte_court
|
|
|
)
|
|
|
SELECT
|
|
|
FINESS,
|
|
|
NOM,
|
|
|
NOM
|
|
|
FROM w_ETAB
|
|
|
WHERE code IS NULL
|
|
|
AND FINESS IS NOT NULL;
|
|
|
|
|
|
-- rechargements des etablissements
|
|
|
DROP TABLE IF EXISTS w_ETAB;
|
|
|
CREATE TEMP TABLE w_ETAB AS
|
|
|
SELECT *
|
|
|
FROM prod_dai.ETABLISSEMENTS
|
|
|
LEFT JOIN base.t_etablissements ON FINESS = code;
|
|
|
|
|
|
-- insertion des données de correspondances (pas d'update car les tables sont vidées avant import)
|
|
|
DROP TABLE IF EXISTS w_TRANS;
|
|
|
CREATE TEMP TABLE w_TRANS AS
|
|
|
SELECT
|
|
|
to_char(NO_4D, 'fm00000000000000000000') as num_admin_sejour,
|
|
|
NO_SSR AS num_sejour_ssr,
|
|
|
etex_pro.oid as oid_pro,
|
|
|
etex_des.oid as oid_des
|
|
|
FROM prod_dai.PATIENTS
|
|
|
LEFT JOIN w_ETAB as etex_pro ON PATIENTS.ETABLISS_NO = etex_pro.NO_FICHE
|
|
|
LEFT JOIN w_ETAB as etex_des ON PATIENTS.ETABLISSEMENT_DESTINATAIRE = etex_des.NO_FICHE
|
|
|
WHERE 1=1
|
|
|
AND ETABLISS_NO <> 0 OR ETABLISSEMENT_DESTINATAIRE <> 0
|
|
|
GROUP BY num_admin_sejour, num_sejour_ssr, oid_pro, oid_des
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_sejours_transferts(
|
|
|
sejour_id,
|
|
|
provenance_id,
|
|
|
destination_id
|
|
|
)
|
|
|
SELECT
|
|
|
p_sejours.oid,
|
|
|
oid_pro,
|
|
|
oid_des
|
|
|
FROM activite[PX].p_sejours
|
|
|
JOIN w_TRANS ON w_TRANS.num_admin_sejour = p_sejours.no_sejour;
|
|
|
|
|
|
|
|
|
-- 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');
|
|
|
|
|
|
|
|
|
-- assurance
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_sejours_assurance_1');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_sejours_assurance_2');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_sejours_assurance_3');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_sejours_assurance_4');
|
|
|
|
|
|
INSERT INTO activite[PX].p_sejours_assurance(
|
|
|
sejour_id,
|
|
|
tiers_payant_0_id,
|
|
|
tiers_payant_1_id,
|
|
|
matricule_1,
|
|
|
tiers_payant_2_id,
|
|
|
matricule_2,
|
|
|
tiers_payant_22_id,
|
|
|
matricule_22)
|
|
|
SELECT
|
|
|
oid AS sejour_id,
|
|
|
p_sejours.tiers_payant_0_id,
|
|
|
p_sejours.tiers_payant_1_id,
|
|
|
substr(w_IDE_PEC.matricule_1,1,30),
|
|
|
p_sejours.tiers_payant_2_id,
|
|
|
substr(w_IDE_PEC.matricule_2,1,30),
|
|
|
p_sejours.tiers_payant_22_id,
|
|
|
''::text AS matricule_22
|
|
|
FROM w_IDE_PEC
|
|
|
JOIN activite[PX].p_sejours ON code_original = PECH_ID_SEJO AND p_sejours.etat = '';
|
|
|
|
|
|
|
|
|
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_sejours_assurance_1');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_sejours_assurance_2');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_sejours_assurance_3');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_sejours_assurance_4');
|
|
|
|
|
|
|
|
|
-- Suppression des tables de travail non utilisées après
|
|
|
DROP TABLE IF EXISTS w_IDE_PEC;
|
|
|
DROP TABLE IF EXISTS w_sejours;
|
|
|
DROP TABLE IF EXISTS w_IDE_MOUVEMENT_S;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Info_comp_PMSISSSR_DAI" comment="Ajout des données SSR depuis le prestataire DAI">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
--GME pour activite SSR
|
|
|
UPDATE activite[PX].p_sejours SET
|
|
|
gme_id = subq.gme_id
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
SEJOUR,
|
|
|
COALESCE(((MIN(ARRAY[NO_FICHE::text, t_gme_c.gme_id::text]))[2]::text )::int , 0) AS gme_id
|
|
|
FROM prod_dai.PMSI_RHS
|
|
|
LEFT JOIN activite[PX].t_gme_c ON GME_SEMAINE = t_gme_c.gme_code
|
|
|
GROUP BY SEJOUR
|
|
|
) subq
|
|
|
WHERE 1=1
|
|
|
AND p_sejours.code_original = subq.SEJOUR
|
|
|
AND p_sejours.gme_id IS DISTINCT FROM COALESCE(subq.gme_id,0)
|
|
|
;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Mouvements">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Recherche UM principale
|
|
|
DROP TABLE IF EXISTS w_PMS_RUM_principal;
|
|
|
CREATE TEMP TABLE w_PMS_RUM_principal AS
|
|
|
SELECT NO_4D,
|
|
|
COALESCE(
|
|
|
(MIN(Array[CASE WHEN PMSI_UNITE_MEDICALE IS NOT NULL THEN PATIENTS.DATE_ENTREE ELSE NULL END::text, PMSI_UNITE_MEDICALE::text]))[2],
|
|
|
(MIN(Array[PATIENTS.DATE_ENTREE::text,PMSI_UNITE_MEDICALE::text]))[2]
|
|
|
)::text AS TRUM_ID_UNME_principale
|
|
|
FROM prod_dai.PATIENTS
|
|
|
join prod_dai.POP_LISTES on TYPE_REEDUCATIO = POP_LISTES.NOM
|
|
|
JOIN activite[PX].p_sejours ON p_sejours.code_original = NO_4D
|
|
|
GROUP BY 1;
|
|
|
|
|
|
CREATE INDEX w_PMS_RUM_principal_i1
|
|
|
ON w_PMS_RUM_principal
|
|
|
USING btree
|
|
|
(NO_4D);
|
|
|
|
|
|
|
|
|
-- Traitement des mouvements
|
|
|
DROP SEQUENCE IF EXISTS w_IDE_MOUVEMENT_seq;
|
|
|
CREATE TEMP SEQUENCE w_IDE_MOUVEMENT_seq
|
|
|
INCREMENT 1
|
|
|
MINVALUE 1
|
|
|
MAXVALUE 9223372036854775807
|
|
|
START 1
|
|
|
CACHE 1;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_IDE_MOUVEMENT;
|
|
|
|
|
|
CREATE TEMP TABLE w_IDE_MOUVEMENT AS
|
|
|
SELECT nextval('w_IDE_MOUVEMENT_seq'::regclass) AS sequence,
|
|
|
subview.MOUV_ID_SEJO,
|
|
|
subview.SEJO_NUM_SEJ,
|
|
|
subview.MOUV_DAT_MOU,
|
|
|
date(subview.MOUV_DAT_MOU) AS MOUV_DAT_MOU_DAT,
|
|
|
extract('hour' FROM MOUV_DAT_MOU) * 10000 + extract('minute' FROM MOUV_DAT_MOU) * 100 + extract('second' FROM MOUV_DAT_MOU) AS MOUV_DAT_MOU_TIM,
|
|
|
'2099/12/31'::timestamp without time zone AS MOUV_DAT_FIN,
|
|
|
date('2099/12/31')::date AS MOUV_DAT_FIN_DAT,
|
|
|
0 AS MOUV_DAT_FIN_TIM,
|
|
|
subview.CAGE_CODE,
|
|
|
subview.TRUM_ID_UNME_principale,
|
|
|
subview.MOUV_ID_UNFO,
|
|
|
subview.MOUV_ID_UNFO_MED,
|
|
|
CASE
|
|
|
WHEN subview.MOUV_ID_LIPO = 0 THEN subview.MOUV_ID_UNFO::text || '-0'
|
|
|
ELSE subview.MOUV_ID_LIPO::text END AS MOUV_ID_LIPO,
|
|
|
''::character(2) AS CAGE_CODE_before,
|
|
|
'0'::text AS MOUV_ID_UNFO_before,
|
|
|
'0'::text AS MOUV_ID_UNFO_MED_before,
|
|
|
0::text AS MOUV_ID_LIPO_before,
|
|
|
''::character(2) AS CAGE_CODE_next,
|
|
|
'0'::text AS MOUV_ID_UNFO_next,
|
|
|
'0'::text AS MOUV_ID_UNFO_MED_next,
|
|
|
0::text AS MOUV_ID_LIPO_next
|
|
|
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
w_NO_ENTRANT AS SEJO_NUM_SEJ,
|
|
|
w_IDE_SEJOUR_complet.NO_4D AS MOUV_ID_SEJO,
|
|
|
CASE
|
|
|
WHEN FIN_DISPO = w_IDE_SEJOUR_complet.DATE_ENTREE THEN w_IDE_SEJOUR_complet.DATE_ENTREE + HEURE_ENTREE_time
|
|
|
WHEN RETOUR_DISPO + interval '1 day' = w_IDE_SEJOUR_complet.DATE_SORTIE THEN w_IDE_SEJOUR_complet.DATE_SORTIE + HEURE_SORTIE_time
|
|
|
WHEN FIN_DISPO IS NOT NULL THEN FIN_DISPO
|
|
|
ELSE w_IDE_SEJOUR_complet.DATE_ENTREE END AS MOUV_DAT_MOU,
|
|
|
CASE
|
|
|
WHEN FIN_DISPO = w_IDE_SEJOUR_complet.DATE_ENTREE THEN 'E'
|
|
|
ELSE '' END AS CAGE_CODE,
|
|
|
COALESCE(TRUM_ID_UNME_principale,'') AS TRUM_ID_UNME_principale,
|
|
|
COALESCE(POP_LISTES.NO_FICHE,0) AS MOUV_ID_UNFO,
|
|
|
TYPE_REEDUCATIO::text AS MOUV_ID_UNFO_MED,
|
|
|
COALESCE(LITS.NO_FICHE::text,LITS_RESERV.NO_FICHE::text,'') AS MOUV_ID_LIPO,
|
|
|
COALESCE(LITS.PAVILLON,w_IDE_SEJOUR_complet.PAVILLON) AS CHAS_ID_UNFO,
|
|
|
w_IDE_SEJOUR_complet.DATE_SORTIE + HEURE_SORTIE_time AS DATE_SORTIE
|
|
|
FROM w_IDE_SEJOUR_complet
|
|
|
LEFT JOIN prod_dai.AFFECTATION_CH ON SEJOUR = NO_4D
|
|
|
LEFT JOIN prod_dai.RESERVATIONS ON RESERVATIONS.NO_SEJOUR = w_IDE_SEJOUR_COMPLET.NO_4D
|
|
|
JOIN activite[PX].p_sejours ON NO_4D = p_sejours.code_original
|
|
|
LEFT JOIN prod_dai.LITS ON LITS.NO_FICHE = AFFECTATION_CH.CHAMBRE
|
|
|
LEFT JOIN w_PMS_RUM_principal ON w_PMS_RUM_principal.NO_4D = w_IDE_SEJOUR_complet.NO_4D
|
|
|
LEFT JOIN prod_dai.POP_LISTES ON w_IDE_SEJOUR_complet.SERVICE = POP_LISTES.NOM AND TITRE_POP = 'Services'
|
|
|
LEFT JOIN prod_dai.LITS LITS_RESERV ON LITS_RESERV.NO_FICHE = RESERVATIONS.CHAMBRE
|
|
|
ORDER BY w_NO_ENTRANT, MOUV_DAT_MOU, CAGE_CODE
|
|
|
) subview;
|
|
|
|
|
|
DELETE FROM w_IDE_MOUVEMENT
|
|
|
USING (
|
|
|
SELECT
|
|
|
SEJO_NUM_SEJ, MOUV_DAT_MOU, MOUV_DAT_MOU_TIM, MAX(CTID) AS fromCTID
|
|
|
FROM w_IDE_MOUVEMENT
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING count(*) > 1) subview
|
|
|
WHERE subview.fromCTID = w_IDE_MOUVEMENT.CTID;
|
|
|
|
|
|
DELETE FROM w_IDE_MOUVEMENT
|
|
|
USING (
|
|
|
SELECT
|
|
|
SEJO_NUM_SEJ, MOUV_DAT_MOU, MOUV_DAT_MOU_TIM, MAX(CTID) AS fromCTID
|
|
|
FROM w_IDE_MOUVEMENT
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING count(*) > 1) subview
|
|
|
WHERE subview.fromCTID = w_IDE_MOUVEMENT.CTID;
|
|
|
|
|
|
-- Si le premier mouvement est postérieur à la date d'entrée, le ramener à cette date
|
|
|
UPDATE w_IDE_MOUVEMENT SET
|
|
|
MOUV_DAT_MOU = DATE_ENTREE,
|
|
|
MOUV_DAT_MOU_DAT = date(DATE_ENTREE),
|
|
|
CAGE_CODE = 'E'
|
|
|
FROM
|
|
|
(
|
|
|
SELECT *
|
|
|
FROM
|
|
|
(
|
|
|
SELECT sejo_num_sej,
|
|
|
date_entree,
|
|
|
mouv_dat_mou,
|
|
|
mouv_dat_fin,
|
|
|
w_IDE_MOUVEMENT.CTID AS w_ctid,
|
|
|
row_number() over (partition by sejo_num_sej order by mouv_dat_mou) AS seq
|
|
|
FROM w_IDE_MOUVEMENT
|
|
|
JOIN activite[PX].p_sejours on sejo_num_sej = no_sejour
|
|
|
ORDER BY SEJO_NUM_SEJ
|
|
|
) subview
|
|
|
WHERE seq = 1 AND
|
|
|
date(date_entree) < date(mouv_dat_mou)
|
|
|
) subview
|
|
|
WHERE w_IDE_MOUVEMENT.SEJO_NUM_SEJ = subview.SEJO_NUM_SEJ AND
|
|
|
w_IDE_MOUVEMENT.CTID = w_CTID
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_IDE_MOUVEMENT
|
|
|
SET CAGE_CODE = CAGE_CODE || 'S',
|
|
|
MOUV_DAT_FIN = sub.DATE_SORTIE,
|
|
|
MOUV_DAT_FIN_DAT = date(DATE_SORTIE),
|
|
|
MOUV_DAT_FIN_TIM = extract('hour' FROM MOUV_DAT_MOU) * 10000 + extract('minute' FROM MOUV_DAT_MOU) * 100 + extract('second' FROM MOUV_DAT_MOU)
|
|
|
FROM (SELECT MAX(sequence) as max_sequence , max(DATE_SORTIE) as DATE_SORTIE
|
|
|
FROM w_IDE_MOUVEMENT JOIN w_IDE_SEJOUR_complet ON SEJO_NUM_SEJ = w_NO_ENTRANT
|
|
|
WHERE DATE_SORTIE != '0001-01-01'
|
|
|
GROUP BY w_NO_ENTRANT, DATE_SORTIE) as sub
|
|
|
WHERE max_sequence = sequence;
|
|
|
|
|
|
UPDATE w_IDE_MOUVEMENT
|
|
|
SET MOUV_DAT_FIN = w_IDE_MOUVEMENT_next.MOUV_DAT_MOU - interval '1 second',
|
|
|
MOUV_DAT_FIN_DAT = date(w_IDE_MOUVEMENT_next.MOUV_DAT_MOU - interval '1 second'),
|
|
|
MOUV_DAT_FIN_TIM = extract('hour' FROM w_IDE_MOUVEMENT_next.MOUV_DAT_MOU - interval '1 second') * 10000 +
|
|
|
extract('minute' FROM w_IDE_MOUVEMENT_next.MOUV_DAT_MOU - interval '1 second') * 100 +
|
|
|
extract('second' FROM w_IDE_MOUVEMENT_next.MOUV_DAT_MOU - interval '1 second'),
|
|
|
CAGE_CODE_next = w_IDE_MOUVEMENT_next.CAGE_CODE,
|
|
|
MOUV_ID_UNFO_next = w_IDE_MOUVEMENT_next.MOUV_ID_UNFO,
|
|
|
MOUV_ID_UNFO_MED_next = w_IDE_MOUVEMENT_next.MOUV_ID_UNFO_MED,
|
|
|
MOUV_ID_LIPO_next = w_IDE_MOUVEMENT_next.MOUV_ID_LIPO
|
|
|
FROM w_IDE_MOUVEMENT w_IDE_MOUVEMENT_next
|
|
|
WHERE w_IDE_MOUVEMENT.SEJO_NUM_SEJ = w_IDE_MOUVEMENT_next.SEJO_NUM_SEJ
|
|
|
AND w_IDE_MOUVEMENT.sequence = w_IDE_MOUVEMENT_next.sequence - 1;
|
|
|
|
|
|
|
|
|
-- Si hopital de jour sans journée,
|
|
|
UPDATE w_IDE_MOUVEMENT
|
|
|
SET CAGE_CODE_next = 'C'
|
|
|
FROM activite[PX].p_sejours,
|
|
|
activite[PX].t_services_facturation
|
|
|
JOIN base.t_modes_traitement on t_services_facturation.mode_traitement_id = t_modes_traitement.oid
|
|
|
WHERE MOUV_ID_SEJO::bigint = p_sejours.code_original AND
|
|
|
code_prevu <> '1' AND
|
|
|
CAGE_CODE = 'E' AND
|
|
|
MOUV_ID_UNFO_MED = t_services_facturation.code_original AND
|
|
|
(CAGE_CODE_NEXT = '' OR CAGE_CODE_NEXT = 'S' AND date_entree <> date_sortie) AND
|
|
|
t_modes_traitement.code = '04' AND
|
|
|
t_services_facturation.type_t2a = '2';
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- calcul mvt avant
|
|
|
|
|
|
UPDATE w_IDE_MOUVEMENT
|
|
|
SET
|
|
|
CAGE_CODE_before = w_IDE_MOUVEMENT_before.CAGE_CODE,
|
|
|
MOUV_ID_UNFO_before = w_IDE_MOUVEMENT_before.MOUV_ID_UNFO,
|
|
|
MOUV_ID_UNFO_MED_before = w_IDE_MOUVEMENT_before.MOUV_ID_UNFO_MED,
|
|
|
MOUV_ID_LIPO_before = w_IDE_MOUVEMENT_before.MOUV_ID_LIPO
|
|
|
FROM w_IDE_MOUVEMENT w_IDE_MOUVEMENT_before
|
|
|
WHERE w_IDE_MOUVEMENT.SEJO_NUM_SEJ = w_IDE_MOUVEMENT_before.SEJO_NUM_SEJ
|
|
|
AND w_IDE_MOUVEMENT.sequence = w_IDE_MOUVEMENT_before.sequence + 1
|
|
|
AND w_IDE_MOUVEMENT.CAGE_CODE <> 'S';
|
|
|
|
|
|
-- Absences
|
|
|
UPDATE w_IDE_MOUVEMENT
|
|
|
SET MOUV_ID_UNFO_MED = '*ABS'
|
|
|
WHERE CAGE_CODE = 'A';
|
|
|
|
|
|
-- Hopital de jour Dernière séance avant dans sortie
|
|
|
UPDATE w_IDE_MOUVEMENT SET
|
|
|
MOUV_DAT_MOU = MOUV_DAT_FIN,
|
|
|
MOUV_DAT_MOU_DAT = MOUV_DAT_FIN_DAT,
|
|
|
MOUV_DAT_MOU_TIM = MOUV_DAT_FIN_TIM
|
|
|
WHERE CAGE_CODE = 'P' AND CAGE_CODE_next = 'S' AND
|
|
|
MOUV_DAT_FIN <> MOUV_DAT_MOU;
|
|
|
|
|
|
-- Hopital de jour Première séance après date entree
|
|
|
UPDATE w_IDE_MOUVEMENT SET
|
|
|
MOUV_DAT_FIN = MOUV_DAT_MOU,
|
|
|
MOUV_DAT_FIN_DAT = MOUV_DAT_MOU_DAT,
|
|
|
MOUV_DAT_FIN_TIM = MOUV_DAT_MOU_TIM
|
|
|
WHERE CAGE_CODE = 'E' AND CAGE_CODE_next = 'C' AND
|
|
|
MOUV_DAT_MOU <> MOUV_DAT_FIN;
|
|
|
|
|
|
-- creation mouvements par jour
|
|
|
|
|
|
DROP TABLE IF EXISTS w_mouvements_sejour;
|
|
|
CREATE TEMP TABLE w_mouvements_sejour AS
|
|
|
SELECT
|
|
|
w_IDE_MOUVEMENT.MOUV_ID_SEJO,
|
|
|
w_IDE_MOUVEMENT.SEJO_NUM_SEJ 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 = MOUV_DAT_MOU_DAT THEN MOUV_DAT_MOU_TIM ELSE 0 END AS heure_debut,
|
|
|
CASE WHEN p_calendrier.date = MOUV_DAT_FIN_DAT THEN MOUV_DAT_FIN_TIM ELSE 240000 END AS heure_fin,
|
|
|
CASE WHEN p_calendrier.date = MOUV_DAT_MOU_DAT AND (CAGE_CODE = 'E' OR CAGE_CODE = 'ES') AND p_sejours.type_sejour = '1' THEN 1 ELSE 0 END AS nb_entrees_directes,
|
|
|
CASE WHEN p_calendrier.date = MOUV_DAT_FIN_DAT AND (CAGE_CODE = 'S' OR CAGE_CODE = 'ES') AND p_sejours.type_sejour = '1' THEN 1 ELSE 0 END AS nb_sorties_directes,
|
|
|
CASE WHEN p_calendrier.date = MOUV_DAT_MOU_DAT AND (CAGE_CODE = 'E' OR CAGE_CODE = 'ES') AND p_sejours.type_sejour = '1' THEN '1' ELSE '0' END AS est_jour_entree,
|
|
|
CASE WHEN p_calendrier.date = MOUV_DAT_FIN_DAT AND (CAGE_CODE = 'S' OR CAGE_CODE = 'ES') AND p_sejours.type_sejour = '1' THEN '1' ELSE '0' END AS est_jour_sortie,
|
|
|
CASE WHEN p_sejours.type_sejour = '1' AND CAGE_CODE_next <> 'C' AND CAGE_CODE <> 'P' THEN '1' ELSE '0' END AS est_jour_hospitalisation,
|
|
|
CASE WHEN p_calendrier.date = MOUV_DAT_MOU_DAT AND (CAGE_CODE = 'E' OR CAGE_CODE = 'ES') AND p_sejours.type_sejour = '2' THEN 1 ELSE 0 END AS nb_ambulatoires,
|
|
|
CASE WHEN p_calendrier.date = MOUV_DAT_MOU_DAT AND p_sejours.type_sejour = '3' THEN 1 ELSE 0 END AS nb_externes,
|
|
|
CASE WHEN p_calendrier.date = MOUV_DAT_MOU_DAT AND (CAGE_CODE = 'E' OR CAGE_CODE = 'ES') AND p_sejours.type_sejour <> '9' AND t_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 = MOUV_DAT_MOU_DAT AND CAGE_CODE IN ('D', 'M') AND p_sejours.type_sejour = '1' AND mouv_id_unfo_med <> mouv_id_unfo_med_before THEN 1 ELSE 0 END AS nb_entrees_mutation_service,
|
|
|
CASE WHEN p_calendrier.date = MOUV_DAT_FIN_DAT AND CAGE_CODE_next IN ('D', 'M') AND p_sejours.type_sejour = '1' AND mouv_id_unfo_med <> mouv_id_unfo_med_next THEN 1 ELSE 0 END AS nb_sorties_mutation_service,
|
|
|
CASE WHEN p_calendrier.date = MOUV_DAT_MOU_DAT AND CAGE_CODE IN ('D', 'M') AND p_sejours.type_sejour = '1' AND mouv_id_unfo <> mouv_id_unfo_before THEN 1 ELSE 0 END AS nb_entrees_mutation_etage,
|
|
|
CASE WHEN p_calendrier.date = MOUV_DAT_FIN_DAT AND CAGE_CODE_next IN ('D', 'M') AND p_sejours.type_sejour = '1' AND mouv_id_unfo <> mouv_id_unfo_next THEN 1 ELSE 0 END AS nb_sorties_mutation_etage,
|
|
|
0 AS nb_entrees_mutation_activite,
|
|
|
0 AS nb_sorties_mutation_activite,
|
|
|
0 AS nb_entrees_mutation_unite_medicale,
|
|
|
0 AS nb_sorties_mutation_unite_medicale,
|
|
|
|
|
|
CASE WHEN p_sejours.type_sejour = '1' AND CAGE_CODE_next <> 'C' AND CAGE_CODE <> 'P' AND (p_calendrier.date <> MOUV_DAT_FIN_DAT OR CAGE_CODE_next = 'S') THEN 1 ELSE 0 END AS nb_jours_js_inclus,
|
|
|
CASE WHEN p_sejours.type_sejour = '1' AND CAGE_CODE_next <> 'C' AND CAGE_CODE <> 'P' AND p_calendrier.date <> MOUV_DAT_FIN_DAT THEN 1 ELSE 0 END AS nb_jours_js_non_inclus,
|
|
|
|
|
|
CASE WHEN p_sejours.type_sejour = '1' AND CAGE_CODE_next <> 'C' AND CAGE_CODE <> 'P' AND t_lits.chambre_particuliere = 'O' THEN '1' ELSE '0' END AS est_chambre_particuliere,
|
|
|
CASE WHEN p_sejours.type_sejour = '1' AND CAGE_CODE_next <> 'C' AND CAGE_CODE <> 'P' AND t_lits.chambre_particuliere = 'O' AND (p_calendrier.date <> MOUV_DAT_FIN_DAT OR CAGE_CODE_next = 'S') THEN 1 ELSE 0 END AS nb_chambres_particulieres,
|
|
|
|
|
|
0 AS nb_bebes,
|
|
|
|
|
|
TRUM_ID_UNME_principale,
|
|
|
MOUV_ID_UNFO_MED,
|
|
|
MOUV_ID_UNFO,
|
|
|
MOUV_ID_LIPO,
|
|
|
|
|
|
COALESCE(t_lieux.oid,0) AS lieu_id,
|
|
|
|
|
|
p_sejours.medecin_sejour_id as medecin_sejour_id,
|
|
|
|
|
|
CASE WHEN p_sejours.code_prevu = '1' OR p_calendrier.date > date(date_extraction) THEN '1' ELSE '0' END AS est_mouvement_previsionnel,
|
|
|
|
|
|
''::text AS est_premier_mouvement_jour,
|
|
|
''::text AS est_dernier_mouvement_jour
|
|
|
FROM w_IDE_MOUVEMENT
|
|
|
LEFT JOIN activite[PX].t_lieux ON
|
|
|
(t_lieux.code_original_1 = MOUV_ID_UNFO_MED::text AND
|
|
|
t_lieux.code_original_2 = TRUM_ID_UNME_principale AND
|
|
|
t_lieux.code_original_4 = MOUV_ID_LIPO AND
|
|
|
t_lieux.code_original_6 = MOUV_ID_UNFO::text )
|
|
|
JOIN w_IDE_SEJOUR_complet ON NO_4D = MOUV_ID_SEJO
|
|
|
JOIN activite[PX].p_sejours ON w_IDE_MOUVEMENT.SEJO_NUM_SEJ = p_sejours.no_sejour AND p_sejours.etat = ''
|
|
|
LEFT JOIN activite[PX].t_lits ON MOUV_ID_LIPO = t_lits.code_original
|
|
|
LEFT JOIN activite[PX].t_unites_fonctionnelles ON MOUV_ID_UNFO::text = t_unites_fonctionnelles.code_original
|
|
|
LEFT JOIN activite[PX].t_services_facturation ON MOUV_ID_UNFO_MED::text = t_services_facturation.code_original
|
|
|
JOIN base.t_dmt ON t_services_facturation.dmt_id = t_dmt.oid
|
|
|
JOIN base.p_calendrier ON p_calendrier.date BETWEEN MOUV_DAT_MOU_DAT AND MOUV_DAT_FIN_DAT AND p_calendrier.date <= date(date_extraction) + interval '1 month'
|
|
|
WHERE --CAGE_CODE <> 'S' AND
|
|
|
--(CAGE_CODE <> 'P' OR CAGE_CODE_next = 'S') AND
|
|
|
(p_sejours.type_sejour NOT IN ('2', '3') OR (p_sejours.type_sejour IN ('2', '3') AND CAGE_CODE = 'E' AND p_calendrier.date = MOUV_DAT_MOU_DAT) OR p_sejours.type_sejour IN ('3')) AND
|
|
|
(p_sejours.code_prevu <> '1' AND p_calendrier.date <= date(date_extraction) OR p_calendrier.date >= date(date_extraction))
|
|
|
ORDER BY sequence, p_calendrier.date;
|
|
|
|
|
|
--DELETE FROM w_mouvements_sejour WHERE heure_fin < heure_debut;
|
|
|
|
|
|
-- Actualisation lieux
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
service_facturation_id = t_services_facturation.oid,
|
|
|
mode_traitement_id = t_services_facturation.mode_traitement_id
|
|
|
FROM activite[PX].t_services_facturation
|
|
|
WHERE
|
|
|
code_original_1 = t_services_facturation.code_original;
|
|
|
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
activite_id = t_activites.oid
|
|
|
FROM activite[PX].t_activites
|
|
|
WHERE
|
|
|
code_original_2 = t_activites.code_original;
|
|
|
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
unite_fonctionnelle_id = t_unites_fonctionnelles.oid
|
|
|
FROM activite[PX].t_unites_fonctionnelles
|
|
|
WHERE
|
|
|
code_original_6 = t_unites_fonctionnelles.code_original;
|
|
|
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
lit_id = t_lits.oid
|
|
|
FROM activite[PX].t_lits
|
|
|
WHERE
|
|
|
code_original_4 = t_lits.code_original;
|
|
|
|
|
|
|
|
|
|
|
|
-- creation nouveaux lieux
|
|
|
|
|
|
INSERT INTO activite[PX].t_lieux(
|
|
|
code_original_1,
|
|
|
code_original_2,
|
|
|
code_original_3,
|
|
|
code_original_4,
|
|
|
code_original_5,
|
|
|
code_original_6,
|
|
|
code_original_7,
|
|
|
service_facturation_id,
|
|
|
activite_id,
|
|
|
lit_id,
|
|
|
unite_medicale_id,
|
|
|
unite_fonctionnelle_id,
|
|
|
mode_traitement_id)
|
|
|
SELECT DISTINCT
|
|
|
MOUV_ID_UNFO_MED,
|
|
|
TRUM_ID_UNME_principale,
|
|
|
'',
|
|
|
MOUV_ID_LIPO,
|
|
|
'',
|
|
|
MOUV_ID_UNFO,
|
|
|
'',
|
|
|
COALESCE(t_services_facturation.oid,0),
|
|
|
COALESCE(t_activites.oid,0),
|
|
|
COALESCE(t_lits.oid,0),
|
|
|
0,
|
|
|
COALESCE(t_unites_fonctionnelles.oid,0),
|
|
|
COALESCE(t_services_facturation.mode_traitement_id,0)
|
|
|
FROM w_mouvements_sejour
|
|
|
LEFT JOIN activite[PX].t_lieux ON
|
|
|
(t_lieux.code_original_1 = MOUV_ID_UNFO_MED::text AND
|
|
|
t_lieux.code_original_2 = TRUM_ID_UNME_principale::text AND
|
|
|
t_lieux.code_original_4 = MOUV_ID_LIPO AND
|
|
|
t_lieux.code_original_6 = MOUV_ID_UNFO::text )
|
|
|
LEFT JOIN activite[PX].t_services_facturation ON MOUV_ID_UNFO_MED::text = t_services_facturation.code_original
|
|
|
LEFT JOIN activite[PX].t_activites ON TRUM_ID_UNME_principale::text = t_activites.code_original
|
|
|
LEFT JOIN activite[PX].t_lits ON MOUV_ID_LIPO = t_lits.code_original
|
|
|
LEFT JOIN activite[PX].t_unites_fonctionnelles ON MOUV_ID_UNFO::text = t_unites_fonctionnelles.code_original
|
|
|
WHERE t_lieux.oid IS NULL;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- Mise à jour lieux dans futurs mouvements
|
|
|
UPDATE w_mouvements_sejour SET lieu_id = t_lieux.oid
|
|
|
FROM activite[PX].t_lieux
|
|
|
WHERE t_lieux.code_original_1 = MOUV_ID_UNFO_MED::text
|
|
|
AND t_lieux.code_original_2 = TRUM_ID_UNME_principale::text
|
|
|
AND t_lieux.code_original_4 = MOUV_ID_LIPO
|
|
|
AND t_lieux.code_original_6 = MOUV_ID_UNFO::text
|
|
|
AND w_mouvements_sejour.lieu_id = 0;
|
|
|
|
|
|
|
|
|
-- Doublons potentiels
|
|
|
DELETE FROM w_mouvements_sejour
|
|
|
USING (
|
|
|
SELECT
|
|
|
no_sejour, date, heure_debut, MAX(CTID) AS fromCTID
|
|
|
FROM w_mouvements_sejour
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING count(*) > 1) subview
|
|
|
WHERE subview.fromCTID = w_mouvements_sejour.CTID;
|
|
|
|
|
|
|
|
|
|
|
|
-- Doublons potentiels
|
|
|
DELETE FROM w_mouvements_sejour
|
|
|
USING (
|
|
|
SELECT
|
|
|
no_sejour, date, heure_debut, MAX(CTID) AS fromCTID
|
|
|
FROM w_mouvements_sejour
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING count(*) > 1) subview
|
|
|
WHERE subview.fromCTID = w_mouvements_sejour.CTID;
|
|
|
|
|
|
|
|
|
-- Doublons potentiels
|
|
|
DELETE FROM w_mouvements_sejour
|
|
|
USING (
|
|
|
SELECT
|
|
|
no_sejour, date, heure_debut, MAX(CTID) AS fromCTID
|
|
|
FROM w_mouvements_sejour
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING count(*) > 1) subview
|
|
|
WHERE subview.fromCTID = w_mouvements_sejour.CTID;
|
|
|
|
|
|
|
|
|
|
|
|
-- Mise en production des mouvements
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_mouvements_sejour_1');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_mouvements_sejour_2');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_mouvements_sejour_3');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_mouvements_sejour_4');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_mouvements_sejour_5');
|
|
|
|
|
|
INSERT INTO activite[PX].p_mouvements_sejour(
|
|
|
sejour_id, no_sejour, date, est_mouvement_previsionnel, 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)
|
|
|
SELECT sejour_id, no_sejour, date, est_mouvement_previsionnel ,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
|
|
|
FROM w_mouvements_sejour
|
|
|
ORDER BY no_sejour, sequence;
|
|
|
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_mouvements_sejour_1');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_mouvements_sejour_2');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_mouvements_sejour_3');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_mouvements_sejour_4');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_mouvements_sejour_5');
|
|
|
|
|
|
-- Lieux de sortie
|
|
|
|
|
|
UPDATE activite[PX].p_sejours SET lieu_sortie_id = p_mouvements_sejour.lieu_id
|
|
|
FROM activite[PX].p_mouvements_sejour
|
|
|
WHERE p_sejours.no_sejour = p_mouvements_sejour.no_sejour
|
|
|
AND p_mouvements_sejour.date = p_sejours.date_sortie
|
|
|
AND (lieu_sortie_id <> p_mouvements_sejour.lieu_id OR lieu_sortie_id IS NULL);
|
|
|
|
|
|
UPDATE activite[PX].p_sejours SET lieu_sortie_id = p_mouvements_sejour.lieu_id
|
|
|
FROM activite[PX].p_mouvements_sejour
|
|
|
WHERE p_sejours.no_sejour = p_mouvements_sejour.no_sejour
|
|
|
AND p_mouvements_sejour.date = p_sejours.date_sortie AND p_mouvements_sejour.nb_sorties_directes = 1
|
|
|
AND (lieu_sortie_id <> p_mouvements_sejour.lieu_id OR lieu_sortie_id IS NULL);
|
|
|
|
|
|
UPDATE activite[PX].p_sejours SET lieu_sortie_id = p_mouvements_sejour.lieu_id
|
|
|
FROM activite[PX].p_mouvements_sejour
|
|
|
WHERE p_sejours.no_sejour = p_mouvements_sejour.no_sejour
|
|
|
AND (p_sejours.lieu_sortie_id = 0 OR lieu_sortie_id IS NULL) ;
|
|
|
|
|
|
UPDATE activite[PX].p_sejours SET lieu_sortie_id = 0
|
|
|
WHERE lieu_sortie_id IS NULL ;
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_sejours SET lieu_sortie_id = 0
|
|
|
WHERE p_sejours.code_prevu = '1' AND (p_sejours.lieu_sortie_id = 0 OR lieu_sortie_id IS NULL);
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_sejours
|
|
|
SET 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();
|
|
|
|
|
|
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
|
|
|
);
|
|
|
|
|
|
|
|
|
-- Problème sur quelques séjours (manque nb entrees)
|
|
|
UPDATE activite[PX].p_mouvements_sejour
|
|
|
SET nb_entrees_directes = 1
|
|
|
WHERE nb_sorties_directes = 1 AND
|
|
|
no_sejour IN (
|
|
|
SELECT p_mouvements_sejour.no_sejour
|
|
|
FROM activite[PX].p_mouvements_sejour
|
|
|
JOIN activite[PX].p_sejours ON p_mouvements_sejour.no_sejour = p_sejours.no_sejour
|
|
|
WHERE type_sejour = '1' AND date_entree = date_sortie
|
|
|
GROUP BY 1
|
|
|
HAVING SUM(nb_entrees_directes) = 0 AND SUM(nb_sorties_directes) > 0
|
|
|
)
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
-- Suppression des tables de travail non utilisées après
|
|
|
-- DROP TABLE IF EXISTS w_IDE_MOUVEMENT;
|
|
|
-- DROP TABLE IF EXISTS w_mouvements_sejour;
|
|
|
-- DROP TABLE IF EXISTS w_seances;
|
|
|
-- DROP TABLE IF EXISTS w_SAD_ACTIVITE_SAISIES_seances;
|
|
|
-- DROP TABLE IF EXISTS w_FAC_LIGNE_FACTURE_seances;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="FACTURE" label="RECUPERATION DES FACTURES">
|
|
|
|
|
|
<NODE label="Entêtes">
|
|
|
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_sejours_orga CASCADE;
|
|
|
CREATE TEMP TABLE w_sejours_orga AS
|
|
|
SELECT no_sejour,
|
|
|
p_sejours.oid AS sejour_id,
|
|
|
p_sejours.code_original,
|
|
|
p_sejours.date_sortie,
|
|
|
p_sejours.ghs_id,
|
|
|
p_sejours.lieu_sortie_id,
|
|
|
p_sejours.tiers_payant_0_id,
|
|
|
p_sejours.tiers_payant_1_id,
|
|
|
p_sejours.tiers_payant_2_id,
|
|
|
p_sejours.tiers_payant_22_id,
|
|
|
t_tiers_payant_1.code_original as tiers_payant_1_orga_id,
|
|
|
t_tiers_payant_2.code_original as tiers_payant_2_orga_id,
|
|
|
t_tiers_payant_22.code_original as tiers_payant_22_orga_id
|
|
|
FROM activite[PX].p_sejours, activite[PX].t_tiers_payant t_tiers_payant_1,
|
|
|
activite[PX].t_tiers_payant t_tiers_payant_2,
|
|
|
activite[PX].t_tiers_payant t_tiers_payant_22
|
|
|
WHERE p_sejours.etat = '' AND
|
|
|
tiers_payant_1_id = t_tiers_payant_1.oid AND
|
|
|
tiers_payant_2_id = t_tiers_payant_2.oid AND
|
|
|
tiers_payant_22_id = t_tiers_payant_22.oid
|
|
|
;
|
|
|
|
|
|
|
|
|
CREATE INDEX w_sejours_orga_i1
|
|
|
ON w_sejours_orga
|
|
|
USING btree
|
|
|
(code_original)
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
-- factures à traiter
|
|
|
|
|
|
-- Informations montants factures et regles
|
|
|
INSERT INTO activite.t_divers(
|
|
|
code,
|
|
|
texte,
|
|
|
valeur,
|
|
|
valeur_date,
|
|
|
description,
|
|
|
show_info_module)
|
|
|
SELECT
|
|
|
'DAI_TRT_COMPTABILISE',
|
|
|
'Traitement champ comptabilisé',
|
|
|
'0',
|
|
|
NULL,
|
|
|
'0=Tout est comptabilise (champ COMPTABILISE FALSE/TRUE non traité, 1=Seul le code TRUE est comptabilisé',
|
|
|
false
|
|
|
WHERE (SELECT count(*) FROM activite.t_divers WHERE code = 'DAI_TRT_COMPTABILISE') = 0
|
|
|
;
|
|
|
|
|
|
-- Notion de COMPTABISEE fause (il y a au moins un règlement)
|
|
|
UPDATE w_FACTURES_615 FACTURES_615
|
|
|
SET COMPTABILISEE = 'true'
|
|
|
WHERE NO_FICHE IN (SELECT FACTURE FROM prod_dai.reglements) AND
|
|
|
COMPTABILISEE = 'false'
|
|
|
;
|
|
|
|
|
|
-- forcer pas comptabilisée si pas de règlement (factures de plus d'un an)
|
|
|
UPDATE w_FACTURES_615 FACTURES_615
|
|
|
SET COMPTABILISEE = 'false'
|
|
|
WHERE NO_FICHE NOT IN (SELECT FACTURE FROM prod_dai.reglements) AND
|
|
|
COMPTABILISEE = 'true' AND
|
|
|
date(CREATION) <= date(now() - interval '1 year')
|
|
|
;
|
|
|
-- COMPTABILISEE = false quand caisse avec un taux de non comptabilisation > 90 %
|
|
|
UPDATE w_FACTURES_615 FACTURES_615
|
|
|
SET COMPTABILISEE= 'false'
|
|
|
FROM
|
|
|
(
|
|
|
SELECT TYPE_DESTINATAI,
|
|
|
CASE WHEN TYPE_DESTINATAI = 1 THEN CAISSE_N WHEN TYPE_DESTINATAI = 2 THEN MUTUELLE ELSE 0 END, CAISSES.NOM,
|
|
|
count(DISTINCT CASE WHEN date(factures_615.CREATION) <= date(now() - interval '1 year') AND comptabilisee = 'true' THEN factures_615.no_fiche ELSE NULL END),
|
|
|
count(DISTINCT CASE WHEN date(factures_615.CREATION) <= date(now() - interval '1 year') AND comptabilisee = 'false' THEN factures_615.no_fiche ELSE NULL END),
|
|
|
count(DISTINCT CASE WHEN date(factures_615.CREATION) <= date(now() - interval '1 year') AND reglements.facture IS NOT NULL THEN factures_615.no_fiche ELSE NULL END),
|
|
|
count(DISTINCT CASE WHEN date(factures_615.CREATION) <= date(now() - interval '1 year') AND reglements.facture IS NULL THEN factures_615.no_fiche ELSE NULL END),
|
|
|
base.cti_array_accum(DISTINCT CASE WHEN date(factures_615.CREATION) > date(now() - interval '1 year') AND COMPTABILISEE = 'true' THEN FACTURES_615.NO_FICHE ELSE NULL END) AS NO_FICHE_array
|
|
|
FROM w_FACTURES_615 FACTURES_615
|
|
|
JOIN prod_dai.PATIENTS ON factures_615.no_patient = patients.no_4d
|
|
|
LEFT JOIN prod_dai.CAISSES ON (CASE WHEN TYPE_DESTINATAI = 1 THEN CAISSE_N WHEN TYPE_DESTINATAI = 2 THEN MUTUELLE ELSE 0 END) = CAISSES.NO_FICHE
|
|
|
LEFT join prod_dai.reglements ON reglements.facture = factures_615.no_fiche
|
|
|
WHERE TYPE_DESTINATAI <> 3
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING
|
|
|
base.cti_division(
|
|
|
count(DISTINCT CASE WHEN date(factures_615.CREATION) <= date(now() - interval '1 year') AND comptabilisee = 'false' THEN factures_615.no_fiche ELSE NULL END),
|
|
|
count(DISTINCT CASE WHEN date(factures_615.CREATION) <= date(now() - interval '1 year') THEN factures_615.no_fiche ELSE NULL END)
|
|
|
) > 0.9 AND
|
|
|
count(DISTINCT CASE WHEN date(factures_615.CREATION) <= date(now() - interval '1 year') THEN factures_615.no_fiche ELSE NULL END) > 0 AND
|
|
|
MAX(CASE WHEN date(factures_615.CREATION) > date(now() - interval '1 year') AND COMPTABILISEE = 'true' THEN FACTURES_615.NO_FICHE ELSE NULL END) > 0
|
|
|
order by 1,2,3
|
|
|
) subview
|
|
|
WHERE FACTURES_615.NO_FICHE = ANY(NO_FICHE_array) AND
|
|
|
NO_FICHE NOT IN (SELECT FACTURE FROM prod_dai.reglements)
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_FAC_FACTURE;
|
|
|
CREATE TEMP TABLE w_FAC_FACTURE AS
|
|
|
SELECT FACTURES_615.*,
|
|
|
w_sejours_orga.*,
|
|
|
TYPE_CLINIQUE,
|
|
|
1 AS CRN_HON_TO_SEJ, --CASE WHEN SEJO_IND_BGH IS NOT DISTINCT FROM '1' OR ETAB_TYP_ETAB = 'PSPH' THEN '1'::text ELSE '0'::text END AS CRN_HON_TO_SEJ,
|
|
|
'0'::text AS FAC_HON,
|
|
|
NO_FICHE::bigint AS FACT_ID_FACT,
|
|
|
date(
|
|
|
COALESCE(
|
|
|
GREATEST(
|
|
|
CASE WHEN REF_FACTURE LIKE to_char(CREATION,'YY.MM') || '.%' THEN CREATION ELSE NULL END,
|
|
|
CASE WHEN REF_FACTURE LIKE to_char(EDITION,'YY.MM') || '.%' THEN EDITION ELSE NULL END,
|
|
|
CASE WHEN REF_FACTURE LIKE to_char(MODIFICATION,'YY.MM') || '.%' THEN MODIFICATION ELSE NULL END,
|
|
|
CASE WHEN REF_FACTURE LIKE to_char(DATE_SOLDE,'YY.MM') || '.%' THEN DATE_SOLDE ELSE NULL END,
|
|
|
CASE WHEN REF_FACTURE LIKE to_char(FIN,'YY.MM') || '.%' THEN FIN ELSE NULL END
|
|
|
)
|
|
|
,
|
|
|
'20991231'::date
|
|
|
)
|
|
|
) AS date_vente,
|
|
|
CASE
|
|
|
WHEN LEFT(REF_FACTURE, 7) = NO_ENTRANT THEN REPLACE(REF_FACTURE,'.','') -- no facture correct
|
|
|
WHEN CHAR_LENGTH(REF_FACTURE) = 9 AND RIGHT(REF_FACTURE, 2) LIKE '0%' THEN NO_ENTRANT || RIGHT(REF_FACTURE,2) -- erreur sur le numero entrant
|
|
|
WHEN REF_FACTURE LIKE to_char(CREATION,'YY.MM') || '.%' THEN REF_FACTURE
|
|
|
WHEN REF_FACTURE LIKE to_char(EDITION,'YY.MM') || '.%' THEN REF_FACTURE
|
|
|
WHEN REF_FACTURE LIKE to_char(MODIFICATION,'YY.MM') || '.%' THEN REF_FACTURE
|
|
|
WHEN REF_FACTURE LIKE to_char(DATE_SOLDE,'YY.MM') || '.%' THEN REF_FACTURE
|
|
|
WHEN REF_FACTURE LIKE to_char(FIN,'YY.MM') || '.%' THEN REF_FACTURE
|
|
|
ELSE w_NO_ENTRANT || TO_CHAR(dense_rank() OVER (PARTITION BY NO_PATIENT, w_NO_ENTRANT ORDER BY DEBUT, FIN, CREATION, EDITION, MODIFICATION),'fm00') END AS FACT_NUM_FAC -- autre : numero automatique
|
|
|
FROM w_FACTURES_615 FACTURES_615
|
|
|
JOIN w_IDE_SEJOUR_complet ON NO_PATIENT = NO_4D
|
|
|
LEFT JOIN prod_dai.PARAMETRES ON 1=1
|
|
|
JOIN w_sejours_orga ON (NO_4D::bigint = w_sejours_orga.code_original)
|
|
|
WHERE DEBUT != '0001-01-01'
|
|
|
;
|
|
|
|
|
|
-- Numéros de factures en double
|
|
|
SELECT base.cti_execute(
|
|
|
'UPDATE w_FAC_FACTURE
|
|
|
SET FACT_NUM_FAC = w_FAC_FACTURE.FACT_NUM_FAC || ''.'' || to_char(nb,''FM990'')
|
|
|
FROM
|
|
|
(
|
|
|
SELECT FACT_NUM_FAC, count(DISTINCT NO_PATIENT) AS nb, MAX(NO_FICHE) AS NO_FICHE
|
|
|
FROM w_FAC_FACTURE
|
|
|
WHERE FACT_NUM_FAC <> ''''
|
|
|
GROUP BY 1
|
|
|
HAVING count(DISTINCT NO_PATIENT) > 1
|
|
|
)
|
|
|
subview
|
|
|
WHERE w_FAC_FACTURE.NO_FICHE = subview.NO_FICHE
|
|
|
',10)
|
|
|
;
|
|
|
|
|
|
-- correction mauvaise date entrée
|
|
|
UPDATE w_FAC_FACTURE
|
|
|
SET EDITION = GREATEST(CREATION,MODIFICATION,FIN)
|
|
|
WHERE EDITION > now();
|
|
|
|
|
|
CREATE INDEX w_FAC_FACTURE_i1
|
|
|
ON w_FAC_FACTURE
|
|
|
USING btree
|
|
|
(NO_FICHE);
|
|
|
|
|
|
--
|
|
|
|
|
|
DROP TABLE IF EXISTS w_FAC_MONTANTS;
|
|
|
CREATE TEMP TABLE w_FAC_MONTANTS AS
|
|
|
SELECT
|
|
|
FACT_ID_FACT AS FACD_ID_FACT,
|
|
|
|
|
|
SUM(TOTAL_FACTURE) AS montant_facture_c,
|
|
|
SUM(CASE WHEN TYPE_DESTINATAI = 3 THEN TOTAL_FACTURE ELSE 0 END) AS montant_facture_0_c,
|
|
|
SUM(CASE WHEN TYPE_DESTINATAI = 1 THEN TOTAL_FACTURE ELSE 0 END) AS montant_facture_1_c,
|
|
|
SUM(CASE WHEN TYPE_DESTINATAI = 2 THEN TOTAL_FACTURE ELSE 0 END) AS montant_facture_2_c,
|
|
|
0 AS montant_facture_22_c,
|
|
|
|
|
|
SUM(CASE WHEN t_divers.valeur <> '1' OR COMPTABILISEE ILIKE 'true' THEN TOTAL_FACTURE ELSE 0 END) AS montant_comptabilise_c, -- colonne comptabilise true/false toujours à false donc on force
|
|
|
SUM(CASE WHEN (t_divers.valeur <> '1' OR COMPTABILISEE ILIKE 'true') AND TYPE_DESTINATAI = 3 THEN TOTAL_FACTURE ELSE 0 END) AS montant_comptabilise_0_c,
|
|
|
SUM(CASE WHEN (t_divers.valeur <> '1' OR COMPTABILISEE ILIKE 'true') AND TYPE_DESTINATAI = 1 THEN TOTAL_FACTURE ELSE 0 END) AS montant_comptabilise_1_c,
|
|
|
SUM(CASE WHEN (t_divers.valeur <> '1' OR COMPTABILISEE ILIKE 'true') AND TYPE_DESTINATAI = 2 THEN TOTAL_FACTURE ELSE 0 END) AS montant_comptabilise_2_c,
|
|
|
0 AS montant_comptabilise_22_c,
|
|
|
|
|
|
SUM(CASE WHEN t_divers.valeur <> '1' OR COMPTABILISEE ILIKE 'true' THEN TOTAL_FACTURE - SOLDE_FACTURE ELSE 0 END) AS montant_regle_c,
|
|
|
SUM(CASE WHEN (t_divers.valeur <> '1' OR COMPTABILISEE ILIKE 'true') AND TYPE_DESTINATAI = 3 THEN TOTAL_FACTURE - SOLDE_FACTURE ELSE 0 END) AS montant_regle_0_c,
|
|
|
SUM(CASE WHEN (t_divers.valeur <> '1' OR COMPTABILISEE ILIKE 'true') AND TYPE_DESTINATAI = 1 THEN TOTAL_FACTURE - SOLDE_FACTURE ELSE 0 END) AS montant_regle_1_c,
|
|
|
SUM(CASE WHEN (t_divers.valeur <> '1' OR COMPTABILISEE ILIKE 'true') AND TYPE_DESTINATAI = 2 THEN TOTAL_FACTURE - SOLDE_FACTURE ELSE 0 END) AS montant_regle_2_c,
|
|
|
0 AS montant_regle_22_c,
|
|
|
|
|
|
-- tables hono fact et hono_transmis vides
|
|
|
0 AS montant_facture_h,
|
|
|
0 AS montant_facture_0_h,
|
|
|
0 AS montant_facture_1_h,
|
|
|
0 AS montant_facture_2_h,
|
|
|
0 AS montant_facture_22_h,
|
|
|
|
|
|
0 AS montant_comptabilise_h,
|
|
|
0 AS montant_comptabilise_0_h,
|
|
|
0 AS montant_comptabilise_1_h,
|
|
|
0 AS montant_comptabilise_2_h,
|
|
|
0 AS montant_comptabilise_22_h,
|
|
|
|
|
|
0 AS montant_regle_h,
|
|
|
0 AS montant_regle_0_h,
|
|
|
0 AS montant_regle_1_h,
|
|
|
0 AS montant_regle_2_h,
|
|
|
0 AS montant_regle_22_h
|
|
|
|
|
|
FROM w_FAC_FACTURE
|
|
|
JOIN activite.t_divers ON t_divers.code = 'DAI_TRT_COMPTABILISE'
|
|
|
GROUP BY FACD_ID_FACT;
|
|
|
|
|
|
|
|
|
CREATE INDEX w_FAC_MONTANTS_i1
|
|
|
ON w_FAC_MONTANTS
|
|
|
USING btree
|
|
|
(FACD_ID_FACT);
|
|
|
|
|
|
|
|
|
-- Informations date dernier reglement
|
|
|
|
|
|
DROP TABLE IF EXISTS w_FAC_REGLEMENT;
|
|
|
CREATE TEMP TABLE w_FAC_REGLEMENT AS
|
|
|
SELECT
|
|
|
FACT_ID_FACT AS LECR_ID_FACT,
|
|
|
MAX(CASE WHEN TYPE_DESTINATAI = 3 THEN REGLEMENTS.RECEPTION ELSE NULL END) AS date_dernier_reglement_0_c,
|
|
|
MAX(CASE WHEN TYPE_DESTINATAI = 1 THEN REGLEMENTS.RECEPTION ELSE NULL END) AS date_dernier_reglement_1_c,
|
|
|
MAX(CASE WHEN TYPE_DESTINATAI = 2 THEN REGLEMENTS.RECEPTION ELSE NULL END) AS date_dernier_reglement_2_c,
|
|
|
'20991231'::date AS date_dernier_reglement_22_c,
|
|
|
'20991231'::date AS date_dernier_reglement_0_h,
|
|
|
'20991231'::date AS date_dernier_reglement_1_h,
|
|
|
'20991231'::date AS date_dernier_reglement_2_h,
|
|
|
'20991231'::date AS date_dernier_reglement_22_h,
|
|
|
count(DISTINCT date_part('month',REGLEMENTS.RECEPTION)) AS nb_mois_reglement
|
|
|
FROM prod_dai.REGLEMENTS
|
|
|
JOIN w_FAC_FACTURE ON REGLEMENTS.FACTURE = w_FAC_FACTURE.FACT_ID_FACT
|
|
|
GROUP BY 1;
|
|
|
|
|
|
CREATE INDEX w_FAC_REGLEMENT_i1
|
|
|
ON w_FAC_REGLEMENT
|
|
|
USING btree
|
|
|
(LECR_ID_FACT);
|
|
|
|
|
|
|
|
|
-- Informations date vente
|
|
|
INSERT INTO activite.t_divers(
|
|
|
code,
|
|
|
texte,
|
|
|
valeur,
|
|
|
valeur_date,
|
|
|
description,
|
|
|
show_info_module)
|
|
|
SELECT
|
|
|
'FORCE_DATE_FAC',
|
|
|
'Force la date de vente à la date de sortie',
|
|
|
0,
|
|
|
NULL,
|
|
|
'Force la date de vente à la date de sortie',
|
|
|
true
|
|
|
WHERE (SELECT count(*) FROM activite.t_divers WHERE code = 'FORCE_DATE_FAC') = 0
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_FAC_DATEVENTE;
|
|
|
CREATE TEMP TABLE w_FAC_DATEVENTE AS
|
|
|
SELECT
|
|
|
FACT_ID_FACT AS LECR_ID_FACT_VENT,
|
|
|
CASE WHEN valeur = 1 AND MAX(w_FAC_FACTURE.FIN) < now() THEN MAX(w_FAC_FACTURE.FIN) ELSE CASE WHEN MAX(GREATEST(CREATION,EDITION,MODIFICATION,FIN)) < now() THEN MAX(GREATEST(CREATION,EDITION,MODIFICATION,FIN)) ELSE NULL END END AS date_vente
|
|
|
FROM w_FAC_FACTURE
|
|
|
JOIN (SELECT valeur FROM activite.t_divers WHERE code = 'FORCE_DATE_FAC') sub ON 1=1
|
|
|
GROUP BY 1, valeur;
|
|
|
|
|
|
CREATE INDEX w_FAC_DATEVENTE_i1
|
|
|
ON w_FAC_DATEVENTE
|
|
|
USING btree
|
|
|
(LECR_ID_FACT_VENT);
|
|
|
|
|
|
UPDATE w_FAC_FACTURE
|
|
|
SET date_vente = w_FAC_DATEVENTE.date_vente
|
|
|
FROM w_FAC_DATEVENTE
|
|
|
WHERE LECR_ID_FACT_VENT = FACT_ID_FACT AND
|
|
|
w_FAC_DATEVENTE.date_vente IS NOT NULL
|
|
|
;
|
|
|
|
|
|
UPDATE w_FAC_FACTURE
|
|
|
SET COMPTABILISEE = 'false'
|
|
|
WHERE date(date_vente) >= date(now())
|
|
|
;
|
|
|
|
|
|
-- Informations expedition
|
|
|
|
|
|
DROP TABLE IF EXISTS w_FAC_BORDEREAU;
|
|
|
CREATE TEMP TABLE w_FAC_BORDEREAU AS
|
|
|
SELECT FACT_ID_FACT AS LBOR_ID_FACT,
|
|
|
'0'::text AS code_expedie_0,
|
|
|
MAX(CASE WHEN BORDEREAU > 0 THEN '1' ELSE '0' END) AS code_expedie_1,
|
|
|
'0' AS code_expedie_2,
|
|
|
'0' AS code_expedie_22,
|
|
|
''::text AS no_bordereau_0,
|
|
|
MAX(CASE WHEN BORDEREAU > 0 THEN LOT ELSE '0' END) AS no_bordereau_1,
|
|
|
'0' AS no_bordereau_2,
|
|
|
'0' AS no_bordereau_22,
|
|
|
'20991231'::date AS date_expedition_0,
|
|
|
MIN(CASE WHEN BORDEREAU > 0 THEN GREATEST(DATE_ENVOI) ELSE '20991231'::date END) AS date_expedition_1,
|
|
|
'20991231'::date AS date_expedition_2,
|
|
|
'20991231'::date AS date_expedition_22
|
|
|
FROM prod_dai.BORDEREAUX, w_FAC_FACTURE
|
|
|
WHERE BORDEREAU = BORDEREAUX.NO_FICHE
|
|
|
GROUP BY 1;
|
|
|
|
|
|
CREATE INDEX w_FAC_BORDEREAU_i1
|
|
|
ON w_FAC_BORDEREAU
|
|
|
USING btree
|
|
|
(LBOR_ID_FACT);
|
|
|
|
|
|
-- Informations rejets
|
|
|
--
|
|
|
-- DROP TABLE IF EXISTS w_FAC_REJET;
|
|
|
-- CREATE TEMP TABLE w_FAC_REJET AS
|
|
|
-- SELECT NOER_ID_FACT::bigint,
|
|
|
-- COUNT(*) as nb_rejets
|
|
|
-- FROM prod_dai.CCL_NOEMIE_REJET, w_FAC_FACTURE
|
|
|
-- WHERE NOER_ID_FACT = FACT_ID_FACT AND TRIM(NOER_CDF_REJET) <> '0001'
|
|
|
-- GROUP BY NOER_ID_FACT;
|
|
|
--
|
|
|
-- CREATE INDEX w_FAC_REJET_i1
|
|
|
-- ON w_FAC_REJET
|
|
|
-- USING btree
|
|
|
-- (NOER_ID_FACT);
|
|
|
--
|
|
|
|
|
|
-- 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(
|
|
|
sejour_id,
|
|
|
no_sejour,
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
type_facture,
|
|
|
code_facture,
|
|
|
date_facture,
|
|
|
code_vente,
|
|
|
date_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_0_id,
|
|
|
tiers_payant_1_id,
|
|
|
tiers_payant_2_id,
|
|
|
tiers_payant_22_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,
|
|
|
code_cloture,
|
|
|
code_cp_demandee,
|
|
|
ghs_bebe1_id,
|
|
|
ghs_bebe2_id,
|
|
|
ghs_bebe3_id,
|
|
|
|
|
|
montant_comptabilise_c,
|
|
|
montant_comptabilise_h,
|
|
|
montant_comptabilise_0_c,
|
|
|
montant_comptabilise_0_h,
|
|
|
montant_comptabilise_1_c,
|
|
|
montant_comptabilise_1_h,
|
|
|
montant_comptabilise_2_c,
|
|
|
montant_comptabilise_2_h,
|
|
|
montant_comptabilise_22_c,
|
|
|
montant_comptabilise_22_h,
|
|
|
|
|
|
nb_rejets,
|
|
|
|
|
|
montant_facture_c_actes_inclus_dans_sejour,
|
|
|
montant_facture_h_actes_inclus_dans_sejour
|
|
|
)
|
|
|
SELECT
|
|
|
sejour_id,
|
|
|
no_sejour,
|
|
|
FACT_NUM_FAC AS no_facture,
|
|
|
MIN(DEBUT) AS date_debut,
|
|
|
MAX(FIN) AS date_fin,
|
|
|
CASE
|
|
|
WHEN MAX(FIN) > now() THEN 'E'
|
|
|
WHEN no_sejour LIKE 'W%' THEN 'E'
|
|
|
WHEN MAX(AVOIR_FACTURE) IS NOT NULL THEN '0'
|
|
|
ELSE '1' END AS type_facture,
|
|
|
CASE
|
|
|
WHEN MAX(FIN) > now() THEN '0'
|
|
|
WHEN no_sejour LIKE 'W%' THEN '0'
|
|
|
ELSE '1' END AS code_facture,
|
|
|
CASE WHEN MAX(w_FAC_FACTURE.date_vente) IS NOT NULL THEN MAX(w_FAC_FACTURE.date_vente) ELSE GREATEST(MAX(CREATION), MAX(EDITION)) END AS date_facture,
|
|
|
CASE WHEN MAX(w_FAC_FACTURE.date_vente) IS NOT NULL THEN '1' ELSE '0' END AS code_vente,
|
|
|
CASE WHEN MAX(w_FAC_FACTURE.date_vente) IS NOT NULL THEN MAX(w_FAC_FACTURE.date_vente) ELSE '20991231'::date END AS date_vente,
|
|
|
CASE WHEN MAX(w_FAC_FACTURE.date_vente) IS NOT NULL THEN extract('year' FROM MAX(w_FAC_FACTURE.date_vente)) * 100 + extract('month' FROM MAX(w_FAC_FACTURE.date_vente)) ELSE extract('year' FROM '20991231'::date) * 100 + extract('month' FROM '20991231'::date) END AS mois_vente,
|
|
|
|
|
|
COALESCE(
|
|
|
GREATEST(
|
|
|
CASE
|
|
|
WHEN SUM(w_FAC_MONTANTS.montant_comptabilise_0_c) = 0 THEN MAX(FIN) ELSE MAX(date_dernier_reglement_0_c) END,
|
|
|
CASE
|
|
|
WHEN SUM(w_FAC_MONTANTS.montant_comptabilise_0_h) = 0 THEN MAX(FIN) ELSE MAX(date_dernier_reglement_0_h) END,
|
|
|
CASE
|
|
|
WHEN SUM(w_FAC_MONTANTS.montant_comptabilise_1_c) = 0 THEN MAX(FIN) ELSE MAX(date_dernier_reglement_1_c) END,
|
|
|
CASE
|
|
|
WHEN SUM(w_FAC_MONTANTS.montant_comptabilise_1_h) = 0 THEN MAX(FIN) ELSE MAX(date_dernier_reglement_1_h) END,
|
|
|
CASE
|
|
|
WHEN SUM(w_FAC_MONTANTS.montant_comptabilise_2_c) = 0 THEN MAX(FIN) ELSE MAX(date_dernier_reglement_2_c) END,
|
|
|
CASE
|
|
|
WHEN SUM(w_FAC_MONTANTS.montant_comptabilise_2_h) = 0 THEN MAX(FIN) ELSE MAX(date_dernier_reglement_2_h) END,
|
|
|
CASE
|
|
|
WHEN SUM(w_FAC_MONTANTS.montant_comptabilise_22_c) = 0 THEN MAX(FIN) ELSE MAX(date_dernier_reglement_22_c) END,
|
|
|
CASE
|
|
|
WHEN SUM(w_FAC_MONTANTS.montant_comptabilise_22_h) = 0 THEN MAX(FIN) ELSE MAX(date_dernier_reglement_22_h) END)
|
|
|
, '20991231') as date_solde,
|
|
|
|
|
|
|
|
|
SUM(w_FAC_MONTANTS.montant_facture_c) AS montant_facture_c,
|
|
|
SUM(w_FAC_MONTANTS.montant_facture_h) AS montant_facture_h,
|
|
|
SUM(w_FAC_MONTANTS.montant_regle_c) AS montant_regle_c,
|
|
|
SUM(w_FAC_MONTANTS.montant_regle_h) AS montant_regle_h,
|
|
|
GREATEST(0,DATE(GREATEST(MAX(CREATION),MAX(EDITION))) - DATE(MAX(FIN))) as delai_facture,
|
|
|
0 as delai_solde,
|
|
|
LEAST(MIN(w_FAC_BORDEREAU.date_expedition_1), MIN(w_FAC_BORDEREAU.date_expedition_2)) as date_expedition,
|
|
|
0 as delai_expedition,
|
|
|
MAX(tiers_payant_0_id),
|
|
|
MAX(tiers_payant_1_id),
|
|
|
MAX(tiers_payant_2_id),
|
|
|
MAX(tiers_payant_22_id),
|
|
|
CASE
|
|
|
WHEN SUM(w_FAC_MONTANTS.montant_comptabilise_0_c) = 0 THEN MAX(FIN)
|
|
|
WHEN MAX(date_dernier_reglement_0_c) IS NOT NULL THEN MAX(date_dernier_reglement_0_c) ELSE '20991231' END as date_solde_0_c,
|
|
|
CASE
|
|
|
WHEN SUM(w_FAC_MONTANTS.montant_comptabilise_0_h) = 0 THEN MAX(FIN)
|
|
|
WHEN MAX(date_dernier_reglement_0_h) IS NOT NULL THEN MAX(date_dernier_reglement_0_h) ELSE '20991231' END as date_solde_0_h,
|
|
|
CASE
|
|
|
WHEN SUM(w_FAC_MONTANTS.montant_comptabilise_1_c) = 0 THEN MAX(FIN)
|
|
|
WHEN MAX(date_dernier_reglement_1_c) IS NOT NULL THEN MAX(date_dernier_reglement_1_c) ELSE '20991231' END as date_solde_1_c,
|
|
|
CASE
|
|
|
WHEN SUM(w_FAC_MONTANTS.montant_comptabilise_1_h) = 0 THEN MAX(FIN)
|
|
|
WHEN MAX(date_dernier_reglement_1_h) IS NOT NULL THEN MAX(date_dernier_reglement_1_h) ELSE '20991231' END as date_solde_1_h,
|
|
|
CASE
|
|
|
WHEN SUM(w_FAC_MONTANTS.montant_comptabilise_2_c) = 0 THEN MAX(FIN)
|
|
|
WHEN MAX(date_dernier_reglement_2_c) IS NOT NULL THEN MAX(date_dernier_reglement_2_c) ELSE '20991231' END as date_solde_2_c,
|
|
|
CASE
|
|
|
WHEN SUM(w_FAC_MONTANTS.montant_comptabilise_2_h) = 0 THEN MAX(FIN)
|
|
|
WHEN MAX(date_dernier_reglement_2_h) IS NOT NULL THEN MAX(date_dernier_reglement_2_h) ELSE '20991231' END as date_solde_2_h,
|
|
|
CASE
|
|
|
WHEN SUM(w_FAC_MONTANTS.montant_comptabilise_22_c) = 0 THEN MAX(FIN)
|
|
|
WHEN MAX(date_dernier_reglement_22_c) IS NOT NULL THEN MAX(date_dernier_reglement_22_c) ELSE '20991231' END as date_solde_22_c,
|
|
|
CASE
|
|
|
WHEN SUM(w_FAC_MONTANTS.montant_comptabilise_22_h) = 0 THEN MAX(FIN)
|
|
|
WHEN MAX(date_dernier_reglement_22_h) IS NOT NULL THEN MAX(date_dernier_reglement_22_h) ELSE '20991231' END as date_solde_22_h,
|
|
|
|
|
|
MAX(w_FAC_BORDEREAU.date_expedition_0),
|
|
|
MAX(w_FAC_BORDEREAU.date_expedition_1),
|
|
|
MAX(w_FAC_BORDEREAU.date_expedition_2),
|
|
|
MAX(w_FAC_BORDEREAU.date_expedition_22),
|
|
|
MAX(w_FAC_BORDEREAU.code_expedie_0),
|
|
|
MAX(w_FAC_BORDEREAU.code_expedie_1),
|
|
|
MAX(w_FAC_BORDEREAU.code_expedie_2),
|
|
|
MAX(w_FAC_BORDEREAU.code_expedie_22),
|
|
|
MAX(w_FAC_BORDEREAU.no_bordereau_0),
|
|
|
MAX(w_FAC_BORDEREAU.no_bordereau_1),
|
|
|
MAX(w_FAC_BORDEREAU.no_bordereau_2),
|
|
|
MAX(w_FAC_BORDEREAU.no_bordereau_22),
|
|
|
|
|
|
SUM(w_FAC_MONTANTS.montant_facture_0_c)AS montant_facture_0_c,
|
|
|
SUM(w_FAC_MONTANTS.montant_facture_0_h) AS montant_facture_0_h,
|
|
|
SUM(w_FAC_MONTANTS.montant_facture_1_c) AS montant_facture_1_c,
|
|
|
SUM(w_FAC_MONTANTS.montant_facture_1_h) AS montant_facture_1_h,
|
|
|
SUM(w_FAC_MONTANTS.montant_facture_2_c) AS montant_facture_2_c,
|
|
|
SUM(w_FAC_MONTANTS.montant_facture_2_h) AS montant_facture_2_h,
|
|
|
SUM(w_FAC_MONTANTS.montant_facture_22_c) AS montant_facture_22_c,
|
|
|
SUM(w_FAC_MONTANTS.montant_facture_22_h) AS montant_facture_22_h,
|
|
|
|
|
|
SUM(w_FAC_MONTANTS.montant_regle_0_c) AS montant_regle_0_c,
|
|
|
SUM(w_FAC_MONTANTS.montant_regle_0_h) AS montant_regle_0_h,
|
|
|
SUM(w_FAC_MONTANTS.montant_regle_1_c) AS montant_regle_1_c,
|
|
|
SUM(w_FAC_MONTANTS.montant_regle_1_h) AS montant_regle_1_h,
|
|
|
SUM(w_FAC_MONTANTS.montant_regle_2_c) AS montant_regle_2_c,
|
|
|
SUM(w_FAC_MONTANTS.montant_regle_2_h) AS montant_regle_2_h,
|
|
|
SUM(w_FAC_MONTANTS.montant_regle_22_c) AS montant_regle_22_c,
|
|
|
SUM(w_FAC_MONTANTS.montant_regle_22_h) AS montant_regle_22_h,
|
|
|
|
|
|
|
|
|
0 AS delai_expedition_0,
|
|
|
0 AS delai_expedition_1,
|
|
|
0 AS delai_expedition_2,
|
|
|
0 AS delai_expedition_22,
|
|
|
0 AS delai_solde_0_c,
|
|
|
0 AS delai_solde_0_h,
|
|
|
0 AS delai_solde_1_c,
|
|
|
0 AS delai_solde_1_h,
|
|
|
0 AS delai_solde_2_c,
|
|
|
0 AS delai_solde_2_h,
|
|
|
0 AS delai_solde_22_c,
|
|
|
0 AS delai_solde_22_h,
|
|
|
|
|
|
0,
|
|
|
'' as particularite_t2a,
|
|
|
|
|
|
'0' as code_cloture,
|
|
|
'0' as code_cp_demandee,
|
|
|
0 AS ghs_bebe1_id,
|
|
|
0 AS ghs_bebe2_id,
|
|
|
0 AS ghs_bebe3_id,
|
|
|
|
|
|
SUM(w_FAC_MONTANTS.montant_comptabilise_c),
|
|
|
SUM(w_FAC_MONTANTS.montant_comptabilise_h),
|
|
|
SUM(w_FAC_MONTANTS.montant_comptabilise_0_c),
|
|
|
SUM(w_FAC_MONTANTS.montant_comptabilise_0_h),
|
|
|
SUM(w_FAC_MONTANTS.montant_comptabilise_1_c),
|
|
|
SUM(w_FAC_MONTANTS.montant_comptabilise_1_h),
|
|
|
SUM(w_FAC_MONTANTS.montant_comptabilise_2_c),
|
|
|
SUM(w_FAC_MONTANTS.montant_comptabilise_2_h),
|
|
|
SUM(w_FAC_MONTANTS.montant_comptabilise_22_c),
|
|
|
SUM(w_FAC_MONTANTS.montant_comptabilise_22_h),
|
|
|
|
|
|
0,
|
|
|
|
|
|
0,
|
|
|
0
|
|
|
|
|
|
|
|
|
FROM w_FAC_FACTURE
|
|
|
LEFT JOIN w_FAC_BORDEREAU ON (LBOR_ID_FACT = FACT_ID_FACT)
|
|
|
LEFT JOIN w_FAC_MONTANTS ON (FACD_ID_FACT = FACT_ID_FACT)
|
|
|
LEFT JOIN w_FAC_REGLEMENT ON (LECR_ID_FACT = FACT_ID_FACT)
|
|
|
-- LEFT JOIN w_FAC_REJET ON (NOER_ID_FACT = FACT_ID_FACT)
|
|
|
GROUP BY 1,2,3,date_sortie
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_3');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_4');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_5');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_6');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_7');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_8');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_9');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_10');
|
|
|
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');
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- 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,
|
|
|
p_sejours.ghs_id,
|
|
|
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,
|
|
|
CASE WHEN code_sorti = '1' THEN date_sortie ELSE date(now()) END AS date_fin_encours,
|
|
|
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
|
|
|
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%' AND type_facture IS DISTINCT FROM 'P'
|
|
|
JOIN activite[PX].t_lieux ON lieu_sortie_id = t_lieux.oid
|
|
|
JOIN activite[PX].t_services_facturation ON t_lieux.service_facturation_id = t_services_facturation.oid
|
|
|
WHERE p_sejours.etat = '' AND p_sejours.est_sans_facturation IS DISTINCT FROM '1' AND date_entree <= now() AND p_sejours.type_sejour <> '6' AND p_sejours.type_sejour <> '9'
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures(
|
|
|
finess,
|
|
|
no_sejour,
|
|
|
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,
|
|
|
ghs_id,
|
|
|
date_debut,
|
|
|
date_fin)
|
|
|
SELECT finess,
|
|
|
no_sejour,
|
|
|
'E' || no_sejour || CASE WHEN avec_facturation_intermediaire = '1' THEN '_' || substr(p_calendrier.mois,3,4) ELSE '' END,
|
|
|
'E' || no_sejour || CASE WHEN avec_facturation_intermediaire = '1' THEN '_' || substr(p_calendrier.mois,3,4) 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 ,
|
|
|
ghs_id,
|
|
|
MIN(GREATEST(date_debut_encours, p_calendrier.date)),
|
|
|
MAX(LEAST(date_fin_encours, p_calendrier.date))
|
|
|
FROM w_factures_trous
|
|
|
JOIN base.p_calendrier ON p_calendrier.date BETWEEN date_debut_encours AND date_fin_encours
|
|
|
WHERE (date_debut_encours <= date_fin_encours or date_fin_facture is null)
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13;
|
|
|
|
|
|
|
|
|
|
|
|
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
|
|
|
);
|
|
|
|
|
|
|
|
|
-- Avoirs qui annulent des factures
|
|
|
UPDATE activite[PX].p_factures SET no_facture_od_avoir = REF_FACTURE
|
|
|
FROM w_FAC_FACTURE
|
|
|
WHERE p_factures.no_facture = regexp_replace(NOTES,'[^0-9]*([0-9\.]+)','\1')
|
|
|
AND AVOIR_FACTURE = 'true'
|
|
|
AND no_facture_od_avoir IS DISTINCT FROM REF_FACTURE;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ods_avoir;
|
|
|
CREATE TEMP TABLE w_ods_avoir AS
|
|
|
|
|
|
SELECT p_factures.no_facture, p_factures.no_facture_od_avoir, p_factures_avoir.date_facture AS date_od_avoir,
|
|
|
SUM(p_factures.montant_comptabilise_c + p_factures.montant_comptabilise_h) AS montant_comptabilise,
|
|
|
SUM(p_factures.montant_regle_c + p_factures.montant_regle_h) AS montant_regle,
|
|
|
SUM(p_factures_avoir.montant_comptabilise_c + p_factures_avoir.montant_comptabilise_h) AS montant_facture_avoir,
|
|
|
SUM(p_factures_avoir.montant_regle_c + p_factures_avoir.montant_regle_h) AS montant_regle_avoir
|
|
|
FROM activite[PX].p_factures JOIN activite[PX].p_factures p_factures_avoir ON p_factures.no_facture = p_factures_avoir.no_facture_od_avoir
|
|
|
WHERE p_factures.type_facture = 'X' AND p_factures_avoir.type_facture = '1'
|
|
|
GROUP BY 1,2,3
|
|
|
HAVING SUM(p_factures.montant_comptabilise_c + p_factures.montant_comptabilise_h) = 0 - SUM(p_factures_avoir.montant_comptabilise_c + p_factures_avoir.montant_comptabilise_h)
|
|
|
AND SUM(p_factures.montant_regle_c + p_factures.montant_regle_h) = 0
|
|
|
AND SUM(p_factures_avoir.montant_regle_c + p_factures_avoir.montant_regle_h) = 0;
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures SET
|
|
|
date_solde_c = date_od_avoir,
|
|
|
date_solde_0_c = date_od_avoir,
|
|
|
date_solde_1_c = date_od_avoir,
|
|
|
date_solde_2_c = date_od_avoir,
|
|
|
date_solde_22_c = date_od_avoir,
|
|
|
date_solde_h = date_od_avoir,
|
|
|
date_solde_0_h = date_od_avoir,
|
|
|
date_solde_1_h = date_od_avoir,
|
|
|
date_solde_2_h = date_od_avoir,
|
|
|
date_solde_22_h = date_od_avoir,
|
|
|
montant_regle_c = montant_comptabilise_c,
|
|
|
montant_regle_0_c = montant_comptabilise_0_c,
|
|
|
montant_regle_1_c = montant_comptabilise_1_c,
|
|
|
montant_regle_2_c = montant_comptabilise_2_c,
|
|
|
montant_regle_22_c = montant_comptabilise_22_c,
|
|
|
montant_regle_h = montant_comptabilise_h,
|
|
|
montant_regle_0_h = montant_comptabilise_0_h,
|
|
|
montant_regle_1_h = montant_comptabilise_1_h,
|
|
|
montant_regle_2_h = montant_comptabilise_2_h,
|
|
|
montant_regle_22_h = montant_comptabilise_22_h
|
|
|
FROM w_ods_avoir
|
|
|
WHERE p_factures.no_facture = w_ods_avoir.no_facture;
|
|
|
|
|
|
UPDATE activite[PX].p_factures SET
|
|
|
date_solde_c = date_od_avoir,
|
|
|
date_solde_0_c = date_od_avoir,
|
|
|
date_solde_1_c = date_od_avoir,
|
|
|
date_solde_2_c = date_od_avoir,
|
|
|
date_solde_22_c = date_od_avoir,
|
|
|
date_solde_h = date_od_avoir,
|
|
|
date_solde_0_h = date_od_avoir,
|
|
|
date_solde_1_h = date_od_avoir,
|
|
|
date_solde_2_h = date_od_avoir,
|
|
|
date_solde_22_h = date_od_avoir,
|
|
|
montant_regle_c = montant_comptabilise_c,
|
|
|
montant_regle_0_c = montant_comptabilise_0_c,
|
|
|
montant_regle_1_c = montant_comptabilise_1_c,
|
|
|
montant_regle_2_c = montant_comptabilise_2_c,
|
|
|
montant_regle_22_c = montant_comptabilise_22_c,
|
|
|
montant_regle_h = montant_comptabilise_h,
|
|
|
montant_regle_0_h = montant_comptabilise_0_h,
|
|
|
montant_regle_1_h = montant_comptabilise_1_h,
|
|
|
montant_regle_2_h = montant_comptabilise_2_h,
|
|
|
montant_regle_22_h = montant_comptabilise_22_h
|
|
|
FROM w_ods_avoir
|
|
|
WHERE p_factures.no_facture = w_ods_avoir.no_facture_od_avoir;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Rejets">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- INSERT INTO activite[PX].p_factures_rejets(
|
|
|
-- no_facture, date_rejet, rejet_id, rejet_code, rejet_texte)
|
|
|
-- SELECT
|
|
|
-- FACT_NUM_FAC ,
|
|
|
-- date(NOER_DAT_CRE) ,
|
|
|
-- 0,
|
|
|
-- TRIM(NOER_CDF_REJET) ,
|
|
|
-- TRIM(NOER_LIB_REJET)
|
|
|
-- FROM prod_dai.CCL_NOEMIE_REJET, w_FAC_FACTURE
|
|
|
-- WHERE NOER_ID_FACT = FACT_ID_FACT
|
|
|
-- AND TRIM(NOER_CDF_REJET) <> '0001' AND TRIM(NOER_LIB_REJET) <> '';
|
|
|
--
|
|
|
-- INSERT INTO activite.t_rejets_noemie (texte, code)
|
|
|
-- SELECT rejet_texte, MAX(rejet_code)
|
|
|
-- FROM activite[PX].p_factures_rejets
|
|
|
-- LEFT JOIN activite.t_rejets_noemie ON (rejet_texte = t_rejets_noemie.texte)
|
|
|
-- WHERE t_rejets_noemie.oid IS NULL
|
|
|
-- GROUP BY 1;
|
|
|
--
|
|
|
-- UPDATE activite[PX].p_factures_rejets
|
|
|
-- SET rejet_id = t_rejets_noemie.oid
|
|
|
-- FROM activite.t_rejets_noemie
|
|
|
-- WHERE rejet_texte = t_rejets_noemie.texte;
|
|
|
--
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Lignes non facturées Clinique">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_FAC_LIGNES;
|
|
|
CREATE TEMP TABLE w_FAC_LIGNES AS
|
|
|
SELECT
|
|
|
NO_FICHE,
|
|
|
ACTE,
|
|
|
DEBUT,
|
|
|
FIN,
|
|
|
QTE,
|
|
|
PRIX_UNIT,
|
|
|
MONTANT,
|
|
|
MONTANT_CAISSE,
|
|
|
POURC_CAISSE,
|
|
|
CASE WHEN FACTURE_CAISSE = FACTURE_MUT THEN MONTANT_MUT ELSE 0 END AS MONTANT_MUT,
|
|
|
CASE WHEN FACTURE_CAISSE = FACTURE_MUT THEN POURC_MUT ELSE 0 END AS POURC_MUT,
|
|
|
CASE WHEN FACTURE_CAISSE = FACTURE_ASSURE THEN MONTANT_ASSURE ELSE 0 END AS MONTANT_ASSURE,
|
|
|
CASE WHEN FACTURE_CAISSE = FACTURE_ASSURE THEN POURC_ASS ELSE 0 END AS POURC_ASS,
|
|
|
FACTURE_CAISSE as LFAC_ID_FAC
|
|
|
FROM prod_dai.LIGNE_FACT
|
|
|
WHERE
|
|
|
FACTURE_CAISSE != 0
|
|
|
-- AND FACTUREE_CAISSE = 'true'
|
|
|
;
|
|
|
|
|
|
INSERT INTO w_FAC_LIGNES
|
|
|
SELECT
|
|
|
NO_FICHE,
|
|
|
ACTE,
|
|
|
DEBUT,
|
|
|
FIN,
|
|
|
CASE WHEN FACTURE_CAISSE = 0 THEN QTE ELSE 0 END,
|
|
|
PRIX_UNIT,
|
|
|
MONTANT,
|
|
|
0 AS MONTANT_CAISSE,
|
|
|
0 AS POURC_CAISSE,
|
|
|
MONTANT_MUT,
|
|
|
POURC_MUT,
|
|
|
CASE WHEN FACTURE_MUT = FACTURE_ASSURE THEN MONTANT_ASSURE ELSE 0 END AS MONTANT_ASSURE,
|
|
|
CASE WHEN FACTURE_MUT = FACTURE_ASSURE THEN POURC_ASS ELSE 0 END AS POURC_ASS,
|
|
|
FACTURE_MUT as LFAC_ID_FAC
|
|
|
FROM prod_dai.LIGNE_FACT
|
|
|
WHERE
|
|
|
FACTURE_MUT != 0
|
|
|
-- AND FACTUREE_MUT = 'true'
|
|
|
AND FACTURE_MUT != FACTURE_CAISSE
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO w_FAC_LIGNES
|
|
|
SELECT
|
|
|
NO_FICHE,
|
|
|
ACTE,
|
|
|
DEBUT,
|
|
|
FIN,
|
|
|
CASE WHEN FACTURE_CAISSE = 0 AND FACTURE_MUT = 0 THEN QTE ELSE 0 END,
|
|
|
PRIX_UNIT,
|
|
|
MONTANT,
|
|
|
0 AS MONTANT_CAISSE,
|
|
|
0 AS POURC_CAISSE,
|
|
|
0 AS MONTANT_MUT,
|
|
|
0 AS POURC_MUT,
|
|
|
MONTANT_ASSURE,
|
|
|
POURC_ASS,
|
|
|
FACTURE_ASSURE as LFAC_ID_FAC
|
|
|
FROM prod_dai.LIGNE_FACT
|
|
|
WHERE
|
|
|
FACTURE_ASSURE != 0
|
|
|
AND FACTURE_MUT != FACTURE_ASSURE AND FACTURE_CAISSE != FACTURE_ASSURE
|
|
|
;
|
|
|
|
|
|
-- Ajout externes (entetes sans lignes)
|
|
|
INSERT INTO w_FAC_LIGNES
|
|
|
SELECT
|
|
|
0 AS NO_FICHE,
|
|
|
split_part(LIBELLE,' ',1) AS ACTE,
|
|
|
DEBUT,
|
|
|
FIN,
|
|
|
1 AS QTE,
|
|
|
TOTAL_FACTURE AS PRIX_UNIT,
|
|
|
TOTAL_FACTURE AS MONTANT,
|
|
|
CASE WHEN TYPE_DESTINATAI = 1 THEN TOTAL_FACTURE ELSE 0 END AS MONTANT_CAISSE,
|
|
|
0 AS POURC_CAISSE,
|
|
|
CASE WHEN TYPE_DESTINATAI = 2 THEN TOTAL_FACTURE ELSE 0 END AS MONTANT_MUT,
|
|
|
0 AS POURC_MUT,
|
|
|
CASE WHEN TYPE_DESTINATAI = 3 THEN TOTAL_FACTURE ELSE 0 END AS MONTANT_ASSURE,
|
|
|
0 AS POURC_ASS,
|
|
|
NO_FICHE AS LFAC_ID_FAC
|
|
|
FROM w_FACTURES_615 FACTURES_615
|
|
|
JOIN w_TARIFS ON split_part(LIBELLE,' ',1) = ACTE
|
|
|
WHERE TOTAL_FACTURE != 0 AND
|
|
|
NO_FICHE NOT IN (SELECT LFAC_ID_FAC FROM w_FAC_LIGNES)
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Lignes non facturées PJ selon planification (pour alimenter prestation présence)
|
|
|
TRUNCATE activite[PX].p_factures_lignes_non_facturees_c;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_HDJ;
|
|
|
CREATE TEMP TABLE w_HDJ AS
|
|
|
SELECT
|
|
|
no_sejour,
|
|
|
PATIENTS.NO_4D,
|
|
|
date(MIN(COALESCE(FACTURES_615.DEBUT,'00010101'))) AS DEBUT_fact,
|
|
|
date(MAX(COALESCE(FACTURES_615.FIN,'00010101'))) AS FIN_fact,
|
|
|
MAX(p_sejours.date_entree) AS date_entree,
|
|
|
MAX(p_sejours.date_sortie) AS date_sorti,
|
|
|
MAX(prestations_presence) AS prestations_presence
|
|
|
FROM activite[PX].p_sejours
|
|
|
JOIN prod_dai.PATIENTS ON p_sejours.code_original = PATIENTS.NO_4D
|
|
|
LEFT JOIN prod_dai.FACTURES_615 ON FACTURES_615.NO_PATIENT = code_original
|
|
|
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 base.t_modes_traitement ON t_services_facturation.mode_traitement_id = t_modes_traitement.oid
|
|
|
WHERE t_modes_traitement.code = '04' AND
|
|
|
prestations_presence <> '' AND
|
|
|
p_sejours.code_prevu = '0' AND
|
|
|
p_sejours.date_sortie >= date(now() - interval '1 year')
|
|
|
GROUP BY 1,2
|
|
|
HAVING MAX(p_sejours.date_sortie) - date(MAX(COALESCE(FACTURES_615.FIN,'00010101'))) > 1
|
|
|
ORDER BY 4
|
|
|
;
|
|
|
|
|
|
ANALYSE w_HDJ
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_lignes_non_facturees_c(
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
coefficient,
|
|
|
rubrique_facturation_id,
|
|
|
prestation_id,
|
|
|
prix_unitaire,
|
|
|
lieu_id)
|
|
|
SELECT
|
|
|
p_factures.no_facture,
|
|
|
date(p_mouvements_sejour.date) AS date_debut,
|
|
|
date(p_mouvements_sejour.date) AS date_fin,
|
|
|
1 AS nb_rubrique,
|
|
|
1 AS coefficient,
|
|
|
t_rubriques_facturation.oid AS rubrique_facturation_id,
|
|
|
t_prestations.oid AS prestation_id,
|
|
|
0::numeric AS prix_unitaire,
|
|
|
p_mouvements_sejour.lieu_id AS lieu_id
|
|
|
FROM activite[PX].p_mouvements_sejour
|
|
|
JOIN w_HDJ ON
|
|
|
p_mouvements_sejour.no_sejour = w_HDJ.no_sejour AND
|
|
|
p_mouvements_sejour.date > FIN_fact
|
|
|
JOIN prod_dai.RESERVATIONS ON RESERVATIONS.NO_SEJOUR = w_HDJ.NO_4D
|
|
|
JOIN activite[PX].p_factures ON
|
|
|
w_HDJ.no_sejour = p_factures.no_sejour AND
|
|
|
type_facture = 'E' AND
|
|
|
p_mouvements_sejour.date BETWEEN p_factures.date_debut AND p_factures.date_fin
|
|
|
JOIN activite[PX].t_rubriques_facturation ON prestations_presence = t_rubriques_facturation.code_original
|
|
|
JOIN activite[PX].t_prestations ON prestations_presence = t_prestations.code
|
|
|
WHERE
|
|
|
(
|
|
|
RESERVATIONS.LUNDI ILIKE 'true' AND EXTRACT(DOW FROM p_mouvements_sejour.date) = 1 OR
|
|
|
RESERVATIONS.MARDI ILIKE 'true' AND EXTRACT(DOW FROM p_mouvements_sejour.date) = 2 OR
|
|
|
RESERVATIONS.MERCREDI ILIKE 'true' AND EXTRACT(DOW FROM p_mouvements_sejour.date) = 3 OR
|
|
|
RESERVATIONS.JEUDI ILIKE 'true' AND EXTRACT(DOW FROM p_mouvements_sejour.date) = 4 OR
|
|
|
RESERVATIONS.VENDREDI ILIKE 'true' AND EXTRACT(DOW FROM p_mouvements_sejour.date) = 5 OR
|
|
|
RESERVATIONS.SAMEDI ILIKE 'true' AND EXTRACT(DOW FROM p_mouvements_sejour.date) = 6
|
|
|
)
|
|
|
;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Lignes facturées Clinique">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- comptes associés
|
|
|
|
|
|
INSERT INTO activite[PX].t_compte(oid, code_original, code, texte, texte_court)
|
|
|
SELECT 0, 0, '', 'Non renseigné', 'Non renseigné' WHERE 0 NOT IN (SELECt oid FROM activite[PX].t_compte);
|
|
|
|
|
|
|
|
|
|
|
|
-- Extraction lignes
|
|
|
DROP TABLE IF EXISTS w_FAC_FACTURE_LIGNE_C;
|
|
|
CREATE TEMP TABLE w_FAC_FACTURE_LIGNE_C AS
|
|
|
SELECT
|
|
|
1::integer AS origine_facturation_id,
|
|
|
w_FAC_LIGNES.NO_FICHE AS LFAC_ID_LFAC,
|
|
|
FACT_NUM_FAC AS no_facture,
|
|
|
w_FAC_LIGNES.DEBUT AS date_debut,
|
|
|
w_FAC_LIGNES.FIN AS date_fin,
|
|
|
CASE WHEN w_FAC_FACTURE.date_vente IS NOT NULL THEN w_FAC_FACTURE.date_vente ELSE '20991231'::date END AS date_vente,
|
|
|
lieu_sortie_id,
|
|
|
1 AS nb_rubrique,
|
|
|
1 AS nb_prestations,
|
|
|
ABS(QTE) as coefficient,
|
|
|
1 AS coefficient_mco,
|
|
|
COALESCE(t_rubriques_facturation.oid::bigint, 0) AS rubrique_facturation_id,
|
|
|
COALESCE(t_rubriques_facturation.oid::bigint, 0) AS rubrique_comptabilisation_id,
|
|
|
MAX(COALESCE(t_compte.oid::bigint, 0)) AS compte_produit_id,
|
|
|
COALESCE(t_prestations.oid::bigint, 0) AS prestation_id,
|
|
|
PRIX_UNIT AS prix_unitaire,
|
|
|
|
|
|
SUM(MONTANT_ASSURE+MONTANT_CAISSE+MONTANT_MUT) AS montant_facture,
|
|
|
SUM(MONTANT_ASSURE) as montant_facture_0,
|
|
|
SUM(MONTANT_CAISSE) as montant_facture_1,
|
|
|
SUM(MONTANT_MUT) as montant_facture_2,
|
|
|
0 as montant_facture_22,
|
|
|
|
|
|
0 AS montant_facture_actes_inclus_dans_sejour,
|
|
|
0 as montant_facture_0_actes_inclus_dans_sejour,
|
|
|
0 as montant_facture_1_actes_inclus_dans_sejour,
|
|
|
0 as montant_facture_2_actes_inclus_dans_sejour,
|
|
|
0 as montant_facture_22_actes_inclus_dans_sejour,
|
|
|
|
|
|
AVG(POURC_ASS) as taux_0,
|
|
|
AVG(POURC_CAISSE) as taux_1,
|
|
|
AVG(POURC_MUT) as taux_2,
|
|
|
0 as taux_22,
|
|
|
|
|
|
|
|
|
SUM(CASE WHEN t_divers.valeur <> '1' OR w_FAC_FACTURE.COMPTABILISEE ILIKE 'true' THEN MONTANT_ASSURE+MONTANT_CAISSE+MONTANT_MUT ELSE 0 END) AS montant_comptabilise,
|
|
|
SUM(CASE WHEN t_divers.valeur <> '1' OR w_FAC_FACTURE.COMPTABILISEE ILIKE 'true' THEN MONTANT_ASSURE ELSE 0 END) as montant_comptabilise_0,
|
|
|
SUM(CASE WHEN t_divers.valeur <> '1' OR w_FAC_FACTURE.COMPTABILISEE ILIKE 'true' THEN MONTANT_CAISSE ELSE 0 END) as montant_comptabilise_1,
|
|
|
SUM(CASE WHEN t_divers.valeur <> '1' OR w_FAC_FACTURE.COMPTABILISEE ILIKE 'true' THEN MONTANT_MUT ELSE 0 END) as montant_comptabilise_2,
|
|
|
0 as montant_comptabilise_22,
|
|
|
|
|
|
0::bigint AS rubrique_facture_id
|
|
|
|
|
|
FROM w_FAC_LIGNES
|
|
|
JOIN activite.t_divers ON t_divers.code = 'DAI_TRT_COMPTABILISE'
|
|
|
LEFT JOIN activite[PX].t_rubriques_facturation ON (ACTE = t_rubriques_facturation.code_original)
|
|
|
LEFT JOIN activite.t_prestations ON (ACTE = t_prestations.code)
|
|
|
JOIN w_FAC_FACTURE ON LFAC_ID_FAC = FACT_ID_FACT
|
|
|
LEFT JOIN activite[PX].t_compte ON (0 = t_compte.code_original)
|
|
|
GROUP BY 1,2,3,4,5,6,7,8,9,10,11,12,13,15,16;
|
|
|
|
|
|
-- mise à niveau de la date de facturation de toutes les lignes (comme pour la facture)
|
|
|
UPDATE w_FAC_FACTURE_LIGNE_C SET date_vente = p_factures.date_vente
|
|
|
FROM
|
|
|
activite[PX].p_factures
|
|
|
WHERE p_factures.no_facture = w_FAC_FACTURE_LIGNE_C.no_facture;
|
|
|
|
|
|
|
|
|
-- Rubriques internes cti
|
|
|
SELECT activite[PX].cti_reorganize_rubrique_facture_c('w_FAC_FACTURE_LIGNE_C');
|
|
|
|
|
|
-- lignes clinique
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_c_1');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_c_2');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_c_3');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_c_4');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_c_5');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_c_6');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_c_7');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_lignes_c_8');
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_lignes_c(
|
|
|
no_facture,
|
|
|
facture_id,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
nb_prestation,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facture_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
compte_produit_id,
|
|
|
prestation_id,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
montant_facture_22,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
|
|
|
montant_encours,
|
|
|
montant_encours_0,
|
|
|
montant_encours_1,
|
|
|
montant_encours_2,
|
|
|
montant_encours_22,
|
|
|
|
|
|
origine_facturation_id,
|
|
|
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
|
|
|
w_FAC_FACTURE_LIGNE_C.no_facture,
|
|
|
p_factures.oid,
|
|
|
w_FAC_FACTURE_LIGNE_C.date_debut,
|
|
|
w_FAC_FACTURE_LIGNE_C.date_fin,
|
|
|
nb_rubrique,
|
|
|
nb_prestations,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facture_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
compte_produit_id,
|
|
|
prestation_id,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
montant_facture_22,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
prix_unitaire,
|
|
|
lieu_sortie_id,
|
|
|
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
|
|
|
origine_facturation_id,
|
|
|
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
|
|
|
|
|
|
FROM w_FAC_FACTURE_LIGNE_C
|
|
|
JOIN activite[PX].p_factures ON p_factures.no_facture = w_FAC_FACTURE_LIGNE_C.no_facture;
|
|
|
|
|
|
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');
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures_lignes_c
|
|
|
SET nb_prestation = coefficient * nb_prestation,
|
|
|
nb_rubrique = coefficient * nb_prestation,
|
|
|
coefficient = 1
|
|
|
WHERE coefficient > 1 AND
|
|
|
prestation_id IN (SELECT oid FROM activite.t_prestations WHERE code IN ('PJ', 'PJ1', 'PJ2', 'FJ', 'PHJ', 'SSM', 'SRC', 'REA', 'STF', 'NN1', 'NN2', 'NN3', 'CP', 'CPC', 'SHO'));
|
|
|
|
|
|
|
|
|
-- Eclatement des supplements par jour
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_sup_c;
|
|
|
|
|
|
CREATE TEMP TABLE w_factures_lignes_sup_c AS
|
|
|
SELECT
|
|
|
p_factures_lignes_c.CTID AS from_CTID,
|
|
|
t_prestations.code AS prestation_code,
|
|
|
CASE WHEN p_sejours.type_sejour <> '5' THEN date(p_sejours.date_entree) ELSE p_factures_lignes_c.date_debut END AS date_debut_ghs,
|
|
|
CASE WHEN p_sejours.type_sejour <> '5' THEN date(p_sejours.date_sortie - interval '1 day') ELSE p_factures_lignes_c.date_fin END 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 type_sejour = '5' THEN p_factures_lignes_c.date_debut WHEN t_prestations.code = 'GHS' THEN date(date_entree + interval '1 day') ELSE date(p_factures_lignes_c.date_debut + interval '1 day') END AS date_debut_det,
|
|
|
CASE WHEN type_sejour = '5' THEN p_factures_lignes_c.date_fin WHEN t_prestations.code = 'GHS' THEN date(p_sejours.date_sortie - interval '1 day') ELSE date(p_factures_lignes_c.date_debut + ((ABS(nb_prestation)-1) || ' day')::interval) END AS date_fin_det,
|
|
|
ABS(CASE WHEN type_sejour <> '5' AND t_prestations.code = 'GHS' THEN date(date_sortie) - date(date_entree) ELSE nb_prestation END) AS nb_det,
|
|
|
p_factures_lignes_c.*
|
|
|
FROM activite[PX].p_factures_lignes_c
|
|
|
JOIN activite[PX].p_factures ON p_factures_lignes_c.no_facture = p_factures.no_facture
|
|
|
JOIN activite[PX].p_sejours ON p_factures.no_sejour = p_sejours.no_sejour
|
|
|
JOIN activite.t_prestations ON prestation_id = t_prestations.oid AND code IN ('PJ', 'PJ1', 'PJ2', 'FJ', 'SSM', 'GHS', 'EXH', 'SRC', 'REA', 'STF', 'NN1', 'NN2', 'NN3', 'CP', 'CPC', 'SHO')
|
|
|
WHERE (nb_prestation > 1 or nb_prestation < -1 OR (type_sejour <> '5' AND t_prestations.code = 'GHS' AND date(date_sortie) - date(date_entree) > 1)) ;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE w_factures_lignes_sup_c SET
|
|
|
date_fin_ghs = date(date_debut_exh - interval '1 day'),
|
|
|
date_fin_det = date(date_debut_exh - interval '1 day'),
|
|
|
nb_prestation_ghs = date(date_debut_exh - interval '1 day') - date_debut_ghs + 1,
|
|
|
nb_det = date(date_debut_exh - interval '1 day') - date_debut_ghs + 1
|
|
|
FROM (
|
|
|
SELECT no_facture, date(MIN(date_debut)) AS date_debut_exh
|
|
|
FROM activite[PX].p_factures_lignes_c
|
|
|
JOIN activite.t_prestations ON prestation_id = t_prestations.oid AND code = 'EXH'
|
|
|
GROUP BY 1) subview
|
|
|
WHERE w_factures_lignes_sup_c.no_facture = subview.no_facture AND
|
|
|
prestation_code = 'GHS';
|
|
|
|
|
|
CREATE INDEX w_factures_lignes_sup_c_i1
|
|
|
ON w_factures_lignes_sup_c
|
|
|
USING btree
|
|
|
(date_debut);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_sup_c_sup;
|
|
|
|
|
|
CREATE TEMP TABLE w_factures_lignes_sup_c_sup AS
|
|
|
SELECT
|
|
|
from_CTID,
|
|
|
no_facture,
|
|
|
date AS date_debut,
|
|
|
date AS date_fin,
|
|
|
CASE WHEN prestation_code = 'GHS' AND date <> date_fin_ghs THEN 0 WHEN nb_prestation < 0 THEN -1 ELSE 1 END AS nb_rubrique,
|
|
|
CASE WHEN prestation_code = 'GHS' AND date <> date_fin_ghs THEN 0 WHEN nb_prestation < 0 THEN -1 ELSE 1 END AS nb_prestation,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
compte_produit_id,
|
|
|
prestation_id,
|
|
|
round(montant_facture / ABS(nb_det),2) AS montant_facture,
|
|
|
round(montant_facture_0 / ABS(nb_det),2) AS montant_facture_0,
|
|
|
round(montant_facture_1 / ABS(nb_det),2) AS montant_facture_1,
|
|
|
round(montant_facture_2 / ABS(nb_det),2) AS montant_facture_2,
|
|
|
round(montant_facture_22 / ABS(nb_det),2) AS montant_facture_22,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
finess,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
round(montant_comptabilise / ABS(nb_det),2) AS montant_comptabilise,
|
|
|
round(montant_comptabilise_0 / ABS(nb_det),2) AS montant_comptabilise_0,
|
|
|
round(montant_comptabilise_1 / ABS(nb_det),2) AS montant_comptabilise_1,
|
|
|
round(montant_comptabilise_2 / ABS(nb_det),2) AS montant_comptabilise_2,
|
|
|
round(montant_comptabilise_22 / ABS(nb_det),2) AS montant_comptabilise_22,
|
|
|
round(montant_encours / ABS(nb_det),2) AS montant_encours,
|
|
|
round(montant_encours_0 / ABS(nb_det),2) AS montant_encours_0,
|
|
|
round(montant_encours_1 / ABS(nb_det),2) AS montant_encours_1,
|
|
|
round(montant_encours_2 / ABS(nb_det),2) AS montant_encours_2,
|
|
|
round(montant_encours_22 / ABS(nb_det),2) AS montant_encours_22,
|
|
|
round(montant_facture_actes_inclus_dans_sejour / ABS(nb_det),2) AS montant_facture_actes_inclus_dans_sejour,
|
|
|
round(montant_facture_0_actes_inclus_dans_sejour / ABS(nb_det),2) AS montant_facture_0_actes_inclus_dans_sejour,
|
|
|
round(montant_facture_1_actes_inclus_dans_sejour / ABS(nb_det),2) AS montant_facture_1_actes_inclus_dans_sejour,
|
|
|
round(montant_facture_2_actes_inclus_dans_sejour / ABS(nb_det),2) AS montant_facture_2_actes_inclus_dans_sejour,
|
|
|
round(montant_facture_22_actes_inclus_dans_sejour / ABS(nb_det),2) AS montant_facture_22_actes_inclus_dans_sejour,
|
|
|
origine_facturation_id,
|
|
|
round(montant_comptabilise_budget_global_1 / ABS(nb_det),2) AS montant_comptabilise_budget_global_1,
|
|
|
facture_id
|
|
|
FROM w_factures_lignes_sup_c
|
|
|
JOIN base.p_calendrier ON p_calendrier.date BETWEEN date_debut_det AND date_fin_det
|
|
|
;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_sup_c_sup_tot;
|
|
|
|
|
|
CREATE TEMP TABLE w_factures_lignes_sup_c_sup_tot AS
|
|
|
|
|
|
SELECT from_CTID,
|
|
|
SUM(nb_rubrique) AS nb_rubrique,
|
|
|
SUM(nb_prestation) AS nb_prestation,
|
|
|
SUM(montant_facture) AS montant_facture,
|
|
|
SUM(montant_facture_0) AS montant_facture_0,
|
|
|
SUM(montant_facture_1) AS montant_facture_1,
|
|
|
SUM(montant_facture_2) AS montant_facture_2,
|
|
|
SUM(montant_facture_22) AS montant_facture_22,
|
|
|
SUM(montant_comptabilise) AS montant_comptabilise,
|
|
|
SUM(montant_comptabilise_0) AS montant_comptabilise_0,
|
|
|
SUM(montant_comptabilise_1) AS montant_comptabilise_1,
|
|
|
SUM(montant_comptabilise_2) AS montant_comptabilise_2,
|
|
|
SUM(montant_comptabilise_22) AS montant_comptabilise_22,
|
|
|
SUM(montant_encours) AS montant_encours,
|
|
|
SUM(montant_encours_0) AS montant_encours_0,
|
|
|
SUM(montant_encours_1) AS montant_encours_1,
|
|
|
SUM(montant_encours_2) AS montant_encours_2,
|
|
|
SUM(montant_encours_22) AS montant_encours_22,
|
|
|
SUM(montant_facture_actes_inclus_dans_sejour) AS montant_facture_actes_inclus_dans_sejour,
|
|
|
SUM(montant_facture_0_actes_inclus_dans_sejour) AS montant_facture_0_actes_inclus_dans_sejour,
|
|
|
SUM(montant_facture_1_actes_inclus_dans_sejour) AS montant_facture_1_actes_inclus_dans_sejour,
|
|
|
SUM(montant_facture_2_actes_inclus_dans_sejour) AS montant_facture_2_actes_inclus_dans_sejour,
|
|
|
SUM(montant_facture_22_actes_inclus_dans_sejour) AS montant_facture_22_actes_inclus_dans_sejour,
|
|
|
SUM(montant_comptabilise_budget_global_1) AS montant_comptabilise_budget_global_1
|
|
|
FROM w_factures_lignes_sup_c_sup
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures_lignes_c
|
|
|
SET
|
|
|
date_fin = p_factures_lignes_c.date_debut,
|
|
|
nb_rubrique = p_factures_lignes_c.nb_rubrique - w_factures_lignes_sup_c_sup_tot.nb_rubrique,
|
|
|
nb_prestation = p_factures_lignes_c.nb_prestation - w_factures_lignes_sup_c_sup_tot.nb_prestation,
|
|
|
montant_facture = p_factures_lignes_c.montant_facture - w_factures_lignes_sup_c_sup_tot.montant_facture,
|
|
|
montant_facture_0 = p_factures_lignes_c.montant_facture_0 - w_factures_lignes_sup_c_sup_tot.montant_facture_0,
|
|
|
montant_facture_1 = p_factures_lignes_c.montant_facture_1 - w_factures_lignes_sup_c_sup_tot.montant_facture_1,
|
|
|
montant_facture_2 = p_factures_lignes_c.montant_facture_2 - w_factures_lignes_sup_c_sup_tot.montant_facture_2,
|
|
|
montant_facture_22 = p_factures_lignes_c.montant_facture_22 - w_factures_lignes_sup_c_sup_tot.montant_facture_22,
|
|
|
montant_comptabilise = p_factures_lignes_c.montant_comptabilise - w_factures_lignes_sup_c_sup_tot.montant_comptabilise,
|
|
|
montant_comptabilise_0 = p_factures_lignes_c.montant_comptabilise_0 - w_factures_lignes_sup_c_sup_tot.montant_comptabilise_0,
|
|
|
montant_comptabilise_1 = p_factures_lignes_c.montant_comptabilise_1 - w_factures_lignes_sup_c_sup_tot.montant_comptabilise_1,
|
|
|
montant_comptabilise_2 = p_factures_lignes_c.montant_comptabilise_2 - w_factures_lignes_sup_c_sup_tot.montant_comptabilise_2,
|
|
|
montant_comptabilise_22 = p_factures_lignes_c.montant_comptabilise_22 - w_factures_lignes_sup_c_sup_tot.montant_comptabilise_22,
|
|
|
montant_encours = p_factures_lignes_c.montant_encours - w_factures_lignes_sup_c_sup_tot.montant_encours,
|
|
|
montant_encours_0 = p_factures_lignes_c.montant_encours_0 - w_factures_lignes_sup_c_sup_tot.montant_encours_0,
|
|
|
montant_encours_1 = p_factures_lignes_c.montant_encours_1 - w_factures_lignes_sup_c_sup_tot.montant_encours_1,
|
|
|
montant_encours_2 = p_factures_lignes_c.montant_encours_2 - w_factures_lignes_sup_c_sup_tot.montant_encours_2,
|
|
|
montant_encours_22 = p_factures_lignes_c.montant_encours_22 - w_factures_lignes_sup_c_sup_tot.montant_encours_22,
|
|
|
montant_facture_actes_inclus_dans_sejour = p_factures_lignes_c.montant_facture_actes_inclus_dans_sejour - w_factures_lignes_sup_c_sup_tot.montant_facture_actes_inclus_dans_sejour,
|
|
|
montant_facture_0_actes_inclus_dans_sejour = p_factures_lignes_c.montant_facture_0_actes_inclus_dans_sejour - w_factures_lignes_sup_c_sup_tot.montant_facture_0_actes_inclus_dans_sejour,
|
|
|
montant_facture_1_actes_inclus_dans_sejour = p_factures_lignes_c.montant_facture_1_actes_inclus_dans_sejour - w_factures_lignes_sup_c_sup_tot.montant_facture_1_actes_inclus_dans_sejour,
|
|
|
montant_facture_2_actes_inclus_dans_sejour = p_factures_lignes_c.montant_facture_2_actes_inclus_dans_sejour - w_factures_lignes_sup_c_sup_tot.montant_facture_2_actes_inclus_dans_sejour,
|
|
|
montant_facture_22_actes_inclus_dans_sejour = p_factures_lignes_c.montant_facture_22_actes_inclus_dans_sejour - w_factures_lignes_sup_c_sup_tot.montant_facture_22_actes_inclus_dans_sejour,
|
|
|
montant_comptabilise_budget_global_1 = p_factures_lignes_c.montant_comptabilise_budget_global_1 - w_factures_lignes_sup_c_sup_tot.montant_comptabilise_budget_global_1
|
|
|
FROM w_factures_lignes_sup_c_sup_tot
|
|
|
WHERE p_factures_lignes_c.CTID = from_CTID;
|
|
|
|
|
|
-- Rubriques internes cti
|
|
|
SELECT activite[PX].cti_reorganize_rubrique_facture_c('w_factures_lignes_sup_c_sup');
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_lignes_c(
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facture_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
compte_produit_id,
|
|
|
prestation_id,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
montant_facture_22,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
finess,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
nb_prestation,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
montant_encours,
|
|
|
montant_encours_0,
|
|
|
montant_encours_1,
|
|
|
montant_encours_2,
|
|
|
montant_encours_22,
|
|
|
montant_facture_actes_inclus_dans_sejour,
|
|
|
montant_facture_0_actes_inclus_dans_sejour,
|
|
|
montant_facture_1_actes_inclus_dans_sejour,
|
|
|
montant_facture_2_actes_inclus_dans_sejour,
|
|
|
montant_facture_22_actes_inclus_dans_sejour,
|
|
|
origine_facturation_id,
|
|
|
montant_comptabilise_budget_global_1,
|
|
|
facture_id)
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facture_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
compte_produit_id,
|
|
|
prestation_id,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
montant_facture_22,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
finess,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
nb_prestation,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
montant_encours,
|
|
|
montant_encours_0,
|
|
|
montant_encours_1,
|
|
|
montant_encours_2,
|
|
|
montant_encours_22,
|
|
|
montant_facture_actes_inclus_dans_sejour,
|
|
|
montant_facture_0_actes_inclus_dans_sejour,
|
|
|
montant_facture_1_actes_inclus_dans_sejour,
|
|
|
montant_facture_2_actes_inclus_dans_sejour,
|
|
|
montant_facture_22_actes_inclus_dans_sejour,
|
|
|
origine_facturation_id,
|
|
|
montant_comptabilise_budget_global_1,
|
|
|
facture_id
|
|
|
FROM w_factures_lignes_sup_c_sup;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures_lignes_c
|
|
|
SET lieu_id = p_mouvements_sejour.lieu_id
|
|
|
FROM activite[PX].p_factures, activite[PX].p_mouvements_sejour
|
|
|
WHERE p_factures_lignes_c.no_facture = p_factures.no_facture AND
|
|
|
p_factures.no_sejour = p_mouvements_sejour.no_sejour AND
|
|
|
activite[PX].p_factures_lignes_c.date_debut = p_mouvements_sejour.date AND
|
|
|
(p_mouvements_sejour.heure_fin = 240000 OR p_mouvements_sejour.nb_sorties_directes = 1) AND
|
|
|
p_factures_lignes_c.lieu_id <> p_mouvements_sejour.lieu_id;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_actes_inclus_dans_sejour;
|
|
|
CREATE TEMP TABLE w_actes_inclus_dans_sejour AS
|
|
|
SELECT FACT_NUM_FAC AS no_facture,
|
|
|
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
|
|
|
FROM activite[PX].p_factures_lignes_c JOIN w_FAC_FACTURE ON no_facture = FACT_NUM_FAC
|
|
|
WHERE
|
|
|
'[ENV_TYPEETS]' IN ('2','3') AND
|
|
|
montant_facture_actes_inclus_dans_sejour <> 0 AND
|
|
|
origine_facturation_id = 3
|
|
|
GROUP BY 1;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_ghs_pj;
|
|
|
CREATE TEMP TABLE w_ghs_pj AS
|
|
|
SELECT p_factures_lignes_c.no_facture,
|
|
|
p_sejours.no_sejour,
|
|
|
p_sejours.est_budget_global,
|
|
|
MIN(p_factures_lignes_c.ctid) AS ctid_min
|
|
|
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
|
|
|
WHERE
|
|
|
'[ENV_TYPEETS]' IN ('2','3') AND
|
|
|
origine_facturation_id = 1 AND
|
|
|
(
|
|
|
prestation_id IN (SELECT oid FROM activite.t_prestations where code IN ('PJ', 'PJ1', 'PJ2', 'GHS', 'AMP5')) OR
|
|
|
rubrique_facturation_id IN (SELECT oid FROM activite[PX].t_rubriques_facturation where actes_inclus_public = '1')
|
|
|
)
|
|
|
GROUP BY 1,2,3;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures_lignes_c
|
|
|
SET
|
|
|
montant_facture_actes_inclus_dans_sejour = 0 - w_actes_inclus_dans_sejour.montant_facture_actes_inclus_dans_sejour,
|
|
|
montant_facture_0_actes_inclus_dans_sejour = 0 - w_actes_inclus_dans_sejour.montant_facture_0_actes_inclus_dans_sejour,
|
|
|
montant_facture_1_actes_inclus_dans_sejour = 0 - w_actes_inclus_dans_sejour.montant_facture_1_actes_inclus_dans_sejour,
|
|
|
montant_facture_2_actes_inclus_dans_sejour = 0 - w_actes_inclus_dans_sejour.montant_facture_2_actes_inclus_dans_sejour,
|
|
|
montant_facture_22_actes_inclus_dans_sejour = 0 - w_actes_inclus_dans_sejour.montant_facture_22_actes_inclus_dans_sejour
|
|
|
FROM w_actes_inclus_dans_sejour, w_ghs_pj
|
|
|
WHERE
|
|
|
'[ENV_TYPEETS]' IN ('2','3') AND
|
|
|
p_factures_lignes_c.no_facture = w_ghs_pj.no_facture AND p_factures_lignes_c.ctid = w_ghs_pj.ctid_min AND
|
|
|
w_actes_inclus_dans_sejour.no_facture = p_factures_lignes_c.no_facture AND
|
|
|
(
|
|
|
prestation_id IN (SELECT oid FROM activite.t_prestations where code IN ('PJ', 'GHS', 'AMP5')) OR
|
|
|
rubrique_facturation_id IN (SELECT oid FROM activite[PX].t_rubriques_facturation where actes_inclus_public = '1')
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_actes_inclus_dans_sejour_t;
|
|
|
CREATE TEMP TABLE w_actes_inclus_dans_sejour_t AS
|
|
|
SELECT no_facture,
|
|
|
SUM(CASE WHEN origine_facturation_id = 1 THEN montant_facture_actes_inclus_dans_sejour ELSE 0 END) AS montant_facture_c_actes_inclus_dans_sejour,
|
|
|
SUM(CASE WHEN origine_facturation_id = 3 THEN montant_facture_actes_inclus_dans_sejour ELSE 0 END) AS montant_facture_h_actes_inclus_dans_sejour
|
|
|
FROM activite[PX].p_factures_lignes_c
|
|
|
WHERE
|
|
|
'[ENV_TYPEETS]' IN ('2','3') AND
|
|
|
montant_facture_actes_inclus_dans_sejour <> 0
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures SET
|
|
|
montant_facture_c_actes_inclus_dans_sejour = w_actes_inclus_dans_sejour_t.montant_facture_c_actes_inclus_dans_sejour,
|
|
|
montant_facture_h_actes_inclus_dans_sejour = w_actes_inclus_dans_sejour_t.montant_facture_h_actes_inclus_dans_sejour
|
|
|
FROM w_actes_inclus_dans_sejour_t
|
|
|
WHERE
|
|
|
'[ENV_TYPEETS]' IN ('2','3') AND
|
|
|
w_actes_inclus_dans_sejour_t.no_facture = p_factures.no_facture;
|
|
|
|
|
|
|
|
|
-- Suppression des tables de travail non utilisées après
|
|
|
--DROP TABLE IF EXISTS w_FAC_LIGNE_FACTURE_DEBITEUR_compte CASCADE;
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_sup_c CASCADE;
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_sup_c_sup_tot CASCADE;
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_sup_c_sup CASCADE;
|
|
|
DROP TABLE IF EXISTS w_actes_inclus_dans_sejour CASCADE;
|
|
|
DROP TABLE IF EXISTS w_ghs_pj CASCADE;
|
|
|
DROP TABLE IF EXISTS w_actes_inclus_dans_sejour_t CASCADE;
|
|
|
--DROP TABLE IF EXISTS w_factures_ventes_bg CASCADE;
|
|
|
--DROP TABLE IF EXISTS w_factures_lignes_bg CASCADE;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Compte client Clinique">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_soldes_c_1');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_soldes_c_2');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_soldes_c_3');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_soldes_c_4');
|
|
|
SELECT base.cti_disable_index('activite[PX]', 'i_factures_soldes_c_8');
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_soldes_c(
|
|
|
no_facture,
|
|
|
date_comptable,
|
|
|
rubrique_comptabilisee_id,
|
|
|
prestation_id,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
montant_regle,
|
|
|
montant_regle_0,
|
|
|
montant_regle_1,
|
|
|
montant_regle_2,
|
|
|
montant_regle_22
|
|
|
)
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
date_vente,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
SUM(montant_comptabilise),
|
|
|
SUM(montant_comptabilise_0),
|
|
|
SUM(montant_comptabilise_1),
|
|
|
SUM(montant_comptabilise_2),
|
|
|
SUM(montant_comptabilise_22),
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0
|
|
|
FROM w_FAC_FACTURE_LIGNE_C
|
|
|
WHERE --date_vente IS NOT NULL AND
|
|
|
(montant_comptabilise <> 0 OR
|
|
|
montant_comptabilise_0 <> 0 OR
|
|
|
montant_comptabilise_1 <> 0 OR
|
|
|
montant_comptabilise_2 <> 0 OR
|
|
|
montant_comptabilise_22 <> 0
|
|
|
)
|
|
|
GROUP BY 1,2,3,4;
|
|
|
|
|
|
|
|
|
INSERT INTO activite.p_factures_soldes_c(
|
|
|
no_facture,
|
|
|
date_comptable,
|
|
|
rubrique_comptabilisee_id,
|
|
|
prestation_id,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
montant_regle,
|
|
|
montant_regle_0,
|
|
|
montant_regle_1,
|
|
|
montant_regle_2,
|
|
|
montant_regle_22
|
|
|
)
|
|
|
SELECT
|
|
|
FACT_NUM_FAC,
|
|
|
date_trunc('day',RECEPTION),
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
SUM(MONTANT) AS montant_regle_c,
|
|
|
SUM(CASE WHEN TYPE_DESTINATAI = 3 THEN MONTANT ELSE 0 END) AS montant_regle_0,
|
|
|
SUM(CASE WHEN TYPE_DESTINATAI = 1 THEN MONTANT ELSE 0 END) AS montant_regle_1,
|
|
|
SUM(CASE WHEN TYPE_DESTINATAI = 2 THEN MONTANT ELSE 0 END) AS montant_regle_2,
|
|
|
0 AS montant_regle_22
|
|
|
FROM prod_dai.REGLEMENTS
|
|
|
JOIN w_FAC_FACTURE ON REGLEMENTS.FACTURE = w_FAC_FACTURE.FACT_ID_FACT
|
|
|
GROUP BY 1,2,3,4;
|
|
|
|
|
|
UPDATE activite.p_factures
|
|
|
SET
|
|
|
montant_regle_c = montant_regle,
|
|
|
montant_regle_0_c = montant_regle_0,
|
|
|
montant_regle_1_c = montant_regle_1,
|
|
|
montant_regle_2_c = montant_regle_2,
|
|
|
montant_regle_22_c = montant_regle_22
|
|
|
FROM
|
|
|
(
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
SUM(montant_regle) AS montant_regle,
|
|
|
SUM(montant_regle_0) AS montant_regle_0,
|
|
|
SUM(montant_regle_1) AS montant_regle_1,
|
|
|
SUM(montant_regle_2) As montant_regle_2,
|
|
|
SUM(montant_regle_22) AS montant_regle_22
|
|
|
FROM activite.p_factures_soldes_c
|
|
|
GROUP BY 1
|
|
|
) sub
|
|
|
WHERE p_factures.no_facture = sub.no_facture
|
|
|
;
|
|
|
|
|
|
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="Post traitement entetes">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- Préfactures inutiles
|
|
|
|
|
|
DELETE FROM activite[PX].p_factures
|
|
|
WHERE type_facture = 'P' AND
|
|
|
coalesce(montant_facture_c,0) = 0 AND
|
|
|
coalesce(montant_facture_h,0) = 0 AND
|
|
|
coalesce(montant_comptabilise_c,0) = 0 AND
|
|
|
coalesce(montant_comptabilise_h,0) = 0 AND
|
|
|
coalesce(montant_regle_c,0) = 0 AND
|
|
|
coalesce(montant_regle_h,0) = 0 AND
|
|
|
no_facture NOT IN (SELECT no_facture FROM activite[PX].p_factures_soldes_c) AND
|
|
|
no_facture NOT IN (SELECT no_facture FROM activite[PX].p_factures_soldes_h)
|
|
|
;
|
|
|
|
|
|
-- Facture reference
|
|
|
|
|
|
DROP TABLE IF EXISTS w_sejours_facture_reference;
|
|
|
CREATE TEMP TABLE w_sejours_facture_reference AS
|
|
|
SELECT
|
|
|
no_sejour,
|
|
|
date_debut,
|
|
|
MAX(date_fin) AS date_fin,
|
|
|
MAX(p_factures.no_facture) AS no_facture_last,
|
|
|
MAX(CASE WHEN type_facture = '0' AND type_facture <> 'P' THEN p_factures.no_facture ELSE null END) AS no_facture_reference_last,
|
|
|
MAX(CASE WHEN type_facture <> '1' AND type_facture <> 'P' THEN p_factures.no_facture ELSE null END) AS no_facture_reference_last_2,
|
|
|
MAX(p_factures.oid) AS facture_id_last,
|
|
|
MAX(CASE WHEN type_facture = '0' AND type_facture <> 'P' THEN p_factures.oid ELSE null END) AS facture_id_reference_last,
|
|
|
MAX(CASE WHEN type_facture <> '1' AND type_facture <> 'P' THEN p_factures.oid ELSE null END) AS facture_id_reference_last_2
|
|
|
FROM activite[PX].p_factures
|
|
|
WHERE type_facture <> 'P'
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
CREATE INDEX w_sejours_facture_reference_i1
|
|
|
ON w_sejours_facture_reference
|
|
|
USING btree
|
|
|
(no_sejour);
|
|
|
|
|
|
UPDATE w_sejours_facture_reference
|
|
|
SET facture_id_last = p_factures_references.oid
|
|
|
FROM activite[PX].p_factures p_factures_references
|
|
|
WHERE w_sejours_facture_reference.no_facture_last = p_factures_references.no_facture
|
|
|
AND w_sejours_facture_reference.facture_id_last <> p_factures_references.oid;
|
|
|
|
|
|
|
|
|
UPDATE w_sejours_facture_reference
|
|
|
SET facture_id_reference_last = p_factures_references.oid
|
|
|
FROM activite[PX].p_factures p_factures_references
|
|
|
WHERE w_sejours_facture_reference.no_facture_reference_last = p_factures_references.no_facture
|
|
|
AND w_sejours_facture_reference.facture_id_reference_last <> p_factures_references.oid;
|
|
|
|
|
|
UPDATE w_sejours_facture_reference
|
|
|
SET facture_id_reference_last_2 = p_factures_references.oid
|
|
|
FROM activite[PX].p_factures p_factures_references
|
|
|
WHERE w_sejours_facture_reference.no_facture_reference_last_2 = p_factures_references.no_facture
|
|
|
AND w_sejours_facture_reference.facture_id_reference_last_2 <> p_factures_references.oid;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures
|
|
|
SET
|
|
|
no_facture_reference = COALESCE(no_facture_reference_last, no_facture_reference_last_2, no_facture_last),
|
|
|
facture_reference_id = COALESCE(facture_id_reference_last, facture_id_reference_last_2, facture_id_last)
|
|
|
FROM w_sejours_facture_reference
|
|
|
WHERE p_factures.no_sejour = w_sejours_facture_reference.no_sejour AND
|
|
|
p_factures.date_debut BETWEEN w_sejours_facture_reference.date_debut AND w_sejours_facture_reference.date_fin AND
|
|
|
(
|
|
|
no_facture_reference IS DISTINCT FROM COALESCE(no_facture_reference_last, no_facture_reference_last_2, no_facture_last) OR
|
|
|
facture_reference_id IS DISTINCT FROM COALESCE(facture_id_reference_last, facture_id_reference_last_2, facture_id_last)
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures
|
|
|
SET no_facture_reference = no_facture
|
|
|
WHERE (no_facture_reference IS NULL OR no_facture_reference = '');
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures
|
|
|
SET type_facture = '0'
|
|
|
WHERE p_factures.type_facture = '2' AND
|
|
|
p_factures.no_facture = p_factures.no_facture_reference;
|
|
|
|
|
|
UPDATE activite[PX].p_factures
|
|
|
SET type_facture = '2'
|
|
|
WHERE p_factures.type_facture = '0' AND
|
|
|
p_factures.no_facture <> p_factures.no_facture_reference;
|
|
|
|
|
|
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;
|
|
|
|
|
|
|
|
|
-- Suppression des tables de travail non utilisées après
|
|
|
DROP TABLE IF EXISTS w_sejours_facture_reference CASCADE;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="CHIFFRIER" label="CREATION DU CHIFFRIER">
|
|
|
|
|
|
<NODE label="Récupération chiffrier">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP TABLE IF EXISTS w_CHIFFRIER;
|
|
|
CREATE TEMP TABLE w_CHIFFRIER AS
|
|
|
SELECT
|
|
|
FACT_NUM_FAC,
|
|
|
MAX(w_FAC_FACTURE.date_vente) AS date_comptable,
|
|
|
SUM(TOTAL_FACTURE) AS montant_ventes_c,
|
|
|
0 AS montant_reglements_c,
|
|
|
0 AS montant_solde_client_c,
|
|
|
0 AS montant_ventes_h,
|
|
|
0 AS montant_reglements_h,
|
|
|
0 AS montant_solde_client_h
|
|
|
FROM w_FAC_FACTURE
|
|
|
JOIN activite.t_divers ON t_divers.code = 'DAI_TRT_COMPTABILISE'
|
|
|
WHERE t_divers.valeur <> '1' OR
|
|
|
COMPTABILISEE ILIKE 'true' AND
|
|
|
date(w_FAC_FACTURE.date_vente) < date(now())
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO w_CHIFFRIER
|
|
|
SELECT
|
|
|
FACT_NUM_FAC,
|
|
|
date(REGLEMENTS.RECEPTION) AS date_comptable,
|
|
|
0 AS montant_ventes_c,
|
|
|
SUM(REGLEMENTS.MONTANT) AS montant_reglements_c,
|
|
|
0 AS montant_solde_client_c,
|
|
|
0 AS montant_ventes_h,
|
|
|
0 AS montant_reglements_h,
|
|
|
0 AS montant_solde_client_h
|
|
|
FROM prod_dai.REGLEMENTS
|
|
|
JOIN w_FAC_FACTURE ON REGLEMENTS.FACTURE = w_FAC_FACTURE.FACT_ID_FACT
|
|
|
GROUP BY 1,2
|
|
|
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_solde_client_c,
|
|
|
montant_ventes_h,
|
|
|
montant_reglements_h,
|
|
|
montant_solde_client_h
|
|
|
)
|
|
|
SELECT
|
|
|
date_comptable,
|
|
|
SUM(montant_ventes_c) AS montant_ventes_c,
|
|
|
0 AS montant_reglements_c,
|
|
|
0 AS montant_solde_client_c,
|
|
|
0 AS montant_ventes_h,
|
|
|
0 AS montant_reglements_h,
|
|
|
0 AS montant_solde_client_h
|
|
|
FROM w_CHIFFRIER
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
TRUNCATE activite[PX].p_factures_comptables;
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_comptables(
|
|
|
no_facture,
|
|
|
date_comptable,
|
|
|
montant_ventes_c,
|
|
|
montant_reglements_c,
|
|
|
montant_ventes_h,
|
|
|
montant_reglements_h
|
|
|
)
|
|
|
SELECT
|
|
|
FACT_NUM_FAC,
|
|
|
date_comptable,
|
|
|
SUM(montant_ventes_c) AS montant_ventes_c,
|
|
|
0 AS montant_reglements_c,
|
|
|
0 AS montant_ventes_h,
|
|
|
0 AS montant_reglements_h
|
|
|
FROM w_CHIFFRIER
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,3;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="PARAM" label="RECUPERATION DES PARAMETRES">
|
|
|
|
|
|
<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 base.t_grands_regimes(code, code_original, texte, texte_court)
|
|
|
SELECT GD_REGIME, GD_REGIME, '', ''
|
|
|
FROM prod_dai.CAISSES
|
|
|
LEFT JOIN base.t_grands_regimes ON GD_REGIME = code
|
|
|
WHERE t_grands_regimes.code IS NULL
|
|
|
GROUP BY 1,2,3,4;
|
|
|
|
|
|
|
|
|
|
|
|
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 NO_FICHE, GD_REGIME || CODE_ORGANISME || CENTRE_PAIEMENT, CASE WHEN TYPE_DE_CAISSE LIKE 'GR%' THEN '1' WHEN TYPE_DE_CAISSE = 'Mutuelles' THEN '2' ELSE '1' END, NOM, NOM
|
|
|
FROM prod_dai.CAISSES
|
|
|
WHERE NO_FICHE IN (
|
|
|
SELECT DISTINCT CAISSE_N
|
|
|
FROM prod_dai.PATIENTS)
|
|
|
AND NO_FICHE::bigint 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 NO_FICHE, NO_FICHE, CASE WHEN TYPE_DE_CAISSE LIKE 'GR%' THEN '1' WHEN TYPE_DE_CAISSE = 'Mutuelles' THEN '2' ELSE '2' END, NOM, NOM
|
|
|
FROM prod_dai.CAISSES
|
|
|
WHERE NO_FICHE IN (
|
|
|
SELECT DISTINCT MUTUELLE
|
|
|
FROM prod_dai.PATIENTS)
|
|
|
AND NO_FICHE::bigint NOT IN (SELECT code_original FROM activite[PX].t_tiers_payant);
|
|
|
|
|
|
UPDATE activite[PX].t_tiers_payant
|
|
|
SET grand_regime_id = t_grands_regimes.oid
|
|
|
FROM prod_dai.CAISSES
|
|
|
JOIN base.t_grands_regimes ON GD_REGIME = code
|
|
|
WHERE t_tiers_payant.code_original = NO_FICHE AND
|
|
|
grand_regime_id IS DISTINCT FROM t_grands_regimes.oid AND
|
|
|
GD_REGIME <> '';
|
|
|
|
|
|
|
|
|
]]></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);
|
|
|
|
|
|
UPDATE base.t_specialites_medecin SET
|
|
|
code_original = code where code_original is null and oid != 0;
|
|
|
|
|
|
INSERT INTO base.t_specialites_medecin(code_original, code, texte, texte_court)
|
|
|
SELECT NO_FICHE, NO_FICHE, NOM, NOM
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
FROM prod_dai.POP_LISTES
|
|
|
|
|
|
WHERE
|
|
|
TITRE_POP = 'Spécialités'
|
|
|
AND NO_FICHE NOT IN (SELECT code_original FROM base.t_specialites_medecin WHERE code_original IS NOT NULL)
|
|
|
ORDER BY NO_FICHE;
|
|
|
|
|
|
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 NO_FICHE::bigint as MEDE_ID_MEDE,
|
|
|
INITIALES || NO_FICHE AS MEDE_CODE,
|
|
|
base.cti_soundex_nom(PERSONNEL.NOM) AS MEDE_NOM_USU_SOUNDEX,
|
|
|
base.cti_soundex_nom(COALESCE(PERSONNEL.PRENOM,'')) AS MEDE_PRENOM_SOUNDEX,
|
|
|
PERSONNEL.NOM AS MEDE_NOM_USU,
|
|
|
COALESCE(PERSONNEL.PRENOM,'') AS MEDE_PRENOM,
|
|
|
COALESCE(ADELI_RPPS,'') AS MEDI_ADELI,
|
|
|
COALESCE(t_medecins_administratifs.medecin_id,0) as medecin_id,
|
|
|
CODE_SPECIALITE
|
|
|
FROM prod_dai.PERSONNEL
|
|
|
LEFT JOIN activite[PX].t_medecins_administratifs ON NO_FICHE = t_medecins_administratifs.code_original
|
|
|
WHERE 1=1
|
|
|
AND length(trim(INITIALES)) > 0
|
|
|
;
|
|
|
|
|
|
|
|
|
INSERT INTO base.t_medecins(nom, prenom, numero_ordre, specialite_id)
|
|
|
SELECT w_medecins.MEDE_NOM_USU, w_medecins.MEDE_PRENOM, w_medecins.MEDI_ADELI, 0 FROM
|
|
|
(SELECT SUBSTR(MEDE_NOM_USU_SOUNDEX, 1, 8) AS MEDE_NOM_USU_SOUNDEX, SUBSTR(MEDE_PRENOM_SOUNDEX, 1, 8) AS MEDE_PRENOM_SOUNDEX, MEDI_ADELI, MIN(MEDE_ID_MEDE) AS MEDE_ID_MEDE
|
|
|
FROM w_medecins
|
|
|
GROUP BY 1,2,3) subview, w_medecins
|
|
|
WHERE w_medecins.MEDE_ID_MEDE = subview.MEDE_ID_MEDE
|
|
|
AND subview.MEDE_NOM_USU_SOUNDEX || ',' || subview.MEDE_PRENOM_SOUNDEX || ',' || subview.MEDI_ADELI 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.MEDE_NOM_USU, w_medecins.MEDE_PRENOM, w_medecins.MEDI_ADELI, 0 FROM
|
|
|
(SELECT MEDE_NOM_USU_SOUNDEX, MEDE_PRENOM_SOUNDEX, MIN(MEDE_ID_MEDE) AS MEDE_ID_MEDE
|
|
|
FROM w_medecins
|
|
|
GROUP BY 1,2) subview, w_medecins
|
|
|
WHERE w_medecins.MEDE_ID_MEDE = subview.MEDE_ID_MEDE
|
|
|
AND subview.MEDE_NOM_USU_SOUNDEX || ',' || subview.MEDE_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(MEDE_NOM_USU_SOUNDEX, 1, 8) = subview.nom
|
|
|
AND SUBSTR(MEDE_PRENOM_SOUNDEX, 1, 8) = subview.prenom
|
|
|
AND MEDI_ADELI = 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(MEDE_NOM_USU_SOUNDEX, 1, 8) = subview.nom
|
|
|
AND SUBSTR(MEDE_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 MEDE_ID_MEDE, MEDE_CODE, MEDE_NOM_USU, MEDE_PRENOM, COALESCE(t_specialites_medecin.oid,0), medecin_id
|
|
|
FROM w_medecins
|
|
|
LEFT JOIN base.t_specialites_medecin ON (CODE_SPECIALITE::bigint = t_specialites_medecin.code)
|
|
|
WHERE MEDE_ID_MEDE NOT IN (SELECT code_original FROM activite[PX].t_medecins_administratifs);
|
|
|
|
|
|
UPDATE activite[PX].t_medecins_administratifs
|
|
|
SET nom = MEDE_NOM_USU,
|
|
|
prenom = MEDE_PRENOM,
|
|
|
specialite_id = COALESCE(t_specialites_medecin.oid,t_specialites_medecin_2.oid,0),
|
|
|
medecin_id = w_medecins.medecin_id,
|
|
|
no_adeli = MEDI_ADELI
|
|
|
FROM w_medecins
|
|
|
LEFT JOIN base.t_specialites_medecin ON (CODE_SPECIALITE || '..' = t_specialites_medecin.code)
|
|
|
LEFT JOIN base.t_specialites_medecin t_specialites_medecin_2 ON (CODE_SPECIALITE = t_specialites_medecin_2.code)
|
|
|
WHERE w_medecins.MEDE_ID_MEDE = t_medecins_administratifs.code_original
|
|
|
AND (
|
|
|
t_medecins_administratifs.nom <> MEDE_NOM_USU OR
|
|
|
t_medecins_administratifs.prenom <> MEDE_PRENOM OR
|
|
|
t_medecins_administratifs.specialite_id <> COALESCE(t_specialites_medecin.oid,t_specialites_medecin_2.oid,0) OR
|
|
|
t_medecins_administratifs.medecin_id <> w_medecins.medecin_id OR
|
|
|
t_medecins_administratifs.no_adeli <> w_medecins.MEDI_ADELI
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].t_medecins_administratifs
|
|
|
SET specialite_id = subview.specialite_medecin_id
|
|
|
FROM
|
|
|
(
|
|
|
SELECT t_medecins_administratifs.oid,t_specialites_medecin.oid AS specialite_medecin_id
|
|
|
FROM activite[PX].t_medecins_administratifs
|
|
|
JOIN base.t_specialites_medecin t_specialites_medecin_2 ON specialite_id = t_specialites_medecin_2.oid
|
|
|
JOIN base.t_specialites_medecin ON t_specialites_medecin_2.code || '..' = t_specialites_medecin.code
|
|
|
) subview
|
|
|
WHERE t_medecins_administratifs.oid = subview.oid;
|
|
|
|
|
|
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;
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Hébergement">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
-- Modes de traitement
|
|
|
|
|
|
INSERT INTO base.t_modes_traitement(code, texte, texte_court)
|
|
|
SELECT CODE_MT, SIGNATAIRE, NOM
|
|
|
FROM prod_dai.POP_LISTES
|
|
|
WHERE CODE_MT <> ''
|
|
|
AND CODE_MT NOT IN (SELECt code FROM base.t_modes_traitement)
|
|
|
ORDER BY CODE_MT;
|
|
|
|
|
|
-- DMT
|
|
|
|
|
|
INSERT INTO base.t_dmt(code, texte, texte_court)
|
|
|
SELECT
|
|
|
CODE_DMT, 'Post_cure pour alcooliques','Post_cure pour alcooliques'
|
|
|
FROM prod_dai.POP_LISTES
|
|
|
WHERE CODE_DMT <> ''
|
|
|
AND CODE_DMT NOT IN (SELECt code FROM base.t_dmt)
|
|
|
ORDER BY CODE_DMT;
|
|
|
|
|
|
-- Services
|
|
|
|
|
|
INSERT INTO activite[PX].t_services_facturation(oid, code_original, code, texte, texte_court)
|
|
|
SELECT 0, 0, '****', 'Non renseigné', 'Non renseigné' WHERE 0 NOT IN (SELECt oid FROM activite[PX].t_services_facturation);
|
|
|
|
|
|
DROP TABLE IF EXISTS w_services
|
|
|
;
|
|
|
INSERT INTO activite[PX].t_services_facturation(code_original, code, texte, texte_court, type_t2a)
|
|
|
SELECT
|
|
|
NOM,
|
|
|
NOM,
|
|
|
SIGNATAIRE,
|
|
|
SIGNATAIRE,
|
|
|
CASE WHEN PMSI_UNITE_MEDICALE <> '' THEN 1 ELSE 0 END
|
|
|
FROM
|
|
|
prod_dai.POP_LISTES
|
|
|
WHERE
|
|
|
CODE_DMT != ''
|
|
|
AND NOM NOT IN (SELECT code_original FROM activite[PX].t_services_facturation WHERE code_original IS NOT NULL )
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].t_services_facturation
|
|
|
SET mode_traitement_id = subview.mode_traitement_id, dmt_id = subview.dmt_id
|
|
|
FROM (
|
|
|
SELECT NOM, COALESCE(t_modes_traitement.oid,0) as mode_traitement_id, COALESCE(t_dmt.oid,0) as dmt_id
|
|
|
FROM prod_dai.POP_LISTES
|
|
|
LEFT JOIN base.t_modes_traitement ON CODE_MT = t_modes_traitement.code
|
|
|
LEFT JOIN base.t_dmt ON CODE_DMT = t_dmt.code
|
|
|
WHERE
|
|
|
CODE_DMT != ''
|
|
|
AND (t_modes_traitement.oid IS NOT NULL OR t_dmt.oid IS NOT NULL)
|
|
|
) subview
|
|
|
WHERE code_original = NOM AND (t_services_facturation.mode_traitement_id = 0 OR t_services_facturation.dmt_id = 0);
|
|
|
|
|
|
INSERT INTO activite[PX].t_services_facturation(code_original, code, texte, texte_court, est_absence)
|
|
|
SELECT '*ABS', '*ABS', 'Absence', 'Absence', '1' WHERE '*ABS' NOT IN (SELECT code_original FROM activite[PX].t_services_facturation);
|
|
|
|
|
|
|
|
|
-- Unités médicales (idem service)
|
|
|
|
|
|
INSERT INTO activite[PX].t_unites_medicales(oid, code_original, code, texte, texte_court)
|
|
|
SELECT 0, 0, '', 'Non renseignée', 'Non renseignée' WHERE 0 NOT IN (SELECt oid FROM activite[PX].t_unites_medicales);
|
|
|
|
|
|
INSERT INTO activite[PX].t_unites_medicales(code_original, code, texte, texte_court)
|
|
|
SELECT
|
|
|
NO_FICHE,
|
|
|
NOM,
|
|
|
SIGNATAIRE,
|
|
|
SIGNATAIRE
|
|
|
FROM
|
|
|
prod_dai.POP_LISTES
|
|
|
WHERE
|
|
|
CODE_DMT != ''
|
|
|
AND NO_FICHE NOT IN (SELECT code_original FROM activite[PX].t_unites_medicales WHERE code_original IS NOT NULL )
|
|
|
GROUP BY 1,2,3,4
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite[PX].t_unites_medicales(code_original, code, texte, texte_court)
|
|
|
SELECT '*ABS', '*ABS', 'Absence', 'Absence' WHERE '*ABS' NOT IN (SELECT code_original FROM activite[PX].t_unites_medicales);
|
|
|
|
|
|
-- Unités fonctionnelles (services dai)
|
|
|
|
|
|
INSERT INTO activite[PX].t_unites_fonctionnelles(oid, code_original, code, texte, texte_court)
|
|
|
SELECT 0, 0, '', 'Non renseignée', 'Non renseignée' WHERE 0 NOT IN (SELECt oid FROM activite[PX].t_unites_fonctionnelles);
|
|
|
|
|
|
INSERT INTO activite[PX].t_unites_fonctionnelles(code_original, code, texte, texte_court)
|
|
|
SELECT NO_FICHE, INITIALES AS UNFO_CODE, NOM, NOM
|
|
|
FROM prod_dai.POP_LISTES
|
|
|
WHERE
|
|
|
NO_FICHE NOT IN (SELECT code_original FROM activite[PX].t_unites_fonctionnelles)
|
|
|
AND TITRE_POP = 'Services'
|
|
|
ORDER BY NO_FICHE;
|
|
|
|
|
|
INSERT INTO activite[PX].t_unites_fonctionnelles(code_original, code, texte, texte_court)
|
|
|
SELECT '*ABS', '*ABS', 'Absence', 'Absence' WHERE '*ABS' NOT IN (SELECT code_original FROM activite[PX].t_unites_fonctionnelles);
|
|
|
|
|
|
-- Activités (um principale)
|
|
|
|
|
|
INSERT INTO activite[PX].t_activites(oid, code_original, code, texte, texte_court)
|
|
|
SELECT 0, 0, '', 'Non renseignée', 'Non renseignée' WHERE 0 NOT IN (SELECt oid FROM activite[PX].t_activites);
|
|
|
|
|
|
|
|
|
-- Etages et lits
|
|
|
|
|
|
INSERT INTO activite[PX].t_etages(oid, code_original, code, texte, texte_court, nb_lits)
|
|
|
SELECT 0, 0, '', 'Non renseigné', 'Non renseigné', 0 WHERE 0 NOT IN (SELECT oid FROM activite[PX].t_etages);
|
|
|
|
|
|
INSERT INTO activite[PX].t_etages(code_original, code, texte, texte_court)
|
|
|
SELECT NO_FICHE, NO_FICHE, NOM, NOM
|
|
|
FROM prod_dai.POP_LISTEs
|
|
|
WHERE
|
|
|
TITRE_POP = 'Pavillons' AND
|
|
|
NO_FICHE::bigint NOT IN (SELECT code_original FROM activite[PX].t_etages WHERE code_original IS NOT NULL )
|
|
|
ORDER BY NO_FICHE;
|
|
|
|
|
|
-- Attention, double définition de lits sur un étage
|
|
|
DROP TABLE IF EXISTS w_LITS;
|
|
|
CREATE TEMP TABLE w_LITS AS
|
|
|
SELECT *
|
|
|
FROM prod_dai.LITS
|
|
|
;
|
|
|
|
|
|
UPDATE w_LITS
|
|
|
SET NUMERO = w_LITS.NUMERO || '-' || w_LITS.NO_FICHE
|
|
|
FROM
|
|
|
(
|
|
|
SELECT PAVILLON, NUMERO, MAX(CASE WHEN INACTIF = 'false' THEN NO_FICHE ELSE 0 END) AS OK_FICHE
|
|
|
FROM w_LITS
|
|
|
GROUP BY 1,2
|
|
|
HAVING count(*) > 1
|
|
|
) SUBVIEW
|
|
|
WHERE w_LITS.PAVILLON = subview.PAVILLON AND
|
|
|
w_LITS.NUMERO = subview.NUMERO AND
|
|
|
w_LITS.NO_FICHE <> subview.OK_FICHE
|
|
|
;
|
|
|
|
|
|
UPDATE activite[PX].t_lits SET
|
|
|
code = NUMERO,
|
|
|
texte = NUMERO,
|
|
|
texte_court = NUMERO,
|
|
|
etage_id = t_etages.oid
|
|
|
FROM w_LITS LITS, activite[PX].t_etages
|
|
|
WHERE
|
|
|
NO_FICHE::bigint = t_lits.code_original
|
|
|
AND PAVILLON::bigint = t_etages.code_original;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_lits(code_original, code, texte, texte_court, etage_id, chambre_particuliere)
|
|
|
SELECT NO_FICHE, NUMERO, NUMERO, NUMERO, t_etages.oid, CASE WHEN CH_PART = 'true' THEN 'O' ELSE 'N' END AS CHAS_IND_CP
|
|
|
FROM w_LITS LITS, activite[PX].t_etages
|
|
|
WHERE
|
|
|
PAVILLON = t_etages.code_original
|
|
|
AND NO_FICHE::bigint NOT IN (SELECT code_original FROM activite[PX].t_lits WHERE code_original IS NOT NULL );
|
|
|
|
|
|
-- Anciennes versions d'étages par lit (pas d'exemple dans la base de prod)
|
|
|
|
|
|
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
|
|
|
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 code = '';
|
|
|
]]></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);
|
|
|
|
|
|
INSERT INTO activite[PX].t_rubriques_facturation(code_original, code, texte, texte_court)
|
|
|
SELECT '*CTI_ACO85', 'ACO85', 'Acomptes 85%', 'Acomptes 85%'
|
|
|
WHERE '*CTI_ACO85' NOT IN (SELECT code_original FROM activite[PX].t_rubriques_facturation);
|
|
|
|
|
|
INSERT INTO activite[PX].t_rubriques_facturation(code_original, code, texte, texte_court)
|
|
|
SELECT '*CTI_ACO', 'ACOMPTE', 'Acomptes', 'Acomptes'
|
|
|
WHERE '*CTI_ACO' NOT IN (SELECT code_original FROM activite[PX].t_rubriques_facturation);
|
|
|
|
|
|
|
|
|
-- actes ligne fac
|
|
|
DROP TABLE IF EXISTS w_TARIFS;
|
|
|
CREATE TEMP TABLE w_TARIFS AS
|
|
|
SELECT ACTE, (MAX(ARRAY[A_PARTIR_DU::text,COALESCE(LIBELLE_FACTURE, ACTE)]))[2] AS LIBELLE_FACTURE
|
|
|
FROM prod_dai.TARIFS
|
|
|
GROUP BY 1
|
|
|
;
|
|
|
|
|
|
ANALYSE w_TARIFS
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite[PX].t_rubriques_facturation(code_original, code, texte, texte_court)
|
|
|
SELECT ACTE, ACTE, MAX(LIBELLE_FACTURE), MAX(LIBELLE_FACTURE)
|
|
|
FROM w_TARIFS TARIFS
|
|
|
WHERE
|
|
|
ACTE NOT IN (SELECT code_original FROM activite[PX].t_rubriques_facturation)
|
|
|
GROUP BY ACTE
|
|
|
ORDER BY ACTE
|
|
|
;
|
|
|
|
|
|
|
|
|
-- table tarifs + ?
|
|
|
INSERT INTO activite.t_prestations(code_original, code, texte, texte_court)
|
|
|
SELECT ACTE, ACTE, MAX(LIBELLE_FACTURE), MAX(LIBELLE_FACTURE)
|
|
|
FROM w_TARIFS TARIFS
|
|
|
WHERE
|
|
|
ACTE NOT IN (SELECT code FROM activite.t_prestations)
|
|
|
GROUP BY ACTE
|
|
|
ORDER BY ACTE
|
|
|
;
|
|
|
|
|
|
INSERT INTO activite.t_prestations(code_original, code, texte, texte_court)
|
|
|
SELECT '*CTI_ACO85', 'ACO85', 'Acomptes 85%', 'Acomptes 85%'
|
|
|
WHERE '*CTI_ACO85' NOT IN (SELECT code_original FROM activite.t_prestations WHERE code_original IS NOT NULL);
|
|
|
|
|
|
INSERT INTO activite.t_prestations(code_original, code, texte, texte_court)
|
|
|
SELECT '*CTI_ACO', 'ACOMPTE', 'Acomptes', 'Acomptes'
|
|
|
WHERE '*CTI_ACO' NOT IN (SELECT code_original FROM activite.t_prestations WHERE code_original IS NOT NULL);
|
|
|
|
|
|
--
|
|
|
-- UPDATE activite[PX].t_protocoles SET
|
|
|
-- code = FAVO_CODE::text,
|
|
|
-- texte = FAVO_LIBELLE::text,
|
|
|
-- texte_court = FAVO_LIBELLE::text
|
|
|
-- FROM
|
|
|
-- prod_dai.SAD_FAVORIS
|
|
|
-- WHERE 1=1
|
|
|
-- AND FAVO_ID_FAVO = t_protocoles.code_original
|
|
|
-- AND (FAVO_CODE <> t_protocoles.code OR FAVO_LIBELLE <> t_protocoles.texte);
|
|
|
--
|
|
|
--
|
|
|
-- INSERT INTO activite[PX].t_protocoles(oid, code_original, code, texte, texte_court)
|
|
|
-- SELECT 0, 0, '***', 'Non renseigné', 'Non renseigné' WHERE 0 NOT IN (SELECT oid FROM activite[PX].t_protocoles);
|
|
|
--
|
|
|
-- INSERT INTO activite[PX].t_protocoles(code_original, code, texte, texte_court)
|
|
|
-- SELECT FAVO_ID_FAVO::bigint, FAVO_CODE, FAVO_LIBELLE, FAVO_LIBELLE
|
|
|
-- FROM prod_dai.SAD_FAVORIS
|
|
|
-- WHERE FAVO_ID_FAVO IN (SELECT LFAC_ID_FAVO FROM prod_dai.FAC_LIGNE_FACTURE GROUP BY 1) AND
|
|
|
-- FAVO_ID_FAVO::bigint NOT IN (SELECT code_original FROM activite[PX].t_protocoles)
|
|
|
-- ORDER BY FAVO_CODE;
|
|
|
--
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="POST" label="TRAITEMENTS COMPLEMENTAIRES">
|
|
|
|
|
|
<NODE label="Compléments facture">
|
|
|
<sqlcmd><![CDATA[
|
|
|
ANALYSE activite.p_sejours;
|
|
|
ANALYSE activite.p_factures;
|
|
|
ANALYSE activite.p_factures_lignes_c;
|
|
|
ANALYSE activite.p_factures_lignes_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,
|
|
|
p_sejours.code_sorti,
|
|
|
p_sejours.date_sortie,
|
|
|
p_sejours.date_groupage,
|
|
|
p_sejours.ghs_id,
|
|
|
|
|
|
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,
|
|
|
|
|
|
0::numeric AS delai_groupage,
|
|
|
0::numeric AS delai_facture,
|
|
|
0::numeric AS delai_expedition,
|
|
|
0::numeric AS delai_solde,
|
|
|
0::numeric AS delai_expedition_0,
|
|
|
0::numeric AS delai_solde_0,
|
|
|
0::numeric AS delai_expedition_1,
|
|
|
0::numeric AS delai_solde_1,
|
|
|
0::numeric AS delai_expedition_2,
|
|
|
0::numeric AS delai_solde_2,
|
|
|
0::numeric AS delai_expedition_22,
|
|
|
0::numeric AS delai_solde_22
|
|
|
|
|
|
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 1,2,3,4,5;
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_sejours
|
|
|
SET date_groupage = date_facture
|
|
|
WHERE (date_groupage IS null OR date_groupage = '20991231' OR date_groupage = '00010101') AND
|
|
|
date_facture <> '2099-12-31';
|
|
|
|
|
|
|
|
|
UPDATE w_sejours_total SET
|
|
|
date_groupage = CASE WHEN date_groupage > '00010101' THEN date_groupage ELSE '20991231' END,
|
|
|
date_facture = CASE WHEN date_facture> '00010101' THEN date_facture ELSE '20991231' END,
|
|
|
date_expedition = CASE WHEN date_expedition > '00010101' THEN date_expedition ELSE '20991231' END,
|
|
|
date_solde = CASE WHEN date_solde > '00010101' THEN date_solde ELSE '20991231' END,
|
|
|
date_expedition_0 = CASE WHEN date_expedition_0 > '00010101' THEN date_expedition_0 ELSE '20991231' END,
|
|
|
date_solde_0 = CASE WHEN date_solde_0 > '00010101' THEN date_solde_0 ELSE '20991231' END,
|
|
|
date_expedition_1 = CASE WHEN date_expedition_1 > '00010101' THEN date_expedition_1 ELSE '20991231' END,
|
|
|
date_solde_1 = CASE WHEN date_solde_1 > '00010101' THEN date_solde_1 ELSE '20991231' END,
|
|
|
date_expedition_2 = CASE WHEN date_expedition_2 > '00010101' THEN date_expedition_2 ELSE '20991231' END,
|
|
|
date_solde_2 = CASE WHEN date_solde_2 > '00010101' THEN date_solde_2 ELSE '20991231' END,
|
|
|
date_expedition_22 = CASE WHEN date_expedition_22 > '00010101' THEN date_expedition_22 ELSE '20991231' END,
|
|
|
date_solde_22 = CASE WHEN date_solde_22 > '00010101' THEN date_solde_22 ELSE '20991231' END;
|
|
|
|
|
|
|
|
|
UPDATE w_sejours_total SET
|
|
|
delai_groupage = LEAST(99999,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 = LEAST(99999,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 = LEAST(99999,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 = LEAST(99999,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 = LEAST(99999,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 = LEAST(99999,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 = LEAST(99999,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 = LEAST(99999,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 = LEAST(99999,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 = LEAST(99999,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 = LEAST(99999,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 = LEAST(99999,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);
|
|
|
|
|
|
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 = w_sejours_total.date_expedition_0,
|
|
|
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 = w_sejours_total.date_expedition_1,
|
|
|
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 = w_sejours_total.date_expedition_2,
|
|
|
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 = w_sejours_total.date_expedition_22,
|
|
|
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,
|
|
|
|
|
|
|
|
|
delai_groupage = w_sejours_total.delai_groupage,
|
|
|
delai_facture = w_sejours_total.delai_facture,
|
|
|
delai_expedition = w_sejours_total.delai_expedition,
|
|
|
delai_solde = w_sejours_total.delai_solde,
|
|
|
delai_expedition_0 = w_sejours_total.delai_expedition_0,
|
|
|
delai_solde_0 = w_sejours_total.delai_solde_0,
|
|
|
delai_expedition_1 = w_sejours_total.delai_expedition_1,
|
|
|
delai_solde_1 = w_sejours_total.delai_solde_1,
|
|
|
delai_expedition_2 = w_sejours_total.delai_expedition_2,
|
|
|
delai_solde_2 = w_sejours_total.delai_solde_2,
|
|
|
delai_expedition_22 = w_sejours_total.delai_expedition_22,
|
|
|
delai_solde_22 = w_sejours_total.delai_solde_22
|
|
|
|
|
|
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 w_sejours_total.date_expedition_0 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 w_sejours_total.date_expedition_1 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 w_sejours_total.date_expedition_2 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 w_sejours_total.date_expedition_22 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 OR
|
|
|
|
|
|
p_sejours.delai_groupage IS DISTINCT FROM w_sejours_total.delai_groupage OR
|
|
|
p_sejours.delai_facture IS DISTINCT FROM w_sejours_total.delai_facture OR
|
|
|
p_sejours.delai_expedition IS DISTINCT FROM w_sejours_total.delai_expedition OR
|
|
|
p_sejours.delai_solde IS DISTINCT FROM w_sejours_total.delai_solde OR
|
|
|
p_sejours.delai_expedition_0 IS DISTINCT FROM w_sejours_total.delai_expedition_0 OR
|
|
|
p_sejours.delai_solde_0 IS DISTINCT FROM w_sejours_total.delai_solde_0 OR
|
|
|
p_sejours.delai_expedition_1 IS DISTINCT FROM w_sejours_total.delai_expedition_1 OR
|
|
|
p_sejours.delai_solde_1 IS DISTINCT FROM w_sejours_total.delai_solde_1 OR
|
|
|
p_sejours.delai_expedition_2 IS DISTINCT FROM w_sejours_total.delai_expedition_2 OR
|
|
|
p_sejours.delai_solde_2 IS DISTINCT FROM w_sejours_total.delai_solde_2 OR
|
|
|
p_sejours.delai_expedition_22 IS DISTINCT FROM w_sejours_total.delai_expedition_22 OR
|
|
|
p_sejours.delai_solde_22 IS DISTINCT FROM w_sejours_total.delai_solde_22
|
|
|
|
|
|
);
|
|
|
|
|
|
-- Suppression des tables de travail non utilisées après
|
|
|
DROP TABLE IF EXISTS w_sejours_total CASCADE;
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Référencements">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'dursej', date_sortie - date_entree
|
|
|
FROM activite[PX].p_sejours
|
|
|
WHERE date_sortie - date_entree NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'dursej')
|
|
|
AND date_sortie >= date_entree
|
|
|
AND date_sortie < '2099-12-31'::date
|
|
|
GROUP BY 2
|
|
|
ORDER BY 2;
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'c_postaux', code_postal_id
|
|
|
FROM activite[PX].p_sejours
|
|
|
WHERE code_postal_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'c_postaux')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'medecin_s', medecin_sejour_id
|
|
|
FROM activite[PX].p_sejours
|
|
|
WHERE medecin_sejour_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'medecin_s')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'medecin_s', medecin_sejour_id
|
|
|
FROM activite[PX].p_mouvements_sejour
|
|
|
WHERE medecin_sejour_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'medecin_s')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'ghs', ghs_id
|
|
|
FROM activite[PX].p_sejours
|
|
|
WHERE ghs_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'ghs')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'ghs', ghs_id
|
|
|
FROM activite[PX].p_factures
|
|
|
WHERE ghs_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'ghs')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'medecin_x', medecin_facture_id
|
|
|
FROM activite[PX].p_factures_lignes_h
|
|
|
WHERE medecin_facture_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'medecin_x')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'rubrique_c', rubrique_facturation_id
|
|
|
FROM activite[PX].p_factures_lignes_c WHERE rubrique_facturation_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'rubrique_c')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'rubrique_c', rubrique_comptabilisation_id
|
|
|
FROM activite[PX].p_factures_lignes_c WHERE rubrique_comptabilisation_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'rubrique_c')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'rubrique_c', rubrique_comptabilisee_id
|
|
|
FROM activite[PX].p_factures_soldes_c WHERE rubrique_comptabilisee_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'rubrique_c')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'prestation_c', prestation_id
|
|
|
FROM activite[PX].p_factures_lignes_c WHERE prestation_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'prestation_c')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'prestation_c', prestation_id
|
|
|
FROM activite[PX].p_factures_soldes_c WHERE prestation_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'prestation_c')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'prestation_c', prestation_id
|
|
|
FROM activite[PX].p_factures_encours_lignes_c WHERE prestation_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'prestation_c')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'prestation_h', prestation_id
|
|
|
FROM activite[PX].p_factures_lignes_h WHERE prestation_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'prestation_h')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'acte_h', acte_id
|
|
|
FROM activite[PX].p_factures_lignes_h WHERE acte_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'acte_h')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'protocole_h', protocole_id
|
|
|
FROM activite[PX].p_factures_lignes_h WHERE protocole_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'protocole_h')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'tiers_payant', tiers_payant_0_id
|
|
|
FROM activite[PX].p_factures WHERE tiers_payant_0_id <> 0 AND tiers_payant_0_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'tiers_payant')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'tiers_payant', tiers_payant_1_id
|
|
|
FROM activite[PX].p_factures WHERE tiers_payant_1_id <> 0 AND tiers_payant_1_id NOT IN (SELECT oid
|
|
|
FROM activite[PX].p_oids WHERE code_table = 'tiers_payant')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'tiers_payant', tiers_payant_2_id
|
|
|
FROM activite[PX].p_factures WHERE tiers_payant_2_id <> 0 AND tiers_payant_2_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'tiers_payant')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'tiers_payant', tiers_payant_22_id
|
|
|
FROM activite[PX].p_factures WHERE tiers_payant_22_id <> 0 AND tiers_payant_22_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'tiers_payant')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'mode_traitement', t_services_facturation.mode_traitement_id
|
|
|
FROM activite[PX].t_lieux JOIN activite[PX].t_services_facturation ON service_facturation_id = t_services_facturation.oid
|
|
|
WHERE
|
|
|
t_services_facturation.mode_traitement_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'mode_traitement' AND oid IS NOT NULL) AND t_services_facturation.mode_traitement_id IS NOT NULL
|
|
|
GROUP BY 2;
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'lit', lit_id
|
|
|
FROM activite[PX].t_lieux WHERE lit_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'lit')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'service', service_facturation_id
|
|
|
FROM activite[PX].t_lieux WHERE service_facturation_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'service')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'etage', etage_id
|
|
|
FROM activite[PX].t_lieux, activite[PX].t_lits WHERE lit_id = t_lits.oid AND etage_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'etage')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
INSERT INTO activite[PX].p_oids (code_table, oid)
|
|
|
SELECT 'gme', gme_id
|
|
|
FROM activite[PX].p_sejours
|
|
|
WHERE gme_id NOT IN (SELECT oid FROM activite[PX].p_oids WHERE code_table = 'gme')
|
|
|
GROUP BY 2;
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Tables répliquées">
|
|
|
|
|
|
<condition><![CDATA[
|
|
|
"[PX]" == ""
|
|
|
]]></condition>
|
|
|
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="ENCOURS" label="ENCOURS ET VALORISATION DES NON FACTURES">
|
|
|
|
|
|
<NODE label="Encours DAI">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
</ROOT>
|