Skip to content

Commit 5f73c16

Browse files
authored
v1.0.0 Passed SIT
1 parent 7de25cd commit 5f73c16

File tree

1 file changed

+221
-0
lines changed

1 file changed

+221
-0
lines changed
Lines changed: 221 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,221 @@
1+
CREATE OR REPLACE PROCEDURE ADMIN.GENERATE_MERGE_SCRIPT (
2+
3+
/*-----------------------------------------------------------------------------------------------------------------------------
4+
Procedure: ORACLE UTILITIES MERGE SCRIPT GENERATOR
5+
Author: Sheldon Bateman (sheldon@gravityconsultingus.com)
6+
Created: 2025/04/30
7+
Version: v1.0.0
8+
Status: Passed SIT for selected MOs
9+
Purpose: Dynamic generator for Oracle MERGE scripts aligned to Oracle Utilities Application Framework (OUAF)
10+
standards, handling Maintenance Object (MO) JSON parsing, key-based ON clauses, and full datatype mappings.
11+
Execute with parameters (examples):
12+
GENERATE_MERGE_SCRIPT(
13+
p_target_schema => 'CISADM',
14+
p_target_table => 'W1_ACTIVITY',
15+
p_procedure_name => 'PROC_MERGE_INTO_W1_ACTIVITY',
16+
p_maint_obj_name => 'W1-ASSET'
17+
)
18+
------------------------------------------------------------------------------------------------------------------------------
19+
Change History
20+
21+
YYYY/MM/DD: developer full name
22+
(* / + / -) A comprehensive description of the changes.
23+
24+
-----------------------------------------------------------------------------------------------------------------------------*/
25+
26+
27+
p_target_schema IN VARCHAR2
28+
,p_target_table IN VARCHAR2
29+
,p_procedure_name IN VARCHAR2
30+
,p_maint_obj_name IN VARCHAR2
31+
) IS
32+
33+
v_sql CLOB;
34+
v_columns SYS_REFCURSOR;
35+
v_col_name VARCHAR2(128);
36+
v_data_type VARCHAR2(128);
37+
v_data_length NUMBER;
38+
v_data_precision NUMBER;
39+
v_data_scale NUMBER;
40+
v_char_used VARCHAR2(3);
41+
v_char_length NUMBER;
42+
v_on_columns SYS.DBMS_DEBUG_VC2COLL := SYS.DBMS_DEBUG_VC2COLL();
43+
v_json_table_cols CLOB;
44+
v_select_cols CLOB;
45+
v_update_set CLOB;
46+
v_insert_cols CLOB;
47+
v_insert_vals CLOB;
48+
v_on_clause CLOB;
49+
v_col_index INTEGER := 0;
50+
v_total_cols INTEGER;
51+
52+
BEGIN
53+
-- Fetch ON clause columns based on W1%P0 index
54+
SELECT COLUMN_NAME
55+
BULK COLLECT INTO v_on_columns
56+
FROM ALL_IND_COLUMNS
57+
WHERE TABLE_OWNER = UPPER(p_target_schema)
58+
AND TABLE_NAME = UPPER(p_target_table)
59+
AND INDEX_NAME IN (
60+
SELECT INDEX_NAME
61+
FROM ALL_INDEXES
62+
WHERE TABLE_OWNER = UPPER(p_target_schema)
63+
AND TABLE_NAME = UPPER(p_target_table)
64+
AND INDEX_NAME LIKE 'W1%P0'
65+
AND UNIQUENESS = 'UNIQUE'
66+
)
67+
ORDER BY COLUMN_POSITION;
68+
69+
-- Find the total number of columns once to control trailing commas in dynamic lists
70+
SELECT COUNT(*)
71+
INTO v_total_cols
72+
FROM ALL_TAB_COLUMNS
73+
WHERE OWNER = UPPER(p_target_schema)
74+
AND TABLE_NAME = UPPER(p_target_table)
75+
76+
-- IN set is based on pre-defined staging table
77+
AND COLUMN_NAME NOT IN ('OBJ', 'PK1', 'PK2', 'PK3', 'PK4', 'PK5', 'DELETED', 'JSON_DATA', 'EXPORTED_TIMESTAMP', 'MERGED_TIMESTAMP', 'INGEST_ID', 'INGEST_VERSION');
78+
79+
-- Build the ON clause text
80+
FOR i IN 1 .. v_on_columns.COUNT LOOP
81+
IF i > 1 THEN
82+
v_on_clause := v_on_clause || ' AND ';
83+
ELSE
84+
v_on_clause := v_on_clause || 'ON (' || CHR(10) || ' ';
85+
END IF;
86+
v_on_clause := v_on_clause || 'tgt.' || v_on_columns(i) || ' = src.' || v_on_columns(i) || CHR(10);
87+
END LOOP;
88+
v_on_clause := v_on_clause || ')';
89+
90+
v_sql := 'CREATE OR REPLACE PROCEDURE ' || p_procedure_name || ' AS' || CHR(10);
91+
v_sql := v_sql || 'BEGIN' || CHR(10);
92+
v_sql := v_sql || 'MERGE INTO ' || p_target_schema || '.' || p_target_table || ' tgt' || CHR(10);
93+
v_sql := v_sql || 'USING (' || CHR(10);
94+
v_sql := v_sql || ' WITH ranked AS (' || CHR(10);
95+
v_sql := v_sql || ' SELECT' || CHR(10);
96+
v_sql := v_sql || ' stg.PK1,' || CHR(10);
97+
v_sql := v_sql || ' stg.OBJ,' || CHR(10);
98+
v_sql := v_sql || ' stg.UPDATED_TIMESTAMP,' || CHR(10);
99+
100+
OPEN v_columns FOR
101+
SELECT COLUMN_NAME, DATA_TYPE, DATA_LENGTH, DATA_PRECISION, DATA_SCALE, CHAR_USED, CHAR_LENGTH
102+
FROM ALL_TAB_COLUMNS
103+
WHERE OWNER = UPPER(p_target_schema)
104+
AND TABLE_NAME = UPPER(p_target_table)
105+
AND COLUMN_NAME NOT IN ('OBJ', 'PK1', 'PK2', 'PK3', 'PK4', 'PK5', 'DELETED', 'JSON_DATA', 'EXPORTED_TIMESTAMP', 'MERGED_TIMESTAMP', 'INGEST_ID', 'INGEST_VERSION')
106+
ORDER BY COLUMN_ID;
107+
108+
LOOP
109+
FETCH v_columns INTO v_col_name, v_data_type, v_data_length, v_data_precision, v_data_scale, v_char_used, v_char_length;
110+
EXIT WHEN v_columns%NOTFOUND;
111+
v_col_index := v_col_index + 1;
112+
113+
-- Build JSON_TABLE COLUMNS and SELECT
114+
IF v_col_name LIKE '%_DTTM' THEN
115+
v_json_table_cols := v_json_table_cols || ' ' || v_col_name || '_STR VARCHAR2(50) PATH ''$.' || v_col_name || '''';
116+
DECLARE
117+
l_dttm_in_on_clause BOOLEAN := FALSE;
118+
BEGIN
119+
FOR i IN 1 .. v_on_columns.COUNT LOOP
120+
IF v_on_columns(i) = v_col_name THEN
121+
l_dttm_in_on_clause := TRUE;
122+
EXIT;
123+
END IF;
124+
END LOOP;
125+
IF l_dttm_in_on_clause THEN
126+
v_select_cols := v_select_cols || ' CAST(TO_TIMESTAMP_TZ(jt.' || v_col_name || '_STR, ''YYYY-MM-DD"T"HH24:MI:SS.FF3TZR'') AS DATE) AS ' || v_col_name;
127+
ELSE
128+
v_select_cols := v_select_cols || ' TO_TIMESTAMP_TZ(jt.' || v_col_name || '_STR, ''YYYY-MM-DD"T"HH24:MI:SS.FF3TZR'') AS ' || v_col_name;
129+
END IF;
130+
END;
131+
ELSIF v_col_name LIKE '%_DT' THEN
132+
v_json_table_cols := v_json_table_cols || ' ' || v_col_name || '_STR VARCHAR2(50) PATH ''$.' || v_col_name || '''';
133+
v_select_cols := v_select_cols || ' CAST(TO_TIMESTAMP_TZ(jt.' || v_col_name || '_STR, ''YYYY-MM-DD"T"HH24:MI:SS.FF3TZR'') AS DATE) AS ' || v_col_name;
134+
ELSIF v_data_type IN ('VARCHAR2', 'CHAR') THEN
135+
v_json_table_cols := v_json_table_cols || ' ' || v_col_name || ' VARCHAR2(' || v_char_length || ') PATH ''$.' || v_col_name || '''';
136+
v_select_cols := v_select_cols || ' jt.' || v_col_name;
137+
ELSIF v_data_type = 'NUMBER' THEN
138+
IF v_data_precision IS NOT NULL THEN
139+
v_json_table_cols := v_json_table_cols || ' ' || v_col_name || ' NUMBER(' || v_data_precision || CASE WHEN v_data_scale IS NOT NULL THEN ',' || v_data_scale ELSE '' END || ') PATH ''$.' || v_col_name || '''';
140+
ELSE
141+
v_json_table_cols := v_json_table_cols || ' ' || v_col_name || ' NUMBER PATH ''$.' || v_col_name || '''';
142+
END IF;
143+
v_select_cols := v_select_cols || ' jt.' || v_col_name;
144+
ELSE
145+
v_json_table_cols := v_json_table_cols || ' ' || v_col_name || ' ' || v_data_type || ' PATH ''$.' || v_col_name || '''';
146+
v_select_cols := v_select_cols || ' jt.' || v_col_name;
147+
END IF;
148+
149+
-- Controls the trailing comma in the dynamic list
150+
IF v_col_index < v_total_cols THEN
151+
v_json_table_cols := v_json_table_cols || ',' || CHR(10);
152+
v_select_cols := v_select_cols || ',' || CHR(10);
153+
ELSE
154+
v_json_table_cols := v_json_table_cols || CHR(10);
155+
v_select_cols := v_select_cols || CHR(10);
156+
END IF;
157+
158+
-- Build UPDATE SET only if column is NOT in ON clause
159+
DECLARE
160+
l_found BOOLEAN := FALSE;
161+
BEGIN
162+
FOR i IN 1 .. v_on_columns.COUNT LOOP
163+
IF v_on_columns(i) = v_col_name THEN
164+
l_found := TRUE;
165+
EXIT;
166+
END IF;
167+
END LOOP;
168+
169+
-- Controls the trailing comma in the dynamic list
170+
IF NOT l_found THEN
171+
v_update_set := v_update_set || ' tgt.' || v_col_name || ' = src.' || v_col_name;
172+
IF v_col_index < v_total_cols THEN
173+
v_update_set := v_update_set || ',' || CHR(10);
174+
ELSE
175+
v_update_set := v_update_set || CHR(10);
176+
END IF;
177+
END IF;
178+
END;
179+
180+
-- Build INSERT columns and values always
181+
v_insert_cols := v_insert_cols || ' ' || v_col_name;
182+
v_insert_vals := v_insert_vals || ' src.' || v_col_name;
183+
IF v_col_index < v_total_cols THEN
184+
v_insert_cols := v_insert_cols || ',' || CHR(10);
185+
v_insert_vals := v_insert_vals || ',' || CHR(10);
186+
ELSE
187+
v_insert_cols := v_insert_cols || CHR(10);
188+
v_insert_vals := v_insert_vals || CHR(10);
189+
END IF;
190+
END LOOP;
191+
CLOSE v_columns;
192+
193+
-- Assemble full SQL
194+
-- CTE is not part of the column list loop so a prepended comma is required for it to be appended to the list
195+
v_sql := v_sql || v_select_cols || ' ,ROW_NUMBER() OVER (PARTITION BY stg.PK1 ORDER BY stg.UPDATED_TIMESTAMP DESC) AS rn' || CHR(10);
196+
v_sql := v_sql || ' FROM ADMIN.STG_GDE_MO stg,' || CHR(10);
197+
v_sql := v_sql || ' JSON_TABLE(' || CHR(10);
198+
v_sql := v_sql || ' stg.JSON_DATA,' || CHR(10);
199+
v_sql := v_sql || ' ''$.' || p_target_table || '[*]'' COLUMNS (' || CHR(10);
200+
v_sql := v_sql || v_json_table_cols;
201+
v_sql := v_sql || ' )' || CHR(10);
202+
v_sql := v_sql || ' ) jt' || CHR(10);
203+
v_sql := v_sql || ' )' || CHR(10);
204+
v_sql := v_sql || ' SELECT r.*' || CHR(10);
205+
v_sql := v_sql || ' FROM ranked r' || CHR(10);
206+
v_sql := v_sql || ' WHERE (1=1)' || CHR(10);
207+
v_sql := v_sql || ' AND r.rn = 1' || CHR(10);
208+
v_sql := v_sql || ' AND r.OBJ = ''' || p_maint_obj_name || '''' || CHR(10);
209+
v_sql := v_sql || ') src' || CHR(10);
210+
v_sql := v_sql || v_on_clause || CHR(10);
211+
v_sql := v_sql || 'WHEN MATCHED THEN UPDATE SET' || CHR(10);
212+
v_sql := v_sql || v_update_set;
213+
v_sql := v_sql || 'WHEN NOT MATCHED THEN INSERT (' || CHR(10);
214+
v_sql := v_sql || v_insert_cols;
215+
v_sql := v_sql || ') VALUES (' || CHR(10);
216+
v_sql := v_sql || v_insert_vals;
217+
v_sql := v_sql || ');' || CHR(10);
218+
v_sql := v_sql || 'END;';
219+
220+
DBMS_OUTPUT.PUT_LINE(v_sql);
221+
END;

0 commit comments

Comments
 (0)