Skip to content

Instantly share code, notes, and snippets.

@sonnyksimon
Last active September 13, 2020 05:04
Show Gist options
  • Save sonnyksimon/e9b4ae0f8db5ade5346a48d328096216 to your computer and use it in GitHub Desktop.
Save sonnyksimon/e9b4ae0f8db5ade5346a48d328096216 to your computer and use it in GitHub Desktop.
QuickSQL
declare
l_message varchar2(32767);
l_script_id varchar2(255);
c integer := 0;
l_inserts number := 0;
l_selects varchar2(1);
begin
eba_dbtools_design_schema_pub.init_collections;
begin
l_inserts := to_number(:INSERTS);
exception when others then
l_inserts := 0;
end;
begin
l_selects := substr(:SELECTS,1,1);
exception when others then
l_selects := 'N';
end;
begin
eba_dbtools_design_schema_pub.add_tables (
P_TABLE_PREFIX => :TABLE_PREFIX,
P_DATE_DATATYPE => NVL(:DATE_DATATYPE,'DATE'),
P_INC_AUDITING => NVL(:AUDIT_COLS,'Y'),
P_TABLES => eba_dbtools_design_schema_pub.pre_process_lines(:P300_RAW_SQL,:MODEL_NAME||'.'||:KEY),
P_PRIMARY_KEY => NVL(:PRIMARY_KEY,'ID'),
P_ROW_VERSION => NVL(:ROW_VERSION,'N'),
P_ROW_KEY => NVL(:ROW_KEY,'N'),
P_SGID => NVL(:SGID,'N'),
p_compressed => NVL(:COMPRESSED,'N'),
p_LONGER_IDENTIFIERS => NVL(:LONGER_IDENTIFIERS,'N'),
p_AUTO_GEN_PK => NVL(:AUTO_GEN_PK,'N'),
p_history_tables => NVL(:HISTORY_TABLES,'N'),
p_apis => NVL(:API,'N'),
p_longer_varchars_yn => NVL(:longer_varchars,'N'),
p_schema => :SCHEMA,
p_inserts => l_inserts,
p_selects => l_selects,
p_uncomment => :UNCOMMENT,
p_tags_fw_yn => NVL(:TAGS_FW,'N')
);
exception when others then
htp.p('add_tables: '||sqlerrm);
end;
--sys.htp.init;
sys.owa_util.mime_header('text/plain', true );
sys.htp.prn('<div id="sql_output">');
sys.htp.prn('<div id="formatted_sql_output">');
begin
eba_dbtools_design_schema_pub.save_as_sql (
P_APP_USER => :APP_USER,
P_APP_SESSION => :APP_SESSION,
P_TRIGGER_METHOD => NVL(:TRIGGER_METHOD,'TRIG'),
P_FK => NVL(:ON_DELETE,'RESTRICT'),
P_ROW_VERSION => NVL(:ROW_VERSION,'N'),
P_ROW_KEY => NVL(:ROW_KEY,'N'),
P_SGID => NVL(:SGID,'N'),
p_compressed => NVL(:COMPRESSED,'N'),
P_TABLE_PREFIX => :TABLE_PREFIX,
p_include_drops => NVL(:INCLUDE_DROPS,'N'),
p_db_version => NVL(:DB_VERSION,'12c'),
p_LONGER_IDENTIFIERS => NVL(:LONGER_IDENTIFIERS,'N'),
p_history_tables => NVL(:HISTORY_TABLES,'N'),
p_apis => NVL(:API,'N'),
p_message => l_message,
P_SCRIPT_ID => l_script_id,
p_AUTO_GEN_PK => NVL(:AUTO_GEN_PK,'N'),
p_audit_cols => NVL(:AUDIT_COLS,'N'),
p_DATE_DATATYPE => NVL(:DATE_DATATYPE,'DATE'),
p_editionable => NVL(:EDITIONABLE,'N'),
p_language => NVL(:A_LANGUAGE,'EN'),
p_apex => NVL(:APEX,'N'),
--
P_PREFIX_PK_WITH_TNAME => NVL(:PREFIX_PK_WITH_TNAME, 'N'),
P_CREATED_COLUMN_NAME => NVL(:CREATED_COLUMN_NAME, 'created'),
P_CREATED_BY_COLUMN_NAME => NVL(:CREATED_BY_COLUMN_NAME, 'created_by'),
P_UPDATED_COLUMN_NAME => NVL(:UPDATED_COLUMN_NAME, 'updated'),
P_UPDATED_BY_COLUMN_NAME => NVL(:UPDATED_BY_COLUMN_NAME, 'updated_by'),
--
p_longer_varchars_yn => NVL(:longer_varchars,'N'),
p_schema => :SCHEMA,
p_inserts => l_inserts,
p_selects => l_selects,
p_uncomment => :UNCOMMENT,
p_tags_fw_yn => NVL(:TAGS_FW,'N'),
p_semantics => :P301_SEMANTICS
);
exception when others then
htp.p('save_as_sql: '||sqlerrm);
end;
eba_dbtools_design_schema_pub.print_generated;
eba_dbtools_design_schema_pub.print_settings2 (p_text=>:P300_RAW_SQL);
sys.htp.prn('</div>');
sys.htp.prn('<div id="sql_sequence">');
:key := NVL(:KEY,0) + 1;
c := 0;
for c1 in (select id from eba_dbtools_saved_models where identifier = :MODEL_KEY and created_by = :APP_USER) loop
c := c + 1;
sys.htp.prn(' <a href="'||apex_page.get_url(p_page => 300, p_request => 'MODEL'||to_char(c1.id))||'">'||apex_escape.html(:MODEL_NAME)||'.'||:KEY||'</a>');
end loop;
if c = 0 then
sys.htp.prn(:MODEL_NAME||'.'||:KEY);
end if;
sys.htp.prn('</div></div>');
end;
var rawSQLCache;
var savedSQLCache;
var sqlChanged = false;
var saveButton$ = $("#save-sql-button");
var codeEditor;
var snippetID$ = $("#snippet_id");
var debounceTimer;
var debounceInterval = 150;
function formatSQLCode(pSelector) {
var lCode;
$(pSelector).each(function() {
lCode = $(this).text();
$(this).empty();
codeEditor = CodeMirror(this, {
value: lCode,
mode: "text/x-sql",
smartIndent: true,
lineNumbers: true,
textWrapping: false,
readOnly: true
});
$(this).codeMirror = codeEditor;
});
};
function updateSQL() {
var currentSQL = $v('P300_RAW_SQL');
$("#gen_sql_btn").prop('disabled',true);
// Only generate SQL if value has changed
if (currentSQL != rawSQLCache) {
// Set cache to new value
rawSQLCache = currentSQL;
// call generateSQL()
generateSQL();
sqlChanged = true;
saveButton$.prop("disabled", false).find(".t-Button-label").text("Save");
apex.message.hidePageSuccess();
} else {
sqlChanged = false;
if (savedSQLCache === rawSQLCache) {
saveButton$.prop("disabled", true).find(".t-Button-label").text("Save");;
}
}
}
function addToRawSQL(codeStr) {
var codeToAdd = codeStr;
console.log(codeToAdd);
var currentSQL = $v('P300_RAW_SQL');
var updatedSQL = currentSQL + codeToAdd;
console.log(updatedSQL);
$s("P300_RAW_SQL", updatedSQL);
updateSQL();
}
window.generateSQL = function() {
apex.server.process(
"format_sql", {
pageItems: ["P300_RAW_SQL"]
}, {
dataType: "text",
loadingIndicator: '#quicksql_output',
loadingIndicatorPosition: "centered",
success: function(pData) {
var renderedData$ = $(pData);
var sqlOutput = renderedData$.find("#formatted_sql_output").html();
var sqlSequence = renderedData$.find("#sql_sequence").html();
$("#quicksql_output").empty().html(sqlOutput);
$("#snippet_id").html(sqlSequence);
formatSQLCode("#quicksql_output");
$("#gen_sql_btn").prop('disabled',false);
}
});
};
function insertExample(num) {
closeModal();
var example_code = $("#qs_example_" + num).text();
$s("P300_RAW_SQL", example_code);
generateSQL()
};
function downloadQuickSQLScript() {
var textToWrite = codeEditor ? codeEditor.getValue() : ' '; //Your text input;
var textblob = new Blob([textToWrite], {
type: 'text/plain'
});
var scriptname = snippetID$.text().trim().replace('.', '-').toLowerCase();
var dl = document.createElement("a");
dl.download = 'quicksql-' + scriptname + '.sql';
dl.innerHTML = "Download File";
if (window.webkitURL != null) {
dl.href = window.webkitURL.createObjectURL(textblob);
} else {
dl.href = window.URL.createObjectURL(textblob);
dl.onclick = destroyClickedElement;
dl.style.display = "none";
document.body.appendChild(dl);
}
dl.click();
}
create or replace package body eba_dbtools_design_schema_pub as
g_date_data_type varchar2(255) := 'date';
g_user varchar2(255) := 'user';
g_app_name varchar2(255) := 'Quick SQL';
g_max_history integer := 50; -- maximum number of models to retain in collection
g_max_inserts integer := 500; -- maximum number of sql INSERT statements to generate per table
g_fm varchar2(100) := null; -- date format mask, used to generate /mask based on auto date format detection
g_worksheet_data_ins_count integer := 0; -- global counter for inserts from worksheets
g_nls_decimal varchar2(1) := '.'; -- NLS
g_nls_units varchar2(1) := ','; -- NLS numeric group seperator
g_nls_usd varchar2(8) := '$'; -- NLS us dollar
g_nls_pct varchar2(1) := '%'; -- pct value, if numeric remove this on insert
g_nls_euro varchar2(8) := '€'; -- NLS_CURRENCY
g_nls_yen varchar2(8) := 'Â¥'; -- NLS_CURRENCY
g_nls_pound varchar2(8) := '£'; -- NLS_CURRENCY
g_semantics varchar2(30) := 'DEFAULT'; -- valid values are BYTE, CHAR, and DEFAULT
procedure printl (p_text in varchar2 default null)
is
begin
sys.htp.p(p_text);
end printl;
procedure printc (p_text in varchar2 default null)
is
begin
sys.htp.prn(p_text);
end printc;
procedure remove_status
is
begin
delete from eba_dbtools_app_log;
commit;
end remove_status;
procedure get_model_worksheets (
p_saved_model_id in number default null)
is
l_count integer := 0;
l_seq number;
begin
for c1 in (select distinct collection_name from EBA_DBTOOLS_SAVED_WORKSHEETS where model_id = p_saved_model_id order by 1) loop
apex_collection.CREATE_OR_TRUNCATE_COLLECTION(p_collection_name => c1.collection_name);
for c2 in (select *
from EBA_DBTOOLS_SAVED_WORKSHEETS
where model_id = p_saved_model_id and collection_name = c1.collection_name
order by seq_id) loop
l_seq := APEX_COLLECTION.ADD_MEMBER (
p_collection_name => c1.collection_name,
p_C001 => c2.C001,
p_C002 => c2.C002,
p_C003 => c2.C003,
p_C004 => c2.C004,
p_C005 => c2.C005,
p_C006 => c2.C006,
p_C007 => c2.C007,
p_C008 => c2.C008,
p_C009 => c2.C009,
p_C010 => c2.C010,
p_C011 => c2.C011,
p_C012 => c2.C012,
p_C013 => c2.C013,
p_C014 => c2.C014,
p_C015 => c2.C015,
p_C016 => c2.C016,
p_C017 => c2.C017,
p_C018 => c2.C018,
p_C019 => c2.C019,
p_C020 => c2.C020,
p_C021 => c2.C021,
p_C022 => c2.C022,
p_C023 => c2.C023,
p_C024 => c2.C024,
p_C025 => c2.C025,
p_C026 => c2.C026,
p_C027 => c2.C027,
p_C028 => c2.C028,
p_C029 => c2.C029,
p_C030 => c2.C030,
p_C031 => c2.C031,
p_C032 => c2.C032,
p_C033 => c2.C033,
p_C034 => c2.C034,
p_C035 => c2.C035,
p_C036 => c2.C036,
p_C037 => c2.C037,
p_C038 => c2.C038,
p_C039 => c2.C039,
p_C040 => c2.C040,
p_C041 => c2.C041,
p_C042 => c2.C042,
p_C043 => c2.C043,
p_C044 => c2.C044,
p_C045 => c2.C045,
p_C046 => c2.C046,
p_C047 => c2.C047,
p_C048 => c2.C048,
p_C049 => c2.C049,
p_C050 => c2.C050);
end loop;
end loop;
commit;
end get_model_worksheets;
procedure save_model_worksheets (
p_saved_model_id in number default null)
is
l_model varchar2(32767);
l_clob clob;
l_count integer := 0;
begin
-- get the raw sql
for c1 in (select model from EBA_DBTOOLS_SAVED_MODELS where id = p_saved_model_id) loop
l_clob := c1.model;
l_model := dbms_lob.substr(l_clob,32767,1);
end loop;
-- see if any collections are referenced
for c1 in (select distinct collection_name
from apex_collections
where collection_name like 'WORKSHEET_%' and
instr(l_model,'@'||collection_name) > 0) loop
-- see if worksheet referenced in raw sql has allready been saved
for c2 in (select count(*) c from EBA_DBTOOLS_SAVED_WORKSHEETS where collection_name = c1.collection_name and model_id = p_saved_model_id) loop
l_count := NVL(c2.c,0);
end loop;
-- if it has not been saved so save it
if l_count = 0 then
for c2 in (select C001, C002, C003, C004, C005, C006, C007, C008, C009, C010,
C011, C012, C013, C014, C015, C016, C017, C018, C019, C020,
C021, C022, C023, C024, C025, C026, C027, C028, C029, C030,
C031, C032, C033, C034, C035, C036, C037, C038, C039, C040,
C041, C042, C043, C044, C045, C046, C047, C048, C049, C050,
seq_id
from apex_collections
where collection_name = c1.collection_name
order by seq_id) loop
insert into EBA_DBTOOLS_SAVED_WORKSHEETS (
model_id, seq_id, collection_name,
C001, C002, C003, C004, C005, C006, C007, C008, C009, C010,
C011, C012, C013, C014, C015, C016, C017, C018, C019, C020,
C021, C022, C023, C024, C025, C026, C027, C028, C029, C030,
C031, C032, C033, C034, C035, C036, C037, C038, C039, C040,
C041, C042, C043, C044, C045, C046, C047, C048, C049, C050
) values (
p_saved_model_id, c2.seq_id, c1.collection_name,
c2.C001, c2.C002, c2.C003, c2.C004, c2.C005, c2.C006, c2.C007, c2.C008, c2.C009, c2.C010,
c2.C011, c2.C012, c2.C013, c2.C014, c2.C015, c2.C016, c2.C017, c2.C018, c2.C019, c2.C020,
c2.C021, c2.C022, c2.C023, c2.C024, c2.C025, c2.C026, c2.C027, c2.C028, c2.C029, c2.C030,
c2.C031, c2.C032, c2.C033, c2.C034, c2.C035, c2.C036, c2.C037, c2.C038, c2.C039, c2.C040,
c2.C041, c2.C042, c2.C043, c2.C044, c2.C045, c2.C046, c2.C047, c2.C048, c2.C049, c2.C050
);
end loop;
end if;
end loop;
commit;
end save_model_worksheets;
function get_data_example (p_example_number in number default 1)
return varchar2
is
begin
if p_example_number = 1 then
return 'Order #'||chr(9)||
'Customer Name'||chr(9)||
'Order Date'||chr(9)||
'Fulfillment Date'||chr(9)||
'Order Items'||chr(9)||
'Unit Cost'||chr(9)||
'Currency'||chr(9)||
'Region'||chr(9)||
'Tags'||chr(10)||
'10'||chr(9)||'Bradley, Eugene'|| chr(9)||to_char(sysdate-1,'MM/DD/RR')|| chr(9)||to_char(sysdate-0,'DD-MM-YYYY')|| chr(9)||'3'||chr(9)|| '$ 870'|| chr(9)||'USD'|| chr(9)||'NAS'|| chr(9)||''||chr(10)||
'9'|| chr(9)||'Hartsfield, William'||chr(9)||to_char(sysdate-2,'MM/DD/RR')|| chr(9)||to_char(sysdate-1,'DD-MM-YYYY')|| chr(9)||'3'||chr(9)|| '$730'|| chr(9)||'USD'|| chr(9)||'NAS'|| chr(9)||''||chr(10)||
'8'|| chr(9)||'OHare, Frank '|| chr(9)||to_char(sysdate-8, 'MM/DD/RR')|| chr(9)||to_char(sysdate-7,'DD-MM-YYYY')|| chr(9)||'1,244'||chr(9)|| '60'|| chr(9)||'USD'|| chr(9)||'NAS'|| chr(9)||'HOT'||chr(10)||
'7'|| chr(9)||'Logan, Edward'|| chr(9)||to_char(sysdate-55,'MM/DD/RR')|| chr(9)||to_char(sysdate-50,'DD-MM-YYYY')||chr(9)||'7'||chr(9)|| '$905'|| chr(9)||'USD'|| chr(9)||'NAS'|| chr(9)||''||chr(10)||
'6'|| chr(9)||'Logan, Edward'|| chr(9)||to_char(sysdate-77,'MM/DD/RR')|| chr(9)||to_char(sysdate-75,'DD-MM-YYYY')||chr(9)||'4'||chr(9)|| '€1.515,00'|| chr(9)||'EURO'|| chr(9)||'EMEA'||chr(9)||'PARTNER'||chr(10)||
'5'|| chr(9)||'Lambert, Albert'|| chr(9)||to_char(sysdate-32,'MM/DD/RR')|| chr(9)||to_char(sysdate-31,'DD-MM-YYYY')||chr(9)||'5'||chr(9)|| '$950.00'|| chr(9)||'USD'|| chr(9)||'NAS'|| chr(9)||'' ||chr(10)||
'4'|| chr(9)||'LaGuardia, Fiorello'||chr(9)||to_char(sysdate-56,'MM/DD/RR')|| chr(9)||to_char(sysdate-55,'DD-MM-YYYY')||chr(9)||'5'||chr(9)|| 'Â¥1.090,04'||chr(9)||'USD'|| chr(9)||'YEN'|| chr(9)||'' ||chr(10)||
'3'|| chr(9)||'Hartsfield, William'||chr(9)||to_char(sysdate-12,'MM/DD/RR')|| chr(9)||to_char(sysdate-10,'DD-MM-YYYY')||chr(9)||'5'||chr(9)|| '$1,640.00'||chr(9)||'USD'|| chr(9)||'NAS'|| chr(9)||' ' ||chr(10)||
'2'|| chr(9)||'Dulles, John'|| chr(9)||to_char(sysdate-18, 'MM/DD/RR')||chr(9)||to_char(sysdate-9,'DD-MM-YYYY')|| chr(9)||'10'||chr(9)|| '$5,380'|| chr(9)||'USD'|| chr(9)||'NAS'|| chr(9)||'LARGE ORDER, HOT'||chr(10)||
'1'|| chr(9)||'Bradley, Eugene'|| chr(9)||to_char(sysdate-29, 'MM/DD/RR')||chr(9)||to_char(sysdate-20,'DD-MM-YYYY')||chr(9)||'3'||chr(9)|| '£1.890,40'||chr(9)||'POUND'|| chr(9)||'EMEA'||chr(9)||'UK';
elsif p_example_number = 2 then
return 'Order #'||chr(9)||
'Customer Name'||chr(9)||
'Order Date'||chr(9)||
'Fulfillment Date'||chr(9)||
'Order Items'||chr(9)||
'Unit Cost'||chr(9)||
'Currency'||chr(9)||
'Region'||chr(9)||
'Tags'||chr(9)||
'Last Updated'||chr(10)||
'10'||chr(9)||'Bradley, Eugene'|| chr(9)||to_char(sysdate-1,'MM/DD/RR')|| chr(9)||to_char(sysdate-0,'DD-MM-YYYY')|| chr(9)||'3'||chr(9)|| '$ 870'|| chr(9)||'USD'|| chr(9)||'NAS'|| chr(9)||'-'||chr(9)|| to_char(systimestamp,'DD-MON-RR HH24.MI.SS.SSXFF AM')||chr(10)||
'9'|| chr(9)||'Hartsfield, William'||chr(9)||to_char(sysdate-2,'MM/DD/RR')|| chr(9)||to_char(sysdate-1,'DD-MM-YYYY')|| chr(9)||'3'||chr(9)|| '$730'|| chr(9)||'USD'|| chr(9)||'NAS'|| chr(9)||'-'||chr(9)|| to_char(systimestamp,'DD-MON-RR HH24.MI.SS.SSXFF AM')||chr(10)||
'8'|| chr(9)||'OHare, Frank '|| chr(9)||to_char(sysdate-8, 'MM/DD/RR')|| chr(9)||to_char(sysdate-7,'DD-MM-YYYY')|| chr(9)||'1,244'||chr(9)|| '60'|| chr(9)||'USD'|| chr(9)||'NAS'|| chr(9)||'HOT'||chr(9)|| to_char(systimestamp,'DD-MON-RR HH24.MI.SS.SSXFF AM')||chr(10)||
'7'|| chr(9)||'Logan, Edward'|| chr(9)||to_char(sysdate-55,'MM/DD/RR')|| chr(9)||to_char(sysdate-50,'DD-MM-YYYY')||chr(9)||'7'||chr(9)|| '$905'|| chr(9)||'USD'|| chr(9)||'NAS'|| chr(9)||'-'||chr(9)|| to_char(systimestamp,'DD-MON-RR HH24.MI.SS.SSXFF AM')||chr(10)||
'6'|| chr(9)||'Logan, Edward'|| chr(9)||to_char(sysdate-77,'MM/DD/RR')|| chr(9)||to_char(sysdate-75,'DD-MM-YYYY')||chr(9)||'4'||chr(9)|| '€1.515,00'|| chr(9)||'EURO'|| chr(9)||'EMEA'||chr(9)||'PARTNER'||chr(9)|| to_char(systimestamp,'DD-MON-RR HH24.MI.SS.SSXFF AM')||chr(10)||
'5'|| chr(9)||'Lambert, Albert'|| chr(9)||to_char(sysdate-32,'MM/DD/RR')|| chr(9)||to_char(sysdate-31,'DD-MM-YYYY')||chr(9)||'5'||chr(9)|| '$950.00'|| chr(9)||'USD'|| chr(9)||'NAS'|| chr(9)||''||chr(9)|| to_char(systimestamp,'DD-MON-RR HH24.MI.SS.SSXFF AM')||chr(10)||
'4'|| chr(9)||'LaGuardia, Fiorello'||chr(9)||to_char(sysdate-56,'MM/DD/RR')|| chr(9)||to_char(sysdate-55,'DD-MM-YYYY')||chr(9)||'5'||chr(9)|| 'Â¥1.090,04'||chr(9)||'USD'|| chr(9)||'YEN'|| chr(9)||''||chr(9)|| to_char(systimestamp,'DD-MON-RR HH24.MI.SS.SSXFF AM')||chr(10)||
'3'|| chr(9)||'Hartsfield, William'||chr(9)||to_char(sysdate-12,'MM/DD/RR')|| chr(9)||to_char(sysdate-10,'DD-MM-YYYY')||chr(9)||'5'||chr(9)|| '$1,640.00'||chr(9)||'USD'|| chr(9)||'NAS'|| chr(9)||'-'||chr(9)|| to_char(systimestamp,'DD-MON-RR HH24.MI.SS.SSXFF AM')||chr(10)||
'2'|| chr(9)||'Dulles, John'|| chr(9)||to_char(sysdate-18, 'MM/DD/RR')||chr(9)||to_char(sysdate-9,'DD-MM-YYYY')|| chr(9)||'10'||chr(9)|| '$5,380'|| chr(9)||'USD'|| chr(9)||'NAS'|| chr(9)||'LARGE ORDER, HOT'||chr(9)||to_char(systimestamp,'DD-MON-RR HH24.MI.SS.SSXFF AM')||chr(10)||
'1'|| chr(9)||'Bradley, Eugene'|| chr(9)||to_char(sysdate-29, 'MM/DD/RR')||chr(9)||to_char(sysdate-20,'DD-MM-YYYY')||chr(9)||'3'||chr(9)|| '£1.890,40'||chr(9)||'POUND'|| chr(9)||'EMEA'||chr(9)||'UK'||chr(9)|| to_char(systimestamp,'DD-MON-RR HH24.MI.SS.SSXFF AM');
else
return 'not found';
end if;
end get_data_example;
procedure log_status (
p_status in varchar2 default null,
p_context in varchar2 default null,
p_sqlerrm in varchar2 default null)
is
begin
insert into eba_dbtools_app_log
(status, context, sqlerrm) values
(p_status, p_context, p_sqlerrm);
commit;
end log_status;
procedure remove_ws_not_in_use (
p_markdown_sql in varchar2 default null)
is
begin
begin
for c1 in (
select distinct collection_name
from apex_collections
where collection_name like 'WORKSHEET_%' and
instr(p_markdown_sql,'@'||collection_name) = 0
) loop
APEX_COLLECTION.DELETE_COLLECTION(p_collection_name => c1.collection_name);
log_status (p_status=>'Delete Collection', p_context => c1.collection_name,p_sqlerrm=> null);
end loop;
exception when others then
log_status (p_status=>'Delete Collection', p_context => 'remove_ws_not_in_use',p_sqlerrm=>sqlerrm);
end;
end remove_ws_not_in_use;
function worksheet_collection_exists (
p_worksheet_name in varchar2 default null)
return boolean
is
c integer := 0;
begin
for c1 in (select 1 from apex_collections where collection_name = upper(p_worksheet_name)) loop
c := c + 1;
exit;
end loop;
if c > 0 then return true;
else return false;
end if;
end worksheet_collection_exists;
function is_number (p_string in varchar2 default null) return boolean
is
s varchar2(100) := null; -- clean string
x number; -- numeric variable
first_comma integer := 0; -- comma
first_dot integer := 0; -- dot
begin
s := trim(p_string);
begin
-- remove currencies
s := replace(s,g_nls_usd,null); -- USD
s := replace(s,g_nls_euro,null);
s := replace(s,g_nls_yen,null);
s := replace(s,g_nls_pound,null);
s := trim(s);
-- detect seperators and decimal when both are present
first_comma := instr(s,','); -- first comma cc
first_dot := instr(s,'.'); -- first dot cc
if first_comma > 0 and first_dot > 0 and first_dot > first_comma then
-- 999,999.00
s := replace(s,',',null);
elsif first_comma > 0 and first_dot > 0 and first_comma > first_dot then
-- 999.999,00
s := replace(s,'.',null);
s := replace(s,',','.');
end if;
-- remove commas
if instr(s,',') > 0 then
-- 999,999.00
s := replace(s,',',null);
end if;
s := rtrim(s,g_nls_decimal);
s := trim(s);
-- cast to number
x := to_number(s);
return true;
exception when others then
return false;
end;
end is_number;
function fmt_heading (
p_string in varchar2 default null,
p_use_underscores in varchar2 default 'Y',
col_number in varchar2 default null)
return varchar2
is
x varchar2(8000) := trim(p_string);
begin
if x is null then
if col_number is not null then
x := 'COL_'||col_number;
else
x := 'not provided';
end if;
end if;
--return upper(x);
for j in 1..50 loop
x := replace(replace(replace(replace(replace(replace(replace(x,'/',' '),'(','_'),')','_'),'&','_'),'%','_'),chr(9),'_'),chr(13),null);
x := replace(replace(replace(x,' ','_'),',','_'),'.','_');
x := replace(replace(rtrim(x,'_'),'~','_'),'*',null);
for k in 1..10 loop
x := regexp_replace(x,'_{2,}','_');
end loop;
end loop;
if p_use_underscores = 'N' then
x := replace(x,'_',' ');
end if;
return trim(lower(x));
end fmt_heading;
function is_date (p_string in varchar2 default null, p_date_format_mask in varchar2 default null) return boolean
is
d date;
begin
begin
d := to_date(p_string,p_date_format_mask);
return true;
exception when others then
return false;
end;
end is_date;
function get_occurances (
p_string in varchar2 default null,
p_in in varchar2 default null)
return number
is
n number := 0;
begin
if p_string is null or p_in is null then return 0; end if;
for c1 in (select MAX((LENGTH(p_string)-LENGTH(REPLACE(p_string,p_in,'')))/LENGTH(p_in)) n from dual) loop
n := c1.n;
end loop;
return n;
end get_occurances;
function get_column_datatype (
p_collection in varchar2 default null,
p_column in varchar2 default null,
p_date_format_mask in varchar2 default null)
return varchar2
is
l_offset integer := 1;
r varchar2(255) := null;
c integer := 0;
l_value varchar2(32767);
l_max_length integer := 0;
l_is_number_count integer := 0;
l_is_date_count integer := 0;
l_nn_v_count integer := 0;
l_contains_null_yn varchar2(1);
-- date guessing
l_cc_1_4_is_number integer := 0;
l_cc_1_4_is_number_max varchar2(30) := '0000';
l_cc_1_2_is_number integer := 0;
l_cc_1_2_is_number_max varchar2(30) := '00';
l_cc_4_2_is_number integer := 0;
l_cc_4_2_is_number_max varchar2(30) := '00';
l_cc_6_2_is_number integer := 0;
l_cc_6_2_is_number_max varchar2(30) := '00';
l_cc_7_2_is_number integer := 0;
l_cc_7_2_is_number_max varchar2(30) := '00';
l_cc_7_4_is_number integer := 0;
l_cc_7_4_is_number_max varchar2(30) := '0000';
l_cc_8_2_is_number integer := 0;
l_cc_8_2_is_number_max varchar2(30) := '00';
l_cc_9_2_is_number integer := 0;
l_cc_9_2_is_number_max varchar2(30) := '00';
--
l_cc_8_4_is_number integer := 0;
l_cc_10_2_is_number integer := 0;
l_cc_11_2_is_number integer := 0;
l_cc_12_2_is_number integer := 0;
l_cc_13_2_is_number integer := 0;
l_cc_14_2_is_number integer := 0;
--
l_cc_3_1_is_slash integer := 0;
l_cc_3_1_is_hyphen integer := 0;
l_cc_3_1_is_dot integer := 0;
--
l_cc_5_1_is_slash integer := 0;
l_cc_5_1_is_hyphen integer := 0;
l_cc_5_1_is_dot integer := 0;
--
l_cc_6_1_is_slash integer := 0;
l_cc_6_1_is_hyphen integer := 0;
l_cc_6_1_is_dot integer := 0;
--
l_cc_7_1_is_slash integer := 0;
l_cc_7_1_is_hyphen integer := 0;
l_cc_7_1_is_dot integer := 0;
--
l_cc_9_1_is_space integer := 0;
--
l_cc_13_1_is_colon integer := 0;
l_cc_13_1_is_dot integer := 0;
--
l_cc_14_1_is_colon integer := 0;
l_cc_14_1_is_dot integer := 0;
--
l_cc_15_1_is_colon integer := 0;
l_cc_15_1_is_dot integer := 0;
--
l_colon_count integer := 0;
l_dot_count integer := 0;
l_AM_count integer := 0;
l_pm_count integer := 0;
begin
g_fm := null;
for c1 in (select * from apex_collections where collection_name = p_collection and seq_id > l_offset) loop
c := c + 1;
if upper(p_column) = 'C001' then l_value := c1.c001;
elsif upper(p_column) = 'C002' then l_value := c1.c002;
elsif upper(p_column) = 'C003' then l_value := c1.c003;
elsif upper(p_column) = 'C004' then l_value := c1.c004;
elsif upper(p_column) = 'C005' then l_value := c1.c005;
elsif upper(p_column) = 'C006' then l_value := c1.c006;
elsif upper(p_column) = 'C007' then l_value := c1.c007;
elsif upper(p_column) = 'C008' then l_value := c1.c008;
elsif upper(p_column) = 'C009' then l_value := c1.c009;
elsif upper(p_column) = 'C010' then l_value := c1.c010;
elsif upper(p_column) = 'C011' then l_value := c1.c011;
elsif upper(p_column) = 'C012' then l_value := c1.c012;
elsif upper(p_column) = 'C013' then l_value := c1.c013;
elsif upper(p_column) = 'C014' then l_value := c1.c014;
elsif upper(p_column) = 'C015' then l_value := c1.c015;
elsif upper(p_column) = 'C016' then l_value := c1.c016;
elsif upper(p_column) = 'C017' then l_value := c1.c017;
elsif upper(p_column) = 'C018' then l_value := c1.c018;
elsif upper(p_column) = 'C019' then l_value := c1.c019;
elsif upper(p_column) = 'C020' then l_value := c1.c020;
elsif upper(p_column) = 'C021' then l_value := c1.c021;
elsif upper(p_column) = 'C022' then l_value := c1.c022;
elsif upper(p_column) = 'C023' then l_value := c1.c023;
elsif upper(p_column) = 'C024' then l_value := c1.c024;
elsif upper(p_column) = 'C025' then l_value := c1.c025;
elsif upper(p_column) = 'C026' then l_value := c1.c026;
elsif upper(p_column) = 'C027' then l_value := c1.c027;
elsif upper(p_column) = 'C028' then l_value := c1.c028;
elsif upper(p_column) = 'C029' then l_value := c1.c029;
elsif upper(p_column) = 'C030' then l_value := c1.c030;
elsif upper(p_column) = 'C031' then l_value := c1.c031;
elsif upper(p_column) = 'C032' then l_value := c1.c032;
elsif upper(p_column) = 'C033' then l_value := c1.c033;
elsif upper(p_column) = 'C034' then l_value := c1.c034;
elsif upper(p_column) = 'C035' then l_value := c1.c035;
elsif upper(p_column) = 'C036' then l_value := c1.c036;
elsif upper(p_column) = 'C037' then l_value := c1.c037;
elsif upper(p_column) = 'C038' then l_value := c1.c038;
elsif upper(p_column) = 'C039' then l_value := c1.c039;
elsif upper(p_column) = 'C040' then l_value := c1.c040;
elsif upper(p_column) = 'C041' then l_value := c1.c041;
elsif upper(p_column) = 'C042' then l_value := c1.c042;
elsif upper(p_column) = 'C043' then l_value := c1.c043;
elsif upper(p_column) = 'C044' then l_value := c1.c044;
elsif upper(p_column) = 'C045' then l_value := c1.c045;
elsif upper(p_column) = 'C046' then l_value := c1.c046;
elsif upper(p_column) = 'C047' then l_value := c1.c047;
elsif upper(p_column) = 'C048' then l_value := c1.c048;
elsif upper(p_column) = 'C049' then l_value := c1.c049;
elsif upper(p_column) = 'C050' then l_value := c1.c050;
end if;
-- only count real data
l_value := replace(replace(replace(l_value,chr(10),null),chr(13),null),chr(9),null);
l_value := trim(l_value);
-- calculate stats
if length(l_value) > l_max_length then
l_max_length := length(l_value);
end if;
if l_value is not null then
l_nn_v_count := l_nn_v_count + 1;
end if;
if l_value is not null and is_number(l_value) then
l_is_number_count := l_is_number_count + 1;
end if;
if l_value is not null and is_date(l_value,p_date_format_mask) then
l_is_date_count := l_is_date_count + 1;
end if;
-- date gussing
if l_value is not null then
if length(l_value) > 10 and is_number(substr(l_value,10,2)) then
l_cc_10_2_is_number := l_cc_10_2_is_number + 1;
end if;
if length(l_value) > 11 and is_number(substr(l_value,11,2)) then
l_cc_11_2_is_number := l_cc_11_2_is_number + 1;
end if;
if length(l_value) > 12 and is_number(substr(l_value,13,2)) then
l_cc_13_2_is_number := l_cc_13_2_is_number + 1;
end if;
if length(l_value) > 13 and is_number(substr(l_value,14,2)) then
l_cc_14_2_is_number := l_cc_14_2_is_number + 1;
end if;
if length(l_value) > 10 and is_number(substr(l_value,8,4)) then
l_cc_8_4_is_number := l_cc_8_4_is_number + 1;
end if;
if is_number(substr(l_value,9,2)) then
l_cc_9_2_is_number := l_cc_9_2_is_number + 1;
if substr(l_value,6,2) > NVL(l_cc_9_2_is_number_max,'00') then
l_cc_9_2_is_number_max := substr(l_value,9,2);
end if;
end if;
if is_number(substr(l_value,6,2)) then
l_cc_6_2_is_number := l_cc_6_2_is_number + 1;
if substr(l_value,6,2) > NVL(l_cc_6_2_is_number_max,'00') then
l_cc_6_2_is_number_max := substr(l_value,6,2);
end if;
end if;
if is_number(substr(l_value,1,4)) then
l_cc_1_4_is_number := l_cc_1_4_is_number + 1;
if substr(l_value,1,4) > NVL(l_cc_1_4_is_number_max,'0000') then
l_cc_1_4_is_number_max := substr(l_value,1,4);
end if;
end if;
if is_number(substr(l_value,1,2)) then
l_cc_1_2_is_number := l_cc_1_2_is_number + 1;
if substr(l_value,1,2) > NVL(l_cc_1_2_is_number_max,'00') then
l_cc_1_2_is_number_max := substr(l_value,1,2);
end if;
end if;
if substr(l_value,4,2) is not null and is_number(substr(l_value,4,2)) then
l_cc_4_2_is_number := l_cc_4_2_is_number + 1;
if substr(l_value,4,2) > NVL(l_cc_4_2_is_number_max,'00') then
l_cc_4_2_is_number_max := substr(l_value,4,2);
end if;
end if;
if substr(l_value,7,2) is not null and is_number(substr(l_value,7,2)) then
l_cc_7_2_is_number := l_cc_7_2_is_number + 1;
if substr(l_value,7,2) > NVL(l_cc_7_2_is_number_max,'00') then
l_cc_7_2_is_number_max := substr(l_value,7,2);
end if;
end if;
if substr(l_value,8,2) is not null and is_number(substr(l_value,8,2)) then
l_cc_8_2_is_number := l_cc_8_2_is_number + 1;
if substr(l_value,8,2) > NVL(l_cc_8_2_is_number_max,'00') then
l_cc_8_2_is_number_max := substr(l_value,8,2);
end if;
end if;
if substr(l_value,7,4) is not null and is_number(substr(l_value,7,4)) then
l_cc_7_4_is_number := l_cc_7_4_is_number + 1;
if substr(l_value,7,2) > NVL(l_cc_7_4_is_number_max,'0000') then
l_cc_7_4_is_number_max := substr(l_value,7,4);
end if;
end if;
--
if substr(l_value,3,1) = '/' then
l_cc_3_1_is_slash := l_cc_3_1_is_slash + 1;
end if;
if substr(l_value,3,1) = '-' then
l_cc_3_1_is_hyphen := l_cc_3_1_is_hyphen + 1;
end if;
if substr(l_value,3,1) = '.' then
l_cc_3_1_is_dot := l_cc_3_1_is_dot + 1;
end if;
--
if substr(l_value,5,1) = '/' then
l_cc_5_1_is_slash := l_cc_5_1_is_slash + 1;
end if;
if substr(l_value,5,1) = '-' then
l_cc_5_1_is_hyphen := l_cc_5_1_is_hyphen + 1;
end if;
if substr(l_value,5,1) = '.' then
l_cc_5_1_is_dot := l_cc_5_1_is_dot + 1;
end if;
--
if substr(l_value,6,1) = '/' then
l_cc_6_1_is_slash := l_cc_6_1_is_slash + 1;
end if;
if substr(l_value,6,1) = '-' then
l_cc_6_1_is_hyphen := l_cc_6_1_is_hyphen + 1;
end if;
if substr(l_value,6,1) = '.' then
l_cc_6_1_is_dot := l_cc_6_1_is_dot + 1;
end if;
if substr(l_value,7,1) = '-' then
l_cc_7_1_is_hyphen := l_cc_7_1_is_hyphen + 1;
end if;
if substr(l_value,7,1) = '.' then
l_cc_7_1_is_dot := l_cc_7_1_is_dot + 1;
end if;
if substr(l_value,7,1) = '/' then
l_cc_7_1_is_slash := l_cc_7_1_is_slash + 1;
end if;
--
if substr(l_value,9,1) = ' ' then
l_cc_9_1_is_space := l_cc_9_1_is_space + 1;
end if;
if substr(l_value,9,1) = ' ' then
l_cc_9_1_is_space := l_cc_9_1_is_space + 1;
end if;
--
if substr(l_value,13,1) = ':' then
l_cc_13_1_is_colon := l_cc_13_1_is_colon + 1;
end if;
if substr(l_value,13,1) = '.' then
l_cc_13_1_is_dot := l_cc_13_1_is_dot + 1;
end if;
if substr(l_value,14,1) = ':' then
l_cc_14_1_is_colon := l_cc_14_1_is_colon + 1;
end if;
if substr(l_value,14,1) = '.' then
l_cc_14_1_is_dot := l_cc_14_1_is_dot + 1;
end if;
if substr(l_value,15,1) = ':' then
l_cc_15_1_is_colon := l_cc_15_1_is_colon +1 ;
end if;
if substr(l_value,15,1) = '.' then
l_cc_15_1_is_dot := l_cc_15_1_is_dot +1 ;
end if;
l_colon_count := get_occurances(l_value,':');
l_dot_count := get_occurances(l_value,'.');
l_am_count := get_occurances(upper(l_value),'AM');
l_pm_count := get_occurances(upper(l_value),'PM');
end if;
end loop;
if c = l_nn_v_count then
l_contains_null_yn := 'N';
else
l_contains_null_yn := 'Y';
end if;
--
-- debug
if instr(upper(l_value),'NOV') > 0 or instr(l_value,'11') > 0 then
log_status (
p_status =>
'c='||c||', '||
'is_number_count='||l_is_number_count||', '||
'cc_3_1_is_slash='||l_cc_3_1_is_slash||', '||
'cc_3_1_is_hyphen='||l_cc_3_1_is_hyphen||', '||
'not_null_value_count= '||l_nn_v_count||', '||
'cc_6_1_is_slash='||l_cc_6_1_is_slash||', '||
'cc_1_2_is_number='||l_cc_1_2_is_number||', '||
'cc_8_2_is_number='||l_cc_8_2_is_number||', '||
'cc_4_2_is_number='||l_cc_4_2_is_number||', '||
'cc_13_1_is_dot='||l_cc_13_1_is_dot||', '||
'max_length='||l_max_length||', '||
'cc_7_4_is_number='||l_cc_7_4_is_number||', '||
'cc_1_2_is_number_max='||l_cc_1_2_is_number_max,
p_context => l_value,
p_sqlerrm => p_column);
end if;
if l_nn_v_count = l_is_number_count and l_nn_v_count > 0 then
r := 'num';
elsif l_nn_v_count = l_is_date_count and l_nn_v_count > 0 then
r := 'date';
g_fm := ' /mask '||p_date_format_mask;
elsif l_cc_3_1_is_hyphen = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_8_4_is_number = l_nn_v_count and
l_cc_11_2_is_number = l_nn_v_count and
l_cc_13_2_is_number = l_nn_v_count and
l_cc_15_1_is_dot = l_nn_v_count and
l_max_length > 18 and l_max_length < 21 and
(l_am_count > 0 or l_pm_count > 0)
then
r := 'date';
-- 1234567890123456789
g_fm := ' /mask DD-MON-YYYY HH.MIAM';
elsif l_cc_3_1_is_hyphen = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_8_2_is_number = l_nn_v_count and
l_cc_11_2_is_number = l_nn_v_count and
l_cc_14_2_is_number = l_nn_v_count and
l_cc_13_1_is_dot = l_nn_v_count and
l_max_length > 15 and l_max_length < 18 and
(l_am_count > 0 or l_pm_count > 0)
then
r := 'date';
-- 12345678901234567
g_fm := ' /mask DD-MON-RR HH.MIAM';
elsif l_cc_3_1_is_hyphen = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_8_4_is_number = l_nn_v_count and
l_cc_11_2_is_number = l_nn_v_count and
l_cc_13_2_is_number = l_nn_v_count and
l_cc_15_1_is_colon = l_nn_v_count and
l_max_length > 18 and l_max_length < 21 and
(l_am_count > 0 or l_pm_count > 0)
then
r := 'date';
-- 1234567890123456789
g_fm := ' /mask DD-MON-YYYY HH:MIAM';
elsif l_cc_3_1_is_hyphen = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_8_2_is_number = l_nn_v_count and
l_cc_11_2_is_number = l_nn_v_count and
l_cc_14_2_is_number = l_nn_v_count and
l_cc_13_1_is_colon = l_nn_v_count and
l_max_length > 15 and l_max_length < 18 and
(l_am_count > 0 or l_pm_count > 0)
then
r := 'date';
-- 12345678901234567
g_fm := ' /mask DD-MON-RR HH:MIAM';
elsif l_cc_3_1_is_hyphen = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_8_2_is_number = l_nn_v_count and
l_cc_11_2_is_number = l_nn_v_count and
l_cc_13_1_is_dot = l_nn_v_count and
l_max_length > 25 and
l_max_length < 35 and
(l_am_count > 0 or l_pm_count > 0)
then
r := 'date';
-- 12345678901234567890123456789
g_fm := ' /mask DD-MON-RR HH24.MI.SS.FF6 AM';
elsif l_cc_3_1_is_hyphen = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_8_2_is_number = l_nn_v_count and
l_cc_11_2_is_number = l_nn_v_count and
l_cc_13_1_is_colon = l_nn_v_count and
l_max_length > 25 and
l_max_length < 35 and
(l_am_count > 0 or l_pm_count > 0)
then
r := 'date';
-- 12345678901234567890123456789
g_fm := ' /mask DD-MON-RR HH24:MI:SS:FF6 AM';
elsif l_cc_3_1_is_hyphen = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_8_2_is_number = l_nn_v_count and
l_cc_7_1_is_hyphen = l_nn_v_count and
l_max_length > 8 and l_max_length < 10
then
r := 'date';
-- 123456789
g_fm := ' /mask DD-MON-RR';
elsif l_cc_3_1_is_slash = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_8_2_is_number = l_nn_v_count and
l_cc_7_1_is_slash = l_nn_v_count and
l_max_length > 8 and l_max_length < 10
then
r := 'date';
-- 123456789
g_fm := ' /mask DD/MON/RR';
elsif l_cc_3_1_is_dot = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_8_2_is_number = l_nn_v_count and
l_cc_7_1_is_dot = l_nn_v_count and
l_max_length > 8 and l_max_length < 10
then
r := 'date';
-- 123456789
g_fm := ' /mask DD.MON.RR';
elsif l_cc_5_1_is_dot = l_nn_v_count and
l_cc_1_4_is_number = l_nn_v_count and
l_cc_6_2_is_number = l_nn_v_count and
l_cc_9_2_is_number = l_nn_v_count and
l_max_length > 8
then
r := 'date';
-- 1234567890
g_fm := ' /mask YYYY.MM.DD';
elsif l_cc_5_1_is_slash = l_nn_v_count and
l_cc_1_4_is_number = l_nn_v_count and
l_cc_6_2_is_number = l_nn_v_count and
l_cc_9_2_is_number = l_nn_v_count and
l_max_length > 8
then
r := 'date';
-- 1234567890
g_fm := ' /mask YYYY/MM/DD';
elsif l_cc_3_1_is_slash = l_nn_v_count and
l_cc_6_1_is_slash = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_4_2_is_number = l_nn_v_count and
l_cc_7_4_is_number = l_nn_v_count and
l_max_length > 8 and l_max_length < 11 and
l_cc_4_2_is_number_max < 13
then
r := 'date';
-- 1234567890
g_fm := ' /mask DD/MM/YYYY';
elsif l_cc_3_1_is_slash = l_nn_v_count and
l_cc_6_1_is_slash = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_4_2_is_number = l_nn_v_count and
l_cc_7_4_is_number = l_nn_v_count and
l_max_length > 8 and l_max_length < 11 and
l_cc_1_2_is_number_max < 13
then
r := 'date';
-- 1234567890
g_fm := ' /mask MM/DD/YYYY';
elsif l_cc_3_1_is_dot = l_nn_v_count and
l_cc_6_1_is_dot = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_4_2_is_number = l_nn_v_count and
l_cc_7_4_is_number = l_nn_v_count and
l_max_length > 8 and l_max_length < 11 and
l_cc_4_2_is_number_max < 13
then
r := 'date';
-- 1234567890
g_fm := ' /mask DD.MM.YYYY';
elsif l_cc_3_1_is_hyphen = l_nn_v_count and
l_cc_6_1_is_hyphen = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_4_2_is_number = l_nn_v_count and
l_cc_7_4_is_number = l_nn_v_count and
l_max_length > 8 and l_max_length < 11 and
l_cc_4_2_is_number_max < 13
then
r := 'date';
-- 1234567890
g_fm := ' /mask DD-MM-YYYY';
elsif l_cc_3_1_is_dot = l_nn_v_count and
l_cc_6_1_is_dot = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_4_2_is_number = l_nn_v_count and
l_cc_7_4_is_number = l_nn_v_count and
l_max_length > 8 and l_max_length < 11 and
l_cc_1_2_is_number_max < 13
then
r := 'date';
-- 1234567890
g_fm := ' /mask MM.DD.YYYY';
--
elsif l_cc_3_1_is_slash = l_nn_v_count and
l_cc_6_1_is_slash = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_4_2_is_number = l_nn_v_count and
l_cc_7_2_is_number = l_nn_v_count and
l_max_length < 9 and
l_cc_4_2_is_number_max < 13
then
r := 'date';
-- 1234567890
g_fm := ' /mask DD/MM/RR';
elsif l_cc_3_1_is_slash = l_nn_v_count and
l_cc_6_1_is_slash = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_4_2_is_number = l_nn_v_count and
l_cc_7_2_is_number = l_nn_v_count and
l_max_length < 9 and
l_cc_1_2_is_number_max < 13
then
r := 'date';
-- 1234567890
g_fm := ' /mask MM/DD/RR';
elsif l_cc_3_1_is_dot = l_nn_v_count and
l_cc_6_1_is_dot = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_4_2_is_number = l_nn_v_count and
l_cc_7_2_is_number = l_nn_v_count and
l_max_length < 9 and
l_cc_4_2_is_number_max < 13
then
r := 'date';
-- 1234567890
g_fm := ' /mask DD.MM.RR';
elsif l_cc_3_1_is_dot = l_nn_v_count and
l_cc_6_1_is_dot = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_4_2_is_number = l_nn_v_count and
l_cc_7_2_is_number = l_nn_v_count and
l_max_length < 9 and
l_cc_1_2_is_number_max < 13
then
r := 'date';
-- 1234567890
g_fm := ' /mask MM.DD.RR';
--
elsif l_cc_3_1_is_slash = l_nn_v_count and
l_cc_6_1_is_slash = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_4_2_is_number = l_nn_v_count and
l_cc_7_2_is_number = l_nn_v_count and
l_max_length > 15 and
l_max_length < 17 and
l_cc_1_2_is_number_max < 13 and
l_colon_count = 1
then
r := 'date';
-- 1234567890123456
g_fm := ' /mask MM/DD/RR HH24:MI';
elsif l_cc_3_1_is_slash = l_nn_v_count and
l_cc_6_1_is_slash = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_4_2_is_number = l_nn_v_count and
l_cc_7_2_is_number = l_nn_v_count and
l_cc_10_2_is_number = l_nn_v_count and
l_max_length > 12 and l_max_length < 15 and
l_cc_4_2_is_number_max < 13 and
l_colon_count = 1
then
r := 'date';
-- 1234567890123456
g_fm := ' /mask DD/MM/RR HH24:MI';
--
elsif l_cc_3_1_is_slash = l_nn_v_count and
l_cc_6_1_is_slash = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_4_2_is_number = l_nn_v_count and
l_cc_7_2_is_number = l_nn_v_count and
l_cc_10_2_is_number = l_nn_v_count and
l_max_length > 17 and
l_max_length < 20 and
l_cc_1_2_is_number_max < 13 and
l_colon_count = 2
then
r := 'date';
-- 1234567890123456789
g_fm := ' /mask MM/DD/RR HH24:MI:SS';
elsif l_cc_3_1_is_slash = l_nn_v_count and
l_cc_6_1_is_slash = l_nn_v_count and
l_cc_1_2_is_number = l_nn_v_count and
l_cc_4_2_is_number = l_nn_v_count and
l_cc_7_2_is_number = l_nn_v_count and
l_max_length > 17 and
l_max_length < 20 and
l_cc_4_2_is_number_max < 13 and
l_colon_count = 2
then
r := 'date';
-- 1234567890123456789
-- DD/MM/RR 24:MI:SS
g_fm := ' /mask DD/MM/RR HH24:MI:SS';
--
elsif l_max_length < 30 then
r := 'vc50';
elsif l_max_length < 100 then
r := 'vc200';
elsif l_max_length > 4000 then
r := 'clob';
else
r := 'vc4000';
end if;
return r;
end get_column_datatype;
function get_worksheet_structure (
p_table_name in varchar2 default null,
p_collection_name in varchar2 default null,
p_first_row_is_header_yn in varchar2 default 'Y', -- ignore and assume this
p_date_format_mask in varchar2 default 'DD-MON-YYYY')
return varchar2
is
x varchar2(32767) := null;
l_indent varchar2(30) := ' ';
l_col_names varchar2(255) := 'A B C D E F G H I J K L M N O P Q R S T U V W X Y ZAAABACADAEAFAGAHAJAKALAMANAOAPAQARASATAUAVAWAXAYAZBA';
l_col_count integer := 0;
c integer := 0;
s varchar2(50) := ' ';
h APEX_APPLICATION_GLOBAL.VC_ARR2;
begin
for i in 1..50 loop h(i) := null; end loop;
-- table name
x := substr(lower(eba_dbtools_design_schema_pub.trim_identifier_length(eba_dbtools_design_schema_pub.clean_name(p_table_name))),1,33);
-- worksheet name
x := replace(rpad(x,35,s),'_',' ')||'@'||p_collection_name;
-- new line
x := x||chr(10);
-- get columns
for c1 in (select * from apex_collections where collection_name = upper(p_collection_name) order by seq_id) loop
c := c + 1;
if c = 1 then
h(1) := l_indent||rpad(fmt_heading(substr(c1.c001,1,30),'N','01'),31,s)||rpad(get_column_datatype(p_collection_name,'C001',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c001,'','01')||g_fm||chr(10);
h(2) := l_indent||rpad(fmt_heading(substr(c1.c002,1,30),'N','02'),31,s)||rpad(get_column_datatype(p_collection_name,'C002',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c002,'','02')||g_fm||chr(10);
h(3) := l_indent||rpad(fmt_heading(substr(c1.c003,1,30),'N','03'),31,s)||rpad(get_column_datatype(p_collection_name,'C003',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c003,'','03')||g_fm||chr(10);
h(4) := l_indent||rpad(fmt_heading(substr(c1.c004,1,30),'N','04'),31,s)||rpad(get_column_datatype(p_collection_name,'C004',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c004,'','04')||g_fm||chr(10);
h(5) := l_indent||rpad(fmt_heading(substr(c1.c005,1,30),'N','05'),31,s)||rpad(get_column_datatype(p_collection_name,'C005',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c005,'','05')||g_fm||chr(10);
h(6) := l_indent||rpad(fmt_heading(substr(c1.c006,1,30),'N','06'),31,s)||rpad(get_column_datatype(p_collection_name,'C006',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c006,'','06')||g_fm||chr(10);
h(7) := l_indent||rpad(fmt_heading(substr(c1.c007,1,30),'N','07'),31,s)||rpad(get_column_datatype(p_collection_name,'C007',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c007,'','07')||g_fm||chr(10);
h(8) := l_indent||rpad(fmt_heading(substr(c1.c008,1,30),'N','08'),31,s)||rpad(get_column_datatype(p_collection_name,'C008',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c008,'','08')||g_fm||chr(10);
h(9) := l_indent||rpad(fmt_heading(substr(c1.c009,1,30),'N','09'),31,s)||rpad(get_column_datatype(p_collection_name,'C009',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c009,'','09')||g_fm||chr(10);
h(10) := l_indent||rpad(fmt_heading(substr(c1.c010,1,30),'N','10'),31,s)||rpad(get_column_datatype(p_collection_name,'C010',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c010,'','10')||g_fm||chr(10);
h(11) := l_indent||rpad(fmt_heading(substr(c1.c011,1,30),'N','11'),31,s)||rpad(get_column_datatype(p_collection_name,'C011',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c011,'','11')||g_fm||chr(10);
h(12) := l_indent||rpad(fmt_heading(substr(c1.c012,1,30),'N','12'),31,s)||rpad(get_column_datatype(p_collection_name,'C012',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c012,'','12')||g_fm||chr(10);
h(13) := l_indent||rpad(fmt_heading(substr(c1.c013,1,30),'N','13'),31,s)||rpad(get_column_datatype(p_collection_name,'C013',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c013,'','13')||g_fm||chr(10);
h(14) := l_indent||rpad(fmt_heading(substr(c1.c014,1,30),'N','14'),31,s)||rpad(get_column_datatype(p_collection_name,'C014',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c014,'','14')||g_fm||chr(10);
h(15) := l_indent||rpad(fmt_heading(substr(c1.c015,1,30),'N','15'),31,s)||rpad(get_column_datatype(p_collection_name,'C015',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c015,'','15')||g_fm||chr(10);
h(16) := l_indent||rpad(fmt_heading(substr(c1.c016,1,30),'N','16'),31,s)||rpad(get_column_datatype(p_collection_name,'C016',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c016,'','16')||g_fm||chr(10);
h(17) := l_indent||rpad(fmt_heading(substr(c1.c017,1,30),'N','17'),31,s)||rpad(get_column_datatype(p_collection_name,'C017',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c017,'','17')||g_fm||chr(10);
h(18) := l_indent||rpad(fmt_heading(substr(c1.c018,1,30),'N','18'),31,s)||rpad(get_column_datatype(p_collection_name,'C018',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c018,'','18')||g_fm||chr(10);
h(19) := l_indent||rpad(fmt_heading(substr(c1.c019,1,30),'N','19'),31,s)||rpad(get_column_datatype(p_collection_name,'C019',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c019,'','19')||g_fm||chr(10);
h(20) := l_indent||rpad(fmt_heading(substr(c1.c020,1,30),'N','20'),31,s)||rpad(get_column_datatype(p_collection_name,'C020',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c020,'','20')||g_fm||chr(10);
h(21) := l_indent||rpad(fmt_heading(substr(c1.c021,1,30),'N','21'),31,s)||rpad(get_column_datatype(p_collection_name,'C021',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c021,'','21')||g_fm||chr(10);
h(22) := l_indent||rpad(fmt_heading(substr(c1.c022,1,30),'N','22'),31,s)||rpad(get_column_datatype(p_collection_name,'C022',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c022,'','22')||g_fm||chr(10);
h(23) := l_indent||rpad(fmt_heading(substr(c1.c023,1,30),'N','23'),31,s)||rpad(get_column_datatype(p_collection_name,'C023',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c023,'','23')||g_fm||chr(10);
h(24) := l_indent||rpad(fmt_heading(substr(c1.c024,1,30),'N','24'),31,s)||rpad(get_column_datatype(p_collection_name,'C024',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c024,'','24')||g_fm||chr(10);
h(25) := l_indent||rpad(fmt_heading(substr(c1.c025,1,30),'N','25'),31,s)||rpad(get_column_datatype(p_collection_name,'C025',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c025,'','25')||g_fm||chr(10);
h(26) := l_indent||rpad(fmt_heading(substr(c1.c026,1,30),'N','26'),31,s)||rpad(get_column_datatype(p_collection_name,'C026',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c026,'','26')||g_fm||chr(10);
h(27) := l_indent||rpad(fmt_heading(substr(c1.c027,1,30),'N','27'),31,s)||rpad(get_column_datatype(p_collection_name,'C027',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c027,'','27')||g_fm||chr(10);
h(28) := l_indent||rpad(fmt_heading(substr(c1.c028,1,30),'N','28'),31,s)||rpad(get_column_datatype(p_collection_name,'C028',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c028,'','28')||g_fm||chr(10);
h(29) := l_indent||rpad(fmt_heading(substr(c1.c029,1,30),'N','29'),31,s)||rpad(get_column_datatype(p_collection_name,'C029',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c029,'','29')||g_fm||chr(10);
h(30) := l_indent||rpad(fmt_heading(substr(c1.c030,1,30),'N','30'),31,s)||rpad(get_column_datatype(p_collection_name,'C030',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c030,'','30')||g_fm||chr(10);
h(31) := l_indent||rpad(fmt_heading(substr(c1.c031,1,30),'N','31'),31,s)||rpad(get_column_datatype(p_collection_name,'C031',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c031,'','31')||g_fm||chr(10);
h(32) := l_indent||rpad(fmt_heading(substr(c1.c032,1,30),'N','32'),31,s)||rpad(get_column_datatype(p_collection_name,'C032',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c032,'','32')||g_fm||chr(10);
h(33) := l_indent||rpad(fmt_heading(substr(c1.c033,1,30),'N','33'),31,s)||rpad(get_column_datatype(p_collection_name,'C033',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c033,'','33')||g_fm||chr(10);
h(34) := l_indent||rpad(fmt_heading(substr(c1.c034,1,30),'N','34'),31,s)||rpad(get_column_datatype(p_collection_name,'C034',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c034,'','34')||g_fm||chr(10);
h(35) := l_indent||rpad(fmt_heading(substr(c1.c035,1,30),'N','35'),31,s)||rpad(get_column_datatype(p_collection_name,'C035',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c035,'','35')||g_fm||chr(10);
h(36) := l_indent||rpad(fmt_heading(substr(c1.c036,1,30),'N','36'),31,s)||rpad(get_column_datatype(p_collection_name,'C036',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c036,'','36')||g_fm||chr(10);
h(37) := l_indent||rpad(fmt_heading(substr(c1.c037,1,30),'N','37'),31,s)||rpad(get_column_datatype(p_collection_name,'C037',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c037,'','37')||g_fm||chr(10);
h(38) := l_indent||rpad(fmt_heading(substr(c1.c038,1,30),'N','38'),31,s)||rpad(get_column_datatype(p_collection_name,'C038',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c038,'','38')||g_fm||chr(10);
h(39) := l_indent||rpad(fmt_heading(substr(c1.c039,1,30),'N','39'),31,s)||rpad(get_column_datatype(p_collection_name,'C039',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c039,'','39')||g_fm||chr(10);
h(40) := l_indent||rpad(fmt_heading(substr(c1.c040,1,30),'N','40'),31,s)||rpad(get_column_datatype(p_collection_name,'C040',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c040,'','40')||g_fm||chr(10);
h(41) := l_indent||rpad(fmt_heading(substr(c1.c041,1,30),'N','41'),31,s)||rpad(get_column_datatype(p_collection_name,'C041',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c041,'','41')||g_fm||chr(10);
h(42) := l_indent||rpad(fmt_heading(substr(c1.c042,1,30),'N','42'),31,s)||rpad(get_column_datatype(p_collection_name,'C042',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c042,'','42')||g_fm||chr(10);
h(43) := l_indent||rpad(fmt_heading(substr(c1.c043,1,30),'N','43'),31,s)||rpad(get_column_datatype(p_collection_name,'C043',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c043,'','43')||g_fm||chr(10);
h(44) := l_indent||rpad(fmt_heading(substr(c1.c044,1,30),'N','44'),31,s)||rpad(get_column_datatype(p_collection_name,'C044',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c044,'','44')||g_fm||chr(10);
h(45) := l_indent||rpad(fmt_heading(substr(c1.c045,1,30),'N','45'),31,s)||rpad(get_column_datatype(p_collection_name,'C045',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c045,'','45')||g_fm||chr(10);
h(46) := l_indent||rpad(fmt_heading(substr(c1.c046,1,30),'N','46'),31,s)||rpad(get_column_datatype(p_collection_name,'C046',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c046,'','46')||g_fm||chr(10);
h(47) := l_indent||rpad(fmt_heading(substr(c1.c047,1,30),'N','47'),31,s)||rpad(get_column_datatype(p_collection_name,'C047',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c047,'','47')||g_fm||chr(10);
h(48) := l_indent||rpad(fmt_heading(substr(c1.c048,1,30),'N','48'),31,s)||rpad(get_column_datatype(p_collection_name,'C048',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c048,'','48')||g_fm||chr(10);
h(49) := l_indent||rpad(fmt_heading(substr(c1.c049,1,30),'N','49'),31,s)||rpad(get_column_datatype(p_collection_name,'C049',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c049,'','49')||g_fm||chr(10);
h(50) := l_indent||rpad(fmt_heading(substr(c1.c050,1,30),'N','50'),31,s)||rpad(get_column_datatype(p_collection_name,'C050',p_date_format_mask),10,s)||'@'||fmt_heading(c1.c050,'','50')||g_fm||chr(10);
end if;
if c1.c001 is not null then if l_col_count < 1 then l_col_count := 1 ; end if; end if;
if c1.c002 is not null then if l_col_count < 2 then l_col_count := 2 ; end if; end if;
if c1.c003 is not null then if l_col_count < 3 then l_col_count := 3 ; end if; end if;
if c1.c004 is not null then if l_col_count < 4 then l_col_count := 4 ; end if; end if;
if c1.c005 is not null then if l_col_count < 5 then l_col_count := 5 ; end if; end if;
if c1.c006 is not null then if l_col_count < 6 then l_col_count := 6 ; end if; end if;
if c1.c007 is not null then if l_col_count < 7 then l_col_count := 7 ; end if; end if;
if c1.c008 is not null then if l_col_count < 8 then l_col_count := 8 ; end if; end if;
if c1.c009 is not null then if l_col_count < 9 then l_col_count := 9 ; end if; end if;
if c1.c010 is not null then if l_col_count < 10 then l_col_count := 10; end if; end if;
if c1.c011 is not null then if l_col_count < 11 then l_col_count := 11; end if; end if;
if c1.c012 is not null then if l_col_count < 12 then l_col_count := 12; end if; end if;
if c1.c013 is not null then if l_col_count < 13 then l_col_count := 13; end if; end if;
if c1.c014 is not null then if l_col_count < 14 then l_col_count := 14; end if; end if;
if c1.c015 is not null then if l_col_count < 15 then l_col_count := 15; end if; end if;
if c1.c016 is not null then if l_col_count < 16 then l_col_count := 16; end if; end if;
if c1.c017 is not null then if l_col_count < 17 then l_col_count := 17; end if; end if;
if c1.c018 is not null then if l_col_count < 18 then l_col_count := 18; end if; end if;
if c1.c019 is not null then if l_col_count < 19 then l_col_count := 19; end if; end if;
if c1.c020 is not null then if l_col_count < 20 then l_col_count := 20; end if; end if;
if c1.c021 is not null then if l_col_count < 21 then l_col_count := 21; end if; end if;
if c1.c022 is not null then if l_col_count < 22 then l_col_count := 22; end if; end if;
if c1.c023 is not null then if l_col_count < 23 then l_col_count := 23; end if; end if;
if c1.c024 is not null then if l_col_count < 24 then l_col_count := 24; end if; end if;
if c1.c025 is not null then if l_col_count < 25 then l_col_count := 25; end if; end if;
if c1.c026 is not null then if l_col_count < 26 then l_col_count := 26; end if; end if;
if c1.c027 is not null then if l_col_count < 27 then l_col_count := 27; end if; end if;
if c1.c028 is not null then if l_col_count < 28 then l_col_count := 28; end if; end if;
if c1.c029 is not null then if l_col_count < 29 then l_col_count := 29; end if; end if;
if c1.c030 is not null then if l_col_count < 30 then l_col_count := 30; end if; end if;
if c1.c031 is not null then if l_col_count < 31 then l_col_count := 31; end if; end if;
if c1.c032 is not null then if l_col_count < 32 then l_col_count := 32; end if; end if;
if c1.c033 is not null then if l_col_count < 33 then l_col_count := 33; end if; end if;
if c1.c034 is not null then if l_col_count < 34 then l_col_count := 34; end if; end if;
if c1.c035 is not null then if l_col_count < 35 then l_col_count := 35; end if; end if;
if c1.c036 is not null then if l_col_count < 36 then l_col_count := 36; end if; end if;
if c1.c037 is not null then if l_col_count < 37 then l_col_count := 37; end if; end if;
if c1.c038 is not null then if l_col_count < 38 then l_col_count := 38; end if; end if;
if c1.c039 is not null then if l_col_count < 39 then l_col_count := 39; end if; end if;
if c1.c040 is not null then if l_col_count < 40 then l_col_count := 40; end if; end if;
if c1.c041 is not null then if l_col_count < 41 then l_col_count := 41; end if; end if;
if c1.c042 is not null then if l_col_count < 42 then l_col_count := 42; end if; end if;
if c1.c043 is not null then if l_col_count < 43 then l_col_count := 43; end if; end if;
if c1.c044 is not null then if l_col_count < 44 then l_col_count := 44; end if; end if;
if c1.c045 is not null then if l_col_count < 45 then l_col_count := 45; end if; end if;
if c1.c046 is not null then if l_col_count < 46 then l_col_count := 46; end if; end if;
if c1.c047 is not null then if l_col_count < 47 then l_col_count := 47; end if; end if;
if c1.c048 is not null then if l_col_count < 48 then l_col_count := 48; end if; end if;
if c1.c049 is not null then if l_col_count < 49 then l_col_count := 49; end if; end if;
if c1.c050 is not null then if l_col_count < 50 then l_col_count := 50; end if; end if;
end loop;
--if NVL(p_first_row_is_header_yn,'N') = 'N' then
-- for i in 1..l_col_count loop
-- if h(i) is null then
-- h(i) := l_indent||trim(substr(l_col_names,(i * 2) + 1,2))||chr(10);
-- end if;
-- end loop;
--end if;
for i in 1..l_col_count loop
x := x||h(i);
end loop;
return x;
end get_worksheet_structure;
procedure load_worksheet_data (
p_n001 in number default null,
p_object_type in varchar2 default null,
p_object_name in varchar2 default null,
p_worksheet in varchar2 default null,
p_format_mask in varchar2 default null)
is
x varchar2(32767) := null;
l_indent varchar2(30) := ' ';
l_exclude varchar2(4000) := '|CREATED|UPDATED|CREATED_BY|UPDATED_BY|ROW_KEY|SECURITY_GROUP_ID|ROW_VERSION|';
l_value varchar2(32767);
l_ws_col APEX_APPLICATION_GLOBAL.VC_ARR2;
l_format_mask varchar2(255) := null;
l_num_headings integer := 0;
begin
l_format_mask := p_format_mask;
for i in 1..50 loop l_ws_col(i) := null; end loop;
-- grab column headings
for c1 in (select * from apex_collections where collection_name = p_worksheet and seq_id = 1) loop
if c1.c001 is not null then l_ws_col( 1) := fmt_heading(c1.c001); end if;
if c1.c002 is not null then l_ws_col( 2) := fmt_heading(c1.c002); end if;
if c1.c003 is not null then l_ws_col( 3) := fmt_heading(c1.c003); end if;
if c1.c004 is not null then l_ws_col( 4) := fmt_heading(c1.c004); end if;
if c1.c005 is not null then l_ws_col( 5) := fmt_heading(c1.c005); end if;
if c1.c006 is not null then l_ws_col( 6) := fmt_heading(c1.c006); end if;
if c1.c007 is not null then l_ws_col( 7) := fmt_heading(c1.c007); end if;
if c1.c008 is not null then l_ws_col( 8) := fmt_heading(c1.c008); end if;
if c1.c009 is not null then l_ws_col( 9) := fmt_heading(c1.c009); end if;
if c1.c010 is not null then l_ws_col(10) := fmt_heading(c1.c010); end if;
if c1.c011 is not null then l_ws_col(11) := fmt_heading(c1.c011); end if;
if c1.c012 is not null then l_ws_col(12) := fmt_heading(c1.c012); end if;
if c1.c013 is not null then l_ws_col(13) := fmt_heading(c1.c013); end if;
if c1.c014 is not null then l_ws_col(14) := fmt_heading(c1.c014); end if;
if c1.c015 is not null then l_ws_col(15) := fmt_heading(c1.c015); end if;
if c1.c016 is not null then l_ws_col(16) := fmt_heading(c1.c016); end if;
if c1.c017 is not null then l_ws_col(17) := fmt_heading(c1.c017); end if;
if c1.c018 is not null then l_ws_col(18) := fmt_heading(c1.c018); end if;
if c1.c019 is not null then l_ws_col(19) := fmt_heading(c1.c019); end if;
if c1.c020 is not null then l_ws_col(20) := fmt_heading(c1.c020); end if;
if c1.c021 is not null then l_ws_col(21) := fmt_heading(c1.c021); end if;
if c1.c022 is not null then l_ws_col(22) := fmt_heading(c1.c022); end if;
if c1.c023 is not null then l_ws_col(23) := fmt_heading(c1.c023); end if;
if c1.c024 is not null then l_ws_col(24) := fmt_heading(c1.c024); end if;
if c1.c025 is not null then l_ws_col(25) := fmt_heading(c1.c025); end if;
if c1.c026 is not null then l_ws_col(26) := fmt_heading(c1.c026); end if;
if c1.c027 is not null then l_ws_col(27) := fmt_heading(c1.c027); end if;
if c1.c028 is not null then l_ws_col(28) := fmt_heading(c1.c028); end if;
if c1.c029 is not null then l_ws_col(29) := fmt_heading(c1.c029); end if;
if c1.c030 is not null then l_ws_col(30) := fmt_heading(c1.c030); end if;
if c1.c031 is not null then l_ws_col(31) := fmt_heading(c1.c031); end if;
if c1.c032 is not null then l_ws_col(32) := fmt_heading(c1.c032); end if;
if c1.c033 is not null then l_ws_col(33) := fmt_heading(c1.c033); end if;
if c1.c034 is not null then l_ws_col(34) := fmt_heading(c1.c034); end if;
if c1.c035 is not null then l_ws_col(35) := fmt_heading(c1.c035); end if;
if c1.c036 is not null then l_ws_col(36) := fmt_heading(c1.c036); end if;
if c1.c037 is not null then l_ws_col(37) := fmt_heading(c1.c037); end if;
if c1.c038 is not null then l_ws_col(38) := fmt_heading(c1.c038); end if;
if c1.c039 is not null then l_ws_col(39) := fmt_heading(c1.c039); end if;
if c1.c040 is not null then l_ws_col(40) := fmt_heading(c1.c040); end if;
if c1.c041 is not null then l_ws_col(41) := fmt_heading(c1.c041); end if;
if c1.c042 is not null then l_ws_col(42) := fmt_heading(c1.c042); end if;
if c1.c043 is not null then l_ws_col(43) := fmt_heading(c1.c043); end if;
if c1.c044 is not null then l_ws_col(44) := fmt_heading(c1.c044); end if;
if c1.c045 is not null then l_ws_col(45) := fmt_heading(c1.c045); end if;
if c1.c046 is not null then l_ws_col(46) := fmt_heading(c1.c046); end if;
if c1.c047 is not null then l_ws_col(47) := fmt_heading(c1.c047); end if;
if c1.c048 is not null then l_ws_col(48) := fmt_heading(c1.c048); end if;
if c1.c049 is not null then l_ws_col(49) := fmt_heading(c1.c049); end if;
if c1.c050 is not null then l_ws_col(50) := fmt_heading(c1.c050); end if;
end loop;
-- deal with null column headings
for j in 1..l_ws_col.count loop
if l_ws_col(j) is not null then
l_num_headings := j;
end if;
end loop;
for j in 1..l_num_headings loop
if l_ws_col(j) is null then
l_ws_col(j) := 'COL_'||lpad(j,2,'00');
APEX_COLLECTION.UPDATE_MEMBER_ATTRIBUTE (
p_collection_name => p_worksheet,
p_seq => '1',
p_attr_number => j,
p_attr_value => l_ws_col(j));
commit;
end if;
end loop;
-- loop over collection where data is stored
for c1 in (select * from apex_collections where collection_name = p_worksheet and seq_id > 1 order by seq_id) loop
x := 'insert into '||p_object_name||' ('||chr(10);
for c2 in (
select
c002 column_name,
c003 data_type,
n003 column_id,
c018 worksheet_column
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.n001 = p_n001 and
NVL(instr(l_exclude,'|'||c002||'|'),0) = 0
order by seq_id
) loop
x := x||l_indent||c2.column_name||','||chr(10);
end loop;
x := rtrim(x,','||chr(10))||chr(10);
x := x||') values ('||chr(10);
for c2 in (
select
upper(c.c001) table_name,
c.c002 column_name,
c.c003 data_type,
c.c004 not_null_yn,
c.n003 column_id,
c.c017 valid_values,
c.c007 FK_TABLE,
NVL(c.c006,'N') is_pk,
c.c013 between_clause,
NVL(c.c018,'WSC_IS_NULL') worksheet_column,
c.c020 format_mask
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.n001 = p_n001 and
NVL(instr(l_exclude,'|'||c.c002||'|'),0) = 0
order by seq_id
) loop
l_value := null;
if c2.format_mask is not null then
l_format_mask := c2.format_mask;
else
l_format_mask := p_format_mask;
end if;
if c2.worksheet_column = l_ws_col(1 ) then l_value := c1.c001;
elsif c2.worksheet_column = l_ws_col(2 ) then l_value := c1.c002;
elsif c2.worksheet_column = l_ws_col(3 ) then l_value := c1.c003;
elsif c2.worksheet_column = l_ws_col(4 ) then l_value := c1.c004;
elsif c2.worksheet_column = l_ws_col(5 ) then l_value := c1.c005;
elsif c2.worksheet_column = l_ws_col(6 ) then l_value := c1.c006;
elsif c2.worksheet_column = l_ws_col(7 ) then l_value := c1.c007;
elsif c2.worksheet_column = l_ws_col(8 ) then l_value := c1.c008;
elsif c2.worksheet_column = l_ws_col(9 ) then l_value := c1.c009;
elsif c2.worksheet_column = l_ws_col(10) then l_value := c1.c010;
elsif c2.worksheet_column = l_ws_col(11) then l_value := c1.c011;
elsif c2.worksheet_column = l_ws_col(12) then l_value := c1.c012;
elsif c2.worksheet_column = l_ws_col(13) then l_value := c1.c013;
elsif c2.worksheet_column = l_ws_col(14) then l_value := c1.c014;
elsif c2.worksheet_column = l_ws_col(15) then l_value := c1.c015;
elsif c2.worksheet_column = l_ws_col(16) then l_value := c1.c016;
elsif c2.worksheet_column = l_ws_col(17) then l_value := c1.c017;
elsif c2.worksheet_column = l_ws_col(18) then l_value := c1.c018;
elsif c2.worksheet_column = l_ws_col(19) then l_value := c1.c019;
elsif c2.worksheet_column = l_ws_col(20) then l_value := c1.c020;
elsif c2.worksheet_column = l_ws_col(21) then l_value := c1.c021;
elsif c2.worksheet_column = l_ws_col(22) then l_value := c1.c022;
elsif c2.worksheet_column = l_ws_col(23) then l_value := c1.c023;
elsif c2.worksheet_column = l_ws_col(24) then l_value := c1.c024;
elsif c2.worksheet_column = l_ws_col(25) then l_value := c1.c025;
elsif c2.worksheet_column = l_ws_col(26) then l_value := c1.c026;
elsif c2.worksheet_column = l_ws_col(27) then l_value := c1.c027;
elsif c2.worksheet_column = l_ws_col(28) then l_value := c1.c028;
elsif c2.worksheet_column = l_ws_col(29) then l_value := c1.c029;
elsif c2.worksheet_column = l_ws_col(30) then l_value := c1.c030;
elsif c2.worksheet_column = l_ws_col(31) then l_value := c1.c031;
elsif c2.worksheet_column = l_ws_col(32) then l_value := c1.c032;
elsif c2.worksheet_column = l_ws_col(33) then l_value := c1.c033;
elsif c2.worksheet_column = l_ws_col(34) then l_value := c1.c034;
elsif c2.worksheet_column = l_ws_col(35) then l_value := c1.c035;
elsif c2.worksheet_column = l_ws_col(36) then l_value := c1.c036;
elsif c2.worksheet_column = l_ws_col(37) then l_value := c1.c037;
elsif c2.worksheet_column = l_ws_col(38) then l_value := c1.c038;
elsif c2.worksheet_column = l_ws_col(39) then l_value := c1.c039;
elsif c2.worksheet_column = l_ws_col(40) then l_value := c1.c040;
elsif c2.worksheet_column = l_ws_col(41) then l_value := c1.c041;
elsif c2.worksheet_column = l_ws_col(42) then l_value := c1.c042;
elsif c2.worksheet_column = l_ws_col(43) then l_value := c1.c043;
elsif c2.worksheet_column = l_ws_col(44) then l_value := c1.c044;
elsif c2.worksheet_column = l_ws_col(45) then l_value := c1.c045;
elsif c2.worksheet_column = l_ws_col(46) then l_value := c1.c046;
elsif c2.worksheet_column = l_ws_col(47) then l_value := c1.c047;
elsif c2.worksheet_column = l_ws_col(48) then l_value := c1.c048;
elsif c2.worksheet_column = l_ws_col(49) then l_value := c1.c049;
elsif c2.worksheet_column = l_ws_col(50) then l_value := c1.c050;
end if;
if l_value is null then
l_value := 'null';
elsif c2.data_type like 'NUMBER%' or c2.data_type like 'INT%' then
l_value := replace(l_value,g_nls_pct,null); -- for numeric columns remove percent symbol
l_value := replace(replace(l_value,g_nls_usd,null),g_nls_euro,null); -- remove NLS currency indicator
l_value := replace(replace(l_value,g_nls_pound,null),g_nls_yen,null); -- remove NLS currency indicator
if instr(l_value,'.') > 0 and instr(l_value,',') > 0 and instr(l_value,',') > instr(l_value,'.') then
l_value := replace(replace(l_value,'.',null),',','.');
end if;
l_value := rtrim(l_value,g_nls_decimal); -- NLS decimal
l_value := replace(l_value,g_nls_units); -- NLS units
elsif c2.data_type like 'DATE' then
l_value := 'to_date('''||l_value||''','''||l_format_mask||''')';
elsif c2.data_type like 'TIMESTAMP' then
l_value := 'to_timestamp('''||l_value||''','''||l_format_mask||''')';
elsif c2.data_type in ('TIMESTAMP WITH TIME ZONE','TIMESTAMP WITH LOCAL TIME ZONE') then
l_value := 'to_timestamp_tz('''||l_value||''','''||l_format_mask||''')';
else
-- value is a character so quote it
l_value := replace(trim(l_value),'''','''''');
l_value := ''''||trim(l_value)||'''';
end if;
x := x||l_indent||l_value||','||chr(10);
end loop; -- c2 columns loop
x := rtrim(x,','||chr(10))||');'||chr(10);
printl (x);
end loop; -- c1 data loop
end load_worksheet_data;
function get_between_low_range (
p_clause in varchar2 default null)
return number
is
l_low_value number;
begin
begin
l_low_value := to_number(trim(substr(p_clause,1,instr(p_clause,'and')-1)));
exception when others then
l_low_value := 1;
end;
return l_low_value;
end get_between_low_range;
function get_between_high_range (
p_clause in varchar2 default null)
return number
is
l_high_value number;
begin
begin
l_high_value := to_number(trim(substr(p_clause,instr(p_clause,'and')+4)));
exception when others then
l_high_value := 1;
end;
return l_high_value;
end get_between_high_range;
procedure save_inserted_primary_keys (
p_table_name in varchar2 default null,
p_primary_key in varchar2 default null,
p_iteration in number default null)
is
begin
begin
if not APEX_COLLECTION.COLLECTION_EXISTS('PRIMARY_KEYS') then
APEX_COLLECTION.CREATE_COLLECTION(p_collection_name => 'PRIMARY_KEYS');
end if;
exception when others then
log_status (p_status=>'Unexpected error attempting to create primary_keys collection', p_context => 'save_inserted_primary_keys',p_sqlerrm=>sqlerrm);
end;
APEX_COLLECTION.ADD_MEMBER (
p_collection_name => 'PRIMARY_KEYS',
p_c001 => p_table_name,
p_c002 => p_primary_key,
p_n001 => p_iteration);
end save_inserted_primary_keys;
function get_valid_foreign_key (p_table_name in varchar2 default null) return number
is
r number := 1; -- foreign key value to return
c number := 0; -- count of rows already generated for parent table primary key
x integer := 0; -- random row of primary keys collection
begin
for c1 in (select count(*) c from apex_collections where collection_name = 'PRIMARY_KEYS' and c001 = p_table_name) loop
c := c1.c;
end loop;
if c > 0 then
c := c + .9999999999999;
x := trunc(DBMS_RANDOM.value(low => 1, high => c));
for c1 in (select c002 from apex_collections where collection_name = 'PRIMARY_KEYS' and c001 = p_table_name and n001 = x) loop
r := to_number(c1.c002);
end loop;
end if;
return r;
end get_valid_foreign_key;
function get_singular (p_str in varchar2 default null) return varchar2
is
x varchar2(4000) := null;
begin
x := trim(p_str);
if upper(x) like '%IES' and length(x) > 5 then
x := substr(x,1,length(x) - 3)||'Y';
elsif upper(x) like '%S' and length(x) > 3 and upper(x) not like '%SS' then
x := rtrim(upper(x),'S');
end if;
return x;
end get_singular;
function remove_prefix (p_name in varchar2 default null, p_prefix in varchar2 default null) return varchar2
is
l_prefix varchar2(255);
begin
l_prefix := rtrim(upper(NVL(p_prefix,g_prefix)),'_');
if l_prefix is null then
return p_name;
else
l_prefix := l_prefix ||'_';
if substr(upper(P_NAME),1,length(l_prefix)) = l_prefix then
return substr(p_name,length(l_prefix)+1);
else
return p_name;
end if;
end if;
end remove_prefix;
procedure create_view (p_view in varchar2 default null)
is
l_view varchar2(32767) := null;
l_view_name varchar2(32767) := null;
i integer := 0;
l_from varchar2(32767) := null;
l_where varchar2(32767) := null;
l_name_arr APEX_APPLICATION_GLOBAL.VC_ARR2; -- table names
l_columns varchar2(32767) := null;
l_column varchar2(255);
x varchar2(255);
c integer;
l_tnames varchar2(32767) := '|';
--
function is_fk (p_col_name in varchar2 default null, p_tab_names in varchar2 default null)
return boolean
is
c number := 0;
begin
-- count column name occurrences for all tables in view
for c1 in (
select count(*) c
from apex_collections
where collection_name = 'SCHEMA_TAB_COLS' and
instr(p_tab_names,'|'||c001||'|') > 0 and
instr(p_tab_names,'|'||c007||'|') > 0 and
c002 = p_col_name
) loop
c := c1.c;
end loop;
if c = 0 then
return false;
else
return true;
end if;
end is_fk;
--
function get_column_count (p_col_name in varchar2 default null, p_tab_names in varchar2 default null)
return number
is
c number := 0;
begin
-- count column name occurrences for all tables in view
for c1 in (
select count(*) c
from apex_collections
where collection_name = 'SCHEMA_TAB_COLS' and
instr(p_tab_names,'|'||c001||'|') > 0 and
upper(c002) = upper(p_col_name)
) loop
c := c1.c;
end loop;
return c;
end get_column_count;
begin
g_prefix := upper(g_prefix);
l_view := trim(substr(replace(upper(p_view),chr(9),' '),6));
i := instr(l_view,' ');
if i = 0 then return; end if;
-- get view name
l_view_name := substr(l_view,1,i-1);
l_view := substr(l_view,i+1);
-- get view tables into an array
for i in 1..30 loop l_view := replace(l_view,' ',' '); end loop;
l_view := trim(l_view);
l_view := rtrim(l_view,chr(10));
l_view := replace(l_view,' ',':');
l_name_arr := APEX_UTIL.STRING_TO_TABLE(l_view);
for i in 1..l_name_arr.count loop
if g_prefix is null then
l_name_arr(i) := clean_name(l_name_arr(i));
else
l_name_arr(i) := clean_name(g_prefix||'_'||l_name_arr(i));
end if;
end loop;
-- get list of tables for use in collection queries
for i in 1..l_name_arr.count loop
l_tnames := l_tnames||l_name_arr(i)||'|';
end loop;
-- from clause
for i in 1..l_name_arr.count loop
if g_prefix is not null then
l_from := l_from||' '||lower(g_schema||l_name_arr(i))||' '||lower(remove_prefix(l_name_arr(i)))||','||chr(10);
else
l_from := l_from||' '||lower(g_schema||l_name_arr(i))||','||chr(10);
end if;
end loop;
l_from := rtrim(l_from,','||chr(10));
---------------------
-- view where clause
--
for c1 in (
select c001 tname,
c002 cname,
nvl(c015,c007) fk,
(select max(c003) from apex_collections where collection_name = 'SCHEMA' and c001 = x.c001) pk
from apex_collections x
where collection_name = 'SCHEMA_TAB_COLS' and
instr(l_tnames,'|'||c001||'|') > 0 and
instr(l_tnames,'|'||nvl(c015,c007)||'|') > 0
) loop
-- determine join
if c1.tname is not null and c1.cname is not null and c1.fk is not null and c1.pk is not null then
--
l_where := l_where||' '||lower(remove_prefix(c1.tname)||'.');
if upper(c1.cname) = 'ID' and upper(nvl(g_prefix_pk_with_tname,'N')) = 'Y' then
l_where := lower(substr(get_singular(c1.tname),1,27)||'_id');
else
l_where := l_where||lower(c1.cname);
end if;
-- use outer join
l_where := l_where||'(+)';
l_where := l_where||' = ';
--
-- join to referenced table
--
l_where := l_where||lower(remove_prefix(c1.fk)||'.');
if upper(nvl(g_prefix_pk_with_tname,'N')) = 'Y' then
-- c1.fk = the foreign key table name
l_where := l_where||lower(substr(get_singular(c1.fk),1,27)||'_id');
else
l_where := l_where||lower(c1.pk);
end if;
l_where := l_where||' &'||chr(10);
end if;
end loop;
l_where := rtrim(l_where,' &'||chr(10));
l_where := replace(l_where,'&','and');
--------------------
-- view select list
--
if g_prefix is not null then l_view_name := clean_name(g_prefix||'_'||l_view_name); end if;
printl('create or replace view '||lower(g_schema||l_view_name)||' as ');
printl('select ');
for i in 1..l_name_arr.count loop
for c1 in (
select c002 cname,
c003 data_type,
n003 column_id,
NVL(c006,'N') is_pk
from apex_collections
where collection_name = 'SCHEMA_TAB_COLS' and
c001 = l_name_arr(i)
) loop
-- determine table.column name to select
x := remove_prefix(l_name_arr(i))||'.'; -- table dot
if upper(c1.is_Pk) = 'Y' and upper(c1.cname) = 'ID' and upper(nvl(g_prefix_pk_with_tname,'N')) = 'Y' then
-- column name of primary key column
x := x|| lower(substr(get_singular(l_name_arr(i)),1,27)||'_id');
elsif upper(c1.cname) = 'CREATED' and upper(nvl(g_created_column_name,'CREATED')) != 'CREATED' then
x := x||lower(trim(g_created_column_name));
elsif upper(c1.cname) = 'CREATED_BY' and upper(nvl(g_created_column_name,'CREATED_BY')) != 'CREATED_BY' then
x := x||lower(trim(g_created_by_column_name));
elsif upper(c1.cname) = 'UPDATED' and upper(nvl(g_created_column_name,'UPDATED')) != 'UPDATED' then
x := x||lower(trim(g_updated_column_name));
elsif upper(c1.cname) = 'UPDATED_BY' and upper(nvl(g_created_column_name,'UPDATED_BY')) != 'UPDATED_BY' then
x := x||lower(trim(g_updated_by_column_name));
else
-- column name on non primary key column and is not another generated column that is renamed
x := x||clean_name(c1.cname);
end if;
if is_fk (clean_name(c1.cname),l_tnames) then
null;
else
c := get_column_count(clean_name(c1.cname),l_tnames);
if c = 1 then
-- column name is unique over all tables
l_column := clean_name(c1.cname);
else
-- column name is ambigious so prefix with table_name
l_column := get_singular(remove_prefix(l_name_arr(i)))||'_'||clean_name(c1.cname); -- mike risk of too long identifier
end if;
l_columns := l_columns||' '||rpad(lower(x),51,' ')||lower(l_column)||','||chr(10);
end if;
end loop;
end loop;
printl(rtrim(l_columns,','||chr(10)));
printl('from ');
printl(l_from);
if l_name_arr.count > 1 then
printl('where');
printl(l_where);
end if;
printl('/');
printl('');
end create_view;
function remove_pound_directives (p_text in varchar2 default null)
return varchar2
is
l_text varchar2(32767) := null;
l_first varchar2(32767) := null;
c integer := null;
h integer := 0; -- location of hash starting on new line
e integer := 0; -- end of hash line
begin
-- clean up
l_text := trim(replace(p_text,chr(13),null));
for i in 1..20 loop l_text := rtrim(l_text,' '||chr(10)); end loop;
l_text := l_text||chr(10);
-- find new line starting with pound
h := instr(l_text,chr(10)||'#');
if h < 2 then
return l_text;
else
l_first := substr(l_text,1,h-1);
l_text := substr(l_text,h);
l_text := ltrim(l_text,chr(10));
e := instr(l_text,chr(10));
if e = 0 then
l_text := null;
elsif e > 1 then
l_text := substr(l_text,e+1);
end if;
return l_first||l_text;
end if;
end remove_pound_directives;
procedure get_default_settings (
p_TABLE_PREFIX out varchar2,
p_ON_DELETE out varchar2,
p_COMPRESSED out varchar2,
p_PRIMARY_KEY out varchar2,
p_TRIGGER_METHOD out varchar2,
p_DATE_DATATYPE out varchar2,
p_API out varchar2,
p_AUDIT_COLS out varchar2,
p_ROW_KEY out varchar2,
p_SGID out varchar2,
p_ROW_VERSION out varchar2,
p_DB_VERSION out varchar2,
p_INCLUDE_DROPS out varchar2,
p_LONGER_IDENTIFIERS out varchar2,
p_HISTORY_TABLES out varchar2,
p_AUTO_GEN_PK out varchar2,
p_EDITIONABLE out varchar2,
p_language out varchar2,
p_APEX out varchar2,
--
p_prefix_pk_with_tname out varchar2, --mike
p_created_column_name out varchar2,
p_created_by_column_name out varchar2,
p_updated_column_name out varchar2,
p_updated_by_column_name out varchar2,
--
p_audit out varchar2,
P_longer_varchars_yn out varchar2,
p_verbose_yn out varchar2,
p_schema out varchar2,
p_inserts out number,
p_selects out varchar2,
p_uncomment out varchar2,
p_tags_fw out varchar2,
p_semantics out varchar2
)
is
begin
p_TABLE_PREFIX := null;
p_ON_DELETE := 'CASCADE';
p_COMPRESSED := 'N';
p_PRIMARY_KEY := 'ID';
p_TRIGGER_METHOD := 'TRIG';
p_DATE_DATATYPE := 'DATE';
p_API := 'N';
p_AUDIT_COLS := 'N';
p_ROW_KEY := 'N';
p_SGID := 'N';
p_ROW_VERSION := 'N';
p_DB_VERSION := '12c';
p_INCLUDE_DROPS := 'N';
p_LONGER_IDENTIFIERS := 'N';
p_HISTORY_TABLES := 'N';
p_AUTO_GEN_PK := 'Y';
p_EDITIONABLE := 'N';
p_APEX := 'N';
p_audit := 'N';
p_longer_varchars_yn := 'N';
p_verbose_yn := 'N';
p_schema := null;
p_inserts := 0;
p_selects := 'N';
p_uncomment := 'Y';
p_tags_fw := 'N';
p_semantics := 'DEFAULT';
p_prefix_pk_with_tname := 'N';
p_created_column_name := 'created';
p_created_by_column_name := 'created_by';
p_updated_column_name := 'updated';
p_updated_by_column_name := 'updated_by';
end get_default_settings;
function is_default_setting (
p_setting in varchar2 default null)
return boolean
is
begin
if nvl(upper(p_setting),'%null%') = 'TABLE_PREFIX' then if g_prefix is null then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'SCHEMA' then if g_schema is null then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'ON_DELETE' then if nvl(g_ON_DELETE,'%null%') = 'CASCADE' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'COMPRESSED' then if nvl(g_COMPRESSED,'%null%') ='N' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'TRIGGER_METHOD' then if nvl(g_TRIGGER_METHOD,'%null%') ='IDENTITY' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'DATE_DATATYPE' then if nvl(g_DATE_DATATYPE,'%null%') ='DATE' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'API' then if nvl(g_api,'%null%') ='N' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'AUDIT_COLS' then if nvl(g_AUDIT_COLS,'%null%') ='N' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'ROW_KEY' then if nvl(g_ROW_KEY,'%null%') ='N' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'SGID' then if nvl(g_SGID,'%null%') ='N' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'ROW_VERSION' then if nvl(g_ROW_VERSION,'%null%') ='N' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'DB_VERSION' then if nvl(g_DB_VERSION,'%null%') ='12c' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'INCLUDE_DROPS' then if nvl(g_INCLUDE_DROPS,'%null%') ='N' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'LONGER_IDENTIFIERS' then if nvl(g_LONGER_IDENTIFIERS,'%null%') ='N' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'LONGER_VARCHARS' then if nvl(g_LONGER_VARCHARS_YN,'%null%') ='N' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'HISTORY_TABLES' then if nvl(g_HISTORY_TABLES,'%null%') ='N' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'AUTO_GEN_PK' then if nvl(g_AUTO_GEN_PK,'%null%') ='Y' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'EDITIONABLE' then if nvl(g_editionable,'%null%') ='N' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'APEX' then if nvl(g_apex,'%null%') ='N' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'VERBOSE' then if nvl(g_verbose_yn,'%null%') ='N' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'AUDIT' then if nvl(g_audit,'%null%') ='N' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'INSERTS' then if nvl(g_inserts,0) = 0 then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'SELECTS' then if nvl(g_selects,'%null%') ='N' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'UNCOMMENT' then if nvl(g_uncomment,'%null%') ='Y' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'TAGS_FW' then if nvl(g_tags_fw,'%null%') ='N' then return true; else return false; end if; end if;
-- mike
if nvl(upper(p_setting),'%null%') = 'PREFIX_PK_WITH_TNAME' then if nvl(g_prefix_pk_with_tname,'%null%') ='N' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'CREATED_COLUMN_NAME' then if nvl(g_created_column_name,'%null%') ='created' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'CREATED_BY_COLUMN_NAME' then if nvl(g_created_by_column_name,'%null%') ='created_by' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'UPDATED_COLUMN_NAME' then if nvl(g_updated_column_name,'%null%') ='updated' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'UPDATED_BY_COLUMN_NAME' then if nvl(g_updated_by_column_name,'%null%') ='updated_by' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'SEMANTICS' then if nvl(g_semantics,'%null%') ='DEFAULT' then return true; else return false; end if; end if;
if nvl(upper(p_setting),'%null%') = 'LANGUAGE' then if nvl(g_semantics,'%null%') ='EN' then return true; else return false; end if; end if;
return false;
end is_default_setting;
function get_settings return varchar2
is
begin
return
'# Prefix = "'||g_prefix ||'"'||chr(10)||
'# Schema = "'||g_schema ||'"'||chr(10)||
'# OnDelete = "'||g_ON_DELETE ||'"'||chr(10)||
'# Compressed = "'||g_COMPRESSED ||'"'||chr(10)||
'# PK = "'||g_TRIGGER_METHOD ||'"'||chr(10)||
'# DATE = "'||g_DATE_DATATYPE ||'"'||chr(10)||
'# SEMANTICS = "'||g_semantics ||'"'||chr(10)||
'# API = "'||g_api ||'"'||chr(10)||
'# AuditCols = "'||g_AUDIT_COLS ||'"'||chr(10)||
'# RowKey = "'||g_ROW_KEY ||'"'||chr(10)||
'# SecurityGroupID = "'||g_SGID ||'"'||chr(10)||
'# RowVersion = "'||g_ROW_VERSION ||'"'||chr(10)||
'# DB = "'||g_DB_VERSION ||'"'||chr(10)||
'# Drop = "'||g_INCLUDE_DROPS ||'"'||chr(10)||
'# LongId = "'||g_LONGER_IDENTIFIERS||'"'||chr(10)||
'# LongVC = "'||g_LONGER_VARCHARS_YN||'"'||chr(10)||
'# Hist = "'||g_HISTORY_TABLES ||'"'||chr(10)||
'# GenPK = "'||g_AUTO_GEN_PK ||'"'||chr(10)||
'# Editionable = "'||g_editionable ||'"'||chr(10)||
'# APEX = "'||g_apex ||'"'||chr(10)||
'# INSERTS = "'||g_inserts ||'"'||chr(10)||
'# SELECTS = "'||g_selects ||'"'||chr(10)||
'# UNCOMMENT = "'||g_uncomment ||'"'||chr(10)||
'# TAGS = "'||g_tags_fw ||'"'||chr(10)||
'# PREFIXPKWITHTNAME = "'||g_prefix_pk_with_tname ||'"'||chr(10)||
'# CREATEDCOL = "'||g_created_column_name ||'"'||chr(10)||
'# CREATEDBYCOL = "'||g_created_by_column_name ||'"'||chr(10)||
'# UPDATEDCOL = "'||g_updated_column_name ||'"'||chr(10)||
'# UPDATEDBYCOL = "'||g_updated_by_column_name ||'"'||chr(10)||
'# VERBOSE = "'||g_verbose_yn ||'"';
-- mike more here
end get_settings;
function get_settings_dela_from_def (p_all_yn in varchar2 default 'N') return varchar2
is
l_delta varchar2(4000) := null;
l_term varchar2(30) := null;
l_start varchar2(30) := null;
l_all_yn varchar2(1) := nvl(upper(substr(p_all_yn,1,1)),'N');
begin
l_term := ', ';
l_start := '';
if not is_default_setting('TABLE_PREFIX' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'prefix="'||g_prefix ||'"'||l_term; end if;
if not is_default_setting('SCHEMA' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'schema="'||rtrim(g_schema,'.') ||'"'||l_term; end if;
if not is_default_setting('ON_DELETE' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'onDelete="'||g_ON_DELETE ||'"'||l_term; end if;
if not is_default_setting('COMPRESSED' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'compressed="'||g_COMPRESSED ||'"'||l_term; end if;
if not is_default_setting('TRIGGER_METHOD' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'PK="'||g_TRIGGER_METHOD ||'"'||l_term; end if;
if not is_default_setting('DATE_DATATYPE' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'date="'||g_DATE_DATATYPE ||'"'||l_term; end if;
if not is_default_setting('SEMANTICS' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'semantics="'||g_SEMANTICS ||'"'||l_term; end if;
if not is_default_setting('API' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'API="'||g_api ||'"'||l_term; end if;
if not is_default_setting('AUDIT_COLS' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'auditCols="'||g_AUDIT_COLS ||'"'||l_term; end if;
if not is_default_setting('ROW_KEY' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'rowKey="'||g_ROW_KEY ||'"'||l_term; end if;
if not is_default_setting('SGID' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'SecurityGroupID="'||g_SGID ||'"'||l_term; end if;
if not is_default_setting('ROW_VERSION' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'rowVersion="'||g_ROW_VERSION ||'"'||l_term; end if;
if not is_default_setting('DB_VERSION' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'DB="'||g_DB_VERSION ||'"'||l_term; end if;
if not is_default_setting('INCLUDE_DROPS' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'drop="'||g_INCLUDE_DROPS ||'"'||l_term; end if;
if not is_default_setting('LONGER_IDENTIFIERS' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'longId="'||g_LONGER_IDENTIFIERS||'"'||l_term; end if;
if not is_default_setting('LONGER_VARCHARS' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'longVC="'||g_longer_varchars_yn||'"'||l_term; end if;
if not is_default_setting('HISTORY_TABLES' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'hist="'||g_HISTORY_TABLES ||'"'||l_term; end if;
if not is_default_setting('AUTO_GEN_PK' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'GenPK="'||g_AUTO_GEN_PK ||'"'||l_term; end if;
if not is_default_setting('EDITIONABLE' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'editionable="'||g_editionable ||'"'||l_term; end if;
if not is_default_setting('LANGUAGE' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'language="'||g_language ||'"'||l_term; end if;
if not is_default_setting('VERBOSE' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'verbose="'||g_verbose_yn ||'"'||l_term; end if;
if not is_default_setting('APEX' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'APEX="'||g_apex ||'"'||l_term; end if;
if not is_default_setting('PREFIX_PK_WITH_TNAME') or l_all_yn = 'Y' then l_delta := l_delta||l_start||'prefixPKwithTname="'|| lower(g_PREFIX_PK_WITH_TNAME)||'"'||l_term; end if; --mike
if not is_default_setting('CREATED_COLUMN_NAME') or l_all_yn = 'Y' then l_delta := l_delta||l_start||'createdCol="'|| lower(g_created_column_name)||'"'||l_term; end if;
if not is_default_setting('CREATED_BY_COLUMN_NAME') or l_all_yn = 'Y' then l_delta := l_delta||l_start||'createdByCol="'||lower(g_created_by_column_name)||'"'||l_term; end if;
if not is_default_setting('UPDATED_COLUMN_NAME') or l_all_yn = 'Y' then l_delta := l_delta||l_start||'updatedCol="'|| lower(g_updated_column_name)||'"'||l_term; end if;
if not is_default_setting('UPDATED_BY_COLUMN_NAME') or l_all_yn = 'Y' then l_delta := l_delta||l_start||'updatedByCol="'||lower(g_updated_by_column_name)||'"'||l_term; end if;
if not is_default_setting('INSERTS' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'inserts="'||g_inserts ||'"'||l_term; end if;
if not is_default_setting('SELECTS' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'selects="'||g_selects ||'"'||l_term; end if;
if not is_default_setting('UNCOMMENT' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'uncomment="'||g_uncomment ||'"'||l_term; end if;
if not is_default_setting('TAGS_FW' ) or l_all_yn = 'Y' then l_delta := l_delta||l_start||'tags="'||g_tags_fw ||'"'||l_term; end if;
--if not is_default_setting('AUDIT' ) then l_delta := l_delta||'# Audit = "'||g_audit ||'"'||chr(10); end if;
-- g_LONGER_IDENTIFIERS
l_delta := replace(l_delta,'="Y"',': true');
l_delta := replace(l_delta,'="N"',': false');
l_delta := replace(l_delta,'=',': ');
return '# settings = { '|| rtrim(rtrim(l_delta,', '),'# ')||' }';
end get_settings_dela_from_def;
procedure set_default_settings
is
begin
g_prefix := null;
g_api := 'N';
g_audit_cols := 'N';
g_compressed := 'N';
g_date_datatype := 'DATE';
g_semantics := 'DEFAULT';
g_on_delete := 'CASCADE';
g_row_key := 'N';
g_sgid := 'N';
g_row_version := 'N';
g_trigger_method := 'TRIG';
g_include_drops := 'N';
g_longer_identifiers := 'N';
g_history_tables := 'N';
g_db_version := '12c';
g_auto_gen_pk := 'Y';
g_language := 'EN';
g_editionable := 'N';
g_apex := 'N';
g_audit := 'N';
g_schema := null;
g_inserts := 0;
g_selects := 'N';
g_uncomment := 'Y';
g_tags_fw := 'N';
g_prefix_pk_with_tname := 'N';
g_created_column_name := 'created';
g_created_by_column_name := 'created_by';
g_updated_column_name := 'updated';
g_updated_by_column_name := 'updated_by';
end set_default_settings;
procedure set_settings_overrides (
p_string in varchar2 default null)
is
x varchar2(32767) := null;
y varchar2(32767) := null;
i integer := 0;
j integer := 0;
l_schema varchar2(255) := null;
l_prefix varchar2(255) := null;
function get_yn (
p_string in varchar2 default null,
p_setting in varchar2 default null)
return varchar2
is
begin
if instr(upper(p_string),rtrim(upper(p_setting),'=')||'=Y') > 0 then
return 'Y';
elsif instr(x,rtrim(upper(p_setting),'=')||'=N') > 0 then
return 'N';
else
return 'N';
end if;
end get_yn;
function get_value (
p_string in varchar2 default null,
p_setting in varchar2 default null)
return varchar2
is
r varchar2(32767) := null;
begin
if instr(p_string,upper(p_string)) > 0 then
r := substr(x,instr(x,upper(p_setting))+length(upper(p_setting)));
if instr(r,'_') > 0 then
r := substr(r,1,(instr(r,'_') - 1));
end if;
return ltrim(rtrim(r,'"'),'"');
else
return null;
end if;
end get_value;
function get_quoted_value (
p_string in varchar2 default null, -- x
p_setting in varchar2 default null) -- 'PREFIX='
return varchar2
is
r varchar2(32767) := null;
s integer := 0;
s2 integer := 0;
begin
r := regexp_substr( p_string, p_setting||'_?"(.*?)"', 1, 1, 'i', 1 );
if r is null then
r := regexp_substr( p_string, p_setting||'(.*?)(\s|$|_)', 1, 1, 'i', 1 );
end if;
return r;
end get_quoted_value;
begin
-- clean and standardize input string
x := replace(p_string,chr(13),'_');
x := replace(x,chr(10),'_');
x := replace(x,chr(9),'_');
x := replace(x,' ','_');
x := replace(x,':','=');
x := upper(x);
x := replace(x,'TRUE','Y');
x := replace(x,'FALSE','N');
x := replace(x,',','_');
x := replace(x,'(','');
x := replace(x,')','');
x := replace(x,'{','');
x := replace(x,'}','');
x := replace(x,'[','');
x := replace(x,']','');
for i in 1..25 loop
x := regexp_replace(x,'_{2,}','_');
x := replace(x,'_=','=');
x := replace(x,'=_','=');
end loop;
if instr(x,'PREFIX=_"') > 0 or instr(x,'PREFIX="') > 0 then
l_prefix := trim(replace(get_quoted_value(x,'PREFIX='),'"',null));
else
l_prefix := trim(replace(get_value(x,'PREFIX='),'"',null));
end if;
l_schema := trim(replace(get_value(x,'SCHEMA='),'"',null));
-- x := replace(x,'"','');
x := replace(x,'ONDELETE=','ON_DELETE=');
x := replace(x,'ROWKEY','ROW_KEY');
x := replace(x,'SECURITYGROUPID','SGID');
x := replace(x,'SECURITY_GROUP_ID','SGID');
x := replace(x,'ROWVERSION','ROW_VERSION');
x := replace(x,'AUDIT COLS','AUDITCOLS');
x := replace(x,'AUDIT COLUMNS=','AUDITCOLS=');
x := replace(x,'COMPRESSED=','COMPRESS=');
x := replace(x,'DATE=','DATE_DATATYPE=');
x := replace(x,'TRIGGER=','TRIGGER_METHOD=');
x := replace(x,'TRIG=','TRIGGER_METHOD=');
x := replace(x,'DROPS=','INCLUDE_DROPS=');
x := replace(x,'DROP=','INCLUDE_DROPS=');
x := replace(x,'LONGID=','LONGER_IDENTIFIERS=');
x := replace(x,'LONGVC=','LONGER_VARCHARS=');
x := replace(x,'HISTORY=','HISTORY_TABLES=');
x := replace(x,'HIST=','HISTORY_TABLES=');
x := replace(x,'DB=','DB_VERSION=');
x := replace(x,'GENPK=','AUTO_GEN_PK=');
x := replace(x,'PK=','TRIGGER_METHOD=');
x := replace(x,'TIMESTAMP_WITH_LOCAL_TIME_ZONE','TIMESTAMP WITH LOCAL TIME ZONE');
x := replace(x,'TIMESTAMP_WITH_TIMEZONE','TIMESTAMP_WITH_TIME_ZONE');
x := replace(x,'TIMESTAMP_WITH_TIME_ZONE','TIMESTAMP WITH TIME ZONE');
x := replace(x,'TIMESTAMP_WITH_LOCAL_TIMEZONE','TIMESTAMP WITH LOCAL TIME ZONE');
x := replace(x,'TIMESTAMP_WITH_TIMEZONE','TIMESTAMP WITH TIME ZONE');
x := replace(x,'TSWLTZ','TIMESTAMP WITH LOCAL TIME ZONE');
x := replace(x,'TSWTZ','TIMESTAMP WITH TIME ZONE');
-- ensure the equals sign is provided
if instr(x,'DROP') > 0 and instr(x,'INCLUDE_DROPS=') = 0 then x := replace(x,'DROP','INCLUDE_DROPS=Y'); end if;
if instr(x,'API') > 0 and instr(x,'API=') = 0 then x := replace(x,'API','API=Y'); end if;
if instr(x,'ROW_VERSION') > 0 and instr(x,'ROW_VERSION=') = 0 then x := replace(x,'ROW_VERSION','ROW_VERSION=Y'); end if;
if instr(x,'ROW_KEY') > 0 and instr(x,'ROW_KEY=') = 0 then x := replace(x,'ROW_KEY','ROW_KEY=Y'); end if;
if instr(x,'SGID') > 0 and instr(x,'SGID=') = 0 then x := replace(x,'SGID','SGID=Y'); end if;
if instr(x,'LONGID') > 0 and instr(x,'LONGID=') = 0 then x := replace(x,'LONGID','LONGER_IDENTIFIERS=Y'); end if;
if instr(x,'LONGVC') > 0 and instr(x,'LONGVC=') = 0 then x := replace(x,'LONGVC','LONGER_VARCHARS=Y'); end if;
if instr(x,'HISTORY') > 0 and instr(x,'HISTORY=') = 0 then x := replace(x,'HISTORY','HISTORY_TABLES=Y'); end if;
if instr(x,'HIST') > 0 and instr(x,'HIST=') = 0 then x := replace(x,'HIST','HISTORY_TABLES=Y'); end if;
if instr(x,'GENPK') > 0 and instr(x,'GENPK=') = 0 then x := replace(x,'GENPK','AUTO_GEN_PK=Y'); end if;
if instr(x,'COMPRESSED') > 0 and instr(x,'COMPRESSED=') = 0 then x := replace(x,'COMPRESSED','COMPRESS=Y'); end if;
if instr(x,'COMPRESS') > 0 and instr(x,'COMPRESS=') = 0 then x := replace(x,'COMPRESS','COMPRESS=Y'); end if;
if instr(x,'AUDITCOLS') > 0 and instr(x,'AUDITCOLS=') = 0 then x := replace(x,'AUDITCOLS','AUDITCOLS=Y'); end if;
if instr(x,'AUDIT_') > 0 and instr(x,'AUDIT=') = 0 then x := replace(x,'AUDIT_','AUDIT=Y'); end if;
if instr(x,'VERBOSE_') > 0 and instr(x,'VERBOSE=') = 0 then x := replace(x,'VERBOSE_','VERBOSE=Y'); end if;
if instr(x,'INSERTS') > 0 and instr(x,'INSERTS=') = 0 then x := replace(x,'INSERTS','INSERTS=1'); end if;
if instr(x,'SELECTS') > 0 and instr(x,'SELECTS=') = 0 then x := replace(x,'SELECTS','SELECTS=Y'); end if;
if instr(x,'UNCOMMENT') > 0 and instr(x,'UNCOMMENT=') = 0 then x := replace(x,'UNCOMMENT','UNCOMMENT=Y'); end if;
if instr(x,'TAGS') > 0 and instr(x,'TAGS=') = 0 then x := replace(x,'TAGS','TAGS=Y'); end if;
if instr(x,'SEMANTICS') > 0 and instr(x,'SEMANTICS=') = 0 then x := replace(x,'SEMANTICS','SEMANTICS='); end if;
if instr(x,'LANGUAGE') > 0 and instr(x,'LANGUAGE=') = 0 then x := replace(x,'LANGUAGE','LANGUAGE='); end if;
if instr(x,'PREFIXPKWITHTNAME') > 0 and instr(x,'PREFIXPKWITHTNAME=') = 0 then x := replace(x,'PREFIXPKWITHTNAME','PREFIXPKWITHTNAME='); end if; -- mike
if instr(x,'CREATEDCOL') > 0 and instr(x,'CREATEDCOL=') = 0 then x := replace(x,'CREATEDCOL','CREATEDCOL='); end if;
if instr(x,'CREATEDBYCOL') > 0 and instr(x,'CREATEDBYCOL=') = 0 then x := replace(x,'CREATEDBYCOL','CREATEDBYCOL='); end if;
if instr(x,'UPDATEDCOL') > 0 and instr(x,'UPDATEDCOL=') = 0 then x := replace(x,'UPDATEDCOL','UPDATEDCOL='); end if;
if instr(x,'UPDATEDBYCOL') > 0 and instr(x,'UPDATEDBYCOL=') = 0 then x := replace(x,'UPDATEDBYCOL','UPDATEDBYCOL='); end if;
-- reset all globals before setting
if instr(x,'RESETSETTINGS') > 0 then
set_default_settings;
end if;
if instr(x,'OVERRIDESETTINGS=Y') > 0 then
set_default_settings;
end if;
-- set globals
if instr(x,'PREFIX=') > 0 then g_prefix := l_prefix; end if;
if instr(x,'SCHEMA=') > 0 then g_schema := l_schema; end if;
if instr(x,'API=') > 0 then g_api := get_yn(x,'API='); end if;
if instr(x,'AUDITCOLS=') > 0 then g_AUDIT_COLS := get_yn(x,'AUDITCOLS='); end if;
if instr(x,'COMPRESS=') > 0 then g_COMPRESSED := get_yn(x,'COMPRESS='); end if;
if instr(x,'DATE_DATATYPE=') > 0 then g_DATE_DATATYPE := get_value(x,'DATE_DATATYPE='); end if;
if instr(x,'ON_DELETE=') > 0 then g_ON_DELETE := get_quoted_value(x,'ON_DELETE='); end if;
if instr(x,'ROW_KEY=') > 0 then g_ROW_KEY := get_yn(x,'ROW_KEY='); end if;
if instr(x,'SGID=') > 0 then g_SGID := get_yn(x,'SGID='); end if;
if instr(x,'ROW_VERSION=') > 0 then g_ROW_VERSION := get_yn(x,'ROW_VERSION='); end if;
if instr(x,'TRIGGER_METHOD=') > 0 then g_TRIGGER_METHOD := get_value(x,'TRIGGER_METHOD='); end if;
if instr(x,'INCLUDE_DROPS=') > 0 then g_INCLUDE_DROPS := get_yn(x,'INCLUDE_DROPS='); end if;
if instr(x,'LONGER_IDENTIFIERS=') > 0 then g_LONGER_IDENTIFIERS := get_yn(x,'LONGER_IDENTIFIERS='); end if;
if instr(x,'LONGER_VARCHARS=') > 0 then g_LONGER_VARCHARS_YN := get_yn(x,'LONGER_VARCHARS='); end if;
if instr(x,'HISTORY_TABLES=') > 0 then g_HISTORY_TABLES := get_yn(x,'HISTORY_TABLES='); end if;
if instr(x,'DB_VERSION=') > 0 then g_DB_VERSION := get_value(x,'DB_VERSION='); end if;
if instr(x,'AUTO_GEN_PK=') > 0 then g_AUTO_GEN_PK := get_yn(x,'AUTO_GEN_PK='); end if;
if instr(x,'EDITIONABLE=') > 0 then g_editionable := get_yn(x,'EDITIONABLE='); end if;
if instr(x,'LANGUAGE=') > 0 then g_language := get_value(x,'LANGUAGE='); end if;
if instr(x,'APEX=') > 0 then g_apex := get_yn(x,'APEX='); end if;
if instr(x,'AUDIT=') > 0 then g_audit := get_yn(x,'AUDIT='); end if;
if instr(x,'VERBOSE=') > 0 then g_verbose_yn := get_yn(x,'VERBOSE='); end if;
if instr(x,'INSERTS=') > 0 then g_inserts := get_value(x,'INSERTS='); end if;
if instr(x,'SELECTS=') > 0 then g_selects := get_yn(x,'SELECTS='); end if;
if instr(x,'UNCOMMENT=') > 0 then g_uncomment := get_yn(x,'UNCOMMENT='); end if;
if instr(x,'TAGS=') > 0 then g_tags_fw := get_yn(x,'TAGS='); end if;
if instr(x,'SEMANTICS=') > 0 then g_semantics := get_value(x,'SEMANTICS='); end if;
if instr(x,'PREFIXPKWITHTNAME=') > 0 then g_prefix_pk_with_tname := get_yn(x,'PREFIXPKWITHTNAME='); end if; --mike
if instr(x,'CREATEDCOL=') > 0 then g_created_column_name := get_quoted_value(x,'CREATEDCOL='); end if;
if instr(x,'CREATEDBYCOL=') > 0 then g_created_by_column_name := get_quoted_value(x,'CREATEDBYCOL='); end if;
if instr(x,'UPDATEDCOL=') > 0 then g_updated_column_name := get_quoted_value(x,'UPDATEDCOL='); end if;
if instr(x,'UPDATEDBYCOL=') > 0 then g_updated_by_column_name := get_quoted_value(x,'UPDATEDBYCOL='); end if;
-- schema
if g_schema is not null then
g_schema := rtrim(trim_identifier_length(upper(clean_name(g_schema))),'.')||'.';
end if;
-- check for valid values
if upper(g_DB_VERSION) in ('11G','12C') then null; else g_DB_VERSION := '12C'; end if;
if g_trigger_method in ('IDENTITY','TRIG','TRIGGER') then null; else g_trigger_method := 'IDENTITY'; end if;
if upper(g_DATE_DATATYPE) in ('DATE','TIMESTAMP','TIMESTAMP WITH TIME ZONE','TIMESTAMP WITH LOCAL TIME ZONE') then null; else g_DATE_DATATYPE := 'DATE'; end if;
if g_language not in ('EN','KO','JA','DE') then g_language := 'EN'; end if;
end set_settings_overrides;
function trim_identifier_length (
p_object_name in varchar2 default null,
p_length_override in number default 0)
return varchar2
is
begin
if NVL(p_length_override,0) != 0 then
return substr(p_object_name,1,p_length_override);
elsif NVL(g_LONGER_IDENTIFIERS,'N') = 'N' then
return substr(p_object_name,1,30);
else
return substr(p_object_name,1,128);
end if;
end trim_identifier_length;
function gen_valid_identifier_name (
p_name in varchar2 default null,
p_suffix in varchar2 default null,
p_table_name in varchar2 default null)
return varchar2
is
t varchar2(128) := null; -- table name
p varchar2(128) := null; -- application prfix
r varchar2(128) := null; -- constraint
s varchar2(128) := null; -- suffix
begin
-- prefix
if g_prefix is not null and p_suffix != 'API' then
p := lower(rtrim(clean_name(g_prefix),'_'))||'_';
end if;
-- schema
if g_schema is not null then
g_schema := rtrim(trim_identifier_length(lower(clean_name(g_schema))),'.')||'.';
end if;
-- suffix
s := '_'||trim(ltrim(lower(clean_name(p_suffix)),'_'));
-- table name
if p_table_name is not null then
t := lower(clean_name(p_table_name));
if NVL(g_LONGER_IDENTIFIERS,'N') = 'N' then
if length(p_name) > 13 then
t := substr(t,1,13);
elsif length(p_name) > 9 then
t := substr(t,1,15);
else
t := substr(t,1,18);
end if;
end if;
t := t||'_';
else
t := null;
end if;
-- do not repeat prefix
if p is not null then
if substr(t,1,length(p)) = lower(p) then
p := null;
end if;
end if;
-- trimmed constraint name
r := replace(trim(lower(p_name)),' ','_');
if nvl(g_longer_identifiers,'N') = 'N' then
r := substr(r,1,30-(nvl(length(t),0)+nvl(length(p),0)+length(s)));
else
r := substr(r,1,128-(nvl(length(t),0)+nvl(length(p),0)+length(s)));
end if;
return regexp_replace(p||t||r||s,'_{2,}','_');
end gen_valid_identifier_name;
function esc_quotes (p_string in varchar2) return varchar2
is
begin
return replace(p_string,'''','''''');
end esc_quotes;
function get_model (p_id in number) return varchar2 is
m varchar2(32767) := null;
c clob;
l integer;
begin
for c1 in (select model from EBA_DBTOOLS_SAVED_MODELS where id = p_id) loop
c := c1.model;
l := dbms_lob.getlength(c);
m := to_char(dbms_lob.substr(c,l,1));
end loop;
return m;
end get_model;
function get_model_from_history (p_id in number) return varchar2 is
m varchar2(32767) := null;
c clob;
l integer;
begin
for c1 in (select clob001 model from apex_collections where collection_name = 'RAW_SQL' and seq_id = p_id) loop
c := c1.model;
l := dbms_lob.getlength(c);
m := to_char(dbms_lob.substr(c,l,1));
end loop;
return m;
end get_model_from_history;
function yn (p_str in varchar2) return varchar2
is
begin
if upper(p_str) = 'Y' then return 'Yes';
elsif upper(p_str) = 'N' then return 'No';
else return p_str;
end if;
end yn;
procedure print_generated
is
begin
printl(' ');
printl('-- Generated by '||g_app_name||' '||
trim(to_char(sysdate,'Day'))||' '||
trim(to_char(sysdate,'Month'))||' '||
trim(to_char(sysdate,'DD, YYYY HH24:MI:SS')));
printl(' ');
end print_generated;
procedure print_settings (p_text in varchar2 default null)
is
begin
printl('-- Settings:');
printl('-- Object Prefix (prefix): '||NVL(g_prefix,'None Specified'));
printl('-- Schema Name (schema): '||NVL(g_prefix,'None Specified'));
printl('-- Generate APIs (api): '||yn(g_api));
printl('-- Include Audit Columns (auditcols): '||yn(g_AUDIT_COLS));
printl('-- Compress Tables (compressed): '||yn(g_COMPRESSED));
printl('-- Generate Date Datatypes as (date): '||g_DATE_DATATYPE);
printl('-- Foreign Key style (ondelete): '||g_ON_DELETE);
printl('-- Add ROW_KEY column (rowkey): '||yn(g_ROW_KEY));
printl('-- Add SECURITY_GROUP_ID column (securitygroupid): '||yn(g_SGID));
printl('-- Add ROW_VERSION column (rowversion): '||yn(g_ROW_VERSION));
printl('-- Primary Key Population Method (pk): '||g_TRIGGER_METHOD);
printl('-- Include Drop Object Commands (drop): '||yn(g_INCLUDE_DROPS));
printl('-- Generate History Tracking (hist): '||yn(g_HISTORY_TABLES));
printl('-- Database Compatability (db): '||g_DB_VERSION);
if g_DB_VERSION like '12%' then
printl('-- Use Longer Identifiers (longid): '||yn(g_LONGER_IDENTIFIERS));
printl('-- Use Longer Varchars (longVC): '||yn(g_LONGER_VARCHARS_YN));
end if;
printl('-- Automatically add ID primary key columns (genpk): '||yn(g_AUTO_GEN_PK));
printl('-- Create PL/SQL objects and views as editionable (edtionable): '||yn(g_editionable));
printl('-- APEX enabled database (apex): '||yn(g_apex));
printl('-- Generate SQL insert statements (inserts): '||g_inserts);
printl('-- Generate SQL select statements (selects): '||yn(g_selects));
printl('-- Create tag tables and triggers to manage tag data: '||yn(g_tags_fw));
printl('-- Uncomment SQL insert and select statements (uncomment): '||yn(g_uncomment));
printl('-- Semantics: '||NVL(g_semantics,'Default'));
printl('-- Verbose: '||yn(g_verbose_yn));
end print_settings;
procedure print_settings2 (p_text in varchar2 default null)
is
begin
printl('/*');
if p_text is not null then
printl(remove_pound_directives(p_text));
end if;
if get_settings_dela_from_def is not null then
if NVL(g_verbose_yn,'N') = 'N' then
printl(get_settings_dela_from_def);
else
printl(get_settings_dela_from_def(p_all_yn=>'Y'));
end if;
end if;
printl('*/');
end print_settings2;
procedure log_history (
p_str in varchar2 default null)
is
begin
-- under development
null;
end log_history;
function validate_object_name (
p_object_name in varchar2 default null,
p_object_prefix in varchar2 default null,
p_LONGER_IDENTIFIERS_yn in varchar2 default 'N')
return varchar2
is
l_name varchar2(255) := trim(upper(p_object_name));
l_reserved varchar2(32767) := '
|ACCESS|
|ADD|
|ALL|
|ALTER|
|AND|
|ANY|
|AS|
|ASC|
|AUDIT|
|BETWEEN|
|BY|
|CHAR|
|CHECK|
|CLUSTER|
|COLUMN|
|COMMENT|
|COMPRESS|
|CONNECT|
|CREATE|
|CURRENT|
|DATE|
|DECIMAL|
|DEFAULT|
|DELETE|
|DESC|
|DISTINCT|
|DROP|
|ELSE|
|EXCLUSIVE|
|EXISTS|
|FILE|
|FLOAT|
|FOR|
|FROM|
|GRANT|
|GROUP|
|HAVING|
|IDENTIFIED|
|IMMEDIATE|
|IN|
|INCREMENT|
|INDEX|
|INITIAL|
|INSERT|
|INTEGER|
|INTERSECT|
|INTO|
|IS|
|LEVEL|
|LIKE|
|LOCK|
|LONG|
|MAXEXTENTS|
|MINUS|
|MLSLABEL|
|MODE|
|MODIFY|
|NOAUDIT|
|NOCOMPRESS|
|NOT|
|NOWAIT|
|NULL|
|NUMBER|
|OF|
|OFFLINE|
|ON|
|ONLINE|
|OPTION|
|OR|
|ORDER|
|PCTFREE|
|PRIOR|
|PRIVILEGES|
|PUBLIC|
|RAW|
|RENAME|
|RESOURCE|
|REVOKE|
|ROW|
|ROWID
|ROWNUM|
|ROWS|
|SELECT|
|SESSION|
|SET|
|SHARE|
|SIZE|
|SMALLINT|
|START|
|SUCCESSFUL|
|SYNONYM|
|SYSDATE|
|TABLE|
|THEN|
|TO|
|TRIGGER|
|UID|
|UNION|
|UNIQUE|
|UPDATE|
|USER|
|VALIDATE|
|VALUES|
|VARCHAR|
|VARCHAR2|
|VIEW|
|WHENEVER|
|WHERE|
|WITH|';
begin
if p_object_prefix is not null then
l_name := rtrim(p_object_prefix,'_')||'_'||l_name;
end if;
if instr(l_reserved,'|'||l_name||'|') > 0 then
l_name := 'THE_'||l_name;
end if;
if NVL(p_LONGER_IDENTIFIERS_yn,'N') = 'Y' then
if length(l_name) > 128 then
return substr(l_name,1,128);
end if;
else
if length(l_name) > 30 then
return substr(l_name,1,30);
end if;
end if;
if substr(l_name,1,1) = '"' then
null;
else
l_name := replace(l_name,' ','_');
if substr(l_name,1,1) in ('1','2','3','4','5','6','7','8','9','0') then
l_name := 'X'||l_name;
end if;
end if;
return l_name;
end validate_object_name;
function validate_data_type (
p_varchar_datatype in varchar2 default null,
p_longer_varchars_yn in varchar2 default 'N')
return varchar2
is
l number := 0;
i1 integer := 0;
i2 integer := 0;
begin
if p_varchar_datatype like 'VARCHAR2%' then
i1 := instr(p_varchar_datatype,'(');
i2 := instr(p_varchar_datatype,')');
if i1 > 0 and i2 > 0 then
l := to_number(substr(p_varchar_datatype,i1+1,(i2-i1)-1));
end if;
if NVL(p_longer_varchars_yn,'N') = 'Y' then
l := least(l,32767);
else
l := least(l,4000);
end if;
if l > 0 then
return 'varchar2('||l||')';
else
return lower(p_varchar_datatype);
end if;
else
return lower(p_varchar_datatype);
end if;
end validate_data_type;
function gen_compress_int (
p_function_name in varchar2 default 'compress_int',
p_prefix in varchar2 default null,
p_inline_yn in varchar2 default 'N')
return varchar2
is
l_sql varchar2(32767) := null;
l_indent varchar2(30) := ' ';
l_editionable varchar2(50) := null;
begin
if g_editionable = 'Y' then l_editionable := 'editionable '; end if;
if NVL(p_inline_yn,'N') = 'N' then
l_sql := 'create or replace '||l_editionable||'function '||g_schema||p_prefix||p_function_name||' (n in integer) return varchar2';
else
l_sql := l_sql ||'declare'||chr(10);
l_sql := l_sql ||l_indent||'function compress_int (n in integer ) return varchar2'||chr(10);
end if;
l_sql := l_sql ||l_indent||'as'||chr(10);
l_sql := l_sql ||l_indent||' ret varchar2(30);'||chr(10);
l_sql := l_sql ||l_indent||' quotient integer;'||chr(10);
l_sql := l_sql ||l_indent||' remainder integer;'||chr(10);
l_sql := l_sql ||l_indent||' digit char(1);'||chr(10);
l_sql := l_sql ||l_indent||'begin'||chr(10);
l_sql := l_sql ||l_indent||' ret := null; quotient := n;'||chr(10);
l_sql := l_sql ||l_indent||' while quotient > 0'||chr(10);
l_sql := l_sql ||l_indent||' loop'||chr(10);
l_sql := l_sql ||l_indent||' remainder := mod(quotient, 10 + 26);'||chr(10);
l_sql := l_sql ||l_indent||' quotient := floor(quotient / (10 + 26));'||chr(10);
l_sql := l_sql ||l_indent||' if remainder < 26 then'||chr(10);
l_sql := l_sql ||l_indent||' digit := chr(ascii(''A'') + remainder);'||chr(10);
l_sql := l_sql ||l_indent||' else'||chr(10);
l_sql := l_sql ||l_indent||' digit := chr(ascii(''0'') + remainder - 26);'||chr(10);
l_sql := l_sql ||l_indent||' end if;'||chr(10);
l_sql := l_sql ||l_indent||' ret := digit || ret;'||chr(10);
l_sql := l_sql ||l_indent||' end loop ;'||chr(10);
l_sql := l_sql ||l_indent||' if length(ret) < 5 then ret := lpad(ret, 4, ''A''); end if ;'||chr(10);
l_sql := l_sql ||l_indent||' return upper(ret);'||chr(10);
l_sql := l_sql ||l_indent||'end compress_int;'||chr(10);
if NVL(p_inline_yn,'N') = 'N' then
l_sql := l_sql||'/'||chr(10);
end if;
return l_sql;
end gen_compress_int;
--
-- clean table name to make it a valid oracle identifier
--
function clean_name (p_name in varchar2) return varchar2
is
l_name varchar2(255) := p_name;
begin
l_name := replace(l_name,unistr('\0009'),' ');
l_name := trim(l_name);
l_name := replace(l_name,chr(10),null);
l_name := replace(l_name,chr(13),null);
if nvl(substr(l_name,1,1),'x') = '"' then
null;
else
l_name := upper(l_name);
l_name := replace(l_name,'-','_');
l_name := replace(l_name,' ','_');
l_name := replace(l_name,'*','');
l_name := replace(l_name,'(','');
l_name := replace(l_name,')','');
l_name := replace(l_name,'!','');
l_name := replace(l_name,'~','');
l_name := replace(l_name,'@','');
l_name := replace(l_name,'%','');
l_name := replace(l_name,'.','_');
l_name := replace(l_name,'+','_');
l_name := replace(l_name,'^','');
l_name := replace(l_name,'&','_');
l_name := replace(l_name,',','');
l_name := replace(l_name,'<','');
l_name := replace(l_name,'>','');
l_name := replace(l_name,'=','');
l_name := replace(l_name,'|','_');
l_name := replace(l_name,';','');
l_name := replace(l_name,'!','');
l_name := replace(l_name,':','');
l_name := replace(l_name,'%','');
l_name := replace(l_name,'^','');
l_name := replace(l_name,'?','');
l_name := replace(l_name,'~','');
l_name := replace(l_name,'`','');
l_name := replace(l_name,'''','');
if substr(l_name,1,1) = '"' and substr(l_name,length(l_name),1) = '"' then
l_name := rtrim(l_name,'"');
l_name := ltrim(l_name,'"');
l_name := replace(l_name,'"','');
l_name := '"'||l_name||'"';
else
l_name := replace(l_name,'"','');
end if;
-- Replace any string of multiple underscores with a single one
l_name := regexp_replace(l_name,'\_+','_');
l_name := rtrim(l_name,'_');
l_name := ltrim(l_name,'_');
end if;
return l_name;
end clean_name;
function scrub_col_data_types (p_str in varchar2 default null) return varchar2
is
x varchar2(32767) := null;
begin
x := upper(p_str);
if x like '% INT' then x := substr(x,1,length(x) - 4);
elsif x like '% INTEGER' then x := substr(x,1,length(x) - 8);
elsif x like '% NUMBER' then x := substr(x,1,length(x) - 7);
elsif x like '% NUM' then x := substr(x,1,length(x) - 4);
elsif x like '% STRING' then x := substr(x,1,length(x) - 7);
end if;
if x like '% STRING(%' then
x := trim(substr(x,1,instr(x,'STRING(')-1));
elsif x like '% VARCHAR2(%' then
x := trim(substr(x,1,instr(x,'VARCHAR2(')-1));
elsif x like '% NUMBER(%' then
x := trim(substr(x,1,instr(x,'NUMBER(')-1));
end if;
x := validate_object_name(x);
return x;
end scrub_col_data_types;
function get_object_name (p_str in varchar2 default null) return varchar2
is
x varchar2(32767) := null;
begin
x := p_str;
if instr(x,'/') > 0 then
x := substr(x,1,(instr(x,'/') - 1));
end if;
if instr(x,'[') > 0 then
x := substr(x,1,(instr(x,'[') - 1));
end if;
x := clean_name(x);
return x;
end get_object_name;
function get_indent (p_str in varchar2) return number
is
c number := 0;
begin
for i in 1..15 loop
if substr(p_str,i,1) = ' ' then
c := c + 1;
elsif substr(p_str,i,1) = chr(9) then
c := c + 3;
else
exit;
end if;
end loop;
return c;
end;
function pre_process_lines (
p_tables in varchar2 default null,
p_name in varchar2 default null)
return varchar2
is
l_tables varchar2(32767) := null;
x varchar2(32767) := null;
c integer := 0;
l_eol integer := 0;
l_first_char integer := 0;
l_size integer := 0;
l_last_indentation integer := 0;
l_seq integer := 0;
l_last_table varchar2(4000) := null;
l_last_new_table integer := 0;
z integer := 0;
l_table_name varchar2(4000) := null;
l_parent_table varchar2(4000) := null;
l_fk varchar2(4000) := null; -- foreign key
l_count integer := 0;
l_column_name varchar2(4000);
l_clob clob;
l_raw_sql_hist_count integer := 0;
begin
begin
if not APEX_COLLECTION.COLLECTION_EXISTS('RAW_SQL') then
APEX_COLLECTION.CREATE_COLLECTION(p_collection_name => 'RAW_SQL');
end if;
l_clob := to_clob(p_tables);
APEX_COLLECTION.ADD_MEMBER (
p_collection_name => 'RAW_SQL',
p_c001 => p_name,
p_clob001 => l_clob,
p_d001 => sysdate);
begin
select max(seq_id) into l_raw_sql_hist_count from apex_collections where collection_name = 'RAW_SQL';
exception when others then
log_status (p_status=>'Unexpected error getting max seq id from collection', p_context => 'pre_process_lines',p_sqlerrm=>sqlerrm);
end;
if NVL(l_raw_sql_hist_count,0) > g_max_history then
for c1 in (select seq_id
from apex_collections
where collection_name = 'RAW_SQL' and seq_id <= (l_raw_sql_hist_count - 15)
order by seq_id desc
) loop
APEX_COLLECTION.DELETE_MEMBER(
p_collection_name => 'RAW_SQL',
p_seq => c1.seq_id);
end loop;
end if;
exception when others then null;
end;
--
-- rewrite with indentation indication
--
if not APEX_COLLECTION.COLLECTION_EXISTS('LINES') then
APEX_COLLECTION.CREATE_COLLECTION(p_collection_name => 'LINES');
else
APEX_COLLECTION.TRUNCATE_COLLECTION(p_collection_name => 'LINES');
end if;
-- clean string
l_tables := replace(p_tables,chr(13),null); -- replate line feeds with null
l_tables := replace(l_tables,chr(9),' '); -- replace tabs with 3 spaces
-- remove trailing whitespace
for j in 1..15 loop
l_tables := rtrim(l_tables,chr(10));
l_tables := rtrim(l_tables);
end loop;
-- remove duplicate new lines
for j in 1..15 loop
if instr(l_tables,chr(10)||chr(10)) > 0 then
l_tables := replace(l_tables,chr(10)||chr(10),chr(10));
else
exit;
end if;
end loop;
-- parse each line into a row in a collection and compute indentation
l_tables := trim(l_tables)||chr(10);
l_size := length(l_tables);
loop
c := c + 1;
if c = 1 then
l_first_char := 1;
else
l_first_char := l_first_char + l_eol;
end if;
l_eol := instr(substr(l_tables,l_first_char),chr(10));
if trim(substr(l_tables,l_first_char, l_eol)) is not null then
if substr(substr(l_tables,l_first_char, l_eol),1,2) = '--' then
null; -- ignore comments
elsif substr(substr(l_tables,l_first_char, l_eol),1,1) = '#' then
--if instr(upper(l_tables),'=') > 0 or instr(upper(l_tables),'DROP') > 0 then
g_settings_override := ' '||g_settings_override||trim(ltrim(substr(l_tables,l_first_char, l_eol),'#'));
--else
-- null; -- assume this is a comment
--end if;
else
APEX_COLLECTION.ADD_MEMBER (
p_collection_name => 'LINES', -- collection name
p_c001 => substr(substr(l_tables,l_first_char, l_eol),1,4000), -- line text
P_c003 => get_object_name(substr(substr(l_tables,l_first_char, l_eol),1,4000)), -- table name
p_n001 => get_indent(substr(l_tables,l_first_char, l_eol)) -- indentation spaces
);
end if;
end if;
if c = 8000 or l_first_char >= l_size then
-- hard limit of 8000 lines
exit;
end if;
end loop;
c := 0;
l_last_indentation := 0;
for c1 in (select seq_id, c001 t, c003 tname, n001 i from apex_collections where collection_name = 'LINES') loop
c := c + 1;
if c1.i = 0 then
l_seq := c;
APEX_COLLECTION.UPDATE_MEMBER (
p_collection_name => 'LINES',
p_seq => l_seq, -- collection sequence number
p_c001 => c1.t, -- line of text
p_c002 => 'TABLE', -- is new table
p_c003 => c1.tname, -- scrubbed table name
p_n001 => c1.i, -- indentation
p_n002 => 0 -- row sequence of parent table
);
l_last_new_table := l_seq;
elsif c > 1 and c1.i > l_last_indentation then
l_seq := c - 1;
z := 0;
-- z is the first table with lower sequence if indentation is greater then zero
for c2 in (select max(seq_id) z
from apex_collections
where collection_name = 'LINES' and n001 < l_last_indentation and c002 = 'TABLE' and seq_id < l_seq) loop
z := c2.z;
end loop;
for c2 in (select c003
from apex_collections
where collection_name = 'LINES' and seq_id = l_seq) loop
l_table_name := c2.c003;
end loop;
for c2 in (select c003
from apex_collections
where collection_name = 'LINES' and seq_id = z) loop
l_parent_table := c2.c003;
end loop;
if l_parent_table is not null then
l_fk := get_singular(l_parent_table)||'_ID';
else
l_fk := null;
end if;
APEX_COLLECTION.UPDATE_MEMBER (
p_collection_name => 'LINES',
p_seq => l_seq, -- collection sequence number
p_c001 => l_last_table, -- line of text
p_c002 => 'TABLE', -- is new table
p_c003 => l_table_name, -- scrubbed table name
p_c004 => l_parent_table, -- scrubbed parent table
p_c005 => l_fk, -- foreign key
p_n001 => l_last_indentation, -- indentation
p_n002 => z -- row sequence of parent table
);
l_last_new_table := l_seq;
end if;
l_last_indentation := c1.i;
l_last_table := c1.t;
end loop;
-- populate c003 with proper table name for all columns
c := 0;
for c1 in (select seq_id, c001, c002, c003, c004, c005, n001, n002 from apex_collections where collection_name = 'LINES' and c002 is null order by seq_id) loop
l_table_name := '';
c := c + 1;
for c2 in (select c003 from apex_collections where collection_name = 'LINES' and seq_id in
(select max(seq_id) s from apex_collections where collection_name = 'LINES' and c002 = 'TABLE' and seq_id < c1.seq_id and n001 < c1.n001)) loop
l_table_name := c2.c003;
end loop;
if l_table_name is null then
for c2 in (select c003 from apex_collections where collection_name = 'LINES' and seq_id in
(select max(seq_id) s from apex_collections where collection_name = 'LINES' and c002 = 'TABLE' and seq_id < c1.seq_id)) loop
l_table_name := c2.c003;
end loop;
end if;
APEX_COLLECTION.UPDATE_MEMBER (
p_collection_name => 'LINES',
p_seq => c1.seq_id, -- collection sequence number
p_c001 => c1.c001, -- line of text
p_c002 => '', -- is new table
p_c003 => l_table_name, -- scrubbed table name
p_c004 => c1.c004, -- scrubbed parent table
p_c005 => c1.c005, -- foreign key
p_n001 => c1.n001, -- indentation
p_n002 => c1.n002); -- row sequence of parent table
end loop;
-- remove any auto generated fk for tables that start in first cc
for c1 in (select seq_id, c001, c002, c003, c004, c005, n001, n002 from apex_collections where collection_name = 'LINES' and n001 = 0 and c005 is not null) loop
APEX_COLLECTION.UPDATE_MEMBER (
p_collection_name => 'LINES',
p_seq => c1.seq_id, -- collection sequence number
p_c001 => c1.c001, -- line of text
p_c002 => c1.c002, -- is new table
p_c003 => c1.c003, -- scrubbed table name
p_c004 => c1.c004, -- scrubbed parent table
p_c005 => null, -- foreign key (MUST BE NULL IN THIS CASE)
p_n001 => c1.n001, -- indentation
p_n002 => c1.n002); -- row sequence of parent table
end loop;
-- generate a scrubbed and flattended list of tables with fk column names to proper parents
-- loop over all table names and then column names within table names
x := null;
for c1 in (select c001 the_line, c002 is_table, c003 tname, c004 parent_table, c005 fk_name
from apex_collections
where collection_name = 'LINES' and c002 = 'TABLE' order by seq_id) loop
-- write table name without indentation
x := x||rtrim(ltrim(c1.the_line),chr(10))||chr(10);
-- select corresponding columns
c := 0;
for c2 in (select c001 the_line, c002 is_table, c003 tname, c004 fk_name
from apex_collections
where collection_name = 'LINES' and c002 is null and c003 = c1.tname order by seq_id) loop
c := c + 1;
if c1.fk_name is not null and c = 1 then
l_count := 0;
for c3 in (select c001 the_line from apex_collections where collection_name = 'LINES' and c002 is null and c003 = c1.tname) loop
l_column_name := clean_name(get_object_name(c3.the_line));
if l_column_name = c1.fk_name then
l_count := l_count + 1; -- found a foreign key column thus do not add it
end if;
end loop;
-- table is a FK to another table so add the FK reference
if l_count = 0 then
x := x||' '||rtrim(c1.fk_name,chr(10))||chr(10);
end if;
end if;
-- line is a column, indent all columns with 3 spaces
x := x||' '||rtrim(ltrim(c2.the_line),chr(10))||chr(10);
end loop; -- column loop
end loop; -- table loop
return x;
end pre_process_lines;
function parm_datatype (
p_tab_datatype in varchar2 default null)
return varchar2
is
begin
if upper(p_tab_datatype) like 'VARCHAR2%' then
return 'varchar2';
else
return lower(p_tab_datatype);
end if;
end parm_datatype;
function gen_api (
p_n001 in number,
p_indent in varchar2,
p_object_type in varchar2 default 'TABLE',
p_object_name in varchar2 default null,
p_type in varchar2 default 'SPEC',
p_prefix in varchar2 default null
) return varchar2
is
l_body varchar2(30) := null;
x varchar2(32767) := null;
l_indent varchar2(30) := p_indent;
l_exclude varchar2(4000) := '|CREATED|UPDATED|CREATED_BY|UPDATED_BY|ROW_KEY|SGID|ROW_VERSION|';
l_editionable varchar2(50) := null;
l_package_name varchar2(128) := null;
begin
if g_editionable = 'Y' then l_editionable := 'editionable '; end if;
if p_object_type = 'TABLE' then
if p_type = 'SPEC' then
l_body := null;
else
l_body := ' body ';
end if;
l_package_name := gen_valid_identifier_name (p_object_name,'API',null);
x := x||'create or replace '||l_editionable||'package '||l_body||g_schema||l_package_name||chr(10);
x := x||'is'||chr(10);
--
-- get
--
x := x||' '||chr(10);
if p_type = 'SPEC' then
x := x||l_indent||'/* example:'||chr(10);
x := x||l_indent||l_indent||'declare'||chr(10);
for c2 in (
select
c002 column_name,
c003 data_type,
n003 column_id
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.n001 = p_n001 and
NVL(instr('|'||c002||'|',l_exclude),0) = 0 and
c002 != 'ID'
) loop
x := x||l_indent||l_indent||l_indent||rpad('l_'||lower(c2.column_name),31,' ')||' '||c2.data_type||';'||chr(10);
end loop;
x := x||l_indent||l_indent||'begin'||chr(10);
x := x||l_indent||l_indent||l_package_name||'.get_row ('||chr(10);
x := x||l_indent||l_indent||l_indent||rpad('p_id',31,' ')||' => 1,'||chr(10);
for c2 in (
select
c002 column_name,
c003 data_type,
n003 column_id
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.n001 = p_n001 and
NVL(instr('|'||c002||'|',l_exclude),0) = 0 and
c002 != 'ID'
) loop
x := x||l_indent||l_indent||l_indent||rpad('p_'||lower(c2.column_name),31,' ')||' => l_'||lower(c2.column_name)||','||chr(10);
end loop;
x := rtrim(x,','||chr(10));
x := x||chr(10);
x := x||l_indent||' );'||chr(10);
x := x||l_indent||' end;'||chr(10);
x := x||l_indent||'*/'||chr(10);
x := x||chr(10);
end if; -- example
x := x||l_indent||'procedure get_row ('||chr(10);
x := x||l_indent||l_indent||rpad('p_id',31,' ')||'in number,'||chr(10);
for c2 in (
select
c002 column_name,
c003 data_type,
n003 column_id
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.n001 = p_n001 and
NVL(instr('|'||c002||'|',l_exclude),0) = 0 and
c002 != 'ID'
) loop
x := x||l_indent||l_indent||rpad('P_'||lower(c2.column_name),31,' ')||'out '||parm_datatype(c2.data_type)||','||chr(10);
end loop;
x := rtrim(x,chr(10));
x := rtrim(x,',');
x := x||chr(10)||l_indent||')';
if p_type = 'SPEC' then
x := x||';'||chr(10);
else
x := x||chr(10)||l_indent||'is'||chr(10);
x := x||l_indent||'begin'||chr(10);
x := x||l_indent||l_indent||'for c1 in (select * from '||lower(g_schema||p_object_name)||' where id = p_id) loop'||chr(10);
for c2 in (
select
c002 column_name,
c003 data_type,
n003 column_id
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.n001 = p_n001 and
NVL(instr('|'||c002||'|',l_exclude),0) = 0
and c002 != 'ID'
) loop
x := x||l_indent||l_indent||l_indent||'p_'||lower(c2.column_name)||' := c1.'||lower(c2.column_name)||';'||chr(10);
end loop;
x := x||l_indent||l_indent||'end loop;'||chr(10);
x := x||l_indent||'end get_row;'||chr(10)||chr(10);
end if;
--
-- insert
--
x := x||' '||chr(10);
if p_type = 'SPEC' then
x := x||l_indent||'/* example:'||chr(10);
x := x||l_indent||l_indent||'begin'||chr(10);
x := x||l_indent||l_indent||l_package_name||'.insert_row ('||chr(10);
for c2 in (
select
c002 column_name,
c003 data_type,
n003 column_id
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.n001 = p_n001 and
NVL(instr('|'||c002||'|',l_exclude),0) = 0 and
c002 not in ('CREATED','CREATED_BY','UPDATED','UPDATED_BY','ROW_VERSION','ROW_KEY','SECURITY_GROUP_ID')
) loop
x := x||l_indent||l_indent||l_indent||rpad('p_'||lower(c2.column_name),30,' ')||'=> ';
if c2.data_type like 'VARCHAR2%' then
x := x||'''x''';
elsif c2.data_type like 'NUMBER%' or c2.data_type like 'INTEGER%' then
x := x||'1';
elsif c2.data_type like 'DATE' then
x := x||'to_date('''||to_char(sysdate,'YYYY.MM.DD')||''',''YYYY.MM.DD'')';
else
x := x||'null';
end if;
x := x||','||chr(10);
end loop;
x := rtrim(x,','||chr(10));
x := x||chr(10);
x := x||l_indent||' );'||chr(10);
x := x||l_indent||' end;'||chr(10);
x := x||l_indent||'*/'||chr(10);
x := x||chr(10);
end if;
x := x||l_indent||'procedure insert_row ('||chr(10);
for c2 in (
select
c002 column_name,
c003 data_type,
n003 column_id
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.n001 = p_n001 and
NVL(instr('|'||c002||'|',l_exclude),0) = 0 and
c002 not in ('CREATED','CREATED_BY','UPDATED','UPDATED_BY')
) loop
x := x||l_indent||l_indent||rpad('p_'||lower(c2.column_name),31,' ')||'in '||parm_datatype(c2.data_type)||' default null,'||chr(10);
end loop;
x := rtrim(x,chr(10));
x := rtrim(x,',');
x := x||chr(10)||l_indent||')';
if p_type = 'SPEC' then
x := x||';'||chr(10);
else
x := x||chr(10)||l_indent||'is'||chr(10);
x := x||l_indent||'begin'||chr(10);
x := x||l_indent||l_indent||'insert into '||lower(g_schema||p_object_name)||' ('||chr(10);
for c2 in (
select
c002 column_name,
c003 data_type,
n003 column_id
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.n001 = p_n001 and
NVL(instr('|'||c002||'|',l_exclude),0) = 0 and
c002 not in ('CREATED','CREATED_BY','UPDATED','UPDATED_BY','ROW_VERSION','ROW_KEY','SECURITY_GROUP_ID')
) loop
x := x||l_indent||l_indent||l_indent||lower(c2.column_name)||','||chr(10);
end loop;
x := rtrim(x,chr(10));
x := rtrim(x,',');
x := x||chr(10)||l_indent||l_indent||') values ('||chr(10);
for c2 in (
select
c002 column_name,
c003 data_type,
n003 column_id
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.n001 = p_n001 and
NVL(instr('|'||c002||'|',l_exclude),0) = 0 and
c002 not in ('CREATED','CREATED_BY','UPDATED','UPDATED_BY','ROW_VERSION','ROW_KEY','SECURITY_GROUP_ID')
) loop
x := x||l_indent||l_indent||l_indent||'p_'||lower(c2.column_name)||','||chr(10);
end loop;
x := rtrim(x,chr(10));
x := rtrim(x,',');
x := x||chr(10)||l_indent||l_indent||');'||chr(10);
x := x||l_indent||'end insert_row;'||chr(10)||chr(10);
end if;
--
-- update
--
x := x||l_indent||'procedure update_row ('||chr(10);
for c2 in (
select
c002 column_name,
c003 data_type,
n003 column_id
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.n001 = p_n001 and
NVL(instr('|'||c002||'|',l_exclude),0) = 0 and
c002 not in ('CREATED','CREATED_BY','UPDATED','UPDATED_BY','ROW_VERSION','ROW_KEY','SECURITY_GROUP_ID')
) loop
x := x||l_indent||l_indent||rpad('p_'||lower(c2.column_name),31,' ')||'in '||parm_datatype(c2.data_type)||' default null,'||chr(10);
end loop;
x := rtrim(x,chr(10));
x := rtrim(x,',');
x := x||chr(10)||l_indent||')';
if p_type = 'SPEC' then
x := x||';'||chr(10);
else
x := x||chr(10)||l_indent||'is'||chr(10);
x := x||l_indent||'begin'||chr(10);
x := x||l_indent||l_indent||'update '||lower(g_schema||p_object_name)||' set '||chr(10);
for c2 in (
select
c002 column_name,
c003 data_type,
n003 column_id
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.n001 = p_n001 and
NVL(instr('|'||c002||'|',l_exclude),0) = 0 and
c002 not in ('CREATED','CREATED_BY','UPDATED','UPDATED_BY','ROW_VERSION','ROW_KEY','SECURITY_GROUP_ID')
) loop
x := x||l_indent||l_indent||l_indent||lower(c2.column_name)||' = p_'||lower(c2.column_name)||','||chr(10);
end loop;
x := rtrim(x,chr(10));
x := rtrim(x,',');
x := x||chr(10)||l_indent||l_indent||'where id = p_id;'||chr(10);
x := x||l_indent||'end update_row;'||chr(10)||chr(10);
end if;
--
-- delete
--
x := x||l_indent||'procedure delete_row ('||chr(10);
x := x||l_indent||l_indent||rpad('p_id',31,' ')||'in number'||chr(10);
x := x||l_indent||')';
if p_type = 'SPEC' then
x := x||';'||chr(10);
else
x := x||chr(10)||l_indent||'is'||chr(10);
x := x||l_indent||'begin'||chr(10);
x := x||l_indent||l_indent||'delete from '||lower(g_schema||p_object_name)||' where id = p_id;'||chr(10);
x := x||l_indent||'end delete_row;'||chr(10)||chr(10);
end if;
x := x||'end '||lower(p_object_name)||'_api;'||chr(10);
x := x||'/'||chr(10)||chr(10);
end if;
return x;
end gen_api;
function gen_example_sql (
p_n001 in number,
p_indent in varchar2,
p_object_type in varchar2 default 'TABLE',
p_object_name in varchar2 default null,
p_type in varchar2 default 'INSERT',
p_iteration in number default 1
) return varchar2
is
l_body varchar2(30) := null;
x varchar2(32767) := null;
l_indent varchar2(30) := p_indent;
l_exclude varchar2(4000) := '|CREATED|UPDATED|CREATED_BY|UPDATED_BY|ROW_KEY|SECURITY_GROUP_ID|ROW_VERSION|';
l_editionable varchar2(50) := null;
l_package_name varchar2(128) := null;
l_check_values varchar2(32767) := null;
l_values varchar2(32767) := null;
l_check_values_arr APEX_APPLICATION_GLOBAL.VC_ARR2;
l_values_arr APEX_APPLICATION_GLOBAL.VC_ARR2;
l_index integer := 0;
l_count integer := 0;
l_row integer := 0;
l_random_row integer := 0;
l_value varchar2(4000);
l_pk number;
l_fk number;
l_low number;
l_high number;
l_high_value number;
l_random_number number;
l_previous_column varchar2(128);
l_language varchar2(2) := lower(g_language);
--
function get_vc_size (p_data_type in varchar2 default null) return number
is
l_size integer := 1;
x varchar2(4000) := null;
begin
if p_data_type like 'VARCHAR%' then
if instr(p_data_type,'(') > 0 then
x := substr(p_data_type,instr(p_data_type,'(')+1);
x := replace(x,')',null);
begin
l_size := to_number(x);
exception when others then null;
end;
end if;
end if;
return l_size;
end get_vc_size;
begin
if NVL(g_audit_cols,'N') = 'Y' then
l_exclude := '|CREATED|UPDATED|CREATED_BY|UPDATED_BY|ROW_KEY|SECURITY_GROUP_ID|ROW_VERSION|';
else
l_exclude := '\ ';
end if;
for c1 in (select count(*) c from EBA_DBTOOLS_RANDOM_NAMES where language = l_language ) loop
l_count := c1.c;
end loop;
------------------------------
-- insert statement generation
--
if p_object_type = 'TABLE' and p_type = 'INSERT' then
x := x||'insert into '||lower(g_schema||p_object_name)||' ('||chr(10);
--
-- insert statement column list
--
for c2 in (
select
c002 column_name,
c003 data_type,
n003 column_id,
NVL(c.c006,'N') is_pk
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.n001 = p_n001 and
NVL(instr(l_exclude,'|'||upper(c002)||'|'),0) = 0 and
c002 not in ('CREATED','CREATED_BY','UPDATED','UPDATED_BY','ROW_VERSION','ROW_KEY','SECURITY_GROUP_ID')
) loop
-- mike mike
if upper(c2.is_pk) = 'Y' and upper(c2.column_name) = 'ID' and upper(g_prefix_pk_with_tname) = 'Y' then
-- column is the primary key e.g. ID column
x := x||l_indent||lower(substr(get_singular(p_object_name),1,27)||'_id')||','||chr(10);
else
-- column is not the primary key column
x := x||l_indent||lower(c2.column_name)||','||chr(10);
end if;
end loop;
--
-- insert statement values list
--
l_previous_column := '?#@';
x := rtrim(x,','||chr(10))||chr(10);
x := x||') values ('||chr(10);
for c2 in (
select
c.c001 table_name,
c.c002 column_name,
upper(c.c003) data_type,
c.c004 not_null_yn,
c.n003 column_id,
c.c017 valid_values,
nvl(c.c015,c.c007) FK_TABLE,
NVL(c.c006,'N') is_pk,
c.c013 between_clause,
c.c019 gen_values,
c.c021 constant_value
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.n001 = p_n001 and
NVL(instr('|'||c.c002||'|',l_exclude),0) = 0 and
c002 not in ('CREATED','CREATED_BY','UPDATED','UPDATED_BY','ROW_VERSION','ROW_KEY','SECURITY_GROUP_ID')
) loop
-- determine row
-- use mod so always get valid row
-- l_row is used for fetching same employee name, email, and city
l_row := mod(p_iteration,l_count);
-- generate a random row id
l_random_row := trunc(sys.dbms_random.value(low => 1, high => l_count+1));
-- generate a random value from a list of valid values
if c2.valid_values is not null then
l_check_values := replace(c2.valid_values,',',':');
l_check_values := replace(l_check_values,': ',':');
l_check_values := replace(l_check_values,' :',':');
l_check_values_arr := APEX_UTIL.STRING_TO_TABLE(l_check_values);
l_high_value := l_check_values_arr.count;
l_high_value := l_high_value + .999999;
l_index := trunc(sys.dbms_random.value(low => 1, high => l_high_value)); -- get random check from array
l_check_values := replace(trim(l_check_values_arr(l_index)),chr(9),' ');
if l_values like ''' %' then
l_values := ''''||substr(l_values,3);
end if;
l_values := trim(ltrim(l_values,chr(9)));
else
l_check_values := null;
end if;
-- constant value
if trim(c2.constant_value) is not null then
if c2.data_type like 'VARCHAR2%' or c2.data_type like 'CLOB' then
if trim(c2.constant_value) = 'NULL' then
l_value := 'null';
else
l_value := trim(c2.constant_value);
l_value := ltrim(l_value,'''');
l_value := rtrim(l_value,'''');
end if;
elsif c2.data_type like 'NUMBER' or c2.data_type like 'INTEGER' then
l_value := trim(c2.constant_value);
end if;
end if;
-- comma seperated random values
if trim(c2.gen_values) is not null then
l_values := trim(c2.gen_values);
for i in 1..10 loop
l_values := replace(l_values,' ',' ');
end loop;
l_values := replace(l_values,',',':');
l_values_arr := APEX_UTIL.STRING_TO_TABLE(l_values);
l_high_value := l_values_arr.count;
if l_high_value = 0 then
l_values := null;
elsif l_high_value = 1 then
null;
else
l_high_value := l_high_value + .999999;
l_index := trunc(sys.dbms_random.value(low => 1, high => l_high_value)); -- get random check from array
l_values := trim(l_values_arr(l_index));
if l_values like ''' %' then
l_values := ''''||substr(l_values,3);
end if;
end if;
else
l_values := null;
end if;
if c2.is_pk = 'Y' then
-- generate data for primary keys
if g_trigger_method = 'TRIG' then
l_pk := to_number(sys_guid(), 'XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX');
else
l_pk := p_iteration;
end if;
x := x||l_indent||to_char(l_pk)||','||chr(10);
save_inserted_primary_keys (c2.table_name, l_pk, p_iteration);
--
elsif c2.FK_TABLE is not null then
l_fk := nvl(get_valid_foreign_key (c2.FK_TABLE),1);
x := x||l_indent||to_char(l_fk)||','||chr(10);
--
elsif c2.data_type like 'VARCHAR2%' or c2.data_type like 'CLOB' then
if trim(c2.constant_value) is not null and l_value is not null then
-- constant value
if l_value = 'null' then
x := x||l_indent||'null,'||chr(10);
else
x := x||l_indent||''''||replace(trim(l_value),'''','''''')||''''||','||chr(10);
end if;
elsif l_values is not null then
-- /values clause data generation
if upper(trim(l_values)) = 'NULL' then
x := x||l_indent||'null'||','||chr(10);
else
if substr(l_values,1,1) != '''' then
l_values := ''''||trim(replace(trim(l_values),'''','''''')) ||'''';
end if;
x := x||l_indent||l_values||','||chr(10);
end if;
elsif l_check_values is not null then
x := x||l_indent||l_check_values||','||chr(10);
elsif c2.column_name like '%DESCRIPTION%' or c2.column_name like '%COMMENT%' then
for c3 in (select max(WORDS_1_100) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_random_row) loop
l_value := substr(c3.x,1,get_vc_size(c2.data_type));
end loop;
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like '%CITY%' or c2.column_name like '%LOCATION%' then
for c3 in (select max(city) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_row) loop
l_value := substr(c3.x,1,get_vc_size(c2.data_type));
end loop;
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like 'COUNTRY' then
for c3 in (select max(country) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_row) loop
l_value := substr(c3.x,1,get_vc_size(c2.data_type));
end loop;
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.table_name like '%EMP%' and c2.column_name like 'TITLE' then
for c3 in (select max(job) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_row) loop
l_value := substr(c3.x,1,get_vc_size(c2.data_type));
end loop;
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like 'JOB' then
for c3 in (select max(job) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_random_row) loop
l_value := substr(c3.x,1,get_vc_size(c2.data_type));
end loop;
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like 'COORD' or c2.column_name like 'LAT_LONG' then
l_value := trunc(sys.dbms_random.value(low => 20, high => 70))|| ' '||
trunc(sys.dbms_random.value(low => 20, high => 70))|| ' N '||
trunc(sys.dbms_random.value(low => 20, high => 70))|| ' '||
trunc(sys.dbms_random.value(low => 20, high => 70))|| 'W';
l_value := substr(l_value,1,get_vc_size(c2.data_type));
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like 'PRICE_SCALE' then
l_random_number := trunc(sys.dbms_random.value(low => 1, high => 5.2));
if l_random_number = 1 then l_value := 'Least Expensive';
elsif l_random_number = 2 then l_value := 'Inexpensive';
elsif l_random_number = 3 then l_value := 'Moderate';
elsif l_random_number = 4 then l_value := 'Expensive';
elsif l_random_number = 5 then l_value := 'Most Expensive';
else l_value := 'Unknown';
end if;
l_value := substr(l_value,1,get_vc_size(c2.data_type));
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like 'ZIP' or c2.column_name like 'ZIP_CODE' then
l_value := trunc(sys.dbms_random.value(low => 10001, high => 99999));
l_value := substr(l_value,1,get_vc_size(c2.data_type));
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like 'URL' or c2.column_name like 'WEB_ADDRESS' then
for c3 in (select max(city) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_random_row) loop
l_value := replace(c3.x,' ',null);
end loop;
l_random_number := trunc(sys.dbms_random.value(low => 1, high => 6.999));
if l_random_number < 4 then l_value := l_value||'.com';
elsif l_random_number < 5 then l_value := l_value||'.net';
else l_value := l_value||'.gov';
end if;
l_value := lower(apex_util.compress_int(l_random_number)||'.'||l_value);
l_value := substr(l_value,1,get_vc_size(c2.data_type));
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like '%FIRST_NAME%' then
for c3 in (select max(first_name) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_row) loop
l_value := substr(c3.x,1,get_vc_size(c2.data_type));
end loop;
l_value := substr(l_value,1,get_vc_size(c2.data_type));
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like '%LAST_NAME%' then
for c3 in (select max(last_name) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_row) loop
l_value := substr(c3.x,1,get_vc_size(c2.data_type));
end loop;
l_value := substr(l_value,1,get_vc_size(c2.data_type));
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like 'ADDRESS' or c2.column_name like 'STREET' or c2.column_name like 'STREET_ADDRESS' then
l_random_number := trunc(sys.dbms_random.value(low => 1, high => 1000.99999));
for c3 in (select max(city) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_random_row) loop
l_value := c3.x;
end loop;
l_value := to_char(l_random_number)||' '||l_value;
if l_random_number < 200 then l_value := l_value||' Blvd';
elsif l_random_number < 600 then l_value := l_value||' Street';
elsif l_random_number < 800 then l_value := l_value||' Ave';
else l_value := l_value||' Place';
end if;
l_value := substr(l_value,1,get_vc_size(c2.data_type));
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like 'SHIP_TO%' or c2.column_name like 'BILL_TO%' then
l_random_number := trunc(sys.dbms_random.value(low => 1, high => 1000.99999));
for c3 in (select max(city) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_random_row) loop
l_value := c3.x;
end loop;
l_value := to_char(l_random_number)||' '||l_value;
if l_random_number < 200 then l_value := l_value||' Blvd';
elsif l_random_number < 600 then l_value := l_value||' Street';
elsif l_random_number < 800 then l_value := l_value||' Ave';
else l_value := l_value||' Place';
end if;
l_value := substr(l_value,1,get_vc_size(c2.data_type));
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like 'PRODUCT' or
(c2.table_name like '%PRODUCTS' and c2.column_name like 'NAME') then
l_random_number := trunc(sys.dbms_random.value(low => 1, high => 100.99999));
l_value := substr('M-'||apex_util.compress_int(l_random_number)||'-'||to_char(l_random_number),1,get_vc_size(c2.data_type));
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like 'TAGS' then
for c3 in (select max(tags) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_random_row) loop
l_value := substr(c3.x,1,get_vc_size(c2.data_type));
end loop;
if l_value is not null and sys.dbms_random.value(low => 1, high => 100) > 50 then
for c3 in (select max(tags) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_random_row) loop
if c3.x is not null then
l_value := substr(l_value||', '||c3.x,1,get_vc_size(c2.data_type));
end if;
end loop;
end if;
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif ((c2.table_name like '%EMP%' and c2.column_name like '%NAME%') or c2.column_Name like '%FULL_NAME%') then
for c3 in (select max(FULL_NAME) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_row) loop
l_value := substr(c3.x,1,get_vc_size(c2.data_type));
end loop;
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif (c2.table_name like '%CUSTOMERS' and c2.column_name like '%NAME') or
(c2.table_name like '%PRODUCTS' and c2.column_name like '%OWNER') or
(c2.table_name like '%STATUS_REPORT%' and c2.column_name like '%OWNER') or
(c2.table_name like '%PROJECTS' and c2.column_name like '%OWNER') or
(c2.table_name like '%ATTACHMENTS' and c2.column_name like '%CONTRIBUTED_BY') or
(c2.table_name like '%MILESTONES' and c2.column_name like '%OWNER') or
(c2.table_name like '%ACTION_ITEMS' and c2.column_name like '%OWNER')
then
for c3 in (select max(FULL_NAME) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_row) loop
l_value := substr(c3.x,1,get_vc_size(c2.data_type));
end loop;
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif (c2.table_name like '%DEPARTMENT%' or c2.table_name like '%DEPT') and
(c2.column_name like '%NAME%' or c2.column_name like 'DNAME' or c2.column_name like 'DEPARTMENT') then
for c3 in (select max(DEPARTMENT_NAME) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_random_row) loop
l_value := substr(c3.x,1,get_vc_size(c2.data_type));
end loop;
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like '%EMAIL%' then
for c3 in (select max(email) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_row) loop
l_value := substr(c3.x,1,get_vc_size(c2.data_type));
end loop;
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like 'IP_ADDRESS' or c2.column_name like 'IPADDRESS' then
l_value := trunc(sys.dbms_random.value(low => 100, high => 200))||'.'||
trunc(sys.dbms_random.value(low => 100, high => 200))||'.'||
trunc(sys.dbms_random.value(low => 10, high => 100))||'.'||
trunc(sys.dbms_random.value(low => 100, high => 200));
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like 'MAC_ADDRESS' or c2.column_name like 'MACADDRESS' then
l_value := substr(sys_guid(),1,2)||':'||substr(sys_guid(),3,2)||':'||substr(sys_guid(),5,2)||':'||substr(sys_guid(),7,2)||':'||substr(sys_guid(),9,2)||':'||substr(sys_guid(),12,2);
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like 'GUID' then
for c9 in (select sys_guid() x from dual) loop
l_value := c9.x;
end loop;
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif c2.column_name like '%NAME%' and l_previous_column not like '%NAME%' then
for c3 in (select max(project_name) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_random_row) loop
l_value := substr(c3.x,1,get_vc_size(c2.data_type));
end loop;
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif get_vc_size(c2.data_type) >= 100 then
for c3 in (select max(WORDS_1_60) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_random_row) loop
l_value := substr(c3.x,1,get_vc_size(c2.data_type));
end loop;
x := x||l_indent||''''||replace(replace(l_value,',.','.'),'''','''''')||''''||','||chr(10);
elsif get_vc_size(c2.data_type) >= 50 then
for c3 in (select max(WORDS_4) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_random_row) loop
l_value := substr(c3.x,1,get_vc_size(c2.data_type));
end loop;
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif get_vc_size(c2.data_type) >= 30 then
for c3 in (select max(WORDS_3) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_random_row) loop
l_value := substr(c3.x,1,get_vc_size(c2.data_type));
end loop;
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
elsif get_vc_size(c2.data_type) >= 10 then
for c3 in (select max(WORDS_1) x from EBA_DBTOOLS_RANDOM_NAMES where language = l_language and seq = l_random_row) loop
l_value := substr(c3.x,1,get_vc_size(c2.data_type));
end loop;
x := x||l_indent||''''||replace(l_value,'''','''''')||''''||','||chr(10);
else
x := x||l_indent||'''x'''||','||chr(10);
end if;
elsif c2.between_clause is not null and (c2.data_type like 'NUMBER%' or c2.data_type like 'INTEGER%') then
-- numeric datatype with between contraint
l_low := get_between_low_range(c2.between_clause);
l_high := get_between_high_range(c2.between_clause);
l_high := l_high + .99999999999;
if trim(c2.constant_value) is not null and l_value is not null then
x := x||l_indent||lower(l_value)||','||chr(10);
else
x := x||l_indent||trunc(sys.dbms_random.value(low => l_low, high => l_high))||','||chr(10);
end if;
elsif l_check_values is not null and (c2.data_type like 'NUMBER%' or c2.data_type like 'INTEGER%') then
if trim(c2.constant_value) is not null and l_value is not null then
x := x||l_indent||lower(l_value)||','||chr(10);
else
x := x||l_indent||l_check_values||','||chr(10);
end if;
elsif l_values is not null and (c2.data_type like 'NUMBER%' or c2.data_type like 'INTEGER%') then
x := x||l_indent||lower(trim(l_values))||','||chr(10);
elsif c2.data_type like 'NUMBER' then
if trim(c2.constant_value) is not null and l_value is not null then
x := x||l_indent||lower(l_value)||','||chr(10);
elsif c2.FK_TABLE is not null then
x := x||l_indent||'1'||','||chr(10);
else
x := x||l_indent||trunc(sys.dbms_random.value(low => 1, high => 100.99999999))||','||chr(10);
end if;
elsif c2.data_type like 'INTEGER' then
if trim(c2.constant_value) is not null and l_value is not null then
x := x||l_indent||lower(l_value)||','||chr(10);
elsif l_check_values is not null then
x := x||l_indent||l_check_values||','||chr(10);
elsif c2.FK_TABLE is not null then
x := x||l_indent||'1'||','||chr(10);
else
x := x||l_indent||trunc(sys.dbms_random.value(low => 1, high => 100.99999999))||','||chr(10);
end if;
elsif c2.data_type like 'NUMBER(' then
if l_values is not null then
-- /values clause data generation
if l_values is null then
x := x||l_indent||'null'||','||chr(10);
else
x := x||l_indent||l_values||','||chr(10);
end if;
elsif l_check_values is not null then
x := x||l_indent||l_check_values||','||chr(10);
elsif c2.FK_TABLE is not null then
x := x||l_indent||'1'||','||chr(10);
else
x := x||l_indent||substr(trunc(sys.dbms_random.value(low => 1, high => 100.9999999)),1,get_vc_size(c2.data_type))||','||chr(10);
end if;
elsif upper(c2.data_type) like 'DATE' then
x := x||l_indent||'sysdate - '||trunc(sys.dbms_random.value(low => 1, high => 100))||','||chr(10);
elsif upper(c2.data_type) like 'TIMESTAMP' then
x := x||l_indent||'systimestamp - numtodsinterval('''||trunc(sys.dbms_random.value(low => 1, high => 100))||''',''hour''),'||chr(10);
elsif upper(c2.data_type) like 'TIMESTAMP WITH TIME ZONE' then
x := x||l_indent||'cast(add_months(systimestamp,-'||trunc(sys.dbms_random.value(low => 1, high => 22))||') as timestamp with time zone),'||chr(10);
elsif upper(c2.data_type) like 'TIMESTAMP WITH LOCAL TIME ZONE' then
x := x||l_indent||'cast(add_months(systimestamp,-'||trunc(sys.dbms_random.value(low => 1, high => 22))||') as timestamp with local time zone),'||chr(10);
else
x := x||l_indent||'null'||','||chr(10);
end if;
l_previous_column := c2.column_name;
end loop;
x := rtrim(x,','||chr(10));
x := x||chr(10)||');'||chr(10);
end if;
--
-- select statement generation
--
if p_object_type = 'TABLE' and p_type = 'SELECT' then
x := x||'select '||chr(10);
for c2 in (
select
c002 column_name,
c003 data_type,
n003 column_id
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.n001 = p_n001
) loop
x := x||l_indent||c2.column_name||','||chr(10);
end loop;
x := rtrim(x,','||chr(10))||chr(10);
x := x||'from '||g_schema||p_object_name||';'||chr(10);
end if; -- example
return x;
end gen_example_sql;
procedure init_collections
is
begin
if not APEX_COLLECTION.COLLECTION_EXISTS('SCHEMA') then
APEX_COLLECTION.CREATE_COLLECTION(p_collection_name => 'SCHEMA');
end if;
if not APEX_COLLECTION.COLLECTION_EXISTS('SCHEMA_TAB_COLS') then
APEX_COLLECTION.CREATE_COLLECTION(p_collection_name => 'SCHEMA_TAB_COLS');
end if;
APEX_COLLECTION.TRUNCATE_COLLECTION(p_collection_name => 'SCHEMA');
APEX_COLLECTION.TRUNCATE_COLLECTION(p_collection_name => 'SCHEMA_TAB_COLS');
end init_collections;
--
-- comments
--
procedure extract_comments (
p_string in varchar2 default null,
p_new_string out varchar2,
p_comments out varchar2
)
is
l_new_str varchar2(32767) := null;
l_comments varchar2(4000) := null;
l_begin integer := 0;
l_end integer := 0;
l_len integer := 0;
begin
l_new_str := p_string;
-- convert dash dash comments to square bracket comments
if instr(l_new_str ,'--') > 0 then
l_new_str := replace(l_new_str,'--','[')||']';
end if;
-- [ style comments ]
l_begin := nvl(instr(l_new_str,'['),0);
l_end := nvl(instr(l_new_str,']'),0);
if l_begin > 0 and l_end = 0 then
l_new_str := l_new_str ||']';
l_end := nvl(instr(l_new_str,']'),0);
end if;
if l_begin > 1 and l_begin < l_end then
l_len := (l_end - l_begin) - 1;
if l_len > 0 then
l_comments := substr(l_new_str,l_begin+1,l_len);
l_new_str := substr(l_new_str,1,l_begin -1)||substr(l_new_str,l_end + 1);
else
l_new_str := p_string;
l_comments := null;
end if;
else
l_new_str := p_string;
l_comments := null;
end if;
p_new_string := l_new_str;
l_comments := replace(l_comments,chr(10),' ');
p_comments := trim(l_comments);
end extract_comments;
procedure extract_history (
p_string in varchar2 default null,
p_new_string out varchar2,
p_history_yn out varchar2
)
is
l_new_string varchar2(4000) := upper(p_string);
l_history_yn varchar2(1) := 'N';
begin
if instr(l_new_string,'/HISTORY') > 0 then
l_history_yn := 'Y';
l_new_string := trim(replace(l_new_string,'/HISTORY',null));
end if;
p_new_string := l_new_string;
p_history_yn := l_history_yn;
end extract_history;
procedure extract_api (
p_string in varchar2 default null,
p_new_string out varchar2,
p_api_yn out varchar2
)
is
l_new_string varchar2(4000) := upper(p_string);
l_api_yn varchar2(1) := 'N';
begin
if instr(l_new_string,'/API') > 0 then
l_api_yn := 'Y';
l_new_string := trim(replace(l_new_string,'/API',null));
end if;
p_new_string := l_new_string;
p_api_yn := l_api_yn;
end extract_api;
procedure extract_audit (
p_string in varchar2 default null,
p_new_string out varchar2,
p_audit_yn out varchar2
)
is
l_new_string varchar2(4000) := upper(p_string);
l_audit_yn varchar2(1) := 'N';
begin
if instr(l_new_string,'/AUDIT') > 0 then
l_audit_yn := 'Y';
l_new_string := trim(replace(l_new_string,'/AUDIT',null));
end if;
p_new_string := l_new_string;
p_audit_yn := l_audit_yn;
end extract_audit;
procedure extract_compressed (
p_string in varchar2 default null,
p_new_string out varchar2,
p_compressed_yn out varchar2
)
is
l_new_string varchar2(4000) := upper(p_string);
l_compressed_yn varchar2(1) := 'N';
begin
if instr(l_new_string,'/COMPRESSED') > 0 then
l_compressed_yn := 'Y';
l_new_string := trim(replace(l_new_string,'/COMPRESSED',null));
end if;
if instr(l_new_string,'/COMPRESS') > 0 then
l_compressed_yn := 'Y';
l_new_string := trim(replace(l_new_string,'/COMPRESS',null));
end if;
p_new_string := l_new_string;
p_compressed_yn := l_compressed_yn;
end extract_compressed;
procedure extract_partitioned (
p_string in varchar2 default null,
p_new_string out varchar2,
p_partitioned_yn out varchar2
)
is
l_new_string varchar2(4000) := upper(p_string);
l_partitioned_yn varchar2(1) := 'N';
begin
if instr(l_new_string,'/PARTITIONED') > 0 then
l_partitioned_yn := 'Y';
l_new_string := trim(replace(l_new_string,'/PARTITIONED',null));
end if;
if instr(l_new_string,'/PARTITION') > 0 then
l_partitioned_yn := 'Y';
l_new_string := trim(replace(l_new_string,'/PARTITION',null));
end if;
p_new_string := l_new_string;
p_partitioned_yn := l_partitioned_yn;
end extract_partitioned;
procedure extract_audit_cols (
p_string in varchar2 default null,
p_new_string out varchar2,
p_audit_cols_yn out varchar2
)
is
l_new_string varchar2(4000) := upper(p_string);
l_audit_cols_yn varchar2(1) := 'N';
begin
if instr(l_new_string,'/AUDITCOLS') > 0 then
l_audit_cols_yn := 'Y';
l_new_string := trim(replace(l_new_string,'/AUDITCOLS',null));
end if;
if instr(l_new_string,'/AUDIT COLUMNS') > 0 then
l_audit_cols_yn := 'Y';
l_new_string := trim(replace(l_new_string,'/AUDIT_COLUMNS',null));
end if;
if instr(l_new_string,'/AUDIT COLS') > 0 then
l_audit_cols_yn := 'Y';
l_new_string := trim(replace(l_new_string,'/AUDIT COLS',null));
end if;
p_new_string := l_new_string;
p_audit_cols_yn := l_audit_cols_yn;
end extract_audit_cols;
procedure extract_REST (
p_string in varchar2 default null,
p_new_string out varchar2,
p_REST_yn out varchar2
)
is
l_new_string varchar2(4000) := upper(p_string);
l_rest_yn varchar2(1) := 'N';
begin
if instr(l_new_string,'/REST') > 0 then
l_rest_yn := 'Y';
l_new_string := trim(replace(l_new_string,'/REST',null));
end if;
p_new_string := l_new_string;
p_rest_yn := l_rest_yn;
end extract_REST;
Procedure extract_insert (
p_string in varchar2 default null,
p_new_string out varchar2,
p_insert_example out integer
)
is
l_new_string varchar2(4000) := null;
l_insert_example integer := 0;
i integer := 0;
j integer := 0;
l_insert_rows_txt varchar2(4000) := null;
l_extra varchar2(4000) := null;
begin
l_new_string := replace(upper(p_string),chr(9),' ');
i := instr(l_new_string,'/INSERT');
if i > 0 then
l_extra := ltrim(substr(l_new_string,i+8)||' '); -- everything after slash insert
l_insert_rows_txt := substr(l_extra,1,instr(l_extra,' ')); -- grab text up to the first space
--
if instr(l_insert_rows_txt,'/') > 1 then
l_insert_rows_txt := substr(l_insert_rows_txt,1,instr(l_insert_rows_txt,'/')-1); -- the insert row count
l_insert_rows_txt := trim(l_insert_rows_txt);
end if;
l_extra := trim(l_extra);
if length(l_extra) > 0 and length(l_insert_rows_txt) > 0 then
l_extra := substr(l_extra,length(l_insert_rows_txt));
l_extra := trim(l_extra);
end if;
l_insert_rows_txt := trim(l_insert_rows_txt);
if instr(l_insert_rows_txt,' ') > 0 then
l_insert_rows_txt := substr(l_insert_rows_txt,1,instr(l_insert_rows_txt,' ')-1); -- get first word
end if;
l_insert_rows_txt := replace(l_insert_rows_txt,' ',null);
l_insert_rows_txt := replace(l_insert_rows_txt,chr(10),null);
l_insert_rows_txt := replace(l_insert_rows_txt,chr(13),null);
l_insert_rows_txt := replace(l_insert_rows_txt,',',null); -- replace commas
l_insert_rows_txt := replace(l_insert_rows_txt,'.',null); -- replace dots
if l_insert_rows_txt is null then
l_insert_example := 1;
else
begin
l_insert_example := to_number(l_insert_rows_txt);
exception when others then
l_insert_example := 1;
end;
end if;
l_new_string := substr(l_new_string,1,instr(l_new_string,'/INSERT')-1); -- remove up until the slash insert
l_new_string := l_new_string || l_extra; -- retain additional options
else
l_insert_example := 0;
end if;
--
p_new_string := l_new_string;
p_insert_example := l_insert_example;
end extract_insert;
Procedure extract_select (
p_string in varchar2 default null,
p_new_string out varchar2,
p_select_example out varchar2
)
is
l_new_string varchar2(4000) := upper(p_string);
l_select_example varchar2(1) := 'N';
begin
if instr(l_new_string,'/SELECT') > 0 then
l_select_example := 'Y';
l_new_string := trim(replace(l_new_string,'/SELECT',null));
end if;
p_new_string := l_new_string;
P_select_example := l_select_example;
end extract_select;
-- do not load uploaded worksheet data
Procedure extract_noload (
p_string in varchar2 default null,
p_new_string out varchar2,
p_noload_ws_data out varchar2
)
is
l_new_string varchar2(4000) := upper(p_string);
l_noload_ws_data varchar2(1) := 'N';
begin
if instr(l_new_string,'/NOLOAD') > 0 then
l_noload_ws_data := 'Y';
l_new_string := trim(replace(l_new_string,'/NOLOAD',null));
end if;
p_new_string := l_new_string;
P_noload_ws_data := l_noload_ws_data;
end extract_noload;
-- allow inserts to be commented
procedure extract_uncomment (
p_string in varchar2 default null,
p_new_string out varchar2,
p_uncommented out varchar2
)
is
l_new_string varchar2(4000) := upper(p_string);
l_uncommented varchar2(1) := 'N';
begin
if instr(l_new_string,'/UNCOMMENTEXAMPLES') > 0 then
l_uncommented := 'Y';
l_new_string := trim(replace(l_new_string,'/UNCOMMENTEXAMPLES',null));
end if;
if instr(l_new_string,'/UNCOMMENT EXAMPLES') > 0 then
l_uncommented := 'Y';
l_new_string := trim(replace(l_new_string,'/UNCOMMENT EXAMPLES',null));
end if;
if instr(l_new_string,'/UNCOMMENTED') > 0 then
l_uncommented := 'Y';
l_new_string := trim(replace(l_new_string,'/UNCOMMENTED',null));
end if;
if instr(l_new_string,'/UNCOMMENT') > 0 then
l_uncommented := 'Y';
l_new_string := trim(replace(l_new_string,'/UNCOMMENT',null));
end if;
p_new_string := l_new_string;
p_uncommented := l_uncommented;
end extract_uncomment;
procedure extract_data_load (
p_string in varchar2 default null,
p_new_string out varchar2,
p_data_load out varchar2
)
is
l_new_string varchar2(4000) := upper(p_string);
l_data_load varchar2(255) := null;
i integer := 0;
begin
i := instr(l_new_string,'@');
if i > 0 then
l_new_string := substr(p_string,1,i-1);
l_data_load := substr(p_string,i+1);
if instr(l_data_load,'/') > 0 then
l_data_load := trim(substr(l_data_load,1,instr(l_data_load,'/')-1));
l_new_string := l_new_string||' '||trim(substr(l_data_load,instr(l_data_load,'/')+1));
end if;
end if;
p_new_string := l_new_string;
p_data_load := replace(replace(l_data_load,chr(13),null),chr(10),null);
end extract_data_load;
--
-- help syntax in HTML
--
function get_pound_options return varchar2
is
begin
return '<p>You can use inline settings to explicitly set SQL syntax generation options.
You can also set options for your session using the user interface.
Using explicit settings ensure the same SQL generation options when sharing SQL scripts.
These options must be on a new line beginning with a # in the first character of the line.
All values are case insensitive.
To have all settings generated use <strong># verbose: true</strong>.
Bracket characters and commas are added for clarity but are ignored.
</p>
<table class="u-Report u-Report--stretch">
<tr><th>Setting</th><th>Description</th><th>Example</th></tr>
<tr><td>APEX</td><td>This setting controls the syntax generated when defaulting database users.
Specifically if you enable audit columns (<strong># auditcols</strong>) additional columns will be added to your table with trigger logic to maintain the value.
When set to <strong>No</strong>, the default, the pseudo column <strong>user</strong> is used to log audit information.
When set to <strong>Yes</strong> the user value is maintained using the following function (nvl(sys_context(''APEX$SESSION'',''APP_USER''),user)).
Valid values are <strong>Y</strong> and <strong>N</strong>.
You can also use <strong># apex</strong> syntax and it will equivalent to <strong># apex: true</strong>.
</td><td># apex: true</td></tr>
<tr><td>API</td><td>Generate PL/SQL APIs on all tables, values are <strong>Y</strong> and <strong>N</strong>.
You can specify <strong># api</strong> and it will be equivalent to <strong># api=y</strong>.
</td><td># api: true</td></tr>
<tr><td>AUDITCOLS</td><td>Add additional created, created_by, updated and updated_by columns to every table created.
Valid values are <strong>Y</strong> and <strong>N</strong>.
You can specify <strong># auditcols</strong> and it will be equivalent to <strong># auditcols: true</strong>.
</td><td># auditcols: true</td></tr>
<tr><td>COMPRESS</td><td>Compress all tables created.
Valid values are <strong>true</strong> and <strong>false</strong>.
The default is <strong>N</strong>.
You can specify <strong># compress</strong> and it will be equivalent to <strong># compress: true</strong>.
</td><td># compress: true</td></tr>
<tr><td>CREATEDBYCOL</td><td>When enabling Audit columns use this setting to override default audit column names.
The default column name to track the user who created a row is <strong>created_by</string>.
</td><td># createdByCol: created_by_user</td></tr>
<tr><td>CREATEDCOL</td><td>When enabling Audit columns use this setting to override default audit column names.
The default column name to track the date of a row being created is <strong>created</string>.
</td><td># created_dt: created_dt</td></tr>
<tr><td>DATE</td><td>By default all date datatypes should use this datatype. Valid values include
<strong>date</strong>,
<strong>timestamp</strong>,
<strong>timestamp with time zone</strong>,
<strong>TSWTZ</strong>,
<strong>timestamp with local time zone</strong>,
<strong>TSWLTZ</strong>.
</td><td># date: "timestamp with local time zone"</td></tr>
<tr><td>DB</td><td>Specify the database version the syntax should be compatible with 11g or 12c. The default is 12c.</td><td># db: "12c"</td></tr>
<tr><td>DROP</td><td>Include commands to drop each database object created.
Valid values are <strong>true</strong> and <strong>false</strong>. The default is <strong>false</strong>.
You can specify <strong># drop</strong> and it will be equivalent to <strong># drop: false</strong>.
</td><td># drop: true</td></tr>
<tr><td>EDITIONABLE</td><td>Create triggers and packages as editionable.
Valid values are <strong>true</strong> and <strong>false</strong>. The default is <strong>false</strong>.
</td><td># editionable: true</td></tr>
<tr><td>HISTORY</td><td>Maintain a history of column value changes in a history table.
Triggers will be created to store old and new values on each update.
On delete all not null columns will also be archived to the history table using a trigger.
Valid values are <strong>true</strong> and <strong>false</strong>. The default is <strong>false</strong>.
You can specify <strong># history</strong> and it will be equivalent to <strong># history: true</strong>.
</td><td># history: true</td></tr>
<tr><td>INSERTS</td><td>Generate insert statements for all tables.
The default is <strong>0</strong>.
By default the insert statements will be commented out use <strong>uncomment</strong> to not comment the generated insert statements.
If you wish to control insert statement count per table specify <strong>/insert</strong> at the table level and do not set this value.
</td><td># inserts: 4</td></tr>
<tr><td>LANGUAGE</td><td>Generate insert statements using this language.
The default is <strong>EN</strong> (English). Supported languages include strong>DE</strong> (German), strong>KO</strong> (Korean), strong>JA</strong> (Japanese).
</td><td># language: 4</td></tr>
<tr><td>LONGID</td><td>Specify if you want to allow longer identifiers to be used for database object names.
If this value is <strong>false</strong> then the maximum length of an object name is restricted to 30 characters.
Longer identifiers allow object names to be up to 128 characters in length.
Valid values are <strong>true</strong> and <strong>false</strong>. The default is <strong>false</strong>.
Use of this option requires database 12c. Database 12c is the default database version for this application.
</td><td># longid: true</tr>
<tr><td>LongVC</td><td>Specify if you want to allow longer identifiers to be used for database object names.
If this value is <strong>false</strong> then the maximum length a varchar2 column datatype will be 4,000 characters.
Longer Varchars allow object datatypes to be up to 32,767 characters in length.
Valid values are <strong>true</strong> and <strong>false</strong>. The default is <strong>false</strong>.
Use of this option requires database 12c. Database 12c is the default database version for this application.
</td><td># longvc: true</tr>
<tr><td>ONDELETE</td><td>Foreign key should perform the following on delete, valid values are CASCADE, RESTRICT and SET NULL.
Use this option to determine how your foreign keys are to be generated.
The default is <strong>CASCADE</strong>
</td><td># ondelete: "cascade"</td></tr>
<tr><td>OVERRIDESETTINGS</td><td>Resets all application settings to default values.
It ignores any application settings currently active for your session.
Use <strong># overrideSettings: true</strong> above your script content to ensure consistent generation options.
Similar to <strong># resetsettings</strong> control except this setting has true and false settings.
</td><td># overrideSettings: true</td></tr>
<tr><td>PK</td><td>Determines how the primary key will be set, valid values include <strong>TRIG</strong>
(for set by trigger) or <strong>IDENTITY</strong> (set declaratively).</td><td># pk: "identify"</td></tr>
<tr><td>PREFIX</td><td>Database object prefix. An underscore will be appended if not provided.
Use this to namespace a collection of tables and database objects.</td><td># prefix: "foo"</td></tr>
<tr><td>PREFIXPKWITHTNAME</td><td>Prefix Primary Key columns with name of table.
For example the primary key of the employees table would be employee_id. Valid values are <strong>Yes</strong> and <strong>No</strong>, default is <strong>No</strong>.
</td><td># prefixPKwithTname: "Yes"</td></tr>
<tr><td>PK</td><td>Automatically generate an ID primary key column for each table.
Valid values are <strong>true</strong> and <strong>false</strong>. The default is <strong>true</strong>.
</td><td># pk: true</td></tr>
<tr><td>RESETSETTINGS</td><td>Resets all application settings to default values.
It ignores any application settings currently active for your session.
Use <strong># resetsettings </strong> above your script content to ensure consistent generation options.
Similar to <strong># overrideSettings: true</strong> control except this setting does not have a false setting.
</td><td># resetsettings</td></tr>
<tr><td>ROWKEY</td><td>For each table add a row_key column that generates an alphanumeric identifier based on a sequence.
Valid values are <strong>true</strong> and <strong>false</strong>. The default is <strong>false</strong>.
</td><td># rowkey: true</td></tr>
<tr><td>SECURITYGROUPID</td><td>For each table add a security_goup_id column to support mutil-tenant applications.
Valid values are <strong>true</strong> and <strong>false</strong>. The default is <strong>false</strong>.
</td><td># securitygroupid: true</td></tr>
<tr><td>ROWVERSION</td><td>For each table add a row version column that increments by 1 for each update.
Valid values are <strong>true</strong> and <strong>false</strong>. The default is <strong>false</strong>.
</td><td># rowversion: true</td></tr>
<tr><td>SELECTS</td><td>Generate select statements for all tables.
The default is <strong>false</strong>.
By default the SQL select statements will be commented out use <strong>uncomment</strong> to not comment the generated select statements.
If you wish to control select statement generation per table specify <strong>/select</strong> at the table level and do not set this value.
</td><td># select: true</td></tr>
<tr><td>SCHEMA</td><td>Prefix object names with a schema name.
Sometimes it is useful to have object names fully prefixed with schema names.
The default is no schema prefix for object names.
</td><td># schema: "scott"</td></tr>
<tr><td>TAGS</td><td>If <strong>tags</strong> are enabled then framework tables, triggers, and a <strong>TAGS_SYNC</strong> procedure will be generated.
All tables with a column named <strong>TAGS</strong> will have logic in a trigger to maintain counts of tags by tables.
The summarized tag information will be maintained in 3 tables, <strong>tags</strong>, <strong>tags_sum</strong>, and <strong>tags_tsum</strong>.
The <strong>tags</strong> table maintains a list of each tag and its tables associated primary key.
The <strong>tags_sum</strong> maintains a count of tag occurrences by tag.
The <strong>tags_tsum</strong> maintains a count of tag occurrences by tag and table.
The default is <strong>false</strong>.
</td><td># tags: true</td></tr>
<tr><td>UNCOMMENT</td><td>Generate insert or select statements as comments if value is <strong>true</strong>.
If values is <strong>false</strong> then do not comment the insert or select statements.
The default is <strong>false</strong>.
</td><td># uncomment: true</td></tr>
<tr><td>UPDATEDBYCOL</td><td>When enabling Audit columns use this setting to override default audit column names.
The default column name to track the user who updates a row is <strong>updated_by</string>.
</td><td># updatedByCol: updated_by_user</td></tr>
<tr><td>UPDATEDCOL</td><td>When enabling Audit columns use this setting to override default audit column names.
The default column name to track the date a row is updated is <strong>updated</string>.
</td><td># updatedCol: updated_dt</td></tr>
<tr><td>Verbose</td><td>Will show all settings, not just settings that are different from the default.
Valid values are <strong>true</strong> and <strong>false</strong>. The default is <strong>false</strong>.
</td><td># verbose: true</td></tr>
</table>';
end get_pound_options;
function get_view_syntax return varchar2
is
begin
return '<p>Enter <strong>view</strong> as unindented text, then specify the view name, then a list of tables.</p>
<pre>view [view_name] [table name] [table name]...</pre>
<p>Ensure the view name contains no spaces, ensure the table names contain no spaces.
Delimit table names by a space or comma.
Example:
<pre>
dept
dname
loc
emp
ename
job
view dept_emp emp dept
</pre>
';
end get_view_syntax;
function get_rules return varchar2
is
begin
return '<p>Enter parent table names without any indention.
Enter table columns with a uniform indention of 3 or more spaces.
Generally its best to not specify primary keys, the system will generate them for you.
Parent child relationships are created simply by indenting child tables under parent tables.</p>
<p>Datatypes typically default to VARCHAR2, if you want a column of a different datatype add a space NUM, INT, DATE to the end of a column name.
Based on the english text contained in the column name, and in the absence of any datatype specified the system will make some guesses.
For example if the column name contains the word DATE then it will be of a date data type.
If you want to specify a specific VARCHAR2 length enter VCn where "n" is the length of the VARCHAR2.
Click the <strong>Syntax</strong> button to show available syntax.
Object names will be automatically formatted underscores so you can use spaces in column and table names.</p>
<p>Click the <strong>Settings</strong> button to view many generation options.
You can automatically add "Who Columns", e.g. who created or last updated a given row and when.
You can add a row sequence column that automatically increments by one on each row update.
A row sequence can be useful to simplify lost update detection.
A PL/SQL API can also be generated which provides a package per table and provides procedures to query, insert, update, and delete rows.
Some applications benifit by having each change captured in a history table, logging of old and new values. This is also an option.
</p>';
end get_rules;
function get_column_datatypes return varchar2
is
begin
return '<table class="u-Report u-Report--stretch">
<tr><td>default (enter nothing)</td><td>The datatype will default to various sized varchar2 or other datatypes depending on the column name.
If <strong>date</strong> appears in the column name it will be assumed to be a date.
If <strong>photo</strong> or <strong>file</strong> appears in the column name it will be assumed to be a blob.
If the column name is <strong>email</strong> or <strong>name</strong> the datatype will be varchar2(255) unless otherwise specified.
</td></tr>
<tr><td>num, number</td><td>number</td></tr>
<tr><td>int, integer</td><td>integer</td></tr>
<tr><td>d, date</td><td>date</td></tr>
<tr><td>ts, timestamp</td><td>timestamp</td></tr>
<tr><td>tstz, tswtz, timestamp with local time zone</td><td>timestamp with local time zone</td></tr>
<tr><td>char, vc, varchar, varchar2, string</td><td>varchar2(4000)</td></tr>
<tr><td>vcNNN <i>(where NNN is a number)</i></td><td>varchar2(NNN)</td></tr>
<tr><td>vc(NNN) <i>(where NNN is a number)</i></td><td>varchar2(NNN)</td></tr>
<tr><td>vc32k</td><td>varchar2(32767), requires longer varchars to be set to <strong>Yes</strong> and database to be set to <strong>12c</strong> or better.</td></tr>
<tr><td>clob</td><td>CLOB</td></tr>
<tr><td>blob</td><td>BLOB</td></tr>
<tr><td>file</td><td>BLOB _filename, _charset, _mimetype, _lastupd columns</td></tr>
</table>';
end get_column_datatypes;
function get_column_directives return varchar2
is
begin
return '<table class="u-Report u-Report--stretch">
<tr><td>/idx, /index, /indexed</td><td>Will create a non unique index on the associated column.</td></tr>
<tr><td>/unique</td><td>Creates a unique constraint.</td></tr>
<tr><td>/check</td><td>Creates a check constraint with with comma or white space delimited values e.g. /cc Y N</td></tr>
<tr><td>/constant</td><td>When generating random data for a table set this column to a constant value, quotes will be added if needed.</td></tr>
<tr><td>/values</td><td>Comma separated list of values to use when generating random data. For example /values 1, 2, 3, 4 or /values Yes, No.</td></tr>
<tr><td>/upper</td><td>Forces column values to upper case.</td></tr>
<tr><td>/lower</td><td>Forces column values to lower case.</td></tr>
<tr><td>/mask</td><td>For use when loading date columns from a worksheet. For example <strong>/mask [ date format mask ]</strong></td></tr>
<tr><td>/nn, /not null</td><td>Adds a not null constraint on the column.</td></tr>
<tr><td>/between</td><td>Adds a between check constraint on the column.</td></tr>
<tr><td>/hidden, /invisible</td><td>Hidden columns are not displayed using select * from table.</td></tr>
<tr><td>/references, /reference, /fk</td><td>Foreign key references e.g. /references table_name. You can also reference tables that are not part of your model.</td></tr>
<tr><td>/pk</td><td>Identifies single column as table primary key. It is recommended not manually specify primary keys and let this app create them for you.</td></tr>
<tr><td>--, [ comments ]</td><td>Enclose comments using square brackets or using dash dash syntax.</td></tr>
<tr><td>@worksheet</td><td>Load data from this worksheet column.</td></tr>
</table>';
end get_column_directives;
function get_table_directives return varchar2
is
begin
return '<table class="u-Report u-Report--stretch">
<tr><td>/api</td><td>Generate PL/SQL package API to query, insert, update, and delete data within a table.</td></tr>
<tr><td>/audit</td><td>Adds Oracle auditing, by default audit all on table name.</td></tr>
<tr><td>/auditcols, /audit cols, /audit columns</td><td>Automatically adds an updated, updated_by, inserted, and inserted_by columns and
the trigger logic to populate.</td></tr>
<tr><td>/compress, /compressed</td><td>Table will be created compressed.</td></tr>
<tr><td>/history</td><td>Generate code to log changes into a history table for this specific table.</td></tr>
<tr><td>/insert NN</td><td>Generate <strong>NN</strong> SQL INSERT statement(s) with random data.</td></tr>
<tr><td>/noload</td><td>For uploaded worksheet data only, specify <strong>/noload</strong> at the table level to not load worksheet data.
By default worksheet data will generate SQL insert statements to load worksheet data.</td></tr>
<tr><td>/select</td><td>Generate SQL SELECT statement.</td></tr>
<tr><td>/rest</td><td>Generate REST enablement of the table using Oracle REST Data Services (ORDS).</td></tr>
<tr><td>/uncomment, /uncommented</td><td>If <strong>Yes</strong> will cause generated SELECT or INSERT SQL statements to not be commented.
Reference /insert and /select.</td></tr>
<tr><td>@worksheet</td><td>Load data from this uploaded worksheet.</td></tr>
</table>';
end get_table_directives;
function get_additional_syntax return varchar2
is
begin
return '<table class="u-Report u-Report--stretch">
<tr><td>--</td><td>start lines with a -- for comments</td></tr>
</table>';
end get_additional_syntax;
function get_example_desc (p_number in number default 1) return varchar2
is
begin
if p_number = 1 then return 'This is an example of a two table data model with the <strong>employees</strong> table as an implicit
child table of the <strong>departments</strong> table.
The <strong>employees</strong> table is identified as a child table by uniformly indenting it under the <strong>departments</strong> table.
The primary and foreign keys are automatically be added, and not specified using the markdown syntax.
The <strong>vc50</strong> column suffix is short-hand for <strong>varchar2(50)</strong>, and <strong>num</strong> is short-hand for <strong>number</strong>.
The <strong>/nn</strong> generates a not null column constraint.
The <strong>/lower</strong> will generate a trigger to force the <strong>ename</strong> column values to lower case.
The <strong>/insert</strong> will generate SQL inserts to be generated with random data for the given table.';
elsif p_number = 2 then return 'This example is a two table data model with table columns identified as indented text.
By default a primary key <strong>ID</strong> column will be added to each table, thus no need to specify the primary key column.
Foreign keys will be automatically detected for any column that ends in <strong>ID</strong>.
Spaces in table or column names will be automatically converted to underscores.
By default datatypes will be varchar2, however you can use shorthand syntax to control the datatype, in this example the <strong>cost center</strong>
column is set to be an integer.';
elsif p_number = 3 then return 'This example highlights a four table data model and the <strong>/upper</strong>, <strong>/lower</strong>,
<strong>/indexed</strong>, <strong>/nn</strong> syntax.
The <strong>/nn</strong> generates a not null column constraint.
The <strong>/lower</strong> forces column values to lower case.
The <strong>/default</strong> will set the default value to the upper case value specified.
The <strong>/insert</strong> will cause SQL insert statements to be generated.
The <strong>emp projects map</strong> is mapping table which facilitates a many to many relationship between the <strong>employees</strong>
table and the <strong>projects</strong> table.
The <strong>/check</strong> will create a check constraint that will limit the values of the <strong>status</strong> column to specific values.';
elsif p_number = 4 then return 'This example shows four levels of table nesting using indentation syntax.
The <strong>customers</strong> table is the parent table and includes a child, grandchild and great grandchild table.
The <strong>/nn</strong> column short-hand syntax to generate a not null check constraint.
The square brackets or dash dash will generate table or column comments.
The <strong>/check</strong> syntax generates a column check constraint to constrain valid column values.
The <strong># RowVersion: true</strong> setting will override your current settings and will generate a <strong>row_version</strong> column and the
trigger logic to maintain the value.
The <strong>#TAGS: true</strong> will cause a tags framework that maintains tables of tag counts.';
elsif p_number = 5 then return 'Parent <strong>projects</strong> table with 4 child tables, <strong>milestones</strong>, <strong>links</strong>,
<strong>attachments</strong>, <strong>action items</strong>.
The <strong>/check</strong> will generate a column check constraint for space delimited values.
The <strong>/values</strong> will when generating data generate a random value of available values. Repeating a value will increase its chances of being randomly selected.
Uses <strong>/history</strong> to maintain history of changes to <strong>milestones</strong> table.
The #options override any application settings. <strong>#APEX</strong> will populate audit information using the application user if available.
The <strong># auditcols: true</strong> will generate per table audit columns.';
elsif p_number = 6 then return 'Example of parent table with many child tables and an example referencing the owners table using the <strong>owner ID</strong>.
Note the foreign key reference is detected because it ends with <strong>ID</strong> and it corresponds to another table name.
So <strong>owner id</strong> in the <strong>action items</strong> table matched the <strong>owners</strong> table.
This also shows the ability for automatic foreign key detection even when the referenced table name is plural and foreign key column is singular.';
elsif p_number = 7 then return 'In this example the <strong>restaurants</strong> table has child tables defined before additional
<strong>restaurants</strong> table columns.
It highlights the ability to add a child table inline within a list of columns.
A view will be created and 60 rows will be inserted into 3 different tables.
The <strong>/nn</strong> ensures the column is not null.
The <strong>/values</strong> is a directive to the random data generation to use one of the comma separated values.';
elsif p_number = 8 then return 'This example shows REST enablement via Oracle REST Data Services (ORDS).
Using <strong>/rest</strong> on the same line as a table will cause a PL/SQL anonymous block to be generated that enables REST operations on the specific table.
Once RESTfully enabled the table becomes accessible via URI.
Review Oracle ORDS documentation for more information.
The /auditcols will automatically add <strong>update</strong>, <strong>updated_by</strong>, <strong>created</strong> and <strong>created_by</strong>
columns and the trigger logic to set their values.';
elsif p_number = 9 then return 'This example attempts to use one of everything.';
else
return null;
end if;
end get_example_desc;
function get_example (p_number in number default 1) return varchar2
is
begin
if p_number = 1 then return 'departments /insert 4
name /nn
location
employees /insert 14
name /nn vc50
email /lower
cost center num
date hired
job
view emp_v departments employees';
elsif p_number = 2 then return 'departments
name
location
employees
department id
name
email
cost center int
date hired
job';
elsif p_number = 3 then return 'departments /insert 4
name /nn
location /default nyc
employees /insert 10 /select
first name /nn
last Name /nn /indexed
email /nn /lower
date hired
job vc10
cost center /upper /constant CR10
projects /insert 12
name /nn
start date date
status /check open closed
priority integer /between 1 and 3
url
description
functional spec file
emp proj map /insert 20
employee id
project id
role /values programmer, manager, specialist, operations
view emp_proj_v employees departments emp_proj_map projects';
elsif p_number = 4 then return '# rowVersion: true, tags: true
customers [All external customers] /insert 10
name /nn
country /nn
ship to address /nn
bill to address /nn
payment method /check cc, po, invoice, not_required
tags
orders [All orders placed by external customers] /insert 10
date of sale
total num
sales channel /check store, sales, trial_conversion
sale type /check subscription purchase
term type /check hourly monthly yearly perpetual
term length int
order line items /insert 50 -- Sum quantity and unit price to compute order total
product vc50 /nn
quantity num /nn
unit price num /nn
order li comments [Order line item specific comments] /insert 5
comment /nn [Free form comments on order lines]
view cust_orders_v customers orders order_line_items
';
elsif p_number = 5 then return '#apex: true, auditcols: true
projects /insert 5
name /nn
owner
milestones /history /insert 10
name
status /check open completed closed /values open, open, open, open, closed, completed
owner
started date
closed date
links /insert 5
name
url
attachments
contributed by
attachment file
action items /insert 12
action
desc clob
owner
status /check open completed closed
view project_ms projects milestones
view project_ai projects action_items';
elsif p_number = 6 then return 'owners
name /nn
email
role
projects
name /nn
owner id
description
milestones
name
status /check open completed closed
owner id
started date
closed date
milestone updates
ms update
update date date
links
name
url
attachments
contributed by
attachment file
action items
action
desc clob
owner id
status /check open completed closed';
elsif p_number = 7 then return 'restaurants /insert 10
name /nn
locations /insert 20
coord vc30
street
city
state vc2 /values NY, NJ, CT, CA, TX, VT, VA, MD, AK
zip code
country /default us
grades /insert 30
location id
date
grade /check a, b, c, d, e
score int
cuisine /values Tsai, Chinese, Mexican, American, Sushi, French, Korean, Italian
price_scale vc30
stars int /check 1 2 3 4 5
view restaurant_grades_v restaurants locations grades';
elsif p_number = 8 then return '
people /rest /auditcols
name /nn
email
tracks /rest
name
tags
events /rest
name /nn
region
country
city
details
event start date
length in days int
event_coverage /rest
person id /fk people';
elsif p_number = 9 then return 'Example 1 /audit /api /auditcols /compress [example of various column options]
a /pk
b /default foo
c /unique
d /upper
e /lower
f [this is a comment]
g vc30
h num
i int
j clob
k blob
l date
m ts
n tswtz
o tswltz
p d
q /nn
r /not null
s /index
t /indexed
u /idx
v /hidden
w /invisable
x /invisible
y file
z string(100)
example 2 -- table comment using dash dash style
a /references example 1
b
long column name that is longer then 30 characters date
many spaces
MiXeD CaSe
special characters !@#$%^&*()-+=x
"quoted identifier"
column comments -- this is a comment
multiple____underscores
11111 leading number column
create [ note that create is a reserved word]
insert
c varchar2(300)
d number,
e varchar(400),
f timestamp with timezone
g timestamp with time zone
-- comments not associated with a table or column';
else return 'No such example';
end if;
end get_example;
--
-- determine datatype of generated column
--
function get_data_type (
p_col_name in varchar2 default null,
p_date_data_type in varchar2 default 'DATE')
return varchar2
is
begin
if instr(upper(p_col_name), 'NUMBER') > 0 then
return 'NUMBER';
elsif upper(p_col_name) like '%_ID' then
return 'NUMBER';
elsif upper(p_col_name) like '%_YN' then
return 'VARCHAR2(1)';
elsif instr(upper(p_col_name), 'DATE') > 0 then
return p_date_data_type;
elsif instr(upper(p_col_name), 'CREATED') > 0 then
return p_date_data_type;
elsif instr(upper(p_col_name), 'UPDATED') > 0 then
return p_date_data_type;
elsif instr(upper(p_col_name), 'EMAIL') > 0 or instr(upper(p_col_name), 'E_MAIL') > 0 then
return 'VARCHAR2(255)';
elsif instr(upper(p_col_name), 'STREET') > 0 or instr(upper(p_col_name), 'STREET') > 0 then
return 'VARCHAR2(255)';
elsif instr(upper(p_col_name), 'CITY') > 0 or instr(upper(p_col_name), 'CITY') > 0 then
return 'VARCHAR2(255)';
elsif instr(upper(p_col_name), 'STATE') > 0 or instr(upper(p_col_name), 'STATE') > 0 then
return 'VARCHAR2(255)';
elsif instr(upper(p_col_name), 'ZIP_CODE') > 0 or instr(upper(p_col_name), 'ZIP') > 0 then
return 'VARCHAR2(30)';
elsif instr(upper(p_col_name), 'STATUS') > 0 or instr(upper(p_col_name), 'STATUS') > 0 then
return 'VARCHAR2(60)';
elsif instr(upper(p_col_name), 'PHONE') > 0 then
return 'VARCHAR2(30)';
elsif instr(upper(p_col_name), 'NAME') > 0 then
return 'VARCHAR2(255)';
elsif upper(p_col_name) like 'BOROUGH' then
return 'VARCHAR2(30)';
else
return 'VARCHAR2(4000)';
end if;
end get_data_type;
--
-- determine column options
--
procedure determine_column_options (
p_column in varchar2 default null,
p_table in varchar2 default null,
p_revised_column out varchar2,
p_not_null out varchar2,
p_is_indexed out varchar2,
p_check_constraints out varchar2,
p_upper_lower out varchar2,
p_is_unique out varchar2,
p_default out varchar2,
p_between out varchar2,
p_hidden out varchar2,
p_references out varchar2,
p_pk out varchar2,
p_check_values out varchar2,
p_data_load out varchar2,
p_values out varchar2,
p_format_mask out varchar2,
p_constant out varchar2
)
is
l integer; -- length of column
x varchar2(255); -- revised column name
i1 integer := 0;
i2 integer := 0;
l_not_null varchar2(1) := null; -- Y or null
l_is_indexed varchar2(1) := null; -- Y or null
l_upper_lower varchar2(1) := null; -- Y or N or null
l_check_constraints varchar2(4000) := null; -- full check syntax or null
l_is_unique varchar2(1) := null; -- Y or null
l_default varchar2(4000) := null; -- actual default clause
l_between varchar2(4000) := null; -- between check constraint
l_check_values varchar2(4000) := null;
l_date_format_mask varchar2(100);
function check_slash(p_string in varchar2 default null) return varchar2
is
begin
if instr(x,'/'||upper(p_string)) > 0 then
x := trim(replace(x,'/'||upper(p_string),null));
return 'Y';
else
return null;
end if;
end;
-- get check constraint
function cc (
p_string in varchar2 default null,
p_tname in varchar2 default null)
return varchar2
is
y varchar2(4000) := null;
i integer := 0;
n varchar2(128) := null; -- table name
c varchar2(128) := null; -- column name
begin
l_check_values := null;
i := NVL(instr(x,'/'||upper(p_string)),0);
if i > 2 then
y := substr(x,i+length(p_string)+2);
y := trim(y);
x := trim(substr(x,1,i-1));
--
-- format in check constraint
--
if instr(y,',') = 0 then
-- only replace spaces with commas if commas are not used
y := trim(replace(y,' ',','));
end if;
for j in 1..20 loop y := replace(y,',,',','); end loop; -- remove double commas
y := regexp_replace( y, '\s*,\s*', ',' );
y := replace(y,',',''''||','||'''');
if substr(y,1,1) != '''' then y := ''''||y; end if; -- add leading quote
if substr(y,length(y),1) != '''' then y := y||''''; end if; -- add trailing quote
--for j in 1..5 loop y := replace(y,'''''',''''); end loop; -- remove double quotes
y := regexp_replace(y,'''{2,}',''''); -- remove double quotes
if upper(x) like '% NUM' or upper(x) like '% NUMBER(%)' or upper(x) like '% NUMBMER' or upper(x) like '% INT' or upper(x) like '% INTEGER' then
-- number colummn so remove quotes
y := replace(y,'''',null);
end if;
c := validate_object_name(scrub_col_data_types(trim(x)));
if replace(translate(c,'0123456789','0000000000'),'0',null) like '%_VC' then
-- c := substr(c,1,instr(c,'_VC')-1);
c := regexp_replace(c, '_+VC\d+$','');
end if;
n := clean_name(p_tname)||'_';
l_check_values := y;
y := ' constraint '||gen_valid_identifier_name(c,'CC',n)||chr(10)||' '||'check ('||lower(c)||' in ('||y||'))';
return y;
else
return null;
end if;
end cc;
-- default clause
function def(p_string in varchar2 default null) return varchar2
is
y varchar2(4000) := null;
i integer := 0;
begin
i := NVL(instr(x,'/'||upper(p_string)),0);
if i > 2 then
y := substr(x,i+length(p_string)+2);
y := trim(y);
x := trim(substr(x,1,i-1));
--
y := trim(y);
return y;
else
return null;
end if;
end def;
-- between
function get_between return varchar2
is
y varchar2(4000) := null;
i integer := 0;
begin
i := NVL(instr(x,'/BETWEEN'),0);
if i > 2 then
y := substr(x,i+7+2);
y := trim(y);
x := trim(substr(x,1,i-1));
--
y := trim(y);
if instr(y,'/') > 0 then
y := substr(y,1,instr(y,'/')-1);
end if;
return lower(y);
else
return null;
end if;
end get_between;
-- references
function get_references return varchar2
is
y varchar2(4000) := null; -- reference constraint
i integer := 0;
begin
-- also remove references clause from x string
i := NVL(instr(x,'/REFERENCES'),0);
if i > 2 then
y := substr(x,i+10+2); -- references clause to end of string
y := trim(y);
x := trim(substr(x,1,i-1)); -- everything up to the tag
--
y := trim(y);
if instr(y,'/') > 0 then
x := x||' '||substr(y,instr(y,'/')); -- return any additional slash clause
y := substr(y,1,instr(y,'/')-1); -- trim additional slash clause
end if;
if y is not null then
-- format manually provided foreign key
y := replace(y,' ','_');
y := ltrim(y,'_');
y := rtrim(y,'_');
for i in 1..10 loop y := replace(y,'_(','('); end loop;
end if;
return y;
else
return null;
end if;
end get_references;
-- reference
function get_reference return varchar2
is
y varchar2(4000) := null; -- reference constraint
i integer := 0;
begin
-- also remove references clause from x string
i := NVL(instr(x,'/REFERENCE'),0);
if i > 2 then
y := substr(x,i+9+2); -- references clause to end of string
y := trim(y);
x := trim(substr(x,1,i-1)); -- everything up to the tag
-- format
y := trim(y);
if instr(y,'/') > 0 then
x := x||' '||substr(y,instr(y,'/')); -- return any additional slash clause
y := substr(y,1,instr(y,'/')-1); -- trim additional slash clause
end if;
if y is not null then
-- format manually provided foreign key
y := replace(y,' ','_');
y := ltrim(y,'_');
y := rtrim(y,'_');
for i in 1..10 loop y := replace(y,'_(','('); end loop;
end if;
return y;
else
return null;
end if;
end get_reference;
-- foreign key
function get_fk return varchar2
is
y varchar2(4000) := null; -- reference constraint
i integer := 0;
begin
-- also remove references clause from x string
i := NVL(instr(x,'/FK'),0);
if i > 2 then
y := substr(x,i+2+2); -- references clause to end of string
y := trim(y);
x := trim(substr(x,1,i-1)); -- everything up to the tag
-- format
y := trim(y);
if instr(y,'/') > 0 then
x := x||' '||substr(y,instr(y,'/')); -- return any additional slash clause
y := substr(y,1,instr(y,'/')-1); -- trim additional slash clause
end if;
if y is not null then
-- format manually provided foreign key
y := replace(y,' ','_');
y := ltrim(y,'_');
y := rtrim(y,'_');
for i in 1..10 loop y := replace(y,'_(','('); end loop;
end if;
return y;
else
return null;
end if;
end get_fk;
-- primary key
function get_pk return varchar2
is
y varchar2(4000) := null; -- reference constraint
i integer := 0;
begin
i := NVL(instr(x,'/PK'),0);
if i > 2 then
y := substr(x,i+2+2); -- references clause to end of string
y := trim(y);
x := trim(substr(x,1,i-1)); -- everything up to the tag
--
-- format
--
y := trim(y);
if instr(y,'/') > 0 then
x := x||' '||substr(y,instr(y,'/')); -- return any additional slash clause
end if;
return 'Y';
else
return null;
end if;
end get_pk;
-- worksheet references @column_name
function ws_ref return varchar2
is
y varchar2(4000) := null;
i integer := 0;
begin
i := NVL(instr(x,'@'),0);
if i > 2 then
y := substr(x,i+1);
y := trim(y);
x := trim(substr(x,1,i-1)); -- revised column name
--
y := trim(y);
if instr(y,'/') > 0 then
x := x||' '||trim(substr(y,instr(y,'/')+0)); -- put back any suffix
y := trim(substr(y,1,instr(y,'/')-1));
end if;
return y; -- worksheet reference
else
return null;
end if;
end ws_ref;
-- get data generation values
function get_values return varchar2
is
y varchar2(4000) := null;
i integer := 0;
begin
i := NVL(instr(x,'/VALUES'),0);
if i > 2 then
y := substr(x,i+6+2); -- start of string
y := trim(y);
x := trim(substr(x,1,i-1)); -- revised column name
--
if instr(y,'/') > 0 then
x := x||' '||trim(substr(y,instr(y,'/')+0)); -- put back any suffix
y := trim(substr(y,1,instr(y,'/')-1));
end if;
return y; -- worksheet reference
else
return null;
end if;
end get_values;
-- get the date format mask for generating inserts that are date or timestamp
function get_date_format_mask return varchar2
is
y varchar2(4000) := null;
i integer := 0;
begin
i := NVL(instr(x,'/MASK'),0);
if i > 2 then
y := substr(x,i+4+2); -- start of string
y := trim(y);
x := trim(substr(x,1,i-1)); -- revised column name
if instr(y,'/ ') > 0 then
x := x||' '||trim(substr(y,instr(y,'/')+0)); -- put back any suffix
y := trim(substr(y,1,instr(y,'/')-1));
end if;
return y; -- date format mask
else
return null;
end if;
end get_date_format_mask;
-- get constant for data loading
function get_constant return varchar2
is
y varchar2(4000) := null;
i integer := 0;
begin
i := NVL(instr(x,'/CONSTANT'),0);
if i > 2 then
y := substr(x,i+8+2); -- start of string
y := trim(y);
x := trim(substr(x,1,i-1)); -- revised column name
if instr(y,'/') > 0 then
x := x||' '||trim(substr(y,instr(y,'/')+0)); -- put back any suffix
y := trim(substr(y,1,instr(y,'/')-1));
end if;
return y; -- worksheet reference
else
return null;
end if;
end get_constant;
begin
--
-- extract options into structured values returning column name as x
--
-- options include:
-- /nn
-- /not null
-- /indexed
-- /idx
-- /index
-- /unique
-- /upper
-- /lower
-- /check [some check constraint]
-- /default [ some default value]
-- /between [ between check constraint]
-- /hidden, /invisable
-- /references, /fk [ table name ]
-- /values
-- /constant
-- /mask [ date format mask ]
-- @reference_column
x := upper(p_column);
-- not null
p_not_null := check_slash('NN');
if NVL(p_not_null,'N') = 'N' then
p_not_null := check_slash('not null');
end if;
-- hidden
x := replace(x,'INVISABLE','INVISIBLE');
p_hidden := check_slash('hidden');
if NVL(p_hidden,'N') = 'N' then
p_hidden := check_slash('invisible');
end if;
-- indexed column
p_is_indexed := check_slash('indexed');
if NVL(p_is_indexed,'N') = 'N' then
p_is_indexed := check_slash('idx');
end if;
if NVL(p_is_indexed,'N') = 'N' then
p_is_indexed := check_slash('index');
end if;
-- upper or lower
p_upper_lower := null;
p_upper_lower := replace(check_slash('upper'),'Y','upper');
if p_upper_lower is null then
p_upper_lower := replace(check_slash('lower'),'Y','lower');
end if;
-- references
p_references := get_references;
if NVL(instr(upper(x),'/FK'),0) > 0 then
p_references := get_fk;
elsif NVL(instr(upper(x),'/REFERENCE'),0) > 0 then
p_references := get_reference;
end if;
-- primary key
p_pk := get_pk;
-- unique column constraint
p_is_unique := check_slash('unique');
-- between check constraint
l_between := get_between;
p_between := l_between;
-- values
p_values := get_values;
-- constant values for data loading
p_constant := get_constant;
-- date format mask
l_date_format_mask := get_date_format_mask;
p_format_mask := l_date_format_mask;
--
-- default and check constraints
-- assume they can be in any order so process trailing option first
--
i1 := NVL(instr(upper(x),'/CHECK'),0);
i2 := NVL(instr(upper(x),'/DEFAULT'),0);
if i1 > 0 and i2 > 0 and i2 > i1 then
p_default := def('default');
p_check_constraints := cc('check',p_table);
elsif i1 > 0 and i2 > 0 and i1 > i2 then
p_check_constraints := cc('check',p_table);
p_default := def('default');
elsif i1 > 0 then
p_check_constraints := cc('check',p_table);
elsif i2 > 0 then
p_default := def('default');
end if;
-- get worksheet at sign references
p_data_load := ws_ref;
--
p_check_values := l_check_values;
-- remove undetected slash options
if instr(x,'/') > 0 then
x := substr(x,1,instr(x,'/')-1);
end if;
p_revised_column := x;
end determine_column_options;
--
-- determine datatype of column using shortcut syntax
--
procedure determine_data_type2 (
p_column in varchar2 default null,
p_revised_column out varchar2,
p_datatype out varchar2)
is
l integer; -- length of column
l_column varchar2(255); -- raw column line of text
l_new_column varchar2(255); -- new name for column
l_data_type varchar2(255); -- data type of column
begin
l_column := trim(upper(p_column));
l_column := replace(l_column,chr(10),null);
l_column := replace(l_column,chr(13),null);
l_column := replace(l_column,unistr('\0009'),' ');
l_column := trim(l_column);
l_column := regexp_replace(l_column,'\s+',' ');
l_column := regexp_replace(l_column,'\s(VAR)?CHAR(2)?\s*\(','VARCHAR2(');
l_column := regexp_replace(l_column,'\sVC\s*32K','VARCHAR2(32767)');
l_column := regexp_replace(l_column,'\sVC\s*\(\s*32K\s*\)','VARCHAR2(32767)');
l_column := regexp_replace(l_column,'\sVC\s*(\d+)','VARCHAR2(\1)');
l_column := regexp_replace(l_column,'\sVC\s*\(\s*(\d+)\s*\)','VARCHAR2(\1)');
l_column := regexp_replace(l_column,'\sNUM(BER)?\s*\(','NUMBER(');
l_column := regexp_replace(l_column,'\sNUM(BER)?\s*(\d+)','NUMBER(\1)');
--
l_column := regexp_replace(l_column,'\sSTRING\s*\(\s*(\d+)\s*\)','VARCHAR2(\1)');
if l_column like '% STRING' then
l_column := substr(l_column,1,length(l_column)-7);
end if;
--
l := length(l_column);
if l_column like '%NUMBER(%)' then
l_new_column := substr(l_column,1,(instr(l_column,'NUMBER(')-1));
l_data_type := substr(l_column,instr(l_column,'NUMBER('));
elsif l_column like '%VARCHAR2(%)' then
l_new_column := substr(l_column,1,(instr(l_column,'VARCHAR2')-1));
l_data_type := substr(l_column,instr(l_column,'VARCHAR2'));
elsif l_column like '%TIMESTAMP WITH%TIME ZONE' then
l_new_column := substr(l_column,1,(instr(l_column,'TIMESTAMP WITH')-1));
l_data_type := substr(l_column,instr(l_column,'TIMESTAMP WITH'));
elsif l_column like '% NUMBER' then
l_new_column := substr(l_column,1,l-7);
l_data_type := 'NUMBER';
elsif l_column like '% NUM' then
l_new_column := substr(l_column,1,l-4);
l_data_type := 'NUMBER';
elsif l_column like '% LONG RAW' then
l_new_column := substr(l_column,1,l-9);
l_data_type := 'LONG RAW';
elsif l_column like '% RAW' then
l_new_column := substr(l_column,1,l-4);
l_data_type := 'RAW';
elsif l_column like '% DATE' then
l_new_column := substr(l_column,1,l-5);
l_data_type := 'DATE';
elsif l_column like '% TSWTZ' then
l_new_column := substr(l_column,1,l-6);
l_data_type := 'TIMESTAMP WITH TIME ZONE';
elsif l_column like '% TSTZ' then
l_new_column := substr(l_column,1,l-5);
l_data_type := 'TIMESTAMP WITH TIME ZONE';
elsif l_column like '% TSWLTZ' then
l_new_column := substr(l_column,1,l-7);
l_data_type := 'TIMESTAMP WITH LOCAL TIME ZONE';
elsif l_column like '% TSLTZ' then
l_new_column := substr(l_column,1,l-6);
l_data_type := 'TIMESTAMP WITH LOCAL TIME ZONE';
elsif l_column like '% TIMESTAMP WITH TIME ZONE' then
l_new_column := substr(l_column,1,l-25);
l_data_type := 'TIMESTAMP WITH TIME ZONE';
elsif l_column like '% TIMESTAMP' then
l_new_column := substr(l_column,1,l-10);
l_data_type := 'TIMESTAMP';
elsif l_column like '% VC' then
l_new_column := rtrim(substr(l_column,1,l-3),'_');
l_data_type := 'VARCHAR2(4000)';
elsif l_column like '% BLOB' then
l_new_column := substr(l_column,1,l-5);
l_data_type := 'BLOB';
elsif l_column like '% CLOB' then
l_new_column := substr(l_column,1,l-5);
l_data_type := 'CLOB';
elsif l_column like '% NCLOB' then
l_new_column := substr(l_column,1,l-6);
l_data_type := 'NCLOB';
elsif l_column like '% D' then
l_new_column := substr(l_column,1,l-2);
l_data_type := 'DATE';
elsif l_column like '% TS' then
l_new_column := substr(l_column,1,l-3);
l_data_type := 'TIMESTAMP';
elsif l_column like '% INTEGER' then
l_new_column := substr(l_column,1,l-8);
l_data_type := 'INTEGER';
elsif l_column like '% INT' then
l_new_column := substr(l_column,1,l-4);
l_data_type := 'INTEGER';
elsif l_column like '% FILE' then
l_new_column := substr(l_column,1,l-4);
l_data_type := 'FILE';
elsif trim(l_column) = 'PHOTO' then
--l_new_column := substr(l_column,1,l-4);
l_new_column := 'PHOTO';
l_data_type := 'FILE';
else
l_new_column := l_column;
l_data_type := nvl(get_data_type(l_new_column,g_date_data_type),'VARCHAR2(4000)');
end if;
l_new_column := trim(rtrim(l_new_column,'_'));
if l_data_type = 'DATE' then
l_data_type := NVL(g_date_data_type,'DATE');
end if;
-- set out variables
p_datatype := l_data_type;
p_revised_column := l_new_column;
end determine_data_type2;
function get_table_name( p_table_name in varchar2 ) return varchar2 is
l_table_name varchar2(255) := upper(p_table_name);
begin
for c1 in ( select c001
from apex_collections
where collection_name = 'SCHEMA'
and (c001 = l_table_name
or c001 = upper(g_prefix||'_'||l_table_name)) ) loop
l_table_name := c1.c001;
exit;
end loop;
return l_table_name;
end get_table_name;
--
-- add table to APEX collection
--
procedure add_table (
P_TABLE_PREFIX in varchar2 default null,
P_DATE_DATATYPE in varchar2 default null,
P_INC_AUDITING in varchar2 default null,
--
P_TABLE_NAME in varchar2 default null,
P_COLUMNS in varchar2 default null,
P_PRIMARY_KEY in varchar2 default null,
P_PARENT_TABLE in varchar2 default null,
P_ROW_VERSION in varchar2 default 'N',
P_row_key in varchar2 default 'N',
P_sgid in varchar2 default 'N',
p_compressed in varchar2 default 'N',
p_LONGER_IDENTIFIERS in varchar2 default 'N',
p_AUTO_GEN_PK in varchar2 default 'Y'
)
is
l_cols varchar2(32767) := null;
l_cols_arr APEX_APPLICATION_GLOBAL.VC_ARR2; -- column name
l_dt_arr APEX_APPLICATION_GLOBAL.VC_ARR2; -- column data type
--
l_not_null_yn APEX_APPLICATION_GLOBAL.VC_ARR2; -- Y or N
l_is_indexed_yn APEX_APPLICATION_GLOBAL.VC_ARR2; -- Y or N
l_cc APEX_APPLICATION_GLOBAL.VC_ARR2; -- actual check constraint
l_upper_lower APEX_APPLICATION_GLOBAL.VC_ARR2; -- UPPER or LOWER or null
l_is_unique_yn APEX_APPLICATION_GLOBAL.VC_ARR2; -- Y or N
l_default APEX_APPLICATION_GLOBAL.VC_ARR2; -- actual default clause
l_comments APEX_APPLICATION_GLOBAL.VC_ARR2; -- comment text
l_between_arr APEX_APPLICATION_GLOBAL.VC_ARR2; -- between check constraint
l_hidden_arr APEX_APPLICATION_GLOBAL.VC_ARR2; -- hidden column
l_references_arr APEX_APPLICATION_GLOBAL.VC_ARR2; -- foreign key references
l_pk_arr APEX_APPLICATION_GLOBAL.VC_ARR2; -- primary key
l_check_values_arr APEX_APPLICATION_GLOBAL.VC_ARR2; -- list of check constraint valid values
l_data_load_arr APEX_APPLICATION_GLOBAL.VC_ARR2; -- at sign references to worksheet data
l_values_arr APEX_APPLICATION_GLOBAL.VC_ARR2; -- random data values
l_format_mask_arr APEX_APPLICATION_GLOBAL.VC_ARR2; -- date format mask
l_constant_arr APEX_APPLICATION_GLOBAL.VC_ARR2; -- constant array
--
l integer := 0;
l_tab varchar2(255) := null;
l_guid number := null;
l_col_guid number := null;
l_col_id integer := 0;
l_pk_column varchar2(255) := null;
l_pk_data_type varchar2(255) := null;
l_ROW_VERSION_column varchar2(255) := null;
l_ROW_VERSION_type varchar2(255) := null;
l_sgid_column varchar2(255) := null;
l_sgid_type varchar2(255) := null;
l_ok_to_add boolean;
l_col_data_type varchar2(255) := null;
l_prefix varchar2(30);
l_parent_table varchar2(255) := null;
l_fk_column varchar2(255) := null;
x varchar2(255) := null;
l_warning varchar2(4000) := null;
l_indent_cc integer := 0;
l_indent varchar2(255) := null;
l_tab_comments varchar2(4000) := null;
l_n004 number := 0;
l_manual_fk_count integer := 0;
l_hist_yn varchar2(1) := 'N';
l_rest_yn varchar2(1) := 'N';
l_api_yn varchar2(1) := 'N';
l_compressed_yn varchar2(1) := 'N';
l_partitioned_yn varchar2(1) := 'N';
l_audit_cols_yn varchar2(1) := 'N';
l_audit_yn varchar2(1) := 'N';
--
l_insert_example integer := 0;
l_select_example varchar2(1) := 'N';
l_uncomment_examples varchar2(1) := 'Y';
l_noload_ws_data varchar2(1) := 'N';
l_data_load_worksheet varchar2(255) := null;
function get_column_id return number
is
begin
l_col_id := l_col_id + 1;
return l_col_id;
end;
function get_guid return number
is
begin
return to_number(sys_guid(), 'XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX');
end get_guid;
function is_foreign_key (p_col_name in varchar2 default null) return varchar2
is
l_foreign_key varchar2(255) := null;
begin
for c1 in (
select c001
from apex_collections
where collection_name = 'SCHEMA' and
(
c001||'_ID' = p_col_name or
rtrim(c001,'S')||'_ID' = p_col_name or
--
c001||'_ID' = l_prefix||p_col_name or
rtrim(c001,'S')||'_ID' = l_prefix||p_col_name or
--
c001||'_ID' = l_prefix||p_col_name or
rtrim(c001,'IES')||'Y'||'_ID' = l_prefix||p_col_name
)
) loop
l_foreign_key := c1.c001;
exit;
end loop;
return l_foreign_key;
end is_foreign_key;
begin
-- Determine table prefix
if P_TABLE_PREFIX is null then
l_prefix := null;
elsif substr(P_TABLE_PREFIX,length(P_TABLE_PREFIX),1) = '_' then
l_prefix := clean_name(P_TABLE_PREFIX)||'_';
else
l_prefix := clean_name(P_TABLE_PREFIX)||'_';
end if;
-- Create or replace collections
l_guid := get_guid;
if not APEX_COLLECTION.COLLECTION_EXISTS('LINES') then
APEX_COLLECTION.CREATE_COLLECTION(p_collection_name => 'LINES');
end if;
if not APEX_COLLECTION.COLLECTION_EXISTS('SCHEMA') then
APEX_COLLECTION.CREATE_COLLECTION(p_collection_name => 'SCHEMA');
end if;
if not APEX_COLLECTION.COLLECTION_EXISTS('SCHEMA_TAB_COLS') then
APEX_COLLECTION.CREATE_COLLECTION(p_collection_name => 'SCHEMA_TAB_COLS');
end if;
-- extract table comments
extract_comments (
p_string => P_TABLE_NAME,
p_new_string => l_tab,
p_comments => l_tab_comments
);
-- detect history
l_hist_yn := 'N';
extract_history (
p_string => l_tab,
p_new_string => l_tab,
p_history_yn => l_hist_yn
);
if g_history_tables = 'Y' then
l_hist_yn := 'Y';
end if;
-- detect PL/SQL APIs
l_api_yn := 'N';
extract_api (
p_string => l_tab,
p_new_string => l_tab,
p_api_yn => l_api_yn
);
if NVL(g_api,'N') = 'Y' then
l_api_yn := 'Y';
end if;
-- detect compressed
l_compressed_yn := 'N';
extract_compressed (
p_string => l_tab,
p_new_string => l_tab,
p_compressed_yn => l_compressed_yn
);
if NVL(g_COMPRESSED,'N') = 'Y' then
l_compressed_yn := 'Y';
end if;
-- detect partitioning
l_partitioned_yn := 'N';
extract_partitioned (
p_string => l_tab,
p_new_string => l_tab,
p_partitioned_yn => l_partitioned_yn
);
-- detect audit columns
l_audit_cols_yn := 'N';
extract_audit_cols (
p_string => l_tab,
p_new_string => l_tab,
p_audit_cols_yn => l_audit_cols_yn
);
-- detect table auditing
l_audit_yn := 'N';
extract_audit (
p_string => l_tab,
p_new_string => l_tab,
p_audit_yn => l_audit_yn
);
-- detect REST
l_rest_yn := 'N';
extract_rest (
p_string => l_tab,
p_new_string => l_tab,
p_rest_yn => l_rest_yn
);
-- detect INSERT
l_insert_example := 0;
if instr(l_tab,'/INSERTS') > 0 then
l_tab := replace(l_tab,'/INSERTS','/INSERT');
end if;
extract_insert (
p_string => l_tab,
p_new_string => l_tab,
p_insert_example => l_insert_example
);
-- detect SELECT
l_select_example := 'N';
extract_select (
p_string => l_tab,
p_new_string => l_tab,
p_select_example => l_select_example
);
-- detect UNCOMMENT
l_uncomment_examples := 'Y';
extract_uncomment (
p_string => l_tab,
p_new_string => l_tab,
p_uncommented => l_uncomment_examples
);
-- detect noload (do not load uploaded worksheet data)
l_noload_ws_data := 'Y';
extract_noload (
p_string => l_tab,
p_new_string => l_tab,
p_noload_ws_data => l_noload_ws_data
);
-- detect worksheet references
l_data_load_worksheet := null;
extract_data_load (
p_string => l_tab,
p_new_string => l_tab,
p_data_load => l_data_load_worksheet
);
-- remove anything after a slash as it is an unknown operation
if instr(l_tab,'/') > 0 then
l_tab := substr(l_tab,1,instr(l_tab,'/')-1);
end if;
-- Cleanse Table Name
l_tab := clean_name(l_tab);
-- add table prefix
if substr(l_tab,1,length(l_prefix)) = l_prefix then
null;
else
l_tab := l_prefix||l_tab;
end if;
l_tab := clean_name(l_tab);
if NVL(p_LONGER_IDENTIFIERS,'N') = 'N' then
if length(l_tab) > 30 then
l_warning := '"'||substr(l_tab,1,1000)||'" name truncated to 30 characters.';
l_tab := substr(l_tab,1,30);
end if;
else
if length(l_tab) > 120 then
l_warning := '"'||substr(l_tab,1,1000)||'" name truncated to 120 characters.';
l_tab := substr(l_tab,1,120);
end if;
end if;
if g_selects = 'Y' then
l_select_example := 'Y'; -- global setting to show for all tables
end if;
if nvl(g_uncomment,'Y') = 'Y' then
l_uncomment_examples := 'Y'; -- global setting to show for all tables
else
l_uncomment_examples := 'N';
end if;
if NVL(l_insert_example,0) = 0 then
-- only override at global scope if not supplied per table
l_insert_example := g_inserts;
end if;
APEX_COLLECTION.ADD_MEMBER (
p_collection_name => 'SCHEMA', -- schema collection one row per table
p_c001 => l_tab, -- table name
p_c002 => l_cols, -- table columns
p_c003 => P_PRIMARY_KEY, -- primary key column name
p_c004 => P_PARENT_TABLE, -- parent table
p_c005 => l_warning, -- warndings
p_c006 => 'TABLE', -- object type
p_c007 => l_tab_comments, -- table comments
p_c008 => l_warning, -- warnings for developer
p_c009 => P_TABLE_NAME, -- unprocessed table name
p_c010 => l_hist_yn, -- maintain history
p_c011 => l_rest_yn, -- REST enable
p_c012 => l_api_yn, -- PL/SQL API enable
p_c013 => l_compressed_yn, -- compress table
p_c014 => l_partitioned_yn, -- partition table
p_c015 => l_audit_cols_yn, -- add audit columns
p_c016 => l_audit_yn, -- auditing
p_c017 => l_select_example, -- generate a select statement Y or N
p_c018 => l_uncomment_examples, -- do not comment example SQL inserts and selects
p_c019 => l_data_load_worksheet, -- load table from this worksheet
p_c020 => l_noload_ws_data, -- genereate sql insert statements for worksheet data
p_n002 => least(NVL(l_insert_example,0),g_max_inserts), -- insert examples 0, 1 or more
p_n001 => l_guid );
-- convert string of columns to an array
l_cols := trim(P_COLUMNS);
l_cols := replace(l_cols,unistr('\0009'),' ');
l_cols := replace(l_cols,chr(13),null);
l_cols := replace(l_cols,chr(10),'~');
l_cols_arr := APEX_UTIL.STRING_TO_TABLE(l_cols,'~');
l_cols := null;
-- process [ comments ] returning column-less string
for i in 1..l_cols_arr.count loop
extract_comments (
p_string => l_cols_arr(i), -- in
p_new_string => l_cols_arr(i), -- out
p_comments => l_comments(i) -- out
);
end loop;
-- remove trailing commas
for i in 1..l_cols_arr.count loop
l_cols_arr(i) := trim(rtrim(l_cols_arr(i),','));
end loop;
-- look for date datatypes
for i in 1..l_cols_arr.count loop
l_cols_arr(i) := replace(l_cols_arr(i), ' TIMESTAMP WITH LOCAL TIME ZONE',' TSWLTZ');
l_cols_arr(i) := replace(l_cols_arr(i), ' TIMESTAMP WITH TIME ZONE',' TSWTZ');
l_cols_arr(i) := replace(l_cols_arr(i), ' TIMESTAMP WITH LOCAL TIMEZONE',' TSWLTZ');
l_cols_arr(i) := replace(l_cols_arr(i), ' TIMESTAMP WITH TIMEZONE',' TSWTZ');
end loop;
-- process column slash options for first slash
for i in 1..l_cols_arr.count loop
-- remove slash options from column array and set array values
determine_column_options (
p_column => l_cols_arr(i),
p_table => l_tab,
-- out values
p_revised_column => l_cols_arr(i),
p_not_null => l_not_null_yn(i),
p_is_indexed => l_is_indexed_yn(i),
p_check_constraints => l_cc(i),
p_upper_lower => l_upper_lower(i),
p_is_unique => l_is_unique_yn(i),
p_default => l_default(i),
p_between => l_between_arr(i),
p_hidden => l_hidden_arr(i),
p_references => l_references_arr(i),
p_pk => l_pk_arr(i),
p_check_values => l_check_values_arr(i),
p_data_load => l_data_load_arr(i),
p_values => l_values_arr(i),
p_format_mask => l_format_mask_arr(i),
p_constant => l_constant_arr(i)
);
end loop;
----------------------------------------------
-- determine datatype and cleanse column names
--
for i in 1..l_cols_arr.count loop
determine_data_type2 (
p_column => l_cols_arr(i),
p_revised_column => x,
p_datatype => l_dt_arr(i) );
l_cols_arr(i) := clean_name(x);
end loop;
----------------
-- add PK column
--
l_pk_column := clean_name(P_PRIMARY_KEY);
l_pk_data_type := 'NUMBER';
l_ok_to_add := true;
if l_pk_column is not null then
for i in 1..l_cols_arr.count loop
if l_pk_column = l_cols_arr(i) then
l_ok_to_add := false;
exit;
end if;
end loop;
if NVL(p_AUTO_GEN_PK,'Y') = 'N' then
l_ok_to_add := false;
end if;
if l_ok_to_add then
APEX_COLLECTION.ADD_MEMBER(
p_collection_name => 'SCHEMA_TAB_COLS',
p_c001 => l_tab,
p_c002 => l_pk_column,
p_c003 => l_pk_data_type,
p_c004 => 'Y', -- not null
p_c005 => 'Y', -- unique
p_c006 => 'Y', -- pk
p_c007 => null, -- fk
p_c008 => null, -- index
p_c009 => null, -- check constraints
p_c010 => null, -- upper or lower
p_c011 => null, -- default
p_c012 => null, -- comments
p_n001 => l_guid,
p_n002 => get_guid,
p_n003 => get_column_id, -- column sequence
p_n004 => 1 -- pk columns first
);
end if;
end if;
-- add ROW_VERSION column
if g_ROW_VERSION = 'Y' then
l_ROW_VERSION_column := 'ROW_VERSION';
l_ROW_VERSION_type := 'INTEGER';
l_ok_to_add := true;
if l_ROW_VERSION_column is not null then
for i in 1..l_cols_arr.count loop
if l_ROW_VERSION_column = l_cols_arr(i) then
l_ok_to_add := false;
exit;
end if;
end loop;
if l_ok_to_add then
APEX_COLLECTION.ADD_MEMBER(
p_collection_name => 'SCHEMA_TAB_COLS',
p_c001 => l_tab,
p_c002 => l_ROW_VERSION_column,
p_c003 => l_ROW_VERSION_type,
p_c004 => 'Y', -- not null
p_c005 => 'N', -- unique
p_c006 => 'N', -- pk
p_n001 => l_guid,
p_n002 => get_guid,
p_n003 => get_column_id,
p_n004 => 3
);
end if;
end if;
end if;
-----------------------
-- add ROW_KEY column
--
if p_row_key = 'Y' then
l_ROW_VERSION_column := 'ROW_KEY';
l_ROW_VERSION_type := 'VARCHAR2(30)';
l_ok_to_add := true;
if l_ROW_VERSION_column is not null then
for i in 1..l_cols_arr.count loop
if l_ROW_VERSION_column = l_cols_arr(i) then
l_ok_to_add := false;
exit;
end if;
end loop;
if l_ok_to_add then
APEX_COLLECTION.ADD_MEMBER(
p_collection_name => 'SCHEMA_TAB_COLS',
p_c001 => l_tab,
p_c002 => l_ROW_VERSION_column,
p_c003 => l_ROW_VERSION_type,
p_c004 => 'Y', -- not null
p_c005 => 'Y', -- unique
p_c006 => 'N', -- pk
p_n001 => l_guid,
p_n002 => get_guid,
p_n003 => get_column_id,
p_n004 => 3
);
end if;
end if;
end if;
-----------------------
-- add SECURITY_GROUP_ID column
--
if p_sgid = 'Y' then
l_sgid_column := 'SECURITY_GROUP_ID';
l_sgid_type := 'NUMBER';
l_ok_to_add := true;
if l_sgid_column is not null then
for i in 1..l_cols_arr.count loop
if l_sgid_column = l_cols_arr(i) then
l_ok_to_add := false;
exit;
end if;
end loop;
if l_ok_to_add then
apex_collection.add_member(
p_collection_name => 'SCHEMA_TAB_COLS',
p_c001 => l_tab,
p_c002 => l_sgid_column,
p_c003 => l_sgid_type,
p_c004 => 'Y', -- not null
p_c005 => 'N', -- unique
p_c006 => 'N', -- pk
p_n001 => l_guid,
p_n002 => get_guid,
p_n003 => get_column_id,
p_n004 => 3
);
end if;
end if;
end if;
----------------------------------------------------------
-- add parent table (requires p_parent_table to be passed)
--
l_parent_table := clean_name(P_PARENT_TABLE);
if l_parent_table is not null then
l_fk_column := substr(l_parent_table||'_ID',1,30);
APEX_COLLECTION.ADD_MEMBER(
p_collection_name => 'SCHEMA_TAB_COLS',
p_c001 => l_tab, -- table name
p_c002 => l_fk_column, -- fk column name
p_c003 => 'NUMBER', -- data type
p_c004 => 'N', -- not null
p_c005 => 'N', -- unique
p_c006 => 'N', -- pk
p_c007 => l_parent_table, -- fk
p_n001 => l_guid,
p_n002 => get_guid,
p_n003 => get_column_id,
p_n004 => 2 -- fk columns second
);
end if;
-----------------------
-- add data columns
--
for i in 1..l_cols_arr.count loop
if l_cols_arr(i) is not null then
-- add multiple column
if l_dt_arr(i) = 'FILE' then
APEX_COLLECTION.ADD_MEMBER(
p_collection_name => 'SCHEMA_TAB_COLS',
p_c001 => l_tab, -- table name
p_c002 => l_cols_arr(i), -- column name
p_c003 => 'BLOB', -- data type
p_c004 => 'N', -- not null
p_c005 => 'N', -- unique
p_c006 => 'N', -- pk
p_n001 => l_guid,
p_n002 => get_guid,
p_n003 => get_column_id,
p_n004 => 3
);
APEX_COLLECTION.ADD_MEMBER(
p_collection_name => 'SCHEMA_TAB_COLS',
p_c001 => l_tab,
p_c002 => l_cols_arr(i)||'_FILENAME',
p_c003 => 'varchar2(512)',
p_c004 => 'N', -- not null
p_c005 => 'N', -- unique
p_c006 => 'N', -- pk
p_n001 => l_guid,
p_n002 => get_guid,
p_n003 => get_column_id,
p_n004 => 3
);
APEX_COLLECTION.ADD_MEMBER(
p_collection_name => 'SCHEMA_TAB_COLS',
p_c001 => l_tab,
p_c002 => l_cols_arr(i)||'_MIMETYPE',
p_c003 => 'varchar2(512)',
p_c004 => 'N', -- not null
p_c005 => 'N', -- unique
p_c006 => 'N', -- pk
p_n001 => l_guid,
p_n002 => get_guid,
p_n003 => get_column_id,
p_n004 => 3
);
APEX_COLLECTION.ADD_MEMBER(
p_collection_name => 'SCHEMA_TAB_COLS',
p_c001 => l_tab,
p_c002 => l_cols_arr(i)||'_CHARSET',
p_c003 => 'varchar2(512)',
p_c004 => 'N', -- not null
p_c005 => 'N', -- unique
p_c006 => 'N', -- pk
p_n001 => l_guid,
p_n002 => get_guid,
p_n003 => get_column_id,
p_n004 => 3
);
APEX_COLLECTION.ADD_MEMBER(
p_collection_name => 'SCHEMA_TAB_COLS',
p_c001 => l_tab,
p_c002 => l_cols_arr(i)||'_LASTUPD',
p_c003 => NVL(g_date_data_type,'DATE'),
p_c004 => 'N', -- not null
p_c005 => 'N', -- unique
p_c006 => 'N', -- pk
p_n001 => l_guid,
p_n002 => get_guid,
p_n003 => get_column_id,
p_n004 => 3
);
else
--
-- standard columns here
--
-- make primary keys numeric if not already numeric
if NVL(l_pk_arr(i),'N') = 'Y' then
if l_dt_arr(i) like 'NUMBER%' or l_dt_arr(i) like 'INTEGER%' then
null;
else
l_dt_arr(i) := 'NUMBER';
end if;
end if;
-- for columns ending in _yn add check constraint if one does not already exist
if l_cols_arr(i) like '%_YN' and l_cc(i) is null then
l_cc(i) := ' constraint '||gen_valid_identifier_name(l_cols_arr(i),'CC',l_tab)||chr(10)||' '||
'check ('||lower(l_cols_arr(i))||' in (''Y'',''N''))';
end if;
-- make foreign key data type to be numeric
if l_references_arr(i) is not null then
if l_dt_arr(i) like 'NUMBER%' or l_dt_arr(i) like 'INTEGER%' then
null;
else
l_dt_arr(i) := 'NUMBER';
end if;
end if;
APEX_COLLECTION.ADD_MEMBER(
p_collection_name => 'SCHEMA_TAB_COLS',
p_c001 => l_tab, -- table name
p_c002 => l_cols_arr(i), -- column name
p_c003 => l_dt_arr(i), -- data type
p_c004 => NVL(l_not_null_yn(i),'N'), -- not null
p_c005 => NVL(l_is_unique_yn(i),'N'), -- unique
p_c006 => 'N', -- pk
p_c007 => is_foreign_key(l_cols_arr(i)), -- FK
p_c008 => l_is_indexed_yn(i), -- index
p_c009 => l_cc(i), -- check constraints
p_c010 => l_upper_lower(i), -- upper or lower
p_c011 => l_default(i), -- default
p_c012 => l_comments(i), -- comments
p_c013 => l_between_arr(i), -- between
p_c014 => l_hidden_arr(i), -- hidden columns
p_c015 => l_references_arr(i), -- fk references
p_c016 => l_pk_arr(i), -- is primary key
p_c017 => l_check_values_arr(i), -- check values only not full syntax
p_c018 => fmt_heading(l_data_load_arr(i)), -- load data from this worksheet column
p_c019 => l_values_arr(i), -- data generation random values
p_c020 => l_format_mask_arr(i), -- date format mask for this column
p_c021 => l_constant_arr(i), -- constant value for data generation
p_n001 => l_guid,
p_n002 => get_guid,
p_n003 => get_column_id,
p_n004 => 3
);
end if;
end if;
end loop;
-----------------------------------------------------
-- update PK attributes if PK was included in columns
--
for c1 in (
select seq_id ,
c001, c002, c003, c004, c005, c006, c007, c008, c009, c010, c011, c012, c013, c014, c015, c016, c017, c018, c019, c020, c021,
n001, n002, n003, n004
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and c002 = l_pk_column
) loop
-- primary column ordering
l_n004 := NVL(c1.n004,3);
if c1.c007 is not null then
l_n004 := 2;
end if;
-- update collection members
APEX_COLLECTION.UPDATE_MEMBER (
p_collection_name => 'SCHEMA_TAB_COLS',
p_seq => c1.seq_id,
p_c001 => c1.c001,
P_c002 => c1.c002,
p_c003 => l_pk_data_type, -- datatype
p_c004 => 'Y', -- required
p_c005 => 'Y', -- unique
p_c006 => 'Y', -- pk
p_c007 => c1.c007,
p_c008 => c1.c008,
p_c009 => c1.c009,
p_c010 => c1.c010,
p_c011 => c1.c011,
p_n001 => c1.n001,
p_n002 => c1.n002,
p_n003 => c1.n003,
p_n004 => l_n004
);
end loop;
commit;
if NVL(P_INC_AUDITING,'N') = 'Y' or nvl(l_audit_cols_yn,'N') = 'Y' then
APEX_COLLECTION.ADD_MEMBER(
p_collection_name => 'SCHEMA_TAB_COLS',
p_c001 => l_tab,
p_c002 => 'CREATED', -- this is the default name user overrides applied later
p_c003 => g_date_data_type, -- date datatype
p_c004 => 'Y', -- not null
p_c005 => 'N', -- unique
p_c006 => 'N', -- pk
p_c007 => null, -- FK
p_c008 => null, -- index
p_c009 => null, -- check constraints
p_c010 => null, -- upper or lower
p_n001 => l_guid,
p_n002 => get_guid,
p_n003 => get_column_id,
p_n004 => 3
);
APEX_COLLECTION.ADD_MEMBER(
p_collection_name => 'SCHEMA_TAB_COLS',
p_c001 => l_tab,
p_c002 => 'CREATED_BY', -- this is the default name user overrides applied later
p_c003 => 'VARCHAR2(255)',
p_c004 => 'Y', -- not null
p_c005 => 'N', -- unique
p_c006 => 'N', -- pk
p_c007 => null, -- FK
p_c008 => null, -- index
p_c009 => null, -- check constraints
p_c010 => null, -- upper or lower
p_n001 => l_guid,
p_n002 => get_guid,
p_n003 => get_column_id,
p_n004 => 3
);
APEX_COLLECTION.ADD_MEMBER(
p_collection_name => 'SCHEMA_TAB_COLS',
p_c001 => l_tab,
p_c002 => 'UPDATED', -- this is the default name user overrides applied later
p_c003 => g_date_data_type,
p_c004 => 'Y', -- not null
p_c005 => 'N', -- unique
p_c006 => 'N', -- pk
p_c007 => null, -- FK
p_c008 => null, -- index
p_c009 => null, -- check constraints
p_c010 => null, -- upper or lower
p_n001 => l_guid,
p_n002 => get_guid,
p_n003 => get_column_id,
p_n004 => 3
);
APEX_COLLECTION.ADD_MEMBER(
p_collection_name => 'SCHEMA_TAB_COLS',
p_c001 => l_tab,
p_c002 => 'UPDATED_BY', -- this is the default name user overrides applied later
p_c003 => 'VARCHAR2(255)',
p_c004 => 'Y', -- not null
p_c005 => 'N', -- unique
p_c006 => 'N', -- pk
p_c007 => null, -- FK
p_c008 => null, -- index
p_c009 => null, -- check constraints
p_c010 => null, -- upper or lower
p_n001 => l_guid,
p_n002 => get_guid,
p_n003 => get_column_id,
p_n004 => 3
);
end if;
end add_table;
procedure add_tables (
p_table_prefix in varchar2 default null,
p_date_datatype in varchar2 default null,
p_inc_auditing in varchar2 default null,
p_primary_key in varchar2 default null,
p_tables in varchar2 default null,
p_row_version in varchar2 default 'N',
p_row_key in varchar2 default 'N',
p_sgid in varchar2 default 'N',
p_compressed in varchar2 default 'N',
p_longer_identifiers in varchar2 default 'N',
p_auto_gen_pk in varchar2 default 'Y',
p_history_tables in varchar2 default 'N',
p_apis in varchar2 default 'N',
p_audit_cols in varchar2 default 'N',
p_audit in varchar2 default 'N',
p_longer_varchars_yn in varchar2 default 'N',
p_verbose_yn in varchar2 default 'N',
p_schema in varchar2 default null,
p_inserts in number default 0,
p_selects in varchar2 default 'N',
p_uncomment in varchar2 default 'Y',
p_tags_fw_yn in varchar2 default 'N',
p_semantics in varchar2 default 'DEFAULT'
)
is
c integer := 0;
l_eol integer := 0;
l_offset integer := 1;
l_last_offset integer := 1;
l_table varchar2(4000) := null;
l_columns varchar2(32767) := null;
l_first_char varchar2(1);
l_tables varchar2(32767) := null;
procedure ct (
p_table in varchar2 default null,
p_columns in varchar2 default null) is
begin
add_table (
P_TABLE_PREFIX => g_prefix,
P_DATE_DATATYPE => g_date_datatype,
P_INC_AUDITING => g_audit_cols,
P_TABLE_NAME => nvl(p_TABLE,'tname is null'),
P_COLUMNS => nvl(P_COLUMNS,'is null'),
P_PRIMARY_KEY => p_primary_key,
P_PARENT_TABLE => null,
P_ROW_VERSION => g_row_version,
P_ROW_KEY => g_row_key,
P_SGID => g_sgid,
p_compressed => g_compressed,
p_LONGER_IDENTIFIERS => g_longer_identifiers,
p_AUTO_GEN_PK => g_auto_gen_pk
);
end ct;
begin
-- set globals
g_prefix := p_table_prefix ;
g_api := p_apis;
g_audit_cols := p_inc_auditing;
g_compressed := p_compressed;
g_date_datatype := p_date_datatype;
-- g_on_delete := p_fk;
g_row_key := p_row_key;
g_sgid := p_sgid;
g_row_version := p_row_version;
-- g_trigger_method := p_trigger_method;
--g_include_drops := p_include_drops;
g_longer_identifiers := p_longer_identifiers;
g_history_tables := p_history_tables;
-- g_db_version := p_db_version;
g_auto_gen_pk := p_auto_gen_pk;
-- g_editionable := p_editionable;
-- g_apex := p_apex;
g_audit := p_audit;
g_selects := NVL(p_selects,'N');
begin
g_inserts := NVL(p_inserts,0);
exception when others then
g_inserts := 0;
end;
g_uncomment := NVL(p_uncomment,'Y');
g_tags_fw := NVL(p_tags_fw_yn,'N');
g_semantics := NVL(p_semantics,'DEFAULT');
g_longer_varchars_yn := NVL(p_longer_varchars_yn,'N');
if p_schema is null then
g_schema := null;
else
g_schema := rtrim(trim_identifier_length(upper(clean_name(p_schema))),'.')||'.';
end if;
set_settings_overrides (p_string=>g_settings_override);
-- log history
log_history(p_str=> p_tables);
--
-- set default data formats
--
if g_DATE_DATATYPE is null then
g_date_data_type := 'DATE';
else
g_date_data_type := g_DATE_DATATYPE;
end if;
--
-- generate tables
--
l_tables := replace(p_tables,chr(13),null);
l_tables := l_tables ||chr(10);
loop
c := c + 1;
l_eol := instr(substr(l_tables,l_offset),chr(10));
l_first_char := substr(substr(l_tables,l_offset,l_eol),1,1);
if l_first_char is not null and l_first_char not in (' ',CHR(9)) then
if l_columns is not null then ct(l_table,l_columns); end if;
l_table := substr(l_tables,l_offset,l_eol);
l_columns := null;
else
l_columns := l_columns||substr(l_tables,l_offset,l_eol);
end if;
if nvl(l_eol,0) = 0 then exit; end if;
l_last_offset := l_offset;
l_offset := l_eol + l_offset;
if c = 15000 then exit; end if;
end loop;
if clean_name(l_table) is not null then
ct(l_table,l_columns);
end if;
end add_tables;
--
-- triger_method
-- trig
-- none
-- identity
--
procedure save_as_sql (
-- live sql integration arguments
p_app_user in varchar2 default null,
-- input setting controls
p_app_session in varchar2 default null,
p_trigger_method in varchar2 default 'STANDARD',
p_fk in varchar2 default 'RESTRICT',
p_row_version in varchar2 default 'N',
p_row_key in varchar2 default 'N',
p_sgid in varchar2 default 'N',
p_table_prefix in varchar2 default null,
p_compressed in varchar2 default 'N',
p_db_version in varchar2 default '12c',
p_include_drops in varchar2 default 'N',
p_longer_identifiers in varchar2 default 'N',
p_history_tables in varchar2 default 'N',
p_apis in varchar2 default 'N',
p_auto_gen_pk in varchar2 default 'Y',
p_audit_cols in varchar2 default 'N',
p_date_datatype in varchar2 default 'DATE',
p_editionable in varchar2 default 'N',
p_language in varchar2 default 'EN',
p_apex in varchar2 default 'N',
--
p_prefix_pk_with_tname in varchar2, --mike
p_created_column_name in varchar2,
p_created_by_column_name in varchar2,
p_updated_column_name in varchar2,
p_updated_by_column_name in varchar2,
--
p_audit in varchar2 default 'N',
p_longer_varchars_yn in varchar2 default 'N',
p_verbose_yn in varchar2 default 'N',
p_schema in varchar2 default null,
p_inserts in number default 0,
p_selects in varchar2 default 'N',
p_uncomment in varchar2 default 'Y',
p_format_mask in varchar2 default 'MM/DD/RR HH24:MI',
p_tags_fw_yn in varchar2 default 'N',
p_semantics in varchar2 default 'DEFAULT',
-- output
P_MESSAGE out varchar2,
P_SCRIPT_ID out varchar2
)
is
l_history_tname varchar2(128);
l_prefix varchar2(30);
l_last_table varchar2(255) := 'mjH125';
l_sequence varchar2(30) := null;
l_idx_cnt integer := 0;
l_indent varchar2(255) := ' ';
l_saved_session_id number := null;
c integer := 0;
l_last_sql integer;
l_sql varchar2(32767);
l_cnt integer := 0;
l_table_name varchar2(255);
l_hist_str varchar2(4000);
l_hist_dt varchar2(255);
l_row_version_num varchar2(255);
l_trig_count integer := 0;
l_comment_count integer := 0;
l_total_indexes integer := 0;
l_hist_sysdate varchar2(255) := null;
l_history_tname_seq varchar2(128) := null;
l_tags_tname varchar2(128) := null;
l_unique_count integer := 0;
l_date_count integer := 0;
l_timestamp_count integer := 0;
l_tswltz_count integer := 0;
l_tswtz_count integer := 0;
l_logic boolean := false;
l_data_type varchar2(255) := null;
l_fk varchar2(4000) := null;
l_n004 number;
l_editionable varchar2(50) := null;
l_del varchar2(32767) := null;
l_ins varchar2(32767) := null;
l_history_table_count integer := 0;
l_rest_count integer := 0;
l_api_count integer := 0;
l_sql_count integer := 0;
l_package_name varchar2(128) := null;
l_col_check_cons varchar2(255) := null;
l_view_count integer := 0;
l_pk_column_name varchar2(128) := null;
l_tags_procedure varchar2(32767);
l_view varchar2(4000);
vi integer;
l_view_name varchar2(4000);
l_tab_pk_column_name varchar2(128) := null;
l_adjusted_data_type varchar2(255) := null;
l_column_name varchar2(255) := null;
--
function get_date_stamp (p_data_type in varchar2) return varchar2
is
l_date_stamp varchar2(255) := 'systimestamp';
begin
if upper(p_data_type) like '%DATE%' then
l_date_stamp := 'sysdate';
elsif upper(p_data_type) like '%LOCAL%' then
l_date_stamp := 'localtimestamp';
else
l_date_stamp := 'systimestamp';
end if;
return l_date_stamp;
end get_date_stamp;
begin
-- set option globals as set by application settings
g_prefix := p_table_prefix ;
g_api := p_apis;
g_audit_cols := p_audit_cols;
g_compressed := p_compressed;
g_date_datatype := p_date_datatype;
g_on_delete := p_fk;
g_row_key := p_row_key;
g_sgid := p_sgid;
g_row_version := p_row_version;
g_trigger_method := p_trigger_method;
g_include_drops := p_include_drops;
g_longer_identifiers := p_longer_identifiers;
g_history_tables := p_history_tables;
g_db_version := p_db_version;
g_auto_gen_pk := p_auto_gen_pk;
g_editionable := p_editionable;
g_language := p_language;
g_apex := p_apex;
g_audit := p_audit;
g_inserts := NVL(p_inserts,0);
g_selects := NVL(p_selects,'N');
g_uncomment := NVL(p_uncomment,'Y');
g_tags_fw := NVL(p_tags_fw_yn,'N');
g_semantics := nvl(p_semantics,'DEFAULT');
g_prefix_pk_with_tname := nvl(p_prefix_pk_with_tname ,'N');
g_created_column_name := nvl(p_created_column_name ,'created');
g_created_by_column_name := nvl(p_created_by_column_name ,'created_by');
g_updated_column_name := nvl(p_updated_column_name ,'updated');
g_updated_by_column_name := nvl(p_updated_by_column_name ,'updated_by');
g_longer_varchars_yn := NVL(p_longer_varchars_yn,'N');
if g_editionable = 'Y' then l_editionable := 'editionable '; end if;
if upper(p_db_version) = '11G' then
g_longer_varchars_yn := 'N';
end if;
-- schema
if p_schema is null then
g_schema := null;
else
g_schema := rtrim(trim_identifier_length(upper(clean_name(p_schema))),'.')||'.';
end if;
-- override application settings with hash values
if g_settings_override is not null then
set_settings_overrides (p_string=>g_settings_override);
end if;
-- set user for APEX
if g_apex = 'Y' then
g_user := 'nvl(sys_context(''APEX$SESSION'',''APP_USER''),user)';
--g_user := 'nvl(wwv_flow.g_user,user)';
end if;
-- set version specific settings
if upper(g_db_version) = '11G' then
if g_trigger_method = 'IDENTITY' then
g_trigger_method := 'TRIGGER';
end if;
end if;
-- validate and adjust object names in schema collection
for c1 in (
select seq_id ,
c001, c002, c003, c004, c005, c006, c007, c008, c009, c010, c011, c012, c013, c014, c015, c016, c017, c018, c019, c020, c021,
n001, n002, n003, n004
from apex_collections
where collection_name = 'SCHEMA') loop
APEX_COLLECTION.UPDATE_MEMBER (
p_collection_name => 'SCHEMA',
p_seq => c1.seq_id,
p_c001 => validate_object_name(c1.c001),
P_c002 => c1.c002,
p_c003 => validate_object_name(c1.c003),
p_c004 => c1.c004,
p_c005 => c1.c005,
p_c006 => c1.c006,
p_c007 => c1.c007,
p_c008 => c1.c008,
p_c009 => c1.c009,
p_c010 => c1.c010,
p_c011 => c1.c011,
p_c012 => c1.c012,
p_c013 => c1.c013,
p_c014 => c1.c014,
p_c015 => c1.c015,
p_c016 => c1.c016,
p_c017 => c1.c017,
p_c018 => c1.c018,
p_c019 => c1.c019,
p_c020 => c1.c020,
p_c021 => c1.c021,
p_n001 => c1.n001,
p_n002 => c1.n002,
p_n003 => c1.n003,
p_n004 => c1.n004
);
end loop;
-- set column ordering columns n004 attribute, 1 = pk, 2 = fk, 3 = all others
-- adjust datatypes to verify they are valid
for c1 in (
select seq_id ,
c001, c002, c003, c004, c005, c006, c007, c008, c009, c010, c011, c012, c013, c014, c015, c016, c017, c018, c019, c020, c021,
n001, n002, n003, n004
from apex_collections
where collection_name = 'SCHEMA_TAB_COLS'
) loop
l_data_type := validate_data_type(c1.c003, NVL(g_longer_varchars_yn,'N'));
l_fk := c1.c007;
l_n004 := c1.n004;
if l_fk is not null then
l_n004 := 2;
end if;
l_table_name := validate_object_name(c1.c001);
APEX_COLLECTION.UPDATE_MEMBER (
p_collection_name => 'SCHEMA_TAB_COLS',
p_seq => c1.seq_id,
p_c001 => l_table_name,
P_c002 => validate_object_name(c1.c002),
p_c003 => l_data_type,
p_c004 => c1.c004,
p_c005 => c1.c005,
p_c006 => c1.c006,
p_c007 => validate_object_name(c1.c007),
p_c008 => c1.c008,
p_c009 => c1.c009,
p_c010 => c1.c010,
p_c011 => c1.c011,
p_c012 => c1.c012,
p_c013 => c1.c013,
p_c014 => c1.c014,
p_c015 => c1.c015,
p_c016 => c1.c016,
p_c017 => c1.c017,
p_c018 => c1.c018,
p_c019 => c1.c019,
p_c020 => c1.c020,
p_c021 => c1.c021,
p_n001 => c1.n001,
p_n002 => c1.n002,
p_n003 => c1.n003,
p_n004 => l_n004
);
end loop;
commit;
-- delete duplicate column names
for c1 in (
select c001, c002, min(seq_id) min_seq_id, count(*) col_count
from apex_collections
where collection_name = 'SCHEMA_TAB_COLS'
group by c001, c002
having count(*) > 1 ) loop
for c2 in (select seq_id
from apex_collections
where collection_name = 'SCHEMA_TAB_COLS' and c001 = c1.c001 and c002 = c1.c002 and seq_id != c1.min_seq_id ) loop
apex_collection.delete_member (p_collection_name => 'SCHEMA_TAB_COLS' , p_seq => c2.seq_id);
end loop;
commit;
end loop;
-- delete ID primary key column if a manual primary key was supplied
for c1 in (
select seq_id, c001 tname, NVL(c016,'N') pk
from apex_collections
where collection_name = 'SCHEMA_TAB_COLS' and NVL(c016,'N') = 'Y'
) loop
for c2 in (select seq_id
from apex_collections
where collection_name = 'SCHEMA_TAB_COLS' and c001 = c1.tname and c002 = 'ID' and seq_id != c1.seq_id ) loop
apex_collection.delete_member (p_collection_name => 'SCHEMA_TAB_COLS' , p_seq => c2.seq_id);
end loop;
commit;
end loop;
-- delete auto generated FK if a manual FK to the same table exists
for c1 in (
select seq_id, c001 tname, c015 manual_fk_table
from apex_collections
where collection_name = 'SCHEMA_TAB_COLS' and c015 is not null
) loop
for c2 in (select seq_id
from apex_collections
where collection_name = 'SCHEMA_TAB_COLS' and c001 = c1.tname and c007 = c1.manual_fk_table and seq_id != c1.seq_id ) loop
apex_collection.delete_member (p_collection_name => 'SCHEMA_TAB_COLS' , p_seq => c2.seq_id);
end loop;
commit;
end loop;
-- generate drop object scripts
if NVL(g_include_drops,'N') = 'Y' then
printl('-- drop objects');
for c1 in (
select
c001 object_name,
c006 object_type
from apex_collections c1
where collection_name = 'SCHEMA' and c001 is not null
order by seq_id) loop
if c1.object_type = 'TABLE' then
printl('drop table '||lower(g_schema||trim_identifier_length(c1.object_name))||' cascade constraints;');
else
printl('drop '||c1.object_type||' '||lower(g_schema||trim_identifier_length(c1.object_name))||';');
end if;
end loop;
if nvl(g_tags_fw,'N') = 'Y' then
if clean_name(g_prefix) is not null then
l_tags_tname := clean_name(g_prefix)||'_'||'TAGS';
else
l_tags_tname := 'TAGS';
end if;
printl('drop procedure '||lower(g_schema||l_tags_tname)||'_sync;');
printl('drop table '||lower(g_schema||l_tags_tname)||' cascade constraints;');
printl('drop table '||lower(g_schema||l_tags_tname)||'_tsum cascade constraints;');
printl('drop table '||lower(g_schema||l_tags_tname)||'_sum cascade constraints;');
--printl('drop type '||g_schema||l_tags_tname||'_TYPE;');
end if;
if upper(nvl(g_history_tables,'N')) = 'Y' then
if clean_name(g_prefix) is not null then
printl('drop table '|| lower(g_schema||trim_identifier_length(rtrim(clean_name(g_prefix),'_')||'_'||'history'))||' cascade constraints;');
printl('drop view '|| lower(g_schema||trim_identifier_length(rtrim(clean_name(g_prefix),'_')||'_'||'history_v'))||';');
printl('drop sequence '||lower(g_schema||trim_identifier_length(clean_name(rtrim(g_prefix,'_'))||'_'||'history_seq'))||';');
else
printl('drop table '||lower(g_schema)||'history'||' cascade constraints;');
printl('drop view '||lower(g_schema)||'history'||'_v'||';');
printl('drop sequence '||lower(g_schema)||'history_seq;');
end if;
end if;
if NVL(p_row_key,'N') = 'Y' then
if clean_name(g_prefix) is not null then
printl('drop sequence '|| lower(g_schema||trim_identifier_length(clean_name(g_prefix)||'_'||'row_key_seq'))||';');
else
printl('drop sequence '||lower(g_schema)||'row_key_seq'||';');
end if;
end if;
-- drop views
for c1 in (
select upper(c001) view_name
from APEX_COLLECTIONS
where collection_name = 'LINES' and
c002 = 'TABLE' and
(upper(c001) like 'VIEW %' or upper(c001) like 'VIEW'||chr(9)||'%') ) loop
g_prefix := lower(g_prefix);
l_view := trim(replace(lower(c1.view_name),chr(9),' '));
l_view := trim(substr(l_view,5));
vi := instr(l_view,' ');
l_view_name := clean_name(substr(l_view,1,vi-1));
if g_prefix is null then
printl('drop view '||lower(g_schema||trim_identifier_length(l_view_name))||';');
else
printl('drop view '||lower(g_schema||trim_identifier_length(rtrim(g_prefix,'_')||'_'||l_view_name))||';');
end if;
end loop;
-- drop plsql table apis
for c1 in (
select
c001 object_name,
c006 object_type,
n001
from apex_collections c1
where collection_name = 'SCHEMA' and
c001 is not null and
c012 = 'Y' and
c006 = 'TABLE') loop
l_package_name := gen_valid_identifier_name (c1.object_name,'API',null);
printl('drop package '||lower(g_schema||trim_identifier_length(l_package_name))||';');
end loop;
if NVL(g_include_drops,'N') = 'Y' then
printl('');
end if;
end if;
-- Determine table prefix
if g_prefix is null then
l_prefix := null;
elsif substr(g_prefix,length(g_prefix),1) = '_' then
l_prefix := clean_name(g_prefix)||'_';
else
l_prefix := clean_name(g_prefix)||'_';
end if;
-- sequence
if g_row_key = 'Y' then
l_sequence := trim_identifier_length(lower(l_prefix)||'row_key_seq');
printl('-- sequences');
printl('create sequence '||lower(g_schema)||l_sequence||';');
printl('');
end if;
-- tables
printl('-- create tables');
l_last_sql := eba_dbtools_SEQ.nextval;
c := c + 10;
for c1 in (
select
c001,
n001,
nvl((
select count(*)
from apex_collections x
where collection_name = 'SCHEMA_TAB_COLS' and x.n001 = c1.n001 and c007 is not null) ,0) c,
c013 is_compressed,
c014 is_partitioned,
c015 add_audit_columns,
c016 is_audited
from apex_collections c1
where collection_name = 'SCHEMA' and c001 is not null
order by seq_id) loop
c := c + 10;
l_table_name := c1.c001;
l_sql := 'create table '||lower(g_schema||trim_identifier_length(l_table_name))||' ('||chr(10);
--------------------
-- loop over columns
--
for c2 in (
select
c001 table_name,
c002 column_name,
c003 data_type,
c004 is_required,
c005 is_unique,
n003 column_id,
NVL(c006,'N') is_primary_key,
c007 foreign_key,
--
c008 is_indexed,
c009 check_constraints,
c010 upper_lower,
c011 default_clause,
c012,
c013 between_clause,
NVL(c014,'N') hidden_column,
c015 fk_ref,
NVL(c016,'N') is_pk,
c017 check_constraint_values
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.n001 = c1.n001
order by NVL(n004,3), n003) loop
--------------------------------
-- adjust for datatype semantics
--
if upper(NVL(g_semantics,'DEFAULT')) = 'DEFAULT' then
l_adjusted_data_type := c2.data_type;
elsif upper(g_semantics) = 'CHAR' then
l_adjusted_data_type := c2.data_type;
if upper(l_adjusted_data_type) like 'VARCHAR2%' then
l_adjusted_data_type := replace(l_adjusted_data_type,')',' char)');
end if;
elsif upper(g_semantics) = 'BYTE' then
l_adjusted_data_type := c2.data_type;
if upper(l_adjusted_data_type) like 'VARCHAR2%' then
l_adjusted_data_type := replace(l_adjusted_data_type,')',' byte)');
end if;
end if;
l_unique_count := 0;
------------------------------------------------------------------
-- adjust audit column names if needed based on peference settings
-- note audit column names are stored in the collection as their default names, user defined preferences applied here
--
l_column_name := lower(c2.column_name); --mike
if l_column_name = 'updated' and g_updated_column_name != l_column_name then
l_column_name := lower(g_updated_column_name);
elsif l_column_name = 'updated_by' and g_updated_by_column_name != l_column_name then
l_column_name := lower(g_updated_by_column_name);
elsif l_column_name = 'created' and g_created_column_name != l_column_name then
l_column_name := lower(g_created_column_name);
elsif l_column_name = 'created_by' and g_created_by_column_name != l_column_name then
l_column_name := lower(g_created_by_column_name);
end if;
if c2.is_primary_key = 'Y' and upper(c2.column_name) = 'ID' and upper(NVL(g_prefix_pk_with_tname,'N')) = 'Y' and upper(c2.data_type) = 'NUMBER' then
l_column_name := lower(substr(get_singular(c2.table_name),1,27)||'_ID'); -- mike mike
end if;
----------------------------
-- column name and data type
--
l_sql := l_sql ||' '||rpad(l_column_name,31,' ') || l_adjusted_data_type;
--------------
-- constraints
--
if c2.is_pk = 'Y' then
l_col_check_cons := 'constraint '||gen_valid_identifier_name(c2.column_name,'PK',c2.table_name) ;
if g_TRIGGER_METHOD = 'IDENTITY' then
l_sql := l_sql ||' generated by default on null as identity '||chr(10)||
' '||l_col_check_cons||' primary key';
else
l_sql := l_sql||' not null '||l_col_check_cons||' primary key';
end if;
elsif c2.is_primary_key = 'Y' then
l_col_check_cons := 'constraint '||gen_valid_identifier_name(c2.column_name,'PK',c2.table_name) ;
if g_TRIGGER_METHOD = 'IDENTITY' then
l_sql := l_sql ||' generated by default on null as identity '||chr(10)||
' '||l_col_check_cons||' primary key';
else
l_sql := l_sql||' not null '||l_col_check_cons||' primary key';
end if;
elsif c2.is_unique = 'Y' then
l_unique_count := l_unique_count + 1;
l_sql := l_sql||chr(10)||' '||
'constraint '||gen_valid_identifier_name(c2.column_name,'UNQ',c2.table_name)||' unique';
end if;
--------------------------------
-- generate column slash options
--
if c2.is_unique = 'Y' and nvl(c2.is_primary_key,'N') != 'Y' then
if l_unique_count = 0 then
l_sql := l_sql ||' constraint '||gen_valid_identifier_name(c2.column_name,'UNQ',c2.table_name)||' unique';
end if;
end if;
if c2.hidden_column = 'Y' then
l_sql := l_sql ||' invisible';
end if;
if c2.default_clause is not null and nvl(c2.is_primary_key,'N') != 'Y' then
if c2.data_type in ('NUMBER','INTEGER') or c2.data_type like ('NUMBER%') or c2.default_clause in ('USER','SYSDATE') then
if g_db_version = '12c' then
l_sql := l_sql ||' default on null '||c2.default_clause;
else
l_sql := l_sql ||' default '||c2.default_clause;
end if;
else
if g_db_version = '12c' then
l_sql := l_sql ||' default on null '''||c2.default_clause||'''';
else
l_sql := l_sql ||' default '''||c2.default_clause||'''';
end if;
end if;
end if;
if c2.foreign_key is not null and c2.is_primary_key != 'Y' then
l_sql := l_sql ||chr(10)||' '||
'constraint '||gen_valid_identifier_name(c2.column_name,'FK',c2.table_name)||
chr(10)||' '||'references '||lower(g_schema||c2.foreign_key);
if g_on_delete = 'CASCADE' then
l_sql := l_sql ||' on delete cascade';
elsif g_on_delete = 'SET NULL' or g_on_delete = 'SET_NULL' then
l_sql := l_sql ||' on delete set null';
end if;
else
if c2.fk_ref is not null then
l_sql := l_sql ||chr(10)||' '||
'constraint '||gen_valid_identifier_name(c2.column_name,'FK',c2.table_name)||
chr(10)||' '||'references '||lower(g_schema||get_table_name(c2.fk_ref));
if g_on_delete = 'CASCADE' then
l_sql := l_sql ||' on delete cascade';
elsif g_on_delete = 'SET NULL' or g_on_delete = 'SET_NULL' then
l_sql := l_sql ||' on delete set null';
end if;
end if;
end if;
if c2.check_constraints is not null then
l_sql := l_sql ||c2.check_constraints;
end if;
if c2.between_clause is not null then
l_sql := l_sql ||chr(10)||' '||
'constraint '||gen_valid_identifier_name(c2.column_Name,'BET',c2.table_name)||chr(10)||
' '||'check ('||lower(c2.column_name)||' between '||c2.between_clause||')';
end if;
if c2.is_primary_key = 'N' then
if c2.is_required = 'Y' then
l_sql := l_sql||' not null';
end if;
end if;
-- comma for end of column
l_sql := l_sql||
','||
chr(10);
end loop;
l_sql := rtrim(l_sql,','||chr(10))||chr(10)||')'||chr(10);
-- table compression
if NVL(c1.is_compressed,'N') = 'Y' then
l_sql := l_sql||'compress'||chr(10);
end if;
-- table partitioning
if NVL(c1.is_partitioned,'N') = 'Y' then
-- mike under development
null;
--l_sql := l_sql||'partition'||chr(10);
end if;
-- terminate SQL statement
printc(l_sql||';');
printc(chr(10)||chr(10));
-- auditing
if NVL(c1.is_audited,'N') = 'Y' then
printl('audit all on '||lower(g_schema||trim_identifier_length(clean_name(c1.c001)))||';');
printl('');
end if;
l_cnt := l_cnt + 1;
end loop; -- c1
----------------
-- TAG framework
--
if g_tags_fw = 'Y' then
-- mike mike
--if upper(NVL(g_prefix_pk_with_tname,'N')) = 'Y' then
-- l_pk_column_name := lower(substr(get_singular(c2.table_name),1,27)||'_ID');
--else
l_pk_column_name := 'id';
--end if;
printl('');
printl('-- tag framework');
if clean_name(g_prefix) is not null then
l_tags_tname := clean_name(g_prefix)||'_'||'tags';
else
l_tags_tname := 'TAGS';
end if;
printl('create table '||lower(g_schema||l_tags_tname)||' (');
-- mike mike
printl(l_indent||l_pk_column_name||' number not null primary key,');
printl(l_indent||'tag varchar2(255) not null enable,');
printl(l_indent||'content_pk number,');
printl(l_indent||'content_table varchar2(128),');
printl(l_indent||lower(g_created_column_name)||' timestamp with local time zone not null,');
printl(l_indent||lower(g_created_by_column_name)||' varchar2(255) not null,');
printl(l_indent||lower(g_updated_column_name)||' timestamp with local time zone,');
printl(l_indent||lower(g_updated_by_column_name)||' varchar2(255) )');
printl(';');
printl('');
printl('create or replace trigger '||lower(g_schema||substr(l_tags_tname,1,26))||'_biu');
printl('before insert or update on '||lower(g_schema||l_tags_tname));
printl('for each row');
printl('begin');
printl(' if inserting then ');
--mike mike
printl(' if :new.'||l_pk_column_name||' is null then ');
printl(' :new.'||l_pk_column_name||' := to_number(sys_guid(),''XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX'');');
printl(' end if;');
printl(' :new.'||lower(g_created_column_name)||' := localtimestamp;');
printl(' :new.'||lower(g_created_by_column_name)||' := nvl(sys_context(''APEX$SESSION'',''APP_USER''),user);');
printl(' end if; ');
printl(' if updating then ');
printl(' :new.'||lower(g_created_column_name)||' := localtimestamp; ');
printl(' :new.'||lower(g_created_by_column_name)||' := nvl(sys_context(''APEX$SESSION'',''APP_USER''),user);');
printl(' end if; ');
printl('end '||lower(substr(l_tags_tname,1,26))||'_biu; ');
printl('/');
printl('');
printl('create table '||lower(g_schema||l_tags_tname)||'_tsum (');
printl(l_indent||'tag varchar2(255),');
printl(l_indent||'content_table varchar2(128),');
printl(l_indent||'tag_count number,');
printl(l_indent||'constraint '||lower(l_tags_tname)||'_tspk primary key (tag,content_table) )');
printl(';');
printl('');
printl('create table '||lower(g_schema||l_tags_tname)||'_sum (');
printl(l_indent||'tag varchar2(255),');
printl(l_indent||'tag_count number,');
printl(l_indent||'constraint '||lower(l_tags_tname)||'_spk primary key (tag) )');
printl(';');
printl('');
--printl('create type '||g_schema||l_tags_tname||'_TYPE as table of varchar2(32767) index by binary_integer');
--printl('/');
--printl('');
l_tags_procedure :=
'create or replace procedure '||lower(g_schema||l_tags_tname)||'_sync (
p_new_tags in varchar2,
p_old_tags in varchar2,
p_content_table in varchar2,
p_content_pk in number )
as
type tags is table of varchar2(255) index by varchar2(255);
type tag_values is table of varchar2(32767) index by binary_integer;
l_new_tags_a tags;
l_old_tags_a tags;
l_new_tags tag_values;
l_old_tags tag_values;
l_merge_tags tag_values;
l_dummy_tag varchar2(255);
i integer;
function string_to_table (
str in varchar2,
sep in varchar2 default '':'')
return tag_values
is
temp tag_values;
l_str varchar2(32767) := str;
pos pls_integer;
i pls_integer := 1;
l_sep_length pls_integer := length(sep);
begin
if str is null or sep is null then
return temp;
end if;
if substr( l_str, 1, l_sep_length ) = sep then
l_str := substr( l_str, l_sep_length + 1 );
end if;
if substr( l_str, length( l_str ) - l_sep_length + 1 ) = sep then
l_str := substr( l_str, 1, length( l_str ) - l_sep_length );
end if;
loop
pos := instr( l_str, sep );
exit when nvl(pos,0) = 0;
temp(i) := substr( l_str, 1, pos-1 );
l_str := substr( l_str, pos + l_sep_length );
i := i + 1;
end loop;
temp(i) := trim(l_str);
return temp;
exception when others then return temp;
end;
begin
l_old_tags := string_to_table(p_old_tags,'','');
l_new_tags := string_to_table(p_new_tags,'','');
if l_old_tags.count > 0 then --do inserts and deletes
--build the associative arrays
for i in 1..l_old_tags.count loop
l_old_tags_a(l_old_tags(i)) := l_old_tags(i);
end loop;
for i in 1..l_new_tags.count loop
l_new_tags_a(l_new_tags(i)) := l_new_tags(i);
end loop;
--do the inserts
for i in 1..l_new_tags.count loop
begin
l_dummy_tag := l_old_tags_a(l_new_tags(i));
exception when no_data_found then
insert into REPLACE_ME (tag, content_pk, content_table )
values (trim(l_new_tags(i)), p_content_pk, p_content_table );
l_merge_tags(l_merge_tags.count + 1) := l_new_tags(i);
end;
end loop;
--do the deletes
for i in 1..l_old_tags.count loop
begin
l_dummy_tag := l_new_tags_a(l_old_tags(i));
exception when no_data_found then
delete from REPLACE_ME where content_pk = p_content_pk and tag = l_old_tags(i);
l_merge_tags(l_merge_tags.count + 1) := l_old_tags(i);
end;
end loop;
else --just do inserts
if l_new_tags.exists(1) then
for i in 1..l_new_tags.count loop
insert into REPLACE_ME (tag, content_pk, content_table )
values (trim(l_new_tags(i)), p_content_pk, p_content_table );
l_merge_tags(l_merge_tags.count + 1) := l_new_tags(i);
end loop;
end if;
end if;
for i in 1..l_merge_tags.count loop
merge into REPLACE_ME_tsum s
using (select count(*) tag_count
from REPLACE_ME
where tag = l_merge_tags(i) and content_table = p_content_table ) t
on (s.tag = l_merge_tags(i) and s.content_table = p_content_table )
when not matched then insert (tag, content_table, tag_count)
values (trim(l_merge_tags(i)), p_content_table, t.tag_count)
when matched then update set s.tag_count = t.tag_count;
merge into REPLACE_ME_sum s
using (select sum(tag_count) tag_count
from REPLACE_ME_tsum
where tag = l_merge_tags(i) ) t
on (s.tag = l_merge_tags(i) )
when not matched then insert (tag, tag_count)
values (trim(l_merge_tags(i)), t.tag_count)
when matched then update set s.tag_count = t.tag_count;
end loop;
end '||lower(l_tags_tname)||'_sync;
/';
l_tags_procedure := replace(l_tags_procedure, 'REPLACE_ME',lower(l_tags_tname));
printl(l_tags_procedure);
end if;
-- triggers
l_trig_count := 0;
for c1 in (
select
c001, -- table name
n001,
nvl((select count(*) from apex_collections x where collection_name = 'SCHEMA_TAB_COLS' and x.n001 = c1.n001 and c007 is not null) ,0) c,
nvl((select count(*) from apex_collections x where collection_name = 'SCHEMA_TAB_COLS' and x.n001 = c1.n001 and c002 = 'ID') ,0) id_cols,
nvl((select max(c002) from apex_collections x where collection_name = 'SCHEMA_TAB_COLS' and x.n001 = c1.n001 and c016 = 'Y') ,0) man_pk,
nvl((select count(*) from apex_collections x where collection_name = 'SCHEMA_TAB_COLS' and x.n001 = c1.n001 and c002 = 'TAGS') ,0) tags_cnt,
nvl((select count(*) from apex_collections x where collection_name = 'SCHEMA_TAB_COLS' and x.n001 = c1.n001 and c002 = 'CREATED') ,0) created_cnt,
nvl((select max(c003) from apex_collections x where collection_name = 'SCHEMA_TAB_COLS' and x.n001 = c1.n001 and c002 = 'CREATED') ,0) created_datatype,
nvl((select count(*) from apex_collections x where collection_name = 'SCHEMA_TAB_COLS' and x.n001 = c1.n001 and c002 = 'CREATED_BY') ,0) created_by_cnt,
nvl((select max(c003) from apex_collections x where collection_name = 'SCHEMA_TAB_COLS' and x.n001 = c1.n001 and c002 = 'CREATED_BY') ,0) created_by_datatype,
nvl((select count(*) from apex_collections x where collection_name = 'SCHEMA_TAB_COLS' and x.n001 = c1.n001 and c002 = 'UPDATED') ,0) updated_cnt,
nvl((select max(c003) from apex_collections x where collection_name = 'SCHEMA_TAB_COLS' and x.n001 = c1.n001 and c002 = 'UPDATED') ,0) updated_datatype,
nvl((select count(*) from apex_collections x where collection_name = 'SCHEMA_TAB_COLS' and x.n001 = c1.n001 and c002 = 'UPDATED_BY') ,0) updated_by_cnt,
nvl((select max(c003) from apex_collections x where collection_name = 'SCHEMA_TAB_COLS' and x.n001 = c1.n001 and c002 = 'UPDATED_BY') ,0) updated_by_datatype,
nvl((select count(*) from apex_collections x where collection_name = 'SCHEMA_TAB_COLS' and x.n001 = c1.n001 and c010 is not null) ,0) upper_lower_count
from apex_collections c1
where collection_name = 'SCHEMA'
order by 3,1) loop
c := c + 10;
if c1.man_PK is not null and c1.man_PK != '0' then
l_tab_pk_column_name := c1.man_pk;
else
--mike mike
if upper(NVL(g_prefix_pk_with_tname,'N')) = 'Y' then
l_tab_pk_column_name := lower(substr(get_singular(trim(c1.c001)),1,27)||'_ID');
else
l_tab_pk_column_name := 'id';
end if;
end if;
if g_TRIGGER_METHOD = 'TRIG' or
g_TRIGGER_METHOD = 'TRIGGER' or
g_ROW_VERSION = 'Y' or
g_row_key = 'Y' or
g_sgid = 'Y' or
c1.created_cnt > 0 or
c1.created_by_cnt > 0 or
c1.upper_lower_count > 0 or
(c1.tags_cnt > 0 and g_tags_fw = 'Y') then
l_trig_count := l_trig_count + 1;
if l_trig_count = 1 then
printl('');
printl('-- triggers');
end if;
l_sql := 'create or replace '||l_editionable||'trigger '||lower(g_schema||trim_identifier_length(trim(c1.c001)||'_biu',26))||chr(10)||
l_indent||'before insert or update '||chr(10)||
l_indent||'on '||lower(g_schema||trim_identifier_length(c1.c001))||chr(10)||
l_indent||'for each row'||chr(10);
if p_row_key = 'Y' then
l_sql := l_sql||gen_compress_int(p_inline_yn=>'Y');
end if;
l_sql := l_sql||'begin'||chr(10);
l_logic := false;
if c1.id_cols > 0 then
-- standard generated PK
if g_TRIGGER_METHOD in ( 'IDENTITY', 'NONE' ) then
null;
else
l_logic := true;
-- mike mike
l_sql := l_sql||l_indent||'if :new.'||l_tab_pk_column_name||' is null then'||chr(10);
l_sql := l_sql||l_indent||l_indent||':new.'||l_tab_pk_column_name||' := to_number(sys_guid(), ''XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX'');'||chr(10);
l_sql := l_sql||l_indent||'end if;'||chr(10);
end if;
elsif c1.man_pk is not null and c1.man_pk != '0' then
-- manual PK
if g_TRIGGER_METHOD in ( 'IDENTITY', 'NONE' ) then
null;
else
l_logic := true;
l_sql := l_sql||l_indent||'if :new.'||lower(c1.man_pk)||' is null then'||chr(10);
l_sql := l_sql||l_indent||l_indent||':new.'||lower(c1.man_pk)||' := to_number(sys_guid(), ''XXXXXXXXXXXXXXXXXXXXXXXXXXXXXXXX'');'||chr(10);
l_sql := l_sql||l_indent||'end if;'||chr(10);
end if;
end if;
if g_ROW_VERSION = 'Y' then
l_logic := true;
l_sql := l_sql||l_indent||'if inserting then'||chr(10);
l_sql := l_sql||l_indent||l_indent||':new.row_version := 1;'||chr(10);
l_sql := l_sql||l_indent||'elsif updating then'||chr(10);
l_sql := l_sql||l_indent||l_indent||':new.row_version := nvl(:old.row_version,0) + 1;'||chr(10);
l_sql := l_sql||l_indent||'end if;'||chr(10);
end if;
if g_row_key = 'Y' then
l_logic := true;
l_sql := l_sql||l_indent||'if inserting then'||chr(10);
l_sql := l_sql||l_indent||l_indent||':new.row_key := compress_int('||lower(l_sequence)||'.nextval);'||chr(10);
l_sql := l_sql||l_indent||'end if;'||chr(10);
end if;
if g_sgid = 'Y' then
l_logic := true;
l_sql := l_sql||l_indent||'if :new.security_group_id is null then'||chr(10);
l_sql := l_sql||l_indent||l_indent||':new.security_group_id := 0;'||chr(10);
l_sql := l_sql||l_indent||'end if;'||chr(10);
end if;
if c1.created_cnt > 0 or c1.created_by_cnt > 0 then
l_logic := true;
l_sql := l_sql||' if inserting then'||chr(10);
if c1.created_cnt > 0 then
l_sql := l_sql||l_indent||l_indent||':new.'||lower(g_created_column_name)||' := '||get_date_stamp(c1.created_datatype)||';'||chr(10);
end if;
if c1.created_by_cnt > 0 then
l_sql := l_sql||l_indent||l_indent||':new.'||lower(g_created_by_column_name)||' := '||g_user||';'||chr(10);
end if;
l_sql := l_sql||l_indent||'end if;'||chr(10);
end if;
if c1.updated_cnt > 0 or c1.updated_by_cnt > 0 then
l_logic := true;
--l_sql := l_sql||' if inserting or updating then'||chr(10);
if c1.updated_cnt > 0 then
l_sql := l_sql||l_indent||':new.'||lower(g_updated_column_name)||' := '||get_date_stamp(c1.updated_datatype)||';'||chr(10);
end if;
if c1.updated_by_cnt > 0 then
l_sql := l_sql||l_indent||':new.'||lower(g_updated_by_column_name)||' := '||g_user||';'||chr(10);
end if;
end if;
-- upper lower
for c2 in (select c002 column_name, c010 upper_lower from apex_collections x where collection_name = 'SCHEMA_TAB_COLS' and x.n001 = c1.n001 and c010 is not null) loop
if c2.upper_lower is not null and c2.column_Name is not null then
l_logic := true;
l_sql := l_sql||l_indent||':new.'||lower(c2.column_name)||' := '||c2.upper_lower||'(:new.'||lower(c2.column_name)||');'||chr(10);
end if;
end loop;
-- tags
if g_tags_fw = 'Y' and c1.tags_cnt > 0 then
l_logic := true;
l_sql := l_sql||l_indent||'if :old.tags is not null or :new.tags is not null then'||chr(10);
l_sql := l_sql||l_indent||l_indent||lower(l_tags_tname)||'_sync ('||chr(10);
l_sql := l_sql||l_indent||l_indent||l_indent||'p_new_tags => :new.tags,'||chr(10);
l_sql := l_sql||l_indent||l_indent||l_indent||'p_old_tags => :old.tags,'||chr(10);
l_sql := l_sql||l_indent||l_indent||l_indent||'p_content_table => '''||trim_identifier_length(c1.c001)||''','||chr(10);
l_sql := l_sql||l_indent||l_indent||l_indent||'p_content_pk => :new.'||lower(l_tab_pk_column_name)||');'||chr(10);
l_sql := l_sql||l_indent||'end if;'||chr(10);
end if;
if not l_logic then
l_sql := l_sql ||l_indent||'null;'||chr(10);
end if;
l_sql := l_sql||'end '||lower(trim_identifier_length(trim(c1.c001)||'_biu',26))||';';
printc(l_sql);
printc(chr(10)||'/'||chr(10)||chr(10));
-- before delete trigger for use with tags
if g_tags_fw = 'Y' and c1.tags_cnt > 0 then
printl('create or replace '||l_editionable||'trigger '||lower(g_schema||trim_identifier_length(trim(c1.c001)||'_bd',27)));
printl(l_indent||'before delete on '||lower(g_schema||trim_identifier_length(c1.c001)));
printl(l_indent||'for each row');
printl(l_indent||'begin');
printl(l_indent||lower(l_tags_tname)||'_sync (');
printl(l_indent||' p_new_tags => null,');
printl(l_indent||' p_old_tags => :old.tags,');
printl(l_indent||' p_content_table => '''||lower(trim_identifier_length(c1.c001))||''',');
printl(l_indent||' p_content_pk => :old.'||lower(l_tab_pk_column_name)||' );');
printl('end '||trim_identifier_length(trim(lower(c1.c001))||'_bd',27)||'; ');
printl('/');
printl('');
end if;
l_cnt := l_cnt + 1;
end if;
end loop;
-- indexes
for c1 in (
select
c001 table_Name,
c002 column_name,
c003 data_type,
decode(c004,'Y','Yes','N','No') is_nullable,
decode(c005,'Y','Yes','N','No') is_unique,
n003 column_id,
decode(c006,'Y','Yes','N','No') is_primary_key,
c007 foreign_key,
c008 is_indexed,
c009 check_constraints,
c010 upper_lower,
c011 default_clause,
n002 col_guid
from apex_collections c1
where collection_name = 'SCHEMA_TAB_COLS' and ( c007 is not null or c008 = 'Y' or c015 is not null)
order by c001,c002,c007)
loop
c := c + 10;
if c1.table_name != l_last_table then
l_idx_cnt := 0;
end if;
l_idx_cnt := l_idx_cnt + 1;
l_total_indexes := l_total_indexes + 1;
if l_total_indexes = 1 then
printl('');
printl('-- indexes');
end if;
l_sql := 'create index '||
lower(g_schema||trim_identifier_length(c1.table_name,27))||'_i'||
l_idx_cnt||' on '||lower(g_schema||trim_identifier_length(c1.table_name))||' ('||lower(trim_identifier_length(c1.column_name))||')';
printc(l_sql);
printc(';'||chr(10));
l_last_table := c1.table_name;
end loop;
--
-- table comments
--
for c1 in (
select
c001 table_name,
c007 comments
from apex_collections c1
where collection_name = 'SCHEMA' and c007 is not null
order by c001)
loop
c := c + 10;
l_comment_count := l_comment_count + 1;
if l_comment_count = 1 then
printl('');
printl('-- comments');
end if;
printl('comment on table '||lower(g_schema||c1.table_name)||' is '''||replace(c1.comments,'''','''''')||''';');
end loop;
--
-- column comments
--
for c1 in (
select
c001 table_name,
c002 column_name,
c003 data_type,
decode(c004,'Y','Yes','N','No') is_nullable,
decode(c005,'Y','Yes','N','No') is_unique,
n003 column_id,
decode(c006,'Y','Yes','N','No') is_primary_key,
c007 foreign_key,
c008 is_indexed,
c009 check_constraints,
c010 upper_lower,
c011 default_clause,
c012 comments,
n002 col_guid
from apex_collections c1
where collection_name = 'SCHEMA_TAB_COLS' and c012 is not null
order by c001,c002,c007)
loop
c := c + 10;
l_comment_count := l_comment_count + 1;
if l_comment_count = 1 then
printl('');
printl('-- comments');
end if;
printl('comment on column '||lower(g_schema||c1.table_name||'.'||c1.column_name)||' is '''||replace(c1.comments,'''','''''')||''';');
end loop;
-- REST enablement
l_rest_count := 0;
for c1 in (
select c001 object_name
from apex_collections c1
where collection_name = 'SCHEMA' and
c001 is not null and
c011 = 'Y' and
c006 = 'TABLE'
order by seq_id) loop
c := c + 10;
l_rest_count := l_rest_count + 1;
if l_rest_count = 1 then
printl('');
printl('-- REST ENABLE tables using Oracle REST Data Services (ORDS)');
end if;
printl('begin');
printl(l_indent||'ords.enable_object(p_enabled=>TRUE, p_object=>'''||esc_quotes(lower(g_schema||c1.object_name))||''');');
printl('end;');
printl('/');
printl('');
end loop;
-------------------
-- history triggers
--
l_history_table_count := 0;
for c1 in (select count(*) c from apex_collections where collection_name = 'SCHEMA' and c010 = 'Y') loop
l_history_table_count := c1.c;
end loop;
if p_history_tables = 'Y' or l_history_table_count > 0 then
printl('');
printl('-- history tracking');
if clean_name(g_prefix) is not null then
l_history_tname := clean_name(g_prefix)||'_'||'history';
else
l_history_tname := 'history';
end if;
l_history_tname_seq := trim_identifier_length(l_history_tname||'_seq');
printl('create sequence '||lower(g_schema||l_history_tname_seq)||';');
printl('create table '||lower(g_schema||l_history_tname)||' (');
printl(l_indent||'id number primary key,');
printl(l_indent||'table_name varchar2(128),');
printl(l_indent||'column_name varchar2(128),');
printl(l_indent||'action varchar2(1) check (action in (''I'',''U'',''D'')),');
printl(l_indent||'action_date '||lower(g_date_data_type)||',');
printl(l_indent||'action_by varchar2(255),');
printl(l_indent||'data_type varchar2(255),');
printl(l_indent||'pk1 number,');
printl(l_indent||'tab_row_version integer,');
printl(l_indent||'old_vc varchar2(4000),');
printl(l_indent||'new_vc varchar2(4000),');
printl(l_indent||'old_number number,');
printl(l_indent||'new_number number,');
printl(l_indent||'old_date date,');
printl(l_indent||'new_date date,');
printl(l_indent||'old_ts timestamp,');
printl(l_indent||'new_ts timestamp,');
printl(l_indent||'old_tswtz timestamp with time zone,');
printl(l_indent||'new_tswtz timestamp with time zone,');
printl(l_indent||'old_tswltz timestamp with local time zone,');
printl(l_indent||'new_tswltz timestamp with local time zone,');
printl(l_indent||'old_clob clob,');
printl(l_indent||'new_clob clob,');
printl(l_indent||'old_blob blob,');
printl(l_indent||'new_blob blob');
printl(')');
printl('/');
printl('');
printl('create index '||lower(g_schema||l_history_tname)||'_idx1 on '||lower(g_schema||l_history_tname)||' (pk1);');
printl('create index '||lower(g_schema||l_history_tname)||'_idx2 on '||lower(g_schema||l_history_tname)||' (table_name, column_name);');
printl('');
printl('create or replace view '||lower(g_schema||l_history_tname)||'_v'||' as');
printl('select id,');
printl(' table_name,');
printl(' column_name,');
printl(' decode(action,''U'',''Update'',''D'',''Delete'') action,');
printl(' action_date,');
printl(' action_by,');
printl(' pk1 table_primary_key,');
printl(' tab_row_version table_row_version,');
printl(' decode(data_type,');
printl(' ''NUMBER'',old_number||'' > ''||new_number,');
printl(' ''VARCHAR2'',substr(old_vc,1,50)||'' > ''||substr(new_vc,1,50),');
printl(' ''DATE'',to_char(old_date,''DD-MON-YYY HH24:MI:SS'')||'' > ''||to_char(new_date,''DD-MON-YYY HH24:MI:SS''),');
printl(' ''TIMESTAMP'',to_char(old_ts,''DD-MON-YYY HH24:MI:SS'')||'' > ''||to_char(new_ts,''DD-MON-YYY HH24:MI:SS''),');
printl(' ''TIMESTAMP WITH TIMEZONE'',to_char(old_tswtz,''DD-MON-YYY HH24:MI:SS'')||'' > ''||to_char(new_tswtz,''DD-MON-YYY HH24:MI:SS''),');
printl(' ''TIMESTAMP WITH LOCAL TIMEZONE'',to_char(old_tswltz,''DD-MON-YYY HH24:MI:SS'')||'' > ''||to_char(new_tswltz,''DD-MON-YYY HH24:MI:SS''),');
printl(' ''BLOB'',''length ''||dbms_lob.getlength(old_blob)||'' > ''||'' length ''||dbms_lob.getlength(new_blob),');
printl(' ''CLOB'',dbms_lob.substr(old_vc,50,1)||'' > ''||dbms_lob.substr(new_vc,50,1)');
printl(' ) change');
printl('from '||lower(g_schema||l_history_tname));
printl('/');
printl('');
--
-- history triggers
--
for c1 in (
select
c001 object_name,
c006 object_type,
c010 history_tables_yn,
n001
from apex_collections c1
where collection_name = 'SCHEMA' and c001 is not null
order by seq_id) loop
l_del := null;
l_hist_str := null;
l_hist_dt := null;
if g_ROW_VERSION = 'Y' then
l_row_version_num := ':new.row_version';
else
l_row_version_num := 'null';
end if;
if c1.object_type = 'TABLE' and c1.history_tables_yn = 'Y' then
-- determine history date
if g_date_data_type = 'DATE' then
l_hist_sysdate := 'SYSDATE';
elsif c1.object_type = 'TIMESTAMP' then
l_hist_sysdate := 'SYSTIMESTAMP';
elsif c1.object_type = 'TIMESTAMP WITH LOCAL TIME ZONE' then
l_hist_sysdate := 'SYSTIMESTAMP';
else
l_hist_sysdate := 'SYSDATE';
end if;
-- after update trigger
printl('create or replace '||l_editionable||'trigger '||lower(g_schema||substr(c1.object_name,1,26))||'_aud ');
printl(l_indent||'after update or delete on '||lower(g_schema||c1.object_name));
printl(l_indent||'for each row');
printl('declare');
printl(l_indent||'t varchar2(128) := '''||c1.object_name||''';');
printl(l_indent||'u varchar2(128) := '||g_user||';');
for c2 in (select sum(decode(c003,'DATE',1,0)) date_count,
sum(decode(c003,'TIMESTAMP',1,0)) timestamp_count,
sum(decode(c003,'TIMESTAMP WITH LOCAL TIME ZONE',1,0)) tswltz_count,
sum(decode(c003,'TIMESTAMP WITH TIME ZONE',1,0)) tswtz_count,
max(decode(c006,'Y',c002,null)) pk
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.c002 not in ('UPDATED','UPDATED_BY','CREATED','CREATED_BY','ROW_KEY','SECURITY_GROUP_ID','ROW_VERSION') and
c.n001 = c1.n001) loop
l_date_count := c2.date_count;
l_timestamp_count := c2.timestamp_count;
l_tswltz_count := c2.tswltz_count;
l_tswtz_count := c2.tswtz_count;
l_pk_column_name := c2.pk;
end loop;
printl('begin');
printl('if updating then');
--
for c2 in (
select
c001 table_name,
c002 column_name,
upper(c003) data_type,
c006 is_pk_yn,
n003 column_id
from apex_collections c
where collection_name = 'SCHEMA_TAB_COLS' and
c.c002 not in ('UPDATED','UPDATED_BY','CREATED','CREATED_BY','ROW_KEY','SECURITY_GROUP_ID','ROW_VERSION') and
c.n001 = c1.n001) loop
if c2.data_type like 'VARCHAR%' then
l_hist_dt := 'VARCHAR2';
l_hist_str := 'old_vc, new_vc';
elsif c2.data_type in ('NUMBER','INTEGER') then
l_hist_dt := 'NUMBER';
l_hist_str := 'old_number, new_number';
elsif c2.data_type in ('DATE') then
l_hist_dt := 'DATE';
l_hist_str := 'old_date, new_date';
elsif c2.data_type in ('TIMESTAMP') then
l_hist_dt := 'TIMESTAMP';
l_hist_str := 'old_ts, new_ts';
elsif c2.data_type in ('TIMESTAMP WITH LOCAL TIME ZONE') then
l_hist_dt := 'TIMESTAMP WITH LOCAL TIMEZONE';
l_hist_str := 'old_tswltz, new_tswltz';
elsif c2.data_type in ('TIMESTAMP WITH TIME ZONE') then
l_hist_dt := 'TIMESTAMP WITH TIMEZONE';
l_hist_str := 'old_tswtz, new_tswtz';
elsif c2.data_type in ('CLOB') then
l_hist_dt := 'CLOB';
l_hist_str := 'old_clob, new_clob';
elsif c2.data_type in ('BLOB') then
l_hist_dt := 'BLOB';
l_hist_str := 'old_blob, new_blob';
else
l_hist_dt := c2.data_type;
end if;
if g_ROW_VERSION = 'Y' and c2.column_name = 'ROW_VERSION' then
null;
else
if c2.data_type like 'VARCHAR%' then
printl(l_indent||'if (:old.'||lower(c2.column_name)||' is null and :new.'||lower(c2.column_name)||' is not null) or ');
printl(l_indent||l_indent||'(:old.'||lower(c2.column_name)||' is not null and :new.'||lower(c2.column_name)||' is null) or ');
printl(l_indent||l_indent||':old.'||lower(c2.column_name)||' != :new.'||lower(c2.column_name)||' then ');
elsif c2.data_type in ('INTEGER') or c2.data_type like 'NUMBER%' then
printl(l_indent||'if (:old.'||lower(c2.column_name)||' is null and :new.'||lower(c2.column_name)||' is not null) or ');
printl(l_indent||l_indent||'(:old.'||lower(c2.column_name)||' is not null and :new.'||lower(c2.column_name)||' is null) or ');
printl(l_indent||l_indent||':old.'||lower(c2.column_name)||' != :new.'||lower(c2.column_name)||' then ');
elsif c2.data_type in ('DATE') then
printl(l_indent||'if (:old.'||lower(c2.column_name)||' is null and :new.'||lower(c2.column_name)||' is not null) or ');
printl(l_indent||l_indent||'(:old.'||lower(c2.column_name)||' is not null and :new.'||lower(c2.column_name)||' is null) or ');
printl(l_indent||l_indent||':old.'||lower(c2.column_name)||' != :new.'||lower(c2.column_name)||' then ');
elsif c2.data_type in ('TIMESTAMP') then
printl(l_indent||'if (:old.'||lower(c2.column_name)||' is null and :new.'||lower(c2.column_name)||' is not null) or ');
printl(l_indent||l_indent||'(:old.'||lower(c2.column_name)||' is not null and :new.'||lower(c2.column_name)||' is null) or ');
printl(l_indent||l_indent||':old.'||lower(c2.column_name)||' != :new.'||lower(c2.column_name)||' then ');
elsif c2.data_type in ('TIMESTAMP WITH LOCAL TIME ZONE') then
printl(l_indent||'if (:old.'||lower(c2.column_name)||' is null and :new.'||lower(c2.column_name)||' is not null) or ');
printl(l_indent||l_indent||'(:old.'||lower(c2.column_name)||' is not null and :new.'||lower(c2.column_name)||' is null) or ');
printl(l_indent||l_indent||':old.'||lower(c2.column_name)||' != :new.'||lower(c2.column_name)||' then ');
elsif c2.data_type in ('CLOB','BLOB') then
printl(l_indent||'if (:old.'||lower(c2.column_name)||' is null and :new.'||lower(c2.column_name)||' is not null) or ');
printl(l_indent||l_indent||'(:old.'||lower(c2.column_name)||' is not null and :new.'||lower(c2.column_name)||' is null) or ');
printl(l_indent||l_indent||'dbms_lob.getlength(:old.'||lower(c2.column_name)||') != dbms_lob.getlength(:new.'||lower(c2.column_name)||') or ');
printl(l_indent||l_indent||'NVL(dbms_lob.compare(:old.'||lower(c2.column_name)||','||':new.'||lower(c2.column_name)||'),0) > 0 then');
else
-- other data types
printl(l_indent||'if (:old.'||lower(c2.column_name)||' is null and :new.'||lower(c2.column_name)||' is not null) or ');
printl(l_indent||l_indent||'(:old.'||lower(c2.column_name)||' is not null and :new.'||lower(c2.column_name)||' is null) or ');
printl(l_indent||l_indent||':old.'||lower(c2.column_name)||' != :new.'||lower(c2.column_name)||' then ');
end if;
-- build insert statement for history
l_ins := l_indent||l_indent||'insert into '||lower(g_schema||l_history_tname)||' ('||chr(10)||
l_indent||l_indent||l_indent||'id, table_name, column_name, pk1, tab_row_version, action, action_date, action_by, data_type, '||l_hist_str||chr(10)||
l_indent||l_indent||') values ('||chr(10)||
l_indent||l_indent||l_indent||lower(l_history_tname_seq)||'.nextval, t, '||
''''||c2.column_name||''''||', '||':old.'||lower(l_pk_column_name)||', '||lower(l_row_version_num)||', ''U'', '||lower(l_hist_sysdate)||', u, '||
''''||upper(l_hist_dt)||''', :old.'||lower(c2.column_name)||', :new.'||lower(c2.column_name)||');'||chr(10);
printl(l_ins);
l_del := l_del || replace(replace(l_ins,'''U''','''D'''),l_indent||l_indent,l_indent);
printl(l_indent||'end if;');
end if;
end loop;
-- deleting
printl('elsif deleting then');
printl(l_del);
printl('end if;');
printl('end '||lower(substr(c1.object_name,1,26))||'_aud;');
printl('/');
printl('');
end if;
end loop;
end if;
--------------------------
-- Generate APIs on tables
--
l_api_count := 0;
for c1 in (
select
c001 object_name,
c006 object_type,
n001
from apex_collections c1
where collection_name = 'SCHEMA' and
c001 is not null and
c012 = 'Y' and
c006 = 'TABLE'
order by seq_id) loop
l_api_count := l_api_count + 1;
if l_api_count = 1 then
printl('');
printl('-- APIs --');
end if;
printl(gen_api (
p_n001 => c1.n001,
p_indent => l_indent,
p_object_type => c1.object_type,
p_object_name => c1.object_name,
p_type => 'SPEC',
p_prefix => null));
printl(gen_api (
p_n001 => c1.n001,
p_indent => l_indent,
p_object_type => c1.object_type,
p_object_name => c1.object_name,
p_type => 'BODY',
p_prefix => null));
end loop;
if l_api_count > 0 then
printl('');
end if;
--------
-- Views
--
for c1 in (
select upper(c001) view_name,
NVL(c017,'N') select_example,
n001
from APEX_COLLECTIONS
where collection_name = 'LINES' and
c002 = 'TABLE' and
(upper(c001) like 'VIEW %' or upper(c001) like 'VIEW'||chr(9)||'%') ) loop
l_view_count := l_view_count + 1;
if l_view_count = 1 then
printl('');
printl('-- create views');
end if;
create_view(c1.view_name);
if c1.select_example = 'Y' then
printl(gen_example_sql (
p_n001 => c1.n001,
p_indent => l_indent,
p_object_type => 'VIEW',
p_object_name => c1.view_name,
p_type => 'SELECT',
p_iteration => 1)
);
end if;
end loop;
-- reset collection
begin
APEX_COLLECTION.CREATE_OR_TRUNCATE_COLLECTION(p_collection_name => 'PRIMARY_KEYS');
exception when others then
log_status (p_status=>'Unexpected error attempting to create primary_keys collection', p_context => 'save_as_sql',p_sqlerrm=>sqlerrm);
end;
-- Generate SQL Examples
l_sql_count := 0;
for c1 in (
select
n001,
c001 object_name,
c006 object_type,
NVL(n002,0) insert_examples,
upper(NVL(c017,'N')) select_example,
NVL(c018,'Y') uncomment,
NVL(c019,'NO WS') worksheet_table,
NVL(c020,'N') noload_ws_data
from apex_collections c1
where collection_name = 'SCHEMA' and
c001 is not null and
c006 = 'TABLE'
order by seq_id) loop
if c1.insert_examples > 0 or c1.select_example = 'Y' then
l_sql_count := l_sql_count + 1;
if l_sql_count = 1 and c1.worksheet_table is null then
printl('');
printl('-- SQL Examples --');
end if;
-- htp.p('hello: c1.worksheet_table='||c1.worksheet_table||', c1.select_example='||c1.select_example); -- mike
if c1.insert_examples > 0 then
if c1.uncomment = 'N' then printl('/*'); end if;
printl('-- load data');
printl(' ');
for j in 1..c1.insert_examples loop
printl(gen_example_sql (
p_n001 => c1.n001,
p_indent => l_indent,
p_object_type => c1.object_type,
p_object_name => c1.object_name,
p_type => 'INSERT',
p_iteration => j)
);
end loop;
printl('commit;');
if c1.uncomment = 'N' then printl('*/'); end if;
end if;
if c1.select_example = 'Y' and c1.worksheet_table != 'NO WS' then
-- yes do generate select statement
-- only for non worksheet examples
if c1.uncomment = 'N' then printl('/*'); end if;
printl(gen_example_sql (
p_n001 => c1.n001,
p_indent => l_indent,
p_object_type => c1.object_type,
p_object_name => c1.object_name,
p_type => 'SELECT',
p_iteration => 1)
);
if c1.uncomment = 'N' then printl('*/'); end if;
end if;
end if;
if c1.worksheet_table is not null then
if c1.noload_ws_data = 'N' then
-- load the data unless requested not to load the data
g_worksheet_data_ins_count := g_worksheet_data_ins_count + 1;
if g_worksheet_data_ins_count = 1 then
printl('-- load data');
end if;
load_worksheet_data (
p_n001 => c1.n001,
p_object_type => c1.object_type,
p_object_name => c1.object_name,
p_worksheet => trim(c1.worksheet_table),
p_format_mask => p_format_mask);
end if;
if c1.select_example = 'Y' then
-- generate SQL select example for worksheet data
printl(gen_example_sql (
p_n001 => c1.n001,
p_indent => l_indent,
p_object_type => c1.object_type,
p_object_name => c1.object_name,
p_type => 'SELECT',
p_iteration => 1)
);
end if;
end if;
end loop;
end save_as_sql;
end eba_dbtools_design_schema_pub;
create or replace package eba_dbtools_design_schema_pub as
g_debug varchar2(32767) := null;
g_settings_override varchar2(32767) := null;
-- global settings
g_prefix varchar2(30) default null; -- prefix all objects with this text, if not proved an underscore will be added
g_api varchar2(1) default 'N'; -- generate a PL/SQL API for each table
g_AUDIT_COLS varchar2(1) default 'N'; -- add created, updated, created_by and updated_by columns and trigger logic per table to track who created or updated rows
g_COMPRESSED varchar2(1) default 'N'; -- make tables compressed by adding compression option
g_DATE_DATATYPE varchar2(60) := 'DATE'; -- generate date columns using DATE, TIMESTAMP, TIMESTAMP WITH TIMEZONE, TIMESTAMP WITH LOCAL TIME ZONE
g_ON_DELETE varchar2(60) := 'CASCADE'; -- for foreign keys perform on delete CASCADE, RESTRICT, or SET NULL
g_ROW_KEY varchar2(1) default 'N'; -- generate a rowkey using a compress ID function on a sequence to provide a human readable key colunn
g_SGID varchar2(1) default 'N'; -- generate a security group ID column to support multi-tenant apps
g_ROW_VERSION varchar2(1) default 'N'; -- add a row version column to each table and the trigger logic to populate it, starts at 1 and increments by 1 for each update
g_TRIGGER_METHOD varchar2(60) := 'TRIG'; -- method of creating triggers to set primary key values, TRIG gets a GUID numeric id, IDENTITY use 12c identities
g_INCLUDE_DROPS varchar2(1) default 'N'; -- for all objects created generate drop scripts on top of the generated output
g_LONGER_IDENTIFIERS varchar2(1) default 'N'; -- support longer 128 byte object identifiers if Y, if N restrict to 30 bytes
g_HISTORY_TABLES varchar2(1) default 'N'; -- create a history table and view to track column changes
g_DB_VERSION varchar2(6) := '12c'; -- generate syntax for database version 11g or 12c
g_AUTO_GEN_PK varchar2(1) := 'Y'; -- automatically add a primary key column to tables
g_editionable varchar2(1) := 'N'; -- make PL/SQL objects editionable
g_language varchar2(2) := 'EN'; -- language control for generated data
g_apex varchar2(1) := 'N'; -- generate triggers that set updated_by and inserted_by using SYS_CONTEXT to obtain app user
--
g_prefix_pk_with_tname varchar2(1) := 'N'; --mike
g_created_column_name varchar2(50) := 'created'; --mike
g_created_by_column_name varchar2(50) := 'created_by'; --mike
g_updated_column_name varchar2(50) := 'updated'; --mike
g_updated_by_column_name varchar2(50) := 'updated_by'; --mike
--
g_audit varchar2(1) := 'N'; -- generated oracle audit on all tables
g_longer_varchars_yn varchar2(1) := 'N'; -- support for varchar2(32767) if Y, if N maximum is varchar2(4000)
g_verbose_yn varchar2(1) := 'N'; -- show all settings at end of generated scripts if Y, if N only show non default settings
g_schema varchar2(128) := null; -- prefix object names with this schema dot
g_inserts number := 0; -- show SQL insert examples for all tables
g_selects varchar2(1) := 'N'; -- show SQL select examples for all tables
g_uncomment varchar2(1) := 'Y'; -- uncomment SQL insert and select examples
g_decimal_character varchar2(1) := '.'; -- under development
g_group_seperator varchar2(1) := ','; -- under development
g_tags_fw varchar2(1) := 'N'; -- generate tag framework
function get_data_example (p_example_number in number default 1) return varchar2;
procedure get_model_worksheets (
p_saved_model_id in number default null)
;
procedure save_model_worksheets (
p_saved_model_id in number default null)
;
procedure log_status (
p_status in varchar2 default null,
p_context in varchar2 default null,
p_sqlerrm in varchar2 default null)
;
procedure remove_ws_not_in_use (
p_markdown_sql in varchar2 default null)
;
function worksheet_collection_exists (
p_worksheet_name in varchar2 default null)
return boolean
;
function is_number (p_string in varchar2 default null) return boolean;
function get_column_datatype (
p_collection in varchar2 default null,
p_column in varchar2 default null,
p_date_format_mask in varchar2 default null)
return varchar2;
function get_worksheet_structure (
p_table_name in varchar2 default null,
p_collection_name in varchar2 default null,
p_first_row_is_header_yn in varchar2 default 'Y',
p_date_format_mask in varchar2 default 'DD-MON-YYYY')
return varchar2
;
procedure set_settings_overrides (
p_string in varchar2 default null);
procedure get_default_settings (
p_TABLE_PREFIX out varchar2,
p_ON_DELETE out varchar2,
p_COMPRESSED out varchar2,
p_PRIMARY_KEY out varchar2,
p_TRIGGER_METHOD out varchar2,
p_DATE_DATATYPE out varchar2,
p_API out varchar2,
p_AUDIT_COLS out varchar2,
p_ROW_KEY out varchar2,
p_SGID out varchar2,
p_ROW_VERSION out varchar2,
p_DB_VERSION out varchar2,
p_INCLUDE_DROPS out varchar2,
p_LONGER_IDENTIFIERS out varchar2,
p_HISTORY_TABLES out varchar2,
p_AUTO_GEN_PK out varchar2,
p_EDITIONABLE out varchar2,
p_language out varchar2,
p_APEX out varchar2,
--
p_prefix_pk_with_tname out varchar2, --mike
p_created_column_name out varchar2, --mike
p_created_by_column_name out varchar2, --mike
p_updated_column_name out varchar2, --mike
p_updated_by_column_name out varchar2, --mike
--
p_audit out varchar2,
p_longer_varchars_yn out varchar2,
p_verbose_yn out varchar2,
p_schema out varchar2,
p_inserts out number,
p_selects out varchar2,
p_uncomment out varchar2,
p_tags_fw out varchar2,
p_semantics out varchar2
)
;
function trim_identifier_length (
p_object_name in varchar2 default null,
p_length_override in number default 0)
return varchar2;
function get_settings return varchar2 ;
function get_model (p_id in number) return varchar2 ;
function get_model_from_history (p_id in number) return varchar2 ;
function get_view_syntax return varchar2 ;
procedure print_generated;
procedure print_settings (p_text in varchar2 default null);
procedure print_settings2 (p_text in varchar2 default null);
procedure log_history (
p_str in varchar2 default null)
;
function pre_process_lines (
p_tables in varchar2 default null,
p_name in varchar2 default null)
return varchar2
;
function clean_name (p_name in varchar2)
return varchar2;
procedure extract_comments (
p_string in varchar2 default null,
p_new_string out varchar2,
p_comments out varchar2
);
function get_pound_options return varchar2;
function get_additional_syntax return varchar2;
function get_column_datatypes return varchar2;
function get_column_directives return varchar2;
function get_table_directives return varchar2;
function get_rules return varchar2;
procedure init_collections ;
function get_example (p_number in number default 1) return varchar2;
function get_example_desc (p_number in number default 1) return varchar2;
procedure add_tables (
p_table_prefix in varchar2 default null,
p_date_datatype in varchar2 default null,
p_inc_auditing in varchar2 default null,
p_primary_key in varchar2 default null,
p_tables in varchar2 default null,
p_row_version in varchar2 default 'N',
p_row_key in varchar2 default 'N',
p_sgid in varchar2 default 'N',
p_compressed in varchar2 default 'N',
p_longer_identifiers in varchar2 default 'N',
p_auto_gen_pk in varchar2 default 'Y',
p_history_tables in varchar2 default 'N',
p_apis in varchar2 default 'N',
p_audit_cols in varchar2 default 'N',
p_audit in varchar2 default 'N',
p_longer_varchars_yn in varchar2 default 'N',
p_verbose_yn in varchar2 default 'N',
p_schema in varchar2 default null,
p_inserts in number default 0,
p_selects in varchar2 default 'N',
p_uncomment in varchar2 default 'Y',
p_tags_fw_yn in varchar2 default 'N',
p_semantics in varchar2 default 'DEFAULT'
);
procedure save_as_sql (
p_app_user in varchar2 default null,
p_app_session in varchar2 default null,
p_trigger_method in varchar2 default 'STANDARD',
p_fk in varchar2 default 'RESTRICT',
P_row_version in varchar2 default 'N',
p_row_key in varchar2 default 'N',
p_sgid in varchar2 default 'N',
P_TABLE_PREFIX in varchar2 default null,
p_compressed in varchar2 default 'N',
p_db_version in varchar2 default '12c',
p_include_drops in varchar2 default 'N',
p_LONGER_IDENTIFIERS in varchar2 default 'N',
p_history_tables in varchar2 default 'N',
p_apis in varchar2 default 'N',
p_AUTO_GEN_PK in varchar2 default 'Y',
p_audit_cols in varchar2 default 'N',
p_DATE_DATATYPE in varchar2 default 'DATE',
p_editionable in varchar2 default 'N',
p_language in varchar2 default 'EN',
p_apex in varchar2 default 'N',
--
p_prefix_pk_with_tname in varchar2, --mike
p_created_column_name in varchar2, --mike
p_created_by_column_name in varchar2, --mike
p_updated_column_name in varchar2, --mike
p_updated_by_column_name in varchar2, --mike
--
p_audit in varchar2 default 'N',
p_longer_varchars_yn in varchar2 default 'N',
p_verbose_yn in varchar2 default 'N',
p_schema in varchar2 default null,
p_inserts in number default 0,
p_selects in varchar2 default 'N',
p_uncomment in varchar2 default 'Y',
p_format_mask in varchar2 default 'MM/DD/RR HH24:MI',
p_tags_fw_yn in varchar2 default 'N',
p_semantics in varchar2 default 'DEFAULT',
--
p_message out varchar2,
p_script_id out varchar2
);
end eba_dbtools_design_schema_pub;
$("#gen_sql_btn").prop('disabled',true);
generateSQL();
apex.message.hidePageSuccess();
$(window).trigger("apexwindowresized");
rawSQLCache = $v('P300_RAW_SQL');
var wsMenu$ = $("#worksheetsMenu_menu");
wsMenu$.menu({
iconType: "fa"
});
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment