diff --git a/plex_install.sql b/plex_install.sql index 1b617fc..909e027 100644 --- a/plex_install.sql +++ b/plex_install.sql @@ -581,10 +581,13 @@ PROCEDURE util_clob_query_to_csv ( p_header_prefix IN VARCHAR2 DEFAULT NULL); PROCEDURE util_clob_table_to_insert ( - p_table_name IN VARCHAR2, - p_data_scn IN NUMBER, - p_max_rows IN NUMBER DEFAULT 1000, - p_insert_all_size IN NUMBER DEFAULT 10); + p_table_name IN VARCHAR2, + p_data_scn IN NUMBER, + p_max_rows IN NUMBER DEFAULT 1000, + p_insert_style IN VARCHAR2 DEFAULT 'INSERT', -- can be INSERT or OM_TAPIGEN + p_insert_all_size IN NUMBER DEFAULT 10, + p_exclude_columns_list IN VARCHAR2 DEFAULT NULL -- a colon separated list of columns that should be excluded for the insert operation (for example audit columns which are populated automatically) FIXME: support the auto detection of an column prefix +); PROCEDURE util_clob_create_runtime_log (p_export_files IN OUT NOCOPY tab_export_files); @@ -846,10 +849,13 @@ PROCEDURE util_clob_query_to_csv ( p_header_prefix IN VARCHAR2 DEFAULT NULL); PROCEDURE util_clob_table_to_insert ( - p_table_name IN VARCHAR2, - p_data_scn IN NUMBER, - p_max_rows IN NUMBER DEFAULT 1000, - p_insert_all_size IN NUMBER DEFAULT 10); + p_table_name IN VARCHAR2, + p_data_scn IN NUMBER, + p_max_rows IN NUMBER DEFAULT 1000, + p_insert_style IN VARCHAR2 DEFAULT 'INSERT', -- can be INSERT or OM_TAPIGEN + p_insert_all_size IN NUMBER DEFAULT 10, + p_exclude_columns_list IN VARCHAR2 DEFAULT NULL -- a list of columns that should be excluded for the insert operation (for example audit columns which are populated automatically) FIXME: support the auto detection of an column prefix +); PROCEDURE util_clob_create_runtime_log (p_export_files IN OUT NOCOPY tab_export_files); @@ -1595,11 +1601,15 @@ END util_clob_query_to_csv; -------------------------------------------------------------------------------------------------------------------------------- PROCEDURE util_clob_table_to_insert ( - p_table_name IN VARCHAR2, - p_data_scn IN NUMBER, - p_max_rows IN NUMBER DEFAULT 1000, - p_insert_all_size IN NUMBER DEFAULT 10) + p_table_name IN VARCHAR2, + p_data_scn IN NUMBER, + p_max_rows IN NUMBER DEFAULT 1000, + p_insert_style IN VARCHAR2 DEFAULT 'INSERT', + p_insert_all_size IN NUMBER DEFAULT 10, + p_exclude_columns_list IN VARCHAR2 DEFAULT NULL) IS + v_insert_style VARCHAR2(30); + v_exclude_columns_list VARCHAR2(32767); v_nls rec_nls; v_query VARCHAR2(32767); v_cursor PLS_INTEGER; @@ -1619,6 +1629,12 @@ IS ---------------------------------------------------------------- + PROCEDURE init IS + BEGIN + v_insert_style := trim(upper(substr(p_insert_style,1,30))); + v_exclude_columns_list := trim(upper(p_exclude_columns_list)) || ':'; + END; + PROCEDURE get_session_nls_params IS BEGIN -- Save current values. @@ -1808,6 +1824,7 @@ IS where table_name = p_table_name and user_generated = 'YES' and virtual_column = 'NO' + and instr(v_exclude_columns_list, ':'||column_name||':') = 0 group by table_name ) LOOP v_query := i.query; @@ -1829,13 +1846,20 @@ IS ELSE dbms_sql.define_column(v_cursor, i, v_buffer_varchar2, c_vc2_max_size); END IF; - v_table_insert_prefix := v_table_insert_prefix || v_desc_tab(i).col_name || ','; + IF v_insert_style = 'INSERT' THEN + v_table_insert_prefix := v_table_insert_prefix || v_desc_tab(i).col_name || ','; + END IF; END LOOP; v_table_insert_prefix := - case when p_insert_all_size > 0 - then 'into ' - else 'insert into ' - end || p_table_name || '(' || rtrim(v_table_insert_prefix, ',' ) || ') values ('; + CASE v_insert_style + WHEN 'INSERT' THEN + case when p_insert_all_size > 0 + then 'into ' + else 'insert into ' + end || p_table_name || '(' || rtrim(v_table_insert_prefix, ',' ) || ') values (' + WHEN 'OM_TAPIGEN' THEN + lower(p_table_name) || '_api.create_or_update_row(' + END; v_ignore_me := dbms_sql.execute(v_cursor); END IF; END parse_query_and_describe_cols; @@ -1849,8 +1873,10 @@ IS PROCEDURE create_header IS BEGIN util_clob_append('-- Script generated by PLEX version ' || c_plex_version || ' - more infos here: ' || c_plex_url || c_crlf); - util_clob_append('-- Performance Hacks by Connor McDonald: https://connor-mcdonald.com/2019/05/17/hacking-together-faster-inserts/' || c_crlf); - util_clob_append('-- For strange line end replacements a big thank to SQL*Plus: https://support.oracle.com/epmos/faces/DocumentDisplay?id=2377701.1 (SQL Failed With ORA-1756 In Sqlplus But Works In SQL Developer)' || c_crlf); + if v_insert_style = 'INSERT' then + util_clob_append('-- Performance Hacks by Connor McDonald: https://connor-mcdonald.com/2019/05/17/hacking-together-faster-inserts/' || c_crlf); + util_clob_append('-- For strange line end replacements a big thank to SQL*Plus: https://support.oracle.com/epmos/faces/DocumentDisplay?id=2377701.1 (SQL Failed With ORA-1756 In Sqlplus But Works In SQL Developer)' || c_crlf); + end if; util_clob_append('prompt - insert xxx rows into ' || p_table_name || ' (exported ' || to_char(systimestamp,'YYYY-MM-DD hh24:mi:ssxff TZR') || ')' || c_crlf); util_clob_append('set define off feedback off sqlblanklines on' || c_crlf); util_clob_append('alter session set cursor_sharing = force;' || c_crlf); @@ -1871,12 +1897,15 @@ IS if v_data_count = 1 then create_header; end if; - if p_insert_all_size > 0 and mod(v_data_count, p_insert_all_size) = 1 then + if v_insert_style = 'INSERT' and p_insert_all_size > 0 and mod(v_data_count, p_insert_all_size) = 1 then util_clob_append('insert all' || c_crlf); end if; line_append(v_table_insert_prefix); --> process row FOR i IN 1..v_col_count LOOP + IF v_insert_style = 'OM_TAPIGEN' THEN + line_append('p_' || lower(v_desc_tab(i).col_name) || '=>'); + END IF; IF v_desc_tab(i).col_type = c_clob THEN dbms_sql.column_value(v_cursor, i, v_buffer_clob); process_clob_buffer; @@ -1900,15 +1929,15 @@ IS process_varchar2_buffer('STRING'); END IF; END IF; - if i != v_col_count then + if i != v_col_count then line_append(','); else - line_append(')' || case when p_insert_all_size < 1 then ';' end); + line_append(')' || case when v_insert_style = 'OM_TAPIGEN' or p_insert_all_size < 1 then ';' end); line_flush_cache; end if; END LOOP; --< end process row - if p_insert_all_size > 0 and mod(v_data_count, p_insert_all_size) = 0 then + if v_insert_style = 'INSERT' and p_insert_all_size > 0 and mod(v_data_count, p_insert_all_size) = 0 then util_clob_append('select * from dual;' || c_crlf); end if; @@ -1923,7 +1952,7 @@ IS if v_data_count = 0 then util_clob_append('Prompt Nothing to insert - there was no data in the source table ' || p_table_name || c_crlf); else - if p_insert_all_size > 0 and mod(v_data_count, p_insert_all_size) != 0 then + if V_insert_style = 'INSERT' and p_insert_all_size > 0 and mod(v_data_count, p_insert_all_size) != 0 then util_clob_append('select * from dual;' || c_crlf); end if; util_clob_append('end;' || c_crlf); @@ -1948,6 +1977,7 @@ IS BEGIN IF p_table_name IS NOT NULL THEN --dbms_lob.createtemporary(v_buffer_clob, true); + init; get_session_nls_params; parse_query_and_describe_cols; create_data; @@ -2955,13 +2985,17 @@ SELECT table_name, v_file_path := v_path.to_data || '/' || v_rec.table_name || '.sql'; util_log_start(v_file_path); util_clob_table_to_insert( - p_table_name => v_rec.table_name, - p_data_scn => v_data_scn, - p_max_rows => p_data_max_rows, - p_insert_all_size => to_number(nvl(regexp_substr(p_data_format,'insert:(\d+)',1,1,'i',1), '10'))); + p_table_name => v_rec.table_name, + p_data_scn => v_data_scn, + p_max_rows => p_data_max_rows, + p_insert_style => 'INSERT', + p_insert_all_size => to_number(nvl(regexp_substr(p_data_format,':(\d+)',1,1,'i',1), '10')), + p_exclude_columns_list => regexp_substr(p_data_format,'(:\w+){1,}') + ); util_clob_add_to_export_files( p_export_files => v_export_files, - p_name => v_file_path); + p_name => v_file_path + ); v_files.data_(v_files.data_.count + 1) := v_file_path; util_log_stop; EXCEPTION @@ -2969,6 +3003,31 @@ SELECT table_name, util_log_error(v_file_path); END; END IF; + + -- insert with table API (OM_TAPIGEN style) + IF upper(p_data_format) LIKE '%OM_TAPIGEN%' THEN + BEGIN + v_file_path := v_path.to_data || '/' || v_rec.table_name || '.api.sql'; + util_log_start(v_file_path); + util_clob_table_to_insert( + p_table_name => v_rec.table_name, + p_data_scn => v_data_scn, + p_max_rows => p_data_max_rows, + p_insert_style => 'OM_TAPIGEN', + p_exclude_columns_list => regexp_substr(p_data_format,'(:\w+){1,}') + ); + util_clob_add_to_export_files( + p_export_files => v_export_files, + p_name => v_file_path + ); + v_files.data_(v_files.data_.count + 1) := v_file_path; + util_log_stop; + EXCEPTION + WHEN OTHERS THEN + util_log_error(v_file_path); + END; + END IF; + END LOOP; CLOSE v_cur; diff --git a/src/PLEX.pkb b/src/PLEX.pkb index 8494784..6252b7c 100644 --- a/src/PLEX.pkb +++ b/src/PLEX.pkb @@ -228,10 +228,13 @@ PROCEDURE util_clob_query_to_csv ( p_header_prefix IN VARCHAR2 DEFAULT NULL); PROCEDURE util_clob_table_to_insert ( - p_table_name IN VARCHAR2, - p_data_scn IN NUMBER, - p_max_rows IN NUMBER DEFAULT 1000, - p_insert_all_size IN NUMBER DEFAULT 10); + p_table_name IN VARCHAR2, + p_data_scn IN NUMBER, + p_max_rows IN NUMBER DEFAULT 1000, + p_insert_style IN VARCHAR2 DEFAULT 'INSERT', -- can be INSERT or OM_TAPIGEN + p_insert_all_size IN NUMBER DEFAULT 10, + p_exclude_columns_list IN VARCHAR2 DEFAULT NULL -- a list of columns that should be excluded for the insert operation (for example audit columns which are populated automatically) FIXME: support the auto detection of an column prefix +); PROCEDURE util_clob_create_runtime_log (p_export_files IN OUT NOCOPY tab_export_files); @@ -977,11 +980,15 @@ END util_clob_query_to_csv; -------------------------------------------------------------------------------------------------------------------------------- PROCEDURE util_clob_table_to_insert ( - p_table_name IN VARCHAR2, - p_data_scn IN NUMBER, - p_max_rows IN NUMBER DEFAULT 1000, - p_insert_all_size IN NUMBER DEFAULT 10) + p_table_name IN VARCHAR2, + p_data_scn IN NUMBER, + p_max_rows IN NUMBER DEFAULT 1000, + p_insert_style IN VARCHAR2 DEFAULT 'INSERT', + p_insert_all_size IN NUMBER DEFAULT 10, + p_exclude_columns_list IN VARCHAR2 DEFAULT NULL) IS + v_insert_style VARCHAR2(30); + v_exclude_columns_list VARCHAR2(32767); v_nls rec_nls; v_query VARCHAR2(32767); v_cursor PLS_INTEGER; @@ -1001,6 +1008,12 @@ IS ---------------------------------------------------------------- + PROCEDURE init IS + BEGIN + v_insert_style := trim(upper(substr(p_insert_style,1,30))); + v_exclude_columns_list := trim(upper(p_exclude_columns_list)) || ':'; + END; + PROCEDURE get_session_nls_params IS BEGIN -- Save current values. @@ -1190,6 +1203,7 @@ IS where table_name = p_table_name and user_generated = 'YES' and virtual_column = 'NO' + and instr(v_exclude_columns_list, ':'||column_name||':') = 0 group by table_name ) LOOP v_query := i.query; @@ -1211,13 +1225,20 @@ IS ELSE dbms_sql.define_column(v_cursor, i, v_buffer_varchar2, c_vc2_max_size); END IF; - v_table_insert_prefix := v_table_insert_prefix || v_desc_tab(i).col_name || ','; + IF v_insert_style = 'INSERT' THEN + v_table_insert_prefix := v_table_insert_prefix || v_desc_tab(i).col_name || ','; + END IF; END LOOP; v_table_insert_prefix := - case when p_insert_all_size > 0 - then 'into ' - else 'insert into ' - end || p_table_name || '(' || rtrim(v_table_insert_prefix, ',' ) || ') values ('; + CASE v_insert_style + WHEN 'INSERT' THEN + case when p_insert_all_size > 0 + then 'into ' + else 'insert into ' + end || p_table_name || '(' || rtrim(v_table_insert_prefix, ',' ) || ') values (' + WHEN 'OM_TAPIGEN' THEN + lower(p_table_name) || '_api.create_or_update_row(' + END; v_ignore_me := dbms_sql.execute(v_cursor); END IF; END parse_query_and_describe_cols; @@ -1231,8 +1252,10 @@ IS PROCEDURE create_header IS BEGIN util_clob_append('-- Script generated by PLEX version ' || c_plex_version || ' - more infos here: ' || c_plex_url || c_crlf); - util_clob_append('-- Performance Hacks by Connor McDonald: https://connor-mcdonald.com/2019/05/17/hacking-together-faster-inserts/' || c_crlf); - util_clob_append('-- For strange line end replacements a big thank to SQL*Plus: https://support.oracle.com/epmos/faces/DocumentDisplay?id=2377701.1 (SQL Failed With ORA-1756 In Sqlplus But Works In SQL Developer)' || c_crlf); + if v_insert_style = 'INSERT' then + util_clob_append('-- Performance Hacks by Connor McDonald: https://connor-mcdonald.com/2019/05/17/hacking-together-faster-inserts/' || c_crlf); + util_clob_append('-- For strange line end replacements a big thank to SQL*Plus: https://support.oracle.com/epmos/faces/DocumentDisplay?id=2377701.1 (SQL Failed With ORA-1756 In Sqlplus But Works In SQL Developer)' || c_crlf); + end if; util_clob_append('prompt - insert xxx rows into ' || p_table_name || ' (exported ' || to_char(systimestamp,'YYYY-MM-DD hh24:mi:ssxff TZR') || ')' || c_crlf); util_clob_append('set define off feedback off sqlblanklines on' || c_crlf); util_clob_append('alter session set cursor_sharing = force;' || c_crlf); @@ -1253,12 +1276,15 @@ IS if v_data_count = 1 then create_header; end if; - if p_insert_all_size > 0 and mod(v_data_count, p_insert_all_size) = 1 then + if v_insert_style = 'INSERT' and p_insert_all_size > 0 and mod(v_data_count, p_insert_all_size) = 1 then util_clob_append('insert all' || c_crlf); end if; line_append(v_table_insert_prefix); --> process row FOR i IN 1..v_col_count LOOP + IF v_insert_style = 'OM_TAPIGEN' THEN + line_append('p_' || lower(v_desc_tab(i).col_name) || '=>'); + END IF; IF v_desc_tab(i).col_type = c_clob THEN dbms_sql.column_value(v_cursor, i, v_buffer_clob); process_clob_buffer; @@ -1282,15 +1308,15 @@ IS process_varchar2_buffer('STRING'); END IF; END IF; - if i != v_col_count then + if i != v_col_count then line_append(','); else - line_append(')' || case when p_insert_all_size < 1 then ';' end); + line_append(')' || case when v_insert_style = 'OM_TAPIGEN' or p_insert_all_size < 1 then ';' end); line_flush_cache; end if; END LOOP; --< end process row - if p_insert_all_size > 0 and mod(v_data_count, p_insert_all_size) = 0 then + if v_insert_style = 'INSERT' and p_insert_all_size > 0 and mod(v_data_count, p_insert_all_size) = 0 then util_clob_append('select * from dual;' || c_crlf); end if; @@ -1305,7 +1331,7 @@ IS if v_data_count = 0 then util_clob_append('Prompt Nothing to insert - there was no data in the source table ' || p_table_name || c_crlf); else - if p_insert_all_size > 0 and mod(v_data_count, p_insert_all_size) != 0 then + if V_insert_style = 'INSERT' and p_insert_all_size > 0 and mod(v_data_count, p_insert_all_size) != 0 then util_clob_append('select * from dual;' || c_crlf); end if; util_clob_append('end;' || c_crlf); @@ -1330,6 +1356,7 @@ IS BEGIN IF p_table_name IS NOT NULL THEN --dbms_lob.createtemporary(v_buffer_clob, true); + init; get_session_nls_params; parse_query_and_describe_cols; create_data; @@ -2337,13 +2364,17 @@ SELECT table_name, v_file_path := v_path.to_data || '/' || v_rec.table_name || '.sql'; util_log_start(v_file_path); util_clob_table_to_insert( - p_table_name => v_rec.table_name, - p_data_scn => v_data_scn, - p_max_rows => p_data_max_rows, - p_insert_all_size => to_number(nvl(regexp_substr(p_data_format,'insert:(\d+)',1,1,'i',1), '10'))); + p_table_name => v_rec.table_name, + p_data_scn => v_data_scn, + p_max_rows => p_data_max_rows, + p_insert_style => 'INSERT', + p_insert_all_size => to_number(nvl(regexp_substr(p_data_format,':(\d+)',1,1,'i',1), '10')), + p_exclude_columns_list => regexp_substr(p_data_format,'(:\w+){1,}') + ); util_clob_add_to_export_files( p_export_files => v_export_files, - p_name => v_file_path); + p_name => v_file_path + ); v_files.data_(v_files.data_.count + 1) := v_file_path; util_log_stop; EXCEPTION @@ -2351,6 +2382,31 @@ SELECT table_name, util_log_error(v_file_path); END; END IF; + + -- insert with table API (OM_TAPIGEN style) + IF upper(p_data_format) LIKE '%OM_TAPIGEN%' THEN + BEGIN + v_file_path := v_path.to_data || '/' || v_rec.table_name || '.api.sql'; + util_log_start(v_file_path); + util_clob_table_to_insert( + p_table_name => v_rec.table_name, + p_data_scn => v_data_scn, + p_max_rows => p_data_max_rows, + p_insert_style => 'OM_TAPIGEN', + p_exclude_columns_list => regexp_substr(p_data_format,'(:\w+){1,}') + ); + util_clob_add_to_export_files( + p_export_files => v_export_files, + p_name => v_file_path + ); + v_files.data_(v_files.data_.count + 1) := v_file_path; + util_log_stop; + EXCEPTION + WHEN OTHERS THEN + util_log_error(v_file_path); + END; + END IF; + END LOOP; CLOSE v_cur; diff --git a/src/PLEX.pks b/src/PLEX.pks index e4d2fe8..97ceecb 100644 --- a/src/PLEX.pks +++ b/src/PLEX.pks @@ -534,10 +534,13 @@ PROCEDURE util_clob_query_to_csv ( p_header_prefix IN VARCHAR2 DEFAULT NULL); PROCEDURE util_clob_table_to_insert ( - p_table_name IN VARCHAR2, - p_data_scn IN NUMBER, - p_max_rows IN NUMBER DEFAULT 1000, - p_insert_all_size IN NUMBER DEFAULT 10); + p_table_name IN VARCHAR2, + p_data_scn IN NUMBER, + p_max_rows IN NUMBER DEFAULT 1000, + p_insert_style IN VARCHAR2 DEFAULT 'INSERT', -- can be INSERT or OM_TAPIGEN + p_insert_all_size IN NUMBER DEFAULT 10, + p_exclude_columns_list IN VARCHAR2 DEFAULT NULL -- a colon separated list of columns that should be excluded for the insert operation (for example audit columns which are populated automatically) FIXME: support the auto detection of an column prefix +); PROCEDURE util_clob_create_runtime_log (p_export_files IN OUT NOCOPY tab_export_files);