mercoledì 23 agosto 2017

[Oracle Tips] Changing Default End Date in SCD KM

ODI has an IKM for Loading SCD Type 2 dimensions. The IKM is 'IKM Oracle Slowly Changing Dimension'. The default value for Slow Changing Dimension (SCD) Type 2 End Date is "01 January 2400".
You may need to change this End Date value because of the source data that you are using to populate the Slowly Changing Dimension. In a recent project, I had to deliver an integration between Oracle Fusion HCM and an on-premise DWH. The End Date for Fusion HCM objects is "31-December-4712". So, if you want to use the ODI IKM to create SCDs you need to customize it.
To do so, first you need to create a copy of the default IKM.

Then open the duplicated object and locate the steps where the default End Date is used.
The step that needs to be customized is 'Insert flow into I$ table'. Edit the Target code to replace '2400-01-01' with '4712-12-31' or whichever value you want to use as End Date.


Once it is done, then you can use this customized IKM in your interfaces for populating SCDs Type 2. 





martedì 22 agosto 2017

[Oracle Tips] Looking for a value in all table columns of a database schema

I have been working on a project where honestly I did not have much knowledge of the data model of the schema I was using. Most of the times I had to figure out in which table (and column) I could find a certain value. Not the best strategy, but Oracle documentation and the project schedule were not not of much help.
The following procedure was extremely useful and has helped me out in many occasions. Depending on the size of the tables that are being scanned, the procedure can take quite a long time to be executed, but it will retrieve all the values that match 'v_search_string' in any column of the datatype and the schema specified as a parameters.

set serveroutput on size 100000;

declare
    v_match_count integer;
    v_counter integer;

    -- The owner of the tables to search through (case-sensitive)

    v_owner varchar2(255) := 'SCHEMA_OWNER';
    -- A string that is part of the data type(s) of the columns to search through (case-insensitive)
    v_data_type varchar2(255) := 'COLUMN_DATATYPE';
    -- The string to be searched for (case-insensitive)
    v_search_string varchar2(4000) := 'VALUE_TO_BE_SEARCHED';

    -- Store the SQL to execute for each table in a CLOB to get around the 32767 byte max size for a VARCHAR2 in PL/SQL
    v_sql clob := '';
begin
    for cur_tables in (select owner, table_name from all_tables where owner = v_owner and table_name in
                       (select table_name from all_tab_columns where owner = all_tables.owner and data_type like '%' ||  upper(v_data_type) || '%')
                       order by table_name) loop
        v_counter := 0;
        v_sql := '';

        for cur_columns in (select column_name from all_tab_columns where
                            owner = v_owner and table_name = cur_tables.table_name and data_type like '%' || upper(v_data_type) || '%') loop
            if v_counter > 0 then
                v_sql := v_sql || ' or ';
            end if;
            v_sql := v_sql || 'upper(' || cur_columns.column_name || ') like ''%' || upper(v_search_string) || '%''';
            v_counter := v_counter + 1;
        end loop;

        v_sql := 'select count(*) from '  || v_owner || '.' || cur_tables.table_name || ' where ' || v_sql;

        execute immediate v_sql
        into v_match_count;

        if v_match_count > 0 then
            dbms_output.put_line('Match in ' || cur_tables.owner || ': ' || cur_tables.table_name || ' - ' || v_match_count || ' records');
        end if;
    end loop;

    exception
        when others then
            dbms_output.put_line('Error when executing the following: ' || dbms_lob.substr(v_sql, 32600));
end;
/



Here is the output of the procedure if I look for 'CRISTINA' string of 'VARCHAR' type in any table column in the 'A' schema: 




Note: the procedure will work only if you have the right privileges to query all_tables and all_tab_columns and you have at least read privileges to the schema