diff --git a/OracleDatabase/SingleInstance/FAQ.md b/OracleDatabase/SingleInstance/FAQ.md index 61462bb62a..abe07f2a93 100644 --- a/OracleDatabase/SingleInstance/FAQ.md +++ b/OracleDatabase/SingleInstance/FAQ.md @@ -4,11 +4,13 @@ Yes, this feature is supported version 19.3 onwards. -Versions prior to 19.3 available on the [Oracle Container Registry](https://container-registry.oracle.com/), like the Oracle Database 12c Standard Edition 2 and Enterprise Edition images, are not based on any of the Dockerfiles contained in this repository. For such versions, if you require the runtime functionality documented in this repository, you will need to build an image from the appropriate Dockerfile. +Versions prior to 19.3 available on the [Oracle Container Registry](https://container-registry.oracle.com/), like the Oracle Database 12c Standard Edition 2 and Enterprise Edition images, are not based on any of the Dockerfiles contained in this repository. +For such versions, if you require the runtime functionality documented in this repository, you will need to build an image from the appropriate Dockerfile. ## How do I change the timezone of my container -As of Docker 17.06-ce, Docker does not yet provide a way to pass down the `TZ` Unix environment variable from the host to the container. Because of that all containers run in the UTC timezone. If you would like to have your database run in a different timezone you can pass on the `TZ` environment variable within the `docker run` command via the `-e` option. An example would be: `docker run ... -e TZ="Europe/Vienna" oracle/database:12.2.0.1-ee`. Another option would be to specify two read-only volume mounts: `docker run ... -v /etc/timezone:/etc/timezone:ro -v /etc/localtime:/etc/localtime:ro oracle/database:12.2.0.1-ee`. This will synchronize the timezone of the the container with that of the Docker host. +As of Docker 17.06-ce, Docker does not yet provide a way to pass down the `TZ` Unix environment variable from the host to the container. Because of that all containers run in the UTC timezone. If you would like to have your database run in a different timezone you can pass on the `TZ` environment variable within the `docker run` command via the `-e` option. +An example would be: `docker run ... -e TZ="Europe/Vienna" oracle/database:12.2.0.1-ee`. Another option would be to specify two read-only volume mounts: `docker run ... -v /etc/timezone:/etc/timezone:ro -v /etc/localtime:/etc/localtime:ro oracle/database:12.2.0.1-ee`. This will synchronize the timezone of the the container with that of the Docker host. ## Can I run Oracle Database containers on Apple M1 (Arm) devices? @@ -25,7 +27,8 @@ which are not available for that architecture. This error is thrown when there is no sufficient space available within the container to unzip the install binaries and run the installation of the Oracle database. The container runs the `df` Unix command, meaning that even if you think there should be enough space, there certainly isn't within the container. -Please make sure that you have enough space available. If you use a storage diver such as `overlay2`, make sure that the output of `docker info` shows a `Base Device Size:` that is bigger than the required space. If not, please change the Base Device Size via the `--storage-opt dm.basesize=` option for the Docker daemon, see [this thread on Docker forums](https://forums.docker.com/t/increase-container-volume-disk-size/1652/4) for more information on that. **Note: You will have to delete all images afterwards to make sure that the new setting is picked up!** +Please make sure that you have enough space available. If you use a storage diver such as `overlay2`, make sure that the output of `docker info` shows a `Base Device Size:` that is bigger than the required space. +If not, please change the Base Device Size via the `--storage-opt dm.basesize=` option for the Docker daemon, see [this thread on Docker forums](https://forums.docker.com/t/increase-container-volume-disk-size/1652/4) for more information on that. **Note: You will have to delete all images afterwards to make sure that the new setting is picked up!** ## Error: The container doesn't have enough memory allocated. A database XE container needs at least 1 GB of shared memory (/dev/shm) @@ -37,7 +40,8 @@ CRC errors by the Unix unzip command during image build can be caused by a lack ## "Cannot create directory" error when using volumes -This is a Unix file system permission issue. Docker by default will map the `uid` inside the container to the outside world. The `uid` for the `oracle` user inside the container is `54321` and therefore all files are created with this `uid`. If you happen to have your volume pointed at a location outside there container where this `uid` doesn't have any permissions for, the container can't write to it and therefore the database files creation fails. There are several remedies for this situation: +This is a Unix file system permission issue. Docker by default will map the `uid` inside the container to the outside world. The `uid` for the `oracle` user inside the container is `54321` and therefore all files are created with this `uid`. +If you happen to have your volume pointed at a location outside there container where this `uid` doesn't have any permissions for, the container can't write to it and therefore the database files creation fails. There are several remedies for this situation: * Use named volumes * Change the ownership of your folder to `54321` @@ -110,3 +114,83 @@ Refer to the [module documentation](https://python-oracledb.readthedocs.io/en/la ## ORA-01157: cannot identify/lock data file This error occurs when the database cannot find a data file (used for tablespaces) that was previously present. This is most likely because the data file has been located outside the volume in a previous container and was hence not persisted. Ensure that when you add tablespaces and/or data files that they are located within the volume location, i.e. $ORACLE_BASE/oradata/$ORACLE_SID, (e.g. `/opt/oracle/oradata/XE`). + +## Running Oracle Database 23c Free on Apple Silicon (ARM) chip + +### Setup Database +Below are the steps to run Oracle Database 23c Free on Apple Silicon (ARM) machine + +1. Install [Podman Lima](https://github.com/lima-vm/lima) on Mac + + ```brew install podman lima``` + +2. Start a lima instance (vm) + + ```limactl start --name podman-amd64 --set='.arch = "x86_64" | .memory = "10GiB"' template://podman``` + + Wait for the VM to boot up. Above command may error out if the VM takes a while to boot up. Ultimately it comes up fine. + +3. Set the address or hostname of the lima container runtime + + ```export CONTAINER_HOST=unix://Users/$USER/.lima/podman-amd64/sock/podman.sock``` + +4. Pull the oracle database 23c free image + + ```podman pull container-registry.oracle.com/database/free:latest``` + +5. Run the container with the pulled image + + ```podman run -e ORACLE_PWD= -d -P container-registry.oracle.com/database/free:latest``` + +6. Check whether the database came up healthy. + +```shell + $ podman ps -a + CONTAINER ID IMAGE COMMAND CREATED STATUS PORTS NAMES + 825dcbd3e822 container-registry.oracle.com/database/free:latest /bin/sh -c exec $... 4 minutes ago Up 4 minutes (healthy) 0.0.0.0:42439->1521/tcp hopeful_yalow +``` + +### Connect +1. Install sqlplus + + ```cd $HOME/Downloads``` + + ```curl -O https://download.oracle.com/otn_software/mac/instantclient/198000/instantclient-basic-macos.x64-19.8.0.0.0dbru.dmg``` + + ```curl -O https://download.oracle.com/otn_software/mac/instantclient/198000/instantclient-sqlplus-macos.x64-19.8.0.0.0dbru.dmg``` + + ```hdiutil mount instantclient-basic-macos.x64-19.8.0.0.0dbru.dmg``` + + ```hdiutil mount instantclient-sqlplus-macos.x64-19.8.0.0.0dbru.dmg``` + + ```/Volumes/instantclient-basic-macos.x64-19.8.0.0.0dbru/install_ic.sh``` + + ```hdiutil unmount /Volumes/instantclient-basic-macos.x64-19.8.0.0.0dbru``` + + ```hdiutil unmount /Volumes/instantclient-sqlplus-macos.x64-19.8.0.0.0dbru``` + +2. Test the connection: + + ```$HOME/Downloads/instantclient_19_8/sqlplus sys@localhost:/FREE as sysdba``` + + ```$HOME/Downloads/instantclient_19_8/sqlplus system@localhost:/FREE``` + + ```$HOME/Downloads/instantclient_19_8/sqlplus pdbadmin@localhost:/FREEPDB1``` + + PORT is 42439 in above e.g. (Step 6 output of "podman ps -a"). + +Alternative (Using SQLcl): + +1. Install [Java](https://download.oracle.com/java/20/latest/jdk-20_macos-aarch64_bin.dmg) + +2. Install [SQLcl](https://download.oracle.com/otn_software/java/sqldeveloper/sqlcl-latest.zip) + +3. Test the connection: + + ```sqlcl/bin/sql sys@localhost:/FREE as sysdba``` + + ```sqlcl/bin/sql system@localhost:/FREE``` + + ```sqlcl/bin/sql pdbadmin@localhost:/FREEPDB1``` + + PORT is 42439 in above e.g. (Step 6 output of "podman ps -a"). \ No newline at end of file diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_EBSHRMS_SCHEMA_PKG.pck b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_EBSHRMS_SCHEMA_PKG.pck new file mode 100644 index 0000000000..313547ba36 --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_EBSHRMS_SCHEMA_PKG.pck @@ -0,0 +1,120 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for CREATING synonym of procedures/packages and Tables required for HRMS +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +create or replace PACKAGE OIM_EBSHRMS_SCHEMA_PKG AS + + PROCEDURE get_schema( schemaout OUT schemalist); + + END OIM_EBSHRMS_SCHEMA_PKG; + + / + +create or replace PACKAGE BODY OIM_EBSHRMS_SCHEMA_PKG AS + +procedure get_schema( + schemaout OUT schemalist + ) AS + attr attributelist; + BEGIN + schemaout := schemalist(); + schemaout.extend(1); + attr := attributelist(); + attr.extend (50); + attr (1) := attributeinfo('HIRE_DATE','date',1,1,0,1); + attr (2) := attributeinfo('BUSINESS_GROUP_ID','varchar2',1,1,0,1); + attr (3) := attributeinfo('LAST_NAME','varchar2',1,1,1,1); + attr (4) := attributeinfo('FIRST_NAME','varchar2',1,1,1,1); + attr (5) := attributeinfo('SEX','varchar2',1,1,0,1); + attr (6) := attributeinfo('PERSON_TYPE_ID','varchar2',1,1,0,1); + attr (7) := attributeinfo('EMPLOYEE_NUMBER','varchar2',1,1,0,1); + attr (8) := attributeinfo('PERSON_ID','varchar2',1,1,0,1); + attr (9) := attributeinfo('TITLE','varchar2',1,1,0,1); + attr (10) := attributeinfo('EMAIL_ADDRESS','varchar2',1,1,0,1); + attr (11) := attributeinfo('MARITAL_STATUS','varchar2',1,1,0,1); + attr (12) := attributeinfo('NATIONALITY','varchar2',1,1,0,1); + attr (13) := attributeinfo('NATIONAL_IDENTIFIER','varchar2',1,1,0,1); + attr (14) := attributeinfo('DATE_OF_BIRTH','date',1,1,0,1); + attr (15) := attributeinfo('TOWN_OF_BIRTH','varchar2',1,1,0,1); + attr (16) := attributeinfo('REGION_OF_BIRTH','varchar2',1,1,0,1); + attr (17) := attributeinfo('COUNTRY_OF_BIRTH','varchar2',1,1,0,1); + attr (18) := attributeinfo('USER_PERSON_TYPE','varchar2',1,1,0,1); + attr (19) := attributeinfo('EFFECTIVE_START_DATE','date',1,1,0,1); + attr (20) := attributeinfo('ACTUAL_TERMINATION_DATE','date',1,1,0,1); + attr (21) := attributeinfo('SUPERVISOR_ID','varchar2',1,1,0,1); + attr (22) := attributeinfo('SUPERVISOR_NAME','varchar2',0,0,0,1); + attr (23) := attributeinfo('JOB','varchar2',1,1,0,1); + attr (24) := attributeinfo('GRADE','varchar2',1,1,0,1); + attr (25) := attributeinfo('DEPARTMENT','varchar2',1,1,0,1); + attr (26) := attributeinfo('PERSON_UPDATED_DATE','date',1,1,0,1); + attr (27) := attributeinfo('ASSIGNMENT_UPDATED_DATE','date',1,1,0,1); + + schemaout( 1 ) := schema_object('__PERSON__',attr); + + attr := attributelist(); + attr.extend; + attr (1) := attributeinfo('ADDRESS_ID','number',1,0,0,1); + attr.extend; + attr (2) := attributeinfo('PRIMARY_FLAG','varchar',1,1,0,1); + attr.extend; + attr (3) := attributeinfo('STYLE','varchar',1,1,0,1); + attr.extend; + attr (4) := attributeinfo('DATE_FROM','date',1,1,0,1); + attr.extend; + attr (5) := attributeinfo('ADDRESS_LINE1','varchar',1,1,0,1); + attr.extend; + attr (6) := attributeinfo('ADDRESS_LINE2','varchar',1,1,0,1); + attr.extend; + attr (7) := attributeinfo('ADDRESS_LINE3','varchar',1,1,0,1); + attr.extend; + attr (8) := attributeinfo('TOWN_OR_CITY','varchar',1,1,0,1); + attr.extend; + attr (9) := attributeinfo('REGION_1','varchar',1,1,0,1); + attr.extend; + attr (10) := attributeinfo('REGION_2','varchar',1,1,0,1); + attr.extend; + attr (11) := attributeinfo('REGION_3','varchar',1,1,0,1); + attr.extend; + attr (12) := attributeinfo('POSTAL_CODE','varchar',1,1,0,1); + attr.extend; + attr (13) := attributeinfo('COUNTRY','varchar',1,1,0,1); + attr.extend; + attr (14) := attributeinfo('DATE_TO','date',1,1,0,1); + attr.extend; + attr (15) := attributeinfo('ADDRESS_TYPE','varchar',1,1,0,1); + attr.extend; + + schemaout.extend; + schemaout( 2 ) := schema_object('__ADDRESS__',attr); + + + attr := attributelist(); + attr.extend; + attr (1) := attributeinfo('ASSIGNMENT_ID','number',1,0,0,1); + attr.extend; + attr (2) := attributeinfo('ASG_EFFECTIVE_START_DATE','date',1,0,0,1); + attr.extend; + attr (3) := attributeinfo('CHANGE_REASON','varchar',1,1,0,1); + attr.extend; + attr (4) := attributeinfo('ORGANIZATION_ID','number',1,1,0,1); + attr.extend; + attr (5) := attributeinfo('JOB_ID','number',1,1,0,1); + attr.extend; + attr (6) := attributeinfo('GRADE_ID','number',1,1,0,1); + attr.extend; + attr (7) := attributeinfo('SUPERVISOR_ID','number',1,1,0,1); + attr.extend; + + schemaout.extend; + schemaout( 3 ) := schema_object('__ASSIGNMENT__',attr); + +END get_schema; + +END OIM_EBSHRMS_SCHEMA_PKG; +/ diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_EMPLOYEE_ADDRESS_WRAPPER.pck b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_EMPLOYEE_ADDRESS_WRAPPER.pck new file mode 100644 index 0000000000..ba03b7affb --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_EMPLOYEE_ADDRESS_WRAPPER.pck @@ -0,0 +1,181 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for CREATING synonym of procedures/packages and Tables required for HRMS +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +create or replace PACKAGE OIM_EMPLOYEE_ADDRESS_WRAPPER AS + + PROCEDURE create_person_address_api (person_id IN number ,primary_flag IN varchar2 ,style IN varchar2 ,date_from IN date ,date_to IN date ,address_type IN varchar2 ,address_line1 IN varchar2 ,address_line2 IN varchar2 ,address_line3 IN varchar2 ,town_or_city IN varchar2 ,region_1 IN varchar2 ,region_2 IN varchar2 ,region_3 IN varchar2 ,postal_code IN varchar2 ,country IN varchar2 ,telephone_number_1 IN varchar2 ,telephone_number_2 IN varchar2 ,telephone_number_3 IN varchar2 ,address_id OUT number ,object_version_number OUT number ); + + PROCEDURE update_person_address_api ( address_id IN number,person_id IN number ,primary_flag IN varchar2 ,style IN varchar2 ,date_from IN date ,date_to IN date ,address_type IN varchar2 ,address_line1 IN varchar2 ,address_line2 IN varchar2 ,address_line3 IN varchar2 ,town_or_city IN varchar2 ,region_1 IN varchar2 ,region_2 IN varchar2 ,region_3 IN varchar2 ,postal_code IN varchar2 ,country IN varchar2 ,telephone_number_1 IN varchar2 ,telephone_number_2 IN varchar2 ,telephone_number_3 IN varchar2); + + PROCEDURE delete_person_address_api ( address_id IN number,date_from IN date); + +END OIM_EMPLOYEE_ADDRESS_WRAPPER; + + / + +create or replace PACKAGE BODY OIM_EMPLOYEE_ADDRESS_WRAPPER AS + + -------Procedure for create address for an employee -------- +procedure create_person_address_api +( + person_id IN number, + primary_flag IN varchar2, + style IN varchar2, + date_from IN date, + date_to IN date, + address_type IN varchar2, + address_line1 IN varchar2, + address_line2 IN varchar2, + address_line3 IN varchar2, + town_or_city IN varchar2, + region_1 IN varchar2, + region_2 IN varchar2, + region_3 IN varchar2, + postal_code IN varchar2, + country IN varchar2, + telephone_number_1 IN varchar2, + telephone_number_2 IN varchar2, + telephone_number_3 IN varchar2, + address_id OUT number, + object_version_number OUT number +) +is +BEGIN + -- Start of API + HR_PERSON_ADDRESS_API.CREATE_PERSON_ADDRESS( + p_effective_date => date_from, + P_person_id => person_id, + P_primary_flag => primary_flag, + P_style => style, + P_date_from => date_from, + P_date_to => date_to, + P_ADDRESS_TYPE => address_type, + P_address_line1 => address_line1, + P_address_line2 => address_line2, + P_address_line3 => address_line3, + P_town_or_city => town_or_city, + P_region_1 => region_1, + P_region_2 => region_2, + P_region_3 => region_3, + P_postal_code => postal_code, + P_country => country, + P_telephone_number_1 => telephone_number_1, + P_telephone_number_2 => telephone_number_2, + P_telephone_number_3 => telephone_number_3, + P_address_id => address_id, + P_object_version_number => object_version_number + ); + + EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line(SUBSTR(SQLERRM,1,200)); + raise; +END create_person_address_api ; + +PROCEDURE update_person_address_api +( + address_id IN number, + person_id IN number, + primary_flag IN varchar2, + style IN varchar2 , + date_from IN date , + date_to IN date , + address_type IN varchar2 , + address_line1 IN varchar2 , + address_line2 IN varchar2 , + address_line3 IN varchar2 , + town_or_city IN varchar2 , + region_1 IN varchar2 , + region_2 IN varchar2 , + region_3 IN varchar2 , + postal_code IN varchar2 , + country IN varchar2 , + telephone_number_1 IN varchar2 , + telephone_number_2 IN varchar2 , + telephone_number_3 IN varchar2 +) +IS + l_object_version_number per_addresses.object_version_number%type; + +BEGIN + SELECT MAX(object_version_number) into l_object_version_number FROM PER_ADDRESSES WHERE address_id = update_person_address_api.address_id; + + -- Start of API + HR_PERSON_ADDRESS_API.update_person_address( + p_effective_date => date_from, + p_address_id => address_id, + p_object_version_number => l_object_version_number, + p_date_from => date_from, + p_date_to => date_to, + p_primary_flag => primary_flag, + p_address_type => address_type, + P_address_line1 => address_line1, + p_address_line2 => address_line2, + p_address_line3 => address_line3, + p_town_or_city => town_or_city, + p_region_1 => region_1, + p_region_2 => region_2, + p_region_3 => region_3, + p_postal_code => postal_code, + p_country => country, + p_telephone_number_1 => telephone_number_1, + p_telephone_number_2 => telephone_number_2, + p_telephone_number_3 => telephone_number_3 +); + +EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line(SUBSTR(SQLERRM,1,200)); + raise; +END update_person_address_api ; + +PROCEDURE delete_person_address_api(address_id IN number, + date_from IN date +) +IS + l_date_to date; + l_date_from date; + l_object_version_number per_addresses.object_version_number%type; + +BEGIN + SELECT MAX(PER_ADDRESSES.date_to) into l_date_to FROM PER_ADDRESSES WHERE address_id = delete_person_address_api.address_id; + --End Date is already set, ignore + if l_date_to is null then + + l_date_to := SYSDATE; + + SELECT MAX(object_version_number) into l_object_version_number FROM PER_ADDRESSES WHERE address_id = delete_person_address_api.address_id; + IF date_from IS NOT NULL THEN + l_date_from := date_from; + ELSE + SELECT MAX(PER_ADDRESSES.date_from) into l_date_from FROM PER_ADDRESSES WHERE address_id = delete_person_address_api.address_id; + end if; + -- date_from should be always less than or equal to date_to + if l_date_from > l_date_to then + l_date_to := l_date_from; + end if; + -- Start of API + HR_PERSON_ADDRESS_API.update_person_address(p_effective_date => l_date_from, + p_address_id => address_id, + p_date_from => l_date_from, + p_date_to => l_date_to, + p_object_version_number => l_object_version_number); + end if; +EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line(SUBSTR(SQLERRM,1,200)); + raise; +END delete_person_address_api ; + + +END OIM_EMPLOYEE_ADDRESS_WRAPPER; + +/ + diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_EMPLOYEE_ADDRESS_WRAPPER_APPS.pck b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_EMPLOYEE_ADDRESS_WRAPPER_APPS.pck new file mode 100644 index 0000000000..d93a4fe430 --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_EMPLOYEE_ADDRESS_WRAPPER_APPS.pck @@ -0,0 +1,181 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for CREATING synonym of procedures/packages and Tables required for HRMS +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +create or replace PACKAGE OIM_EMPLOYEE_ADDRESS_WRAPPER AUTHID CURRENT_USER AS + + PROCEDURE create_person_address_api (person_id IN number ,primary_flag IN varchar2 ,style IN varchar2 ,date_from IN date ,date_to IN date ,address_type IN varchar2 ,address_line1 IN varchar2 ,address_line2 IN varchar2 ,address_line3 IN varchar2 ,town_or_city IN varchar2 ,region_1 IN varchar2 ,region_2 IN varchar2 ,region_3 IN varchar2 ,postal_code IN varchar2 ,country IN varchar2 ,telephone_number_1 IN varchar2 ,telephone_number_2 IN varchar2 ,telephone_number_3 IN varchar2 ,address_id OUT number ,object_version_number OUT number ); + + PROCEDURE update_person_address_api ( address_id IN number,person_id IN number ,primary_flag IN varchar2 ,style IN varchar2 ,date_from IN date ,date_to IN date ,address_type IN varchar2 ,address_line1 IN varchar2 ,address_line2 IN varchar2 ,address_line3 IN varchar2 ,town_or_city IN varchar2 ,region_1 IN varchar2 ,region_2 IN varchar2 ,region_3 IN varchar2 ,postal_code IN varchar2 ,country IN varchar2 ,telephone_number_1 IN varchar2 ,telephone_number_2 IN varchar2 ,telephone_number_3 IN varchar2); + + PROCEDURE delete_person_address_api ( address_id IN number,date_from IN date); + +END OIM_EMPLOYEE_ADDRESS_WRAPPER; + + / + + create or replace PACKAGE BODY OIM_EMPLOYEE_ADDRESS_WRAPPER AS + + -------Procedure for create address for an employee -------- +procedure create_person_address_api +( + person_id IN number, + primary_flag IN varchar2, + style IN varchar2, + date_from IN date, + date_to IN date, + address_type IN varchar2, + address_line1 IN varchar2, + address_line2 IN varchar2, + address_line3 IN varchar2, + town_or_city IN varchar2, + region_1 IN varchar2, + region_2 IN varchar2, + region_3 IN varchar2, + postal_code IN varchar2, + country IN varchar2, + telephone_number_1 IN varchar2, + telephone_number_2 IN varchar2, + telephone_number_3 IN varchar2, + address_id OUT number, + object_version_number OUT number +) +is +BEGIN + -- Start of API + HR_PERSON_ADDRESS_API.CREATE_PERSON_ADDRESS( + p_effective_date => date_from, + P_person_id => person_id, + P_primary_flag => primary_flag, + P_style => style, + P_date_from => date_from, + P_date_to => date_to, + P_ADDRESS_TYPE => address_type, + P_address_line1 => address_line1, + P_address_line2 => address_line2, + P_address_line3 => address_line3, + P_town_or_city => town_or_city, + P_region_1 => region_1, + P_region_2 => region_2, + P_region_3 => region_3, + P_postal_code => postal_code, + P_country => country, + P_telephone_number_1 => telephone_number_1, + P_telephone_number_2 => telephone_number_2, + P_telephone_number_3 => telephone_number_3, + P_address_id => address_id, + P_object_version_number => object_version_number + ); + + EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line(SUBSTR(SQLERRM,1,200)); + raise; +END create_person_address_api ; + +PROCEDURE update_person_address_api +( + address_id IN number, + person_id IN number, + primary_flag IN varchar2, + style IN varchar2 , + date_from IN date , + date_to IN date , + address_type IN varchar2 , + address_line1 IN varchar2 , + address_line2 IN varchar2 , + address_line3 IN varchar2 , + town_or_city IN varchar2 , + region_1 IN varchar2 , + region_2 IN varchar2 , + region_3 IN varchar2 , + postal_code IN varchar2 , + country IN varchar2 , + telephone_number_1 IN varchar2 , + telephone_number_2 IN varchar2 , + telephone_number_3 IN varchar2 +) +IS + l_object_version_number per_addresses.object_version_number%type; + +BEGIN + SELECT MAX(object_version_number) into l_object_version_number FROM PER_ADDRESSES WHERE address_id = update_person_address_api.address_id; + + -- Start of API + HR_PERSON_ADDRESS_API.update_person_address( + p_effective_date => date_from, + p_address_id => address_id, + p_object_version_number => l_object_version_number, + p_date_from => date_from, + p_date_to => date_to, + p_primary_flag => primary_flag, + p_address_type => address_type, + P_address_line1 => address_line1, + p_address_line2 => address_line2, + p_address_line3 => address_line3, + p_town_or_city => town_or_city, + p_region_1 => region_1, + p_region_2 => region_2, + p_region_3 => region_3, + p_postal_code => postal_code, + p_country => country, + p_telephone_number_1 => telephone_number_1, + p_telephone_number_2 => telephone_number_2, + p_telephone_number_3 => telephone_number_3 +); + +EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line(SUBSTR(SQLERRM,1,200)); + raise; +END update_person_address_api ; + +PROCEDURE delete_person_address_api(address_id IN number, + date_from IN date +) +IS + l_date_to date; + l_date_from date; + l_object_version_number per_addresses.object_version_number%type; + +BEGIN + SELECT MAX(PER_ADDRESSES.date_to) into l_date_to FROM PER_ADDRESSES WHERE address_id = delete_person_address_api.address_id; + --End Date is already set, ignore + if l_date_to is null then + + l_date_to := SYSDATE; + + SELECT MAX(object_version_number) into l_object_version_number FROM PER_ADDRESSES WHERE address_id = delete_person_address_api.address_id; + IF date_from IS NOT NULL THEN + l_date_from := date_from; + ELSE + SELECT MAX(PER_ADDRESSES.date_from) into l_date_from FROM PER_ADDRESSES WHERE address_id = delete_person_address_api.address_id; + end if; + -- date_from should be always less than or equal to date_to + if l_date_from > l_date_to then + l_date_to := l_date_from; + end if; + -- Start of API + HR_PERSON_ADDRESS_API.update_person_address(p_effective_date => l_date_from, + p_address_id => address_id, + p_date_from => l_date_from, + p_date_to => l_date_to, + p_object_version_number => l_object_version_number); + end if; +EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line(SUBSTR(SQLERRM,1,200)); + raise; +END delete_person_address_api ; + + +END OIM_EMPLOYEE_ADDRESS_WRAPPER; + +/ + diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_EMPLOYEE_WRAPPER.pck b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_EMPLOYEE_WRAPPER.pck new file mode 100644 index 0000000000..29606bdaa2 --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_EMPLOYEE_WRAPPER.pck @@ -0,0 +1,1230 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for CREATING synonym of procedures/packages and Tables required for HRMS +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +create or replace PACKAGE OIM_EMPLOYEE_WRAPPER AS + + PROCEDURE create_person_api (hire_date IN date ,business_group_id IN number ,last_name IN varchar2 ,first_name IN varchar2 ,sex IN varchar2 ,person_type_id IN number , + employee_number IN OUT nocopy varchar2 ,person_id OUT nocopy number ,title IN varchar2 ,email_address IN varchar2 ,marital_status IN varchar2 , + nationality IN varchar2, national_identifier IN varchar2 ,date_of_birth IN date ,town_of_birth IN varchar2 ,region_of_birth IN varchar2 ,country_of_birth IN varchar2 ); + + PROCEDURE update_person_api (person_id IN number ,last_name IN varchar2 DEFAULT NULL ,first_name IN varchar2 DEFAULT NULL ,sex IN varchar2 ,person_type_id IN number DEFAULT NULL, + hire_date IN date DEFAULT NULL ,business_group_id IN number ,employee_number IN OUT nocopy varchar2 ,object_version_number IN OUT nocopy number , + title IN varchar2 ,email_address IN varchar2 ,marital_status IN varchar2 ,nationality IN varchar2 ,national_identifier IN varchar2 ,date_of_birth IN date , + town_of_birth IN varchar2 ,region_of_birth IN varchar2 ,country_of_birth IN varchar2 ); + + PROCEDURE delete_person_api ( person_id IN number ); + + PROCEDURE terminate_person_api (person_id IN number ); + + PROCEDURE rehire_ex_emp_api (person_id IN number ,hire_date IN date ); + + PROCEDURE create_person_assignment_api ( person_id IN number, asg_effective_start_date IN date, organization_id IN number, supervisor_id IN number, --assignment_number IN OUT varchar2, + change_reason IN varchar2, job_id IN number, grade_id IN number, assignment_id OUT number); + + PROCEDURE delete_person_assignment_api(assignment_id IN number,asg_effective_start_date IN date); + + PROCEDURE update_person_assignment_api( person_id IN number, assignment_id IN number,organization_id IN number,job_id IN number,grade_id IN number,supervisor_id IN number,change_reason IN varchar2,asg_effective_start_date IN date); + + END OIM_EMPLOYEE_WRAPPER; + + / + +create or replace PACKAGE BODY OIM_EMPLOYEE_WRAPPER AS + +procedure create_person_api(hire_date IN date, + business_group_id IN number, + last_name IN varchar2, + first_name IN varchar2, + sex IN varchar2, + person_type_id IN number, + employee_number IN OUT nocopy varchar2, + person_id OUT nocopy number, + title IN varchar2, + email_address IN varchar2, + marital_status IN varchar2, + nationality IN varchar2, + national_identifier IN varchar2, + date_of_birth IN date, + town_of_birth IN varchar2, + region_of_birth IN varchar2, + country_of_birth IN varchar2 ) +is + -- Declare cursors and local variables + l_full_name per_all_people_f.full_name%type; + l_assignment_id per_all_assignments_f.person_id%type; + l_effective_start_date per_all_people_f.effective_start_date%type; + l_effective_end_date per_all_people_f.effective_end_date%type; + l_per_object_version_number per_all_people_f.object_version_number%TYPE; + l_asg_object_version_number per_all_assignments_f.object_version_number%TYPE; + l_comment_id per_all_people_f.comment_id%type; + l_assignment_sequence per_all_assignments_f.assignment_sequence%type; + l_assignment_number per_all_assignments_f.assignment_number%type; + l_name_combination_warning boolean; + l_assign_payroll_warning boolean; + l_orig_hire_warning boolean; + sys_person_type per_person_types.system_person_type%type; + l_pdp_object_version_number NUMBER; + +BEGIN + -- Start of API + select system_person_type into sys_person_type from per_person_types where person_type_id=create_person_api.person_type_id; + if sys_person_type = 'EMP' then + + HR_EMPLOYEE_API.create_employee(p_hire_date => hire_date, + p_business_group_id => business_group_id, + p_last_name => last_name, + p_first_name => first_name, + p_sex => sex, + p_person_type_id => person_type_id, + p_employee_number => employee_number, + p_person_id => person_id, + p_full_name => l_full_name, + p_assignment_id => l_assignment_id, + p_assignment_sequence => l_assignment_sequence, + p_assignment_number => l_assignment_number, + p_per_object_version_number => l_per_object_version_number, + p_asg_object_version_number => l_asg_object_version_number, + p_per_effective_start_date => l_effective_start_date, + p_per_effective_end_date => l_effective_end_date, + p_per_comment_id => l_comment_id, + p_name_combination_warning => l_name_combination_warning, + p_assign_payroll_warning => l_assign_payroll_warning, + p_orig_hire_warning => l_orig_hire_warning, + p_title => title, + p_email_address => email_address, + p_marital_status => marital_status, + p_nationality => nationality, + p_national_identifier => national_identifier, + p_date_of_birth => date_of_birth, + p_town_of_birth => town_of_birth, + p_region_of_birth => region_of_birth, + p_country_of_birth => country_of_birth + + ); + elsif sys_person_type = 'CWK' then + + HR_CONTINGENT_WORKER_API.create_cwk(p_validate => FALSE, + p_start_date => hire_date, + p_business_group_id => business_group_id, + p_last_name => last_name, + p_first_name => first_name, + p_sex => sex, + p_person_type_id => person_type_id, + p_npw_number => employee_number, + p_person_id => person_id, + p_per_object_version_number => l_per_object_version_number, + p_per_effective_start_date => l_effective_start_date, + p_per_effective_end_date => l_effective_end_date, + p_pdp_object_version_number => l_pdp_object_version_number, + p_full_name => l_full_name, + p_comment_id => l_comment_id, + p_assignment_id => l_assignment_id, + p_asg_object_version_number => l_asg_object_version_number, + p_assignment_sequence => l_assignment_sequence, + p_assignment_number => l_assignment_number, + p_name_combination_warning => l_name_combination_warning, + p_title => title, + p_email_address => email_address, + p_marital_status => marital_status, + p_nationality => nationality, + p_national_identifier => national_identifier, + p_date_of_birth => date_of_birth, + p_town_of_birth => town_of_birth, + p_region_of_birth => region_of_birth, + p_country_of_birth => country_of_birth + ); + else + raise_application_error (-20001, 'Invalid person type'); + end if; + +EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line(SUBSTR(SQLERRM,1,100)); + raise; +END create_person_api; + +-------Procedure for updating an employee record-------- +procedure update_person_api( person_id IN number, + last_name IN varchar2 default null, + first_name IN varchar2 default null, + sex IN varchar2, + person_type_id IN number default null, + hire_date IN date default null, + business_group_id IN number, + employee_number IN OUT nocopy varchar2, + object_version_number IN OUT nocopy number, + title IN varchar2, + email_address IN varchar2, + marital_status IN varchar2, + nationality IN varchar2, + national_identifier IN varchar2, + date_of_birth IN date, + town_of_birth IN varchar2, + region_of_birth IN varchar2, + country_of_birth IN varchar2) +is + -- Declare cursors and local variables + l_effective_date date := TRUNC(sysdate); + l_object_version_number per_all_people_f.object_version_number%type; + l_employee_number per_all_people_f.employee_number%type; + l_npw_number per_all_people_f.npw_number%type; + l_emp_start_date per_all_people_f.effective_start_date%type; + l_cwk_start_date per_all_people_f.start_date%type; + l_datetrack_update_mode varchar2(10); + l_effective_start_date date; + l_effective_end_date date; + l_full_name per_all_people_f.full_name%type; + l_comment_id per_all_people_f.comment_id%type; + l_name_combination_warning boolean; + l_assign_payroll_warning boolean; + l_orig_hire_warning boolean; + l_hire_date date; + p_update_type varchar(10); + p_old_start_date date; + l_Err_Msg varchar(1000); + sys_person_type per_person_types.system_person_type%type; + + ---- + cursor cur_emp_ovn is + select employee_number, npw_number,object_version_number, effective_start_date + from per_all_people_f + where person_id = update_person_api.person_id + and business_group_id = update_person_api.business_group_id + and ((effective_start_date > trunc(sysdate)) OR trunc(sysdate) between effective_start_date and effective_end_date); +BEGIN + + ---Initialise local variables before call to hr_person_api.update_person + for rec IN cur_emp_ovn + loop + l_employee_number := rec.employee_number; + l_emp_start_date := rec.effective_start_Date; + l_npw_number := rec.npw_number; + + + end loop; + l_datetrack_update_mode := 'CORRECTION'; + select system_person_type into sys_person_type from per_person_types where person_type_id=update_person_api.person_type_id; + if sys_person_type = 'EMP' then + l_hire_date :=hire_date; + p_update_type := 'E'; + elsif sys_person_type = 'CWK' then + l_npw_number := employee_number; + employee_number := null; + l_hire_date := null; + p_update_type := 'C'; + end if; + if l_emp_start_date <> hire_date then + HR_CHANGE_START_DATE_API.Update_Start_Date(p_validate => FALSE, + p_person_id => person_id, + p_old_start_date => l_emp_start_date, + p_new_start_date => hire_date, + p_update_type => p_update_type, + p_applicant_number => NULL, + p_warn_ee => l_Err_Msg ); + end if; + + for rec IN cur_emp_ovn + loop + l_object_version_number := rec.object_version_number; + l_effective_date := rec.effective_start_Date; + end loop; + + -- Start of API + HR_PERSON_API.update_person(p_effective_date => l_effective_date, + p_datetrack_update_mode => l_datetrack_update_mode, + p_person_id => person_id, + p_last_name => last_name, + p_first_name => first_name, + p_sex => sex, + p_person_type_id => person_type_id, + p_original_date_of_hire => l_hire_date, + p_employee_number => employee_number, + p_npw_number => l_npw_number, + p_object_version_number => l_object_version_number, + p_effective_start_date => l_effective_start_date, + p_effective_end_date => l_effective_end_date, + p_full_name => l_full_name, + p_comment_id => l_comment_id, + p_name_combination_warning => l_name_combination_warning, + p_assign_payroll_warning => l_assign_payroll_warning, + p_orig_hire_warning => l_orig_hire_warning, + p_title => title, + p_email_address => email_address, + p_marital_status => marital_status, + p_nationality => nationality, + p_national_identifier => national_identifier, + p_date_of_birth => date_of_birth, + p_town_of_birth => town_of_birth, + p_region_of_birth => region_of_birth, + p_country_of_birth => country_of_birth); + + EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line(SUBSTR(SQLERRM,1,200)); + raise; +END update_person_api ; + + +-------Procedure for deleting an employee record-------- +procedure delete_person_api(person_id IN number) +is + -- Declare cursors and local variables + l_validate boolean; + l_effective_date date; + l_perform_predel_validation boolean; + l_person_org_manager_warning varchar2(10); +BEGIN + ---Initialise local variables before call to hr_person_api.delete_person + l_validate := FALSE; + l_effective_date := TRUNC(sysdate); + l_perform_predel_validation := FALSE; + + -- Start of API + HR_PERSON_API.delete_person(p_validate => l_validate, + p_effective_date => l_effective_date, + p_person_id => person_id, + p_perform_predel_validation => l_perform_predel_validation, + p_person_org_manager_warning => l_person_org_manager_warning + ); + + EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line(SUBSTR(SQLERRM,1,200)); + raise; +END delete_person_api ; + +-------Procedure for terminating an employee -------- +------ Private method to terminate contingent worker. This has to be defined before caller method +procedure terminate_cwk_api (person_id IN number) +is + l_terminate_cwk_flag varchar2(1) := 'N'; + l_terminate_msg varchar2(600); + l_le_terminate_cwk_exception exception; + l_effective_date date := trunc(sysdate); + l_termination_reason per_periods_of_placement.termination_reason%type; + l_person_type_id per_person_types.person_type_id%type; + l_period_of_service_id per_periods_of_placement.period_of_placement_id%type; + l_actual_termination_date per_periods_of_placement.actual_termination_date%type :=trunc(sysdate); + l_last_standard_process_date per_periods_of_placement.last_standard_process_date%type := trunc(sysdate); + l_object_version_number per_periods_of_placement.object_version_number%type; + l_start_date per_periods_of_placement.date_start%type; + l_notif_term_date date; + l_final_process_date per_periods_of_service.final_process_date%type; + l_supervisor_warning boolean := false; + l_event_warning boolean := false; + l_interview_warning boolean := false; + l_review_warning boolean := false; + l_recruiter_warning boolean := false; + l_asg_future_changes_warning boolean := false; + l_entries_changed_warning varchar2(300); + l_pay_proposal_warning boolean := false; + l_dod_warning boolean := false; + l_org_now_no_manager_warning boolean := false; +begin + begin + select pos.period_of_placement_id, pos.object_version_number, date_start into l_period_of_service_id, l_object_version_number, l_start_date + from per_periods_of_placement pos + where pos.person_id = terminate_cwk_api.person_id; + + exception + when others then + l_terminate_msg := 'Error while selecting cwk details : '||substr(sqlerrm,1,150); + raise l_le_terminate_cwk_exception; + end; + + begin + HR_CONTINGENT_WORKER_API.actual_termination_placement(p_validate => false, + p_effective_date => l_effective_date, + p_person_id => person_id, + p_date_start => l_start_date, + p_person_type_id => l_person_type_id, + p_actual_termination_date => l_actual_termination_date, + p_termination_reason => l_termination_reason, + p_object_version_number => l_object_version_number, + p_last_standard_process_date => l_last_standard_process_date, + p_supervisor_warning => l_supervisor_warning, + p_event_warning => l_event_warning, + p_interview_warning => l_interview_warning, + p_review_warning => l_review_warning, + p_recruiter_warning => l_recruiter_warning, + p_asg_future_changes_warning => l_asg_future_changes_warning, + p_entries_changed_warning => l_entries_changed_warning, + p_pay_proposal_warning => l_pay_proposal_warning, + p_dod_warning => l_dod_warning + ); + + if l_object_version_number is null then + l_terminate_cwk_flag := 'N'; + l_terminate_msg := 'Warning validating API: hr_contingent_worker_api.actual_termination_placement'; + raise l_le_terminate_cwk_exception; + end if; + + l_terminate_cwk_flag := 'Y'; + exception + when others then + l_terminate_msg := 'Error validating API: hr_contingent_worker_api.actual_termination_placement : '||substr(sqlerrm,1,150); + raise l_le_terminate_cwk_exception; + end; + + if l_terminate_cwk_flag = 'Y' then + begin + HR_CONTINGENT_WORKER_API.final_process_placement (p_validate => false, + p_person_id => person_id, + p_date_start => l_start_date, + p_object_version_number => l_object_version_number, + p_final_process_date => l_final_process_date, + p_org_now_no_manager_warning => l_org_now_no_manager_warning, + p_asg_future_changes_warning => l_asg_future_changes_warning, + p_entries_changed_warning => l_entries_changed_warning ); + exception + when others then + l_terminate_msg := 'Error validating API: hr_contingent_worker_api.final_process_placement : '||substr(sqlerrm,1,150); + raise l_le_terminate_cwk_exception; + end; + end if; + +end terminate_cwk_api; + + +-------Procedure for terminating an employee -------- +procedure terminate_person_api (person_id IN number) +is + -- Declare cursors and local variables + l_object_version_number number; + l_period_of_service_id number; + l_validate boolean; + l_supervisor_warning boolean; + l_event_warning boolean; + l_interview_warning boolean; + l_review_warning boolean; + l_recruiter_warning boolean; + l_asg_future_changes_warning boolean; + l_entries_changed_warning varchar2(30); + l_leaving_reasons varchar2(30); + l_org_now_no_manager_warning boolean; + l_pay_proposal_warning boolean; + l_dod_warning boolean; + l_last_working_date date; + l_actual_notice_period_date date; + l_effective_date date; + l_person_type_id number; + l_assignment_status_type_id number; + sys_person_type per_person_types.system_person_type%type; + +BEGIN + + select system_person_type into sys_person_type from per_person_types where person_type_id = (select person_type_id from PER_PERSON_TYPE_USAGES_F where person_id=terminate_person_api.person_id); + if sys_person_type = 'EMP' then + + ---Initialise local variables before call to hr_ex_employee_api.actual_termination_emp + l_last_working_date := TRUNC(sysdate); + l_actual_notice_period_date := TRUNC(sysdate); + l_effective_date := TRUNC(sysdate); + l_validate := FALSE; + + SELECT pps.period_of_service_id, pps.object_version_number INTO l_period_of_service_id,l_object_version_number + FROM per_periods_of_service pps WHERE pps.person_id = terminate_person_api.person_id AND pps.actual_termination_date is NULL; + + HR_EX_EMPLOYEE_API.actual_termination_emp( p_validate => l_validate, + p_effective_date => l_effective_date, + p_period_of_service_id => l_period_of_service_id, + p_object_version_number => l_object_version_number, + p_actual_termination_date => l_actual_notice_period_date, + p_last_standard_process_date => l_last_working_date, + p_person_type_id => l_person_type_id, + p_assignment_status_type_id => l_assignment_status_type_id, + p_leaving_reason => l_leaving_reasons, + p_supervisor_warning => l_supervisor_warning, + p_event_warning => l_event_warning, + p_interview_warning => l_interview_warning, + p_review_warning => l_review_warning, + p_recruiter_warning => l_recruiter_warning, + p_asg_future_changes_warning => l_asg_future_changes_warning, + p_entries_changed_warning => l_entries_changed_warning, + p_pay_proposal_warning => l_pay_proposal_warning, + p_dod_warning => l_dod_warning); + + HR_EX_EMPLOYEE_API.final_process_emp( p_validate => l_validate, + p_period_of_service_id => l_period_of_service_id, + p_object_version_number => l_object_version_number, + p_final_process_date => l_last_working_date, + p_org_now_no_manager_warning => l_org_now_no_manager_warning, + p_asg_future_changes_warning => l_asg_future_changes_warning, + p_entries_changed_warning => l_entries_changed_warning); + + elsif sys_person_type = 'CWK' then + terminate_cwk_api(person_id); + end if; + + EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line(SUBSTR(SQLERRM,1,200)); + raise; +END terminate_person_api; + +-------Procedure for re-hiring an ex-employee -------- +procedure rehire_ex_emp_api(person_id IN number, + hire_date IN date) +is + -- Declare cursors and local variables + l_validate boolean; + l_per_object_version_number number; + l_person_type_id number; + l_rehire_reason varchar2(10); + l_assignment_id number; + l_asg_object_version_number number; + l_hire_date date; + l_per_effective_start_date date; + l_per_effective_end_date date; + l_assignment_sequence number; + l_assignment_number varchar2(10); + l_assign_payroll_warning boolean; +BEGIN + ---Initialise local variables before call to hr_employee_api.re_hire_ex_employee + l_validate := FALSE; + SELECT MAX(object_version_number) into l_per_object_version_number FROM per_all_people_f WHERE person_id = rehire_ex_emp_api.person_id; + -- Start of API + HR_EMPLOYEE_API.re_hire_ex_employee( p_validate => l_validate, + p_hire_date => hire_date, + p_person_id => person_id, + p_per_object_version_number => l_per_object_version_number, + p_person_type_id => l_person_type_id, + p_rehire_reason => l_rehire_reason, + p_assignment_id => l_assignment_id, + p_asg_object_version_number => l_asg_object_version_number, + p_per_effective_start_date => l_per_effective_start_date, + p_per_effective_end_date => l_per_effective_end_date, + p_assignment_sequence => l_assignment_sequence, + p_assignment_number => l_assignment_number, + p_assign_payroll_warning => l_assign_payroll_warning); + + EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line(SUBSTR(SQLERRM,1,200)); + raise; +END rehire_ex_emp_api; + +procedure create_cwk_assignment( asg_effective_start_date in date, + person_id in number, + organization_id in number, + supervisor_id in number, + change_reason in varchar2, + job_id in number, + grade_id in number, + assignment_id out number) +IS + l_assignment_number varchar2(2000); + l_assignment_category varchar2(2000); + l_assignment_status_type_id number; + l_comments varchar2(2000); + l_default_code_comb_id number; + l_establishment_id number; + l_frequency varchar2(2000); + l_internal_address_line varchar2(2000); + l_labour_union_member_flag varchar2(2000); + l_location_id number; + l_manager_flag varchar2(2000); + l_normal_hours number; + l_position_id number; + l_project_title varchar2(2000); + l_set_of_books_id number; + l_source_type varchar2(2000); + l_time_normal_finish varchar2(2000); + l_time_normal_start varchar2(2000); + l_title varchar2(2000); + l_vendor_assignment_number varchar2(2000); + l_vendor_employee_number varchar2(2000); + l_vendor_id number; + l_vendor_site_id number; + l_po_header_id number; + l_po_line_id number; + l_projected_assignment_end date; + l_attribute_category varchar2(2000); + l_scl_concat_segments varchar2(2000); + l_pgp_concat_segments varchar2(2000); + l_supervisor_assignment_id number; + -- output variables + l_object_version_number number; + l_effective_start_date date; + l_effective_end_date date; + l_assignment_sequence number; + l_comment_id number; + l_people_group_id number; + l_people_group_name varchar2(2000); + l_other_manager_warning boolean; + l_hourly_salaried_warning boolean; + l_soft_coding_keyflex_id number; +BEGIN + -- Calling API HR_ASSIGNMENT_API.create_secondary_cwk_asg + HR_ASSIGNMENT_API.create_secondary_cwk_asg(p_validate => false + ,p_effective_date => asg_effective_start_date + ,p_business_group_id => organization_id + ,p_person_id => person_id + ,p_organization_id => organization_id + ,p_assignment_number => l_assignment_number + ,p_assignment_category => l_assignment_category + ,p_assignment_status_type_id => l_assignment_status_type_id + ,p_change_reason => change_reason + ,p_comments => l_comments + ,p_default_code_comb_id => l_default_code_comb_id + ,p_establishment_id => l_establishment_id + ,p_frequency => l_frequency + ,p_internal_address_line => l_internal_address_line + ,p_job_id => job_id + ,p_labour_union_member_flag => l_labour_union_member_flag + ,p_location_id => l_location_id + ,p_manager_flag => l_manager_flag + ,p_normal_hours => l_normal_hours + ,p_position_id => l_position_id + ,p_grade_id => grade_id + ,p_project_title => l_project_title + ,p_set_of_books_id => l_set_of_books_id + ,p_source_type => l_source_type + ,p_supervisor_id => supervisor_id + ,p_time_normal_finish => l_time_normal_finish + ,p_time_normal_start => l_time_normal_start + ,p_title => l_title + ,p_vendor_assignment_number => l_vendor_assignment_number + ,p_vendor_employee_number => l_vendor_employee_number + ,p_vendor_id => l_vendor_id + ,p_vendor_site_id => l_vendor_site_id + ,p_po_header_id => l_po_header_id + ,p_po_line_id => l_po_line_id + ,p_projected_assignment_end => l_projected_assignment_end + ,p_attribute_category => l_attribute_category + ,p_attribute1 => null + ,p_attribute2 => null + ,p_attribute3 => null + ,p_attribute4 => null + ,p_attribute5 => null + ,p_attribute6 => null + ,p_attribute7 => null + ,p_attribute8 => null + ,p_attribute9 => null + ,p_attribute10 => null + ,p_attribute11 => null + ,p_attribute12 => null + ,p_attribute13 => null + ,p_attribute14 => null + ,p_attribute15 => null + ,p_attribute16 => null + ,p_attribute17 => null + ,p_attribute18 => null + ,p_attribute19 => null + ,p_attribute20 => null + ,p_attribute21 => null + ,p_attribute22 => null + ,p_attribute23 => null + ,p_attribute24 => null + ,p_attribute25 => null + ,p_attribute26 => null + ,p_attribute27 => null + ,p_attribute28 => null + ,p_attribute29 => null + ,p_attribute30 => null + ,p_pgp_segment1 => null + ,p_pgp_segment2 => null + ,p_pgp_segment3 => null + ,p_pgp_segment4 => null + ,p_pgp_segment5 => null + ,p_pgp_segment6 => null + ,p_pgp_segment7 => null + ,p_pgp_segment8 => null + ,p_pgp_segment9 => null + ,p_pgp_segment10 => null + ,p_pgp_segment11 => null + ,p_pgp_segment12 => null + ,p_pgp_segment13 => null + ,p_pgp_segment14 => null + ,p_pgp_segment15 => null + ,p_pgp_segment16 => null + ,p_pgp_segment17 => null + ,p_pgp_segment18 => null + ,p_pgp_segment19 => null + ,p_pgp_segment20 => null + ,p_pgp_segment21 => null + ,p_pgp_segment22 => null + ,p_pgp_segment23 => null + ,p_pgp_segment24 => null + ,p_pgp_segment25 => null + ,p_pgp_segment26 => null + ,p_pgp_segment27 => null + ,p_pgp_segment28 => null + ,p_pgp_segment29 => null + ,p_pgp_segment30 => null + ,p_scl_segment1 => null + ,p_scl_segment2 => null + ,p_scl_segment3 => null + ,p_scl_segment4 => null + ,p_scl_segment5 => null + ,p_scl_segment6 => null + ,p_scl_segment7 => null + ,p_scl_segment8 => null + ,p_scl_segment9 => null + ,p_scl_segment10 => null + ,p_scl_segment11 => null + ,p_scl_segment12 => null + ,p_scl_segment13 => null + ,p_scl_segment14 => null + ,p_scl_segment15 => null + ,p_scl_segment16 => null + ,p_scl_segment17 => null + ,p_scl_segment18 => null + ,p_scl_segment19 => null + ,p_scl_segment20 => null + ,p_scl_segment21 => null + ,p_scl_segment22 => null + ,p_scl_segment23 => null + ,p_scl_segment24 => null + ,p_scl_segment25 => null + ,p_scl_segment26 => null + ,p_scl_segment27 => null + ,p_scl_segment28 => null + ,p_scl_segment29 => null + ,p_scl_segment30 => null + ,p_scl_concat_segments => l_scl_concat_segments + ,p_pgp_concat_segments => l_pgp_concat_segments + ,p_supervisor_assignment_id => l_supervisor_assignment_id + ,p_assignment_id => assignment_id + ,p_object_version_number => l_object_version_number + ,p_effective_start_date => l_effective_start_date + ,p_effective_end_date => l_effective_end_date + ,p_assignment_sequence => l_assignment_sequence + ,p_comment_id => l_comment_id + ,p_people_group_id => l_people_group_id + ,p_people_group_name => l_people_group_name + ,p_other_manager_warning => l_other_manager_warning + ,p_hourly_salaried_warning => l_hourly_salaried_warning + ,p_soft_coding_keyflex_id => l_soft_coding_keyflex_id); + exception when others then + dbms_output.put_line('error : ' || sqlerrm); + raise; +END create_cwk_assignment; + + +-------Procedure for assign an assignment to employee -------- +PROCEDURE create_person_assignment_api( person_id IN number, + asg_effective_start_date IN date, + organization_id IN number, + supervisor_id IN number, + change_reason IN varchar2, + job_id IN number, + grade_id IN number, + assignment_id OUT number) +IS + l_concatenated_segments hr_soft_coding_keyflex.concatenated_segments%type; + l_cagr_con_segments varchar2(2000); + l_group_name pay_people_groups.group_name%type; + l_object_version_number per_all_assignments_f.object_version_number%type; + l_assignment_number per_all_assignments_f.assignment_number%TYPE; + l_effective_start_date per_all_assignments_f.effective_start_date%type; + l_effective_end_date per_all_assignments_f.effective_end_date%type; + l_assignment_sequence per_all_assignments_f.assignment_sequence%type; + l_comment_id per_all_assignments_f.comment_id%type; + l_other_manager_warning boolean; + l_hourly_salaried_warning boolean; + l_gsp_post_process_warning varchar2(2000); + l_validate boolean; + l_cagr_grade_def_id per_cagr_grades_def.cagr_grade_def_id%type; + l_soft_coding_keyflex_id per_all_assignments_f.soft_coding_keyflex_id%type; + l_people_group_id number; + l_location_id number; + l_asg_primary_eff_start_date date; + l_asg_primary_eff_end_date date; + l_asg_primary_obj_version number; + l_asg_primary_id number; + validcount number; + valid_job_count number; + sys_person_type per_person_types.system_person_type%type; +BEGIN + + select location_id into l_location_id from HR_ALL_ORGANIZATION_UNITS where location_id is not null and organization_id = create_person_assignment_api.organization_id; + + IF create_person_assignment_api.grade_id IS NOT NULL THEN + select count(*) into validcount from PER_VALID_GRADES where business_group_id =create_person_assignment_api.organization_id + and job_id=create_person_assignment_api.job_id and grade_id=create_person_assignment_api.grade_id; + if validcount = 0 then + raise_application_error (-20001, 'Invalid combination of organization, job and grade'); + end if; + ELSE + select count(*) into valid_job_count from PER_JOBS where job_id = create_person_assignment_api.job_id; + if valid_job_count = 0 then + raise_application_error (-20001, 'Invalid combination of organization, job and grade'); + end if; + END IF; + + select system_person_type into sys_person_type from per_person_types where person_type_id = (select person_type_id from PER_PERSON_TYPE_USAGES_F where person_id=create_person_assignment_api.person_id); + if sys_person_type = 'EMP' then + -- Start of API + -- CREATING SECONDARY ASSIGNMENT WHICH IS NOT A PRIMARY YET + HR_ASSIGNMENT_API.create_secondary_emp_asg(p_effective_date => asg_effective_start_date, + p_person_id => person_id, + p_organization_id => organization_id, + p_supervisor_id => supervisor_id, + p_assignment_number => l_assignment_number, + p_change_reason => change_reason, + p_location_id => l_location_id, + p_group_name => l_group_name, + p_job_id => job_id, + p_grade_id => grade_id, + p_concatenated_segments => l_concatenated_segments, + p_cagr_grade_def_id => l_cagr_grade_def_id, + p_cagr_concatenated_segments => l_cagr_con_segments, + p_assignment_id => assignment_id, + p_soft_coding_keyflex_id => l_soft_coding_keyflex_id, + p_object_version_number => l_object_version_number, + p_effective_start_date => l_effective_start_date, + p_effective_end_date => l_effective_end_date, + p_assignment_sequence => l_assignment_sequence, + p_comment_id => l_comment_id, + p_other_manager_warning => l_other_manager_warning, + p_hourly_salaried_warning => l_hourly_salaried_warning, + p_gsp_post_process_warning => l_gsp_post_process_warning, + p_people_group_id => l_people_group_id); + + elsif sys_person_type = 'CWK' then + if grade_id is not null then + raise_application_error (-20001, 'Grade Id is can not be assigned to Contingent Worker'); + end if; + create_cwk_assignment(asg_effective_start_date,person_id,organization_id,supervisor_id,change_reason,job_id,grade_id,assignment_id); + end if; + + EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line(SUBSTR(SQLERRM,1,200)); + raise; +END create_person_assignment_api ; + +-------Procedure for delete assignment of employee -------- +procedure delete_person_assignment_api(assignment_id IN number, + asg_effective_start_date IN date) +is + l_validate boolean; + l_datetrack_mode VARCHAR2(100); + l_effective_date date; + l_object_version_number number; + l_effective_start_date per_all_assignments_f.effective_start_date%type; + l_effective_end_date per_all_assignments_f.effective_end_date%type; + l_loc_change_tax_issues boolean; + l_delete_asg_budgets boolean; + l_org_now_no_manager_warning boolean; + l_element_salary_warning boolean; + l_element_entries_warning boolean; + l_spp_warning boolean; + l_cost_warning boolean; + l_life_events_exists boolean; + l_cobra_coverage_elements boolean; + l_assgt_term_elements boolean; + +begin + + l_validate := false; + l_datetrack_mode := 'ZAP'; + l_effective_date := asg_effective_start_date; + + SELECT MAX(object_version_number) into l_object_version_number FROM PER_ALL_ASSIGNMENTS_F WHERE assignment_id = delete_person_assignment_api.assignment_id; + if l_effective_date is null then + select EFFECTIVE_START_DATE into l_effective_date from PER_ALL_ASSIGNMENTS_F where assignment_id = delete_person_assignment_api.assignment_id and job_id is not null AND ((EFFECTIVE_START_DATE >= TRUNC(sysdate)) OR (TRUNC(sysdate) BETWEEN EFFECTIVE_START_DATE AND EFFECTIVE_END_DATE) ); + end if; + -- start of api + HR_ASSIGNMENT_API.delete_assignment( p_validate => l_validate, + p_effective_date => l_effective_date, + p_datetrack_mode => l_datetrack_mode, + p_assignment_id => assignment_id, + p_object_version_number => l_object_version_number, + p_effective_start_date => l_effective_start_date, + p_effective_end_date => l_effective_end_date, + p_loc_change_tax_issues => l_loc_change_tax_issues, + p_delete_asg_budgets => l_delete_asg_budgets, + p_org_now_no_manager_warning => l_org_now_no_manager_warning, + p_element_salary_warning => l_element_salary_warning, + p_element_entries_warning => l_element_entries_warning, + p_spp_warning => l_spp_warning, + p_cost_warning => l_cost_warning, + p_life_events_exists => l_life_events_exists, + p_cobra_coverage_elements => l_cobra_coverage_elements, + p_assgt_term_elements => l_assgt_term_elements); + +exception + when others then + dbms_output.put_line(substr(sqlerrm,1,200)); + raise; +end delete_person_assignment_api ; + +procedure update_cwk_assignment( assignment_id IN number, + organization_id IN number, + job_id IN number, + grade_id IN number, + supervisor_id IN number, + change_reason IN varchar2, + asg_effective_start_date IN date) +IS + l_position_id number; + l_special_ceiling_step_id number; + l_group_name varchar2(1000); + l_effective_start_date date; + l_effective_end_date date; + l_org_now_no_manager_warning boolean; + l_people_group_id number; + l_obj_version number; + l_assignment_category varchar2(2000); + l_assignment_number varchar2(2000); + l_change_reason varchar2(2000); + l_comments varchar2(2000); + l_default_code_comb_id number; + l_establishment_id number; + l_frequency varchar2(2000); + l_internal_address_line varchar2(2000); + l_labour_union_member_flag varchar2(2000); + l_manager_flag varchar2(2000); + l_normal_hours number; + l_project_title varchar2(2000); + l_set_of_books_id number; + l_source_type varchar2(2000); + l_supervisor_id number; + l_time_normal_finish varchar2(2000); + l_time_normal_start varchar2(2000); + l_title varchar2(2000); + l_vendor_assignment_number varchar2(2000); + l_vendor_employee_number varchar2(2000); + l_vendor_id number; + l_vendor_site_id number; + l_po_header_id number; + l_po_line_id number; + l_projected_assignment_end date; + l_assignment_status_type_id number; + l_concat_segments varchar2(2000); + l_attribute_category varchar2(2000); + l_supervisor_assignment_id number; + l_comment_id number; + l_no_managers_warning boolean; + l_other_manager_warning boolean; + l_soft_coding_keyflex_id number; + l_concatenated_segments varchar2(2000); + l_hourly_salaried_warning boolean; + l_called_from_mass_update boolean; + l_pay_basis_id number; + l_people_group_name varchar2(2000); + l_spp_delete_warning boolean; + l_entries_changed_warning varchar2(2000); + l_tax_district_changed_warning boolean; + l_location_id number; + l_datetrack_update_mode varchar2(100); + +BEGIN + l_datetrack_update_mode := 'CORRECTION'; + + -- Calling API HR_ASSIGNMENT_API.CREATE_SECONDARY_CWK_ASG + SELECT MAX(object_version_number) into l_obj_version FROM PER_ALL_ASSIGNMENTS_F WHERE ASSIGNMENT_ID = update_cwk_assignment.assignment_id; + + select location_id into l_location_id from HR_ALL_ORGANIZATION_UNITS where location_id is not null and organization_id = update_cwk_assignment.organization_id; + HR_ASSIGNMENT_API.update_cwk_asg_criteria(p_validate => FALSE, + p_effective_date => asg_effective_start_date, + p_datetrack_update_mode => l_datetrack_update_mode, + p_assignment_id => assignment_id, + p_called_from_mass_update => l_called_from_mass_update, + p_object_version_number => l_obj_version, + p_grade_id => grade_id, + p_position_id => l_position_id, + p_job_id => job_id, + p_location_id => l_location_id, + p_organization_id => organization_id, + p_pay_basis_id => l_pay_basis_id, + p_segment1 => null, + p_segment2 => null, + p_segment3 => null, + p_segment4 => null, + p_segment5 => null, + p_segment6 => null, + p_segment7 => null, + p_segment8 => null, + p_segment9 => null, + p_segment10 => null, + p_segment11 => null, + p_segment12 => null, + p_segment13 => null, + p_segment14 => null, + p_segment15 => null, + p_segment16 => null, + p_segment17 => null, + p_segment18 => null, + p_segment19 => null, + p_segment20 => null, + p_segment21 => null, + p_segment22 => null, + p_segment23 => null, + p_segment24 => null, + p_segment25 => null, + p_segment26 => null, + p_segment27 => null, + p_segment28 => null, + p_segment29 => null, + p_segment30 => null, + p_concat_segments => l_concat_segments, + p_people_group_name => l_people_group_name, + p_effective_start_date => l_effective_start_date, + p_effective_end_date => l_effective_end_date, + p_people_group_id => l_people_group_id, + p_org_now_no_manager_warning => l_org_now_no_manager_warning, + p_other_manager_warning => l_other_manager_warning, + p_spp_delete_warning => l_spp_delete_warning, + p_entries_changed_warning => l_entries_changed_warning, + p_tax_district_changed_warning => l_tax_district_changed_warning); + + HR_ASSIGNMENT_API.UPDATE_CWK_ASG( p_validate => false, + p_effective_date => asg_effective_start_date, + p_datetrack_update_mode => l_datetrack_update_mode, + p_assignment_id => assignment_id, + p_object_version_number => l_obj_version, + p_assignment_category => l_assignment_category, + p_assignment_number => l_assignment_number, + p_change_reason => change_reason, + p_comments => l_comments, + p_default_code_comb_id => l_default_code_comb_id, + p_establishment_id => l_establishment_id, + p_frequency => l_frequency, + p_internal_address_line => l_internal_address_line, + p_labour_union_member_flag => l_labour_union_member_flag, + p_manager_flag => l_manager_flag, + p_normal_hours => l_normal_hours, + p_project_title => l_project_title, + p_set_of_books_id => l_set_of_books_id, + p_source_type => l_source_type, + p_supervisor_id => supervisor_id, + p_time_normal_finish => l_time_normal_finish, + p_time_normal_start => l_time_normal_start, + p_title => l_title, + p_vendor_assignment_number => l_vendor_assignment_number, + p_vendor_employee_number => l_vendor_employee_number, + p_vendor_id => l_vendor_id, + p_vendor_site_id => l_vendor_site_id, + p_po_header_id => l_po_header_id, + p_po_line_id => l_po_line_id, + p_projected_assignment_end => l_projected_assignment_end, + p_assignment_status_type_id => hr_api.g_number, + p_concat_segments => l_concat_segments, + p_attribute_category => l_attribute_category, + p_attribute1 => null, + p_attribute2 => null, + p_attribute3 => null, + p_attribute4 => null, + p_attribute5 => null, + p_attribute6 => null, + p_attribute7 => null, + p_attribute8 => null, + p_attribute9 => null, + p_attribute10 => null, + p_attribute11 => null, + p_attribute12 => null, + p_attribute13 => null, + p_attribute14 => null, + p_attribute15 => null, + p_attribute16 => null, + p_attribute17 => null, + p_attribute18 => null, + p_attribute19 => null, + p_attribute20 => null, + p_attribute21 => null, + p_attribute22 => null, + p_attribute23 => null, + p_attribute24 => null, + p_attribute25 => null, + p_attribute26 => null, + p_attribute27 => null, + p_attribute28 => null, + p_attribute29 => null, + p_attribute30 => null, + p_scl_segment1 => null, + p_scl_segment2 => null, + p_scl_segment3 => null, + p_scl_segment4 => null, + p_scl_segment5 => null, + p_scl_segment6 => null, + p_scl_segment7 => null, + p_scl_segment8 => null, + p_scl_segment9 => null, + p_scl_segment10 => null, + p_scl_segment11 => null, + p_scl_segment12 => null, + p_scl_segment13 => null, + p_scl_segment14 => null, + p_scl_segment15 => null, + p_scl_segment16 => null, + p_scl_segment17 => null, + p_scl_segment18 => null, + p_scl_segment19 => null, + p_scl_segment20 => null, + p_scl_segment21 => null, + p_scl_segment22 => null, + p_scl_segment23 => null, + p_scl_segment24 => null, + p_scl_segment25 => null, + p_scl_segment26 => null, + p_scl_segment27 => null, + p_scl_segment28 => null, + p_scl_segment29 => null, + p_scl_segment30 => null, + p_supervisor_assignment_id => l_supervisor_assignment_id, + p_org_now_no_manager_warning => l_org_now_no_manager_warning, + p_effective_start_date => l_effective_start_date, + p_effective_end_date => l_effective_end_date, + p_comment_id => l_comment_id, + p_no_managers_warning => l_no_managers_warning, + p_other_manager_warning => l_other_manager_warning, + p_soft_coding_keyflex_id => l_soft_coding_keyflex_id, + p_concatenated_segments => l_concatenated_segments, + p_hourly_salaried_warning => l_hourly_salaried_warning); +exception when others then + dbms_output.put_line('error : ' || sqlerrm); + raise; +END update_cwk_assignment; + + +PROCEDURE update_person_assignment_api( person_id IN number, + assignment_id IN number, + organization_id IN number, + job_id IN number, + grade_id IN number, + supervisor_id IN number, + change_reason IN varchar2, + asg_effective_start_date IN date +) +IS + l_validate boolean; + l_datetrack_update_mode VARCHAR2(100); + l_obj_version number; + l_assignment_number VARCHAR2(100); + l_concatenated_segments VARCHAR2(100); + l_cagr_concatenated_segments varchar2(2000); + l_comment_id number; + l_effective_start_date date; + l_effective_end_date date; + l_other_manager_warning boolean; + l_hourly_salaried_warning boolean; + l_no_managers_warning boolean; + l_gsp_post_process_warning varchar2(100); + l_assignment_status_type_id per_assignment_status_types.assignment_status_type_id%TYPE; + l_soft_coding_keyflex_id number; + l_cagr_grade_def_id number; + l_default_code_comb_id number; + l_set_of_books_id number; + l_normal_hours number; + l_probation_period number; + l_date_probation_end date; + l_probation_unit varchar2(100); + l_frequency varchar2(4); + l_bargaining_unit_code varchar2(4); + l_contract_id number; + l_special_ceiling_step_id number; + l_people_group_id number; + l_soft_coding_keyflex_cri_id number; + l_group_name varchar2(100); + l_cri_effective_start_date date; + l_cri_effective_end_date date; + l_org_now_no_manager_warning boolean; + l_cri_other_manager_warning boolean; + l_spp_delete_warning boolean; + l_entries_changed_warning varchar2(100); + l_tax_district_changed_warning boolean; + l_cri_concatenated_segments varchar2(100); + l_cri_gsp_post_process_warning varchar2(100); + l_location_id number; + sys_person_type per_person_types.system_person_type%type; + effective_date_to_compare date; +BEGIN + l_validate := false; + l_datetrack_update_mode := 'CORRECTION'; + + select EFFECTIVE_START_DATE into effective_date_to_compare from PER_ALL_ASSIGNMENTS_F where assignment_id = update_person_assignment_api.assignment_id and job_id is not null AND ((EFFECTIVE_START_DATE >= TRUNC(sysdate)) OR (TRUNC(SYSDATE) BETWEEN EFFECTIVE_START_DATE AND EFFECTIVE_END_DATE) ); + + if TRUNC(asg_effective_start_date) <> TRUNC (effective_date_to_compare) then + raise_application_error (-20001, 'Can not update assignment start date'); + end if; + + SELECT MAX(object_version_number) into l_obj_version FROM PER_ALL_ASSIGNMENTS_F WHERE ASSIGNMENT_ID = update_person_assignment_api.assignment_id; + + select location_id into l_location_id from HR_ALL_ORGANIZATION_UNITS where location_id is not null and organization_id = update_person_assignment_api.organization_id; + select system_person_type into sys_person_type from per_person_types where person_type_id = (select person_type_id from PER_PERSON_TYPE_USAGES_F where person_id=update_person_assignment_api.person_id); + if sys_person_type ='EMP' then + + HR_ASSIGNMENT_API.update_emp_asg_criteria (p_effective_date => asg_effective_start_date, + p_datetrack_update_mode => l_datetrack_update_mode, + p_assignment_id => assignment_id, + p_validate => l_validate, + p_grade_id => grade_id, + p_job_id => job_id, + p_organization_id => organization_id, + p_location_id => l_location_id, + p_object_version_number => l_obj_version, + p_special_ceiling_step_id => l_special_ceiling_step_id, + p_people_group_id => l_people_group_id, + p_soft_coding_keyflex_id => l_soft_coding_keyflex_cri_id, + p_group_name => l_group_name, + p_effective_start_date => l_cri_effective_start_date, + p_effective_end_date => l_cri_effective_end_date, + p_org_now_no_manager_warning => l_org_now_no_manager_warning, + p_other_manager_warning => l_cri_other_manager_warning, + p_spp_delete_warning => l_spp_delete_warning, + p_entries_changed_warning => l_entries_changed_warning, + p_tax_district_changed_warning => l_tax_district_changed_warning, + p_concatenated_segments => l_cri_concatenated_segments, + p_gsp_post_process_warning => l_cri_gsp_post_process_warning); + + + HR_ASSIGNMENT_API.update_emp_asg ( p_validate => l_validate, + p_effective_date => asg_effective_start_date, + p_datetrack_update_mode => l_datetrack_update_mode, + p_assignment_id => assignment_id, + p_object_version_number => l_obj_version, + p_supervisor_id => supervisor_id, + p_assignment_number => l_assignment_number, + p_change_reason => change_reason, + p_comments => NULL, + p_date_probation_end => l_date_probation_end, + p_default_code_comb_id => l_default_code_comb_id, + p_frequency => l_frequency, + p_internal_address_line => NULL, + p_manager_flag => NULL, + p_normal_hours => l_normal_hours, + p_perf_review_period => NULL, + p_perf_review_period_frequency => NULL, + p_probation_period => l_probation_period, + p_probation_unit => l_probation_unit, + p_projected_assignment_end => NULL, + p_sal_review_period => NULL, + p_sal_review_period_frequency => NULL, + p_set_of_books_id => l_set_of_books_id, + p_source_type => NULL, + p_time_normal_finish => NULL, + p_time_normal_start => NULL, + p_bargaining_unit_code => l_bargaining_unit_code, + p_cagr_grade_def_id => l_cagr_grade_def_id, + p_soft_coding_keyflex_id => l_soft_coding_keyflex_id, + p_cagr_concatenated_segments => l_cagr_concatenated_segments, + p_concatenated_segments => l_concatenated_segments, + p_comment_id => l_comment_id, + p_effective_start_date => l_effective_start_date, + p_effective_end_date => l_effective_end_date, + p_no_managers_warning => l_no_managers_warning, + p_other_manager_warning => l_other_manager_warning, + p_hourly_salaried_warning => l_hourly_salaried_warning, + p_gsp_post_process_warning => l_gsp_post_process_warning); + elsif sys_person_type = 'CWK' then + update_cwk_assignment(assignment_id,organization_id,job_id,grade_id,supervisor_id,change_reason,asg_effective_start_date ); + end if; + + EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line(SUBSTR(SQLERRM,1,200)); + raise; +END update_person_assignment_api; + +END OIM_EMPLOYEE_WRAPPER; +/ diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_FND_GLOBAL.pck b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_FND_GLOBAL.pck new file mode 100644 index 0000000000..23791f35f0 --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_FND_GLOBAL.pck @@ -0,0 +1,67 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for CREATING synonym of procedures/packages and Tables required for HRMS +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +create or replace package OIM_FND_GLOBAL is + +-- Public function and procedure declarations + +---------------------------------------------------------------------- +-- +-- APPS_INITIALIZE - Setup PL/SQL security context +-- +-- This procedure may be called to initialize the global security +-- context for a database session. This should only be done when +-- the session is established outside of a normal forms or +-- concurrent program connection. +-- +-- IN +-- FND User ID +-- FND Responsibility ID (two part key, resp_id / resp_appl_id) +-- FND Security Group ID +-- +procedure APPS_INITIALIZE( + user_id in number, + resp_id in number, + resp_appl_id in number, + security_group_id in number default 0, + server_id in number default -1); + +end OIM_FND_GLOBAL; +/ +create or replace package body OIM_FND_GLOBAL is + +---------------------------------------------------------------------- +-- This procedure may be called to initialize the global security +-- context for a database session. This should only be done when +-- the session is established outside of a normal forms or +-- concurrent program connection. +-- +-- IN +-- FND User ID +-- FND Responsibility ID (two part key, resp_id / resp_appl_id) +-- FND Security Group ID +-- +procedure APPS_INITIALIZE( + user_id in number, + resp_id in number, + resp_appl_id in number, + security_group_id in number default 0, + server_id in number default -1) is +begin + FND_GLOBAL.APPS_INITIALIZE( + user_id , + resp_id , + resp_appl_id , + security_group_id , + server_id); +end APPS_INITIALIZE; + +end OIM_FND_GLOBAL; +/ diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_TYPES.pck b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_TYPES.pck new file mode 100644 index 0000000000..f8978f193c --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OIM_TYPES.pck @@ -0,0 +1,46 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for CREATING synonym of procedures/packages and Tables required for HRMS +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +declare objexist number; +begin + select count(*) into objexist from user_types where type_name='ATTRIBUTEINFO'; + if objexist = 0 then + execute immediate 'create or replace TYPE attributeinfo AS OBJECT (attName VARCHAR2 ( 100 ), attType VARCHAR2 ( 100 ), creatable INTEGER , updatable INTEGER , required INTEGER , readable INTEGER)' ; + end if; +end; +/ + +declare objexist number; +begin + select count(*) into objexist from user_types where type_name='ATTRIBUTELIST'; + if objexist = 0 then + execute immediate 'create or replace type attributelist is varray(100) of attributeinfo' ; + end if; +end; +/ + +declare objexist number; +begin + select count(*) into objexist from user_types where type_name='SCHEMA_OBJECT'; + if objexist = 0 then + execute immediate 'create or replace TYPE schema_object AS OBJECT ( schemaname VARCHAR2 ( 100 ), attr attributelist)' ; + end if; +end; +/ + +declare objexist number; +begin + select count(*) into objexist from user_types where type_name='SCHEMALIST'; + if objexist = 0 then + execute immediate 'create or replace type schemalist is varray(50) of schema_object' ; + end if; +end; +/ + diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSAppstablesSynonyms.sql b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSAppstablesSynonyms.sql new file mode 100644 index 0000000000..002c29f5dd --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSAppstablesSynonyms.sql @@ -0,0 +1,82 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for CREATING synonym of procedures/packages and Tables required for HRMS +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +prompt Connecting &USERNAME; +accept Databasename prompt"Enter the name of the database ::"; +connect &USERNAME/&USERPWD@&Databasename; + +prompt create or replace synonym PER_PEOPLE_F for APPS.PER_PEOPLE_F; +create or replace synonym PER_PEOPLE_F for APPS.PER_PEOPLE_F; + +prompt create or replace synonym PER_ALL_ASSIGNMENTS_F for APPS.PER_ALL_ASSIGNMENTS_F; +create or replace synonym PER_ALL_ASSIGNMENTS_F for APPS.PER_ALL_ASSIGNMENTS_F; + +prompt create or replace synonym PER_PERIODS_OF_SERVICE for APPS.PER_PERIODS_OF_SERVICE; +create or replace synonym PER_PERIODS_OF_SERVICE for APPS.PER_PERIODS_OF_SERVICE; + +prompt create or replace synonym PER_PERIODS_OF_PLACEMENT for APPS.PER_PERIODS_OF_PLACEMENT; +create or replace synonym PER_PERIODS_OF_PLACEMENT for APPS.PER_PERIODS_OF_PLACEMENT; + +prompt create or replace synonym HR_EMPLOYEE_API for APPS.HR_EMPLOYEE_API; +create or replace synonym HR_EMPLOYEE_API for APPS.HR_EMPLOYEE_API; + +prompt create or replace synonym HR_PERSON_API for APPS.HR_PERSON_API; +create or replace synonym HR_PERSON_API for APPS.HR_PERSON_API; + +prompt create or replace synonym HR_CHANGE_START_DATE_API for APPS.HR_CHANGE_START_DATE_API; +create or replace synonym HR_CHANGE_START_DATE_API for APPS.HR_CHANGE_START_DATE_API; + +prompt create or replace synonym PER_ADDRESSES for APPS.PER_ADDRESSES; +create or replace synonym PER_ADDRESSES for APPS.PER_ADDRESSES; + +prompt create or replace synonym PER_PERSON_TYPE_USAGES_F for APPS.PER_PERSON_TYPE_USAGES_F; +create or replace synonym PER_PERSON_TYPE_USAGES_F for APPS.PER_PERSON_TYPE_USAGES_F; + + +prompt create or replace synonym PER_ALL_PEOPLE_F for APPS.PER_ALL_PEOPLE_F; +create or replace synonym PER_ALL_PEOPLE_F for APPS.PER_ALL_PEOPLE_F; + +prompt create or replace synonym PER_JOBS for APPS.PER_JOBS; +create or replace synonym PER_JOBS for APPS.PER_JOBS; + +prompt create or replace synonym PER_GRADES for APPS.PER_GRADES; +create or replace synonym PER_GRADES for APPS.PER_GRADES; + +prompt create or replace synonym HR_ALL_ORGANIZATION_UNITS for APPS.HR_ALL_ORGANIZATION_UNITS; +create or replace synonym HR_ALL_ORGANIZATION_UNITS for APPS.HR_ALL_ORGANIZATION_UNITS; + +prompt create or replace synonym HR_PERSON_ADDRESS_API for APPS.HR_PERSON_ADDRESS_API; +create or replace synonym HR_PERSON_ADDRESS_API for APPS.HR_PERSON_ADDRESS_API; + +prompt create or replace synonym HR_CONTINGENT_WORKER_API for APPS.HR_CONTINGENT_WORKER_API; +create or replace synonym HR_CONTINGENT_WORKER_API for APPS.HR_CONTINGENT_WORKER_API; + +prompt create or replace synonym HR_ASSIGNMENT_API for APPS.HR_ASSIGNMENT_API; +create or replace synonym HR_ASSIGNMENT_API for APPS.HR_ASSIGNMENT_API; + +prompt create or replace synonym HR_PERSON_ADDRESS_BK1 for APPS.HR_PERSON_ADDRESS_BK1; +create or replace synonym HR_PERSON_ADDRESS_BK1 for APPS.HR_PERSON_ADDRESS_BK1; + +prompt create or replace synonym hr_api for APPS.hr_api; +create or replace synonym hr_api for APPS.hr_api; + + +prompt create or replace synonym HZ_PARTIES for APPS.HZ_PARTIES; +create or replace synonym HZ_PARTIES for APPS.HZ_PARTIES; + +prompt create or replace synonym PER_PERSON_TYPES for APPS.PER_PERSON_TYPES; +create or replace synonym PER_PERSON_TYPES for APPS.PER_PERSON_TYPES; + +prompt create or replace synonym PER_VALID_GRADES for APPS.PER_VALID_GRADES; +create or replace synonym PER_VALID_GRADES for APPS.PER_VALID_GRADES; + +prompt create or replace synonym FND_LOOKUP_VALUES_VL for APPS.FND_LOOKUP_VALUES_VL; +create or replace synonym FND_LOOKUP_VALUES_VL for APPS.FND_LOOKUP_VALUES_VL; + diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSUser.sql b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSUser.sql new file mode 100644 index 0000000000..00e403b6ed --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSUser.sql @@ -0,0 +1,22 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for Creating: Database User & for Granting basic privileges, like: Connect, Create synonym & alter procedure +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +Accept USERNAME prompt"Enter New database Username to be created::" +Accept USERPWD prompt"Enter the New user password::" hide +CREATE USER &USERNAME identified by &USERPWD; +alter user &USERNAME enable editions; +prompt grant connect, resource to &USERNAME; +grant connect, resource to &USERNAME; + +prompt grant create synonym to &USERNAME; +grant create synonym to &USERNAME; + +prompt grant alter any procedure to &USERNAME; +grant alter any procedure to &USERNAME; diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSUserAD_ZDGrants.sql b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSUserAD_ZDGrants.sql new file mode 100644 index 0000000000..3396edde54 --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSUserAD_ZDGrants.sql @@ -0,0 +1,122 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for EXECUTE Grant on procedures/packages and Tables required for HRMS +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +---- EXECUTE Grant on procedures/packages required for OIM database USER ---- + +prompt exec AD_ZD.grant_privs('EXECUTE','HR_EMPLOYEE_API','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','HR_EMPLOYEE_API','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','HR_PERSON_API','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','HR_PERSON_API','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','HR_CHANGE_START_DATE_API','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','HR_CHANGE_START_DATE_API','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','HR_PERSON_ADDRESS_API','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','HR_PERSON_ADDRESS_API','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','HR_PERSON_ADDRESS_BK1','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','HR_PERSON_ADDRESS_BK1','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','HR_API','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','HR_API','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','HR_CONTINGENT_WORKER_API','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','HR_CONTINGENT_WORKER_API','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','HR_ASSIGNMENT_API','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','HR_ASSIGNMENT_API','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','FND_GLOBAL','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','FND_GLOBAL','&USERNAME'); + +---- SELECT Grant on tables required for OIM database USER ---- + +prompt exec AD_ZD.grant_privs('SELECT','PER_ALL_ASSIGNMENTS_F','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','PER_ALL_ASSIGNMENTS_F','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','PER_ALL_ASSIGNMENTS_F','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','PER_ALL_ASSIGNMENTS_F','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','PER_PEOPLE_F','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','PER_PEOPLE_F','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','PER_PEOPLE_F','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','PER_PEOPLE_F','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','PER_PERSON_TYPES','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','PER_PERSON_TYPES','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','PER_PERSON_TYPES','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','PER_PERSON_TYPES','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','PER_PERIODS_OF_SERVICE','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','PER_PERIODS_OF_SERVICE','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','PER_PERIODS_OF_SERVICE','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','PER_PERIODS_OF_SERVICE','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','PER_PERIODS_OF_PLACEMENT','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','PER_PERIODS_OF_PLACEMENT','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','PER_PERIODS_OF_PLACEMENT','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','PER_PERIODS_OF_PLACEMENT','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','PER_ADDRESSES','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','PER_ADDRESSES','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','PER_ADDRESSES','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','PER_ADDRESSES','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','PER_PERSON_TYPE_USAGES_F','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','PER_PERSON_TYPE_USAGES_F','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','PER_PERSON_TYPE_USAGES_F','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','PER_PERSON_TYPE_USAGES_F','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','PER_ALL_PEOPLE_F','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','PER_ALL_PEOPLE_F','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','PER_ALL_PEOPLE_F','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','PER_ALL_PEOPLE_F','&USERNAME'); + + +-- Grant execute privileges to the wrapper packages created in APPS schema + +prompt exec AD_ZD.grant_privs('EXECUTE','OIM_EMPLOYEE_WRAPPER','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','OIM_EMPLOYEE_WRAPPER','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','OIM_EMPLOYEE_ADDRESS_WRAPPER','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','OIM_EMPLOYEE_ADDRESS_WRAPPER','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','HZ_PARTIES','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','HZ_PARTIES','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','HZ_PARTIES','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','HZ_PARTIES','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','PER_JOBS','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','PER_JOBS','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','PER_JOBS','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','PER_JOBS','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','PER_GRADES','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','PER_GRADES','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','PER_GRADES','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','PER_GRADES','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','HR_ALL_ORGANIZATION_UNITS','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','HR_ALL_ORGANIZATION_UNITS','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','HR_ALL_ORGANIZATION_UNITS','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','HR_ALL_ORGANIZATION_UNITS','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','PER_VALID_GRADES','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','PER_VALID_GRADES','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','PER_VALID_GRADES','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','PER_VALID_GRADES','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','FND_LOOKUP_VALUES_VL','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','FND_LOOKUP_VALUES_VL','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','FND_LOOKUP_VALUES_VL','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','FND_LOOKUP_VALUES_VL','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','OIM_FND_GLOBAL','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','OIM_FND_GLOBAL','&USERNAME'); diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSUserAcl.sql b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSUserAcl.sql new file mode 100644 index 0000000000..80896a587f --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSUserAcl.sql @@ -0,0 +1,27 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for EXECUTE Grant on procedures/packages and Tables required for HRMS +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +accept hostname prompt"Enter the hostname for network acl [Input will be ignored If DB version is earlier than 11g] ::"; +/ + +DECLARE majorversion number; +BEGIN + select REGEXP_SUBSTR(version, '[^.]+', 1, 1) into majorversion FROM V$INSTANCE; + if majorversion > 10 then + DBMS_NETWORK_ACL_ADMIN.add_privilege('OracleEBS.xml', UPPER('&USERNAME'), TRUE, 'connect'); + DBMS_NETWORK_ACL_ADMIN.assign_acl ( acl => 'OracleEBS.xml', host => '&hostname'); + else + dbms_output.put_line('Ignoring assigning network acl'); + end if; +END; +/ + +COMMIT; +/ diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSUserGrants.sql b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSUserGrants.sql new file mode 100644 index 0000000000..4deab8bb53 --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSUserGrants.sql @@ -0,0 +1,95 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for EXECUTE Grant on procedures/packages and Tables required for HRMS +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + + +---- EXECUTE Grant on procedures/packages required for OIM database USER ---- + +prompt grant execute on APPS.HR_EMPLOYEE_API to &USERNAME; +grant execute on APPS.HR_EMPLOYEE_API to &USERNAME; + +prompt grant execute on APPS.HR_PERSON_API to &USERNAME; +grant execute on APPS.HR_PERSON_API to &USERNAME; + +prompt grant execute on APPS.HR_CHANGE_START_DATE_API to &USERNAME; +grant execute on APPS.HR_CHANGE_START_DATE_API to &USERNAME; + +prompt grant execute on APPS.HR_PERSON_ADDRESS_API to &USERNAME; +grant execute on APPS.HR_PERSON_ADDRESS_API to &USERNAME; + +prompt grant execute on APPS.HR_PERSON_ADDRESS_BK1 to &USERNAME; +grant execute on APPS.HR_PERSON_ADDRESS_BK1 to &USERNAME; + +prompt grant execute on APPS.HR_API to &USERNAME; +grant execute on APPS.HR_API to &USERNAME; + +prompt grant execute on APPS.HR_CONTINGENT_WORKER_API to &USERNAME; +grant execute on APPS.HR_CONTINGENT_WORKER_API to &USERNAME; + +prompt grant execute on APPS.HR_ASSIGNMENT_API to &USERNAME; +grant execute on APPS.HR_ASSIGNMENT_API to &USERNAME; + +prompt grant execute on APPS.FND_GLOBAL to &USERNAME; +grant execute on APPS.FND_GLOBAL to &USERNAME; + +---- SELECT Grant on tables required for OIM database USER ---- + +prompt grant select on APPS.PER_ALL_ASSIGNMENTS_F to &USERNAME; +grant select, update on APPS.PER_ALL_ASSIGNMENTS_F to &USERNAME; + +prompt grant select on APPS.PER_PEOPLE_F to &USERNAME; +grant select, update on APPS.PER_PEOPLE_F to &USERNAME; + +prompt grant select on APPS.PER_PERSON_TYPES to &USERNAME; +grant select, update on APPS.PER_PERSON_TYPES to &USERNAME; + +prompt grant select on APPS.PER_PERIODS_OF_SERVICE to &USERNAME; +grant select, update on APPS.PER_PERIODS_OF_SERVICE to &USERNAME; + +prompt grant select on APPS.PER_PERIODS_OF_PLACEMENT to &USERNAME; +grant select, update on APPS.PER_PERIODS_OF_PLACEMENT to &USERNAME; + +prompt grant select on APPS.PER_ADDRESSES to &USERNAME; +grant select, update on APPS.PER_ADDRESSES to &USERNAME; + +prompt grant select on APPS.PER_PERSON_TYPE_USAGES_F to &USERNAME; +grant select, update on APPS.PER_PERSON_TYPE_USAGES_F to &USERNAME; + +prompt grant select on APPS.PER_ALL_PEOPLE_F to &USERNAME; +grant select, update on APPS.PER_ALL_PEOPLE_F to &USERNAME; + + +-- Grant execute privileges to the wrapper packages created in APPS schema + +prompt grant execute on APPS.OIM_EMPLOYEE_WRAPPER to &USERNAME; +grant execute on APPS.OIM_EMPLOYEE_WRAPPER to &USERNAME; + +prompt grant execute on APPS.OIM_EMPLOYEE_ADDRESS_WRAPPER to &USERNAME; +grant execute on APPS.OIM_EMPLOYEE_ADDRESS_WRAPPER to &USERNAME; + +prompt grant select, update on APPS.HZ_PARTIES to &USERNAME; +grant select, update on APPS.HZ_PARTIES to &USERNAME; + +prompt grant select, update on APPS.PER_JOBS to &USERNAME; +grant select, update on APPS.PER_JOBS to &USERNAME; + +prompt grant select, update on APPS.PER_GRADES to &USERNAME; +grant select, update on APPS.PER_GRADES to &USERNAME; + +prompt grant select, update on APPS.HR_ALL_ORGANIZATION_UNITS to &USERNAME; +grant select, update on APPS.HR_ALL_ORGANIZATION_UNITS to &USERNAME; + +prompt grant select, update on APPS.PER_VALID_GRADES to &USERNAME; +grant select, update on APPS.PER_VALID_GRADES to &USERNAME; + +prompt grant select, update on APPS.FND_LOOKUP_VALUES_VL to &USERNAME; +grant select, update on APPS.FND_LOOKUP_VALUES_VL to &USERNAME; + +prompt grant execute on APPS.OIM_FND_GLOBAL to &USERNAME; +grant execute on APPS.OIM_FND_GLOBAL to &USERNAME; diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSUserSynonyms.sql b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSUserSynonyms.sql new file mode 100644 index 0000000000..3c72ba6278 --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/OimHRMSUserSynonyms.sql @@ -0,0 +1,24 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for CREATING synonym of procedures/packages. +-- Using previously created OimHRMSAppstablesSynonyms for HRF-OIM database USER +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +prompt Connecting &USERNAME; +accept Databasename prompt"Enter the name of the database ::"; +connect &USERNAME/&USERPWD@&Databasename; + +prompt create or replace synonym OIM_EMPLOYEE_WRAPPER for APPS.OIM_EMPLOYEE_WRAPPER; +create or replace synonym OIM_EMPLOYEE_WRAPPER for APPS.OIM_EMPLOYEE_WRAPPER; + +prompt create or replace synonym OIM_EMPLOYEE_ADDRESS_WRAPPER for APPS.OIM_EMPLOYEE_ADDRESS_WRAPPER; +create or replace synonym OIM_EMPLOYEE_ADDRESS_WRAPPER for APPS.OIM_EMPLOYEE_ADDRESS_WRAPPER; + +prompt create or replace synonym OIM_FND_GLOBAL for APPS.OIM_FND_GLOBAL; +create or replace synonym OIM_FND_GLOBAL for APPS.OIM_FND_GLOBAL; + diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/Run_HRMS_DBScripts.bat b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/Run_HRMS_DBScripts.bat new file mode 100755 index 0000000000..6892610052 --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/Run_HRMS_DBScripts.bat @@ -0,0 +1,134 @@ + +REM Copyright (c) 2023 Oracle and/or its affiliates. +REM +REM Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +REM +REM Author: OIG Development +REM +REM Description: Script file for Creating a service account in EBS target For HRMS +REM +REM +REM DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +echo off +if exist run.sql del run.sql + +if "%ORACLE_HOME%"=="" ( +SET /p ORACLE_HOME=Enter the ORACLE_HOME :: +) else ( +ECHO ORACLE_HOME is ::%ORACLE_HOME% +) + +SET /p Systemuser=Enter the System User name :: + +SET /p Databasename=Enter the name of the database :: + +REM ---- Create Log file ---- +ECHO SPOOL OIM_APPS_HRMS_TARGET.log >> run.sql +SET /p NEWUSER=Would you like to create new user for connector operations [y/n] :: +IF /I "%NEWUSER%" == "yes" ( +goto :yes +) else IF /I "%NEWUSER%" == "y" ( +goto :yes +) else IF /I "%NEWUSER%" == "no" ( +goto :no +) else IF /I "%NEWUSER%" == "n" ( +goto :no +) else ( +echo "Invalid option" +goto :end +) + +:yes +set NEWUSER=Y +SET /p EBS121X=Are you running this script with EBS target 12.1.x [y/n] :: +IF /I "%EBS121X%" == "yes" ( +goto :yesEBS121X +) else IF /I "%EBS121X%" == "y" ( +goto :yesEBS121X +) else IF /I "%EBS121X%" == "no" ( +goto :noEBS121X +) else IF /I "%EBS121X%" == "n" ( +goto :noEBS121X +) else ( +echo "Invalid option" +goto :end +) + +:yesEBS121X +set EBS121X=Y +goto :continue + +:noEBS121X +set EBS121X=N +goto :continue + +:no +set NEWUSER=N + +:continue +REM ---- Connecting to DataBase through APPS user---- +ECHO prompt Connecting to APPS >> run.sql +ECHO connect apps@%Databasename% >> run.sql + + +REM ---- Creating packages ---- +ECHO @OIM_TYPES.pck >> run.sql +ECHO @OIM_FND_GLOBAL.pck >> run.sql +ECHO @OIM_EBSHRMS_SCHEMA_PKG.pck >> run.sql +ECHO @OIM_EMPLOYEE_WRAPPER.pck >> run.sql + +IF "%NEWUSER%" == "Y" ( + ECHO @OIM_EMPLOYEE_ADDRESS_WRAPPER.pck >> run.sql +) else ( + ECHO @OIM_EMPLOYEE_ADDRESS_WRAPPER_APPS.pck >> run.sql +) + +ECHO prompt Disconnecting APPS >> run.sql +ECHO disconn >> run.sql + +IF /I "%NEWUSER%" == "Y" ( + REM ---- Connecting to DataBase through System user---- + ECHO prompt Connecting to %Systemuser% >> run.sql + ECHO connect %Systemuser%@%Databasename% >>run.sql + + REM ---- Creating the DataBase User---- + ECHO @OimHRMSUser.sql >> run.sql + + IF /I "%EBS121X%" == "Y" ( + REM ---- Executing Grant on procedures/packages and Tables---- + ECHO @OimHRMSUserGrants.sql >> run.sql + ) + + ECHO @OimHRMSUserAcl.sql >> run.sql + + ECHO prompt Disconnecting %Systemuser% >> run.sql + ECHO disconn >> run.sql + + IF /I "%EBS121X%" == "N" ( + REM ---- Connecting to DataBase through APPS user---- + ECHO prompt Connecting to APPS >> run.sql + ECHO connect apps@%Databasename% >> run.sql + + REM ---- Executing AD_ZD.grant_privs on procedures/packages and Tables---- + ECHO @OimHRMSUserAD_ZDGrants.sql >> run.sql + + ECHO prompt Disconnecting APPS >> run.sql + ECHO disconn >> run.sql + ) + + REM ---- Creating synonym of procedures/packages and Tables---- + ECHO @OimHRMSAppstablesSynonyms.sql >> run.sql + + REM ---- Creating synonym of procedures/packages Using previously created OimUserAppstablesSynonyms---- + ECHO @OimHRMSUserSynonyms.sql >> run.sql + ECHO @OIM_TYPES.pck >> run.sql + ECHO @OIM_EBSHRMS_SCHEMA_PKG.pck >> run.sql +) + +ECHO SPOOL OFF >> run.sql +ECHO EXIT >> run.sql + +%ORACLE_HOME%\bin\sqlplus /nolog @run.sql +del run.sql +:end diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/Run_HRMS_DBScripts.sh b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/Run_HRMS_DBScripts.sh new file mode 100755 index 0000000000..7d8b9a9538 --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_HRMS/1.0/Run_HRMS_DBScripts.sh @@ -0,0 +1,146 @@ +#!/bin/sh +# +# Copyright (c) 2023 Oracle and/or its affiliates. +# +# Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +# +# Author: OIG Development +# +# Description: Script file for Creating a service account in EBS target For HRMS +# +# +# DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + + +if [ -f run.sql ] +then +rm -f run.sql +fi + +if [ -f "$ORACLE_HOME" ] +then +echo "Enter the ORACLE_HOME ::" +read -r orahome +ORACLE_HOME=$orahome +else +echo "ORACLE_HOME is ::" +echo "$ORACLE_HOME" +fi + +export ORACLE_HOME + +echo Enter the System User Name :: +read -r Systemuser + +echo Enter the name of the database :: +read -r Databasename + +# ---- User Input to choose Connector ---- + +# ---- Create Log file ---- +echo SPOOL OIM_APPS_HRMS_TARGET.log >> run.sql + +echo "Would you like to create new user for connector operations [y/n]: \c" +read -r NEWUSER + +if echo "$NEWUSER" | grep -qE "^(yes|y)" +then + NEWUSER=Y + echo "Are you running this script with EBS target 12.1.x [y/n]: \c" + read -r EBS121X + + if echo "$EBS121X" | grep -qE "^(yes|y)" + then + EBS121X=Y + elif echo "$EBS121X" | grep -qE "^(no|n)" + then + EBS121X=N + else + echo "Invalid Option" + exit + fi +elif echo "$NEWUSER" | grep -qE "^(no|n)" +then + NEWUSER=N +else + echo "Invalid Option" + exit +fi + + +# ---- Connecting to DataBase through APPS user---- +{ + echo prompt Connecting to APPS; + echo connect apps@"$Databasename"; + # ---- Creating packages ---- + echo @OIM_TYPES.pck; + echo @OIM_FND_GLOBAL.pck; + echo @OIM_EBSHRMS_SCHEMA_PKG.pck; + echo @OIM_EMPLOYEE_WRAPPER.pck; +} >> run.sql + +if echo "$NEWUSER" | grep -qE "^(Y)" +then +echo @OIM_EMPLOYEE_ADDRESS_WRAPPER.pck >> run.sql +else +echo @OIM_EMPLOYEE_ADDRESS_WRAPPER_APPS.pck >> run.sql +fi + +echo prompt Disconnecting APPS >> run.sql +echo disconn >> run.sql +# --- If user wants to create new user --------------- +if echo "$NEWUSER" | grep -qE "^(Y)" +then +# ---- Connecting to DataBase through System user---- +{ + echo prompt Connecting to "$Systemuser"; + echo connect "$Systemuser"@"$Databasename"; + # ---- Creating the DataBase User--- + echo @OimHRMSUser.sql; +} >> run.sql + +if echo "$EBS121X" | grep -qE "^(Y)" +then + # ---- Executing grant on procedures/packages and Tables---- + echo @OimHRMSUserGrants.sql >> run.sql +fi + +{ + echo @OimHRMSUserAcl.sql; + echo prompt Disconnecting "$Systemuser"; + echo disconn; +} >> run.sql + + +if echo "$EBS121X" | grep -qE "^(N)" +then + { + # ---- Connecting to DataBase through APPS user---- + echo prompt Connecting to APPS; + echo connect apps@"$Databasename"; + # ---- Executing AD_ZD.grant_privs on procedures/packages and Tables---- + echo @OimHRMSUserAD_ZDGrants.sql; + echo prompt Disconnecting APPS; + echo disconn; + } >> run.sql + +fi + +{ + # ---- Creating synonym of procedures/packages and Tables---- + echo @OimHRMSAppstablesSynonyms.sql; + + # ---- Creating synonym of procedures/packages Using previously created OimUserAppstablesSynonyms---- + echo @OimHRMSUserSynonyms.sql; + echo @OIM_TYPES.pck; + echo @OIM_EBSHRMS_SCHEMA_PKG.pck; +} >> run.sql + +fi +{ + echo SPOOL OFF; + echo EXIT; +} >> run.sql + +"$ORACLE_HOME"/bin/sqlplus /nolog @run.sql +rm -f run.sql diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/GET_LAST_UPDATE_DATE_FUNCTION.pck b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/GET_LAST_UPDATE_DATE_FUNCTION.pck new file mode 100644 index 0000000000..071587731a --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/GET_LAST_UPDATE_DATE_FUNCTION.pck @@ -0,0 +1,33 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for EXECUTE Grant on procedures/packages and Tables required for OIM database USER +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +-- function that gets latest date from roles and responsibilities +create or replace function get_last_update_date(p_user_id IN NUMBER) return date +result_cache is + l_lastupdate_date date; +begin + select max(l_max_date) into l_lastupdate_date from ( + (select rol.last_update_date l_max_date + from fnd_user f, wf_user_role_assignments rol + where f.user_id = p_user_id + and rol.user_name = f.user_name + and rol.role_name like 'UMX%') + union all + select /*+ index(resp.wur WF_LOCAL_USER_ROLES_U1) */ resp.last_update_date l_max_date + from FND_USER_RESP_GROUPS_DIRECT resp + where resp.user_id = p_user_id + union all + select last_update_date l_max_date from fnd_user where user_id=p_user_id); + + return l_lastupdate_date; + +end; + +/ diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OIM_EBSUM_SCHEMA_PKG.pck b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OIM_EBSUM_SCHEMA_PKG.pck new file mode 100644 index 0000000000..871b91fae8 --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OIM_EBSUM_SCHEMA_PKG.pck @@ -0,0 +1,102 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for EBS UM +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +create or replace package OIM_EBSUM_SCHEMA_PKG is + ---------------------------------------------------------------------- + -- + -- Generates schema for Connector + -- Schema includes supported object classes and attribute information for object classes + procedure get_schema( + schemaout OUT schemalist + ); + +end OIM_EBSUM_SCHEMA_PKG; + +/ + +create or replace PACKAGE BODY OIM_EBSUM_SCHEMA_PKG AS + ----------------------------------------------------------------------- + -------------------Schema Declaration---------------------------------- + ------- Add the columns that need to be extended here + ------- For adding the attributes one need to follow the steps + ------- 1. Add attr.extend - For every attribute before addition of it to schema + ------- 2. attr (order_no) := attributeinfo(Attr_Name,Attr_Type,creatable,updatable,required,readable) + ------Add the attribute info for that extending attribute + ------ order_no - the order of the attribute. please dont skip the order + ------ Attr_Name - the name of the attribute + ------ Attr_Type - the sql type of the attribute + ------ creatable,updatable,required,readable - are properties of the attribute. 1 represents true and + ------ 0 represent false + + procedure get_schema(schemaout OUT schemalist) + AS + attr attributelist; + BEGIN + schemaout := schemalist(); + attr := attributelist(); + attr.extend(20); --initialize + attr (1) := attributeinfo('USER_NAME','varchar2',1,1,1,1); + attr (2) := attributeinfo('OWNER','varchar2',1,1,0,0); + attr (3) := attributeinfo('PASSWORD','varchar2',1,1,0,1); + attr (4) := attributeinfo('SESSION_NUMBER','varchar2',1,1,0,1); + attr (5) := attributeinfo('START_DATE','date',1,1,1,1); + attr (6) := attributeinfo('END_DATE','date',1,1,0,1); + attr (7) := attributeinfo('DESCRIPTION','varchar2',1,1,0,1); + attr (8) := attributeinfo('EMAIL_ADDRESS','varchar',1,1,0,1); + attr (9) := attributeinfo('USER_ID','NUMBER',0,0,1,1); + attr (10) := attributeinfo('CUSTOMER_ID','VARCHAR',1,1,0,1); + attr (11) := attributeinfo('SUPPLIER_ID','NUMBER',1,1,0,1); + attr (12) := attributeinfo('EMPLOYEE_ID','VARCHAR',1,1,0,1); + attr (13) := attributeinfo('FAX','varchar',1,1,0,1); + attr (14) := attributeinfo('DATE_UPDATED','date',1,1,0,1); + attr (15) := attributeinfo('PASSWORD_LIFESPAN','varchar',1,1,0,1); + attr (16) := attributeinfo('PASSWORD_EXP_TYPE','varchar',1,1,0,1); + attr (17) := attributeinfo('PARTY_TYPE','varchar',1,1,0,1); + attr (18) := attributeinfo('PARTY_ID','varchar',1,1,0,1); + attr (19) := attributeinfo('SUPPLIER_NAME','varchar',1,1,0,1); + attr (20) := attributeinfo('SUPPLIER_PARTY_ID','varchar',1,1,0,1); + attr.extend; + attr (21) := attributeinfo('PARTY_FIRST_NAME','varchar',1,1,0,1); + attr.extend; + attr (22) := attributeinfo('PARTY_LAST_NAME','varchar',1,1,0,1); + attr.extend; + attr (23) := attributeinfo('USER_GUID','raw',1,1,0,1); + schemaout.extend; + schemaout( 1 ) := schema_object('__ACCOUNT__',attr); + + attr := attributelist(); + attr.extend(10); + attr (1) := attributeinfo('RESPONSIBILITY_ID','varchar',1,1,1,1); + attr (2) := attributeinfo('SECURITY_GROUP_ID','varchar',1,1,1,1); + attr (3) := attributeinfo('RESP_DESCRIPTION','varchar',1,1,0,1); + attr (4) := attributeinfo('RESP_START_DATE','date',1,1,1,1); + attr (5) := attributeinfo('RESP_END_DATE','date',1,1,1,1); + attr (6) := attributeinfo('RESPONSIBILITY_APP_ID','varchar',1,1,1,1); + + schemaout.extend; + schemaout( 2 ) := schema_object('__RESPONSIBILITY__',attr); + + + attr := attributelist(); + attr.extend(5); + attr (1) := attributeinfo('ROLE_ID','varchar',1,1,1,1); + attr (2) := attributeinfo('ROLE_START_DATE','date',1,1,1,1); + attr (3) := attributeinfo('EXPIRATION_DATE','date',1,1,1,1); + attr (4) := attributeinfo('ROLE_APP_ID','varchar',1,1,1,1); + + schemaout.extend; + schemaout( 3 ) := schema_object('__ROLE__',attr); + + + END get_schema; + +end OIM_EBSUM_SCHEMA_PKG; + +/ diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OIM_FND_GLOBAL.pck b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OIM_FND_GLOBAL.pck new file mode 100644 index 0000000000..797b6d42e1 --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OIM_FND_GLOBAL.pck @@ -0,0 +1,67 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for EBS UM +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +create or replace package OIM_FND_GLOBAL is + +-- Public function and procedure declarations + +---------------------------------------------------------------------- +-- +-- APPS_INITIALIZE - Setup PL/SQL security context +-- +-- This procedure may be called to initialize the global security +-- context for a database session. This should only be done when +-- the session is established outside of a normal forms or +-- concurrent program connection. +-- +-- IN +-- FND User ID +-- FND Responsibility ID (two part key, resp_id / resp_appl_id) +-- FND Security Group ID +-- +procedure APPS_INITIALIZE( + user_id in number, + resp_id in number, + resp_appl_id in number, + security_group_id in number default 0, + server_id in number default -1); + +end OIM_FND_GLOBAL; +/ +create or replace package body OIM_FND_GLOBAL is + +---------------------------------------------------------------------- +-- This procedure may be called to initialize the global security +-- context for a database session. This should only be done when +-- the session is established outside of a normal forms or +-- concurrent program connection. +-- +-- IN +-- FND User ID +-- FND Responsibility ID (two part key, resp_id / resp_appl_id) +-- FND Security Group ID +-- +procedure APPS_INITIALIZE( + user_id in number, + resp_id in number, + resp_appl_id in number, + security_group_id in number default 0, + server_id in number default -1) is +begin + FND_GLOBAL.APPS_INITIALIZE( + user_id , + resp_id , + resp_appl_id , + security_group_id , + server_id); +end APPS_INITIALIZE; + +end OIM_FND_GLOBAL; +/ diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OIM_FND_USER_TCA_PKG.pck b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OIM_FND_USER_TCA_PKG.pck new file mode 100644 index 0000000000..2c1e1fbe88 --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OIM_FND_USER_TCA_PKG.pck @@ -0,0 +1,1276 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for EBS UM +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +create or replace package OIM_FND_USER_TCA_PKG is + ---------------------------------------------------------------------- + -- + -- CreateUser (PUBLIC) + -- Insert new user record into FND_USER table. + -- If that user exists already, exception raised with the error message. + -- There are three input arguments must be provided. All the other columns + -- in FND_USER table can take the default value. + -- + -- *** NOTE: This version accepts the old customer_id/employee_id + -- keys foreign keys to the "person". Use CreateUserParty to create + -- a user with the new person_party_id key. + -- + -- Input (Mandatory) + -- user_name: The name of the new user + -- owner: 'SEED' or 'CUST'(customer) + -- password: The password for this new user + -- + procedure CreateUser ( + user_name in varchar2, + owner in varchar2, + password in varchar2 default null, + session_number in number default 0, + start_date in date default sysdate, + end_date in date default null, + last_logon_date in date default null, + description in varchar2 default null, + password_date in date default null, + password_accesses_left in number default null, + password_lifespan_accesses in number default null, + password_lifespan_days in number default null, + employee_id in number default null, + email_address in varchar2 default null, + fax in varchar2 default null, + customer_id in number default null, + supplier_id in number default null, + user_guid in raw, + user_id out NUMBER); + + ---------------------------------------------------------------------- + -- + -- CreateUserParty (PUBLIC) + -- Insert new user record into FND_USER table. + -- If that user exists already, exception raised with the error message. + -- There are three input arguments must be provided. All the other columns + -- in FND_USER table can take the default value. + -- + -- *** NOTE: This version accepts the new person_party_id foreign key + -- to the "person". Use CreateUser to create a user with the old + -- customer_id/employee_id keys. + -- + -- Input (Mandatory) + -- x_user_name: The name of the new user + -- x_owner: 'SEED' or 'CUST'(customer) + -- x_unencrypted_password: The password for this new user + -- + + + procedure CreateUserParty ( + user_name in varchar2, + owner in varchar2, + password in varchar2 default null, + session_number in number default 0, + start_date in date default sysdate, + end_date in date default null, + last_logon_date in date default null, + description in varchar2 default null, + password_date in date default null, + password_accesses_left in number default null, + password_lifespan_accesses in number default null, + password_lifespan_days in number default null, + email_address in varchar2 default null, + fax in varchar2 default null, + party_id in number default null, + user_guid in raw, + user_id out NUMBER + ); + + ---------------------------------------------------------------------- + -- + -- UpdateUser (Public) + -- Update any column for a particular user record. If that user does + -- not exist, exception raised with error message. + -- You can use this procedure to update a user's password for example. + -- + -- *** NOTE: This version accepts the old customer_id/employee_id + -- keys foreign keys to the "person". Use UpdateUserParty to update + -- a user with the new person_party_id key. + -- + -- Usage Example in pl/sql + -- begin fnd_user_pkg.updateuser('SCOTT', 'SEED', 'DRAGON'); end; + -- + -- Mandatory Input Arguments + -- user_name: An existing user name + -- wner: 'SEED' or 'CUST'(customer) + -- + procedure UpdateUser ( + user_name in varchar2, + owner in varchar2, + password in varchar2 default null, + session_number in number default null, + start_date in date default null, + end_date in date default null, + last_logon_date in date default null, + description in varchar2 default null, + password_date in date default null, + password_accesses_left in number default null, + password_lifespan_accesses in number default null, + password_lifespan_days in number default null, + employee_id in number default null, + email_address in varchar2 default null, + fax in varchar2 default null, + customer_id in number default null, + supplier_id in number default null, + old_password in varchar2 default null, + user_guid in raw); + + ---------------------------------------------------------------------- + -- + -- UpdateUserParty (Public) + -- Update any column for a particular user record. If that user does + -- not exist, exception raised with error message. + -- You can use this procedure to update a user's password for example. + -- + -- *** NOTE: This version accepts the new person_party_id foreign key + -- to the "person". Use UpdateUser to update a user with the old + -- customer_id/employee_id keys. + -- + -- Usage Example in pl/sql + -- begin fnd_user_pkg.updateuser('SCOTT', 'SEED', 'DRAGON'); end; + -- + -- Mandatory Input Arguments + -- x_user_name: An existing user name + -- x_owner: 'SEED' or 'CUST'(customer) + -- + + procedure UpdateUserParty ( + user_name in varchar2, + owner in varchar2, + password in varchar2 default null, + session_number in number default null, + start_date in date default null, + end_date in date default null, + last_logon_date in date default null, + description in varchar2 default null, + password_date in date default null, + password_accesses_left in number default null, + password_lifespan_accesses in number default null, + password_lifespan_days in number default null, + email_address in varchar2 default null, + fax in varchar2 default null, + party_id in number, + old_password in varchar2 default null, + user_guid in raw + ); + + + ---------------------------------------------------------------------------- + -- + -- DisableUser (PUBLIC) + -- Sets end_date to sysdate for a given user. This is to terminate that user. + -- You longer can log in as this user anymore. If username is not valid, + -- exception raised with error message. + -- + -- Usage example in pl/sql + -- begin fnd_user_pkg.disableuser('SCOTT'); end; + -- + -- Input (Mandatory) + -- username: User Name + -- + procedure DisableUser(user_name varchar2); + + + ---------------------------------------------------------------------------- + -- + -- EnableUser (PUBLIC) + -- Sets the start_date and end_date as requested. By default, the + -- start_date will be set to sysdate and end_date to null. + -- This is to enable that user. + -- You can log in as this user from now. + -- If username is not valid, exception raised with error message. + -- + -- Usage example in pl/sql + -- begin fnd_user_pkg.enableuser('SCOTT'); end; + -- begin fnd_user_pkg.enableuser('SCOTT', sysdate+1, sysdate+30); end; + -- + -- Input (Mandatory) + -- username: User Name + -- Input (Non-Mandatory) + -- start_date: Start Date + -- end_date: End Date + -- + procedure EnableUser(user_name varchar2, + start_date date default sysdate, + end_date date default FND_USER_PKG.null_date); + + + -------------------------------------------------------------------------- + -- + -- DelResp (PUBLIC) + -- Detach a responsibility which is currently attached to this given user. + -- If any of the username or application short name or responsibility key or + -- security group is not valid, exception raised with error message. + -- + -- Usage example in pl/sql + -- begin fnd_user_pkg.delresp('SCOTT', '0', '123', + -- '0'); end; + -- Input (Mandatory) + -- username: User Name + -- responsibility_app_id : Application Id + -- responsibility_id : Responsibility Id + -- security_group_id : Security Group Id + -- + procedure DelResp(user_name varchar2, + responsibility_app_id varchar2, + responsibility_id varchar2, + security_group_id varchar2); + + -------------------------------------------------------------------------- + -- + -- AddResp (PUBLIC) + -- For a given user, attach a valid responsibility. + -- If user name or application short name or responsbility key name + -- or security group key is not valid, exception raised with error message. + -- + -- Usage example in pl/sql + -- begin fnd_user_pkg.addresp('SCOTT', '0', '234', + -- '0', 'DESCRIPTION', sysdate, null); end; + -- Input (Mandatory) + -- username: User Name + -- responsibility_app_id : Application Id + -- responsibility_id : Responsibility Id + -- security_group_id : Security Group Id + -- resp_description: Description + -- resp_start_date: Start Date + -- resp_end_date: End Date + -- + procedure AddResp(user_name varchar2, + responsibility_app_id varchar2, + responsibility_id varchar2, + security_group_id varchar2, + resp_description varchar2, + resp_start_date date default sysdate, + resp_end_date date); + + ----------------------------------------------------------------------------- + -- + -- change_user_name (PUBLIC) + -- This api changes username, deals with encryption changes and will + -- eventually at some point in time in the future, update foreign keys + -- that were using the old username. For now it will just do a handoff + -- of old username and new username to WF so that they can update their + -- foreign keys. + -- + -- Usage example in pl/sql + -- begin fnd_user_pkg.change_user_name('SOCTT', 'SCOTT'); end; + -- + -- Input (Mandantory) + -- user_name_old: Old User Name + -- user_name_new: New User Name + -- + + procedure change_user_name( user_name_old in varchar2, + user_name_new in varchar2); + + + + ----------------------------------------------------------------------------- + -- + -- propagateUserRole (PUBLIC) + -- This api to add role to user + + PROCEDURE propagateUserRole(user_name in varchar2, + role_id in varchar2, + role_start_date in date default sysdate, + expiration_date in date default null); + + ----------------------------------------------------------------------------- + -- + -- change_user_name (PUBLIC) + -- This api to revoke user role + + PROCEDURE revokeUserRole(user_name in varchar2, + role_id in varchar2); + + ----------------------------------------------------------------------------- + -- Procedure to change the password for a user + -- Input (Mandantory) + -- user_name: User Name + -- password: New password for a user + + PROCEDURE ChangePassword(user_name varchar2, + password varchar2); + + ---------------------------------------------------------------------- + -- + -- Create Supplier organization + -- Input (Mandatory) + -- supplier_name: The name of the Supplier organization + + PROCEDURE create_supplier( supplier_name IN VARCHAR2, + supplier_party_id out number); + + ---------------------------------------------------------------------- + -- + -- Create Supplier contact for supplier + -- Input (Mandatory) + -- supplier_name: The name of the Supplier organization + -- party_first_name: Supplier contact first name + -- party_last_name: Supplier contact last name + + PROCEDURE create_supplier_contact(supplier_name IN VARCHAR2, + party_first_name IN VARCHAR2, + party_last_name IN VARCHAR2, + party_id out number); + ---------------------------------------------------------------------- + -- + -- Link Supplier contact party with the user + -- Input (Mandatory) + -- user_name: The name of the Supplier organization + -- party_id: Party id + + procedure link_user_party(user_name varchar2,party_id number); + + -------Procedure for creating party-------- + + procedure create_party( party_last_name in varchar2, + party_first_name in varchar2, + user_name in varchar2, + user_guid in varchar2 default null, + party_id out number + ); + -------Procedure for updating party-------- + + procedure update_party( party_last_name in varchar2, + party_first_name in varchar2, + user_name in varchar2 , + user_guid in varchar2 default null + ); + + PROCEDURE validatePartyAndPerson( party_id in number, + employee_id in number default null); + + procedure revokeUser(user_id in number); + + procedure create_supplier_security_attrs(user_name in varchar2, supplier_party_id in number); + +end OIM_FND_USER_TCA_PKG; + +/ + +create or replace PACKAGE BODY OIM_FND_USER_TCA_PKG AS + error_message VARCHAR2(70) := 'Invalid End date. End date cannot be less than start date.'; + ----------------------------------------------------------------------- + -- + -- CreateUser (PUBLIC) + -- Insert new user record into FND_USER table. + -- If that user exists already, exception raised with the error message. + -- There are three input arguments must be provided. All the other columns + -- in FND_USER table can take the default value. + -- + -- *** NOTE: This version accepts the old customer_id/employee_id + -- keys foreign keys to the "person". Use CreateUserParty to create + -- a user with the new person_party_id key. + -- + -- Input (Mandatory) + -- x_user_name: The name of the new user + -- x_owner: 'SEED' or 'CUST'(customer) + -- x_unencrypted_password: The password for this new user + -- + procedure CreateUser( user_name in varchar2, + owner in varchar2, + password in varchar2 default null, + session_number in number default 0, + start_date in date default sysdate, + end_date in date default null, + last_logon_date in date default null, + description in varchar2 default null, + password_date in date default null, + password_accesses_left in number default null, + password_lifespan_accesses in number default null, + password_lifespan_days in number default null, + employee_id in number default null, + email_address in varchar2 default null, + fax in varchar2 default null, + customer_id in number default null, + supplier_id in number default null, + user_guid in raw, + user_id out NUMBER) + is + x_user_name fnd_user.user_name%type; + x_owner varchar2(200); + x_unencrypted_password varchar2(200); + x_session_number number default 0; + x_start_date date; + x_end_date date; + x_last_logon_date date; + x_description varchar2(200); + x_password_date date; + x_password_accesses_left number; + x_password_lifespan_accesses number; + x_password_lifespan_days number; + x_employee_id number; + x_email_address fnd_user.email_address%type; + x_fax fnd_user.fax%type; + x_customer_id number; + x_supplier_id number; + x_user_id number; + x_user_guid fnd_user.user_guid%type; + begin + if password_lifespan_accesses is null then + x_password_lifespan_accesses := FND_USER_PKG.null_number; + else + x_password_lifespan_accesses := password_lifespan_accesses; + end if; + + if password_lifespan_days is null then + x_password_lifespan_days := FND_USER_PKG.null_number; + else + x_password_lifespan_days := password_lifespan_days; + end if; + x_user_name := user_name; + x_owner := owner; + x_unencrypted_password := password; + x_session_number := session_number; + x_start_date := start_date; + x_end_date := end_date; + x_last_logon_date := last_logon_date; + x_description := description; + x_password_date := sysdate; + x_password_accesses_left := password_accesses_left; + x_employee_id := employee_id; + x_email_address := email_address; + x_fax := fax; + x_customer_id := customer_id; + x_supplier_id := supplier_id; + x_user_guid := user_guid; + if x_start_date > x_end_date then + raise_application_error (-20001, error_message); + end if; + FND_USER_PKG.CreateUser(x_user_name, + x_owner, + x_unencrypted_password, + x_session_number, + x_start_date, + x_end_date, + x_last_logon_date, + x_description, + x_password_date, + x_password_accesses_left, + x_password_lifespan_accesses, + x_password_lifespan_days, + x_employee_id, + x_email_address, + x_fax, + x_customer_id, + x_supplier_id); + if x_user_guid is not null then + update fnd_user set user_guid = x_user_guid where user_name = x_user_name; + end if; + SELECT USER_ID into x_user_id FROM FND_USER WHERE USER_NAME=x_user_name; + user_id := x_user_id; + end CreateUser; + + ---------------------------------------------------------------------- + -- + -- CreateUserParty (PUBLIC) + -- Insert new user record into FND_USER table. + -- If that user exists already, exception raised with the error message. + -- There are three input arguments must be provided. All the other columns + -- in FND_USER table can take the default value. + -- + -- *** NOTE: This version accepts the new person_party_id foreign key + -- to the "person". Use CreateUser to create a user with the old + -- customer_id/employee_id keys. + -- + -- Input (Mandatory) + -- x_user_name: The name of the new user + -- x_owner: 'SEED' or 'CUST'(customer) + -- x_unencrypted_password: The password for this new user + -- + + procedure CreateUserParty(user_name in varchar2, + owner in varchar2, + password in varchar2 default null, + session_number in number default 0, + start_date in date default sysdate, + end_date in date default null, + last_logon_date in date default null, + description in varchar2 default null, + password_date in date default null, + password_accesses_left in number default null, + password_lifespan_accesses in number default null, + password_lifespan_days in number default null, + email_address in varchar2 default null, + fax in varchar2 default null, + party_id in number default null, + user_guid in raw, + user_id out NUMBER) + is + + x_user_name fnd_user.user_name%type; + x_owner varchar2(200); + x_unencrypted_password varchar2(200); + x_session_number number default 0; + x_start_date date; + x_end_date date; + x_last_logon_date date; + x_description varchar2(200); + x_password_date date; + x_password_accesses_left number; + x_password_lifespan_accesses number; + x_password_lifespan_days number; + x_email_address fnd_user.email_address%type; + x_fax fnd_user.fax%type; + x_user_id number; + x_party_id number; + x_user_guid fnd_user.user_guid%type; + begin + if password_lifespan_accesses is null then + x_password_lifespan_accesses := FND_USER_PKG.null_number; + else + x_password_lifespan_accesses := password_lifespan_accesses; + end if; + if password_lifespan_days is null then + x_password_lifespan_days := FND_USER_PKG.null_number; + else + x_password_lifespan_days := password_lifespan_days; + end if; + x_user_name := user_name; + x_owner := owner; + x_unencrypted_password := password; + x_session_number := session_number; + x_start_date := start_date; + x_end_date := end_date; + x_last_logon_date := last_logon_date; + x_description := description; + x_password_date := sysdate; + x_user_guid := user_guid; + x_password_accesses_left := password_accesses_left; + x_email_address := email_address; + x_fax := fax; + x_party_id := party_id; + + if x_start_date > x_end_date then + raise_application_error (-20001, error_message); + end if; + + FND_USER_PKG.CreateUserParty( x_user_name, + x_owner, + x_unencrypted_password, + x_session_number, + x_start_date, + x_end_date, + x_last_logon_date, + x_description, + x_password_date, + x_password_accesses_left, + x_password_lifespan_accesses, + x_password_lifespan_days, + x_email_address, + x_fax, + x_party_id); + if x_user_guid is not null then + update fnd_user set user_guid = x_user_guid where user_name = x_user_name; + end if; + SELECT USER_ID into x_user_id FROM FND_USER WHERE USER_NAME=x_user_name; + user_id := x_user_id; + end CreateUserParty; + ---------------------------------------------------------------------- + -- + -- UpdateUser (Public) + -- Update any column for a particular user record. If that user does + -- not exist, exception raised with error message. + -- You can use this procedure to update a user's password for example. + -- + -- *** NOTE: This version accepts the old customer_id/employee_id + -- keys foreign keys to the "person". Use UpdateUserParty to update + -- a user with the new person_party_id key. + -- + -- Usage Example in pl/sql + -- begin fnd_user_pkg.updateuser('SCOTT', 'SEED', 'DRAGON'); end; + -- + -- Mandatory Input Arguments + -- x_user_name: An existing user name + -- x_owner: 'SEED' or 'CUST'(customer) + -- + procedure UpdateUser (user_name in varchar2, + owner in varchar2, + password in varchar2 default null, + session_number in number default null, + start_date in date default null, + end_date in date default null, + last_logon_date in date default null, + description in varchar2 default null, + password_date in date default null, + password_accesses_left in number default null, + password_lifespan_accesses in number default null, + password_lifespan_days in number default null, + employee_id in number default null, + email_address in varchar2 default null, + fax in varchar2 default null, + customer_id in number default null, + supplier_id in number default null, + old_password in varchar2 default null, + user_guid in raw) + is + x_user_name fnd_user.user_name%type; + x_owner varchar2(200); + x_unencrypted_password varchar2(200); + x_session_number number default 0; + x_start_date date; + x_end_date date; + x_last_logon_date date; + x_description varchar2(200); + x_password_date date; + x_password_accesses_left number; + x_password_lifespan_accesses number; + x_password_lifespan_days number; + x_employee_id number; + x_email_address fnd_user.email_address%type; + x_fax fnd_user.fax%type; + x_customer_id number; + x_supplier_id number; + x_old_password varchar2(200); + x_user_guid fnd_user.user_guid%type; + begin + x_password_accesses_left := password_accesses_left; + if password_lifespan_accesses is null then + x_password_lifespan_accesses := FND_USER_PKG.null_number; + else + x_password_lifespan_accesses := password_lifespan_accesses; + end if; + if password_lifespan_days is null then + x_password_lifespan_days := FND_USER_PKG.null_number; + else + x_password_lifespan_days := password_lifespan_days; + end if; + x_user_name := user_name; + select start_date into x_start_date from fnd_user where user_name=x_user_name; + if x_start_date <> start_date then + x_password_date := sysdate; + end if; + + x_owner := owner; + x_unencrypted_password := password; + x_session_number := session_number; + x_start_date := start_date; + x_end_date := end_date; + x_last_logon_date := last_logon_date; + x_description := description; + x_employee_id := employee_id; + x_email_address := email_address; + x_fax := fax; + x_customer_id := customer_id; + x_supplier_id := supplier_id; + x_old_password := old_password; + x_user_guid := user_guid; + + if (x_end_date != FND_USER_PKG.null_date) AND (x_start_date > x_end_date) then + raise_application_error (-20001, error_message); + end if; + FND_USER_PKG.UpdateUser(x_user_name, + x_owner, + x_unencrypted_password, + x_session_number, + x_start_date, + x_end_date, + x_last_logon_date, + x_description, + x_password_date, + x_password_accesses_left, + x_password_lifespan_accesses, + x_password_lifespan_days, + x_employee_id, + x_email_address, + x_fax, + x_customer_id, + x_supplier_id, + x_old_password); + if x_user_guid is not null then + update fnd_user set user_guid = x_user_guid where user_name = x_user_name; + end if; + end UpdateUser; + + procedure UpdateUserParty(user_name in varchar2, + owner in varchar2, + password in varchar2 default null, + session_number in number default null, + start_date in date default null, + end_date in date default null, + last_logon_date in date default null, + description in varchar2 default null, + password_date in date default null, + password_accesses_left in number default null, + password_lifespan_accesses in number default null, + password_lifespan_days in number default null, + email_address in varchar2 default null, + fax in varchar2 default null, + party_id in number, + old_password in varchar2 default null, + user_guid in raw) + is + x_user_name fnd_user.user_name%type; + x_owner varchar2(200); + x_unencrypted_password varchar2(200); + x_session_number number default 0; + x_start_date date; + x_end_date date; + x_last_logon_date date; + x_description varchar2(200); + x_password_date date; + x_password_accesses_left number; + x_password_lifespan_accesses number; + x_password_lifespan_days number; + x_employee_id number; + x_email_address fnd_user.email_address%type; + x_fax fnd_user.fax%type; + x_party_id number; + x_old_password varchar2(200); + x_user_guid fnd_user.user_guid%type; + begin + if password_lifespan_accesses is null then + x_password_lifespan_accesses := FND_USER_PKG.null_number; + else + x_password_lifespan_accesses := password_lifespan_accesses; + end if; + if password_lifespan_days is null then + x_password_lifespan_days := FND_USER_PKG.null_number; + else + x_password_lifespan_days := password_lifespan_days; + end if; + x_user_name := user_name; + + select start_date into x_start_date from fnd_user where user_name=x_user_name; + if x_start_date <> start_date then + x_password_date := sysdate; + end if; + + x_owner := owner; + x_unencrypted_password := password; + x_session_number := session_number; + x_start_date := start_date; + x_end_date := end_date; + x_last_logon_date := last_logon_date; + x_description := description; + x_password_accesses_left := password_accesses_left; + x_email_address := email_address; + x_fax := fax; + x_party_id := party_id; + x_old_password := old_password; + x_user_guid :=user_guid; + + if (x_end_date != FND_USER_PKG.null_date) AND (x_start_date > x_end_date) then + raise_application_error (-20001, error_message); + end if; + + FND_USER_PKG.UpdateUserParty(x_user_name, + x_owner, + x_unencrypted_password, + x_session_number, + x_start_date, + x_end_date, + x_last_logon_date, + x_description, + x_password_date, + x_password_accesses_left, + x_password_lifespan_accesses, + x_password_lifespan_days, + x_email_address, + x_fax, + x_party_id, + x_old_password); + if x_user_guid is not null then + update fnd_user set user_guid = x_user_guid where user_name = x_user_name; + end if; + end UpdateUserParty; + + + ---------------------------------------------------------------------------- + -- + -- DisableUser (PUBLIC) + -- Sets end_date to sysdate for a given user. This is to terminate that user. + -- You longer can log in as this user anymore. If username is not valid, + -- exception raised with error message. + -- + -- Usage example in pl/sql + -- begin fnd_user_pkg.disableuser('SCOTT'); end; + -- + -- Input (Mandatory) + -- username: User Name + -- + procedure DisableUser(user_name varchar2) + is + x_user_name varchar2(200); + begin + x_user_name := user_name; + FND_USER_PKG.DisableUser(x_user_name); + end DisableUser; + + ---------------------------------------------------------------------------- + -- + -- EnableUser (PUBLIC) + -- Sets the start_date and end_date as requested. By default, the + -- start_date will be set to sysdate and end_date to null. + -- This is to enable that user. + -- You can log in as this user from now. + -- If username is not valid, exception raised with error message. + -- + -- Usage example in pl/sql + -- begin fnd_user_pkg.enableuser('SCOTT'); end; + -- begin fnd_user_pkg.enableuser('SCOTT', sysdate+1, sysdate+30); end; + -- + -- Input (Mandatory) + -- username: User Name + -- Input (Non-Mandatory) + -- start_date: Start Date + -- end_date: End Date + -- + procedure EnableUser(user_name varchar2, + start_date date default sysdate, + end_date date ) + is + x_user_name varchar2(200); + x_start_date date; + x_end_date date; + begin + x_user_name := user_name; + x_start_date := start_date; + if end_date is null then + x_end_date := FND_USER_PKG.null_date; + else + x_end_date := end_date; + end if; + FND_USER_PKG.EnableUser(x_user_name, + x_start_date, + x_end_date); + end EnableUser; + + -------------------------------------------------------------------------- + -- + -- DelResp (PUBLIC) + -- Detach a responsibility which is currently attached to this given user. + -- If any of the username or application short name or responsibility key or + -- security group is not valid, exception raised with error message. + -- + -- Usage example in pl/sql + -- begin fnd_user_pkg.delresp('SCOTT', 'FND', 'APPLICATION_DEVELOPER', + -- 'STANDARD'); end; + -- Input (Mandatory) + -- username : User Name + -- responsibility_app_id : Application Short Id + -- responsibility_id : Responsibility Id + -- security_group_id : Security Group Id + -- + procedure DelResp(user_name varchar2, + responsibility_app_id varchar2, + responsibility_id varchar2, + security_group_id varchar2) + is + responsibility_short_name varchar2(1000); + app_short_name varchar2(1000); + sec_group_key varchar2(1000); + begin + SELECT responsibility_key into responsibility_short_name FROM fnd_responsibility WHERE responsibility_id = DelResp.responsibility_id AND application_id = responsibility_app_id; + SELECT application_short_name into app_short_name FROM fnd_application WHERE application_id = responsibility_app_id; + SELECT security_group_key into sec_group_key FROM fnd_security_groups WHERE security_group_id = DelResp.security_group_id; + FND_USER_PKG.DelResp(user_name, + app_short_name, + responsibility_short_name, + sec_group_key); + end DelResp; + + -------------------------------------------------------------------------- + -- + -- AddResp (PUBLIC) + -- For a given user, attach a valid responsibility. + -- If user name or application short name or responsbility key name + -- or security group key is not valid, exception raised with error message. + -- + -- Usage example in pl/sql + -- begin fnd_user_pkg.addresp('SCOTT', '0', '123', + -- '0', 'DESCRIPTION', sysdate, null); end; + -- Input (Mandatory) + -- username: User Name + -- responsibility_app_id : Application Short Id + -- responsibility_id : Responsibility Id + -- security_group_id : Security Group Id + -- resp_description: Description + -- resp_start_date: Start Date + -- resp_end_date: End Date + -- + procedure AddResp(user_name varchar2, + responsibility_app_id varchar2, + responsibility_id varchar2, + security_group_id varchar2, + resp_description varchar2, + resp_start_date date default sysdate, + resp_end_date date) + is + responsibility_short_name varchar2(1000); + app_short_name varchar2(1000); + sec_group_key varchar2(1000); + x_resp_start_date date; + + begin + + if resp_start_date is null then + x_resp_start_date := sysdate; + else + x_resp_start_date := resp_start_date; + end if; + + SELECT responsibility_key into responsibility_short_name FROM fnd_responsibility WHERE responsibility_id = AddResp.responsibility_id AND application_id = responsibility_app_id; + SELECT application_short_name into app_short_name FROM fnd_application WHERE application_id = responsibility_app_id; + SELECT security_group_key into sec_group_key FROM fnd_security_groups WHERE security_group_id = AddResp.security_group_id; + if x_resp_start_date > resp_end_date then + raise_application_error (-20001, error_message); + end if; + + FND_USER_PKG.AddResp( user_name, + app_short_name, + responsibility_short_name, + sec_group_key, + resp_description, + x_resp_start_date, + resp_end_date); + end AddResp; + + -------------------------------------------------------------------------- + -- + -- change_user_name (PUBLIC) + -- This api changes username, deals with encryption changes and will + -- eventually at some point in time in the future, update foreign keys + -- that were using the old username. For now it will just do a handoff + -- of old username and new username to WF so that they can update their + -- foreign keys. + -- + -- Usage example in pl/sql + -- begin fnd_user_pkg.change_user_name('SOCTT', 'SCOTT'); end; + -- + -- Input (Mandantory) + -- user_name_old: Old User Name + -- user_name_new: New User Name + + procedure change_user_name(user_name_old in varchar2, + user_name_new in varchar2) + is + begin + FND_USER_PKG.change_user_name(user_name_old, user_name_new ); + end change_user_name; + + + -------Procedure for propagateUserRole-------- + PROCEDURE propagateUserRole(user_name in varchar2, + role_id in varchar2, + role_start_date in date default sysdate, + expiration_date in date default null) + IS + x_role_start_date date; + + begin + if role_start_date is null then + x_role_start_date := sysdate; + else + x_role_start_date := role_start_date; + end if; + + if x_role_start_date > expiration_date then + raise_application_error (-20001, error_message); + end if; + + UMX_ACCESS_ROLES_PVT.propagateUserRole( p_user_name => user_name, + p_role_name => role_id, + p_start_date => x_role_start_date, + p_expiration_date => expiration_date); + + end propagateUserRole; + + -------Procedure for revokeUserRole-------- + PROCEDURE revokeUserRole(user_name in varchar2, + role_id in varchar2) + IS + l_start_date date; + x_user_name varchar2(500); + l_expiration_date date := sysdate; + begin + x_user_name := user_name; + select min(start_date) into l_start_date from WF_USER_ROLE_ASSIGNMENTS where user_name=x_user_name and role_name=role_id; + WF_LOCAL_SYNCH.PropagateUserRole(p_user_name => x_user_name, + p_role_name => role_id, + p_start_date => l_start_date, + p_expiration_date => l_expiration_date); + + end revokeUserRole; + + procedure ChangePassword(user_name varchar2, + password varchar2) + is + + begin + if FND_USER_PKG.changepassword(username=>user_name,newpassword =>password) then + dbms_output.put_line('Password updated successfully' ); + ELSE + raise_application_error (-20001, 'Error while updating the password'); + end if; + EXCEPTION + WHEN OTHERS THEN + raise; + end; + + PROCEDURE create_supplier(supplier_name IN VARCHAR2, + supplier_party_id out number) + is + l_vendor_rec ap_vendor_pub_pkg.r_vendor_rec_type; + l_return_status VARCHAR2(10); + l_msg_count NUMBER; + l_msg_data VARCHAR2(1000); + l_vendor_id NUMBER; + + BEGIN + l_vendor_rec.vendor_name := supplier_name; + l_vendor_rec.start_date_active := sysdate ; + + POS_VENDOR_PUB_PKG.create_vendor(p_vendor_rec => l_vendor_rec, + x_return_status => l_return_status, + x_msg_count => l_msg_count, + x_msg_data => l_msg_data, + x_vendor_id => l_vendor_id, + x_party_id => supplier_party_id); + + end create_supplier; + + ---------------------------------------------------------------------- + -- + -- Create Supplier contact for supplier + -- Input (Mandatory) + -- supplier_name: The name of the Supplier organization + -- party_first_name: Supplier contact first name + -- party_last_name: Supplier contact last name + + PROCEDURE create_supplier_contact( supplier_name IN VARCHAR2, + party_first_name IN VARCHAR2, + party_last_name IN VARCHAR2, + party_id OUT number) + is + l_vendor_contact_rec ap_vendor_pub_pkg.r_vendor_contact_rec_type; + l_return_status VARCHAR2(10); + l_msg_count NUMBER; + l_msg_data VARCHAR2(1000); + l_vendor_contact_id NUMBER; + l_per_party_id NUMBER; + l_rel_party_id NUMBER; + l_rel_id NUMBER; + l_org_contact_id NUMBER; + l_party_site_id NUMBER; + + BEGIN + SELECT vendor_id INTO l_vendor_contact_rec.vendor_id + FROM pos_po_vendors_v + WHERE vendor_name = supplier_name; + + l_vendor_contact_rec.person_first_name := party_first_name; + l_vendor_contact_rec.person_last_name := party_last_name; + + + POS_VENDOR_PUB_PKG.create_vendor_contact(p_vendor_contact_rec => l_vendor_contact_rec, + x_return_status => l_return_status, + x_msg_count => l_msg_count, + x_msg_data => l_msg_data, + x_vendor_contact_id => l_vendor_contact_id, + x_per_party_id => party_id, + x_rel_party_id => l_rel_party_id, + x_rel_id => l_rel_id, + x_org_contact_id => l_org_contact_id, + x_party_site_id => l_party_site_id); + + + end create_supplier_contact; + + ---------------------------------------------------------------------- + -- + -- Link Supplier contact party with the user + -- Input (Mandatory) + -- user_name: The name of the Supplier organization + -- party_id: Party id + + procedure link_user_party(user_name varchar2, + party_id number) + is + begin + FND_USER_PKG.UpdateUserParty (user_name,null, null,null,null,null,null, + null,null,null,null,null,null,null, + party_id,null); + end link_user_party; + + procedure create_party( party_last_name IN varchar2, + party_first_name IN varchar2, + user_name IN varchar2, + user_guid IN varchar2 default null, + party_id OUT number) + is + -- Declare cursors and local variables + p_oid_rec fnd_oid_util.ldap_message_type; + x_ret_status varchar2(1000); + BEGIN + + IF party_last_name is NULL THEN + p_oid_rec.sn := fnd_API.G_MISS_CHAR; + ELSE + p_oid_rec.sn := party_last_name; + END IF; + + IF party_first_name is NULL THEN + p_oid_rec.givenName := fnd_API.G_MISS_CHAR; + ELSE + p_oid_rec.givenName := party_first_name; + END IF; + + + p_oid_rec.object_name := user_name; + p_oid_rec.orclGUID := user_guid; + + + -- Start of API + FND_OID_USERS.hz_create(p_oid_rec,x_ret_status); + + if (x_ret_status = fnd_Api.G_RET_STS_SUCCESS) then + select person_party_id into party_id from fnd_user where user_name = p_oid_rec.object_name; + end if; + + EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line(SUBSTR(SQLERRM,1,100)); + END create_party; + + -------Procedure for updating a person party-------- + procedure update_party( party_last_name IN varchar2, + party_first_name IN varchar2, + user_name IN varchar2 , + user_guid IN varchar2 default null) + IS + + -- Declare cursors and local variables + p_oid_rec fnd_oid_util.ldap_message_type; + x_ret_status varchar2(1000); + p_person_rec HZ_PARTY_V2PUB.PERSON_REC_TYPE; + x_profile_id varchar2(1000); + x_msg_data varchar2(1000); + l_party_object_version_number number; + x_msg_count number; + l_init_msg_list varchar2(1000); + p_party_id number; + x_user_name varchar2(1000); + BEGIN + + IF party_last_name is NULL THEN + p_oid_rec.sn := fnd_API.G_MISS_CHAR; + ELSE + p_oid_rec.sn := party_last_name; + END IF; + + IF party_first_name is NULL THEN + p_oid_rec.givenName := fnd_API.G_MISS_CHAR; + ELSE + p_oid_rec.givenName := party_first_name; + END IF; + + p_oid_rec.object_name := user_name; + p_oid_rec.orclGUID := user_guid; + + -- Start of API + fnd_oid_users.hz_update(p_oid_rec,x_ret_status); + if (x_ret_status <> fnd_api.G_RET_STS_SUCCESS) + then + if party_first_name is NULL THEN + p_person_rec.person_first_name := fnd_API.G_MISS_CHAR; + else + p_person_rec.person_first_name := party_first_name; + end if; + p_person_rec.person_last_name := party_last_name; + x_user_name := user_name; + select person_party_id into p_party_id from fnd_user where user_name=x_user_name; + p_person_rec.party_rec.party_id := p_party_id; + SELECT object_version_number into l_party_object_version_number FROM hz_parties WHERE party_id=p_party_id; + HZ_PARTY_V2PUB.update_person ( p_init_msg_list => l_init_msg_list, + p_person_rec => p_person_rec, + p_party_object_version_number => l_party_object_version_number, + x_profile_id => x_profile_id, + x_return_status => x_ret_status, + x_msg_count => x_msg_count, + x_msg_data => x_msg_data); + end if; + EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line(SUBSTR(SQLERRM,1,100)); + END update_party; + + + PROCEDURE validatePartyAndPerson( party_id IN number, + employee_id IN number default null) + IS + x_person_party_id number; + begin + if employee_id is not null then + select party_id into x_person_party_id from per_all_people_f where person_id = employee_id and rownum=1; + if x_person_party_id <> party_id then + raise_application_error(-20101, 'Input party_id and person party id are different'); + end if; + end if; + end validatePartyAndPerson; + + procedure revokeUser(user_id in number) + IS + x_user_name fnd_user.user_name%type; + x_party_id number; + begin + select user_name into x_user_name from fnd_user where user_id=revokeUser.user_id; + disableuser(x_user_name); + end revokeUser; + + procedure addSecurityAttribute(user_id IN number, + security_attribute IN varchar2, + app_id IN varchar2, + security_value IN varchar2) + IS + x_return_status VARCHAR2(2000); + x_msg_count NUMBER; + x_msg_data VARCHAR2(2000); + begin + ICX_USER_SEC_ATTR_PUB.create_user_sec_attr(p_api_version_number => 1, + p_return_status => x_return_status, + p_msg_count => x_msg_count, + p_msg_data => x_msg_data, + p_web_user_id => user_id, + p_attribute_code => security_attribute, + p_attribute_appl_id => app_id, + p_varchar2_value => '', + p_date_value => '', + p_number_value => security_value, + p_created_by => -1, + p_creation_date => sysdate, + p_last_updated_by => -1, + p_last_update_date => sysdate, + p_last_update_login => -1); + end addSecurityAttribute; + + procedure create_supplier_security_attrs(user_name IN varchar2, + supplier_party_id IN number) + IS + l_user_id number; + x_user_name fnd_user.user_name%type; + l_vendor_id number; + begin + x_user_name := user_name; + select user_id into l_user_id from fnd_user where user_name=upper(x_user_name); + select vendor_id into l_vendor_id from ap_suppliers where party_id=supplier_party_id; + + addSecurityAttribute(l_user_id,'ICX_SUPPLIER_ORG_ID',177,l_vendor_id); + + end create_supplier_security_attrs; + + +end OIM_FND_USER_TCA_PKG; + +/ diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OIM_TYPES.pck b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OIM_TYPES.pck new file mode 100644 index 0000000000..da760aa6b8 --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OIM_TYPES.pck @@ -0,0 +1,46 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for EBS UM +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +declare objexist number; +begin + select count(*) into objexist from user_types where type_name='ATTRIBUTEINFO'; + if objexist = 0 then + execute immediate 'create or replace TYPE attributeinfo AS OBJECT (attName VARCHAR2 ( 100 ), attType VARCHAR2 ( 100 ), creatable INTEGER , updatable INTEGER , required INTEGER , readable INTEGER)' ; + end if; +end; +/ + +declare objexist number; +begin + select count(*) into objexist from user_types where type_name='ATTRIBUTELIST'; + if objexist = 0 then + execute immediate 'create or replace type attributelist is varray(100) of attributeinfo' ; + end if; +end; +/ + +declare objexist number; +begin + select count(*) into objexist from user_types where type_name='SCHEMA_OBJECT'; + if objexist = 0 then + execute immediate 'create or replace TYPE schema_object AS OBJECT ( schemaname VARCHAR2 ( 100 ), attr attributelist)' ; + end if; +end; +/ + +declare objexist number; +begin + select count(*) into objexist from user_types where type_name='SCHEMALIST'; + if objexist = 0 then + execute immediate 'create or replace type schemalist is varray(50) of schema_object' ; + end if; +end; +/ + diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OimUser.sql b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OimUser.sql new file mode 100644 index 0000000000..00e403b6ed --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OimUser.sql @@ -0,0 +1,22 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for Creating: Database User & for Granting basic privileges, like: Connect, Create synonym & alter procedure +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +Accept USERNAME prompt"Enter New database Username to be created::" +Accept USERPWD prompt"Enter the New user password::" hide +CREATE USER &USERNAME identified by &USERPWD; +alter user &USERNAME enable editions; +prompt grant connect, resource to &USERNAME; +grant connect, resource to &USERNAME; + +prompt grant create synonym to &USERNAME; +grant create synonym to &USERNAME; + +prompt grant alter any procedure to &USERNAME; +grant alter any procedure to &USERNAME; diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OimUserAD_ZDGrants.sql b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OimUserAD_ZDGrants.sql new file mode 100644 index 0000000000..d166ef0cbf --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OimUserAD_ZDGrants.sql @@ -0,0 +1,139 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for EXECUTE Grant on procedures/packages and Tables required for OIM database USER +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +---- EXECUTE Grant on procedures/packages required for OIM database USER ---- + +prompt exec AD_ZD.grant_privs('EXECUTE','WF_LOCAL_SYNCH','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','WF_LOCAL_SYNCH','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','FND_USER_PKG','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','FND_USER_PKG','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','FND_API','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','FND_API','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','FND_GLOBAL','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','FND_GLOBAL','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','UMX_ACCESS_ROLES_PVT','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','UMX_ACCESS_ROLES_PVT','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','FND_USER_RESP_GROUPS_API','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','FND_USER_RESP_GROUPS_API','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','ICX_USER_SEC_ATTR_PUB','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','ICX_USER_SEC_ATTR_PUB','&USERNAME'); + +---- SELECT Grant on tables required for OIM database USER ---- + +prompt exec AD_ZD.grant_privs('SELECT','FND_APPLICATION','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','FND_APPLICATION','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','FND_RESPONSIBILITY','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','FND_RESPONSIBILITY','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','FND_RESPONSIBILITY_TL','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','FND_RESPONSIBILITY_TL','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','FND_USER_RESP_GROUPS_DIRECT','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','FND_USER_RESP_GROUPS_DIRECT','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','FND_APPLICATION_VL','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','FND_APPLICATION_VL','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','FND_RESPONSIBILITY_VL','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','FND_RESPONSIBILITY_VL','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','FND_SECURITY_GROUPS_VL','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','FND_SECURITY_GROUPS_VL','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','FND_USER_RESP_GROUPS_DIRECT','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','FND_USER_RESP_GROUPS_DIRECT','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','PER_ALL_PEOPLE_F','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','PER_ALL_PEOPLE_F','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','FND_APPLICATION_TL','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','FND_APPLICATION_TL','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','WF_LOCAL_USER_ROLES','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','WF_LOCAL_USER_ROLES','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','WF_USER_ROLES','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','WF_USER_ROLES','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','WF_LOCAL_ROLES','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','WF_LOCAL_ROLES','&USERNAME'); + +---- SELECT, UPDATE Grant on tables required for OIM database USER ---- + +prompt exec AD_ZD.grant_privs('SELECT','FND_USER','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','FND_USER','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','FND_USER','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','FND_USER','&USERNAME'); + +-- Grant execute privileges to the wrapper packages created in APPS schema + +prompt exec AD_ZD.grant_privs('EXECUTE','OIM_FND_GLOBAL','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','OIM_FND_GLOBAL','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','OIM_FND_USER_TCA_PKG','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','OIM_FND_USER_TCA_PKG','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','FND_SECURITY_GROUPS','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','FND_SECURITY_GROUPS','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','FND_SECURITY_GROUPS_TL','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','FND_SECURITY_GROUPS_TL','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','FND_OID_USERS','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','FND_OID_USERS','&USERNAME'); + +prompt exec AD_ZD.grant_privs('EXECUTE','FND_OID_UTIL','&USERNAME'); +exec AD_ZD.grant_privs('EXECUTE','FND_OID_UTIL','&USERNAME'); + +---- SELECT, UPDATE Grant on tables required for OIM database USER ---- + +prompt exec AD_ZD.grant_privs('SELECT','HZ_PARTIES','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','HZ_PARTIES','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','HZ_PARTIES','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','HZ_PARTIES','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','HZ_PERSON_PROFILES','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','HZ_PERSON_PROFILES','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','HZ_PERSON_PROFILES','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','HZ_PERSON_PROFILES','&USERNAME'); + +-- Grant execute privileges to the wrapper packages created in APPS schema + +prompt exec AD_ZD.grant_privs('SELECT','AP_SUPPLIERS','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','AP_SUPPLIERS','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','AP_SUPPLIERS','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','AP_SUPPLIERS','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','AP_SUPPLIER_CONTACTS','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','AP_SUPPLIER_CONTACTS','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','AP_SUPPLIER_CONTACTS','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','AP_SUPPLIER_CONTACTS','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','HZ_RELATIONSHIPS','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','HZ_RELATIONSHIPS','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','HZ_RELATIONSHIPS','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','HZ_RELATIONSHIPS','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','UMX_ROLE_ASSIGNMENTS_V','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','UMX_ROLE_ASSIGNMENTS_V','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','UMX_ROLE_ASSIGNMENTS_V','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','UMX_ROLE_ASSIGNMENTS_V','&USERNAME'); + +prompt exec AD_ZD.grant_privs('SELECT','WF_USER_ROLE_ASSIGNMENTS','&USERNAME'); +exec AD_ZD.grant_privs('SELECT','WF_USER_ROLE_ASSIGNMENTS','&USERNAME'); +prompt exec AD_ZD.grant_privs('UPDATE','WF_USER_ROLE_ASSIGNMENTS','&USERNAME'); +exec AD_ZD.grant_privs('UPDATE','WF_USER_ROLE_ASSIGNMENTS','&USERNAME'); diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OimUserAppstablesSynonyms.sql b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OimUserAppstablesSynonyms.sql new file mode 100644 index 0000000000..863fa36569 --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OimUserAppstablesSynonyms.sql @@ -0,0 +1,94 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for CREATING synonym of procedures/packages and Tables required for OIM database USER +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +prompt Connecting &USERNAME; +accept Databasename prompt"Enter the name of the database ::"; +connect &USERNAME/&USERPWD@&Databasename; + +prompt create or replace synonym FND_RESPONSIBILITY for APPS.FND_RESPONSIBILITY; +create or replace synonym FND_RESPONSIBILITY for APPS.FND_RESPONSIBILITY; + +prompt create or replace synonym FND_APPLICATION for apps.FND_APPLICATION; +create or replace synonym FND_APPLICATION for apps.FND_APPLICATION; + +prompt create or replace synonym FND_RESPONSIBILITY_VL for APPS.FND_RESPONSIBILITY_VL; +create or replace synonym FND_RESPONSIBILITY_VL for APPS.FND_RESPONSIBILITY_VL; + +prompt create or replace synonym FND_SECURITY_GROUPS_VL for APPS.FND_SECURITY_GROUPS_VL; +create or replace synonym FND_SECURITY_GROUPS_VL for APPS.FND_SECURITY_GROUPS_VL; + +prompt create or replace synonym FND_APPLICATION_VL for APPS.FND_APPLICATION_VL; +create or replace synonym FND_APPLICATION_VL for APPS.FND_APPLICATION_VL; + +prompt create or replace synonym FND_USER_RESP_GROUPS_DIRECT for apps.FND_USER_RESP_GROUPS_DIRECT; +create or replace synonym FND_USER_RESP_GROUPS_DIRECT for apps.FND_USER_RESP_GROUPS_DIRECT; + +prompt create or replace synonym FND_USER for APPS.FND_USER; +create or replace synonym FND_USER for APPS.FND_USER; + +prompt create or replace synonym FND_RESPONSIBILITY_TL for APPS.FND_RESPONSIBILITY_TL; +create or replace synonym FND_RESPONSIBILITY_TL for APPS.FND_RESPONSIBILITY_TL; + +prompt create or replace synonym FND_USER_RESP_GROUPS_DIRECT for apps.FND_USER_RESP_GROUPS_DIRECT; +create or replace synonym FND_USER_RESP_GROUPS_DIRECT for apps.FND_USER_RESP_GROUPS_DIRECT; + +prompt create or replace synonym PER_ALL_PEOPLE_F for APPS.PER_ALL_PEOPLE_F ; +create or replace synonym PER_ALL_PEOPLE_F for APPS.PER_ALL_PEOPLE_F ; + +prompt create or replace synonym FND_APPLICATION_TL for APPS.FND_APPLICATION_TL; +create or replace synonym FND_APPLICATION_TL for APPS.FND_APPLICATION_TL; + +prompt create or replace synonym WF_LOCAL_USER_ROLES for APPS.WF_LOCAL_USER_ROLES; +create or replace synonym WF_LOCAL_USER_ROLES for APPS.WF_LOCAL_USER_ROLES; + +prompt create or replace synonym WF_USER_ROLES for APPS.WF_USER_ROLES; +create or replace synonym WF_USER_ROLES for APPS.WF_USER_ROLES; + +prompt create or replace synonym WF_LOCAL_ROLES for APPS.WF_LOCAL_ROLES; +create or replace synonym WF_LOCAL_ROLES for APPS.WF_LOCAL_ROLES; + +prompt create or replace synonym FND_API for APPS.FND_API; +create or replace synonym FND_API for APPS.FND_API; + +prompt create or replace synonym FND_SECURITY_GROUPS for APPS.FND_SECURITY_GROUPS; +create or replace synonym FND_SECURITY_GROUPS for APPS.FND_SECURITY_GROUPS; + +prompt create or replace synonym FND_SECURITY_GROUPS_TL for APPS.FND_SECURITY_GROUPS_TL; +create or replace synonym FND_SECURITY_GROUPS_TL for APPS.FND_SECURITY_GROUPS_TL; + +prompt create or replace synonym HZ_PARTIES for APPS.HZ_PARTIES; +create or replace synonym HZ_PARTIES for APPS.HZ_PARTIES; + +prompt create or replace synonym HZ_PERSON_PROFILES for APPS.HZ_PERSON_PROFILES; +create or replace synonym HZ_PERSON_PROFILES for APPS.HZ_PERSON_PROFILES; + +prompt create or replace synonym FND_OID_USERS for APPS.FND_OID_USERS; +create or replace synonym FND_OID_USERS for APPS.FND_OID_USERS; + +prompt create or replace synonym FND_OID_UTIL for APPS.FND_OID_UTIL; +create or replace synonym FND_OID_UTIL for APPS.FND_OID_UTIL; + +prompt create or replace synonym UMX_ROLE_ASSIGNMENTS_V for APPS.UMX_ROLE_ASSIGNMENTS_V; +create or replace synonym UMX_ROLE_ASSIGNMENTS_V for APPS.UMX_ROLE_ASSIGNMENTS_V; + +prompt create or replace synonym WF_USER_ROLE_ASSIGNMENTS for APPS.WF_USER_ROLE_ASSIGNMENTS; +create or replace synonym WF_USER_ROLE_ASSIGNMENTS for APPS.WF_USER_ROLE_ASSIGNMENTS; + +prompt create or replace synonym AP_SUPPLIERS for APPS.AP_SUPPLIERS; +create or replace synonym AP_SUPPLIERS for APPS.AP_SUPPLIERS; + +prompt create or replace synonym AP_SUPPLIER_CONTACTS for APPS.AP_SUPPLIER_CONTACTS; +create or replace synonym AP_SUPPLIER_CONTACTS for APPS.AP_SUPPLIER_CONTACTS; + +prompt create or replace synonym HZ_RELATIONSHIPS for APPS.HZ_RELATIONSHIPS; +create or replace synonym HZ_RELATIONSHIPS for APPS.HZ_RELATIONSHIPS; + +prompt create or replace synonym ICX_USER_SEC_ATTR_PUB for APPS.ICX_USER_SEC_ATTR_PUB; +create or replace synonym ICX_USER_SEC_ATTR_PUB for APPS.ICX_USER_SEC_ATTR_PUB; diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OimUserGrants.sql b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OimUserGrants.sql new file mode 100644 index 0000000000..27fdca9269 --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OimUserGrants.sql @@ -0,0 +1,129 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for EXECUTE Grant on procedures/packages and Tables required for OIM database USER +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +---- EXECUTE Grant on procedures/packages required for OIM database USER ---- + +prompt grant execute on APPS.WF_LOCAL_SYNCH to &USERNAME; +grant execute on APPS.WF_LOCAL_SYNCH to &USERNAME; + +prompt grant execute on APPS.FND_USER_PKG to &USERNAME; +grant execute on APPS.FND_USER_PKG to &USERNAME; + +prompt grant execute on APPS.FND_API to &USERNAME; +grant execute on APPS.FND_API to &USERNAME; + +prompt grant execute on APPS.FND_GLOBAL to &USERNAME; +grant execute on APPS.FND_GLOBAL to &USERNAME; + +prompt grant execute on APPS.UMX_ACCESS_ROLES_PVT to &USERNAME; +grant execute on APPS.UMX_ACCESS_ROLES_PVT to &USERNAME; + +prompt grant execute on APPS.FND_USER_RESP_GROUPS_API to &USERNAME; +grant execute on APPS.FND_USER_RESP_GROUPS_API to &USERNAME; + +prompt grant execute on APPS.ICX_USER_SEC_ATTR_PUB to &USERNAME; +grant execute on APPS.ICX_USER_SEC_ATTR_PUB to &USERNAME; + +---- SELECT Grant on tables required for OIM database USER ---- + +prompt grant select on APPS.FND_APPLICATION to &USERNAME; +grant select on APPS.FND_APPLICATION to &USERNAME; + +prompt grant select on APPS.FND_RESPONSIBILITY to &USERNAME; +grant select on APPS.FND_RESPONSIBILITY to &USERNAME; + +prompt grant select on APPS.FND_RESPONSIBILITY_TL to &USERNAME; +grant select on APPS.FND_RESPONSIBILITY_TL to &USERNAME; + +prompt grant select on APPS.FND_USER_RESP_GROUPS_DIRECT to &USERNAME; +grant select on APPS.FND_USER_RESP_GROUPS_DIRECT to &USERNAME; + +prompt grant select on APPS.fnd_application_vl to &USERNAME; +grant select on APPS.fnd_application_vl to &USERNAME; + + +prompt grant select on APPS.FND_RESPONSIBILITY_VL to &USERNAME; +grant select on APPS.fnd_responsibility_vl to &USERNAME; + + +prompt grant select on APPS.fnd_security_groups_vl to &USERNAME; +grant select on APPS.fnd_security_groups_vl to &USERNAME; + +prompt grant select on APPS.FND_USER_RESP_GROUPS_DIRECT to &USERNAME; +grant select on APPS.FND_USER_RESP_GROUPS_DIRECT to &USERNAME; + +prompt grant select on APPS.PER_ALL_PEOPLE_F to &USERNAME; +grant select on APPS.PER_ALL_PEOPLE_F to &USERNAME; + +prompt grant select on APPS.FND_APPLICATION_TL to &USERNAME; +grant select on APPS.FND_APPLICATION_TL to &USERNAME; + +prompt grant select on APPS.WF_LOCAL_USER_ROLES to &USERNAME; +grant select on APPS.WF_LOCAL_USER_ROLES to &USERNAME; + +prompt grant select on APPS.WF_USER_ROLES to &USERNAME; +grant select on APPS.WF_USER_ROLES to &USERNAME; + +prompt grant select on APPS.WF_LOCAL_ROLES to &USERNAME; +grant select on APPS.WF_LOCAL_ROLES to &USERNAME; + +---- SELECT, UPDATE Grant on tables required for OIM database USER ---- + +prompt grant select, update on APPS.FND_USER to &USERNAME; +grant select, update on APPS.FND_USER to &USERNAME; + + +-- Grant execute privileges to the wrapper packages created in APPS schema + +prompt grant execute on APPS.OIM_FND_GLOBAL to &USERNAME; +grant execute on APPS.OIM_FND_GLOBAL to &USERNAME; + +prompt grant execute on APPS.OIM_FND_USER_TCA_PKG to &USERNAME; +grant execute on APPS.OIM_FND_USER_TCA_PKG to &USERNAME; + +prompt grant select on apps.fnd_security_groups to &USERNAME; +grant select on apps.fnd_security_groups to &USERNAME; + +prompt grant select on apps.fnd_security_groups_tl to &USERNAME; +grant select on apps.fnd_security_groups_tl to &USERNAME; + +prompt grant execute on APPS.FND_OID_USERS to &USERNAME; +grant execute on APPS.FND_OID_USERS to &USERNAME; + +prompt grant execute on APPS.FND_OID_UTIL to &USERNAME; +grant execute on APPS.FND_OID_UTIL to &USERNAME; + +---- SELECT, UPDATE Grant on tables required for OIM database USER ---- + +prompt grant select, update on APPS.HZ_PARTIES to &USERNAME; +grant select, update on APPS.HZ_PARTIES to &USERNAME; + +prompt grant select, update on APPS.HZ_PERSON_PROFILES to &USERNAME; +grant select, update on APPS.HZ_PERSON_PROFILES to &USERNAME; + +-- Grant execute privileges to the wrapper packages created in APPS schema + +prompt grant select, update on APPS.ap_suppliers to &USERNAME; +grant select, update on APPS.ap_suppliers to &USERNAME; + + +prompt grant select, update on APPS.ap_supplier_contacts to &USERNAME; +grant select, update on APPS.ap_supplier_contacts to &USERNAME; + + +prompt grant select, update on APPS.hz_relationships to &USERNAME; +grant select, update on APPS.hz_relationships to &USERNAME; + +prompt grant select, update on APPS.umx_role_assignments_v to &USERNAME; +grant select, update on APPS.umx_role_assignments_v to &USERNAME; + +prompt grant select, update on APPS.wf_user_role_assignments to &USERNAME; +grant select, update on APPS.wf_user_role_assignments to &USERNAME; + diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OimUserSynonyms.sql b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OimUserSynonyms.sql new file mode 100644 index 0000000000..344e64be1a --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/OimUserSynonyms.sql @@ -0,0 +1,23 @@ +-- Copyright (c) 2023 Oracle and/or its affiliates. +-- +-- Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +-- +-- Author: OIG Development +-- +-- Description: Script file for CREATING synonym of procedures/packages using previously created OimUserAppstablesSynonyms +-- +-- DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +prompt Connecting &USERNAME; +accept Databasename prompt"Enter the name of the database ::"; +connect &USERNAME/&USERPWD@&Databasename; + + +prompt create or replace synonym OIM_FND_USER_TCA_PKG for APPS.OIM_FND_USER_TCA_PKG; +create or replace synonym OIM_FND_USER_TCA_PKG for APPS.OIM_FND_USER_TCA_PKG; + +prompt create or replace synonym OIM_FND_GLOBAL for APPS.OIM_FND_GLOBAL; +create or replace synonym OIM_FND_GLOBAL for APPS.OIM_FND_GLOBAL; + +prompt create or replace synonym WF_LOCAL_SYNCH for APPS.WF_LOCAL_SYNCH; +create or replace synonym WF_LOCAL_SYNCH for APPS.WF_LOCAL_SYNCH; diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/Run_UM_DBScripts.bat b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/Run_UM_DBScripts.bat new file mode 100755 index 0000000000..2d67e7e6d8 --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/Run_UM_DBScripts.bat @@ -0,0 +1,107 @@ +REM Copyright (c) 2023 Oracle and/or its affiliates. +REM +REM Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +REM +REM Author: OIG Development +REM +REM Description: Script file for Creating a service account in EBS target for UM +REM +REM +REM DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +echo off +if exist run.sql del run.sql + +if "%ORACLE_HOME%"=="" ( +SET /p ORACLE_HOME=Enter the ORACLE_HOME :: +) else ( +ECHO ORACLE_HOME is ::%ORACLE_HOME% +) + +SET /p Systemuser=Enter the System User name :: + +SET /p Databasename=Enter the name of the database :: + +REM ---- Create Log file ---- +ECHO SPOOL OIM_APPS_USER.log >> run.sql + +SET /p EBS121X=Are you running this script with EBS target 12.1.x [y/n] :: +IF /I "%EBS121X%" == "yes" ( +goto :yesEBS121X +) else IF /I "%EBS121X%" == "y" ( +goto :yesEBS121X +) else IF /I "%EBS121X%" == "no" ( +goto :noEBS121X +) else IF /I "%EBS121X%" == "n" ( +goto :noEBS121X +) else ( +echo "Invalid option" +goto :end +) + +:yesEBS121X +set EBS121X=Y +goto :continue + +:noEBS121X +set EBS121X=N + +:continue +REM ---- Connecting to DataBase through APPS user---- +ECHO prompt Connecting to APPS >> run.sql +ECHO connect apps@%Databasename% >> run.sql + + +REM ---- Creating packages ---- +ECHO @OIM_TYPES.pck >> run.sql +ECHO @OIM_EBSUM_SCHEMA_PKG.pck >> run.sql +ECHO @OIM_FND_GLOBAL.pck >> run.sql +ECHO @OIM_FND_USER_TCA_PKG.pck >> run.sql +ECHO @GET_LAST_UPDATE_DATE_FUNCTION.pck >> run.sql + +ECHO prompt Disconnecting APPS >> run.sql +ECHO disconn >> run.sql + +REM ---- Connecting to DataBase through System user---- +ECHO prompt Connecting to %Systemuser% >> run.sql +ECHO connect %Systemuser%@%Databasename% >>run.sql + +REM ---- Creating the DataBase User---- +ECHO @OimUser.sql >> run.sql + +IF /I "%EBS121X%" == "Y" ( + REM ---- Executing Grant on procedures/packages and Tables---- + ECHO @OimUserGrants.sql >> run.sql +) + +ECHO prompt Disconnecting %Systemuser% >> run.sql +ECHO disconn >> run.sql + +IF /I "%EBS121X%" == "N" ( + REM ---- Connecting to DataBase through APPS user---- + ECHO prompt Connecting to APPS >> run.sql + ECHO connect apps@%Databasename% >> run.sql + + REM ---- Executing AD_ZD.grant_privs on procedures/packages and Tables---- + ECHO @OimUserAD_ZDGrants.sql >> run.sql + + ECHO prompt Disconnecting APPS >> run.sql + ECHO disconn >> run.sql +) + +REM ---- Creating synonym of procedures/packages and Tables---- +ECHO @OimUserAppstablesSynonyms.sql >> run.sql + +REM ---- Creating synonym of procedures/packages Using previously created OimUserAppstablesSynonyms---- +ECHO @OimUserSynonyms.sql >> run.sql +ECHO @OIM_TYPES.pck >> run.sql +ECHO @OIM_EBSUM_SCHEMA_PKG.pck >> run.sql +ECHO @GET_LAST_UPDATE_DATE_FUNCTION.pck >> run.sql + + +ECHO SPOOL OFF >> run.sql +ECHO EXIT >> run.sql + +%ORACLE_HOME%\bin\sqlplus /nolog @run.sql +del run.sql +:end diff --git a/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/Run_UM_DBScripts.sh b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/Run_UM_DBScripts.sh new file mode 100755 index 0000000000..26ebbdec35 --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/Oracle_EBS_UM/1.0/Run_UM_DBScripts.sh @@ -0,0 +1,116 @@ +#!/bin/sh +# +# Copyright (c) 2023 Oracle and/or its affiliates. +# +# Licensed under the Universal Permissive License v 1.0 as shown at https://oss.oracle.com/licenses/upl. +# +# Author: OIG Development +# +# Description: Script file for Creating a service account in EBS target for UM +# +# +# DO NOT ALTER OR REMOVE COPYRIGHT NOTICES OR THIS HEADER. + +if [ -f run.sql ] +then +rm -f run.sql +fi + +if [ -f "$ORACLE_HOME" ] +then +echo "Enter the ORACLE_HOME ::" +read -r orahome +ORACLE_HOME="$orahome" +else +echo "ORACLE_HOME is ::" +echo "$ORACLE_HOME" +fi + +export ORACLE_HOME + +echo Enter the System User Name :: +read -r Systemuser + +echo Enter the name of the database :: +read -r Databasename + +# ---- User Input to choose Connector ---- + +# ---- Create Log file ---- +echo SPOOL OIM_APPS_USER.log >> run.sql +echo "Are you running this script with EBS target 12.1.x [y/n]: \c" +read -r EBS121X + +if echo "$EBS121X" | grep -qE "^(yes|y)" +then + EBS121X=Y +elif echo "$EBS121X" | grep -qE "^(no|n)" + then + EBS121X=N + else + echo "Invalid Option" + exit +fi + +# ---- Connecting to DataBase through APPS user---- +{ echo prompt Connecting to APPS; + echo connect apps@"$Databasename"; +# ---- Creating packages ---- + echo @OIM_TYPES.pck; + echo @OIM_EBSUM_SCHEMA_PKG.pck; + echo @OIM_FND_GLOBAL.pck; + echo @OIM_FND_USER_TCA_PKG.pck; + echo @GET_LAST_UPDATE_DATE_FUNCTION.pck; + + echo prompt Disconnecting APPS; + echo disconn; + + # ---- Connecting to DataBase through System user---- + echo prompt Connecting to "$Systemuser"; + echo connect "$Systemuser"@"$Databasename"; + # ---- Creating the DataBase User--- + echo @OimUser.sql; +} >> run.sql + + +if echo "$EBS121X" | grep -qE "^(Y)" +then + # ---- Executing grant on procedures/packages and Tables---- + echo @OimUserGrants.sql >> run.sql +fi + +echo prompt Disconnecting "$Systemuser" >> run.sql +echo disconn >> run.sql + +if echo "$EBS121X" | grep -qE "^(N)" +then + + { + # ---- Connecting to DataBase through APPS user---- + echo prompt Connecting to APPS; + echo connect apps@"$Databasename"; + + # ---- Executing AD_ZD.grant_privs on procedures/packages and Tables---- + echo @OimUserAD_ZDGrants.sql; + + echo prompt Disconnecting APPS; + echo disconn; + } >> run.sql +fi + +{ + # ---- Creating synonym of procedures/packages and Tables---- + echo @OimUserAppstablesSynonyms.sql; + + # ---- Creating synonym of procedures/packages Using previously created OimUserAppstablesSynonyms---- + echo @OimUserSynonyms.sql; + echo @OIM_TYPES.pck; + echo @OIM_EBSUM_SCHEMA_PKG.pck; + echo @GET_LAST_UPDATE_DATE_FUNCTION.pck; + + echo SPOOL OFF; + echo EXIT; + } >> run.sql + +"$ORACLE_HOME"/bin/sqlplus /nolog @run.sql +rm -f run.sql diff --git a/OracleIdentityGovernance/samples/scripts/README.md b/OracleIdentityGovernance/samples/scripts/README.md new file mode 100644 index 0000000000..8c6848ea9a --- /dev/null +++ b/OracleIdentityGovernance/samples/scripts/README.md @@ -0,0 +1,11 @@ +# Scripts for connectors + +## Oracle EBS HRMS + +Directory Oracle_EBS_HRMS contains script files for creating a service account in EBS target For HRMS + +## Oracle EBS UM + +Directory Oracle_EBS_UM contains script files for creating a service account in EBS target For UM + +Copyright (c) 2019, 2023 Oracle and/or its affiliates. \ No newline at end of file