rework boolean params, improvements
This commit is contained in:
parent
87cf3e5348
commit
847154994d
21
LICENSE.txt
Normal file
21
LICENSE.txt
Normal file
@ -0,0 +1,21 @@
|
||||
The MIT License (MIT)
|
||||
|
||||
Copyright (c) 2018 Ottmar Gobrecht
|
||||
|
||||
Permission is hereby granted, free of charge, to any person obtaining a copy
|
||||
of this software and associated documentation files (the "Software"), to deal
|
||||
in the Software without restriction, including without limitation the rights
|
||||
to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
|
||||
copies of the Software, and to permit persons to whom the Software is
|
||||
furnished to do so, subject to the following conditions:
|
||||
|
||||
The above copyright notice and this permission notice shall be included in all
|
||||
copies or substantial portions of the Software.
|
||||
|
||||
THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
|
||||
IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
|
||||
FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
|
||||
AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
|
||||
LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
|
||||
OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
|
||||
SOFTWARE.
|
||||
61
README.md
61
README.md
@ -1,5 +1,19 @@
|
||||
# PLEX - PL/SQL export utilities
|
||||
|
||||
One word regarding the parameters in this package: To be usable in the SQL and PL/SQL context all boolean parameters are coded as varchars. We check only the uppercased first character:
|
||||
|
||||
- 0 (zero), N [O], F [ALSE] will be parsed as FALSE
|
||||
- 1 (one), Y [ES], T [RUE] will be parsed as TRUE
|
||||
- If we can't find a match the default for the parameter is used
|
||||
- This means the following keywords are also correct ;-)
|
||||
- `yes please`
|
||||
- `no thanks`
|
||||
- `yeah`
|
||||
- `nope`
|
||||
- `Yippie Yippie Yeah Yippie Yeah`
|
||||
- `time goes by...`
|
||||
- All that fun only because Oracle does not support boolean values in pure SQL context...
|
||||
|
||||
|
||||
## BackApp
|
||||
|
||||
@ -14,11 +28,11 @@ Get a zip file for an APEX application (or schema) including:
|
||||
|
||||
```sql
|
||||
DECLARE
|
||||
l_zip_file blob;
|
||||
l_zip blob;
|
||||
BEGIN
|
||||
|
||||
-- do the backapp
|
||||
l_zip_file := plex.backapp(p_app_id => 100);
|
||||
l_zip := plex.backapp(p_app_id => 100);
|
||||
|
||||
-- do something with the zip file
|
||||
|
||||
@ -33,21 +47,18 @@ END;
|
||||
FUNCTION backapp
|
||||
(
|
||||
p_app_id IN NUMBER DEFAULT NULL, -- If not provided we simply skip the APEX app export.
|
||||
p_app_public_reports IN BOOLEAN DEFAULT TRUE, -- Include public reports in your application export.
|
||||
p_app_private_reports IN BOOLEAN DEFAULT FALSE, -- Include private reports in your application export.
|
||||
p_app_report_subscriptions IN BOOLEAN DEFAULT FALSE, -- Include IRt or IG subscription settings in your application export.
|
||||
p_app_translations IN BOOLEAN DEFAULT TRUE, -- Include translations in your application export.
|
||||
p_app_subscriptions IN BOOLEAN DEFAULT TRUE, -- Include component subscriptions.
|
||||
p_app_original_ids IN BOOLEAN DEFAULT FALSE, -- Include original workspace id, application id and component ids.
|
||||
p_app_packaged_app_mapping IN BOOLEAN DEFAULT FALSE, -- Include mapping between the application and packaged application if it exists.
|
||||
|
||||
p_include_object_ddl IN BOOLEAN DEFAULT TRUE, -- Include DDL of current user/schema and its objects.
|
||||
p_object_prefix IN VARCHAR2 DEFAULT NULL, -- Filter the schema objects with the provided object prefix.
|
||||
|
||||
p_include_data IN BOOLEAN DEFAULT FALSE, -- Include CSV data of each table.
|
||||
p_data_max_rows IN NUMBER DEFAULT 1000, -- Maximal number of rows per table.
|
||||
|
||||
p_debug IN BOOLEAN DEFAULT FALSE -- Generate plex_backapp_log.md in the root of the zip file.
|
||||
p_app_public_reports IN VARCHAR2 DEFAULT 'Y', -- Include public reports in your application export.
|
||||
p_app_private_reports IN VARCHAR2 DEFAULT 'N', -- Include private reports in your application export.
|
||||
p_app_report_subscriptions IN VARCHAR2 DEFAULT 'N', -- Include IRt or IG subscription settings in your application export.
|
||||
p_app_translations IN VARCHAR2 DEFAULT 'Y', -- Include translations in your application export.
|
||||
p_app_subscriptions IN VARCHAR2 DEFAULT 'Y', -- Include component subscriptions.
|
||||
p_app_original_ids IN VARCHAR2 DEFAULT 'N', -- Include original workspace id, application id and component ids.
|
||||
p_app_packaged_app_mapping IN VARCHAR2 DEFAULT 'N', -- Include mapping between the application and packaged application if it exists.
|
||||
p_include_object_ddl IN VARCHAR2 DEFAULT 'Y', -- Include DDL of current user/schema and its objects.
|
||||
p_object_prefix IN VARCHAR2 DEFAULT NULL, -- Filter the schema objects with the provided object prefix.
|
||||
p_include_data IN VARCHAR2 DEFAULT 'N', -- Include CSV data of each table.
|
||||
p_data_max_rows IN NUMBER DEFAULT 1000, -- Maximal number of rows per table.
|
||||
p_debug IN VARCHAR2 DEFAULT 'N' -- Generate plex_backapp_log.md in the root of the zip file.
|
||||
) RETURN BLOB;
|
||||
```
|
||||
|
||||
@ -61,7 +72,7 @@ Export one or more queries as CSV data within a zip file.
|
||||
|
||||
```sql
|
||||
DECLARE
|
||||
l_zip_file blob;
|
||||
l_zip blob;
|
||||
BEGIN
|
||||
|
||||
--fill the queries array
|
||||
@ -76,9 +87,9 @@ BEGIN
|
||||
);
|
||||
|
||||
-- process the queries
|
||||
l_zip_file := plex.queries_to_csv;
|
||||
l_zip := plex.queries_to_csv;
|
||||
|
||||
-- do something with the file...
|
||||
-- do something with the zip file...
|
||||
|
||||
END;
|
||||
/
|
||||
@ -90,11 +101,11 @@ END;
|
||||
```sql
|
||||
FUNCTION queries_to_csv
|
||||
(
|
||||
p_delimiter IN VARCHAR2 DEFAULT ',',
|
||||
p_quote_mark IN VARCHAR2 DEFAULT '"',
|
||||
p_line_terminator IN VARCHAR2 DEFAULT chr(10),
|
||||
p_header_prefix IN VARCHAR2 DEFAULT NULL,
|
||||
p_debug BOOLEAN DEFAULT FALSE -- Generate debug_log.md in the root of the zip file.
|
||||
p_delimiter IN VARCHAR2 DEFAULT ',', -- The column delimiter - you could use plex.tab if you like
|
||||
p_quote_mark IN VARCHAR2 DEFAULT '"', -- Used when the data contains the delimiter character.
|
||||
p_line_terminator IN VARCHAR2 DEFAULT lf, -- Default is line feed (plex.lf) - there are also plex.crlf and plex.cr.
|
||||
p_header_prefix IN VARCHAR2 DEFAULT NULL, -- Prefix the header line with this text.
|
||||
p_debug IN VARCHAR2 DEFAULT 'N' -- Generate plex_queries_to_csv_log.md in the root of the zip file.
|
||||
) RETURN BLOB;
|
||||
```
|
||||
|
||||
|
||||
291
plex.pkb
291
plex.pkb
@ -30,16 +30,31 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
|
||||
-- CODE
|
||||
|
||||
FUNCTION util_bool_to_yn(p_bool IN BOOLEAN) RETURN VARCHAR2 IS
|
||||
FUNCTION tab RETURN VARCHAR2 IS
|
||||
BEGIN
|
||||
RETURN CASE WHEN p_bool THEN 'Y' ELSE 'N' END;
|
||||
END util_bool_to_yn;
|
||||
RETURN c_tab;
|
||||
END;
|
||||
|
||||
FUNCTION lf RETURN VARCHAR2 IS
|
||||
BEGIN
|
||||
RETURN c_lf;
|
||||
END;
|
||||
|
||||
FUNCTION cr RETURN VARCHAR2 IS
|
||||
BEGIN
|
||||
RETURN c_cr;
|
||||
END;
|
||||
|
||||
FUNCTION crlf RETURN VARCHAR2 IS
|
||||
BEGIN
|
||||
RETURN c_crlf;
|
||||
END;
|
||||
|
||||
--
|
||||
|
||||
FUNCTION util_bool_to_string(p_bool IN BOOLEAN) RETURN VARCHAR2 IS
|
||||
BEGIN
|
||||
RETURN CASE WHEN p_bool THEN 'TRUE' ELSE 'FALSE' END;
|
||||
RETURN CASE WHEN p_bool THEN 'Y' ELSE 'N' END;
|
||||
END util_bool_to_string;
|
||||
|
||||
--
|
||||
@ -52,11 +67,11 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
l_bool_string VARCHAR2(1 CHAR);
|
||||
l_return BOOLEAN;
|
||||
BEGIN
|
||||
l_bool_string := lower(substr(p_bool_string, 1, 1));
|
||||
l_bool_string := upper(substr(p_bool_string, 1, 1));
|
||||
l_return := CASE
|
||||
WHEN l_bool_string IN ('1', 'y', 't') THEN
|
||||
WHEN l_bool_string IN ('1', 'Y', 'T') THEN
|
||||
TRUE
|
||||
WHEN l_bool_string IN ('0', 'n', 'f') THEN
|
||||
WHEN l_bool_string IN ('0', 'N', 'F') THEN
|
||||
FALSE
|
||||
ELSE
|
||||
p_default
|
||||
@ -325,11 +340,12 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
util_g_clob_append( --step
|
||||
'| ' || lpad(to_char(i), 4) || ' | ' ||
|
||||
--elapsed
|
||||
lpad(to_char(util_ilog_get_runtime(g_debug.start_time, g_debug.data(i).stop_time), '990D000'),
|
||||
lpad(TRIM(to_char(util_ilog_get_runtime(g_debug.start_time, g_debug.data(i).stop_time),
|
||||
'99990D000')),
|
||||
9) || ' | ' ||
|
||||
--execution
|
||||
lpad(to_char(util_ilog_get_runtime(g_debug.data(i).start_time, g_debug.data(i).stop_time),
|
||||
'990D000000'),
|
||||
lpad(TRIM(to_char(util_ilog_get_runtime(g_debug.data(i).start_time, g_debug.data(i).stop_time),
|
||||
'9990D000000')),
|
||||
11) || ' | ' ||
|
||||
--action
|
||||
rpad(g_debug.data(i).action, 64) || ' |' || chr(10));
|
||||
@ -354,7 +370,7 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
p_data_max_rows IN NUMBER DEFAULT 1000,
|
||||
p_debug IN BOOLEAN DEFAULT FALSE
|
||||
) RETURN BLOB IS
|
||||
l_zip_file BLOB;
|
||||
l_zip BLOB;
|
||||
l_current_user user_objects.object_name%TYPE;
|
||||
l_app_owner user_objects.object_name%TYPE;
|
||||
l_the_point VARCHAR2(30) := '. < this is the point ;-)';
|
||||
@ -372,10 +388,10 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
CLOSE cur_owner;
|
||||
END IF;
|
||||
IF p_app_id IS NOT NULL AND l_app_owner IS NULL THEN
|
||||
raise_application_error(-20001,
|
||||
raise_application_error(-20101,
|
||||
'Could not find owner for application - are you sure you provided the right app_id?');
|
||||
ELSIF p_app_id IS NOT NULL AND l_app_owner != l_current_user THEN
|
||||
raise_application_error(-20002, 'You are not the owner of the app - please login as the owner.');
|
||||
raise_application_error(-20102, 'You are not the owner of the app - please login as the owner.');
|
||||
END IF;
|
||||
util_ilog_stop;
|
||||
END check_owner;
|
||||
@ -415,11 +431,11 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
-- https://apexplained.wordpress.com/2012/03/20/workspace-application-and-page-export-in-plsql/
|
||||
-- unfortunately not available: wwv_flow_gen_api2.export which is used in application builder (app:4000, page:4900)
|
||||
l_app_file := wwv_flow_utilities.export_application_to_clob(p_application_id => p_app_id,
|
||||
p_export_ir_public_reports => util_bool_to_yn(p_app_public_reports),
|
||||
p_export_ir_private_reports => util_bool_to_yn(p_app_private_reports),
|
||||
p_export_ir_notifications => util_bool_to_yn(p_app_report_subscriptions),
|
||||
p_export_translations => util_bool_to_yn(p_app_translations),
|
||||
p_export_pkg_app_mapping => util_bool_to_yn(p_app_packaged_app_mapping),
|
||||
p_export_ir_public_reports => util_bool_to_string(p_app_public_reports),
|
||||
p_export_ir_private_reports => util_bool_to_string(p_app_private_reports),
|
||||
p_export_ir_notifications => util_bool_to_string(p_app_report_subscriptions),
|
||||
p_export_translations => util_bool_to_string(p_app_translations),
|
||||
p_export_pkg_app_mapping => util_bool_to_string(p_app_packaged_app_mapping),
|
||||
p_with_original_ids => p_app_original_ids,
|
||||
p_exclude_subscriptions => CASE
|
||||
WHEN p_app_subscriptions THEN
|
||||
@ -432,7 +448,7 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
util_ilog_start('app:save_single_file');
|
||||
util_g_clob_createtemporary;
|
||||
util_g_clob_append(l_app_file);
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'App/UI/f' || p_app_id || '.sql',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
@ -446,7 +462,7 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
util_ilog_append_action_text(':' || l_file_path);
|
||||
util_g_clob_createtemporary;
|
||||
util_g_clob_append(substr(str1 => l_app_file, pos => l_content_start_pos, len => l_content_length) || chr(10));
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'App/UI/f' || p_app_id || '/' || l_file_path,
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
@ -460,7 +476,7 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
FOR i IN 1 .. l_app_install_file.count LOOP
|
||||
util_g_clob_append('@' || l_app_install_file(i) || chr(10));
|
||||
END LOOP;
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'App/UI/f' || p_app_id || '/install.sql',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
@ -475,7 +491,7 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
util_ilog_start('ddl:USER:' || l_current_user);
|
||||
util_g_clob_createtemporary;
|
||||
util_g_clob_append(dbms_metadata.get_ddl('USER', l_current_user));
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'App/DDL/User/' || l_current_user || '.sql',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
@ -487,7 +503,7 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
SELECT DISTINCT username FROM user_role_privs) LOOP
|
||||
util_g_clob_append(dbms_metadata.get_granted_ddl('ROLE_GRANT', l_current_user));
|
||||
END LOOP;
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'App/DDL/User/' || l_current_user || '_roles.sql',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
@ -499,7 +515,7 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
SELECT DISTINCT username FROM user_sys_privs) LOOP
|
||||
util_g_clob_append(dbms_metadata.get_granted_ddl('SYSTEM_GRANT', l_current_user));
|
||||
END LOOP;
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'App/DDL/User/' || l_current_user || '_system_privileges.sql',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
@ -511,7 +527,7 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
SELECT DISTINCT grantee FROM user_tab_privs WHERE grantee = l_current_user) LOOP
|
||||
util_g_clob_append(dbms_metadata.get_granted_ddl('OBJECT_GRANT', l_current_user));
|
||||
END LOOP;
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'App/DDL/User/' || l_current_user || '_object_privileges.sql',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
@ -560,7 +576,7 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
1,
|
||||
regexp_instr(l_ddl_file, 'CREATE OR REPLACE( EDITIONABLE)? PACKAGE BODY') - 1),
|
||||
' ' || chr(10)));
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'App/DDL/' || i.dir_name || '/' || i.object_name || '.pks',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
@ -568,7 +584,7 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
util_g_clob_createtemporary;
|
||||
util_g_clob_append(substr(l_ddl_file,
|
||||
regexp_instr(l_ddl_file, 'CREATE OR REPLACE( EDITIONABLE)? PACKAGE BODY')));
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'App/DDL/PackageBodies/' || i.object_name || '.pkb',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
@ -587,7 +603,7 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
1,
|
||||
'im'),
|
||||
' ' || chr(10)));
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'App/DDL/' || i.dir_name || '/' || i.object_name || '.sql',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
@ -596,7 +612,7 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
util_g_clob_append(dbms_metadata.get_ddl(object_type => i.object_type,
|
||||
NAME => i.object_name,
|
||||
SCHEMA => l_current_user));
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'App/DDL/' || i.dir_name || '/' || i.object_name || '.sql',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
@ -615,7 +631,7 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
util_ilog_start('ddl:GRANT:' || i.privilege || ':' || i.object_name);
|
||||
util_g_clob_createtemporary;
|
||||
util_g_clob_append(dbms_metadata.get_dependent_ddl('OBJECT_GRANT', i.object_name, i.grantor));
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'App/DDL/Grants/' || i.privilege || '_on_' || i.object_name || '.sql',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
@ -633,7 +649,7 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
util_ilog_start('data:' || i.table_name);
|
||||
util_g_clob_createtemporary;
|
||||
util_g_clob_query_to_csv(p_query => 'select * from ' || i.table_name, p_max_rows => p_data_max_rows);
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'App/Data/' || i.table_name || '.csv',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
@ -643,10 +659,10 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
--
|
||||
PROCEDURE process_docs_folder IS
|
||||
BEGIN
|
||||
util_ilog_start('folders:Docs');
|
||||
util_ilog_start('folder:Docs');
|
||||
util_g_clob_createtemporary;
|
||||
util_g_clob_append(l_the_point);
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'Docs/_save_your_docs_here',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
@ -655,10 +671,10 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
--
|
||||
PROCEDURE process_scripts_folder IS
|
||||
BEGIN
|
||||
util_ilog_start('folders:Scripts');
|
||||
util_ilog_start('folder:Scripts');
|
||||
util_g_clob_createtemporary;
|
||||
util_g_clob_append(l_the_point);
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'Scripts/_save_your_scripts_here',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
@ -667,10 +683,10 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
--
|
||||
PROCEDURE process_tests_folder IS
|
||||
BEGIN
|
||||
util_ilog_start('folders:Tests');
|
||||
util_ilog_start('folder:Tests');
|
||||
util_g_clob_createtemporary;
|
||||
util_g_clob_append(l_the_point);
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'Tests/_save_your_tests_here',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
@ -684,17 +700,17 @@ CREATE OR REPLACE PACKAGE BODY plex IS
|
||||
util_g_clob_append('# Your global README file
|
||||
|
||||
It is a good practice to have a README file in the root of your project with
|
||||
a high level overview of your application and links to detailed informations
|
||||
in the Docs folder when needed.
|
||||
a high level overview of your application. Put the more detailed docs in the
|
||||
Docs folder.
|
||||
|
||||
You can start with a copy of this file. Name it README.md an try to use
|
||||
You can start with a copy of this file. Name it README.md and try to use
|
||||
Markdown when writing your content - this has many benefits and you don''t
|
||||
waist time by formatting your docs. If you are unsure have a look at some
|
||||
projects at [Github][1] or any other code hosting platform.
|
||||
|
||||
[1]: https://github.com
|
||||
');
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file, p_file_name => 'README.dist.md', p_content => util_g_clob_to_blob);
|
||||
apex_zip.add_file(p_zipped_blob => l_zip, p_file_name => 'README.dist.md', p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
util_ilog_stop;
|
||||
END process_readme_dist;
|
||||
@ -703,53 +719,49 @@ projects at [Github][1] or any other code hosting platform.
|
||||
BEGIN
|
||||
IF p_debug THEN
|
||||
util_g_clob_createtemporary;
|
||||
util_g_clob_append('# PLEX BackApp Log
|
||||
util_g_clob_append('# PLEX - BackApp Log
|
||||
|
||||
|
||||
## Parameters
|
||||
|
||||
```sql
|
||||
DECLARE
|
||||
l_zip BLOB;
|
||||
BEGIN
|
||||
l_zip := plex.backapp(
|
||||
p_app_id => ' || to_char(p_app_id) || ',
|
||||
p_app_public_reports => ' || util_bool_to_string(p_app_public_reports) || ',
|
||||
p_app_private_reports => ' || util_bool_to_string(p_app_private_reports) || ',
|
||||
p_app_report_subscriptions => ' || util_bool_to_string(p_app_report_subscriptions) || ',
|
||||
p_app_translations => ' || util_bool_to_string(p_app_translations) || ',
|
||||
p_app_subscriptions => ' || util_bool_to_string(p_app_subscriptions) || ',
|
||||
p_app_original_ids => ' || util_bool_to_string(p_app_original_ids) || ',
|
||||
p_app_packaged_app_mapping => ' || util_bool_to_string(p_app_packaged_app_mapping) || ',
|
||||
p_include_object_ddl => ' || util_bool_to_string(p_include_object_ddl) || ',
|
||||
p_object_prefix => ' || CASE WHEN p_object_prefix IS NOT NULL THEN
|
||||
SELECT plex.backapp(
|
||||
p_app_id => ' || to_char(p_app_id) || ',
|
||||
p_app_public_reports => ''' || util_bool_to_string(p_app_public_reports) || ''',
|
||||
p_app_private_reports => ''' || util_bool_to_string(p_app_private_reports) || ''',
|
||||
p_app_report_subscriptions => ''' || util_bool_to_string(p_app_report_subscriptions) || ''',
|
||||
p_app_translations => ''' || util_bool_to_string(p_app_translations) || ''',
|
||||
p_app_subscriptions => ''' || util_bool_to_string(p_app_subscriptions) || ''',
|
||||
p_app_original_ids => ''' || util_bool_to_string(p_app_original_ids) || ''',
|
||||
p_app_packaged_app_mapping => ''' || util_bool_to_string(p_app_packaged_app_mapping) || ''',
|
||||
p_include_object_ddl => ''' || util_bool_to_string(p_include_object_ddl) || ''',
|
||||
p_object_prefix => ' || CASE WHEN p_object_prefix IS NOT NULL THEN
|
||||
'''' || p_object_prefix || '''' ELSE 'NULL'
|
||||
END || ',
|
||||
p_include_data => ' || util_bool_to_string(p_include_data) || ',
|
||||
p_data_max_rows => ' || to_char(p_data_max_rows) || ',
|
||||
p_debug => ' || util_bool_to_string(p_debug) || ');
|
||||
|
||||
--> do something with your zip file
|
||||
END;
|
||||
/
|
||||
p_include_data => ''' || util_bool_to_string(p_include_data) || ''',
|
||||
p_data_max_rows => ' || to_char(p_data_max_rows) || ',
|
||||
p_debug => ''' || util_bool_to_string(p_debug) || '''
|
||||
)
|
||||
FROM dual;
|
||||
```
|
||||
|
||||
## Log Entries
|
||||
|
||||
Export started at ' || to_char(g_debug.start_time, 'yyyy-mm-dd hh24:mi:ss') || ' and took ' ||
|
||||
round(util_ilog_get_runtime(g_debug.start_time, g_debug.stop_time), 3) || ' seconds to finish.
|
||||
TRIM(to_char(round(util_ilog_get_runtime(g_debug.start_time, g_debug.stop_time), 3),
|
||||
'999G990D000')) || ' seconds to finish.
|
||||
');
|
||||
util_ilog_get_md_tab;
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'plex_backapp_log.md',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
END IF;
|
||||
END;
|
||||
END create_debug_log;
|
||||
--
|
||||
BEGIN
|
||||
util_ilog_init('plex.backapp' || CASE WHEN p_app_id IS NOT NULL THEN '(' || to_char(p_app_id) || ')' END, p_debug);
|
||||
dbms_lob.createtemporary(l_zip_file, TRUE);
|
||||
dbms_lob.createtemporary(l_zip, TRUE);
|
||||
check_owner;
|
||||
--
|
||||
IF p_app_id IS NOT NULL THEN
|
||||
@ -775,8 +787,8 @@ Export started at ' || to_char(g_debug.start_time, 'yyyy-mm-dd hh24:mi:ss') || '
|
||||
--
|
||||
util_ilog_exit;
|
||||
create_debug_log;
|
||||
apex_zip.finish(l_zip_file);
|
||||
RETURN l_zip_file;
|
||||
apex_zip.finish(l_zip);
|
||||
RETURN l_zip;
|
||||
END backapp;
|
||||
|
||||
--
|
||||
@ -784,18 +796,18 @@ Export started at ' || to_char(g_debug.start_time, 'yyyy-mm-dd hh24:mi:ss') || '
|
||||
FUNCTION backapp
|
||||
(
|
||||
p_app_id IN NUMBER DEFAULT NULL,
|
||||
p_app_public_reports IN VARCHAR2 DEFAULT 'TRUE',
|
||||
p_app_private_reports IN VARCHAR2 DEFAULT 'FALSE',
|
||||
p_app_report_subscriptions IN VARCHAR2 DEFAULT 'FALSE',
|
||||
p_app_translations IN VARCHAR2 DEFAULT 'TRUE',
|
||||
p_app_subscriptions IN VARCHAR2 DEFAULT 'TRUE',
|
||||
p_app_original_ids IN VARCHAR2 DEFAULT 'FALSE',
|
||||
p_app_packaged_app_mapping IN VARCHAR2 DEFAULT 'FALSE',
|
||||
p_include_object_ddl IN VARCHAR2 DEFAULT 'TRUE',
|
||||
p_app_public_reports IN VARCHAR2 DEFAULT 'Y',
|
||||
p_app_private_reports IN VARCHAR2 DEFAULT 'N',
|
||||
p_app_report_subscriptions IN VARCHAR2 DEFAULT 'N',
|
||||
p_app_translations IN VARCHAR2 DEFAULT 'Y',
|
||||
p_app_subscriptions IN VARCHAR2 DEFAULT 'Y',
|
||||
p_app_original_ids IN VARCHAR2 DEFAULT 'N',
|
||||
p_app_packaged_app_mapping IN VARCHAR2 DEFAULT 'N',
|
||||
p_include_object_ddl IN VARCHAR2 DEFAULT 'Y',
|
||||
p_object_prefix IN VARCHAR2 DEFAULT NULL,
|
||||
p_include_data IN VARCHAR2 DEFAULT 'FALSE',
|
||||
p_include_data IN VARCHAR2 DEFAULT 'N',
|
||||
p_data_max_rows IN NUMBER DEFAULT 1000,
|
||||
p_debug IN VARCHAR2 DEFAULT 'FALSE'
|
||||
p_debug IN VARCHAR2 DEFAULT 'N'
|
||||
) RETURN BLOB IS
|
||||
BEGIN
|
||||
RETURN backapp(p_app_id => p_app_id,
|
||||
@ -839,38 +851,97 @@ Export started at ' || to_char(g_debug.start_time, 'yyyy-mm-dd hh24:mi:ss') || '
|
||||
p_header_prefix IN VARCHAR2 DEFAULT NULL,
|
||||
p_debug BOOLEAN DEFAULT FALSE
|
||||
) RETURN BLOB IS
|
||||
l_zip_file BLOB;
|
||||
l_zip BLOB;
|
||||
--
|
||||
PROCEDURE create_debug_log IS
|
||||
BEGIN
|
||||
IF p_debug THEN
|
||||
util_g_clob_createtemporary;
|
||||
util_g_clob_append('# PLEX - Queries to CSV Log
|
||||
|
||||
|
||||
## Parameters
|
||||
|
||||
```sql
|
||||
SELECT plex.queries_to_csv(
|
||||
p_delimiter => ''' || p_delimiter || ''',
|
||||
p_quote_mark => ''' || p_quote_mark || ''',
|
||||
p_line_terminator => ' || CASE p_line_terminator WHEN c_cr THEN 'chr(13)' WHEN c_lf THEN
|
||||
'chr(10)' WHEN c_crlf THEN 'chr(10) || chr(13)' ELSE p_line_terminator
|
||||
END || ',
|
||||
p_header_prefix => ' || CASE WHEN p_header_prefix IS NOT NULL THEN
|
||||
'''' || p_header_prefix || '''' ELSE 'NULL'
|
||||
END || ',
|
||||
p_debug => ''' || util_bool_to_string(p_debug) || '''
|
||||
)
|
||||
FROM dual;
|
||||
```
|
||||
|
||||
## Log Entries
|
||||
|
||||
Export started at ' || to_char(g_debug.start_time, 'yyyy-mm-dd hh24:mi:ss') || ' and took ' ||
|
||||
TRIM(to_char(round(util_ilog_get_runtime(g_debug.start_time, g_debug.stop_time), 3),
|
||||
'999G990D000')) || ' seconds to finish.
|
||||
');
|
||||
util_ilog_get_md_tab;
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => 'plex_queries_to_csv_log.md',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
END IF;
|
||||
END create_debug_log;
|
||||
--
|
||||
BEGIN
|
||||
util_ilog_init('plex.queries_to_csv', p_debug);
|
||||
util_ilog_start('init_temp_clob_and_file_variable');
|
||||
dbms_lob.createtemporary(l_zip_file, TRUE);
|
||||
util_ilog_stop;
|
||||
FOR i IN g_queries.first .. g_queries.last LOOP
|
||||
util_ilog_start('prcess_query_to_csv:' || to_char(i));
|
||||
util_g_clob_createtemporary;
|
||||
util_g_clob_query_to_csv(p_query => g_queries(i).query,
|
||||
p_max_rows => g_queries(i).max_rows,
|
||||
p_delimiter => p_delimiter,
|
||||
p_quote_mark => p_quote_mark,
|
||||
p_line_terminator => p_line_terminator,
|
||||
p_header_prefix => p_header_prefix);
|
||||
apex_zip.add_file(p_zipped_blob => l_zip_file,
|
||||
p_file_name => regexp_replace(srcstr => g_queries(i).file_name,
|
||||
pattern => '\.csv$',
|
||||
replacestr => NULL,
|
||||
position => 1,
|
||||
occurrence => 0,
|
||||
modifier => 'i') || '.csv',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
util_ilog_stop;
|
||||
END LOOP;
|
||||
util_ilog_start('cleanup_and_finish_apex_zip_file');
|
||||
g_queries.delete;
|
||||
apex_zip.finish(l_zip_file);
|
||||
util_ilog_stop;
|
||||
util_ilog_exit;
|
||||
RETURN l_zip_file;
|
||||
IF g_queries.count = 0 THEN
|
||||
raise_application_error(-20201,
|
||||
'You need first to add queries by using plex.add_query. Calling plex.queries_to_csv clears the global queries array for subsequent processing.');
|
||||
ELSE
|
||||
util_ilog_init('plex.queries_to_csv', p_debug);
|
||||
dbms_lob.createtemporary(l_zip, TRUE);
|
||||
FOR i IN g_queries.first .. g_queries.last LOOP
|
||||
util_ilog_start('process_query_to_csv:' || to_char(i) || ':' || g_queries(i).file_name);
|
||||
util_g_clob_createtemporary;
|
||||
util_g_clob_query_to_csv(p_query => g_queries(i).query,
|
||||
p_max_rows => g_queries(i).max_rows,
|
||||
p_delimiter => p_delimiter,
|
||||
p_quote_mark => p_quote_mark,
|
||||
p_line_terminator => p_line_terminator,
|
||||
p_header_prefix => p_header_prefix);
|
||||
apex_zip.add_file(p_zipped_blob => l_zip,
|
||||
p_file_name => regexp_replace(srcstr => g_queries(i).file_name,
|
||||
pattern => '\.csv$',
|
||||
replacestr => NULL,
|
||||
position => 1,
|
||||
occurrence => 0,
|
||||
modifier => 'i') || '.csv',
|
||||
p_content => util_g_clob_to_blob);
|
||||
util_g_clob_freetemporary;
|
||||
util_ilog_stop;
|
||||
END LOOP;
|
||||
g_queries.delete;
|
||||
util_ilog_exit;
|
||||
create_debug_log;
|
||||
apex_zip.finish(l_zip);
|
||||
RETURN l_zip;
|
||||
END IF;
|
||||
END queries_to_csv;
|
||||
|
||||
--
|
||||
|
||||
FUNCTION queries_to_csv
|
||||
(
|
||||
p_delimiter IN VARCHAR2 DEFAULT ',',
|
||||
p_quote_mark IN VARCHAR2 DEFAULT '"',
|
||||
p_line_terminator IN VARCHAR2 DEFAULT lf,
|
||||
p_header_prefix IN VARCHAR2 DEFAULT NULL,
|
||||
p_debug IN VARCHAR2 DEFAULT 'N' -- Generate plex_queries_to_csv_log.md in the root of the zip file.
|
||||
) RETURN BLOB IS
|
||||
BEGIN
|
||||
RETURN queries_to_csv(p_delimiter => p_delimiter,
|
||||
p_quote_mark => p_quote_mark,
|
||||
p_line_terminator => p_line_terminator,
|
||||
p_header_prefix => p_header_prefix,
|
||||
p_debug => util_string_to_bool(p_debug, FALSE));
|
||||
END queries_to_csv;
|
||||
|
||||
--
|
||||
|
||||
91
plex.pks
91
plex.pks
@ -3,13 +3,25 @@ CREATE OR REPLACE PACKAGE plex AUTHID CURRENT_USER IS
|
||||
PL/SQL export utilities:
|
||||
- Depends on APEX 5 because of the used APEX_ZIP package
|
||||
- License: MIT
|
||||
- URL: https://github.com/ogobrecht/plex
|
||||
- URL: https://github.com/ogobrecht/plex
|
||||
|
||||
One word regarding the parameters in this package: To be usable in the SQL
|
||||
and PL/SQL context all boolean parameters are coded as varchars. We check
|
||||
only the lowercased first character:
|
||||
- 0(zero), N(O), F(ALSE) will be parsed as FALSE
|
||||
- 1(one), Y(ES), T(RUE) will be parsed as TRUE
|
||||
- If we can't find a match the default for the parameter is used
|
||||
*/
|
||||
|
||||
c_plex CONSTANT VARCHAR2(30 CHAR) := 'PLEX - PL/SQL export utils';
|
||||
c_plex_version CONSTANT VARCHAR2(10 CHAR) := '0.3.0';
|
||||
|
||||
c_length_application_info PLS_INTEGER := 64;
|
||||
c_tab CONSTANT VARCHAR2(2) := chr(9);
|
||||
c_lf CONSTANT VARCHAR2(2) := chr(10);
|
||||
c_cr CONSTANT VARCHAR2(2) := chr(13);
|
||||
c_crlf CONSTANT VARCHAR2(2) := chr(13) || chr(10);
|
||||
|
||||
c_length_application_info CONSTANT PLS_INTEGER := 64;
|
||||
SUBTYPE application_info_text IS VARCHAR2(64);
|
||||
|
||||
TYPE t_debug_view_row IS RECORD(
|
||||
@ -22,59 +34,36 @@ CREATE OR REPLACE PACKAGE plex AUTHID CURRENT_USER IS
|
||||
action application_info_text);
|
||||
TYPE t_debug_view_tab IS TABLE OF t_debug_view_row;
|
||||
|
||||
/*
|
||||
Helper for common delimiter and line terminators.
|
||||
*/
|
||||
FUNCTION tab RETURN VARCHAR2;
|
||||
FUNCTION lf RETURN VARCHAR2;
|
||||
FUNCTION cr RETURN VARCHAR2;
|
||||
FUNCTION crlf RETURN VARCHAR2;
|
||||
|
||||
/*
|
||||
Get a zip file for an APEX application including:
|
||||
Get a zip file for an APEX app or schema including:
|
||||
- The app export SQL file - full and splitted ready to use for version control
|
||||
- All objects DDL, object grants DDL
|
||||
- All objects DDL including the grants to/from other users
|
||||
- Optional the data in csv files - useful for small applications in cloud environments for a logical backup
|
||||
- Everything in a (hopefully) nice directory structure
|
||||
- Everything in a (hopefully) nice directory structure
|
||||
*/
|
||||
FUNCTION backapp
|
||||
(
|
||||
p_app_id IN NUMBER DEFAULT NULL, -- If not provided we simply skip the APEX app export.
|
||||
p_app_public_reports IN BOOLEAN DEFAULT TRUE, -- Include public reports in your application export.
|
||||
p_app_private_reports IN BOOLEAN DEFAULT FALSE, -- Include private reports in your application export.
|
||||
p_app_report_subscriptions IN BOOLEAN DEFAULT FALSE, -- Include IRt or IG subscription settings in your application export.
|
||||
p_app_translations IN BOOLEAN DEFAULT TRUE, -- Include translations in your application export.
|
||||
p_app_subscriptions IN BOOLEAN DEFAULT TRUE, -- Include component subscriptions.
|
||||
p_app_original_ids IN BOOLEAN DEFAULT FALSE, -- Include original workspace id, application id and component ids.
|
||||
p_app_packaged_app_mapping IN BOOLEAN DEFAULT FALSE, -- Include mapping between the application and packaged application if it exists.
|
||||
p_include_object_ddl IN BOOLEAN DEFAULT TRUE, -- Include DDL of current user/schema and its objects.
|
||||
p_app_public_reports IN VARCHAR2 DEFAULT 'Y', -- Include public reports in your application export.
|
||||
p_app_private_reports IN VARCHAR2 DEFAULT 'N', -- Include private reports in your application export.
|
||||
p_app_report_subscriptions IN VARCHAR2 DEFAULT 'N', -- Include IRt or IG subscription settings in your application export.
|
||||
p_app_translations IN VARCHAR2 DEFAULT 'Y', -- Include translations in your application export.
|
||||
p_app_subscriptions IN VARCHAR2 DEFAULT 'Y', -- Include component subscriptions.
|
||||
p_app_original_ids IN VARCHAR2 DEFAULT 'N', -- Include original workspace id, application id and component ids.
|
||||
p_app_packaged_app_mapping IN VARCHAR2 DEFAULT 'N', -- Include mapping between the application and packaged application if it exists.
|
||||
p_include_object_ddl IN VARCHAR2 DEFAULT 'Y', -- Include DDL of current user/schema and its objects.
|
||||
p_object_prefix IN VARCHAR2 DEFAULT NULL, -- Filter the schema objects with the provided object prefix.
|
||||
p_include_data IN BOOLEAN DEFAULT FALSE, -- Include CSV data of each table.
|
||||
p_include_data IN VARCHAR2 DEFAULT 'N', -- Include CSV data of each table.
|
||||
p_data_max_rows IN NUMBER DEFAULT 1000, -- Maximal number of rows per table.
|
||||
p_debug IN BOOLEAN DEFAULT FALSE -- Generate plex_backapp_log.md in the root of the zip file.
|
||||
) RETURN BLOB;
|
||||
|
||||
/*
|
||||
An overloaded function for a pure SQL context. You have to provide
|
||||
at least one boolean paramater as a string representation (1 and 0
|
||||
provided as numbers will work too), so that the DB can decide which
|
||||
version of the function to use - otherwise you will get this error:
|
||||
ORA-06553: PLS-307: too many declarations of 'BACKAPP' match this call
|
||||
|
||||
SELECT plex.backapp (p_app_id => 100, p_debug => 1) FROM dual;
|
||||
|
||||
In the background we check only the lowercased first character:
|
||||
- 0(zero), n(o), f(alse) will be parsed as FALSE
|
||||
- 1(one), y(es), t(rue) will be parsed as TRUE
|
||||
- If we can't find a match the default for the parameter is used
|
||||
*/
|
||||
FUNCTION backapp
|
||||
(
|
||||
p_app_id IN NUMBER DEFAULT NULL,
|
||||
p_app_public_reports IN VARCHAR2 DEFAULT 'TRUE',
|
||||
p_app_private_reports IN VARCHAR2 DEFAULT 'FALSE',
|
||||
p_app_report_subscriptions IN VARCHAR2 DEFAULT 'FALSE',
|
||||
p_app_translations IN VARCHAR2 DEFAULT 'TRUE',
|
||||
p_app_subscriptions IN VARCHAR2 DEFAULT 'TRUE',
|
||||
p_app_original_ids IN VARCHAR2 DEFAULT 'FALSE',
|
||||
p_app_packaged_app_mapping IN VARCHAR2 DEFAULT 'FALSE',
|
||||
p_include_object_ddl IN VARCHAR2 DEFAULT 'TRUE',
|
||||
p_object_prefix IN VARCHAR2 DEFAULT NULL,
|
||||
p_include_data IN VARCHAR2 DEFAULT 'FALSE',
|
||||
p_data_max_rows IN NUMBER DEFAULT 1000,
|
||||
p_debug IN VARCHAR2 DEFAULT 'FALSE'
|
||||
p_debug IN VARCHAR2 DEFAULT 'N' -- Generate plex_backapp_log.md in the root of the zip file.
|
||||
) RETURN BLOB;
|
||||
|
||||
/*
|
||||
@ -92,11 +81,11 @@ CREATE OR REPLACE PACKAGE plex AUTHID CURRENT_USER IS
|
||||
*/
|
||||
FUNCTION queries_to_csv
|
||||
(
|
||||
p_delimiter IN VARCHAR2 DEFAULT ',',
|
||||
p_quote_mark IN VARCHAR2 DEFAULT '"',
|
||||
p_line_terminator IN VARCHAR2 DEFAULT chr(10),
|
||||
p_header_prefix IN VARCHAR2 DEFAULT NULL,
|
||||
p_debug BOOLEAN DEFAULT FALSE -- Generate debug_log.md in the root of the zip file.
|
||||
p_delimiter IN VARCHAR2 DEFAULT ',', -- The column delimiter - there is also plex.tab as a helper function.
|
||||
p_quote_mark IN VARCHAR2 DEFAULT '"', -- Used when the data contains the delimiter character.
|
||||
p_line_terminator IN VARCHAR2 DEFAULT lf, -- Default is line feed (plex.lf) - there are also plex.crlf and plex.cr as helpers.
|
||||
p_header_prefix IN VARCHAR2 DEFAULT NULL, -- Prefix the header line with this text.
|
||||
p_debug IN VARCHAR2 DEFAULT 'N' -- Generate plex_queries_to_csv_log.md in the root of the zip file.
|
||||
) RETURN BLOB;
|
||||
|
||||
/*
|
||||
|
||||
Loading…
x
Reference in New Issue
Block a user