|
|
<?xml version="1.0" encoding="ISO-8859-1"?>
|
|
|
<ROOT>
|
|
|
|
|
|
|
|
|
<NODE name="INIT" label="INITIALISATIONS">
|
|
|
|
|
|
<NODE label="Identification des séjours">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
-- Factures sur des anciens dossiers
|
|
|
|
|
|
DROP TABLE IF EXISTS w_G_SP3;
|
|
|
CREATE TEMP TABLE w_G_SP3 AS
|
|
|
SELECT * FROM prod_calystene.G_SP3;
|
|
|
|
|
|
CREATE INDEX w_G_SP3_i1
|
|
|
ON w_G_SP3
|
|
|
USING btree
|
|
|
(NUM_ENTREE);
|
|
|
|
|
|
|
|
|
UPDATE w_G_SP3
|
|
|
SET NUM_ENTREE = SEJOUR.NUM_ADMINISTRATIF
|
|
|
FROM prod_calystene.G_ENTREE
|
|
|
JOIN prod_calystene.SEJOUR ON G_ENTREE.NUM_DEM_ADM = SEJOUR.NUM_DEM_ADM
|
|
|
WHERE w_G_SP3.NUM_ENTREE = G_ENTREE.NUM_ENTREE AND
|
|
|
w_G_SP3.NUM_ENTREE IS DISTINCT FROM SEJOUR.NUM_ADMINISTRATIF;
|
|
|
|
|
|
-- Séjours à traiter
|
|
|
|
|
|
DROP TABLE IF EXISTS w_SEJOUR_ok;
|
|
|
CREATE TEMP TABLE w_SEJOUR_ok AS
|
|
|
SELECT
|
|
|
BON_A_FACTURER,
|
|
|
CH,
|
|
|
CH_ENT,
|
|
|
CHG_HOSP,
|
|
|
CMT_ENT,
|
|
|
CMT_SORT,
|
|
|
CMT_URG,
|
|
|
CODE_UFR,
|
|
|
CODE_UFR_ENT,
|
|
|
''::text AS CODE_SER_ENT,
|
|
|
CP_URG,
|
|
|
CR,
|
|
|
CR_ENT,
|
|
|
DATE_CRE,
|
|
|
DATE_ENTREE,
|
|
|
DATE_SORT_REEL,
|
|
|
DATE_SORTIE_PREV,
|
|
|
DELAI_PREV_REEL,
|
|
|
HEURE_ENTREE,
|
|
|
MODE_ENTREE,
|
|
|
NUM,
|
|
|
NUM_ADMINISTRATIF::text,
|
|
|
NUM_DEM_ADM,
|
|
|
NUM_DOS_AD,
|
|
|
NUM_ETAB_PROV,
|
|
|
NUM_LIT,
|
|
|
NUM_LIT_ENT,
|
|
|
NUM_MED_RESP,
|
|
|
SEJ_PREC,
|
|
|
SEJ_SUIV,
|
|
|
SS_UF,
|
|
|
SS_UF_ENT,
|
|
|
TYPE_ABSENCE,
|
|
|
TYPE_ADM,
|
|
|
TYPE_ENTREE,
|
|
|
TYPE_HOSP,
|
|
|
TYPE_HOSP_ENT,
|
|
|
TYPE_PROVENANCE,
|
|
|
UF,
|
|
|
UF_ENT,
|
|
|
PERS_CONF,
|
|
|
'N'::text AS OK
|
|
|
FROM prod_calystene.SEJOUR;
|
|
|
|
|
|
|
|
|
UPDATE w_SEJOUR_ok
|
|
|
SET DATE_SORT_REEL = DATE_ENTREE
|
|
|
WHERE TYPE_ENTREE = '9'
|
|
|
;
|
|
|
|
|
|
|
|
|
UPDATE w_SEJOUR_ok
|
|
|
SET OK = 'O'
|
|
|
WHERE DATE_ENTREE >= '20090101' OR DATE_SORT_REEL >= '20090101' OR DATE_SORT_REEL IS NULL OR
|
|
|
NUM_ADMINISTRATIF IN (SELECT NUM_ENTREE FROM w_G_SP3 G_SP3 WHERE DT_LANC >= '20090101' OR DT_FACTURE >= '20090101')
|
|
|
;
|
|
|
|
|
|
|
|
|
-- Correction SEJOUR n° interne en double
|
|
|
UPDATE w_SEJOUR_ok
|
|
|
SET NUM_DEM_ADM = subview.NUM_DEM_ADM + 10000000
|
|
|
FROM
|
|
|
(SELECT NUM_DEM_ADM, MIN(w_SEJOUR_ok.NUM) AS NUM
|
|
|
FROM w_SEJOUR_ok
|
|
|
WHERE OK = 'O'
|
|
|
GROUP BY 1
|
|
|
HAVING COUNT(*) > 1
|
|
|
) subview
|
|
|
WHERE w_SEJOUR_ok.NUM_DEM_ADM = subview.NUM_DEM_ADM AND w_SEJOUR_ok.NUM = subview.NUM;
|
|
|
|
|
|
|
|
|
-- Correction SEJOUR (numéro, de sejour en double)
|
|
|
|
|
|
UPDATE w_SEJOUR_ok
|
|
|
SET NUM_ADMINISTRATIF = NUM_DEM_ADM
|
|
|
WHERE NUM_ADMINISTRATIF = '';
|
|
|
|
|
|
|
|
|
UPDATE w_SEJOUR_ok
|
|
|
SET NUM_ADMINISTRATIF = subview.NUM_ADMINISTRATIF || '-1'
|
|
|
FROM
|
|
|
(SELECT NUM_ADMINISTRATIF, (min(Array[DATE_ENTREE::text, NUM_DEM_ADM::text]))[2]::numeric AS NUM_DEM_ADM
|
|
|
FROM w_SEJOUR_ok
|
|
|
WHERE OK = 'O'
|
|
|
GROUP BY 1
|
|
|
HAVING COUNT(*) > 1
|
|
|
) subview
|
|
|
WHERE w_SEJOUR_ok.NUM_DEM_ADM = subview.NUM_DEM_ADM AND w_SEJOUR_ok.OK = 'O';
|
|
|
|
|
|
UPDATE w_SEJOUR_ok
|
|
|
SET NUM_ADMINISTRATIF = subview.NUM_ADMINISTRATIF || '-2'
|
|
|
FROM
|
|
|
(SELECT NUM_ADMINISTRATIF, (min(Array[DATE_ENTREE::text, NUM_DEM_ADM::text]))[2]::numeric AS NUM_DEM_ADM
|
|
|
FROM w_SEJOUR_ok
|
|
|
WHERE OK = 'O'
|
|
|
GROUP BY 1
|
|
|
HAVING COUNT(*) > 1
|
|
|
) subview
|
|
|
WHERE w_SEJOUR_ok.NUM_DEM_ADM = subview.NUM_DEM_ADM AND w_SEJOUR_ok.OK = 'O';
|
|
|
|
|
|
UPDATE w_SEJOUR_ok
|
|
|
SET NUM_ADMINISTRATIF = subview.NUM_ADMINISTRATIF || '-3'
|
|
|
FROM
|
|
|
(SELECT NUM_ADMINISTRATIF, (min(Array[DATE_ENTREE::text, NUM_DEM_ADM::text]))[2]::numeric AS NUM_DEM_ADM
|
|
|
FROM w_SEJOUR_ok
|
|
|
WHERE OK = 'O'
|
|
|
GROUP BY 1
|
|
|
HAVING COUNT(*) > 1
|
|
|
) subview
|
|
|
WHERE w_SEJOUR_ok.NUM_DEM_ADM = subview.NUM_DEM_ADM AND w_SEJOUR_ok.OK = 'O';
|
|
|
|
|
|
UPDATE w_SEJOUR_ok
|
|
|
SET NUM_ADMINISTRATIF = subview.NUM_ADMINISTRATIF || '-4'
|
|
|
FROM
|
|
|
(SELECT NUM_ADMINISTRATIF, (min(Array[DATE_ENTREE::text, NUM_DEM_ADM::text]))[2]::numeric AS NUM_DEM_ADM
|
|
|
FROM w_SEJOUR_ok
|
|
|
WHERE OK = 'O'
|
|
|
GROUP BY 1
|
|
|
HAVING COUNT(*) > 1
|
|
|
) subview
|
|
|
WHERE w_SEJOUR_ok.NUM_DEM_ADM = subview.NUM_DEM_ADM AND w_SEJOUR_ok.OK = 'O';
|
|
|
|
|
|
UPDATE w_SEJOUR_ok
|
|
|
SET NUM_ADMINISTRATIF = subview.NUM_ADMINISTRATIF || '-5'
|
|
|
FROM
|
|
|
(SELECT NUM_ADMINISTRATIF, (min(Array[DATE_ENTREE::text, NUM_DEM_ADM::text]))[2]::numeric AS NUM_DEM_ADM
|
|
|
FROM w_SEJOUR_ok
|
|
|
WHERE OK = 'O'
|
|
|
GROUP BY 1
|
|
|
HAVING COUNT(*) > 1
|
|
|
) subview
|
|
|
WHERE w_SEJOUR_ok.NUM_DEM_ADM = subview.NUM_DEM_ADM AND w_SEJOUR_ok.OK = 'O';
|
|
|
|
|
|
|
|
|
UPDATE w_SEJOUR_ok
|
|
|
SET NUM_DEM_ADM = subview.NUM_DEM_ADM + 10000000
|
|
|
FROM
|
|
|
(SELECT NUM_DEM_ADM, min(w_SEJOUR_ok.CTID) AS minCTID
|
|
|
FROM w_SEJOUR_ok
|
|
|
WHERE OK = 'O'
|
|
|
GROUP BY 1
|
|
|
HAVING COUNT(*) > 1
|
|
|
) subview
|
|
|
WHERE w_SEJOUR_ok.NUM_DEM_ADM = subview.NUM_DEM_ADM AND w_SEJOUR_ok.CTID = minCTID;
|
|
|
|
|
|
-- Service = UF + type hosp
|
|
|
|
|
|
UPDATE w_SEJOUR_ok
|
|
|
SET CODE_SER_ENT = CASE WHEN CODE_UFR_ENT <> '' THEN CODE_UFR_ENT ELSE '9999' END || '_CO'
|
|
|
WHERE OK = 'O' AND TYPE_HOSP_ENT ILIKE '%consultation%' AND CODE_SER_ENT = '';
|
|
|
|
|
|
|
|
|
UPDATE w_SEJOUR_ok
|
|
|
SET CODE_SER_ENT = CASE WHEN CODE_UFR_ENT <> '' THEN CODE_UFR_ENT ELSE '9999' END || '_HC'
|
|
|
WHERE OK = 'O' AND TYPE_HOSP_ENT ILIKE '%complete%' AND CODE_SER_ENT = '';
|
|
|
|
|
|
|
|
|
UPDATE w_SEJOUR_ok
|
|
|
SET CODE_SER_ENT = CASE WHEN CODE_UFR_ENT <> '' THEN CODE_UFR_ENT ELSE '9999' END || '_HS'
|
|
|
WHERE OK = 'O' AND TYPE_HOSP_ENT ILIKE '%semaine%' AND CODE_SER_ENT = '';
|
|
|
|
|
|
UPDATE w_SEJOUR_ok
|
|
|
SET CODE_SER_ENT = CASE WHEN CODE_UFR_ENT <> '' THEN CODE_UFR_ENT ELSE '9999' END || '_AM'
|
|
|
WHERE OK = 'O' AND TYPE_HOSP_ENT ILIKE '%ambulatoire%' AND CODE_SER_ENT = '';
|
|
|
|
|
|
UPDATE w_SEJOUR_ok
|
|
|
SET CODE_SER_ENT = CASE WHEN CODE_UFR_ENT <> '' THEN CODE_UFR_ENT ELSE '9999' END || '_HJ'
|
|
|
WHERE OK = 'O' AND TYPE_HOSP_ENT ILIKE '%jour%' AND CODE_SER_ENT = '';
|
|
|
|
|
|
-- index
|
|
|
|
|
|
ALTER TABLE w_SEJOUR_ok ADD CONSTRAINT w_SEJOUR_ok_pkey PRIMARY KEY(NUM_DEM_ADM);
|
|
|
|
|
|
CREATE INDEX w_SEJOUR_ok_i1
|
|
|
ON w_SEJOUR_ok
|
|
|
USING btree
|
|
|
(NUM_ADMINISTRATIF);
|
|
|
|
|
|
|
|
|
|
|
|
-- préparation table mutations
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MUTATION_ok;
|
|
|
CREATE TEMP TABLE w_MUTATION_ok AS
|
|
|
SELECT MUTATION.*, ''::text AS CODE_SER_DEST
|
|
|
FROM prod_calystene.MUTATION
|
|
|
JOIN w_SEJOUR_ok ON MUTATION.NUM_DEM_ADM = w_SEJOUR_ok.NUM_DEM_ADM AND w_SEJOUR_ok.OK = 'O';
|
|
|
|
|
|
|
|
|
UPDATE w_MUTATION_ok
|
|
|
SET CODE_SER_DEST = CASE WHEN CODE_UFR_DEST <> '' THEN CODE_UFR_DEST ELSE '9999' END || '_CO'
|
|
|
WHERE TYPE_HOSP_DEST ILIKE '%consultation%' AND CODE_SER_DEST = '';
|
|
|
|
|
|
|
|
|
UPDATE w_MUTATION_ok
|
|
|
SET CODE_SER_DEST = CASE WHEN CODE_UFR_DEST <> '' THEN CODE_UFR_DEST ELSE '9999' END || '_HC'
|
|
|
WHERE TYPE_HOSP_DEST ILIKE '%complete%' AND CODE_SER_DEST = '';
|
|
|
|
|
|
|
|
|
UPDATE w_MUTATION_ok
|
|
|
SET CODE_SER_DEST = CASE WHEN CODE_UFR_DEST <> '' THEN CODE_UFR_DEST ELSE '9999' END || '_HS'
|
|
|
WHERE TYPE_HOSP_DEST ILIKE '%semaine%' AND CODE_SER_DEST = '';
|
|
|
|
|
|
UPDATE w_MUTATION_ok
|
|
|
SET CODE_SER_DEST = CASE WHEN CODE_UFR_DEST <> '' THEN CODE_UFR_DEST ELSE '9999' END || '_AM'
|
|
|
WHERE TYPE_HOSP_DEST ILIKE '%ambulatoire%' AND CODE_SER_DEST = '';
|
|
|
|
|
|
UPDATE w_MUTATION_ok
|
|
|
SET CODE_SER_DEST = CASE WHEN CODE_UFR_DEST <> '' THEN CODE_UFR_DEST ELSE '9999' END || '_HJ'
|
|
|
WHERE TYPE_HOSP_DEST ILIKE '%jour%' AND CODE_SER_DEST = '';
|
|
|
|
|
|
CREATE INDEX w_MUTATION_ok_i1
|
|
|
ON w_MUTATION_ok
|
|
|
USING btree
|
|
|
(NUM_DEM_ADM);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Détection modifications">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="SEJOUR" label="RECUPERATION DES SEJOURS">
|
|
|
|
|
|
<NODE label="Patients">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
INSERT INTO activite[PX].p_patients(finess, no_patient, nom, nom_naissance, prenom, date_naissance, code_sexe)
|
|
|
SELECT '', NUM_DOS_AD, NOMM, NOMP, PATIENT.PRENOM, date(DATE_NAISS), CASE WHEN PATIENT.SEXE IN ('1','2') THEN '2' ELSE '1' END
|
|
|
FROM prod_calystene.PATIENT
|
|
|
LEFT JOIN activite[PX].p_patients ON (NUM_DOS_AD = p_patients.no_patient)
|
|
|
WHERE p_patients.no_patient IS NULL;
|
|
|
|
|
|
UPDATE activite[PX].p_patients
|
|
|
SET nom = PATIENT.NOMM,
|
|
|
nom_naissance = PATIENT.NOMP,
|
|
|
prenom = PATIENT.PRENOM,
|
|
|
date_naissance = date(DATE_NAISS),
|
|
|
code_sexe = CASE WHEN PATIENT.SEXE IN ('1','2') THEN '2' ELSE '1' END
|
|
|
FROM prod_calystene.PATIENT
|
|
|
WHERE p_patients.no_patient = NUM_DOS_AD
|
|
|
AND (
|
|
|
p_patients.nom IS DISTINCT FROM PATIENT.NOMM OR
|
|
|
p_patients.nom_naissance IS DISTINCT FROM PATIENT.NOMP OR
|
|
|
p_patients.prenom IS DISTINCT FROM PATIENT.PRENOM OR
|
|
|
p_patients.date_naissance IS DISTINCT FROM date(DATE_NAISS) OR
|
|
|
p_patients.code_sexe IS DISTINCT FROM CASE WHEN PATIENT.SEXE IN ('1','2') THEN '2' ELSE '1' END
|
|
|
);
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Séjours">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_HISTO_MVTS_sortie;
|
|
|
CREATE TEMP TABLE w_HISTO_MVTS_sortie AS
|
|
|
SELECT NUM_DEM_ADM,
|
|
|
to_number('0' || (max(ARRAY[DATE_REEL::text, HEURE_DEP]))[2],'000000') * 100 AS heure_sortie,
|
|
|
(max(ARRAY[DATE_REEL::text, HEURE_DEP]))[2] AS heure_sortie_originale
|
|
|
FROM prod_calystene.HISTO_MVTS
|
|
|
WHERE TYPE_MVT = 1
|
|
|
GROUP BY 1;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_HISTO_MVTS_sortie;
|
|
|
CREATE TEMP TABLE w_HISTO_MVTS_sortie AS
|
|
|
SELECT NUM_DEM_ADM,
|
|
|
date(max(DATE_REEL)) AS DATE_REEL,
|
|
|
to_number('0' || (max(ARRAY[DATE_REEL::text, HEURE_DEP]))[2],'000000') * 100 AS heure_sortie,
|
|
|
(max(ARRAY[DATE_REEL::text, HEURE_DEP]))[2] AS heure_sortie_originale
|
|
|
FROM prod_calystene.HISTO_MVTS
|
|
|
WHERE TYPE_MVT = 1
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
UPDATE w_HISTO_MVTS_sortie
|
|
|
SET heure_sortie = to_number('0' || HEURE_ENTREE,'000000') * 100 + 59,
|
|
|
heure_sortie_originale = HEURE_ENTREE || ':59'
|
|
|
FROM prod_calystene.SEJOUR
|
|
|
WHERE w_HISTO_MVTS_sortie.NUM_DEM_ADM = SEJOUR.NUM_DEM_ADM AND
|
|
|
DATE_REEL = date(SEJOUR.DATE_ENTREE) AND
|
|
|
heure_sortie_originale < HEURE_ENTREE;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_G_COUVERTURE_CAISSE;
|
|
|
CREATE TEMP TABLE w_G_COUVERTURE_CAISSE AS
|
|
|
SELECT NUM_DEM_ADM,
|
|
|
(MAX(ARRAY[DT_DEBUT::text, COALESCE(t_tiers_payant.oid,0)::text]))[2]::bigint AS tiers_payant_1_id,
|
|
|
(MAX(ARRAY[DT_DEBUT::text, IMMATRICULATION]))[2]::text AS IMMATRICULATION
|
|
|
FROM prod_calystene.G_COUVERTURE_CAISSE
|
|
|
LEFT JOIN activite[PX].t_tiers_payant ON CODE_CAISSE= code_original
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_G_COUVERTURE_MUTUELLE;
|
|
|
CREATE TEMP TABLE w_G_COUVERTURE_MUTUELLE AS
|
|
|
SELECT NUM_DEM_ADM,
|
|
|
(MAX(ARRAY[DT_DEBUT::text, CASE WHEN TYPE_ORGANISME = 'M' THEN COALESCE(t_tiers_payant.oid,0)::text ELSE '0' END]))[2]::bigint AS tiers_payant_2_id,
|
|
|
(MAX(ARRAY[DT_DEBUT::text, CASE WHEN TYPE_ORGANISME = 'M' THEN CASE WHEN NUM_ADHESION <> '' THEN NUM_ADHESION ELSE IMMATRICULATION END ELSE '' END]))[2]::text AS NUM_ADHESION,
|
|
|
(MAX(ARRAY[DT_DEBUT::text, CASE WHEN TYPE_ORGANISME <> 'M' THEN COALESCE(t_tiers_payant.oid,0)::text ELSE '0' END]))[2]::bigint AS tiers_payant_22_id,
|
|
|
(MAX(ARRAY[DT_DEBUT::text, CASE WHEN TYPE_ORGANISME <> 'M' THEN CASE WHEN NUM_ADHESION <> '' THEN NUM_ADHESION ELSE IMMATRICULATION END ELSE '' END]))[2]::text AS NUM_ADHESION_22
|
|
|
FROM prod_calystene.G_COUVERTURE_MUTUELLE
|
|
|
LEFT JOIN activite[PX].t_tiers_payant ON NUM_ORGANISME = code_original
|
|
|
GROUP BY 1;
|
|
|
|
|
|
UPDATE w_G_COUVERTURE_MUTUELLE
|
|
|
SET tiers_payant_2_id = tiers_payant_22_id,
|
|
|
NUM_ADHESION = NUM_ADHESION_22
|
|
|
WHERE tiers_payant_22_id <> 0 AND tiers_payant_2_id = 0;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_sejours;
|
|
|
CREATE TEMP TABLE w_sejours AS
|
|
|
SELECT
|
|
|
w_SEJOUR_ok.NUM_ADMINISTRATIF AS no_sejour,
|
|
|
w_SEJOUR_ok.NUM_DEM_ADM AS code_original,
|
|
|
w_SEJOUR_ok.NUM AS code_original_2,
|
|
|
w_SEJOUR_ok.NUM_DOS_AD AS no_patient,
|
|
|
date(w_SEJOUR_ok.DATE_ENTREE) AS date_entree,
|
|
|
to_number('0' || HEURE_ENTREE,'000000') * 100 AS heure_entree,
|
|
|
COALESCE(w_SEJOUR_ok.DATE_SORT_REEL, w_SEJOUR_ok.DATE_SORTIE_PREV, '20991231') AS date_sortie,
|
|
|
COALESCE(w_HISTO_MVTS_sortie.heure_sortie,0) AS heure_sortie,
|
|
|
CASE WHEN PATIENT.SEXE IN ('1','2') THEN '2' ELSE '1' END AS code_sexe,
|
|
|
0 AS age,
|
|
|
CASE WHEN DATE_SORT_REEL IS NOT NULL THEN 1 ELSE 0 END AS code_sorti,
|
|
|
0 AS code_prevu,
|
|
|
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 w_SEJOUR_ok.TYPE_ENTREE = '9' THEN '3'
|
|
|
WHEN t_modes_traitement.code IN ('19', '23') AND date(w_SEJOUR_ok.DATE_SORT_REEL) = date(w_SEJOUR_ok.DATE_ENTREE) THEN '2'
|
|
|
WHEN t_modes_traitement.code IN ('04') AND date(w_SEJOUR_ok.DATE_SORT_REEL) = date(w_SEJOUR_ok.DATE_ENTREE) THEN '2'
|
|
|
WHEN t_modes_traitement.code IN ('03') AND date(w_SEJOUR_ok.DATE_SORT_REEL) = date(w_SEJOUR_ok.DATE_ENTREE) THEN '2'
|
|
|
WHEN t_modes_traitement.code IN ('10') AND date(w_SEJOUR_ok.DATE_SORT_REEL) <= date(w_SEJOUR_ok.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,
|
|
|
'0'::text AS code_cp_demandee,
|
|
|
t_services_facturation.mode_traitement_id AS mode_traitement_id,
|
|
|
SUBSTR(w_SEJOUR_ok.MODE_ENTREE,1,1) AS mode_entree,
|
|
|
'0'::character(1) AS provenance,
|
|
|
'8'::character(1) AS mode_sortie,
|
|
|
'0'::character(1) AS destination,
|
|
|
t_tiers_payant.oid AS tiers_payant_0_id,
|
|
|
COALESCE(w_G_COUVERTURE_CAISSE.tiers_payant_1_id,0) AS tiers_payant_1_id,
|
|
|
COALESCE(w_G_COUVERTURE_MUTUELLE.tiers_payant_2_id,0) AS tiers_payant_2_id,
|
|
|
COALESCE(w_G_COUVERTURE_MUTUELLE.tiers_payant_22_id,0) AS tiers_payant_22_id,
|
|
|
1::numeric AS est_budget_global,
|
|
|
0::bigint AS code_postal_id
|
|
|
FROM w_SEJOUR_ok
|
|
|
JOIN prod_calystene.PATIENT ON w_SEJOUR_ok.NUM_DOS_AD = PATIENT.NUM_DOS_AD
|
|
|
LEFT JOIN w_HISTO_MVTS_sortie ON w_SEJOUR_ok.NUM_DEM_ADM = w_HISTO_MVTS_sortie.NUM_DEM_ADM
|
|
|
LEFT JOIN w_G_COUVERTURE_MUTUELLE ON w_SEJOUR_ok.NUM_DEM_ADM = w_G_COUVERTURE_MUTUELLE.NUM_DEM_ADM
|
|
|
LEFT JOIN w_G_COUVERTURE_CAISSE ON w_SEJOUR_ok.NUM_DEM_ADM = w_G_COUVERTURE_CAISSE.NUM_DEM_ADM
|
|
|
LEFT JOIN activite[PX].t_tiers_payant ON code_original = '0'
|
|
|
LEFT JOIN activite[PX].t_services_facturation ON w_SEJOUR_ok.CODE_SER_ENT = t_services_facturation.code_original
|
|
|
LEFT JOIN base.t_modes_traitement ON t_services_facturation.mode_traitement_id = t_modes_traitement.oid
|
|
|
LEFT JOIN base.t_dmt ON t_services_facturation.dmt_id = t_dmt.oid
|
|
|
LEFT JOIN activite[PX].t_medecins_administratifs ON NUM_MED_RESP = t_medecins_administratifs.code_original
|
|
|
WHERE w_SEJOUR_ok.OK = 'O'
|
|
|
;
|
|
|
|
|
|
-- Forcage type selon séjour
|
|
|
UPDATE w_sejours
|
|
|
SET type_sejour = t_sejour.type_sejour
|
|
|
FROM activite.t_sejour
|
|
|
WHERE t_sejour.no_sejour = w_sejours.no_sejour AND
|
|
|
t_sejour.type_sejour IN ('1','2','3','4','5','6','9');
|
|
|
|
|
|
UPDATE w_sejours SET MODE_SORTIE = SORTIE_DEF.MODE_SORTIE
|
|
|
FROM prod_calystene.SORTIE_DEF
|
|
|
WHERE code_original = SORTIE_DEF.NUM_DEM_ADM AND
|
|
|
LENGTH(SORTIE_DEF.MODE_SORTIE) <= 1;
|
|
|
|
|
|
UPDATE w_sejours SET
|
|
|
mode_entree = substr(SEJOUR_SSR.MODE_ENTREE,1,1),
|
|
|
provenance = substr(SEJOUR_SSR.PROVENANCE,1,1),
|
|
|
mode_sortie = substr(SEJOUR_SSR.MODE_SORTIE,1,1),
|
|
|
destination = substr(SEJOUR_SSR.DESTINATION,1,1)
|
|
|
FROM prod_calystene.SEJOUR_SSR
|
|
|
WHERE code_original_2 = SEJOUR_SSR.NUM_SEJ;
|
|
|
|
|
|
|
|
|
|
|
|
-- Code postal
|
|
|
DROP TABLE IF EXISTS w_sejours_cp;
|
|
|
CREATE TEMP TABLE w_sejours_cp AS
|
|
|
SELECT no_sejour, MAX(t_codes_postaux.oid) AS code_postal_id
|
|
|
FROM w_sejours
|
|
|
JOIN prod_calystene.SEJOUR ON w_sejours.code_original = SEJOUR.NUM_DEM_ADM
|
|
|
JOIN prod_calystene.G_ENTREE ON G_ENTREE.NUM_DEM_ADM = SEJOUR.NUM_DEM_ADM
|
|
|
JOIN prod_calystene.PRE_ADM ON PRE_ADM.NUM = SEJOUR.NUM_DEM_ADM
|
|
|
JOIN base.t_codes_postaux ON PRE_ADM.CP = t_codes_postaux.code
|
|
|
GROUP BY 1;
|
|
|
|
|
|
UPDATE w_sejours
|
|
|
SET code_postal_id = w_sejours_cp.code_postal_id
|
|
|
FROM w_sejours_cp
|
|
|
WHERE w_sejours_cp.no_sejour = w_sejours.no_sejour AND
|
|
|
w_sejours.code_postal_id IS DISTINCT FROM w_sejours_cp.code_postal_id;
|
|
|
|
|
|
|
|
|
|
|
|
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');
|
|
|
|
|
|
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;
|
|
|
|
|
|
|
|
|
|
|
|
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');
|
|
|
|
|
|
-- 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]' = '';
|
|
|
|
|
|
|
|
|
|
|
|
-- 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(IMMATRICULATION,1,30),
|
|
|
p_sejours.tiers_payant_2_id,
|
|
|
substr(NUM_ADHESION,1,30),
|
|
|
p_sejours.tiers_payant_22_id,
|
|
|
substr(NUM_ADHESION_22,1,30) AS matricule_22
|
|
|
FROM activite[PX].p_sejours
|
|
|
LEFT JOIN w_G_COUVERTURE_MUTUELLE ON code_original = w_G_COUVERTURE_MUTUELLE.NUM_DEM_ADM
|
|
|
LEFT JOIN w_G_COUVERTURE_CAISSE ON code_original = w_G_COUVERTURE_CAISSE.NUM_DEM_ADM
|
|
|
WHERE 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');
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Mouvements">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
DROP SEQUENCE IF EXISTS w_MUTATION_seq;
|
|
|
CREATE TEMP SEQUENCE w_MUTATION_seq
|
|
|
INCREMENT 1
|
|
|
MINVALUE 1
|
|
|
MAXVALUE 9223372036854775807
|
|
|
START 1
|
|
|
CACHE 1;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_MUTATION;
|
|
|
CREATE TEMP TABLE w_MUTATION AS
|
|
|
SELECT nextval('w_MUTATION_seq'::regclass) AS sequence,
|
|
|
subview.NUM_DEM_ADM,
|
|
|
subview.DATE_MVT,
|
|
|
date(subview.DATE_MVT) AS DATE_MVT_DAT,
|
|
|
extract('hour' FROM DATE_MVT) * 10000 + extract('minute' FROM DATE_MVT) * 100 + extract('second' FROM DATE_MVT) AS DATE_MVT_TIM,
|
|
|
'2099/12/31'::timestamp without time zone AS DATE_FIN_MVT,
|
|
|
date('2099/12/31')::date AS DATE_FIN_MVT_DAT,
|
|
|
000000::numeric(6, 0) AS DATE_FIN_MVT_TIM,
|
|
|
subview.type_mouvement,
|
|
|
subview.SER AS SER_SEJ,
|
|
|
subview.SER,
|
|
|
subview.UFR AS UFR_SEJ,
|
|
|
subview.UFR,
|
|
|
subview.SS_UF,
|
|
|
subview.lit_code_original AS lit_code_original,
|
|
|
''::text AS type_mouvement_before,
|
|
|
0::text AS SER_before,
|
|
|
0::text AS UFR_before,
|
|
|
0::text AS SS_UF_before,
|
|
|
'0'::text AS lit_code_original_before,
|
|
|
''::text AS type_mouvement_next,
|
|
|
0::text AS SER_next,
|
|
|
0::text AS UFR_next,
|
|
|
0::text AS SS_UF_next,
|
|
|
'0'::text AS lit_code_original_next,
|
|
|
CH,
|
|
|
LIT
|
|
|
FROM
|
|
|
(
|
|
|
SELECT NUM_DEM_ADM,
|
|
|
DATE_ENTREE + (CASE WHEN HEURE_ENTREE LIKE '%:%' THEN HEURE_ENTREE ELSE '00:00' END)::interval AS DATE_MVT,
|
|
|
'E'::text AS type_mouvement,
|
|
|
CASE WHEN NUM_LIT_ENT <> '' THEN NUM_LIT_ENT ELSE '0' END AS NUM_LIT,
|
|
|
CODE_SER_ENT AS SER,
|
|
|
CODE_UFR_ENT AS UFR,
|
|
|
SS_UF_ENT AS SS_UF,
|
|
|
UF_ENT AS UF,
|
|
|
CASE WHEN SS_UF_ENT <> '' AND CH_ENT = '' AND NUM_LIT_ENT = '' THEN SS_UF_ENT || '|0'
|
|
|
WHEN SS_UF_ENT <> '' AND CH_ENT <> '' AND NUM_LIT_ENT = '' THEN SS_UF_ENT || '|' || CH_ENT
|
|
|
WHEN SS_UF_ENT <> '' AND CH_ENT <> '' AND NUM_LIT_ENT <> '' THEN SS_UF_ENT || '|' || CH_ENT || '|' || NUM_LIT_ENT
|
|
|
ELSE '0' END AS lit_code_original,
|
|
|
CH_ENT AS CH,
|
|
|
NUM_LIT_ENT AS LIT
|
|
|
FROM w_SEJOUR_ok
|
|
|
WHERE w_SEJOUR_ok.OK = 'O'
|
|
|
UNION
|
|
|
SELECT MUTATION.NUM_DEM_ADM,
|
|
|
DATE_MVT + HEURE_DEP::interval AS DATE_MVT,
|
|
|
'M'::text AS type_mouvement,
|
|
|
CASE WHEN LIT_DEST <> '' THEN LIT_DEST ELSE '0' END AS NUM_LIT,
|
|
|
CODE_SER_DEST AS SER,
|
|
|
CODE_UFR_DEST AS UFR,
|
|
|
SS_UF_DEST AS SS_UF,
|
|
|
UF_DEST AS UF,
|
|
|
CASE WHEN SS_UF_DEST <> '' AND CH_DEST = '' AND LIT_DEST = '' THEN SS_UF_DEST || '|0'
|
|
|
WHEN SS_UF_DEST <> '' AND CH_DEST <> '' AND LIT_DEST = '' THEN SS_UF_DEST || '|' || CH_DEST
|
|
|
WHEN SS_UF_DEST <> '' AND CH_DEST <> '' AND LIT_DEST <> '' THEN SS_UF_DEST || '|' || CH_DEST || '|' || LIT_DEST
|
|
|
ELSE '0' END AS lit_code_original,
|
|
|
CH_DEST AS CH,
|
|
|
LIT_DEST AS LIT
|
|
|
FROM w_MUTATION_ok MUTATION
|
|
|
JOIN prod_calystene.HISTO_MVTS ON MUTATION.NUM_DEM_ADM = HISTO_MVTS.NUM_DEM_ADM AND MUTATION.NO_MVT = HISTO_MVTS.NO_MVT
|
|
|
JOIN w_SEJOUR_ok ON MUTATION.NUM_DEM_ADM = w_SEJOUR_ok.NUM_DEM_ADM AND w_SEJOUR_ok.OK = 'O'
|
|
|
UNION
|
|
|
SELECT HISTO_MVTS.NUM_DEM_ADM,
|
|
|
DATE_REEL + HEURE_DEP::interval AS DATE_MVT,
|
|
|
'AD'::text AS type_mouvement,
|
|
|
''::text AS NUM_LIT,
|
|
|
''::text AS SER,
|
|
|
''::text AS UFR,
|
|
|
''::text AS SS_UF,
|
|
|
''::text AS UF,
|
|
|
''::text AS lit_code_original,
|
|
|
''::text AS CH,
|
|
|
''::text AS LIT
|
|
|
FROM prod_calystene.HISTO_MVTS
|
|
|
JOIN w_SEJOUR_ok ON HISTO_MVTS.NUM_DEM_ADM = w_SEJOUR_ok.NUM_DEM_ADM AND w_SEJOUR_ok.OK = 'O'
|
|
|
WHERE TYPE_MVT IN (2,3) AND HEURE_DEP <> '' AND COALESCE(HEURE_RET_REEL,HEURE_RET_PREV) <> ''
|
|
|
UNION
|
|
|
SELECT HISTO_MVTS.NUM_DEM_ADM,
|
|
|
COALESCE(DATE_RET_REEL + HEURE_RET_REEL::interval,DATE_RET_PREV + HEURE_RET_PREV::interval) AS DATE_MVT,
|
|
|
'AR'::text AS type_mouvement,
|
|
|
''::text AS NUM_LIT,
|
|
|
''::text AS SER,
|
|
|
''::text AS UFR,
|
|
|
''::text AS SS_UF,
|
|
|
''::text AS UF,
|
|
|
''::text AS lit_code_original,
|
|
|
''::text AS CH,
|
|
|
''::text AS LIT
|
|
|
FROM prod_calystene.HISTO_MVTS
|
|
|
JOIN w_SEJOUR_ok ON HISTO_MVTS.NUM_DEM_ADM = w_SEJOUR_ok.NUM_DEM_ADM AND w_SEJOUR_ok.OK = 'O'
|
|
|
WHERE TYPE_MVT IN (2,3) AND HEURE_DEP <> '' AND COALESCE(HEURE_RET_REEL,HEURE_RET_PREV) <> ''
|
|
|
UNION
|
|
|
SELECT w_SEJOUR_ok.NUM_DEM_ADM,
|
|
|
COALESCE(w_SEJOUR_ok.DATE_SORT_REEL, w_SEJOUR_ok.DATE_SORTIE_PREV, '20991231') +
|
|
|
COALESCE(w_HISTO_MVTS_sortie.heure_sortie_originale,'00:00')::interval AS DATE_MVT,
|
|
|
'S'::text AS type_mouvement,
|
|
|
''::text AS NUM_LIT,
|
|
|
''::text AS SER,
|
|
|
''::text AS UFR,
|
|
|
''::text AS SS_UF,
|
|
|
''::text AS UF,
|
|
|
''::text AS lit_code_original,
|
|
|
''::text AS CH,
|
|
|
''::text AS LIT
|
|
|
FROM w_SEJOUR_ok
|
|
|
LEFT JOIN w_HISTO_MVTS_sortie ON w_SEJOUR_ok.NUM_DEM_ADM = w_HISTO_MVTS_sortie.NUM_DEM_ADM
|
|
|
WHERE w_SEJOUR_ok.OK = 'O'
|
|
|
ORDER BY 1,2,3
|
|
|
) subview
|
|
|
|
|
|
;
|
|
|
|
|
|
-- Traitement des absences
|
|
|
|
|
|
SELECT base.cti_execute(
|
|
|
'UPDATE w_MUTATION SET
|
|
|
SER_SEJ = w_MUTATION_prev.SER_SEJ,
|
|
|
SER = CASE WHEN w_MUTATION.type_mouvement <> ''AD'' THEN w_MUTATION_prev.SER_SEJ ELSE ''*ABS'' END,
|
|
|
UFR_SEJ = w_MUTATION_prev.UFR_SEJ,
|
|
|
UFR = CASE WHEN w_MUTATION.type_mouvement <> ''AD'' THEN w_MUTATION_prev.UFR_SEJ ELSE ''*ABS'' END,
|
|
|
SS_UF = w_MUTATION_prev.SS_UF,
|
|
|
lit_code_original = w_MUTATION_prev.lit_code_original,
|
|
|
CH = w_MUTATION_prev.CH,
|
|
|
LIT = w_MUTATION_prev.LIT
|
|
|
FROM w_MUTATION w_MUTATION_prev
|
|
|
WHERE w_MUTATION.NUM_DEM_ADM = w_MUTATION_prev.NUM_DEM_ADM AND
|
|
|
w_MUTATION.sequence = w_MUTATION_prev.sequence + 1 AND
|
|
|
w_MUTATION.type_mouvement IN (''AD'', ''AR'', ''S'') AND
|
|
|
w_MUTATION.UFR = '''' AND w_MUTATION_prev.UFR <> ''''', 500);
|
|
|
|
|
|
|
|
|
UPDATE w_MUTATION
|
|
|
SET SER = '*ABS', UFR = '*ABS'
|
|
|
WHERE UFR = '' AND type_mouvement = 'AD';
|
|
|
|
|
|
|
|
|
-- Services manquant
|
|
|
|
|
|
INSERT INTO activite[PX].t_services_facturation(code_original, code, texte, texte_court, type_t2a)
|
|
|
SELECT SER, SER, SER, SER, '0'
|
|
|
FROM w_MUTATION
|
|
|
WHERE
|
|
|
SER NOT IN (SELECT code_original FROM activite[PX].t_services_facturation)
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_unites_fonctionnelles(code_original, code, texte, texte_court)
|
|
|
SELECT UFR, UFR, UFR, UFR
|
|
|
FROM w_MUTATION
|
|
|
WHERE
|
|
|
UFR NOT IN (SELECT code_original FROM activite[PX].t_unites_fonctionnelles)
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- Lits manquants
|
|
|
INSERT INTO activite[PX].t_lits(code_original, code, texte, texte_court, etage_id, chambre_particuliere)
|
|
|
SELECT lit_code_original, CH || '-' || LIT, 'Ch ' || CH || ' - lit ' || LIT, CH || ' ' || LIT, t_etages.oid, 'N'
|
|
|
FROM w_MUTATION
|
|
|
JOIN activite[PX].t_etages ON SS_UF = t_etages.code_original
|
|
|
WHERE type_mouvement <> 'S' AND
|
|
|
CH <> '' AND
|
|
|
LIT <> '' AND
|
|
|
lit_code_original NOT IN (SELECT code_original FROM activite[PX].t_lits )
|
|
|
GROUP BY 1,2,3,4,5;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_lits(code_original, code, texte, texte_court, etage_id, chambre_particuliere)
|
|
|
SELECT lit_code_original, CH , 'Ch ' || CH , CH , t_etages.oid, 'N'
|
|
|
FROM w_MUTATION
|
|
|
JOIN activite[PX].t_etages ON SS_UF = t_etages.code_original
|
|
|
WHERE type_mouvement <> 'S' AND
|
|
|
CH <> '' AND
|
|
|
LIT = '' AND
|
|
|
lit_code_original NOT IN (SELECT code_original FROM activite[PX].t_lits )
|
|
|
GROUP BY 1,2,3,4,5;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- calcul date fin
|
|
|
|
|
|
UPDATE w_MUTATION
|
|
|
SET DATE_FIN_MVT = CASE WHEN w_MUTATION_next.type_mouvement <> 'S' THEN w_MUTATION_next.DATE_MVT - interval '1 second' ELSE w_MUTATION_next.DATE_MVT END,
|
|
|
DATE_FIN_MVT_DAT = date(CASE WHEN w_MUTATION_next.type_mouvement <> 'S' THEN w_MUTATION_next.DATE_MVT - interval '1 second' ELSE w_MUTATION_next.DATE_MVT END),
|
|
|
DATE_FIN_MVT_TIM = extract('hour' FROM CASE WHEN w_MUTATION_next.type_mouvement <> 'S' THEN w_MUTATION_next.DATE_MVT - interval '1 second' ELSE w_MUTATION_next.DATE_MVT END) * 10000 +
|
|
|
extract('minute' FROM CASE WHEN w_MUTATION_next.type_mouvement <> 'S' THEN w_MUTATION_next.DATE_MVT - interval '1 second' ELSE w_MUTATION_next.DATE_MVT END) * 100 +
|
|
|
extract('second' FROM CASE WHEN w_MUTATION_next.type_mouvement <> 'S' THEN w_MUTATION_next.DATE_MVT - interval '1 second' ELSE w_MUTATION_next.DATE_MVT END),
|
|
|
type_mouvement_next = w_MUTATION_next.type_mouvement,
|
|
|
SER_next = w_MUTATION_next.SER,
|
|
|
UFR_next = w_MUTATION_next.UFR,
|
|
|
SS_UF_next = w_MUTATION_next.SS_UF,
|
|
|
lit_code_original_next = w_MUTATION_next.lit_code_original
|
|
|
FROM w_MUTATION w_MUTATION_next
|
|
|
WHERE w_MUTATION.NUM_DEM_ADM = w_MUTATION_next.NUM_DEM_ADM
|
|
|
AND w_MUTATION.sequence = w_MUTATION_next.sequence - 1
|
|
|
AND w_MUTATION.type_mouvement <> 'S';
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- calcul mvt avant
|
|
|
|
|
|
UPDATE w_MUTATION
|
|
|
SET
|
|
|
type_mouvement_before = w_MUTATION_before.type_mouvement,
|
|
|
SER_before = w_MUTATION_before.SER,
|
|
|
UFR_before = w_MUTATION_before.UFR,
|
|
|
SS_UF_before = w_MUTATION_before.SS_UF,
|
|
|
lit_code_original_before = w_MUTATION_before.lit_code_original
|
|
|
FROM w_MUTATION w_MUTATION_before
|
|
|
WHERE w_MUTATION.NUM_DEM_ADM = w_MUTATION_before.NUM_DEM_ADM
|
|
|
AND w_MUTATION.sequence = w_MUTATION_before.sequence + 1
|
|
|
AND w_MUTATION.type_mouvement <> 'S';
|
|
|
|
|
|
|
|
|
|
|
|
-- creation mouvements par jour
|
|
|
|
|
|
DROP TABLE IF EXISTS w_mouvements_sejour;
|
|
|
CREATE TEMP TABLE w_mouvements_sejour AS
|
|
|
SELECT
|
|
|
w_MUTATION.NUM_DEM_ADM,
|
|
|
p_sejours.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 = DATE_MVT_DAT THEN DATE_MVT_TIM ELSE 0 END AS heure_debut,
|
|
|
CASE WHEN p_calendrier.date = DATE_FIN_MVT_DAT THEN DATE_FIN_MVT_TIM ELSE 240000 END AS heure_fin,
|
|
|
CASE WHEN p_calendrier.date = DATE_MVT_DAT AND type_mouvement = 'E' AND p_sejours.type_sejour = '1' THEN 1 ELSE 0 END AS nb_entrees_directes,
|
|
|
CASE WHEN p_calendrier.date = DATE_FIN_MVT_DAT AND type_mouvement_next = 'S' AND p_sejours.type_sejour = '1' THEN 1 ELSE 0 END AS nb_sorties_directes,
|
|
|
CASE WHEN p_calendrier.date = DATE_MVT_DAT AND type_mouvement = 'E' AND p_sejours.type_sejour = '1' THEN '1' ELSE '0' END AS est_jour_entree,
|
|
|
CASE WHEN p_calendrier.date = DATE_FIN_MVT_DAT AND type_mouvement_next = 'S' AND p_sejours.type_sejour = '1' THEN '1' ELSE '0' END AS est_jour_sortie,
|
|
|
CASE WHEN p_sejours.type_sejour = '1' THEN '1' ELSE '0' END AS est_jour_hospitalisation,
|
|
|
CASE WHEN p_calendrier.date = DATE_MVT_DAT AND type_mouvement = 'E' AND p_sejours.type_sejour = '2' THEN 1 ELSE 0 END AS nb_ambulatoires,
|
|
|
CASE WHEN p_calendrier.date = DATE_MVT_DAT AND type_mouvement = 'E' AND p_sejours.type_sejour = '3' THEN 1 ELSE 0 END AS nb_externes,
|
|
|
CASE WHEN p_calendrier.date = DATE_MVT_DAT AND type_mouvement = 'E' 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 = DATE_MVT_DAT AND type_mouvement IN ('D', 'M') AND p_sejours.type_sejour = '1' AND SER <> SER_before AND SER <> '*ABS' AND SER_before <> '*ABS' THEN 1 ELSE 0 END AS nb_entrees_mutation_service,
|
|
|
CASE WHEN p_calendrier.date = DATE_MVT_DAT AND type_mouvement_next IN ('D', 'M') AND p_sejours.type_sejour = '1' AND SER <> SER_next AND SER <> '*ABS' AND SER_next <> '*ABS' THEN 1 ELSE 0 END AS nb_sorties_mutation_service,
|
|
|
CASE WHEN p_calendrier.date = DATE_MVT_DAT AND type_mouvement IN ('D', 'M') AND p_sejours.type_sejour = '1' AND SS_UF <> SS_UF_before THEN 1 ELSE 0 END AS nb_entrees_mutation_etage,
|
|
|
CASE WHEN p_calendrier.date = DATE_MVT_DAT AND type_mouvement_next IN ('D', 'M') AND p_sejours.type_sejour = '1' AND SS_UF <> SS_UF_next THEN 1 ELSE 0 END AS nb_sorties_mutation_etage,
|
|
|
0 AS nb_entrees_mutation_activite,
|
|
|
0 AS nb_sorties_mutation_activite,
|
|
|
0 AS nb_entrees_mutation_unite_medicale,
|
|
|
0 AS nb_sorties_mutation_unite_medicale,
|
|
|
|
|
|
CASE WHEN p_sejours.type_sejour = '1' AND (p_calendrier.date <> DATE_FIN_MVT_DAT OR type_mouvement_next = 'S') THEN 1 ELSE 0 END AS nb_jours_js_inclus,
|
|
|
CASE WHEN t_modes_traitement.code IN ('04', '19', '20') OR (p_sejours.type_sejour = '1' AND p_calendrier.date <> DATE_FIN_MVT_DAT) THEN 1 ELSE 0 END AS nb_jours_js_non_inclus,
|
|
|
|
|
|
CASE WHEN p_sejours.type_sejour = '1' AND t_lits.chambre_particuliere = 'O' THEN '1' ELSE '0' END AS est_chambre_particuliere,
|
|
|
CASE WHEN p_sejours.type_sejour = '1' AND t_lits.chambre_particuliere = 'O' AND (p_calendrier.date <> DATE_MVT_DAT OR type_mouvement_next = 'S') THEN 1 ELSE 0 END AS nb_chambres_particulieres,
|
|
|
|
|
|
0::numeric AS nb_bebes,
|
|
|
|
|
|
SER,
|
|
|
UFR,
|
|
|
SS_UF,
|
|
|
lit_code_original,
|
|
|
|
|
|
COALESCE(t_lieux.oid,0) AS lieu_id,
|
|
|
|
|
|
p_sejours.medecin_sejour_id as medecin_sejour_id,
|
|
|
|
|
|
CASE WHEN p_sejours.code_prevu = '1' OR p_calendrier.date > date(now()) THEN '1' ELSE '0' END AS est_mouvement_previsionnel,
|
|
|
|
|
|
'0'::text AS est_premier_mouvement_jour,
|
|
|
'0'::text AS est_dernier_mouvement_jour
|
|
|
|
|
|
FROM w_MUTATION
|
|
|
LEFT JOIN activite[PX].t_lieux ON (t_lieux.code_original_1 = SER AND
|
|
|
t_lieux.code_original_3 = SS_UF AND
|
|
|
t_lieux.code_original_4 = lit_code_original AND
|
|
|
t_lieux.code_original_6 = UFR )
|
|
|
JOIN activite[PX].p_sejours ON w_MUTATION.NUM_DEM_ADM = p_sejours.code_original AND p_sejours.etat = ''
|
|
|
JOIN activite[PX].t_lits ON lit_code_original = t_lits.code_original
|
|
|
JOIN activite[PX].t_services_facturation ON SER = t_services_facturation.code_original
|
|
|
JOIN activite[PX].t_unites_fonctionnelles ON UFR = t_unites_fonctionnelles.code_original
|
|
|
JOIN base.t_dmt ON t_services_facturation.dmt_id = t_dmt.oid
|
|
|
JOIN base.t_modes_traitement ON t_services_facturation.mode_traitement_id = t_modes_traitement.oid
|
|
|
JOIN base.p_calendrier ON p_calendrier.date BETWEEN DATE_MVT_DAT AND DATE_FIN_MVT_DAT AND p_calendrier.date <= date(now()) + interval '1 month'
|
|
|
WHERE type_mouvement <> 'S' AND
|
|
|
(p_sejours.type_sejour NOT IN ('2', '3') OR (p_sejours.type_sejour IN ('2', '3') AND type_mouvement = 'E' AND p_calendrier.date = DATE_MVT_DAT))
|
|
|
AND (p_sejours.code_prevu <> '1' AND p_calendrier.date <= date(now()) OR p_calendrier.date >= date(now()))
|
|
|
ORDER BY sequence, p_calendrier.date;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- Actualisation lieux
|
|
|
|
|
|
UPDATE activite[PX].t_lieux SET
|
|
|
service_facturation_id = t_services_facturation.oid,
|
|
|
lit_id = t_lits.oid,
|
|
|
unite_fonctionnelle_id = t_unites_fonctionnelles.oid,
|
|
|
mode_traitement_id = t_services_facturation.mode_traitement_id
|
|
|
FROM activite[PX].t_services_facturation, activite[PX].t_lits, activite[PX].t_unites_fonctionnelles
|
|
|
WHERE
|
|
|
code_original_1 = t_services_facturation.code_original AND
|
|
|
code_original_4 = t_lits.code_original AND
|
|
|
code_original_6 = t_unites_fonctionnelles.code_original AND
|
|
|
(
|
|
|
t_lieux.service_facturation_id IS DISTINCT FROM t_services_facturation.oid OR
|
|
|
t_lieux.lit_id IS DISTINCT FROM t_lits.oid OR
|
|
|
t_lieux.unite_fonctionnelle_id IS DISTINCT FROM t_unites_fonctionnelles.oid OR
|
|
|
t_lieux.mode_traitement_id IS DISTINCT FROM t_services_facturation.mode_traitement_id
|
|
|
);
|
|
|
|
|
|
|
|
|
-- 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
|
|
|
SER,
|
|
|
'',
|
|
|
SS_UF,
|
|
|
lit_code_original,
|
|
|
'',
|
|
|
UFR,
|
|
|
'',
|
|
|
t_services_facturation.oid,
|
|
|
0,
|
|
|
t_lits.oid,
|
|
|
0,
|
|
|
t_unites_fonctionnelles.oid,
|
|
|
t_services_facturation.mode_traitement_id
|
|
|
FROM w_mouvements_sejour
|
|
|
JOIN activite[PX].t_services_facturation ON SER = t_services_facturation.code_original
|
|
|
JOIN activite[PX].t_lits ON lit_code_original = t_lits.code_original
|
|
|
JOIN activite[PX].t_unites_fonctionnelles ON UFR = t_unites_fonctionnelles.code_original
|
|
|
LEFT JOIN activite[PX].t_lieux ON (t_lieux.code_original_1 = SER AND t_lieux.code_original_4 = lit_code_original AND t_lieux.code_original_6 = UFR )
|
|
|
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 = SER
|
|
|
AND t_lieux.code_original_4 = lit_code_original
|
|
|
AND t_lieux.code_original_6 = UFR
|
|
|
AND w_mouvements_sejour.lieu_id = 0;
|
|
|
|
|
|
-- Suppression mouvements HS et HS sans acte
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_mouvements_sejour_041920;
|
|
|
CREATE TEMP TABLE w_mouvements_sejour_041920 AS
|
|
|
SELECT p_sejours.no_sejour, p_sejours.code_original
|
|
|
FROM w_mouvements_sejour
|
|
|
JOIN activite[PX].p_sejours ON w_mouvements_sejour.no_sejour = p_sejours.no_sejour
|
|
|
JOIN activite[PX].t_lieux on lieu_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 IN ('04', '19', '20') AND t_services_facturation.est_sans_facturation <> '1'
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_mouvements_sejour_041920_reel;
|
|
|
CREATE TEMP TABLE w_mouvements_sejour_041920_reel AS
|
|
|
SELECT no_sejour, date(A_DT_DEBUT) AS date
|
|
|
FROM w_G_SP3 G_SP3
|
|
|
JOIN w_mouvements_sejour_041920 ON NUM_ENTREE = no_sejour
|
|
|
JOIN prod_calystene.G_LIGNEA_SP3 ON G_LIGNEA_SP3.NUM_AVIS = G_SP3.NUM_AVIS
|
|
|
WHERE date(A_DT_DEBUT) = date(A_DT_FIN)
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
INSERT INTO w_mouvements_sejour_041920_reel
|
|
|
SELECT no_sejour, date(DT_DEBUT) AS date
|
|
|
FROM w_G_SP3 G_SP3
|
|
|
JOIN w_mouvements_sejour_041920 ON NUM_ENTREE = no_sejour
|
|
|
JOIN prod_calystene.G_LIGNEC_SP3 ON G_LIGNEC_SP3.NUM_AVIS = G_SP3.NUM_AVIS
|
|
|
WHERE date(DT_DEBUT) = date(DT_FIN)
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
--INSERT INTO w_mouvements_sejour_041920_reel
|
|
|
--SELECT no_sejour, date(DATE_ACT) AS date
|
|
|
--FROM prod_calystene.SEJOUR
|
|
|
--JOIN w_mouvements_sejour_041920 ON NUM_ADMINISTRATIF = no_sejour
|
|
|
--JOIN prod_calystene.TPS_REEDUC ON NUM_SEJ = NUM
|
|
|
--GROUP BY 1,2;
|
|
|
|
|
|
INSERT INTO w_mouvements_sejour_041920_reel
|
|
|
SELECT no_sejour, date(DATE_v) AS date
|
|
|
FROM prod_calystene.JRS_PRESENT
|
|
|
JOIN w_mouvements_sejour_041920 ON NUM_ENTREE = no_sejour
|
|
|
WHERE TYPE_HOSPITALISATION = 'HPJ'
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
|
|
|
DELETE
|
|
|
FROM w_mouvements_sejour
|
|
|
WHERE no_sejour IN (SELECT no_sejour FROM w_mouvements_sejour_041920) AND
|
|
|
no_sejour || date NOT IN (SELECT no_sejour || date FROM w_mouvements_sejour_041920_reel);
|
|
|
|
|
|
|
|
|
UPDATE w_mouvements_sejour
|
|
|
SET heure_debut = 080000, est_premier_mouvement_jour = '1'
|
|
|
WHERE no_sejour IN (SELECT no_sejour FROM w_mouvements_sejour_041920) AND
|
|
|
heure_debut = 0;
|
|
|
|
|
|
|
|
|
UPDATE w_mouvements_sejour
|
|
|
SET heure_fin = 170000, est_dernier_mouvement_jour = '1'
|
|
|
WHERE no_sejour IN (SELECT no_sejour FROM w_mouvements_sejour_041920) AND
|
|
|
heure_fin = 240000 AND est_jour_sortie <> '1';
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- 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,
|
|
|
est_premier_mouvement_jour, est_dernier_mouvement_jour, 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,
|
|
|
est_premier_mouvement_jour, est_dernier_mouvement_jour, jour_semaine, is_weekend
|
|
|
FROM w_mouvements_sejour
|
|
|
WHERE heure_fin >= heure_debut
|
|
|
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
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="FACTURE" label="RECUPERATION DES FACTURES">
|
|
|
|
|
|
<NODE label="Entêtes">
|
|
|
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_G_LIGNEA_SP3_dates;
|
|
|
CREATE TEMP TABLE w_G_LIGNEA_SP3_dates AS
|
|
|
SELECT NUM_AVIS, date(MIN(A_DT_DEBUT)) AS A_DT_DEBUT, date(MAX(COALESCE(A_DT_FIN,A_DT_DEBUT))) AS A_DT_FIN
|
|
|
FROM prod_calystene.G_LIGNEA_SP3
|
|
|
WHERE A_DT_DEBUT IS NOT NULL
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
ALTER TABLE w_G_LIGNEA_SP3_dates ADD CONSTRAINT w_G_LIGNEA_SP3_dates_pkey PRIMARY KEY(NUM_AVIS);
|
|
|
|
|
|
|
|
|
|
|
|
ALTER SEQUENCE activite[PX].s_factures RESTART WITH 1;
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures;
|
|
|
CREATE TEMP TABLE w_factures AS
|
|
|
|
|
|
SELECT
|
|
|
nextval('activite[PX].s_factures'::regclass) AS oid,
|
|
|
p_sejours.no_sejour as no_sejour,
|
|
|
p_sejours.oid AS sejour_id,
|
|
|
G_SP3.NUM_AVIS AS no_facture,
|
|
|
date(COALESCE(w_G_LIGNEA_SP3_dates.A_DT_DEBUT, DT_DEB_FACT,p_sejours.date_entree)) AS date_debut,
|
|
|
date(COALESCE(w_G_LIGNEA_SP3_dates.A_DT_FIN, B_DT_FIN,p_sejours.date_sortie)) AS date_fin,
|
|
|
CASE
|
|
|
WHEN G_SP3.ANNULE = 'a' THEN 'X'
|
|
|
WHEN TOTAL_AVIS < 0 THEN '1'
|
|
|
ELSE '0' END AS type_facture,
|
|
|
p_sejours.code_cp_demandee,
|
|
|
'1'::text AS code_facture,
|
|
|
date(DT_FACTURE) AS date_facture,
|
|
|
'1'::text AS code_vente,
|
|
|
date(DT_LANC) AS date_vente,
|
|
|
extract('year' FROM DT_LANC) * 100 + extract('month' FROM DT_LANC) AS mois_vente,
|
|
|
'0'::text as code_cloture,
|
|
|
0::numeric AS nb_rejets,
|
|
|
G_SP3.NUM_AVIS AS no_facture_reference,
|
|
|
0::bigint AS facture_reference_id,
|
|
|
NUM_AVIS_ANNULE AS no_facture_od_avoir,
|
|
|
0::bigint AS facture_od_avoir_id,
|
|
|
0::bigint AS ghs_id,
|
|
|
0::bigint AS ghs_bebe1_id,
|
|
|
0::bigint AS ghs_bebe2_id,
|
|
|
0::bigint AS ghs_bebe3_id,
|
|
|
''::text as particularite_t2a,
|
|
|
p_sejours.tiers_payant_1_id,
|
|
|
p_sejours.tiers_payant_2_id,
|
|
|
p_sejours.tiers_payant_22_id,
|
|
|
p_sejours.tiers_payant_0_id,
|
|
|
|
|
|
date(DT_LANC) AS date_expedition,
|
|
|
CASE WHEN TOTAL_MALADE <> 0 THEN date(DT_LANC) ELSE '20991231'::date END AS date_expedition_0,
|
|
|
CASE WHEN TOTAL_SS <> 0 THEN date(DT_LANC) ELSE '20991231'::date END AS date_expedition_1,
|
|
|
CASE WHEN TOTAL_DIVERS <> 0 THEN date(DT_LANC) ELSE '20991231'::date END AS date_expedition_2,
|
|
|
CASE WHEN TOTAL_DEPARTEMENT <> 0 THEN date(DT_LANC) ELSE '20991231'::date END AS date_expedition_22,
|
|
|
CASE WHEN TOTAL_MALADE <> 0 THEN '1' ELSE '0' END AS code_expedie_0,
|
|
|
CASE WHEN TOTAL_SS <> 0 THEN '1' ELSE '0' END AS code_expedie_1,
|
|
|
CASE WHEN TOTAL_DIVERS <> 0 THEN '1' ELSE '0' END AS code_expedie_2,
|
|
|
CASE WHEN TOTAL_DEPARTEMENT <> 0 THEN '1' ELSE '0' END AS code_expedie_22,
|
|
|
''::text AS no_bordereau_0,
|
|
|
''::text AS no_bordereau_1,
|
|
|
''::text AS no_bordereau_2,
|
|
|
''::text AS no_bordereau_22,
|
|
|
|
|
|
CASE WHEN TOTAL_SS + TOTAL_DIVERS + TOTAL_DEPARTEMENT + TOTAL_MALADE <> 0 THEN date(DT_LANC) ELSE '20991231'::date END AS date_solde,
|
|
|
CASE WHEN TOTAL_SS + TOTAL_DIVERS + TOTAL_DEPARTEMENT + TOTAL_MALADE <> 0 THEN date(DT_LANC) ELSE '20991231'::date END AS date_solde_c,
|
|
|
'20991231'::date as date_solde_h,
|
|
|
CASE WHEN TOTAL_MALADE <> 0 THEN date(DT_LANC) ELSE '20991231'::date END AS date_solde_0_c,
|
|
|
'20991231'::date as date_solde_0_h,
|
|
|
CASE WHEN TOTAL_SS <> 0 THEN date(DT_LANC) ELSE '20991231'::date END AS date_solde_1_c,
|
|
|
'20991231'::date as date_solde_1_h,
|
|
|
CASE WHEN TOTAL_DIVERS <> 0 THEN date(DT_LANC) ELSE '20991231'::date END AS date_solde_2_c,
|
|
|
'20991231'::date as date_solde_2_h,
|
|
|
CASE WHEN TOTAL_DEPARTEMENT <> 0 THEN date(DT_LANC) ELSE '20991231'::date END AS date_solde_22_c,
|
|
|
'20991231'::date as date_solde_22_h,
|
|
|
TOTAL_AVIS AS montant_facture_c,
|
|
|
0::numeric AS montant_facture_h,
|
|
|
TOTAL_MALADE AS montant_facture_0_c,
|
|
|
0::numeric AS montant_facture_0_h,
|
|
|
TOTAL_SS AS montant_facture_1_c,
|
|
|
0::numeric AS montant_facture_1_h,
|
|
|
TOTAL_DIVERS AS montant_facture_2_c,
|
|
|
0::numeric AS montant_facture_2_h,
|
|
|
TOTAL_DEPARTEMENT AS montant_facture_22_c,
|
|
|
0::numeric AS montant_facture_22_h,
|
|
|
0::numeric AS montant_facture_c_actes_inclus_dans_sejour,
|
|
|
0::numeric AS montant_facture_h_actes_inclus_dans_sejour,
|
|
|
CASE WHEN HBG <> '1' THEN 0 ELSE TOTAL_SS END + TOTAL_MALADE + TOTAL_DIVERS + TOTAL_DEPARTEMENT AS montant_comptabilise_c,
|
|
|
0::numeric AS montant_comptabilise_h,
|
|
|
TOTAL_MALADE AS montant_comptabilise_0_c,
|
|
|
0 AS montant_comptabilise_0_h,
|
|
|
CASE WHEN HBG <> '1' THEN 0 ELSE TOTAL_SS END AS montant_comptabilise_1_c,
|
|
|
0::numeric AS montant_comptabilise_1_h,
|
|
|
TOTAL_DIVERS AS montant_comptabilise_2_c,
|
|
|
0::numeric AS montant_comptabilise_2_h,
|
|
|
TOTAL_DEPARTEMENT AS montant_comptabilise_22_c,
|
|
|
0::numeric AS montant_comptabilise_22_h,
|
|
|
CASE WHEN HBG <> '1' THEN TOTAL_SS ELSE 0 END AS montant_comptabilise_budget_global_c,
|
|
|
REGLE_MALADE + REGLE_DIVERS + REGLE_DEPARTEMENT AS montant_regle_c,
|
|
|
0::numeric AS montant_regle_h,
|
|
|
REGLE_MALADE AS montant_regle_0_c,
|
|
|
0::numeric AS montant_regle_0_h,
|
|
|
0::numeric AS montant_regle_1_c,
|
|
|
0::numeric AS montant_regle_1_h,
|
|
|
REGLE_DIVERS AS montant_regle_2_c,
|
|
|
0::numeric AS montant_regle_2_h,
|
|
|
REGLE_DEPARTEMENT AS montant_regle_22_c,
|
|
|
0::numeric AS montant_regle_22_h,
|
|
|
|
|
|
0::numeric AS delai_facture,
|
|
|
|
|
|
0::numeric AS delai_expedition,
|
|
|
0::numeric AS delai_expedition_0,
|
|
|
0::numeric AS delai_expedition_1,
|
|
|
0::numeric AS delai_expedition_2,
|
|
|
0::numeric AS delai_expedition_22,
|
|
|
0::numeric AS delai_solde,
|
|
|
0::numeric AS delai_solde_0_c,
|
|
|
0::numeric AS delai_solde_0_h,
|
|
|
0::numeric AS delai_solde_1_c,
|
|
|
0::numeric AS delai_solde_1_h,
|
|
|
0::numeric AS delai_solde_2_c,
|
|
|
0::numeric AS delai_solde_2_h,
|
|
|
0::numeric AS delai_solde_22_c,
|
|
|
0::numeric AS delai_solde_22_h
|
|
|
|
|
|
FROM w_G_SP3 G_SP3
|
|
|
JOIN w_SEJOUR_ok ON w_SEJOUR_ok.NUM_ADMINISTRATIF = G_SP3.NUM_ENTREE
|
|
|
JOIN activite[PX].p_sejours ON w_SEJOUR_ok.NUM_DEM_ADM = p_sejours.code_original AND p_sejours.etat = ''
|
|
|
LEFT JOIN w_G_LIGNEA_SP3_dates ON w_G_LIGNEA_SP3_dates.NUM_AVIS = G_SP3.NUM_AVIS
|
|
|
WHERE VALIDE = 1
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
UPDATE w_factures
|
|
|
SET date_debut = p_sejours.date_entree
|
|
|
FROM activite[PX].p_sejours
|
|
|
WHERE w_factures.no_sejour = p_sejours.no_sejour AND
|
|
|
w_factures.date_debut < p_sejours.date_entree;
|
|
|
|
|
|
UPDATE w_factures
|
|
|
SET date_debut = p_sejours.date_entree
|
|
|
FROM activite[PX].p_sejours
|
|
|
WHERE w_factures.no_sejour = p_sejours.no_sejour AND
|
|
|
w_factures.date_debut > p_sejours.date_sortie;
|
|
|
|
|
|
|
|
|
UPDATE w_factures
|
|
|
SET date_fin = p_sejours.date_sortie
|
|
|
FROM activite[PX].p_sejours
|
|
|
WHERE w_factures.no_sejour = p_sejours.no_sejour AND
|
|
|
w_factures.date_fin > p_sejours.date_sortie AND p_sejours.code_sorti = '1';
|
|
|
|
|
|
|
|
|
UPDATE w_factures
|
|
|
SET date_fin = p_sejours.date_sortie
|
|
|
FROM activite[PX].p_sejours
|
|
|
WHERE w_factures.no_sejour = p_sejours.no_sejour AND
|
|
|
w_factures.date_fin < p_sejours.date_entree;
|
|
|
|
|
|
|
|
|
|
|
|
-- Avoirs qui annulent des factures
|
|
|
|
|
|
UPDATE w_factures SET
|
|
|
no_facture_od_avoir = w_factures_avoir.no_facture
|
|
|
FROM w_factures w_factures_avoir
|
|
|
WHERE w_factures_avoir.no_facture_od_avoir = w_factures.no_facture AND w_factures.no_facture_od_avoir = '';
|
|
|
|
|
|
|
|
|
UPDATE w_factures SET
|
|
|
facture_od_avoir_id = w_factures_avoir.oid
|
|
|
FROM w_factures w_factures_avoir
|
|
|
WHERE w_factures_avoir.no_facture_od_avoir = w_factures.no_facture AND w_factures.facture_od_avoir_id = 0;
|
|
|
|
|
|
|
|
|
|
|
|
-- Facture de référence
|
|
|
|
|
|
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(w_factures.no_facture) AS no_facture_last,
|
|
|
MAX(CASE WHEN type_facture = '0' AND type_facture <> 'P' THEN w_factures.no_facture ELSE null END) AS no_facture_reference_last,
|
|
|
MAX(CASE WHEN type_facture <> '1' AND type_facture <> 'P' THEN w_factures.no_facture ELSE null END) AS no_facture_reference_last_2,
|
|
|
MAX(w_factures.oid) AS facture_id_last,
|
|
|
MAX(CASE WHEN type_facture = '0' AND type_facture <> 'P' THEN w_factures.oid ELSE null END) AS facture_id_reference_last,
|
|
|
MAX(CASE WHEN type_facture <> '1' AND type_facture <> 'P' THEN w_factures.oid ELSE null END) AS facture_id_reference_last_2
|
|
|
FROM w_factures
|
|
|
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 = w_factures_references.oid
|
|
|
FROM w_factures w_factures_references
|
|
|
WHERE w_sejours_facture_reference.no_facture_last = w_factures_references.no_facture
|
|
|
AND w_sejours_facture_reference.facture_id_last <> w_factures_references.oid;
|
|
|
|
|
|
|
|
|
UPDATE w_sejours_facture_reference
|
|
|
SET facture_id_reference_last = w_factures_references.oid
|
|
|
FROM w_factures w_factures_references
|
|
|
WHERE w_sejours_facture_reference.no_facture_reference_last = w_factures_references.no_facture
|
|
|
AND w_sejours_facture_reference.facture_id_reference_last <> w_factures_references.oid;
|
|
|
|
|
|
UPDATE w_sejours_facture_reference
|
|
|
SET facture_id_reference_last_2 = w_factures_references.oid
|
|
|
FROM w_factures w_factures_references
|
|
|
WHERE w_sejours_facture_reference.no_facture_reference_last_2 = w_factures_references.no_facture
|
|
|
AND w_sejours_facture_reference.facture_id_reference_last_2 <> w_factures_references.oid;
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE w_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 w_factures.no_sejour = w_sejours_facture_reference.no_sejour AND
|
|
|
w_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 w_factures
|
|
|
SET no_facture_reference = no_facture
|
|
|
WHERE (no_facture_reference IS NULL OR no_facture_reference = '');
|
|
|
|
|
|
|
|
|
UPDATE w_factures
|
|
|
SET type_facture = '0'
|
|
|
WHERE w_factures.type_facture = '2' AND
|
|
|
w_factures.no_facture = w_factures.no_facture_reference;
|
|
|
|
|
|
UPDATE w_factures
|
|
|
SET type_facture = '2'
|
|
|
WHERE w_factures.type_facture = '0' AND
|
|
|
w_factures.no_facture <> w_factures.no_facture_reference;
|
|
|
|
|
|
UPDATE w_factures
|
|
|
SET facture_reference_id = w_factures_references.oid
|
|
|
FROM w_factures w_factures_references
|
|
|
WHERE w_factures.no_facture_reference = w_factures_references.no_facture
|
|
|
AND w_factures.facture_reference_id <> w_factures_references.oid;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- 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,
|
|
|
no_facture_reference,
|
|
|
facture_reference_id,
|
|
|
no_facture_od_avoir,
|
|
|
facture_od_avoir_id,
|
|
|
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,
|
|
|
montant_comptabilise_budget_global_c,
|
|
|
|
|
|
nb_rejets,
|
|
|
|
|
|
montant_facture_c_actes_inclus_dans_sejour,
|
|
|
montant_facture_h_actes_inclus_dans_sejour
|
|
|
)
|
|
|
SELECT
|
|
|
sejour_id,
|
|
|
no_sejour,
|
|
|
no_facture,
|
|
|
no_facture_reference,
|
|
|
facture_reference_id,
|
|
|
no_facture_od_avoir,
|
|
|
facture_od_avoir_id,
|
|
|
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,
|
|
|
montant_comptabilise_budget_global_c,
|
|
|
|
|
|
nb_rejets,
|
|
|
|
|
|
montant_facture_c_actes_inclus_dans_sejour,
|
|
|
montant_facture_h_actes_inclus_dans_sejour
|
|
|
FROM w_factures;
|
|
|
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_3');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_4');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_5');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_6');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_7');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_8');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_9');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_10');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_11');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_12');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_13');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_14');
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Rejets">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Lignes non facturées Clinique">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Lignes facturées Clinique">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
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');
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_c;
|
|
|
CREATE TEMP TABLE w_factures_lignes_c AS
|
|
|
SELECT
|
|
|
1::integer AS origine_facturation_id,
|
|
|
p_factures.oid AS facture_id,
|
|
|
p_factures.no_facture AS no_facture,
|
|
|
date(COALESCE(A_DT_DEBUT, p_factures.date_debut)) AS date_debut,
|
|
|
date(COALESCE(A_DT_FIN, p_factures.date_fin))AS date_fin,
|
|
|
p_factures.date_vente AS date_vente,
|
|
|
p_sejours.lieu_sortie_id,
|
|
|
CASE WHEN A_TOTAL < 0 THEN 0 - A_NB_JOUR ELSE A_NB_JOUR END AS nb_rubrique,
|
|
|
CASE WHEN A_TOTAL < 0 THEN 0 - A_NB_JOUR ELSE A_NB_JOUR END AS nb_prestations,
|
|
|
1::numeric as coefficient,
|
|
|
1::numeric 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,
|
|
|
COALESCE(t_prestations.oid::bigint, 0) AS prestation_id,
|
|
|
ABS(A_TARIF) AS prix_unitaire,
|
|
|
|
|
|
A_TOTAL AS montant_facture,
|
|
|
A_MALADE as montant_facture_0,
|
|
|
A_SS as montant_facture_1,
|
|
|
A_DIVERS as montant_facture_2,
|
|
|
A_DEPARTEMENT as montant_facture_22,
|
|
|
|
|
|
0::numeric AS montant_facture_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_0_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_1_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_2_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_22_actes_inclus_dans_sejour,
|
|
|
|
|
|
CASE WHEN A_DIVERS = 0 AND A_DEPARTEMENT = 0 THEN 100 - A_TAUX_CAISSE ELSE 0 END as taux_0,
|
|
|
A_TAUX_CAISSE as taux_1,
|
|
|
CASE WHEN A_DIVERS <> 0 THEN 100 - A_TAUX_CAISSE ELSE 0 END as taux_2,
|
|
|
CASE WHEN A_DEPARTEMENT <> 0 THEN 100 - A_TAUX_CAISSE ELSE 0 END as taux_22,
|
|
|
|
|
|
|
|
|
A_DEPARTEMENT + A_DIVERS + A_MALADE + CASE WHEN HBG <> '1' THEN 0 ELSE A_SS END AS montant_comptabilise,
|
|
|
A_MALADE AS montant_comptabilise_0,
|
|
|
CASE WHEN HBG <> '1' THEN 0 ELSE A_SS END AS montant_comptabilise_1,
|
|
|
A_DIVERS AS montant_comptabilise_2,
|
|
|
A_DEPARTEMENT as montant_comptabilise_22,
|
|
|
CASE WHEN HBG <> '1' THEN A_SS ELSE 0 END AS montant_comptabilise_budget_global_1,
|
|
|
|
|
|
CASE WHEN p_factures.montant_regle_2_c = p_factures.montant_comptabilise_2_c THEN A_DIVERS ELSE 0 END +
|
|
|
CASE WHEN p_factures.montant_regle_0_c = p_factures.montant_comptabilise_0_c THEN A_MALADE ELSE 0 END +
|
|
|
CASE WHEN p_factures.montant_regle_22_c = p_factures.montant_comptabilise_22_c THEN A_DEPARTEMENT ELSE 0 END
|
|
|
AS montant_regle,
|
|
|
CASE WHEN p_factures.montant_regle_0_c = p_factures.montant_comptabilise_0_c THEN A_MALADE ELSE 0 END AS montant_regle_0,
|
|
|
0::numeric as montant_regle_1,
|
|
|
CASE WHEN p_factures.montant_regle_2_c = p_factures.montant_comptabilise_2_c THEN A_DIVERS ELSE 0 END AS montant_regle_2,
|
|
|
CASE WHEN p_factures.montant_regle_22_c = p_factures.montant_comptabilise_22_c THEN A_DEPARTEMENT ELSE 0 END AS montant_regle_22,
|
|
|
0::numeric AS rubrique_facture_id
|
|
|
|
|
|
FROM prod_calystene.G_LIGNEA_SP3
|
|
|
JOIN w_G_SP3 G_SP3 ON G_LIGNEA_SP3.NUM_AVIS = G_SP3.NUM_AVIS
|
|
|
JOIN activite[PX].p_factures ON G_LIGNEA_SP3.NUM_AVIS = no_facture
|
|
|
JOIN activite[PX].p_sejours ON p_factures.no_sejour = p_sejours.no_sejour AND p_sejours.etat = ''
|
|
|
LEFT JOIN activite[PX].t_rubriques_facturation ON (A_CODE_TARIF = t_rubriques_facturation.code_original)
|
|
|
LEFT JOIN activite.t_prestations ON (A_CODE_TARIF = t_prestations.code)
|
|
|
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
SELECT
|
|
|
1::integer AS origine_facturation_id,
|
|
|
p_factures.oid AS facture_id,
|
|
|
p_factures.no_facture AS no_facture,
|
|
|
date(COALESCE(DT_DEBUT, p_factures.date_debut)) AS date_debut,
|
|
|
date(COALESCE(DT_FIN, p_factures.date_fin))AS date_fin,
|
|
|
p_factures.date_vente AS date_vente,
|
|
|
p_sejours.lieu_sortie_id,
|
|
|
CASE WHEN C_TOTAL < 0 THEN 0 - C_NB ELSE C_NB END AS nb_rubrique,
|
|
|
CASE WHEN C_TOTAL < 0 THEN 0 - C_NB ELSE C_NB END AS nb_prestations,
|
|
|
1::numeric as coefficient,
|
|
|
1::numeric 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,
|
|
|
COALESCE(t_prestations.oid::bigint, 0) AS prestation_id,
|
|
|
ABS(C_TARIF) AS prix_unitaire,
|
|
|
|
|
|
C_TOTAL AS montant_facture,
|
|
|
C_MALADE as montant_facture_0,
|
|
|
0::numeric as montant_facture_1,
|
|
|
C_DIVERS as montant_facture_2,
|
|
|
C_DEPARTEMENT as montant_facture_22,
|
|
|
|
|
|
0::numeric AS montant_facture_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_0_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_1_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_2_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_22_actes_inclus_dans_sejour,
|
|
|
|
|
|
CASE WHEN C_DIVERS = 0 AND C_DEPARTEMENT <> 0 THEN 100 ELSE 0 END as taux_0,
|
|
|
0::NUMERIC as taux_1,
|
|
|
CASE WHEN C_DIVERS <> 0 THEN 100 ELSE 0 END as taux_2,
|
|
|
CASE WHEN C_DEPARTEMENT <> 0 THEN 100 ELSE 0 END as taux_22,
|
|
|
|
|
|
|
|
|
C_DEPARTEMENT + C_DIVERS + C_MALADE AS montant_comptabilise,
|
|
|
C_MALADE AS montant_comptabilise_0,
|
|
|
0::numeric as montant_comptabilise_1,
|
|
|
C_DIVERS AS montant_comptabilise_2,
|
|
|
C_DEPARTEMENT as montant_comptabilise_22,
|
|
|
0::NUMERIC as montant_comptabilise_budget_global_1,
|
|
|
|
|
|
CASE WHEN p_factures.montant_regle_2_c = p_factures.montant_comptabilise_2_c THEN C_DIVERS ELSE 0 END +
|
|
|
CASE WHEN p_factures.montant_regle_0_c = p_factures.montant_comptabilise_0_c THEN C_MALADE ELSE 0 END +
|
|
|
CASE WHEN p_factures.montant_regle_22_c = p_factures.montant_comptabilise_22_c THEN C_DEPARTEMENT ELSE 0 END
|
|
|
AS montant_regle,
|
|
|
CASE WHEN p_factures.montant_regle_0_c = p_factures.montant_comptabilise_0_c THEN C_MALADE ELSE 0 END AS montant_regle_0,
|
|
|
0::numeric as montant_regle_1,
|
|
|
CASE WHEN p_factures.montant_regle_2_c = p_factures.montant_comptabilise_2_c THEN C_DIVERS ELSE 0 END AS montant_regle_2,
|
|
|
CASE WHEN p_factures.montant_regle_22_c = p_factures.montant_comptabilise_22_c THEN C_DEPARTEMENT ELSE 0 END AS montant_regle_22,
|
|
|
0::numeric AS rubrique_facture_id
|
|
|
|
|
|
FROM prod_calystene.G_LIGNEC_SP3
|
|
|
JOIN w_G_SP3 G_SP3 ON G_LIGNEC_SP3.NUM_AVIS = G_SP3.NUM_AVIS
|
|
|
JOIN activite[PX].p_factures ON G_LIGNEC_SP3.NUM_AVIS = no_facture
|
|
|
JOIN activite[PX].p_sejours ON p_factures.no_sejour = p_sejours.no_sejour AND p_sejours.etat = ''
|
|
|
LEFT JOIN activite[PX].t_rubriques_facturation ON (CODE_PRESTATION = t_rubriques_facturation.code_original)
|
|
|
LEFT JOIN activite.t_prestations ON (CODE_PRESTATION = t_prestations.code)
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
SELECT
|
|
|
1::integer AS origine_facturation_id,
|
|
|
p_factures.oid AS facture_id,
|
|
|
p_factures.no_facture AS no_facture,
|
|
|
date(COALESCE(B_DT_DEBUT, p_factures.date_debut)) AS date_debut,
|
|
|
date(COALESCE(B_DT_FIN, p_factures.date_fin))AS date_fin,
|
|
|
p_factures.date_vente AS date_vente,
|
|
|
p_sejours.lieu_sortie_id,
|
|
|
CASE WHEN B_TOTAL < 0 THEN 0 - B_NB_JOUR ELSE B_NB_JOUR END AS nb_rubrique,
|
|
|
CASE WHEN B_TOTAL < 0 THEN 0 - B_NB_JOUR ELSE B_NB_JOUR END AS nb_prestations,
|
|
|
1::numeric as coefficient,
|
|
|
1::numeric 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,
|
|
|
COALESCE(t_prestations.oid::bigint, 0) AS prestation_id,
|
|
|
ABS(B_TARIF) AS prix_unitaire,
|
|
|
|
|
|
B_TOTAL AS montant_facture,
|
|
|
B_MALADE as montant_facture_0,
|
|
|
B_SS as montant_facture_1,
|
|
|
B_DIVERS as montant_facture_2,
|
|
|
B_DEPARTEMENT as montant_facture_22,
|
|
|
|
|
|
0::numeric AS montant_facture_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_0_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_1_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_2_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_22_actes_inclus_dans_sejour,
|
|
|
|
|
|
CASE WHEN B_DIVERS = 0 AND B_DEPARTEMENT = 0 THEN 100 ELSE 0 END as taux_0,
|
|
|
0::NUMERIC as taux_1,
|
|
|
CASE WHEN B_DIVERS <> 0 THEN 100 ELSE 0 END as taux_2,
|
|
|
CASE WHEN B_DEPARTEMENT <> 0 THEN 100 ELSE 0 END as taux_22,
|
|
|
|
|
|
|
|
|
B_DEPARTEMENT + B_DIVERS + B_MALADE + CASE WHEN HBG <> '1' THEN 0 ELSE B_SS END AS montant_comptabilise,
|
|
|
B_MALADE AS montant_comptabilise_0,
|
|
|
CASE WHEN HBG <> '1' THEN 0 ELSE B_SS END AS montant_comptabilise_1,
|
|
|
B_DIVERS AS montant_comptabilise_2,
|
|
|
B_DEPARTEMENT as montant_comptabilise_22,
|
|
|
CASE WHEN HBG <> '1' THEN B_SS ELSE 0 END AS montant_comptabilise_budget_global_1,
|
|
|
|
|
|
CASE WHEN p_factures.montant_regle_2_c = p_factures.montant_comptabilise_2_c THEN B_DIVERS ELSE 0 END +
|
|
|
CASE WHEN p_factures.montant_regle_0_c = p_factures.montant_comptabilise_0_c THEN B_MALADE ELSE 0 END +
|
|
|
CASE WHEN p_factures.montant_regle_22_c = p_factures.montant_comptabilise_22_c THEN B_DEPARTEMENT ELSE 0 END
|
|
|
AS montant_regle,
|
|
|
CASE WHEN p_factures.montant_regle_0_c = p_factures.montant_comptabilise_0_c THEN B_MALADE ELSE 0 END AS montant_regle_0,
|
|
|
0::numeric as montant_regle_1,
|
|
|
CASE WHEN p_factures.montant_regle_2_c = p_factures.montant_comptabilise_2_c THEN B_DIVERS ELSE 0 END AS montant_regle_2,
|
|
|
CASE WHEN p_factures.montant_regle_22_c = p_factures.montant_comptabilise_22_c THEN B_DEPARTEMENT ELSE 0 END AS montant_regle_22,
|
|
|
0::numeric AS rubrique_facture_id
|
|
|
|
|
|
FROM w_G_SP3 G_SP3
|
|
|
JOIN activite[PX].p_factures ON NUM_AVIS = no_facture
|
|
|
JOIN activite[PX].p_sejours ON p_factures.no_sejour = p_sejours.no_sejour AND p_sejours.etat = ''
|
|
|
LEFT JOIN activite[PX].t_rubriques_facturation ON ( 'FJ' = t_rubriques_facturation.code_original)
|
|
|
LEFT JOIN activite.t_prestations ON ('FJ' = t_prestations.code)
|
|
|
WHERE B_TOTAL <> 0
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
SELECT
|
|
|
1::integer AS origine_facturation_id,
|
|
|
p_factures.oid AS facture_id,
|
|
|
p_factures.no_facture AS no_facture,
|
|
|
date(COALESCE(B_DT_FIN, p_factures.date_fin)) AS date_debut,
|
|
|
date(COALESCE(B_DT_FIN, p_factures.date_fin))AS date_fin,
|
|
|
p_factures.date_vente AS date_vente,
|
|
|
p_sejours.lieu_sortie_id,
|
|
|
CASE WHEN B_JS_TOTAL < 0 THEN 0 - B_NB_JOUR_SORTIE ELSE B_NB_JOUR_SORTIE END AS nb_rubrique,
|
|
|
CASE WHEN B_JS_TOTAL < 0 THEN 0 - B_NB_JOUR_SORTIE ELSE B_NB_JOUR_SORTIE END AS nb_prestations,
|
|
|
1::numeric as coefficient,
|
|
|
1::numeric 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,
|
|
|
COALESCE(t_prestations.oid::bigint, 0) AS prestation_id,
|
|
|
ABS(B_TARIF) AS prix_unitaire,
|
|
|
|
|
|
B_JS_TOTAL AS montant_facture,
|
|
|
B_JS_MALADE as montant_facture_0,
|
|
|
B_JS_SS as montant_facture_1,
|
|
|
B_JS_DIVERS as montant_facture_2,
|
|
|
B_JS_DEPARTEMENT as montant_facture_22,
|
|
|
|
|
|
0::numeric AS montant_facture_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_0_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_1_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_2_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_22_actes_inclus_dans_sejour,
|
|
|
|
|
|
CASE WHEN B_JS_DIVERS = 0 AND B_JS_DEPARTEMENT <> 0 THEN 100 ELSE 0 END as taux_0,
|
|
|
0::NUMERIC as taux_1,
|
|
|
CASE WHEN B_JS_DIVERS <> 0 THEN 100 ELSE 0 END as taux_2,
|
|
|
CASE WHEN B_JS_DEPARTEMENT <> 0 THEN 100 ELSE 0 END as taux_22,
|
|
|
|
|
|
B_JS_DEPARTEMENT + B_JS_DIVERS + B_JS_MALADE + CASE WHEN HBG <> '1' THEN 0 ELSE B_JS_SS END AS montant_comptabilise,
|
|
|
B_JS_MALADE AS montant_comptabilise_0,
|
|
|
CASE WHEN HBG <> '1' THEN 0 ELSE B_JS_SS END AS montant_comptabilise_1,
|
|
|
B_JS_DIVERS AS montant_comptabilise_2,
|
|
|
B_JS_DEPARTEMENT as montant_comptabilise_22,
|
|
|
CASE WHEN HBG <> '1' THEN B_JS_SS ELSE 0 END AS montant_comptabilise_budget_global_1,
|
|
|
|
|
|
CASE WHEN p_factures.montant_regle_2_c = p_factures.montant_comptabilise_2_c THEN B_JS_DIVERS ELSE 0 END +
|
|
|
CASE WHEN p_factures.montant_regle_0_c = p_factures.montant_comptabilise_0_c THEN B_JS_MALADE ELSE 0 END +
|
|
|
CASE WHEN p_factures.montant_regle_22_c = p_factures.montant_comptabilise_22_c THEN B_JS_DEPARTEMENT ELSE 0 END
|
|
|
AS montant_regle,
|
|
|
CASE WHEN p_factures.montant_regle_0_c = p_factures.montant_comptabilise_0_c THEN B_JS_MALADE ELSE 0 END AS montant_regle_0,
|
|
|
0::numeric as montant_regle_1,
|
|
|
CASE WHEN p_factures.montant_regle_2_c = p_factures.montant_comptabilise_2_c THEN B_JS_DIVERS ELSE 0 END AS montant_regle_2,
|
|
|
CASE WHEN p_factures.montant_regle_22_c = p_factures.montant_comptabilise_22_c THEN B_JS_DEPARTEMENT ELSE 0 END AS montant_regle_22,
|
|
|
0::numeric AS rubrique_facture_id
|
|
|
|
|
|
FROM w_G_SP3 G_SP3
|
|
|
JOIN activite[PX].p_factures ON NUM_AVIS = no_facture
|
|
|
JOIN activite[PX].p_sejours ON p_factures.no_sejour = p_sejours.no_sejour AND p_sejours.etat = ''
|
|
|
LEFT JOIN activite[PX].t_rubriques_facturation ON ( 'FJA' = t_rubriques_facturation.code_original)
|
|
|
LEFT JOIN activite.t_prestations ON ('FJA' = t_prestations.code)
|
|
|
WHERE B_JS_TOTAL <> 0
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
SELECT
|
|
|
1::integer AS origine_facturation_id,
|
|
|
p_factures.oid AS facture_id,
|
|
|
p_factures.no_facture AS no_facture,
|
|
|
p_factures.date_debut AS date_debut,
|
|
|
date(COALESCE(B_DT_FIN, p_factures.date_fin))AS date_fin,
|
|
|
p_factures.date_vente AS date_vente,
|
|
|
p_sejours.lieu_sortie_id,
|
|
|
CASE WHEN TOTAL_AVIS < 0 THEN -1 ELSE 1 END AS nb_rubrique,
|
|
|
CASE WHEN TOTAL_AVIS < 0 THEN -1 ELSE 1 END AS nb_prestations,
|
|
|
1::numeric as coefficient,
|
|
|
1::numeric 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,
|
|
|
COALESCE(t_prestations.oid::bigint, 0) AS prestation_id,
|
|
|
ABS(TOTAL_AVIS) AS prix_unitaire,
|
|
|
|
|
|
TOTAL_AVIS AS montant_facture,
|
|
|
TOTAL_MALADE as montant_facture_0,
|
|
|
TOTAL_SS as montant_facture_1,
|
|
|
TOTAL_DIVERS as montant_facture_2,
|
|
|
TOTAL_DEPARTEMENT as montant_facture_22,
|
|
|
|
|
|
0::numeric AS montant_facture_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_0_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_1_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_2_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_22_actes_inclus_dans_sejour,
|
|
|
|
|
|
CASE WHEN TOTAL_DIVERS = 0 AND TOTAL_DEPARTEMENT = 0 THEN 100 ELSE 0 END as taux_0,
|
|
|
0::NUMERIC as taux_1,
|
|
|
CASE WHEN TOTAL_DIVERS <> 0 THEN 100 ELSE 0 END as taux_2,
|
|
|
CASE WHEN TOTAL_DEPARTEMENT <> 0 THEN 100 ELSE 0 END as taux_22,
|
|
|
|
|
|
|
|
|
TOTAL_DEPARTEMENT + TOTAL_DIVERS + TOTAL_MALADE + CASE WHEN HBG <> '1' THEN 0 ELSE TOTAL_SS END AS montant_comptabilise,
|
|
|
TOTAL_MALADE AS montant_comptabilise_0,
|
|
|
CASE WHEN HBG <> '1' THEN 0 ELSE TOTAL_SS END AS montant_comptabilise_1,
|
|
|
TOTAL_DIVERS AS montant_comptabilise_2,
|
|
|
TOTAL_DEPARTEMENT as montant_comptabilise_22,
|
|
|
CASE WHEN HBG <> '1' THEN TOTAL_SS ELSE 0 END AS montant_comptabilise_budget_global_1,
|
|
|
|
|
|
CASE WHEN p_factures.montant_regle_2_c = p_factures.montant_comptabilise_2_c THEN TOTAL_DIVERS ELSE 0 END +
|
|
|
CASE WHEN p_factures.montant_regle_0_c = p_factures.montant_comptabilise_0_c THEN TOTAL_MALADE ELSE 0 END +
|
|
|
CASE WHEN p_factures.montant_regle_22_c = p_factures.montant_comptabilise_22_c THEN TOTAL_DEPARTEMENT ELSE 0 END
|
|
|
AS montant_regle,
|
|
|
CASE WHEN p_factures.montant_regle_0_c = p_factures.montant_comptabilise_0_c THEN TOTAL_MALADE ELSE 0 END AS montant_regle_0,
|
|
|
0::numeric as montant_regle_1,
|
|
|
CASE WHEN p_factures.montant_regle_2_c = p_factures.montant_comptabilise_2_c THEN TOTAL_DIVERS ELSE 0 END AS montant_regle_2,
|
|
|
CASE WHEN p_factures.montant_regle_22_c = p_factures.montant_comptabilise_22_c THEN TOTAL_DEPARTEMENT ELSE 0 END AS montant_regle_22,
|
|
|
0::numeric AS rubrique_facture_id
|
|
|
|
|
|
FROM w_G_SP3 G_SP3
|
|
|
JOIN activite[PX].p_factures ON NUM_AVIS = no_facture
|
|
|
JOIN activite[PX].p_sejours ON p_factures.no_sejour = p_sejours.no_sejour AND p_sejours.etat = ''
|
|
|
LEFT JOIN activite[PX].t_rubriques_facturation ON ( 'DIV' = t_rubriques_facturation.code_original)
|
|
|
LEFT JOIN activite.t_prestations ON ('DIV' = t_prestations.code)
|
|
|
WHERE TOTAL_AVIS <> 0 AND G_SP3.TYPE_FACTURE = 4
|
|
|
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_c_r;
|
|
|
CREATE TEMP TABLE w_factures_lignes_c_r AS
|
|
|
SELECT w_factures_lignes_c.no_facture, p_factures.montant_regle_0_c AS to_montant_regle,
|
|
|
MIN(w_factures_lignes_c.CTID) AS to_ctid
|
|
|
FROM w_factures_lignes_c
|
|
|
JOIN activite[PX].p_factures ON
|
|
|
p_factures.no_facture = w_factures_lignes_c.no_facture AND
|
|
|
p_factures.montant_regle_0_c <> 0 AND
|
|
|
p_factures.montant_regle_0_c <> p_factures.montant_comptabilise_0_c AND
|
|
|
w_factures_lignes_c.montant_regle_0 = 0 AND
|
|
|
w_factures_lignes_c.montant_comptabilise_0 <> 0 AND
|
|
|
w_factures_lignes_c.montant_comptabilise_0 = p_factures.montant_regle_0_c
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
|
|
|
UPDATE w_factures_lignes_c
|
|
|
SET montant_regle_0 = to_montant_regle,
|
|
|
montant_regle = montant_regle + to_montant_regle
|
|
|
FROM w_factures_lignes_c_r
|
|
|
WHERE w_factures_lignes_c.CTID = to_ctid;
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_c_r;
|
|
|
CREATE TEMP TABLE w_factures_lignes_c_r AS
|
|
|
SELECT w_factures_lignes_c.no_facture, p_factures.montant_regle_2_c AS to_montant_regle,
|
|
|
MIN(w_factures_lignes_c.CTID) AS to_ctid
|
|
|
FROM w_factures_lignes_c
|
|
|
JOIN activite[PX].p_factures ON
|
|
|
p_factures.no_facture = w_factures_lignes_c.no_facture AND
|
|
|
p_factures.montant_regle_2_c <> 0 AND
|
|
|
p_factures.montant_regle_2_c <> p_factures.montant_comptabilise_2_c AND
|
|
|
w_factures_lignes_c.montant_regle_2 = 0 AND
|
|
|
w_factures_lignes_c.montant_comptabilise_2 <> 0 AND
|
|
|
w_factures_lignes_c.montant_comptabilise_2 = p_factures.montant_regle_2_c
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
|
|
|
UPDATE w_factures_lignes_c
|
|
|
SET montant_regle_2 = to_montant_regle,
|
|
|
montant_regle = montant_regle + to_montant_regle
|
|
|
FROM w_factures_lignes_c_r
|
|
|
WHERE w_factures_lignes_c.CTID = to_ctid;
|
|
|
|
|
|
|
|
|
-- Autres montants réglés (non soldés à une rubrique d'attente
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_c_r;
|
|
|
CREATE TEMP TABLE w_factures_lignes_c_r AS
|
|
|
SELECT w_factures_lignes_c.no_facture,
|
|
|
SUM(w_factures_lignes_c.montant_regle_0) AS to_montant_regle_0,
|
|
|
SUM(w_factures_lignes_c.montant_regle_2) AS to_montant_regle_2
|
|
|
FROM w_factures_lignes_c
|
|
|
GROUP BY 1;
|
|
|
|
|
|
INSERT INTO w_factures_lignes_c
|
|
|
SELECT
|
|
|
1::integer AS origine_facturation_id,
|
|
|
p_factures.oid AS facture_id,
|
|
|
p_factures.no_facture AS no_facture,
|
|
|
p_factures.date_debut AS date_debut,
|
|
|
p_factures.date_fin AS date_fin,
|
|
|
p_factures.date_vente AS date_vente,
|
|
|
p_sejours.lieu_sortie_id,
|
|
|
0::NUMERIC AS nb_rubrique,
|
|
|
0::NUMERIC AS nb_prestations,
|
|
|
1::numeric as coefficient,
|
|
|
1::numeric 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,
|
|
|
COALESCE(t_prestations.oid::bigint, 0) AS prestation_id,
|
|
|
0::NUMERIC AS prix_unitaire,
|
|
|
|
|
|
0::NUMERIC AS montant_facture,
|
|
|
0::NUMERIC AS montant_facture_0,
|
|
|
0::NUMERIC AS montant_facture_1,
|
|
|
0::NUMERIC AS montant_facture_2,
|
|
|
0::NUMERIC AS montant_facture_22,
|
|
|
|
|
|
0::numeric AS montant_facture_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_0_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_1_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_2_actes_inclus_dans_sejour,
|
|
|
0::numeric as montant_facture_22_actes_inclus_dans_sejour,
|
|
|
|
|
|
0::NUMERIC AS taux_0,
|
|
|
0::NUMERIC AS taux_1,
|
|
|
0::NUMERIC AS taux_2,
|
|
|
0::NUMERIC AS taux_22,
|
|
|
|
|
|
|
|
|
0::NUMERIC AS montant_comptabilise,
|
|
|
0::NUMERIC AS montant_comptabilise_0,
|
|
|
0::NUMERIC AS montant_comptabilise_1,
|
|
|
0::NUMERIC AS montant_comptabilise_2,
|
|
|
0::numeric as montant_comptabilise_22,
|
|
|
0::NUMERIC AS montant_comptabilise_budget_global_1,
|
|
|
|
|
|
round((p_factures.montant_regle_c - to_montant_regle_0 - to_montant_regle_2)::numeric,2) AS montant_regle,
|
|
|
round((p_factures.montant_regle_0_c - to_montant_regle_0)::numeric,2) AS montant_regle_0,
|
|
|
0::numeric as montant_regle_1,
|
|
|
round((p_factures.montant_regle_2_c - to_montant_regle_2)::numeric,2) AS montant_regle_2,
|
|
|
0::numeric as montant_regle_22,
|
|
|
0::numeric AS rubrique_facture_id
|
|
|
|
|
|
FROM activite[PX].p_factures
|
|
|
JOIN activite[PX].p_sejours ON p_factures.no_sejour = p_sejours.no_sejour AND p_sejours.etat = ''
|
|
|
JOIN w_factures_lignes_c_r ON w_factures_lignes_c_r.no_facture = p_factures.no_facture
|
|
|
LEFT JOIN activite[PX].t_rubriques_facturation ON ( '*REGPAR' = t_rubriques_facturation.code_original)
|
|
|
LEFT JOIN activite.t_prestations ON ('*REGPAR' = t_prestations.code_original)
|
|
|
WHERE round((p_factures.montant_regle_0_c - to_montant_regle_0)::numeric,2) <> 0 OR
|
|
|
round((p_factures.montant_regle_2_c - to_montant_regle_2)::numeric,2) <> 0;
|
|
|
|
|
|
-- Rubriques internes cti
|
|
|
SELECT activite[PX].cti_reorganize_rubrique_facture_c('w_factures_lignes_c');
|
|
|
|
|
|
-- Validation MVTS
|
|
|
INSERT INTO activite[PX].p_factures_lignes_c(
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
nb_prestation,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facture_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_id,
|
|
|
prestation_id,
|
|
|
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_comptabilise_budget_global_1,
|
|
|
|
|
|
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
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
nb_prestations,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facture_id,
|
|
|
rubrique_facturation_id,
|
|
|
rubrique_comptabilisation_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,
|
|
|
montant_comptabilise_budget_global_1,
|
|
|
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_factures_lignes_c
|
|
|
WHERE (montant_facture <> 0 OR
|
|
|
montant_facture_0 <> 0 OR
|
|
|
montant_facture_1 <> 0 OR
|
|
|
montant_facture_2 <> 0 OR
|
|
|
montant_comptabilise <> 0 OR
|
|
|
montant_comptabilise_0 <> 0 OR
|
|
|
montant_comptabilise_1 <> 0 OR
|
|
|
montant_comptabilise_2 <> 0 OR
|
|
|
montant_regle <> 0 OR
|
|
|
montant_regle_0 <> 0 OR
|
|
|
montant_regle_1 <> 0 OR
|
|
|
montant_regle_2 <> 0) ;
|
|
|
|
|
|
|
|
|
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_c_1');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_c_2');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_lignes_c_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');
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
-- Eclatement des supplements par jour
|
|
|
DROP TABLE IF EXISTS w_mouvements_sejour_absence;
|
|
|
CREATE TEMP TABLE w_mouvements_sejour_absence AS
|
|
|
SELECT no_sejour, date
|
|
|
FROM activite[PX].p_mouvements_sejour
|
|
|
JOIN activite[PX].t_lieux ON lieu_id = t_lieux.oid
|
|
|
JOIN activite[PX].t_services_facturation ON service_facturation_id = t_services_facturation.oid AND t_services_facturation.est_absence = '1'
|
|
|
WHERE 120000 BETWEEN heure_debut AND heure_fin
|
|
|
GROUP BY 1,2;
|
|
|
|
|
|
|
|
|
CREATE INDEX w_mouvements_sejour_absence_i1
|
|
|
ON w_mouvements_sejour_absence
|
|
|
USING btree
|
|
|
(no_sejour);
|
|
|
|
|
|
|
|
|
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, p_factures.no_sejour, 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
|
|
|
WHERE prestation_id IN (SELECT oid
|
|
|
FROM activite.t_prestations
|
|
|
WHERE code IN ('31', 'PJ', 'FJ', 'PHJ', 'SSM', 'SRC', 'REA', 'STF', 'NN1', 'NN2', 'NN3', 'CP', 'CPC', 'SHO') OR
|
|
|
t_prestations.type_ventilation_jour = '1'
|
|
|
)
|
|
|
AND (nb_prestation > 1 or nb_prestation < -1);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_lignes_sup_c_sup;
|
|
|
|
|
|
CREATE TEMP TABLE w_factures_lignes_sup_c_sup AS
|
|
|
SELECT
|
|
|
from_CTID,
|
|
|
no_sejour,
|
|
|
no_facture,
|
|
|
nb_prestation AS from_nb_prestation,
|
|
|
p_calendrier.date AS date_debut,
|
|
|
p_calendrier.date AS date_fin,
|
|
|
CASE WHEN nb_rubrique < 0 THEN -1 ELSE 1 END AS nb_rubrique,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facturation_id,
|
|
|
prestation_id,
|
|
|
round(montant_facture / ABS(nb_prestation),2) AS montant_facture,
|
|
|
round(montant_facture_0 / ABS(nb_prestation),2) AS montant_facture_0,
|
|
|
round(montant_facture_1 / ABS(nb_prestation),2) AS montant_facture_1,
|
|
|
round(montant_facture_2 / ABS(nb_prestation),2) AS montant_facture_2,
|
|
|
round(montant_facture_22 / ABS(nb_prestation),2) AS montant_facture_22,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
finess,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
CASE WHEN nb_prestation < 0 THEN -1 ELSE 1 END AS nb_prestation,
|
|
|
round(montant_comptabilise / ABS(nb_prestation),2) AS montant_comptabilise,
|
|
|
round(montant_comptabilise_0 / ABS(nb_prestation),2) AS montant_comptabilise_0,
|
|
|
round(montant_comptabilise_1 / ABS(nb_prestation),2) AS montant_comptabilise_1,
|
|
|
round(montant_comptabilise_2 / ABS(nb_prestation),2) AS montant_comptabilise_2,
|
|
|
round(montant_comptabilise_22 / ABS(nb_prestation),2) AS montant_comptabilise_22,
|
|
|
rubrique_comptabilisation_id,
|
|
|
round(montant_encours / ABS(nb_prestation),2) AS montant_encours,
|
|
|
round(montant_encours_0 / ABS(nb_prestation),2) AS montant_encours_0,
|
|
|
round(montant_encours_1 / ABS(nb_prestation),2) AS montant_encours_1,
|
|
|
round(montant_encours_2 / ABS(nb_prestation),2) AS montant_encours_2,
|
|
|
round(montant_encours_22 / ABS(nb_prestation),2) AS montant_encours_22,
|
|
|
round(montant_facture_actes_inclus_dans_sejour / ABS(nb_prestation),2) AS montant_facture_actes_inclus_dans_sejour,
|
|
|
round(montant_facture_0_actes_inclus_dans_sejour / ABS(nb_prestation),2) AS montant_facture_0_actes_inclus_dans_sejour,
|
|
|
round(montant_facture_1_actes_inclus_dans_sejour / ABS(nb_prestation),2) AS montant_facture_1_actes_inclus_dans_sejour,
|
|
|
round(montant_facture_2_actes_inclus_dans_sejour / ABS(nb_prestation),2) AS montant_facture_2_actes_inclus_dans_sejour,
|
|
|
round(montant_facture_22_actes_inclus_dans_sejour / ABS(nb_prestation),2) AS montant_facture_22_actes_inclus_dans_sejour,
|
|
|
origine_facturation_id,
|
|
|
round(montant_comptabilise_budget_global_1 / ABS(nb_prestation),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 AND GREATEST(date_fin, date_debut + ABS(nb_prestation)::integer -1) AND
|
|
|
p_calendrier.date <> date_debut
|
|
|
;
|
|
|
|
|
|
CREATE INDEX w_factures_lignes_sup_c_sup_i1
|
|
|
ON w_factures_lignes_sup_c_sup
|
|
|
USING btree
|
|
|
(no_sejour);
|
|
|
|
|
|
|
|
|
UPDATE w_factures_lignes_sup_c_sup SET
|
|
|
nb_rubrique = 0,
|
|
|
coefficient = 0,
|
|
|
montant_facture = 0,
|
|
|
montant_facture_0 = 0,
|
|
|
montant_facture_1 = 0,
|
|
|
montant_facture_2 = 0,
|
|
|
montant_facture_22 = 0,
|
|
|
prix_unitaire = 0,
|
|
|
nb_prestation = 0,
|
|
|
montant_comptabilise = 0,
|
|
|
montant_comptabilise_0 = 0,
|
|
|
montant_comptabilise_1 = 0,
|
|
|
montant_comptabilise_2 = 0,
|
|
|
montant_comptabilise_22 = 0,
|
|
|
montant_encours = 0,
|
|
|
montant_encours_0 = 0,
|
|
|
montant_encours_1 = 0,
|
|
|
montant_encours_2 = 0,
|
|
|
montant_encours_22 = 0,
|
|
|
montant_facture_actes_inclus_dans_sejour = 0,
|
|
|
montant_facture_0_actes_inclus_dans_sejour = 0,
|
|
|
montant_facture_1_actes_inclus_dans_sejour = 0,
|
|
|
montant_facture_2_actes_inclus_dans_sejour = 0,
|
|
|
montant_facture_22_actes_inclus_dans_sejour = 0,
|
|
|
montant_comptabilise_budget_global_1 = 0
|
|
|
FROM w_mouvements_sejour_absence
|
|
|
WHERE w_mouvements_sejour_absence.no_sejour = w_factures_lignes_sup_c_sup.no_sejour AND
|
|
|
w_mouvements_sejour_absence.date = w_factures_lignes_sup_c_sup.date_debut
|
|
|
;
|
|
|
|
|
|
SELECT base.cti_execute(
|
|
|
'DELETE FROM w_factures_lignes_sup_c_sup
|
|
|
USING (
|
|
|
SELECT no_facture, from_CTID,
|
|
|
MAX(date_debut) AS date_debut
|
|
|
FROM w_factures_lignes_sup_c_sup
|
|
|
WHERE nb_prestation <> 0
|
|
|
GROUP BY 1,2
|
|
|
HAVING ABS(MAX(from_nb_prestation)) -1 < ABS(SUM(nb_prestation))
|
|
|
) subview
|
|
|
WHERE w_factures_lignes_sup_c_sup.from_CTID = subview.from_CTID AND
|
|
|
w_factures_lignes_sup_c_sup.date_debut = subview.date_debut',10)
|
|
|
;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
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(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;
|
|
|
|
|
|
DELETE FROM w_factures_lignes_sup_c_sup WHERE nb_rubrique = 0 AND nb_prestation = 0 AND montant_facture = 0;
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures_lignes_c
|
|
|
SET
|
|
|
date_fin = p_factures_lignes_c.date_debut,
|
|
|
nb_rubrique = CASE WHEN p_factures_lignes_c.nb_rubrique < 0 THEN -1 ELSE 1 END ,
|
|
|
nb_prestation = CASE WHEN p_factures_lignes_c.nb_prestation < 0 THEN -1 ELSE 1 END ,
|
|
|
montant_facture = p_factures_lignes_c.montant_facture - w_factures_lignes_sup_c_sup_tot.montant_facture,
|
|
|
montant_facture_0 = p_factures_lignes_c.montant_facture_0 - w_factures_lignes_sup_c_sup_tot.montant_facture_0,
|
|
|
montant_facture_1 = p_factures_lignes_c.montant_facture_1 - w_factures_lignes_sup_c_sup_tot.montant_facture_1,
|
|
|
montant_facture_2 = p_factures_lignes_c.montant_facture_2 - w_factures_lignes_sup_c_sup_tot.montant_facture_2,
|
|
|
montant_facture_22 = p_factures_lignes_c.montant_facture_22 - w_factures_lignes_sup_c_sup_tot.montant_facture_22,
|
|
|
montant_comptabilise = p_factures_lignes_c.montant_comptabilise - w_factures_lignes_sup_c_sup_tot.montant_comptabilise,
|
|
|
montant_comptabilise_0 = p_factures_lignes_c.montant_comptabilise_0 - w_factures_lignes_sup_c_sup_tot.montant_comptabilise_0,
|
|
|
montant_comptabilise_1 = p_factures_lignes_c.montant_comptabilise_1 - w_factures_lignes_sup_c_sup_tot.montant_comptabilise_1,
|
|
|
montant_comptabilise_2 = p_factures_lignes_c.montant_comptabilise_2 - w_factures_lignes_sup_c_sup_tot.montant_comptabilise_2,
|
|
|
montant_comptabilise_22 = p_factures_lignes_c.montant_comptabilise_22 - w_factures_lignes_sup_c_sup_tot.montant_comptabilise_22,
|
|
|
montant_encours = p_factures_lignes_c.montant_encours - w_factures_lignes_sup_c_sup_tot.montant_encours,
|
|
|
montant_encours_0 = p_factures_lignes_c.montant_encours_0 - w_factures_lignes_sup_c_sup_tot.montant_encours_0,
|
|
|
montant_encours_1 = p_factures_lignes_c.montant_encours_1 - w_factures_lignes_sup_c_sup_tot.montant_encours_1,
|
|
|
montant_encours_2 = p_factures_lignes_c.montant_encours_2 - w_factures_lignes_sup_c_sup_tot.montant_encours_2,
|
|
|
montant_encours_22 = p_factures_lignes_c.montant_encours_22 - w_factures_lignes_sup_c_sup_tot.montant_encours_22,
|
|
|
montant_facture_actes_inclus_dans_sejour = p_factures_lignes_c.montant_facture_actes_inclus_dans_sejour - w_factures_lignes_sup_c_sup_tot.montant_facture_actes_inclus_dans_sejour,
|
|
|
montant_facture_0_actes_inclus_dans_sejour = p_factures_lignes_c.montant_facture_0_actes_inclus_dans_sejour - w_factures_lignes_sup_c_sup_tot.montant_facture_0_actes_inclus_dans_sejour,
|
|
|
montant_facture_1_actes_inclus_dans_sejour = p_factures_lignes_c.montant_facture_1_actes_inclus_dans_sejour - w_factures_lignes_sup_c_sup_tot.montant_facture_1_actes_inclus_dans_sejour,
|
|
|
montant_facture_2_actes_inclus_dans_sejour = p_factures_lignes_c.montant_facture_2_actes_inclus_dans_sejour - w_factures_lignes_sup_c_sup_tot.montant_facture_2_actes_inclus_dans_sejour,
|
|
|
montant_facture_22_actes_inclus_dans_sejour = p_factures_lignes_c.montant_facture_22_actes_inclus_dans_sejour - w_factures_lignes_sup_c_sup_tot.montant_facture_22_actes_inclus_dans_sejour,
|
|
|
montant_comptabilise_budget_global_1 = p_factures_lignes_c.montant_comptabilise_budget_global_1 - w_factures_lignes_sup_c_sup_tot.montant_comptabilise_budget_global_1
|
|
|
FROM w_factures_lignes_sup_c_sup_tot
|
|
|
WHERE p_factures_lignes_c.CTID = from_CTID;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].p_factures_lignes_c(
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facturation_id,
|
|
|
prestation_id,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
montant_facture_22,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
finess,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
nb_prestation,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
rubrique_comptabilisation_id,
|
|
|
montant_encours,
|
|
|
montant_encours_0,
|
|
|
montant_encours_1,
|
|
|
montant_encours_2,
|
|
|
montant_encours_22,
|
|
|
montant_facture_actes_inclus_dans_sejour,
|
|
|
montant_facture_0_actes_inclus_dans_sejour,
|
|
|
montant_facture_1_actes_inclus_dans_sejour,
|
|
|
montant_facture_2_actes_inclus_dans_sejour,
|
|
|
montant_facture_22_actes_inclus_dans_sejour,
|
|
|
origine_facturation_id,
|
|
|
montant_comptabilise_budget_global_1,
|
|
|
facture_id)
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
date_debut,
|
|
|
date_fin,
|
|
|
nb_rubrique,
|
|
|
coefficient,
|
|
|
coefficient_mco,
|
|
|
rubrique_facturation_id,
|
|
|
prestation_id,
|
|
|
montant_facture,
|
|
|
montant_facture_0,
|
|
|
montant_facture_1,
|
|
|
montant_facture_2,
|
|
|
montant_facture_22,
|
|
|
taux_0,
|
|
|
taux_1,
|
|
|
taux_2,
|
|
|
taux_22,
|
|
|
finess,
|
|
|
prix_unitaire,
|
|
|
lieu_id,
|
|
|
nb_prestation,
|
|
|
montant_comptabilise,
|
|
|
montant_comptabilise_0,
|
|
|
montant_comptabilise_1,
|
|
|
montant_comptabilise_2,
|
|
|
montant_comptabilise_22,
|
|
|
rubrique_comptabilisation_id,
|
|
|
montant_encours,
|
|
|
montant_encours_0,
|
|
|
montant_encours_1,
|
|
|
montant_encours_2,
|
|
|
montant_encours_22,
|
|
|
montant_facture_actes_inclus_dans_sejour,
|
|
|
montant_facture_0_actes_inclus_dans_sejour,
|
|
|
montant_facture_1_actes_inclus_dans_sejour,
|
|
|
montant_facture_2_actes_inclus_dans_sejour,
|
|
|
montant_facture_22_actes_inclus_dans_sejour,
|
|
|
origine_facturation_id,
|
|
|
montant_comptabilise_budget_global_1,
|
|
|
facture_id
|
|
|
FROM w_factures_lignes_sup_c_sup;
|
|
|
|
|
|
|
|
|
|
|
|
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
|
|
|
JOIN activite[PX].t_lieux ON lieu_id = t_lieux.oid
|
|
|
JOIN activite[PX].t_services_facturation ON service_facturation_id = t_services_facturation.oid AND t_services_facturation.est_absence IS DISTINCT FROM '1'
|
|
|
WHERE p_factures.no_sejour = p_mouvements_sejour.no_sejour AND
|
|
|
p_factures_lignes_c.date_debut = p_mouvements_sejour.date AND
|
|
|
p_factures_lignes_c.no_facture = p_factures.no_facture 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;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></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_factures_lignes_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[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,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
0,
|
|
|
SUM(montant_regle),
|
|
|
SUM(montant_regle_0),
|
|
|
SUM(montant_regle_1),
|
|
|
SUM(montant_regle_2),
|
|
|
SUM(montant_regle_22)
|
|
|
FROM w_factures_lignes_c
|
|
|
WHERE date_vente IS NOT NULL AND
|
|
|
(montant_regle <> 0 OR
|
|
|
montant_regle_0 <> 0 OR
|
|
|
montant_regle_1 <> 0 OR
|
|
|
montant_regle_2 <> 0 OR
|
|
|
montant_regle_22 <> 0
|
|
|
)
|
|
|
GROUP BY 1,2,3,4;
|
|
|
|
|
|
|
|
|
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_soldes_c_2');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_soldes_c_3');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_soldes_c_4');
|
|
|
SELECT base.cti_enable_index('activite[PX]', 'i_factures_soldes_c_8');
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Lignes non facturées Honoraires">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Lignes factures Honoraires">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Compte client Honoraires">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="CHIFFRIER" label="CREATION DU CHIFFRIER">
|
|
|
|
|
|
<NODE label="Récupération chiffrier">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
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(DT_LANC) AS date_comptable,
|
|
|
SUM(TOTAL_DEPARTEMENT + TOTAL_DIVERS + TOTAL_MALADE + CASE WHEN HBG <> '1' THEN 0 ELSE TOTAL_SS END) AS montant_ventes_c,
|
|
|
SUM(REGLE_DEPARTEMENT + REGLE_DIVERS + REGLE_MALADE + CASE WHEN HBG <> '1' THEN 0 ELSE REGLE_SS END) AS montant_reglements_c,
|
|
|
SUM(TOTAL_DEPARTEMENT + TOTAL_DIVERS + TOTAL_MALADE + CASE WHEN HBG <> '1' THEN 0 ELSE TOTAL_SS END) -
|
|
|
SUM(REGLE_DEPARTEMENT + REGLE_DIVERS + REGLE_MALADE + CASE WHEN HBG <> '1' THEN 0 ELSE REGLE_SS END) AS montant_solde_client_c,
|
|
|
0::numeric AS montant_ventes_h,
|
|
|
0::numeric AS montant_reglements_h,
|
|
|
0::numeric AS montant_solde_client_h
|
|
|
FROM w_G_SP3 G_SP3
|
|
|
WHERE VALIDE = 1 AND
|
|
|
NUM_ENTREE IN (SELECT NUM_ADMINISTRATIF FROM prod_calystene.SEJOUR) AND
|
|
|
DT_LANC >= '20090101'
|
|
|
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
|
|
|
NUM_AVIS,
|
|
|
date(DT_LANC) AS date_comptable,
|
|
|
SUM(TOTAL_DEPARTEMENT + TOTAL_DIVERS + TOTAL_MALADE + CASE WHEN HBG <> '1' THEN 0 ELSE TOTAL_SS END) AS montant_ventes_c,
|
|
|
SUM(REGLE_DEPARTEMENT + REGLE_DIVERS + REGLE_MALADE + CASE WHEN HBG <> '1' THEN 0 ELSE REGLE_SS END) AS montant_reglements_c,
|
|
|
0::numeric AS montant_ventes_h,
|
|
|
0::numeric AS montant_reglements_h
|
|
|
FROM w_G_SP3 G_SP3
|
|
|
WHERE VALIDE = 1 AND
|
|
|
NUM_ENTREE IN (SELECT NUM_ADMINISTRATIF FROM prod_calystene.SEJOUR) AND
|
|
|
DT_LANC >= '20090101'
|
|
|
GROUP BY 1,2
|
|
|
ORDER BY 1,2;
|
|
|
|
|
|
]]></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 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 CODE_CAISSE, CODE_CAISSE, '1', INTITULE, INTITULE
|
|
|
FROM prod_calystene.CAISSE
|
|
|
WHERE CODE_CAISSE 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 NUM_MUTUELLE, to_char(NUM_MUTUELLE, 'FM0000'), '2', INTITULE, INTITULE
|
|
|
FROM prod_calystene.MUTUELLE
|
|
|
WHERE NUM_MUTUELLE 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 base.t_grands_regimes
|
|
|
WHERE type_tiers_payant = '1' AND
|
|
|
SUBSTR(t_tiers_payant.code,1,2) = t_grands_regimes.code AND
|
|
|
grand_regime_id IS DISTINCT FROM t_grands_regimes.oid AND
|
|
|
SUBSTR(t_tiers_payant.code,1,2) <> '00';
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Médecins">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
INSERT INTO base.t_specialites_medecin(oid, code, code_original, texte, texte_court)
|
|
|
SELECT 0, '', '0', 'Non saisie', 'Non saisie'
|
|
|
WHERE 0 NOT IN (SELECT oid FROM base.t_specialites_medecin);
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_specialites_medecin(oid, code, code_original, texte, texte_court)
|
|
|
SELECT 0, '', '0', 'Non saisie', 'Non saisie'
|
|
|
WHERE 0 NOT IN (SELECT oid FROM activite[PX].t_specialites_medecin);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO base.t_medecins(oid, nom, prenom, numero_ordre, specialite_id )
|
|
|
SELECT 0, 'Non renseigné', '', '', 0 WHERE 0 NOT IN (SELECT oid FROM base.t_medecins);
|
|
|
|
|
|
INSERT INTO activite[PX].t_medecins_administratifs(oid, code_original, code, nom, prenom, specialite_id, medecin_id)
|
|
|
SELECT 0, '0', '****', 'Non renseigné', '', 0, 0 WHERE 0 NOT IN (SELECT oid FROM activite[PX].t_medecins_administratifs);
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_medecins;
|
|
|
CREATE TEMP TABLE w_medecins AS
|
|
|
SELECT NUM AS NUM_ORIGINAL,
|
|
|
NUM,
|
|
|
base.cti_soundex_nom(PERSONNEL.NOM) AS NOM_SOUNDEX,
|
|
|
base.cti_soundex_nom(PERSONNEL.PRENOM) AS PRENOM_SOUNDEX,
|
|
|
PERSONNEL.NOM,
|
|
|
PERSONNEL.PRENOM,
|
|
|
COALESCE(CODE_PRESCRIPTEUR,'') AS CODE_PRESCRIPTEUR,
|
|
|
''::text AS SPECIALITE,
|
|
|
COALESCE(t_medecins_administratifs.medecin_id,0) as medecin_id
|
|
|
FROM prod_calystene.PERSONNEL
|
|
|
LEFT JOIN activite[PX].t_medecins_administratifs ON NUM = t_medecins_administratifs.code_original
|
|
|
WHERE NUM IN (SELECT NUM_MED_RESP FROM prod_calystene.SEJOUR GROUP BY 1);
|
|
|
|
|
|
UPDATE w_medecins SET NOM_SOUNDEX = NOM WHERE NOM_SOUNDEX = '';
|
|
|
|
|
|
|
|
|
INSERT INTO base.t_medecins(nom, prenom, numero_ordre, specialite_id)
|
|
|
SELECT w_medecins.NOM, w_medecins.PRENOM, w_medecins.CODE_PRESCRIPTEUR, 0 FROM
|
|
|
(SELECT SUBSTR(NOM_SOUNDEX, 1, 8) AS NOM_SOUNDEX,
|
|
|
SUBSTR(PRENOM_SOUNDEX, 1, 8) AS PRENOM_SOUNDEX,
|
|
|
CODE_PRESCRIPTEUR,
|
|
|
MIN(NUM_ORIGINAL) AS NUM_ORIGINAL
|
|
|
FROM w_medecins
|
|
|
GROUP BY 1,2,3) subview, w_medecins
|
|
|
WHERE w_medecins.NUM_ORIGINAL = subview.NUM_ORIGINAL
|
|
|
AND w_medecins.CODE_PRESCRIPTEUR <> ''
|
|
|
AND substr(subview.NOM_SOUNDEX,1,8) || ',' || substr(subview.PRENOM_SOUNDEX,1,8) || ',' || subview.CODE_PRESCRIPTEUR 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.NOM, w_medecins.PRENOM, w_medecins.CODE_PRESCRIPTEUR, 0 FROM
|
|
|
(SELECT NOM_SOUNDEX, PRENOM_SOUNDEX, MIN(NUM_ORIGINAL) AS MEDE_ID_MEDE
|
|
|
FROM w_medecins
|
|
|
GROUP BY 1,2) subview, w_medecins
|
|
|
WHERE w_medecins.NUM_ORIGINAL = subview.MEDE_ID_MEDE
|
|
|
AND subview.NOM_SOUNDEX || ',' || subview.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(NOM_SOUNDEX, 1, 8) = SUBSTR(subview.nom,1,8)
|
|
|
AND SUBSTR(PRENOM_SOUNDEX, 1, 8) = SUBSTR(subview.prenom,1,8)
|
|
|
AND CODE_PRESCRIPTEUR = subview.numero_ordre
|
|
|
AND CODE_PRESCRIPTEUR <> ''
|
|
|
AND w_medecins.medecin_id = 0;
|
|
|
|
|
|
UPDATE w_medecins SET medecin_id = subview.medecin_id
|
|
|
FROM
|
|
|
(SELECT base.cti_soundex_nom(nom) as nom , base.cti_soundex_nom(prenom) as prenom, MIN(oid) AS medecin_id FROM base.t_medecins GROUP BY 1,2) subview
|
|
|
WHERE NOM_SOUNDEX = subview.nom
|
|
|
AND PRENOM_SOUNDEX = subview.prenom
|
|
|
AND w_medecins.medecin_id = 0;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_medecins_administratifs(code_original, code, nom, prenom, specialite_id, medecin_id)
|
|
|
SELECT DISTINCT NUM_ORIGINAL, NUM, NOM, PRENOM, COALESCE(t_specialites_medecin.oid,0), medecin_id
|
|
|
FROM w_medecins
|
|
|
LEFT JOIN base.t_specialites_medecin ON (SPECIALITE = t_specialites_medecin.code_original)
|
|
|
WHERE NUM_ORIGINAL NOT IN (SELECT code_original FROM activite[PX].t_medecins_administratifs);
|
|
|
|
|
|
UPDATE activite[PX].t_medecins_administratifs
|
|
|
SET nom = w_medecins.NOM,
|
|
|
prenom = w_medecins.PRENOM,
|
|
|
specialite_id = COALESCE(t_specialites_medecin.oid,0),
|
|
|
medecin_id = w_medecins.medecin_id,
|
|
|
no_adeli = CODE_PRESCRIPTEUR
|
|
|
FROM w_medecins LEFT JOIN base.t_specialites_medecin ON (SPECIALITE = t_specialites_medecin.code_original)
|
|
|
WHERE w_medecins.NUM_ORIGINAL = t_medecins_administratifs.code_original
|
|
|
AND (
|
|
|
t_medecins_administratifs.nom <> w_medecins.NOM OR
|
|
|
t_medecins_administratifs.prenom <> w_medecins.PRENOM OR
|
|
|
t_medecins_administratifs.specialite_id <> COALESCE(t_specialites_medecin.oid,0) OR
|
|
|
t_medecins_administratifs.medecin_id <> w_medecins.medecin_id OR
|
|
|
t_medecins_administratifs.no_adeli <> <w_medecins.CODE_PRESCRIPTEUR
|
|
|
);
|
|
|
|
|
|
|
|
|
|
|
|
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
|
|
|
|
|
|
|
|
|
|
|
|
-- DMT
|
|
|
|
|
|
|
|
|
|
|
|
-- Services
|
|
|
|
|
|
INSERT INTO activite[PX].t_services_facturation(oid, code_original, code, texte, texte_court)
|
|
|
SELECT 0, 0, '****', 'Non renseigné', 'Non renseigné' WHERE 0 NOT IN (SELECt oid FROM activite[PX].t_services_facturation);
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_services_facturation(code_original, code, texte, texte_court, mode_traitement_id, type_t2a)
|
|
|
SELECT
|
|
|
UFR.CODE || '_CO',
|
|
|
UFR.CODE || '_CO',
|
|
|
NOM || ' - Consultations',
|
|
|
NOM || ' - Consult',
|
|
|
COALESCE(t_modes_traitement.oid,0),
|
|
|
'0'
|
|
|
FROM prod_calystene.UFR
|
|
|
JOIN prod_calystene.SEJOUR ON UFR.CODE = SEJOUR.CODE_UFR_ENT AND TYPE_HOSP_ENT ILIKE '%consultation%'
|
|
|
LEFT JOIN base.t_modes_traitement ON t_modes_traitement.code = '07'
|
|
|
WHERE
|
|
|
UFR.CODE || '_CO' NOT IN (SELECT code_original FROM activite[PX].t_services_facturation)
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_services_facturation(code_original, code, texte, texte_court, mode_traitement_id, type_t2a)
|
|
|
SELECT
|
|
|
UFR.CODE || '_HC',
|
|
|
UFR.CODE || '_HC',
|
|
|
NOM || ' - Hospitalisation complète',
|
|
|
NOM || ' - H.C.',
|
|
|
COALESCE(t_modes_traitement.oid,0),
|
|
|
'0'
|
|
|
FROM prod_calystene.UFR
|
|
|
JOIN prod_calystene.SEJOUR ON UFR.CODE = SEJOUR.CODE_UFR_ENT AND TYPE_HOSP_ENT ILIKE '%complete%'
|
|
|
LEFT JOIN base.t_modes_traitement ON t_modes_traitement.code = '03'
|
|
|
WHERE
|
|
|
UFR.CODE || '_HC' NOT IN (SELECT code_original FROM activite[PX].t_services_facturation)
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_services_facturation(code_original, code, texte, texte_court, mode_traitement_id, type_t2a)
|
|
|
SELECT
|
|
|
UFR.CODE || '_HS',
|
|
|
UFR.CODE || '_HS',
|
|
|
NOM || ' - Hospitalisation semaine',
|
|
|
NOM || ' - H.S.',
|
|
|
COALESCE(t_modes_traitement.oid,0),
|
|
|
'0'
|
|
|
FROM prod_calystene.UFR
|
|
|
JOIN prod_calystene.SEJOUR ON UFR.CODE = SEJOUR.CODE_UFR_ENT AND TYPE_HOSP_ENT ILIKE '%semaine%'
|
|
|
LEFT JOIN base.t_modes_traitement ON t_modes_traitement.code = '20'
|
|
|
WHERE
|
|
|
UFR.CODE || '_HS' NOT IN (SELECT code_original FROM activite[PX].t_services_facturation)
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_services_facturation(code_original, code, texte, texte_court, mode_traitement_id, type_t2a)
|
|
|
SELECT
|
|
|
UFR.CODE || '_HJ',
|
|
|
UFR.CODE || '_HJ',
|
|
|
NOM || ' - Hospitalisation de jour',
|
|
|
NOM || ' - H.J.',
|
|
|
COALESCE(t_modes_traitement.oid,0),
|
|
|
'0'
|
|
|
FROM prod_calystene.UFR
|
|
|
JOIN prod_calystene.SEJOUR ON UFR.CODE = SEJOUR.CODE_UFR_ENT AND TYPE_HOSP_ENT ILIKE '%jour%'
|
|
|
LEFT JOIN base.t_modes_traitement ON t_modes_traitement.code = '04'
|
|
|
WHERE
|
|
|
UFR.CODE || '_HJ' NOT IN (SELECT code_original FROM activite[PX].t_services_facturation)
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_services_facturation(code_original, code, texte, texte_court, mode_traitement_id, type_t2a)
|
|
|
SELECT
|
|
|
UFR.CODE || '_AM',
|
|
|
UFR.CODE || '_AM',
|
|
|
NOM || ' - Ambulatoire',
|
|
|
NOM || ' - Ambu',
|
|
|
COALESCE(t_modes_traitement.oid,0),
|
|
|
'0'
|
|
|
FROM prod_calystene.UFR
|
|
|
JOIN prod_calystene.SEJOUR ON UFR.CODE = SEJOUR.CODE_UFR_ENT AND TYPE_HOSP_ENT ILIKE '%ambulatoire%'
|
|
|
LEFT JOIN base.t_modes_traitement ON t_modes_traitement.code = '19'
|
|
|
WHERE
|
|
|
UFR.CODE || '_AM' NOT IN (SELECT code_original FROM activite[PX].t_services_facturation)
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_services_facturation(code_original, code, texte, texte_court, mode_traitement_id, type_t2a)
|
|
|
SELECT
|
|
|
UFR.CODE || '_CO',
|
|
|
UFR.CODE || '_CO',
|
|
|
NOM || ' - Consultations',
|
|
|
NOM || ' - Consult',
|
|
|
COALESCE(t_modes_traitement.oid,0),
|
|
|
'0'
|
|
|
FROM prod_calystene.UFR
|
|
|
JOIN prod_calystene.MUTATION ON UFR.CODE = MUTATION.CODE_UFR_DEST AND TYPE_HOSP_DEST ILIKE '%consultation%'
|
|
|
LEFT JOIN base.t_modes_traitement ON t_modes_traitement.code = '07'
|
|
|
WHERE
|
|
|
UFR.CODE || '_CO' NOT IN (SELECT code_original FROM activite[PX].t_services_facturation)
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_services_facturation(code_original, code, texte, texte_court, mode_traitement_id, type_t2a)
|
|
|
SELECT
|
|
|
UFR.CODE || '_HC',
|
|
|
UFR.CODE || '_HC',
|
|
|
NOM || ' - Hospitalisation complète',
|
|
|
NOM || ' - H.C.',
|
|
|
COALESCE(t_modes_traitement.oid,0),
|
|
|
'0'
|
|
|
FROM prod_calystene.UFR
|
|
|
JOIN prod_calystene.MUTATION ON UFR.CODE = MUTATION.CODE_UFR_DEST AND TYPE_HOSP_DEST ILIKE '%complete%'
|
|
|
LEFT JOIN base.t_modes_traitement ON t_modes_traitement.code = '03'
|
|
|
WHERE
|
|
|
UFR.CODE || '_HC' NOT IN (SELECT code_original FROM activite[PX].t_services_facturation)
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_services_facturation(code_original, code, texte, texte_court, mode_traitement_id, type_t2a)
|
|
|
SELECT
|
|
|
UFR.CODE || '_HS',
|
|
|
UFR.CODE || '_HS',
|
|
|
NOM || ' - Hospitalisation semaine',
|
|
|
NOM || ' - H.S.',
|
|
|
COALESCE(t_modes_traitement.oid,0),
|
|
|
'0'
|
|
|
FROM prod_calystene.UFR
|
|
|
JOIN prod_calystene.MUTATION ON UFR.CODE = MUTATION.CODE_UFR_DEST AND TYPE_HOSP_DEST ILIKE '%semaine%'
|
|
|
LEFT JOIN base.t_modes_traitement ON t_modes_traitement.code = '20'
|
|
|
WHERE
|
|
|
UFR.CODE || '_HS' NOT IN (SELECT code_original FROM activite[PX].t_services_facturation)
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_services_facturation(code_original, code, texte, texte_court, mode_traitement_id, type_t2a)
|
|
|
SELECT
|
|
|
UFR.CODE || '_HJ',
|
|
|
UFR.CODE || '_HJ',
|
|
|
NOM || ' - Hospitalisation de jour',
|
|
|
NOM || ' - H.J.',
|
|
|
COALESCE(t_modes_traitement.oid,0),
|
|
|
'0'
|
|
|
FROM prod_calystene.UFR
|
|
|
JOIN prod_calystene.MUTATION ON UFR.CODE = MUTATION.CODE_UFR_DEST AND TYPE_HOSP_DEST ILIKE '%jour%'
|
|
|
LEFT JOIN base.t_modes_traitement ON t_modes_traitement.code = '04'
|
|
|
WHERE
|
|
|
UFR.CODE || '_HJ' NOT IN (SELECT code_original FROM activite[PX].t_services_facturation)
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_services_facturation(code_original, code, texte, texte_court, mode_traitement_id, type_t2a)
|
|
|
SELECT
|
|
|
UFR.CODE || '_AM',
|
|
|
UFR.CODE || '_AM',
|
|
|
NOM || ' - Ambulatoire',
|
|
|
NOM || ' - Ambu',
|
|
|
COALESCE(t_modes_traitement.oid,0),
|
|
|
'0'
|
|
|
FROM prod_calystene.UFR
|
|
|
JOIN prod_calystene.MUTATION ON UFR.CODE = MUTATION.CODE_UFR_DEST AND TYPE_HOSP_DEST ILIKE '%ambulatoire%'
|
|
|
LEFT JOIN base.t_modes_traitement ON t_modes_traitement.code = '19'
|
|
|
WHERE
|
|
|
UFR.CODE || '_AM' NOT IN (SELECT code_original FROM activite[PX].t_services_facturation)
|
|
|
GROUP BY 1,2,3,4,5
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
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 fonctionnelles
|
|
|
|
|
|
INSERT INTO activite[PX].t_unites_fonctionnelles(oid, code_original, code, texte, texte_court)
|
|
|
SELECT 0, 0, '', 'Non renseignée', 'Non renseignée' WHERE 0 NOT IN (SELECt oid FROM activite[PX].t_unites_fonctionnelles);
|
|
|
|
|
|
INSERT INTO activite[PX].t_unites_fonctionnelles(code_original, code, texte, texte_court)
|
|
|
SELECT CODE, CODE, NOM, NOM
|
|
|
FROM prod_calystene.UFR
|
|
|
WHERE
|
|
|
CODE NOT IN (SELECT code_original FROM activite[PX].t_unites_fonctionnelles)
|
|
|
ORDER BY CODE;
|
|
|
|
|
|
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);
|
|
|
|
|
|
|
|
|
-- Unités médicales
|
|
|
|
|
|
INSERT INTO activite[PX].t_unites_medicales(oid, code_original, code, texte, texte_court)
|
|
|
SELECT 0, 0, '', 'Non renseignée', 'Non renseignée' WHERE 0 NOT IN (SELECt oid FROM activite[PX].t_unites_medicales);
|
|
|
|
|
|
INSERT INTO activite[PX].t_unites_medicales(code_original, code, texte, texte_court)
|
|
|
SELECT NUM, NUM, NOM, NOM
|
|
|
FROM prod_calystene.UNITE_MEDICALE
|
|
|
WHERE
|
|
|
NUM NOT IN (SELECT code_original FROM activite[PX].t_unites_medicales)
|
|
|
ORDER BY NUM;
|
|
|
|
|
|
|
|
|
-- Activités
|
|
|
|
|
|
INSERT INTO activite[PX].t_activites(oid, code_original, code, texte, texte_court)
|
|
|
SELECT 0, 0, '', 'Non renseignée', 'Non renseignée' WHERE 0 NOT IN (SELECt oid FROM activite[PX].t_activites);
|
|
|
|
|
|
|
|
|
|
|
|
-- Etages et lits
|
|
|
|
|
|
INSERT INTO activite[PX].t_etages(oid, code_original, code, texte, texte_court, nb_lits)
|
|
|
SELECT 0, 0, '', 'Non renseigné', 'Non renseigné', 0 WHERE 0 NOT IN (SELECT oid FROM activite[PX].t_etages);
|
|
|
|
|
|
INSERT INTO activite[PX].t_etages(code_original, code, texte, texte_court)
|
|
|
SELECT NOM, NOM, SERVICE, SERVICE
|
|
|
FROM prod_calystene.SOUS_UNITE
|
|
|
WHERE
|
|
|
NOM NOT IN (SELECT code_original FROM activite[PX].t_etages)
|
|
|
ORDER BY NOM;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_lits(code_original, code, texte, texte_court, etage_id, chambre_particuliere)
|
|
|
SELECT SOUS_UNITE || '|' || NUM_CH || '|' || NUM_LIT, NUM_CH || '-' || NUM_LIT, 'Ch ' || NUM_CH || ' - lit ' || NUM_LIT, NUM_CH || ' ' || NUM_LIT, t_etages.oid, 'N'
|
|
|
FROM prod_calystene.LIT
|
|
|
JOIN activite[PX].t_etages ON LIT.SOUS_UNITE = t_etages.code_original
|
|
|
WHERE SOUS_UNITE || '|' || NUM_CH || '|' || NUM_LIT NOT IN (SELECT code_original FROM activite[PX].t_lits );
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_lits(code_original, code, texte, texte_court, etage_id, chambre_particuliere)
|
|
|
SELECT SOUS_UNITE || '|' || NUM_CH, NUM_CH, 'Ch ' || NUM_CH, NUM_CH, t_etages.oid, 'N'
|
|
|
FROM prod_calystene.LIT
|
|
|
JOIN activite[PX].t_etages ON LIT.SOUS_UNITE = t_etages.code_original
|
|
|
WHERE SOUS_UNITE || '|' || NUM_CH NOT IN (SELECT code_original FROM activite[PX].t_lits )
|
|
|
GROUP BY 1,2,3,4,5;
|
|
|
|
|
|
|
|
|
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, 'N'
|
|
|
FROM activite[PX].t_etages
|
|
|
WHERE oid > 0 AND
|
|
|
code_original || '|0' NOT IN (SELECT code_original FROM activite[PX].t_lits );
|
|
|
|
|
|
UPDATE activite[PX].t_lits SET code = '*****' WHERE code = '';
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
<NODE label="Facturation">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
-- 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 'DIV', 'DIV', 'Divers', 'Divers'
|
|
|
WHERE 'DIV' 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_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 '*REGPAR', '*REGPAR', 'Règlement partiel', 'Règlement partiel'
|
|
|
WHERE '*REGPAR' NOT IN (SELECT code_original FROM activite[PX].t_rubriques_facturation);
|
|
|
|
|
|
|
|
|
SELECT CODE, CODE,
|
|
|
(MAX(ARRAY[COALESCE(DT_FIN_VALIDITE,'20991231')::text,LIBELLE]))[2],
|
|
|
(MAX(ARRAY[COALESCE(DT_FIN_VALIDITE,'20991231')::text,LIBELLE]))[2]
|
|
|
FROM prod_calystene.G_TH_FRAIS_SEJOUR
|
|
|
GROUP BY 1;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_rubriques_facturation(code_original, code, texte, texte_court)
|
|
|
SELECT CODE, CODE,
|
|
|
(MAX(ARRAY[COALESCE(DT_FIN_VALIDITE,'20991231')::text,LIBELLE]))[2],
|
|
|
(MAX(ARRAY[COALESCE(DT_FIN_VALIDITE,'20991231')::text,LIBELLE]))[2]
|
|
|
FROM prod_calystene.G_TH_FRAIS_SEJOUR
|
|
|
WHERE CODE NOT IN (SELECT code_original FROM activite[PX].t_rubriques_facturation)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
INSERT INTO activite[PX].t_rubriques_facturation(code_original, code, texte, texte_court)
|
|
|
SELECT CODE, CODE,
|
|
|
(MAX(ARRAY[COALESCE(DT_FIN_VALIDITE,'20991231')::text,LIBELLE]))[2],
|
|
|
(MAX(ARRAY[COALESCE(DT_FIN_VALIDITE,'20991231')::text,LIBELLE]))[2]
|
|
|
FROM prod_calystene.G_TH_PRESTATION
|
|
|
WHERE CODE NOT IN (SELECT code_original FROM activite[PX].t_rubriques_facturation)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
INSERT INTO activite.t_prestations(code_original, code, texte, texte_court)
|
|
|
SELECT 'DIV', 'DIV',
|
|
|
'Divers',
|
|
|
'Divers'
|
|
|
WHERE 'DIV' NOT IN (SELECT code FROM activite.t_prestations)
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO activite.t_prestations(code_original, code, texte, texte_court)
|
|
|
SELECT CODE, CODE,
|
|
|
(MAX(ARRAY[COALESCE(DT_FIN_VALIDITE,'20991231')::text,LIBELLE]))[2],
|
|
|
(MAX(ARRAY[COALESCE(DT_FIN_VALIDITE,'20991231')::text,LIBELLE]))[2]
|
|
|
FROM prod_calystene.G_TH_FRAIS_SEJOUR
|
|
|
WHERE CODE NOT IN (SELECT code FROM activite.t_prestations)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
INSERT INTO activite.t_prestations(code_original, code, texte, texte_court)
|
|
|
SELECT '*REGPAR', '*REGPAR',
|
|
|
'Règlement partiel',
|
|
|
'Règlement partiel'
|
|
|
WHERE '*REGPAR' NOT IN (SELECT code_original FROM activite.t_prestations)
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
INSERT INTO activite.t_prestations(code_original, code, texte, texte_court)
|
|
|
SELECT CODE, CODE,
|
|
|
(MAX(ARRAY[COALESCE(DT_FIN_VALIDITE,'20991231')::text,LIBELLE]))[2],
|
|
|
(MAX(ARRAY[COALESCE(DT_FIN_VALIDITE,'20991231')::text,LIBELLE]))[2]
|
|
|
FROM prod_calystene.G_TH_PRESTATION
|
|
|
WHERE CODE NOT IN (SELECT code FROM activite.t_prestations)
|
|
|
GROUP BY 1
|
|
|
ORDER BY 1;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
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);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
</NODE>
|
|
|
|
|
|
<NODE name="POST" label="TRAITEMENTS COMPLEMENTAIRES">
|
|
|
|
|
|
<NODE label="Compléments facture">
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures;
|
|
|
CREATE TEMP TABLE w_factures AS
|
|
|
SELECT
|
|
|
no_facture,
|
|
|
no_facture_reference,
|
|
|
CASE WHEN date_expedition_0 < date_facture AND date_facture <> '2099-12-31' THEN date_facture ELSE date_expedition_0 END AS date_expedition_0,
|
|
|
|
|
|
CASE WHEN montant_comptabilise_1_c = 0 THEN '00010101' WHEN montant_comptabilise_1_c = montant_regle_1_c THEN date_solde_1_c ELSE '20991231' END AS date_solde,
|
|
|
CASE WHEN montant_comptabilise_1_c = 0 THEN '00010101' WHEN montant_comptabilise_1_c = montant_regle_1_c THEN date_solde_1_c ELSE '20991231' END AS date_solde_c,
|
|
|
CASE WHEN montant_comptabilise_1_h = 0 THEN '00010101' WHEN montant_comptabilise_1_h = montant_regle_1_h THEN date_solde_1_h ELSE '20991231' END AS date_solde_h,
|
|
|
CASE WHEN montant_comptabilise_0_c = 0 THEN '00010101' WHEN montant_comptabilise_0_c = montant_regle_0_c THEN date_solde_0_c ELSE '20991231' END AS date_solde_0_c,
|
|
|
CASE WHEN montant_comptabilise_0_h = 0 THEN '00010101' WHEN montant_comptabilise_0_h = montant_regle_0_h THEN date_solde_0_h ELSE '20991231' END AS date_solde_0_h,
|
|
|
CASE WHEN montant_comptabilise_1_c = 0 THEN '00010101' WHEN montant_comptabilise_1_c = montant_regle_1_c THEN date_solde_1_c ELSE '20991231' END AS date_solde_1_c,
|
|
|
CASE WHEN montant_comptabilise_1_h = 0 THEN '00010101' WHEN montant_comptabilise_1_h = montant_regle_1_h THEN date_solde_1_h ELSE '20991231' END AS date_solde_1_h,
|
|
|
CASE WHEN montant_comptabilise_2_c = 0 THEN '00010101' WHEN montant_comptabilise_2_c = montant_regle_2_c THEN date_solde_2_c ELSE '20991231' END AS date_solde_2_c,
|
|
|
CASE WHEN montant_comptabilise_2_h = 0 THEN '00010101' WHEN montant_comptabilise_2_h = montant_regle_2_h THEN date_solde_2_h ELSE '20991231' END AS date_solde_2_h,
|
|
|
CASE WHEN montant_comptabilise_22_c = 0 THEN '00010101' WHEN montant_comptabilise_22_c = montant_regle_22_c THEN date_solde_22_c ELSE '20991231' END AS date_solde_22_c,
|
|
|
CASE WHEN montant_comptabilise_22_h = 0 THEN '00010101' WHEN montant_comptabilise_22_h = montant_regle_22_h THEN date_solde_22_h ELSE '20991231' END AS date_solde_22_h
|
|
|
FROM activite[PX].p_factures;
|
|
|
|
|
|
UPDATE w_factures SET
|
|
|
date_solde = GREATEST(date_solde_0_c, date_solde_0_h, date_solde_1_c, date_solde_1_h, date_solde_2_c, date_solde_2_h, date_solde_22_c, date_solde_22_h),
|
|
|
date_solde_c = GREATEST(date_solde_0_c, date_solde_1_c, date_solde_2_c, date_solde_22_c),
|
|
|
date_solde_h = GREATEST(date_solde_0_h, date_solde_1_h, date_solde_2_h, date_solde_22_h)
|
|
|
WHERE
|
|
|
date_solde IS DISTINCT FROM GREATEST(date_solde_0_c, date_solde_0_h, date_solde_1_c, date_solde_1_h, date_solde_2_c, date_solde_2_h, date_solde_22_c, date_solde_22_h) OR
|
|
|
date_solde_c IS DISTINCT FROM GREATEST(date_solde_0_c, date_solde_1_c, date_solde_2_c, date_solde_22_c) OR
|
|
|
date_solde_h IS DISTINCT FROM GREATEST(date_solde_0_h, date_solde_1_h, date_solde_2_h, date_solde_22_h) ;
|
|
|
|
|
|
CREATE INDEX w_factures_i1
|
|
|
ON w_factures
|
|
|
USING btree
|
|
|
(no_facture);
|
|
|
|
|
|
CREATE INDEX w_factures_i2
|
|
|
ON w_factures
|
|
|
USING btree
|
|
|
(no_facture_reference);
|
|
|
|
|
|
|
|
|
|
|
|
DROP TABLE IF EXISTS w_factures_references_soldes;
|
|
|
|
|
|
CREATE TEMP TABLE w_factures_references_soldes AS
|
|
|
SELECT
|
|
|
no_facture_reference,
|
|
|
MAX(date_solde) AS date_solde_reference,
|
|
|
MAX(date_solde_c) AS date_solde_reference_c,
|
|
|
MAX(date_solde_h) AS date_solde_reference_h,
|
|
|
MAX(date_solde_0_c) AS date_solde_reference_0_c,
|
|
|
MAX(date_solde_0_h) AS date_solde_reference_0_h,
|
|
|
MAX(date_solde_1_c) AS date_solde_reference_1_c,
|
|
|
MAX(date_solde_1_h) AS date_solde_reference_1_h,
|
|
|
MAX(date_solde_2_c) AS date_solde_reference_2_c,
|
|
|
MAX(date_solde_2_h) AS date_solde_reference_2_h,
|
|
|
MAX(date_solde_22_c) AS date_solde_reference_22_c,
|
|
|
MAX(date_solde_22_h) AS date_solde_reference_22_h
|
|
|
FROM w_factures
|
|
|
GROUP BY no_facture_reference;
|
|
|
|
|
|
|
|
|
CREATE INDEX w_factures_references_soldes_i1
|
|
|
ON w_factures_references_soldes
|
|
|
USING btree
|
|
|
(no_facture_reference);
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
UPDATE activite[PX].p_factures
|
|
|
SET
|
|
|
date_expedition_0 = w_factures.date_expedition_0,
|
|
|
date_solde = w_factures.date_solde,
|
|
|
date_solde_c = w_factures.date_solde_c,
|
|
|
date_solde_h = w_factures.date_solde_h,
|
|
|
date_solde_0_c = w_factures.date_solde_0_c,
|
|
|
date_solde_0_h = w_factures.date_solde_0_h,
|
|
|
date_solde_1_c = w_factures.date_solde_1_c,
|
|
|
date_solde_1_h = w_factures.date_solde_1_h,
|
|
|
date_solde_2_c = w_factures.date_solde_2_c,
|
|
|
date_solde_2_h = w_factures.date_solde_2_h,
|
|
|
date_solde_22_c = w_factures.date_solde_22_c,
|
|
|
date_solde_22_h = w_factures.date_solde_22_h,
|
|
|
date_solde_reference = w_factures_references_soldes.date_solde_reference,
|
|
|
date_solde_reference_c = w_factures_references_soldes.date_solde_reference_c,
|
|
|
date_solde_reference_h = w_factures_references_soldes.date_solde_reference_h,
|
|
|
date_solde_reference_0_c = w_factures_references_soldes.date_solde_reference_0_c,
|
|
|
date_solde_reference_0_h = w_factures_references_soldes.date_solde_reference_0_h,
|
|
|
date_solde_reference_1_c = w_factures_references_soldes.date_solde_reference_1_c,
|
|
|
date_solde_reference_1_h = w_factures_references_soldes.date_solde_reference_1_h,
|
|
|
date_solde_reference_2_c = w_factures_references_soldes.date_solde_reference_2_c,
|
|
|
date_solde_reference_2_h = w_factures_references_soldes.date_solde_reference_2_h,
|
|
|
date_solde_reference_22_c = w_factures_references_soldes.date_solde_reference_22_c,
|
|
|
date_solde_reference_22_h = w_factures_references_soldes.date_solde_reference_22_h
|
|
|
FROM w_factures
|
|
|
JOIN w_factures_references_soldes ON w_factures_references_soldes.no_facture_reference = w_factures.no_facture_reference
|
|
|
WHERE p_factures.no_facture = w_factures.no_facture
|
|
|
AND (
|
|
|
p_factures.date_expedition_0 IS DISTINCT FROM w_factures.date_expedition_0 OR
|
|
|
p_factures.date_solde IS DISTINCT FROM w_factures.date_solde OR
|
|
|
p_factures.date_solde_c IS DISTINCT FROM w_factures.date_solde_c OR
|
|
|
p_factures.date_solde_h IS DISTINCT FROM w_factures.date_solde_h OR
|
|
|
p_factures.date_solde_0_c IS DISTINCT FROM w_factures.date_solde_0_c OR
|
|
|
p_factures.date_solde_0_h IS DISTINCT FROM w_factures.date_solde_0_h OR
|
|
|
p_factures.date_solde_1_c IS DISTINCT FROM w_factures.date_solde_1_c OR
|
|
|
p_factures.date_solde_1_h IS DISTINCT FROM w_factures.date_solde_1_h OR
|
|
|
p_factures.date_solde_2_c IS DISTINCT FROM w_factures.date_solde_2_c OR
|
|
|
p_factures.date_solde_2_h IS DISTINCT FROM w_factures.date_solde_2_h OR
|
|
|
p_factures.date_solde_22_c IS DISTINCT FROM w_factures.date_solde_22_c OR
|
|
|
p_factures.date_solde_22_h IS DISTINCT FROM w_factures.date_solde_22_h OR
|
|
|
p_factures.date_solde_reference IS DISTINCT FROM w_factures_references_soldes.date_solde_reference OR
|
|
|
p_factures.date_solde_reference_c IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_c OR
|
|
|
p_factures.date_solde_reference_h IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_h OR
|
|
|
p_factures.date_solde_reference_0_c IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_0_c OR
|
|
|
p_factures.date_solde_reference_0_h IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_0_h OR
|
|
|
p_factures.date_solde_reference_1_c IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_1_c OR
|
|
|
p_factures.date_solde_reference_1_h IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_1_h OR
|
|
|
p_factures.date_solde_reference_2_c IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_2_c OR
|
|
|
p_factures.date_solde_reference_2_h IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_2_h OR
|
|
|
p_factures.date_solde_reference_22_c IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_22_c OR
|
|
|
p_factures.date_solde_reference_22_h IS DISTINCT FROM w_factures_references_soldes.date_solde_reference_22_h
|
|
|
);
|
|
|
|
|
|
|
|
|
]]></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 = CASE WHEN code_sorti = '1' AND date_groupage > date_sortie AND date_groupage < '2099-12-31' AND ghs_id <> 0
|
|
|
THEN date_groupage - date_sortie ELSE 0 END,
|
|
|
delai_facture = CASE WHEN code_sorti = '1' AND date_facture > date_sortie AND date_facture < '2099-12-31' AND date_facture > date_sortie
|
|
|
THEN date_facture - date_sortie ELSE 0 END,
|
|
|
delai_expedition = CASE WHEN code_sorti = '1' AND date_expedition > date_sortie AND date_facture < '2099-12-31' AND date_expedition < '2099-12-31'
|
|
|
THEN date_expedition - date_sortie ELSE 0 END,
|
|
|
delai_solde = CASE WHEN code_sorti = '1' AND date_solde > date_sortie AND date_facture < '2099-12-31' AND date_solde < '2099-12-31'
|
|
|
THEN date_solde - date_sortie ELSE 0 END,
|
|
|
delai_expedition_0 = CASE WHEN code_sorti = '1' AND date_expedition_0 > date_sortie AND date_facture < '2099-12-31' AND date_expedition_0 < '2099-12-31'
|
|
|
THEN date_expedition_0 - date_sortie ELSE 0 END,
|
|
|
delai_solde_0 = CASE WHEN code_sorti = '1'AND date_solde_0 > date_sortie AND date_facture < '2099-12-31' AND date_solde_0 < '2099-12-31'
|
|
|
THEN date_solde_0 - date_sortie ELSE 0 END,
|
|
|
delai_expedition_1 = CASE WHEN code_sorti = '1' AND date_expedition_1 > date_sortie AND date_facture < '2099-12-31' AND date_expedition_1 < '2099-12-31'
|
|
|
THEN date_expedition_1 - date_sortie ELSE 0 END,
|
|
|
delai_solde_1 = CASE WHEN code_sorti = '1' AND date_solde_1 > date_sortie AND date_facture < '2099-12-31' AND date_solde_1 < '2099-12-31'
|
|
|
THEN date_solde_1 - date_sortie ELSE 0 END,
|
|
|
delai_expedition_2 = CASE WHEN code_sorti = '1' AND date_expedition_2 > date_sortie AND date_facture < '2099-12-31' AND date_expedition_2 < '2099-12-31'
|
|
|
THEN date_expedition_2 - date_sortie ELSE 0 END,
|
|
|
delai_solde_2 = CASE WHEN code_sorti = '1' AND date_solde_2 > date_sortie AND date_facture < '2099-12-31' AND date_solde_2 < '2099-12-31'
|
|
|
THEN date_solde_2 - date_sortie ELSE 0 END,
|
|
|
delai_expedition_22 = CASE WHEN code_sorti = '1' AND date_expedition_22 > date_sortie AND date_facture < '2099-12-31' AND date_expedition_22 < '2099-12-31'
|
|
|
THEN date_expedition_22 - date_sortie ELSE 0 END,
|
|
|
delai_solde_22 = CASE WHEN code_sorti = '1' AND date_solde_22 > date_sortie AND date_facture < '2099-12-31' AND date_solde_22 < '2099-12-31'
|
|
|
THEN date_solde_22 - date_sortie ELSE 0 END;
|
|
|
|
|
|
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
|
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
<NODE label="Tables répliquées">
|
|
|
|
|
|
<condition><![CDATA[
|
|
|
"[PX]" == ""
|
|
|
]]></condition>
|
|
|
|
|
|
<sqlcmd><![CDATA[
|
|
|
|
|
|
|
|
|
|
|
|
]]></sqlcmd>
|
|
|
</NODE>
|
|
|
</NODE>
|
|
|
|
|
|
|
|
|
|
|
|
</ROOT>
|