Skip to content

Commit 3c3d1a5

Browse files
authored
v0.1-beta POC
Initial POC test
1 parent 5f73c16 commit 3c3d1a5

File tree

1 file changed

+45
-160
lines changed

1 file changed

+45
-160
lines changed

oracle-utilities-merge-script-generator v0.1-beta.sql

Lines changed: 45 additions & 160 deletions
Original file line numberDiff line numberDiff line change
@@ -8,210 +8,95 @@ CREATE OR REPLACE PROCEDURE ADMIN.GENERATE_MERGE_SCRIPT (
88
Status: Passed Unit Testing
99
Purpose: Dynamic generator for Oracle MERGE scripts aligned to Oracle Utilities Application Framework (OUAF)
1010
standards, handling Maintenance Object (MO) JSON parsing, key-based ON clauses, and full datatype mappings.
11-
Execute with parameters (examples):
12-
BEGIN
13-
ADMIN.GENERATE_MERGE_SCRIPT(
14-
p_target_schema => 'CISADM',
15-
p_target_table => 'W1_ACTIVITY',
16-
p_procedure_name => 'PROC_MERGE_INTO_W1_ACTIVITY',
17-
p_maint_obj_name => 'W1-ASSET'
18-
);
19-
END;
20-
/
2111
------------------------------------------------------------------------------------------------------------------------------
22-
Change History
23-
24-
YYYY/MM/DD: developer full name
25-
(* / + / -) A comprehensive description of the changes.
26-
27-
-----------------------------------------------------------------------------------------------------------------------------*/
28-
29-
12+
CREATE OR REPLACE PROCEDURE ADMIN.GENERATE_MERGE_SCRIPT (
3013
p_target_schema IN VARCHAR2,
3114
p_target_table IN VARCHAR2,
3215
p_procedure_name IN VARCHAR2,
3316
p_maint_obj_name IN VARCHAR2
3417
) IS
3518
36-
v_sql CLOB;
37-
v_columns SYS_REFCURSOR;
38-
v_col_name VARCHAR2(128);
39-
v_data_type VARCHAR2(128);
40-
v_data_length NUMBER;
41-
v_data_precision NUMBER;
42-
v_data_scale NUMBER;
43-
v_char_used VARCHAR2(3);
44-
v_char_length NUMBER;
45-
v_on_columns SYS.DBMS_DEBUG_VC2COLL := SYS.DBMS_DEBUG_VC2COLL();
46-
v_json_table_cols CLOB;
47-
v_select_cols CLOB;
48-
v_update_set CLOB;
49-
v_insert_cols CLOB;
50-
v_insert_vals CLOB;
51-
v_on_clause CLOB;
52-
v_col_index INTEGER := 0;
53-
v_total_cols INTEGER;
19+
v_sql CLOB;
20+
v_columns SYS_REFCURSOR;
21+
v_col_name VARCHAR2(128);
22+
v_data_type VARCHAR2(128);
23+
v_on_clause VARCHAR2(4000);
24+
v_update_set VARCHAR2(4000);
25+
v_insert_cols VARCHAR2(4000);
26+
v_insert_vals VARCHAR2(4000);
27+
v_json_table_columns VARCHAR2(4000);
5428
BEGIN
55-
-- Fetch ON clause columns based on W1%P0 index
56-
SELECT COLUMN_NAME
57-
BULK COLLECT INTO v_on_columns
58-
FROM ALL_IND_COLUMNS
59-
WHERE TABLE_OWNER = UPPER(p_target_schema)
60-
AND TABLE_NAME = UPPER(p_target_table)
61-
AND INDEX_NAME IN (
62-
SELECT INDEX_NAME
63-
FROM ALL_INDEXES
64-
WHERE TABLE_OWNER = UPPER(p_target_schema)
65-
AND TABLE_NAME = UPPER(p_target_table)
66-
AND INDEX_NAME LIKE 'W1%P0'
67-
AND UNIQUENESS = 'UNIQUE'
68-
)
69-
ORDER BY COLUMN_POSITION;
70-
71-
-- Find the total number of columns once to control commas
72-
SELECT COUNT(*)
73-
INTO v_total_cols
74-
FROM ALL_TAB_COLUMNS
75-
WHERE OWNER = UPPER(p_target_schema)
76-
AND TABLE_NAME = UPPER(p_target_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);
29+
v_sql := 'CREATE OR REPLACE PROCEDURE ' || p_procedure_name || ' AS ' || CHR(10);
9130
v_sql := v_sql || 'BEGIN' || CHR(10);
9231
v_sql := v_sql || 'MERGE INTO ' || p_target_schema || '.' || p_target_table || ' tgt' || CHR(10);
9332
v_sql := v_sql || 'USING (' || CHR(10);
9433
v_sql := v_sql || ' WITH ranked AS (' || CHR(10);
95-
v_sql := v_sql || ' SELECT' || CHR(10);
34+
v_sql := v_sql || ' SELECT ' || CHR(10);
9635
v_sql := v_sql || ' stg.PK1,' || CHR(10);
9736
v_sql := v_sql || ' stg.OBJ,' || CHR(10);
9837
v_sql := v_sql || ' stg.UPDATED_TIMESTAMP,' || CHR(10);
9938
10039
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;
40+
SELECT COLUMN_NAME, DATA_TYPE
41+
FROM ALL_TAB_COLUMNS
42+
WHERE OWNER = UPPER(p_target_schema)
43+
AND TABLE_NAME = UPPER(p_target_table)
44+
AND COLUMN_NAME NOT IN ('OBJ', 'PK1', 'PK2', 'PK3', 'PK4', 'PK5', 'DELETED', 'JSON_DATA', 'EXPORTED_TIMESTAMP', 'MERGED_TIMESTAMP', 'INGEST_ID', 'INGEST_VERSION')
45+
ORDER BY COLUMN_ID;
10746
10847
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;
48+
FETCH v_columns INTO v_col_name, v_data_type;
11049
EXIT WHEN v_columns%NOTFOUND;
111-
v_col_index := v_col_index + 1;
11250
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;
51+
-- JSON_TABLE Columns
52+
IF v_data_type LIKE '%DATE%' OR v_col_name LIKE '%_DT' THEN
53+
v_json_table_columns := v_json_table_columns || v_col_name || '_STR VARCHAR2(50) PATH ''$.' || v_col_name || ''',' || CHR(10);
54+
ELSIF v_data_type LIKE '%TIMESTAMP%' OR v_col_name LIKE '%_DTTM' THEN
55+
v_json_table_columns := v_json_table_columns || v_col_name || '_STR VARCHAR2(50) PATH ''$.' || v_col_name || ''',' || CHR(10);
14456
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;
57+
v_json_table_columns := v_json_table_columns || v_col_name || ' ' || v_data_type || ' PATH ''$.' || v_col_name || ''',' || CHR(10);
14758
END IF;
14859
149-
IF v_col_index < v_total_cols THEN
150-
v_json_table_cols := v_json_table_cols || ',' || CHR(10);
151-
v_select_cols := v_select_cols || ',' || CHR(10);
152-
ELSE
153-
v_json_table_cols := v_json_table_cols || CHR(10);
154-
v_select_cols := v_select_cols || CHR(10);
60+
-- UPDATE and INSERT Clauses
61+
IF v_update_set IS NOT NULL THEN
62+
v_update_set := v_update_set || ',' || CHR(10);
15563
END IF;
64+
v_update_set := v_update_set || ' tgt.' || v_col_name || ' = src.' || v_col_name;
15665
157-
-- Build UPDATE SET only if column is NOT in ON clause
158-
DECLARE
159-
l_found BOOLEAN := FALSE;
160-
BEGIN
161-
FOR i IN 1 .. v_on_columns.COUNT LOOP
162-
IF v_on_columns(i) = v_col_name THEN
163-
l_found := TRUE;
164-
EXIT;
165-
END IF;
166-
END LOOP;
167-
IF NOT l_found THEN
168-
v_update_set := v_update_set || ' tgt.' || v_col_name || ' = src.' || v_col_name;
169-
IF v_col_index < v_total_cols THEN
170-
v_update_set := v_update_set || ',' || CHR(10);
171-
ELSE
172-
v_update_set := v_update_set || CHR(10);
173-
END IF;
174-
END IF;
175-
END;
176-
177-
-- Build INSERT columns and values always
178-
v_insert_cols := v_insert_cols || ' ' || v_col_name;
179-
v_insert_vals := v_insert_vals || ' src.' || v_col_name;
180-
IF v_col_index < v_total_cols THEN
66+
IF v_insert_cols IS NOT NULL THEN
18167
v_insert_cols := v_insert_cols || ',' || CHR(10);
18268
v_insert_vals := v_insert_vals || ',' || CHR(10);
183-
ELSE
184-
v_insert_cols := v_insert_cols || CHR(10);
185-
v_insert_vals := v_insert_vals || CHR(10);
18669
END IF;
70+
v_insert_cols := v_insert_cols || ' ' || v_col_name;
71+
v_insert_vals := v_insert_vals || ' src.' || v_col_name;
18772
END LOOP;
18873
CLOSE v_columns;
18974
190-
-- Assemble full SQL
191-
v_sql := v_sql || v_select_cols || ' ,ROW_NUMBER() OVER (PARTITION BY stg.PK1 ORDER BY stg.UPDATED_TIMESTAMP DESC) AS rn' || CHR(10);
75+
v_sql := v_sql || ' jt.*,' || CHR(10);
76+
v_sql := v_sql || ' ROW_NUMBER() OVER (PARTITION BY stg.PK1 ORDER BY stg.UPDATED_TIMESTAMP DESC) AS rn' || CHR(10);
19277
v_sql := v_sql || ' FROM ADMIN.STG_GDE_MO stg,' || CHR(10);
19378
v_sql := v_sql || ' JSON_TABLE(' || CHR(10);
19479
v_sql := v_sql || ' stg.JSON_DATA,' || CHR(10);
195-
v_sql := v_sql || ' ''$.' || p_target_table || '[*]'' COLUMNS (' || CHR(10);
196-
v_sql := v_sql || v_json_table_cols;
80+
v_sql := v_sql || ' ''$.' || p_maint_obj_name || '[*]'' COLUMNS (' || CHR(10);
81+
v_sql := v_sql || v_json_table_columns || CHR(10);
19782
v_sql := v_sql || ' )' || CHR(10);
19883
v_sql := v_sql || ' ) jt' || CHR(10);
19984
v_sql := v_sql || ' )' || CHR(10);
200-
v_sql := v_sql || ' SELECT r.*' || CHR(10);
201-
v_sql := v_sql || ' FROM ranked r' || CHR(10);
202-
v_sql := v_sql || ' WHERE (1=1)' || CHR(10);
203-
v_sql := v_sql || ' AND r.rn = 1' || CHR(10);
204-
v_sql := v_sql || ' AND r.OBJ = ''' || p_maint_obj_name || '''' || CHR(10);
20585
v_sql := v_sql || ') src' || CHR(10);
206-
v_sql := v_sql || v_on_clause || CHR(10);
86+
v_sql := v_sql || 'ON (' || CHR(10);
87+
v_sql := v_sql || ' -- TODO: Add ON conditions manually if needed' || CHR(10);
88+
v_sql := v_sql || ')' || CHR(10);
20789
v_sql := v_sql || 'WHEN MATCHED THEN UPDATE SET' || CHR(10);
208-
v_sql := v_sql || v_update_set;
90+
v_sql := v_sql || v_update_set || CHR(10);
20991
v_sql := v_sql || 'WHEN NOT MATCHED THEN INSERT (' || CHR(10);
210-
v_sql := v_sql || v_insert_cols;
92+
v_sql := v_sql || v_insert_cols || CHR(10);
21193
v_sql := v_sql || ') VALUES (' || CHR(10);
212-
v_sql := v_sql || v_insert_vals;
94+
v_sql := v_sql || v_insert_vals || CHR(10);
21395
v_sql := v_sql || ');' || CHR(10);
21496
v_sql := v_sql || 'END;';
21597
98+
-- Output the generated SQL
21699
DBMS_OUTPUT.PUT_LINE(v_sql);
100+
217101
END;
102+
/

0 commit comments

Comments
 (0)