return: text lang: plpgsql src: | DECLARE _module_pmsimco TEXT; result TEXT; BEGIN IF EXISTS (SELECT * FROM pg_tables WHERE schemaname = 'pmsi' AND tablename = 't_lpp') THEN _module_pmsimco = '1'; ELSE _module_pmsimco = '0'; END IF; -- NOuvelle table dans base pour retro comptabilite IF NOT EXISTS ( SELECT table_name FROM information_schema.tables WHERE table_schema || '.' || table_name = 'base.t_classification_atc' ) THEN CREATE TABLE base.t_classification_atc ( classification_atc_1_code text DEFAULT ''::text, classification_atc_1_id bigint DEFAULT 0, classification_atc_1_texte text DEFAULT ''::text, classification_atc_2_code text DEFAULT ''::text, classification_atc_2_id bigint DEFAULT 0, classification_atc_2_texte text DEFAULT ''::text, classification_atc_3_code text DEFAULT ''::text, classification_atc_3_id bigint DEFAULT 0, classification_atc_3_texte text DEFAULT ''::text, classification_atc_4_code text DEFAULT ''::text, classification_atc_4_id bigint DEFAULT 0, classification_atc_4_texte text DEFAULT ''::text, code text DEFAULT ''::text, code_original text NOT NULL, est_atc text DEFAULT ''::text, est_cladimed text DEFAULT ''::text, oid bigint NOT NULL DEFAULT nextval('base.s_classification_atc'::regclass), section_code character varying(10)[], section_id bigint[], section_texte text[], texte text, texte_court text, CONSTRAINT t_classification_atc_pkey PRIMARY KEY (oid), CONSTRAINT t_classification_atc_ukey UNIQUE (code_original) ) WITH ( OIDS=FALSE ) ; INSERT INTO base.t_classification_atc( oid, code_original, code, texte, texte_court, classification_atc_1_code, classification_atc_1_id, classification_atc_1_texte, classification_atc_2_code, classification_atc_2_id, classification_atc_2_texte, classification_atc_3_code, classification_atc_3_id, classification_atc_3_texte, classification_atc_4_code, classification_atc_4_id, classification_atc_4_texte, est_atc, est_cladimed) SELECT 0::bigint AS oid, '*' AS code_original, chr(127) || '*********' AS code, 'Non renseignée' AS texte, 'Non renseignée' AS texte_court, chr(127) || '*********' AS classification_atc_1_code, 0::bigint AS classification_atc_1_id, 'Non renseignée' AS classification_atc_1_texte, chr(127) || '*********' AS classification_atc_2_code, 0::bigint AS classification_atc_2_id, 'Non renseignée' AS classification_atc_2_texte, chr(127) || '*********' AS classification_atc_3_code, 0::bigint AS classification_atc_3_id, 'Non renseignée' AS classification_atc_3_texte, chr(127) || '*********' AS classification_atc_4_code, 0::bigint AS classification_atc_4_id, 'Non renseignée' AS classification_atc_4_texte, '0' AS est_atc, '0' AS est_cladimed WHERE 0 NOT IN (SELECT oid FROM base.t_classification_atc) ; END IF; -- Nouvelle colonne dans base (retro comptabililité) IF NOT EXISTS ( SELECT column_name FROM information_schema.columns WHERE table_schema || '.' || table_name = 'base.t_ucd' AND column_name = 'classification_atc_id') THEN ALTER TABLE base.t_ucd ADD COLUMN classification_atc_id bigint default 0; END IF; -- Si module pmsi, ajout des ucd pmsi IF _module_pmsimco = '1' THEN INSERT INTO base.t_ucd (code, texte, texte_court, atc_code) SELECT code, texte, texte_court, atc_code FROM pmsi.t_ucd WHERE oid <> 0 AND code NOT IN (SELECT code FROM base.t_ucd WHERE code IS NOT NULL) ; UPDATE base.t_ucd SET atc_code = t_ucd_pmsi.atc_code FROM pmsi.t_ucd t_ucd_pmsi WHERE t_ucd.code = t_ucd_pmsi.code AND t_ucd.atc_code IS DISTINCT FROM t_ucd_pmsi.atc_code ; END IF; INSERT INTO base.t_ucd(oid, code, texte, texte_court) SELECT 0, chr(127) || '*******', chr(127) || 'Non renseigné', chr(127) || 'Non renseigné' WHERE 0 NOT IN (SELECT oid FROM base.t_ucd); UPDATE base.t_ucd SET texte_court = texte WHERE COALESCE(texte_court,'') = ''; -- Initialisation arborescence ATC INSERT INTO base.t_classification_atc (code, code_original, texte, texte_court) SELECT atc_code, MAX(atc_code), MAX(atc_texte), MAX(atc_texte) FROm base.t_ucd WHERE atc_code <> '' AND length(atc_code) = 7 AND atc_code NOT IN (SELECT code FROM base.t_classification_atc WHERE code IS NOT NULL) GROUP BY 1 ; INSERT INTO base.t_classification_atc (code, code_original, texte, texte_court) SELECT substr(code,1,5), MAX(substr(code,1,5)), MAX(substr(code,1,5)), MAX(substr(code,1,5)) FROM base.t_classification_atc WHERE length(code) = 7 AND substr(code,1,5) NOT IN (SELECT code FROM base.t_classification_atc WHERE code IS NOT NULL) GROUP BY 1 ; INSERT INTO base.t_classification_atc (code, code_original, texte, texte_court) SELECT substr(code,1,4), MAX(substr(code,1,4)), MAX(substr(code,1,4)), MAX(substr(code,1,4)) FROM base.t_classification_atc WHERE length(code) = 7 AND substr(code,1,4) NOT IN (SELECT code FROM base.t_classification_atc WHERE code IS NOT NULL) GROUP BY 1 ; INSERT INTO base.t_classification_atc (code, code_original, texte, texte_court) SELECT substr(code,1,3), MAX(substr(code,1,3)), MAX(substr(code,1,3)), MAX(substr(code,1,3)) FROM base.t_classification_atc WHERE length(code) = 7 AND substr(code,1,3) NOT IN (SELECT code FROM base.t_classification_atc WHERE code IS NOT NULL) GROUP BY 1 ; INSERT INTO base.t_classification_atc (code, code_original, texte, texte_court) SELECT substr(code,1,2), MAX(substr(code,1,2)), MAX(substr(code,1,2)), MAX(substr(code,1,2)) FROM base.t_classification_atc WHERE length(code) = 7 AND substr(code,1,2) NOT IN (SELECT code FROM base.t_classification_atc WHERE code IS NOT NULL) GROUP BY 1 ; -- Standard ATC INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || '99XX99', code_original || '99XX99', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 1 AND code_original || '99XX99' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || '99', code_original || '99', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 1 AND code_original || '99' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || '99X', code_original || '99X', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 1 AND code_original || '99X' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || '99XX', code_original || '99XX', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 1 AND code_original || '99XX' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || 'XX99', code_original || 'XX99', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 3 AND substr(code,2,1) BETWEEN '0' AND '9' AND substr(code,1,1) IN (SELECT code FROM base.t_classification_atc) AND code_original || 'XX99' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || 'XX', code_original || 'XX', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 3 AND substr(code,2,1) BETWEEN '0' AND '9' AND substr(code,1,1) IN (SELECT code FROM base.t_classification_atc) AND code_original || 'XX' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || 'X', code_original || 'X', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 3 AND substr(code,2,1) BETWEEN '0' AND '9' AND substr(code,1,1) IN (SELECT code FROM base.t_classification_atc) AND code_original || 'X' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || 'X99', code_original || 'X99', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 4 AND substr(code,2,1) BETWEEN '0' AND '9' AND substr(code,1,3) IN (SELECT code FROM base.t_classification_atc) AND code_original || 'X99' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || 'X', code_original || 'X', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 4 AND substr(code,2,1) BETWEEN '0' AND '9' AND substr(code,1,3) IN (SELECT code FROM base.t_classification_atc) AND code_original || 'X' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || '99', code_original || '99', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 5 AND substr(code,2,1) BETWEEN '0' AND '9' AND substr(code,1,4) IN (SELECT code FROM base.t_classification_atc) AND code_original || '99' NOT IN (SELECT code FROM base.t_classification_atc); -- Spécial préfixe à deux caractères INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || '99XX99', code_original || '99XX99', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 2 AND substr(code,2,1) NOT BETWEEN '0' AND '9' AND code_original || '99XX99' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || '99', code_original || '99', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 2 AND substr(code,2,1) NOT BETWEEN '0' AND '9' AND code_original || '99' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || '99X', code_original || '99X', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 2 AND substr(code,2,1) NOT BETWEEN '0' AND '9' AND code_original || '99X' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || '99XX', code_original || '99XX', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 2 AND substr(code,2,1) NOT BETWEEN '0' AND '9' AND code_original || '99XX' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || 'XX99', code_original || 'XX99', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 4 AND substr(code,2,1) NOT BETWEEN '0' AND '9' AND substr(code,1,2) IN (SELECT code FROM base.t_classification_atc) AND code_original || 'XX99' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || 'XX', code_original || 'XX', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 4 AND substr(code,2,1) NOT BETWEEN '0' AND '9' AND substr(code,1,2) IN (SELECT code FROM base.t_classification_atc) AND code_original || 'XX' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || 'X', code_original || 'X', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 4 AND substr(code,2,1) NOT BETWEEN '0' AND '9' AND substr(code,1,2) IN (SELECT code FROM base.t_classification_atc) AND code_original || 'X' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || 'X99', code_original || 'X99', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 5 AND substr(code,2,1) NOT BETWEEN '0' AND '9' AND substr(code,1,4) IN (SELECT code FROM base.t_classification_atc) AND code_original || 'X99' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || 'X', code_original || 'X', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 5 AND substr(code,2,1) NOT BETWEEN '0' AND '9' AND substr(code,1,4) IN (SELECT code FROM base.t_classification_atc) AND code_original || 'X' NOT IN (SELECT code FROM base.t_classification_atc); INSERT INTO base.t_classification_atc(code_original, code, texte, texte_court ) SELECT code_original || '99', code_original || '99', texte || ' (NON PRECISE)', texte_court || ' (NON PRECISE)' FROM base.t_classification_atc WHERE oid <> 0 AND length(code) = 6 AND substr(code,2,1) NOT BETWEEN '0' AND '9' AND substr(code,1,5) IN (SELECT code FROM base.t_classification_atc) AND code_original || '99' NOT IN (SELECT code FROM base.t_classification_atc); -- compléments UPDATE base.t_classification_atc SET texte = trim(replace(texte,'(NON PRECISE)','')), texte_court = trim(replace(texte,'(NON PRECISE)','')) WHERE code like 'Z%' AND texte like '%(NON PRECISE)%'; UPDATE base.t_classification_atc SET classification_atc_1_id = t_classification_atc_1.oid, classification_atc_1_code = t_classification_atc_1.code, classification_atc_1_texte = t_classification_atc_1.texte FROM base.t_classification_atc t_classification_atc_1 WHERE t_classification_atc.oid <> 0 AND substr(t_classification_atc.code,1,1) = t_classification_atc_1.code AND substr(t_classification_atc.code,2,1) BETWEEN '0' AND '9' AND ( t_classification_atc.classification_atc_1_id IS DISTINCT FROM t_classification_atc_1.oid OR t_classification_atc.classification_atc_1_code IS DISTINCT FROM t_classification_atc_1.code OR t_classification_atc.classification_atc_1_texte IS DISTINCT FROM t_classification_atc_1.texte ); UPDATE base.t_classification_atc SET classification_atc_1_id = t_classification_atc_1.oid, classification_atc_1_code = t_classification_atc_1.code, classification_atc_1_texte = t_classification_atc_1.texte FROM base.t_classification_atc t_classification_atc_1 WHERE t_classification_atc.oid <> 0 AND substr(t_classification_atc.code,1,2) = t_classification_atc_1.code AND substr(t_classification_atc.code,2,1) NOT BETWEEN '0' AND '9' AND ( t_classification_atc.classification_atc_1_id IS DISTINCT FROM t_classification_atc_1.oid OR t_classification_atc.classification_atc_1_code IS DISTINCT FROM t_classification_atc_1.code OR t_classification_atc.classification_atc_1_texte IS DISTINCT FROM t_classification_atc_1.texte ); UPDATE base.t_classification_atc SET classification_atc_1_id = t_classification_atc_1.oid, classification_atc_1_code = t_classification_atc_1.code, classification_atc_1_texte = t_classification_atc_1.texte FROM base.t_classification_atc t_classification_atc_1 WHERE t_classification_atc.oid <> 0 AND t_classification_atc_1.code = 'X' AND COALESCE(t_classification_atc.classification_atc_1_id,0) = 0 AND ( t_classification_atc.classification_atc_1_id IS DISTINCT FROM t_classification_atc_1.oid OR t_classification_atc.classification_atc_1_code IS DISTINCT FROM t_classification_atc_1.code OR t_classification_atc.classification_atc_1_texte IS DISTINCT FROM t_classification_atc_1.texte ); UPDATE base.t_classification_atc SET classification_atc_1_code = t_classification_atc_1.code, classification_atc_1_texte = t_classification_atc_1.texte FROM base.t_classification_atc t_classification_atc_1 WHERE t_classification_atc.classification_atc_1_id = t_classification_atc_1.oid AND ( t_classification_atc.classification_atc_1_code IS DISTINCT FROM t_classification_atc_1.code OR t_classification_atc.classification_atc_1_texte IS DISTINCT FROM t_classification_atc_1.texte ); UPDATE base.t_classification_atc SET classification_atc_2_id = t_classification_atc_1.oid, classification_atc_2_code = t_classification_atc_1.code, classification_atc_2_texte = t_classification_atc_1.texte FROM base.t_classification_atc t_classification_atc_1 WHERE t_classification_atc.oid <> 0 AND substr(t_classification_atc.code,1,3) = t_classification_atc_1.code AND substr(t_classification_atc.code,2,1) BETWEEN '0' AND '9' AND length(t_classification_atc.code) >= 3 AND ( t_classification_atc.classification_atc_2_id IS DISTINCT FROM t_classification_atc_1.oid OR t_classification_atc.classification_atc_2_code IS DISTINCT FROM t_classification_atc_1.code OR t_classification_atc.classification_atc_2_texte IS DISTINCT FROM t_classification_atc_1.texte ); UPDATE base.t_classification_atc SET classification_atc_2_id = t_classification_atc_1.oid, classification_atc_2_code = t_classification_atc_1.code, classification_atc_2_texte = t_classification_atc_1.texte FROM base.t_classification_atc t_classification_atc_1 WHERE t_classification_atc.oid <> 0 AND substr(t_classification_atc.code,1,4) = t_classification_atc_1.code AND substr(t_classification_atc.code,2,1) NOT BETWEEN '0' AND '9' AND length(t_classification_atc.code) >= 4 AND ( t_classification_atc.classification_atc_2_id IS DISTINCT FROM t_classification_atc_1.oid OR t_classification_atc.classification_atc_2_code IS DISTINCT FROM t_classification_atc_1.code OR t_classification_atc.classification_atc_2_texte IS DISTINCT FROM t_classification_atc_1.texte ); UPDATE base.t_classification_atc SET classification_atc_2_id = t_classification_atc_1.oid, classification_atc_2_code = t_classification_atc_1.code, classification_atc_2_texte = t_classification_atc_1.texte FROM base.t_classification_atc t_classification_atc_1 WHERE t_classification_atc.oid <> 0 AND t_classification_atc_1.code = t_classification_atc.classification_atc_1_code || '99' AND COALESCE(t_classification_atc.classification_atc_2_id,0) = 0 AND ( t_classification_atc.classification_atc_2_id IS DISTINCT FROM t_classification_atc_1.oid OR t_classification_atc.classification_atc_2_code IS DISTINCT FROM t_classification_atc_1.code OR t_classification_atc.classification_atc_2_texte IS DISTINCT FROM t_classification_atc_1.texte ); UPDATE base.t_classification_atc SET classification_atc_2_code = t_classification_atc_1.code, classification_atc_2_texte = t_classification_atc_1.texte FROM base.t_classification_atc t_classification_atc_1 WHERE t_classification_atc.classification_atc_2_id = t_classification_atc_1.oid AND ( t_classification_atc.classification_atc_2_code IS DISTINCT FROM t_classification_atc_1.code OR t_classification_atc.classification_atc_2_texte IS DISTINCT FROM t_classification_atc_1.texte ); UPDATE base.t_classification_atc SET classification_atc_3_id = t_classification_atc_1.oid, classification_atc_3_code = t_classification_atc_1.code, classification_atc_3_texte = t_classification_atc_1.texte FROM base.t_classification_atc t_classification_atc_1 WHERE t_classification_atc.oid <> 0 AND substr(t_classification_atc.code,1,4) = t_classification_atc_1.code AND substr(t_classification_atc.code,2,1) BETWEEN '0' AND '9' AND length(t_classification_atc.code) >= 4 AND ( t_classification_atc.classification_atc_3_id IS DISTINCT FROM t_classification_atc_1.oid OR t_classification_atc.classification_atc_3_code IS DISTINCT FROM t_classification_atc_1.code OR t_classification_atc.classification_atc_3_texte IS DISTINCT FROM t_classification_atc_1.texte ); UPDATE base.t_classification_atc SET classification_atc_3_id = t_classification_atc_1.oid, classification_atc_3_code = t_classification_atc_1.code, classification_atc_3_texte = t_classification_atc_1.texte FROM base.t_classification_atc t_classification_atc_1 WHERE t_classification_atc.oid <> 0 AND substr(t_classification_atc.code,1,5) = t_classification_atc_1.code AND substr(t_classification_atc.code,2,1) NOT BETWEEN '0' AND '9' AND length(t_classification_atc.code) >= 5 AND ( t_classification_atc.classification_atc_3_id IS DISTINCT FROM t_classification_atc_1.oid OR t_classification_atc.classification_atc_3_code IS DISTINCT FROM t_classification_atc_1.code OR t_classification_atc.classification_atc_3_texte IS DISTINCT FROM t_classification_atc_1.texte ); UPDATE base.t_classification_atc SET classification_atc_3_id = t_classification_atc_1.oid, classification_atc_3_code = t_classification_atc_1.code, classification_atc_3_texte = t_classification_atc_1.texte FROM base.t_classification_atc t_classification_atc_1 WHERE t_classification_atc.oid <> 0 AND t_classification_atc_1.code = t_classification_atc.classification_atc_2_code || 'X' AND COALESCE(t_classification_atc.classification_atc_3_id,0) = 0 AND ( t_classification_atc.classification_atc_3_id IS DISTINCT FROM t_classification_atc_1.oid OR t_classification_atc.classification_atc_3_code IS DISTINCT FROM t_classification_atc_1.code OR t_classification_atc.classification_atc_3_texte IS DISTINCT FROM t_classification_atc_1.texte ); UPDATE base.t_classification_atc SET classification_atc_3_code = t_classification_atc_1.code, classification_atc_3_texte = t_classification_atc_1.texte FROM base.t_classification_atc t_classification_atc_1 WHERE t_classification_atc.classification_atc_3_id = t_classification_atc_1.oid AND ( t_classification_atc.classification_atc_3_code IS DISTINCT FROM t_classification_atc_1.code OR t_classification_atc.classification_atc_3_texte IS DISTINCT FROM t_classification_atc_1.texte ); UPDATE base.t_classification_atc SET classification_atc_4_id = t_classification_atc_1.oid, classification_atc_4_code = t_classification_atc_1.code, classification_atc_4_texte = t_classification_atc_1.texte FROM base.t_classification_atc t_classification_atc_1 WHERE t_classification_atc.oid <> 0 AND substr(t_classification_atc.code,2,1) BETWEEN '0' AND '9' AND substr(t_classification_atc.code,1,5) = t_classification_atc_1.code AND length(t_classification_atc.code) >= 5 AND ( t_classification_atc.classification_atc_4_id IS DISTINCT FROM t_classification_atc_1.oid OR t_classification_atc.classification_atc_4_code IS DISTINCT FROM t_classification_atc_1.code OR t_classification_atc.classification_atc_4_texte IS DISTINCT FROM t_classification_atc_1.texte ); UPDATE base.t_classification_atc SET classification_atc_4_id = t_classification_atc_1.oid, classification_atc_4_code = t_classification_atc_1.code, classification_atc_4_texte = t_classification_atc_1.texte FROM base.t_classification_atc t_classification_atc_1 WHERE t_classification_atc.oid <> 0 AND substr(t_classification_atc.code,2,1) NOT BETWEEN '0' AND '9' AND substr(t_classification_atc.code,1,6) = t_classification_atc_1.code AND length(t_classification_atc.code) >= 6 AND ( t_classification_atc.classification_atc_4_id IS DISTINCT FROM t_classification_atc_1.oid OR t_classification_atc.classification_atc_4_code IS DISTINCT FROM t_classification_atc_1.code OR t_classification_atc.classification_atc_4_texte IS DISTINCT FROM t_classification_atc_1.texte ); UPDATE base.t_classification_atc SET classification_atc_4_id = t_classification_atc_1.oid, classification_atc_4_code = t_classification_atc_1.code, classification_atc_4_texte = t_classification_atc_1.texte FROM base.t_classification_atc t_classification_atc_1 WHERE t_classification_atc.oid <> 0 AND t_classification_atc_1.code = t_classification_atc.classification_atc_3_code || 'X' AND COALESCE(t_classification_atc.classification_atc_4_id,0) = 0 AND ( t_classification_atc.classification_atc_4_id IS DISTINCT FROM t_classification_atc_1.oid OR t_classification_atc.classification_atc_4_code IS DISTINCT FROM t_classification_atc_1.code OR t_classification_atc.classification_atc_4_texte IS DISTINCT FROM t_classification_atc_1.texte ); UPDATE base.t_classification_atc SET classification_atc_4_code = t_classification_atc_1.code, classification_atc_4_texte = t_classification_atc_1.texte FROM base.t_classification_atc t_classification_atc_1 WHERE t_classification_atc.classification_atc_4_id = t_classification_atc_1.oid AND ( t_classification_atc.classification_atc_4_code IS DISTINCT FROM t_classification_atc_1.code OR t_classification_atc.classification_atc_4_texte IS DISTINCT FROM t_classification_atc_1.texte ); UPDATE base.t_classification_atc SET classification_atc_1_id = oid, classification_atc_1_code = code, classification_atc_1_texte = texte_court, classification_atc_2_id = oid, classification_atc_2_code = code, classification_atc_2_texte = texte_court, classification_atc_3_id = oid, classification_atc_3_code = code, classification_atc_3_texte = texte_court, classification_atc_4_id = oid, classification_atc_4_code = code, classification_atc_4_texte = texte_court WHERE ( classification_atc_1_code = 'X' AND code NOT LIKE 'X%' OR classification_atc_1_id = 0 OR classification_atc_1_id IS NULL ) AND (classification_atc_1_id IS DISTINCT FROM oid OR classification_atc_1_code IS DISTINCT FROM code OR classification_atc_1_texte IS DISTINCT FROM texte_court OR classification_atc_2_id IS DISTINCT FROM oid OR classification_atc_2_code IS DISTINCT FROM code OR classification_atc_2_texte IS DISTINCT FROM texte_court OR classification_atc_3_id IS DISTINCT FROM oid OR classification_atc_3_code IS DISTINCT FROM code OR classification_atc_3_texte IS DISTINCT FROM texte_court OR classification_atc_4_id IS DISTINCT FROM oid OR classification_atc_4_code IS DISTINCT FROM code OR classification_atc_4_texte IS DISTINCT FROM texte_court ) ; -- Ventilation ATC/CLADIMED UPDATE base.t_classification_atc SET est_atc = subview.est_atc, est_cladimed = subview.est_cladimed FROM (SELECT substr(t_classification_atc.code,1,1) AS code, MAX(est_atc) AS est_atc, MAX(est_cladimed) AS est_cladimed FROM base.t_classification_atc WHERE oid <> 0 GROUP BY 1 ORDER BY 1 ) subview WHERE substr(t_classification_atc.code,2,6) = '99' AND substr(t_classification_atc.code,1,1) = subview.code AND ( t_classification_atc.est_atc IS DISTINCT FROM subview.est_atc OR t_classification_atc.est_cladimed IS DISTINCT FROM subview.est_cladimed ) ; UPDATE base.t_classification_atc SET est_atc = subview.est_atc, est_cladimed = subview.est_cladimed FROM (SELECT substr(t_classification_atc.code,1,3) AS code, MAX(est_atc) AS est_atc, MAX(est_cladimed) AS est_cladimed FROM base.t_classification_atc WHERE oid <> 0 GROUP BY 1 ORDER BY 1 ) subview WHERE substr(t_classification_atc.code,4,4) = 'X' AND substr(t_classification_atc.code,1,3) = subview.code AND ( t_classification_atc.est_atc IS DISTINCT FROM subview.est_atc OR t_classification_atc.est_cladimed IS DISTINCT FROM subview.est_cladimed ) ; UPDATE base.t_classification_atc SET est_atc = subview.est_atc, est_cladimed = subview.est_cladimed FROM (SELECT substr(t_classification_atc.code,1,4) AS code, MAX(est_atc) AS est_atc, MAX(est_cladimed) AS est_cladimed FROM base.t_classification_atc WHERE oid <> 0 GROUP BY 1 ORDER BY 1 ) subview WHERE substr(t_classification_atc.code,5,3) = 'X' AND substr(t_classification_atc.code,1,4) = subview.code AND ( t_classification_atc.est_atc IS DISTINCT FROM subview.est_atc OR t_classification_atc.est_cladimed IS DISTINCT FROM subview.est_cladimed ) ; UPDATE base.t_classification_atc SET est_atc = subview.est_atc, est_cladimed = subview.est_cladimed FROM (SELECT substr(t_classification_atc.code,1,5) AS code, MAX(est_atc) AS est_atc, MAX(est_cladimed) AS est_cladimed FROM base.t_classification_atc WHERE oid <> 0 GROUP BY 1 ORDER BY 1 ) subview WHERE substr(t_classification_atc.code,6,2) = 'XX' AND substr(t_classification_atc.code,1,5) = subview.code AND ( t_classification_atc.est_atc IS DISTINCT FROM subview.est_atc OR t_classification_atc.est_cladimed IS DISTINCT FROM subview.est_cladimed ) ; UPDATE base.t_ucd SET classification_atc_id = t_classification_atc.oid FROM base.t_classification_atc WHERE t_classification_atc.code = atc_code AND classification_atc_id IS DISTINCT FROM t_classification_atc.oid ; -- Recopie dans activite INSERT INTO activite.t_ucd_c (oid, code, texte, texte_court, classification_atc_id) SELECT oid, code, texte, texte_court, classification_atc_id FROM base.t_ucd WHERE oid NOT IN (SELECT oid FROM activite.t_ucd_c); UPDATE activite.t_ucd_c SET code = t_ucd.code, texte = t_ucd.texte, texte_court = t_ucd.texte_court, classification_atc_id = t_ucd.classification_atc_id FROM base.t_ucd WHERE t_ucd.oid = t_ucd_c.oid AND ( t_ucd_c.code IS DISTINCT FROM t_ucd.code OR t_ucd_c.texte IS DISTINCT FROM t_ucd.texte OR t_ucd_c.texte_court IS DISTINCT FROM t_ucd.texte_court OR t_ucd_c.classification_atc_id IS DISTINCT FROM t_ucd.classification_atc_id ); UPDATE activite.t_ucd_c SET classification_atc_code = t_classification_atc.code, classification_atc_texte = t_classification_atc.texte_court, classification_atc_section_id = t_classification_atc.section_id, classification_atc_section_code = t_classification_atc.section_code, classification_atc_section_texte = t_classification_atc.section_texte, classification_atc_1_id = t_classification_atc.classification_atc_1_id, classification_atc_1_code = t_classification_atc.classification_atc_1_code, classification_atc_1_texte = t_classification_atc.classification_atc_1_texte, classification_atc_2_id = t_classification_atc.classification_atc_2_id, classification_atc_2_code = t_classification_atc.classification_atc_2_code, classification_atc_2_texte = t_classification_atc.classification_atc_2_texte, classification_atc_3_id = t_classification_atc.classification_atc_3_id, classification_atc_3_code = t_classification_atc.classification_atc_3_code, classification_atc_3_texte = t_classification_atc.classification_atc_3_texte, classification_atc_4_id = t_classification_atc.classification_atc_4_id, classification_atc_4_code = t_classification_atc.classification_atc_4_code, classification_atc_4_texte = t_classification_atc.classification_atc_4_texte FROM base.t_classification_atc WHERE classification_atc_id = t_classification_atc.oid AND ( t_ucd_c.classification_atc_code IS DISTINCT FROM t_classification_atc.code OR t_ucd_c.classification_atc_texte IS DISTINCT FROM t_classification_atc.texte_court OR t_ucd_c.classification_atc_section_id IS DISTINCT FROM t_classification_atc.section_id OR t_ucd_c.classification_atc_section_code::text[] IS DISTINCT FROM t_classification_atc.section_code::text[] OR t_ucd_c.classification_atc_section_texte::text[] IS DISTINCT FROM t_classification_atc.section_texte::text[] OR t_ucd_c.classification_atc_1_id IS DISTINCT FROM t_classification_atc.classification_atc_1_id OR t_ucd_c.classification_atc_1_code IS DISTINCT FROM t_classification_atc.classification_atc_1_code OR t_ucd_c.classification_atc_1_texte IS DISTINCT FROM t_classification_atc.classification_atc_1_texte OR t_ucd_c.classification_atc_2_id IS DISTINCT FROM t_classification_atc.classification_atc_2_id OR t_ucd_c.classification_atc_2_code IS DISTINCT FROM t_classification_atc.classification_atc_2_code OR t_ucd_c.classification_atc_2_texte IS DISTINCT FROM t_classification_atc.classification_atc_2_texte OR t_ucd_c.classification_atc_3_id IS DISTINCT FROM t_classification_atc.classification_atc_3_id OR t_ucd_c.classification_atc_3_code IS DISTINCT FROM t_classification_atc.classification_atc_3_code OR t_ucd_c.classification_atc_3_texte IS DISTINCT FROM t_classification_atc.classification_atc_3_texte OR t_ucd_c.classification_atc_4_id IS DISTINCT FROM t_classification_atc.classification_atc_4_id OR t_ucd_c.classification_atc_4_code IS DISTINCT FROM t_classification_atc.classification_atc_4_code OR t_ucd_c.classification_atc_4_texte IS DISTINCT FROM t_classification_atc.classification_atc_4_texte ) ; -- Nouvelle colonne dans base (retro comptabililité) IF NOT EXISTS ( SELECT column_name FROM information_schema.columns WHERE table_schema || '.' || table_name = 'base.t_lpp' AND column_name = 'classification_atc_id') THEN ALTER TABLE base.t_lpp ADD COLUMN classification_atc_id bigint default 0; END IF; INSERT INTO base.t_lpp(oid, code, texte, texte_court) SELECT 0, chr(127) || '*******', chr(127) || 'Non renseigné', chr(127) || 'Non renseigné' WHERE 0 NOT IN (SELECT oid FROM base.t_lpp); -- Si module pmsi, ajout des lpp pmsi IF _module_pmsimco = '1' THEN INSERT INTO base.t_lpp (code, texte, texte_court) SELECT code, texte, texte_court FROM pmsi.t_lpp WHERE oid <> 0 AND code NOT IN (SELECT code FROM base.t_lpp WHERE code IS NOT NULL) ; END IF; UPDATE base.t_lpp SET texte_court = texte WHERE COALESCE(texte_court,'') = ''; INSERT INTO activite.t_lpp_c (oid, code, texte, texte_court, classification_atc_id) SELECT oid, code, texte, texte_court, classification_atc_id FROM base.t_lpp WHERE oid NOT IN (SELECT oid FROM activite.t_lpp_c); UPDATE activite.t_lpp_c SET code = t_lpp.code, texte = t_lpp.texte, texte_court = t_lpp.texte_court, classification_atc_id = t_lpp.classification_atc_id FROM base.t_lpp WHERE t_lpp.oid = t_lpp_c.oid AND ( t_lpp_c.code IS DISTINCT FROM t_lpp.code OR t_lpp_c.texte IS DISTINCT FROM t_lpp.texte OR t_lpp_c.texte_court IS DISTINCT FROM t_lpp.texte_court OR t_lpp_c.classification_atc_id IS DISTINCT FROM t_lpp.classification_atc_id ); UPDATE activite.t_lpp_c SET classification_atc_code = t_classification_atc.code, classification_atc_texte = t_classification_atc.texte_court, classification_atc_section_id = t_classification_atc.section_id, classification_atc_section_code = t_classification_atc.section_code, classification_atc_section_texte = t_classification_atc.section_texte, classification_atc_1_id = t_classification_atc.classification_atc_1_id, classification_atc_1_code = t_classification_atc.classification_atc_1_code, classification_atc_1_texte = t_classification_atc.classification_atc_1_texte, classification_atc_2_id = t_classification_atc.classification_atc_2_id, classification_atc_2_code = t_classification_atc.classification_atc_2_code, classification_atc_2_texte = t_classification_atc.classification_atc_2_texte, classification_atc_3_id = t_classification_atc.classification_atc_3_id, classification_atc_3_code = t_classification_atc.classification_atc_3_code, classification_atc_3_texte = t_classification_atc.classification_atc_3_texte, classification_atc_4_id = t_classification_atc.classification_atc_4_id, classification_atc_4_code = t_classification_atc.classification_atc_4_code, classification_atc_4_texte = t_classification_atc.classification_atc_4_texte FROM base.t_classification_atc WHERE classification_atc_id = t_classification_atc.oid AND ( t_lpp_c.classification_atc_code IS DISTINCT FROM t_classification_atc.code OR t_lpp_c.classification_atc_texte IS DISTINCT FROM t_classification_atc.texte_court OR t_lpp_c.classification_atc_section_id IS DISTINCT FROM t_classification_atc.section_id OR t_lpp_c.classification_atc_section_code::text[] IS DISTINCT FROM t_classification_atc.section_code::text[] OR t_lpp_c.classification_atc_section_texte::text[] IS DISTINCT FROM t_classification_atc.section_texte::text[] OR t_lpp_c.classification_atc_1_id IS DISTINCT FROM t_classification_atc.classification_atc_1_id OR t_lpp_c.classification_atc_1_code IS DISTINCT FROM t_classification_atc.classification_atc_1_code OR t_lpp_c.classification_atc_1_texte IS DISTINCT FROM t_classification_atc.classification_atc_1_texte OR t_lpp_c.classification_atc_2_id IS DISTINCT FROM t_classification_atc.classification_atc_2_id OR t_lpp_c.classification_atc_2_code IS DISTINCT FROM t_classification_atc.classification_atc_2_code OR t_lpp_c.classification_atc_2_texte IS DISTINCT FROM t_classification_atc.classification_atc_2_texte OR t_lpp_c.classification_atc_3_id IS DISTINCT FROM t_classification_atc.classification_atc_3_id OR t_lpp_c.classification_atc_3_code IS DISTINCT FROM t_classification_atc.classification_atc_3_code OR t_lpp_c.classification_atc_3_texte IS DISTINCT FROM t_classification_atc.classification_atc_3_texte OR t_lpp_c.classification_atc_4_id IS DISTINCT FROM t_classification_atc.classification_atc_4_id OR t_lpp_c.classification_atc_4_code IS DISTINCT FROM t_classification_atc.classification_atc_4_code OR t_lpp_c.classification_atc_4_texte IS DISTINCT FROM t_classification_atc.classification_atc_4_texte ) ; RETURN 'OK'; END;