-------------------------------------------------------- -- DDL for Procedure P_MANAGE_USERS -------------------------------------------------------- set define off; CREATE OR REPLACE EDITIONABLE PROCEDURE "ENVX_OPER"."P_MANAGE_USERS" ( pi_internal_profile IN OUT CLOB ) AS v_json_aux json; v_id_user NUMBER := JSON_VALUE(pi_internal_profile, '$.userId'); v_user_name VARCHAR2(500) := JSON_VALUE(pi_internal_profile, '$.user'); v_user_mail VARCHAR2(500) := JSON_VALUE(pi_internal_profile, '$.email'); v_user_status NUMBER := 0; BEGIN --- Verificación de Roles Revocados --- DELETE user_roles ur WHERE ur.id_user = v_id_user AND ( SELECT 1 FROM JSON_TABLE ( JSON(pi_internal_profile), '$.idm[*]' COLUMNS ( "domain" VARCHAR2 (100) PATH '$.domain', "group" VARCHAR2 (100) PATH '$.group' ) ) j, system_role sr WHERE j."domain" = nvl(sr.idm_domain, 'others') AND lower(j."group") = lower(sr.idm_group) AND sr.id_role = ur.id_role ) IS NULL; --- Verificación de Roles Revocados --- --- Verificación de Perfiles Revocados --- DELETE user_roles ur WHERE ur.id_user = v_id_user AND ( SELECT 1 FROM JSON_TABLE ( JSON(pi_internal_profile), '$.idm[*]' COLUMNS ( "domain" VARCHAR2 (100) PATH '$.domain', "group" VARCHAR2 (100) PATH '$.group' ) ) j, system_role sr, system_profile sp WHERE j."domain" = nvl(sr.idm_domain, 'others') AND lower(j."group") = lower(sp.idm_group) AND lower(sr.id_role) = lower(sp.id_role) AND sr.id_role = ur.id_role AND sp.id_sys_profile = ur.id_sys_profile ) IS NULL; --- Verificación de Perfiles Revocados --- --- Incorporación de Nuevos Perfiles --- FOR prf IN ( SELECT v_id_user AS id_user, v_user_name AS user_name, v_user_mail AS user_mail, sr.id_role, sp.id_sys_profile, 1 FROM JSON_TABLE ( JSON(pi_internal_profile), '$.idm[*]' COLUMNS ( "domain" VARCHAR2 (100) PATH '$.domain', "group" VARCHAR2 (100) PATH '$.group' ) ) j, system_role sr, system_profile sp WHERE j."domain" = nvl(sr.idm_domain, 'others') AND lower(j."group") = lower(sp.idm_group) AND lower(sr.id_role) = lower(sp.id_role) ) LOOP BEGIN INSERT INTO user_roles ur VALUES prf; EXCEPTION WHEN OTHERS THEN NULL; END; END LOOP; --- Incorporación de Nuevos Perfiles --- --- Extraccion de roles ENVX correspondientes --- SELECT JSON_ARRAYAGG(JSON_OBJECT('roleId' VALUE r1.id_role, 'roleName' VALUE r1.role_name)) AS roles_array INTO v_json_aux FROM ( SELECT UNIQUE ur.id_role, sr.role_name FROM user_roles ur, system_role sr WHERE ur.id_role = sr.id_role AND id_user = v_id_user ) r1; SELECT JSON_TRANSFORM(pi_internal_profile, INSERT '$.roles' = v_json_aux) INTO pi_internal_profile FROM dual; --- Extraccion de roles ENVX correspondientes --- --- Extraccion de perfiles ENVX correspondientes --- SELECT JSON_ARRAYAGG( JSON_OBJECT('roleId' VALUE r1.id_role, 'sysProfileId' VALUE r1.id_sys_profile, 'sysProfileName' VALUE r1.sys_profile_name) ) AS json_profiles INTO v_json_aux FROM ( SELECT UNIQUE ur.id_role, sp.id_sys_profile, sp.sys_profile_name FROM user_roles ur, system_profile sp WHERE ur.id_role = sp.id_role AND ur.id_sys_profile = sp.id_sys_profile AND id_user = v_id_user ) r1; SELECT JSON_TRANSFORM(pi_internal_profile, INSERT '$.profiles' = v_json_aux) INTO pi_internal_profile FROM dual; --- Extraccion de perfiles ENVX correspondientes --- END; /