Merge remote-tracking branch 'refs/remotes/mortenbra/master'
This commit is contained in:
commit
11a15da296
@ -250,8 +250,8 @@ This library is a collection of various utility packages for PL/SQL, as well as
|
||||
|
||||
##Miscellaneous utilities and demos
|
||||
|
||||
* http://www.toadworld.com/Portals/0/stevenf/demo.zip
|
||||
* http://www.toadworld.com/ORACLE/StevenFeuersteinsPLSQLObsession/tabid/153/Default.aspx
|
||||
* http://www.oracle.com/webfolder/technetwork/tutorials/plsql/sfdemo.zip
|
||||
* http://www.toadworld.com/platforms/oracle/w/wiki/8243.plsql-obsession
|
||||
|
||||
##PL/SQL Frameworks
|
||||
|
||||
|
||||
@ -1,12 +1,13 @@
|
||||
-- see http://technology.amis.nl/blog/10995/create-an-excel-file-with-plsql
|
||||
|
||||
begin
|
||||
xlsx_builder_pkg.clear_workbook;
|
||||
xlsx_builder_pkg.new_sheet;
|
||||
xlsx_builder_pkg.cell( 5, 1, 5 );
|
||||
xlsx_builder_pkg.cell( 3, 1, 3 );
|
||||
xlsx_builder_pkg.cell( 2, 2, 45 );
|
||||
xlsx_builder_pkg.cell( 3, 2, 'Anton Scheffer', p_alignment => xlsx_builder_pkg.get_alignment( p_wraptext => true ) );
|
||||
xlsx_builder_pkg.cell( 1, 4, sysdate );
|
||||
xlsx_builder_pkg.cell( 1, 4, sysdate, p_fontId => xlsx_builder_pkg.get_font( 'Calibri', p_rgb => 'FFFF0000' ) );
|
||||
xlsx_builder_pkg.cell( 2, 4, sysdate, p_numFmtId => xlsx_builder_pkg.get_numFmt( 'dd/mm/yyyy h:mm' ) );
|
||||
xlsx_builder_pkg.cell( 3, 4, sysdate, p_numFmtId => xlsx_builder_pkg.get_numFmt( xlsx_builder_pkg.orafmt2excel( 'dd/mon/yyyy' ) ) );
|
||||
xlsx_builder_pkg.cell( 5, 5, 75, p_borderId => xlsx_builder_pkg.get_border( 'double', 'double', 'double', 'double' ) );
|
||||
@ -33,5 +34,71 @@ begin
|
||||
end;
|
||||
/
|
||||
|
||||
-- Create an Excel file with validation
|
||||
begin
|
||||
xlsx_builder_pkg.clear_workbook;
|
||||
xlsx_builder_pkg.new_sheet;
|
||||
xlsx_builder_pkg.cell( 1, 6, 5 );
|
||||
xlsx_builder_pkg.cell( 1, 7, 3 );
|
||||
xlsx_builder_pkg.cell( 1, 8, 7 );
|
||||
xlsx_builder_pkg.new_sheet;
|
||||
xlsx_builder_pkg.cell( 2, 6, 15, p_sheet => 2 );
|
||||
xlsx_builder_pkg.cell( 2, 7, 13, p_sheet => 2 );
|
||||
xlsx_builder_pkg.cell( 2, 8, 17, p_sheet => 2 );
|
||||
xlsx_builder_pkg.list_validation( 6, 3, 1, 6, 1, 8, p_show_error => true, p_sheet => 1 );
|
||||
xlsx_builder_pkg.defined_name( 2, 6, 2, 8, 'Anton', 2 );
|
||||
xlsx_builder_pkg.list_validation
|
||||
( 6, 1, 'Anton'
|
||||
, p_style => 'information'
|
||||
, p_title => 'valid values are'
|
||||
, p_prompt => '13, 15 and 17'
|
||||
, p_show_error => true
|
||||
, p_error_title => 'Are you sure?'
|
||||
, p_error_txt => 'Valid values are: 13, 15 and 17'
|
||||
, p_sheet => 1 );
|
||||
xlsx_builder_pkg.save( 'MY_DIR', 'my.xlsx' );
|
||||
end;
|
||||
/
|
||||
|
||||
|
||||
begin
|
||||
xlsx_builder_pkg.clear_workbook;
|
||||
xlsx_builder_pkg.new_sheet;
|
||||
xlsx_builder_pkg.cell( 1, 6, 5 );
|
||||
xlsx_builder_pkg.cell( 1, 7, 3 );
|
||||
xlsx_builder_pkg.cell( 1, 8, 7 );
|
||||
xlsx_builder_pkg.set_autofilter( 1,1, p_row_start => 5, p_row_end => 8 );
|
||||
xlsx_builder_pkg.new_sheet;
|
||||
xlsx_builder_pkg.cell( 2, 6, 5 );
|
||||
xlsx_builder_pkg.cell( 2, 7, 3 );
|
||||
xlsx_builder_pkg.cell( 2, 8, 7 );
|
||||
xlsx_builder_pkg.set_autofilter( 2,2, p_row_start => 5, p_row_end => 8 );
|
||||
xlsx_builder_pkg.save( 'MY_DIR', 'my.xlsx' );
|
||||
end;
|
||||
/
|
||||
|
||||
-- Create workbook with frozen cells
|
||||
begin
|
||||
xlsx_builder_pkg.clear_workbook;
|
||||
xlsx_builder_pkg.new_sheet;
|
||||
for c in 1 .. 10
|
||||
loop
|
||||
xlsx_builder_pkg.cell( c, 1, 'COL' || c );
|
||||
xlsx_builder_pkg.cell( c, 2, 'val' || c );
|
||||
xlsx_builder_pkg.cell( c, 3, c );
|
||||
end loop;
|
||||
xlsx_builder_pkg.freeze_rows( 1 );
|
||||
xlsx_builder_pkg.new_sheet;
|
||||
for r in 1 .. 10
|
||||
loop
|
||||
xlsx_builder_pkg.cell( 1, r, 'ROW' || r );
|
||||
xlsx_builder_pkg.cell( 2, r, 'val' || r );
|
||||
xlsx_builder_pkg.cell( 3, r, r );
|
||||
end loop;
|
||||
xlsx_builder_pkg.freeze_cols( 3 );
|
||||
xlsx_builder_pkg.new_sheet;
|
||||
xlsx_builder_pkg.cell( 3, 3, 'Start freeze' );
|
||||
xlsx_builder_pkg.freeze_pane( 3,3 );
|
||||
xlsx_builder_pkg.save( 'MY_DIR', 'my.xlsx' );
|
||||
end;
|
||||
/
|
||||
|
||||
@ -1,4 +1,6 @@
|
||||
|
||||
NOTE: This changelog is no longer being maintained. See the Git changelog for an up-to-date list of changes.
|
||||
|
||||
Version 1.7.1
|
||||
=============
|
||||
|
||||
|
||||
@ -533,14 +533,16 @@ begin
|
||||
end get_bucket_region;
|
||||
|
||||
|
||||
procedure get_object_list (p_bucket_name in varchar2,
|
||||
p_prefix in varchar2,
|
||||
p_max_keys in number,
|
||||
p_list out t_object_list,
|
||||
p_more_marker in out varchar2)
|
||||
procedure get_object_list (p_bucket_name in varchar2,
|
||||
p_prefix in varchar2,
|
||||
p_max_keys in number,
|
||||
p_list out t_object_list,
|
||||
p_next_continuation_token in out varchar2)
|
||||
as
|
||||
l_clob clob;
|
||||
l_xml xmltype;
|
||||
l_xml_is_truncated xmltype;
|
||||
l_xml_next_continuation xmltype;
|
||||
|
||||
l_date_str varchar2(255);
|
||||
l_auth_str varchar2(255);
|
||||
@ -548,7 +550,6 @@ as
|
||||
l_header_names t_str_array := t_str_array();
|
||||
l_header_values t_str_array := t_str_array();
|
||||
|
||||
l_count pls_integer := 0;
|
||||
l_returnvalue t_object_list;
|
||||
|
||||
begin
|
||||
@ -557,7 +558,7 @@ begin
|
||||
|
||||
Purpose: get objects
|
||||
|
||||
Remarks: see http://docs.amazonwebservices.com/AmazonS3/latest/API/index.html?RESTObjectGET.html
|
||||
Remarks: see http://docs.aws.amazon.com/AmazonS3/latest/API/v2-RESTBucketGET.html
|
||||
|
||||
see http://code.google.com/p/plsql-utils/issues/detail?id=16
|
||||
|
||||
@ -573,6 +574,7 @@ begin
|
||||
------ ---------- -------------------------------------
|
||||
MBR 15.01.2011 Created
|
||||
JKEMP 14.08.2012 Rewritten as private procedure, see remarks above
|
||||
KJS 06.10.2016 Modified to use newest S3 API which performs much better on large buckets. Changed for-loop to bulk operation.
|
||||
|
||||
*/
|
||||
|
||||
@ -594,38 +596,36 @@ begin
|
||||
l_header_values.extend;
|
||||
l_header_values(3) := l_auth_str;
|
||||
|
||||
if p_more_marker is not null then
|
||||
l_clob := make_request (get_url(p_bucket_name) || '?marker=' || p_more_marker || '&max-keys=' || p_max_keys || '&prefix=' || utl_url.escape(p_prefix), 'GET', l_header_names, l_header_values, null);
|
||||
if p_next_continuation_token is not null then
|
||||
l_clob := make_request (get_url(p_bucket_name) || '?list-type=2&continuation-token=' || utl_url.escape(p_next_continuation_token) || '&max-keys=' || p_max_keys || '&prefix=' || utl_url.escape(p_prefix), 'GET', l_header_names, l_header_values, null);
|
||||
else
|
||||
l_clob := make_request (get_url(p_bucket_name) || '?max-keys=' || p_max_keys || '&prefix=' || utl_url.escape(p_prefix), 'GET', l_header_names, l_header_values, null);
|
||||
l_clob := make_request (get_url(p_bucket_name) || '?list-type=2&max-keys=' || p_max_keys || '&prefix=' || utl_url.escape(p_prefix), 'GET', l_header_names, l_header_values, null);
|
||||
end if;
|
||||
|
||||
if (l_clob is not null) and (length(l_clob) > 0) then
|
||||
|
||||
l_xml := xmltype (l_clob);
|
||||
|
||||
check_for_errors (l_xml);
|
||||
|
||||
for l_rec in (
|
||||
select extractValue(value(t), '*/Key', g_aws_namespace_s3_full) as key,
|
||||
extractValue(value(t), '*/Size', g_aws_namespace_s3_full) as size_bytes,
|
||||
extractValue(value(t), '*/LastModified', g_aws_namespace_s3_full) as last_modified
|
||||
from table(xmlsequence(l_xml.extract('//ListBucketResult/Contents', g_aws_namespace_s3_full))) t
|
||||
) loop
|
||||
l_count := l_count + 1;
|
||||
l_returnvalue(l_count).key := l_rec.key;
|
||||
l_returnvalue(l_count).size_bytes := l_rec.size_bytes;
|
||||
l_returnvalue(l_count).last_modified := to_date(l_rec.last_modified, g_date_format_xml);
|
||||
end loop;
|
||||
select extractValue(value(t), '*/Key', g_aws_namespace_s3_full),
|
||||
extractValue(value(t), '*/Size', g_aws_namespace_s3_full),
|
||||
to_date(extractValue(value(t), '*/LastModified', g_aws_namespace_s3_full), g_date_format_xml)
|
||||
bulk collect into l_returnvalue
|
||||
from table(xmlsequence(l_xml.extract('//ListBucketResult/Contents', g_aws_namespace_s3_full))) t;
|
||||
|
||||
-- check if this is the last set of data or not, and set the in/out p_next_continuation_token as expected
|
||||
l_xml_is_truncated := l_xml.extract('//ListBucketResult/IsTruncated/text()', g_aws_namespace_s3_full);
|
||||
|
||||
-- check if this is the last set of data or not
|
||||
|
||||
l_xml := l_xml.extract('//ListBucketResult/IsTruncated/text()', g_aws_namespace_s3_full);
|
||||
|
||||
if l_xml is not null and l_xml.getStringVal = 'true' then
|
||||
p_more_marker := l_returnvalue(l_returnvalue.last).key;
|
||||
if l_xml_is_truncated is not null and l_xml_is_truncated.getStringVal = 'true' then
|
||||
l_xml_next_continuation := l_xml.extract('//ListBucketResult/NextContinuationToken/text()', g_aws_namespace_s3_full);
|
||||
if l_xml_next_continuation is not null then
|
||||
p_next_continuation_token := l_xml_next_continuation.getStringVal;
|
||||
else
|
||||
p_next_continuation_token := null;
|
||||
end if;
|
||||
else
|
||||
p_next_continuation_token := null;
|
||||
end if;
|
||||
|
||||
end if;
|
||||
|
||||
p_list := l_returnvalue;
|
||||
@ -638,7 +638,7 @@ function get_object_list (p_bucket_name in varchar2,
|
||||
p_max_keys in number := null) return t_object_list
|
||||
as
|
||||
l_object_list t_object_list;
|
||||
l_more_marker varchar2(4000);
|
||||
l_next_continuation_token varchar2(4000);
|
||||
begin
|
||||
|
||||
/*
|
||||
@ -654,11 +654,11 @@ begin
|
||||
*/
|
||||
|
||||
get_object_list (
|
||||
p_bucket_name => p_bucket_name,
|
||||
p_prefix => p_prefix,
|
||||
p_max_keys => p_max_keys,
|
||||
p_list => l_object_list,
|
||||
p_more_marker => l_more_marker --ignored by this function
|
||||
p_bucket_name => p_bucket_name,
|
||||
p_prefix => p_prefix,
|
||||
p_max_keys => p_max_keys,
|
||||
p_list => l_object_list,
|
||||
p_next_continuation_token => l_next_continuation_token --ignored by this function
|
||||
);
|
||||
|
||||
return l_object_list;
|
||||
@ -671,7 +671,7 @@ function get_object_tab (p_bucket_name in varchar2,
|
||||
p_max_keys in number := null) return t_object_tab pipelined
|
||||
as
|
||||
l_object_list t_object_list;
|
||||
l_more_marker varchar2(4000);
|
||||
l_next_continuation_token varchar2(4000);
|
||||
begin
|
||||
|
||||
/*
|
||||
@ -689,18 +689,18 @@ begin
|
||||
loop
|
||||
|
||||
get_object_list (
|
||||
p_bucket_name => p_bucket_name,
|
||||
p_prefix => p_prefix,
|
||||
p_max_keys => p_max_keys,
|
||||
p_list => l_object_list,
|
||||
p_more_marker => l_more_marker
|
||||
p_bucket_name => p_bucket_name,
|
||||
p_prefix => p_prefix,
|
||||
p_max_keys => p_max_keys,
|
||||
p_list => l_object_list,
|
||||
p_next_continuation_token => l_next_continuation_token
|
||||
);
|
||||
|
||||
for i in 1 .. l_object_list.count loop
|
||||
pipe row (l_object_list(i));
|
||||
end loop;
|
||||
|
||||
exit when l_more_marker is null;
|
||||
exit when l_next_continuation_token is null;
|
||||
|
||||
end loop;
|
||||
|
||||
|
||||
@ -522,7 +522,7 @@ begin
|
||||
l_xml := make_request (l_soap_action, get_request_envelope);
|
||||
|
||||
l_returnvalue.sequence_number := 1;
|
||||
l_returnvalue.folder_id := flex_ws_api.parse_xml(l_xml, '//*/t:FolderId/@Id/text()', g_namespace_messages || ' ' || g_namespace_types);
|
||||
l_returnvalue.folder_id := flex_ws_api.parse_xml(l_xml, '//*/t:FolderId/@Id', g_namespace_messages || ' ' || g_namespace_types);
|
||||
l_returnvalue.display_name := flex_ws_api.parse_xml(l_xml, '//*/t:DisplayName/text()', g_namespace_messages || ' ' || g_namespace_types);
|
||||
l_returnvalue.total_count := to_number(flex_ws_api.parse_xml(l_xml, '//*/t:TotalCount/text()', g_namespace_messages || ' ' || g_namespace_types));
|
||||
l_returnvalue.child_folder_count := to_number(flex_ws_api.parse_xml(l_xml, '//*/t:ChildFolderCount/text()', g_namespace_messages || ' ' || g_namespace_types));
|
||||
@ -831,8 +831,8 @@ begin
|
||||
|
||||
-- general Item info
|
||||
l_returnvalue.sequence_number := 1;
|
||||
l_returnvalue.item_id := flex_ws_api.parse_xml(l_xml, '//*/t:ItemId/@Id/text()', g_namespace_messages || ' ' || g_namespace_types);
|
||||
l_returnvalue.change_key := flex_ws_api.parse_xml(l_xml, '//*/t:ItemId/@ChangeKey/text()', g_namespace_messages || ' ' || g_namespace_types);
|
||||
l_returnvalue.item_id := flex_ws_api.parse_xml(l_xml, '//*/t:ItemId/@Id', g_namespace_messages || ' ' || g_namespace_types);
|
||||
l_returnvalue.change_key := flex_ws_api.parse_xml(l_xml, '//*/t:ItemId/@ChangeKey', g_namespace_messages || ' ' || g_namespace_types);
|
||||
l_returnvalue.item_size := to_number(flex_ws_api.parse_xml(l_xml, '//*/t:Size/text()', g_namespace_messages || ' ' || g_namespace_types));
|
||||
|
||||
l_returnvalue.subject := flex_ws_api.parse_xml(l_xml, '//*/t:Subject/text()', g_namespace_messages || ' ' || g_namespace_types);
|
||||
@ -1209,7 +1209,7 @@ begin
|
||||
l_xml := make_request (l_soap_action, get_request_envelope);
|
||||
|
||||
-- TODO: verify that ID is returned/parsed...
|
||||
l_returnvalue := flex_ws_api.parse_xml(l_xml, '//*/m:Items/t:CalendarItem/t:ItemId/@Id/text()', g_namespace_messages || ' ' || g_namespace_types);
|
||||
l_returnvalue := flex_ws_api.parse_xml(l_xml, '//*/m:Items/t:CalendarItem/t:ItemId/@Id', g_namespace_messages || ' ' || g_namespace_types);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
@ -1278,7 +1278,7 @@ begin
|
||||
l_xml := make_request (l_soap_action, get_request_envelope);
|
||||
|
||||
-- TODO: verify that ID is returned/parsed...
|
||||
l_returnvalue := flex_ws_api.parse_xml(l_xml, '//*/m:Items/t:Task/t:ItemId/@Id/text()', g_namespace_messages || ' ' || g_namespace_types);
|
||||
l_returnvalue := flex_ws_api.parse_xml(l_xml, '//*/m:Items/t:Task/t:ItemId/@Id', g_namespace_messages || ' ' || g_namespace_types);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
@ -1376,7 +1376,7 @@ begin
|
||||
l_xml := make_request (l_soap_action, get_request_envelope);
|
||||
|
||||
-- TODO: verify that ID is returned/parsed...
|
||||
l_returnvalue := flex_ws_api.parse_xml(l_xml, '//*/m:Items/t:Message/t:ItemId/@Id/text()', g_namespace_messages || ' ' || g_namespace_types);
|
||||
l_returnvalue := flex_ws_api.parse_xml(l_xml, '//*/m:Items/t:Message/t:ItemId/@Id', g_namespace_messages || ' ' || g_namespace_types);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
@ -1633,7 +1633,7 @@ begin
|
||||
|
||||
l_xml := make_request (l_soap_action, get_request_envelope);
|
||||
|
||||
l_returnvalue.attachment_id := flex_ws_api.parse_xml(l_xml, '//*/m:Attachments/t:FileAttachment/t:AttachmentId/@Id/text()', g_namespace_messages || ' ' || g_namespace_types);
|
||||
l_returnvalue.attachment_id := flex_ws_api.parse_xml(l_xml, '//*/m:Attachments/t:FileAttachment/t:AttachmentId/@Id', g_namespace_messages || ' ' || g_namespace_types);
|
||||
l_returnvalue.name := flex_ws_api.parse_xml(l_xml, '//*/m:Attachments/t:FileAttachment/t:Name/text()', g_namespace_messages || ' ' || g_namespace_types);
|
||||
l_returnvalue.content_type := flex_ws_api.parse_xml(l_xml, '//*/m:Attachments/t:FileAttachment/t:ContentType/text()', g_namespace_messages || ' ' || g_namespace_types);
|
||||
l_returnvalue.content_id := flex_ws_api.parse_xml(l_xml, '//*/m:Attachments/t:FileAttachment/t:ContentId/text()', g_namespace_messages || ' ' || g_namespace_types);
|
||||
@ -1706,7 +1706,7 @@ begin
|
||||
l_xml := make_request (l_soap_action, get_request_envelope);
|
||||
|
||||
-- TODO: verify that value is returned...
|
||||
l_returnvalue := flex_ws_api.parse_xml(l_xml, '//*/m:Attachments/t:FileAttachment/t:AttachmentId/@Id/text()', g_namespace_messages || ' ' || g_namespace_types);
|
||||
l_returnvalue := flex_ws_api.parse_xml(l_xml, '//*/m:Attachments/t:FileAttachment/t:AttachmentId/@Id', g_namespace_messages || ' ' || g_namespace_types);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
|
||||
@ -246,7 +246,9 @@ begin
|
||||
|
||||
l_blob := zip_util_pkg.get_file (p_template, l_file_list(i));
|
||||
|
||||
if l_file_list(i) in ('word/document.xml', 'word/footer1.xml', 'xl/sharedStrings.xml') or (l_file_list(i) like 'ppt/slides/slide%.xml') then
|
||||
if l_file_list(i) in ('word/document.xml', 'word/footer1.xml', 'xl/sharedStrings.xml')
|
||||
or (l_file_list(i) like 'ppt/slides/slide%.xml')
|
||||
or (l_file_list(i) like 'ppt/notesSlides/notesSlide%.xml') then
|
||||
|
||||
l_clob := sql_util_pkg.blob_to_clob (l_blob);
|
||||
l_clob := string_util_pkg.multi_replace (l_clob, p_names, p_values);
|
||||
|
||||
626
ora/paypal_util_pkg.pkb
Normal file
626
ora/paypal_util_pkg.pkb
Normal file
@ -0,0 +1,626 @@
|
||||
create or replace package body paypal_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles PayPal REST API
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.08.2014 Created
|
||||
|
||||
*/
|
||||
|
||||
g_api_base_url_sandbox string_util_pkg.t_max_db_varchar2 := 'https://api.sandbox.paypal.com';
|
||||
g_api_base_url_live string_util_pkg.t_max_db_varchar2 := 'https://api.paypal.com';
|
||||
|
||||
g_api_base_url string_util_pkg.t_max_db_varchar2 := g_api_base_url_live;
|
||||
|
||||
g_wallet_path string_util_pkg.t_max_db_varchar2;
|
||||
g_wallet_password string_util_pkg.t_max_db_varchar2;
|
||||
|
||||
|
||||
procedure set_api_base_url (p_sandbox_url in varchar2,
|
||||
p_live_url in varchar2)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: set API base URL
|
||||
|
||||
Remarks: useful if you need to use a proxy for HTTPS requests from the database
|
||||
see http://blog.rhjmartens.nl/2015/07/making-https-webservice-requests-from.html
|
||||
see http://ora-00001.blogspot.com/2016/04/how-to-set-up-iis-as-ssl-proxy-for-utl-http-in-oracle-xe.html
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 06.03.2016 Created
|
||||
|
||||
*/
|
||||
|
||||
-- set available URLs
|
||||
g_api_base_url_sandbox := p_sandbox_url;
|
||||
g_api_base_url_live := p_live_url;
|
||||
|
||||
-- set the "live" URL as the default
|
||||
g_api_base_url := g_api_base_url_live;
|
||||
|
||||
end set_api_base_url;
|
||||
|
||||
|
||||
function make_request (p_url in varchar2,
|
||||
p_body in clob := null,
|
||||
p_http_method in varchar2 := 'POST',
|
||||
p_access_token in t_access_token := null,
|
||||
p_username in varchar2 := null,
|
||||
p_password in varchar2 := null) return clob
|
||||
as
|
||||
l_returnvalue clob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: make HTTP request
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.08.2014 Created
|
||||
|
||||
*/
|
||||
|
||||
apex_web_service.g_request_headers.delete;
|
||||
|
||||
if (p_access_token.access_token is not null) then
|
||||
apex_web_service.g_request_headers(1).name := 'Content-Type';
|
||||
apex_web_service.g_request_headers(1).value := 'application/json';
|
||||
apex_web_service.g_request_headers(2).name := 'Authorization';
|
||||
apex_web_service.g_request_headers(2).value := p_access_token.token_type || ' ' || p_access_token.access_token;
|
||||
else
|
||||
apex_web_service.g_request_headers(1).name := 'Content-Type';
|
||||
apex_web_service.g_request_headers(1).value := 'application/x-www-form-urlencoded';
|
||||
apex_web_service.g_request_headers(2).name := 'Accept';
|
||||
apex_web_service.g_request_headers(2).value := 'application/json';
|
||||
apex_web_service.g_request_headers(3).name := 'Accept-Language';
|
||||
apex_web_service.g_request_headers(3).value := 'en_US';
|
||||
end if;
|
||||
|
||||
debug_pkg.printf('%1 %2', p_http_method, p_url);
|
||||
|
||||
l_returnvalue := apex_web_service.make_rest_request(
|
||||
p_url => p_url,
|
||||
p_http_method => p_http_method,
|
||||
p_body => p_body,
|
||||
p_username => p_username,
|
||||
p_password => p_password,
|
||||
p_wallet_path => g_wallet_path,
|
||||
p_wallet_pwd => g_wallet_password
|
||||
);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end make_request;
|
||||
|
||||
|
||||
function decode_json_value (p_json_value in varchar2) return varchar2
|
||||
as
|
||||
l_returnvalue varchar2(32000);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: decode JSON value
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 26.01.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := replace(p_json_value, '\''', '''');
|
||||
l_returnvalue := replace(l_returnvalue, '\"', '"');
|
||||
l_returnvalue := replace(l_returnvalue, '\b', chr(9)); -- backspace
|
||||
l_returnvalue := replace(l_returnvalue, '\t', chr(9)); -- tab
|
||||
l_returnvalue := replace(l_returnvalue, '\n', chr(10)); -- line feed
|
||||
l_returnvalue := replace(l_returnvalue, '\f', chr(12)); -- form feed
|
||||
l_returnvalue := replace(l_returnvalue, '\r', chr(13)); -- carriage return
|
||||
|
||||
l_returnvalue := unistr(replace(l_returnvalue, '\u', '\')); -- unicode character
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end decode_json_value;
|
||||
|
||||
|
||||
function encode_json_value (p_value in varchar2) return varchar2
|
||||
as
|
||||
l_returnvalue varchar2(32000);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: encode JSON value
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 19.04.2013 Created
|
||||
MBR 15.04.2015 Handle unicode chars properly, based on code from https://technology.amis.nl/wp-content/uploads/2015/03/json_agg.txt
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := asciistr(p_value);
|
||||
l_returnvalue := replace(l_returnvalue, '\', '\u');
|
||||
l_returnvalue := replace(l_returnvalue, '"', '\"');
|
||||
l_returnvalue := replace(l_returnvalue, '\u005C', '\\');
|
||||
l_returnvalue := replace(l_returnvalue, '/', '\/');
|
||||
l_returnvalue := replace(l_returnvalue, '''', '\''');
|
||||
l_returnvalue := replace(l_returnvalue, chr(8), '\b'); -- backspace
|
||||
l_returnvalue := replace(l_returnvalue, chr(9), '\t'); -- tab
|
||||
l_returnvalue := replace(l_returnvalue, chr(10), '\n'); -- line feed
|
||||
l_returnvalue := replace(l_returnvalue, chr(12), '\f'); -- form feed
|
||||
l_returnvalue := replace(l_returnvalue, chr(13), '\r'); -- carriage return
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end encode_json_value;
|
||||
|
||||
|
||||
function encode_json_boolean (p_value in boolean) return varchar2
|
||||
as
|
||||
l_returnvalue varchar2(32000);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: encode JSON boolean value
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 17.11.2015 Created
|
||||
|
||||
*/
|
||||
|
||||
if p_value then
|
||||
l_returnvalue := 'true';
|
||||
else
|
||||
l_returnvalue := 'false';
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end encode_json_boolean;
|
||||
|
||||
|
||||
function get_json_value (p_data in clob,
|
||||
p_name in varchar2) return varchar2
|
||||
as
|
||||
l_returnvalue varchar2(4000) := null;
|
||||
l_start_pos pls_integer;
|
||||
l_end_pos pls_integer;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get JSON value
|
||||
|
||||
Remarks: TODO: this is not a proper JSON parser, just a crude string parser, but will do for now. Refactor using APEX_JSON later...
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 26.01.2010 Created
|
||||
MBR 21.05.2010 Trim strings
|
||||
|
||||
*/
|
||||
|
||||
-- assumes that values are always enclosed in double quotes (no null values)
|
||||
|
||||
l_start_pos := instr(p_data, '"' || p_name || '":"');
|
||||
|
||||
if l_start_pos > 0 then
|
||||
l_start_pos := l_start_pos + length ('"' || p_name || '":"');
|
||||
l_end_pos := instr(p_data, '",', l_start_pos);
|
||||
if l_end_pos = 0 then
|
||||
l_end_pos := instr(p_data, '"}', l_start_pos);
|
||||
end if;
|
||||
|
||||
l_returnvalue := substr(p_data, l_start_pos, l_end_pos - l_start_pos);
|
||||
l_returnvalue := trim(replace(l_returnvalue, chr(160), ''));
|
||||
|
||||
end if;
|
||||
|
||||
if l_returnvalue is not null then
|
||||
l_returnvalue := substr(decode_json_value (l_returnvalue),1,4000);
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_json_value;
|
||||
|
||||
|
||||
procedure check_response_for_errors (p_response in clob)
|
||||
as
|
||||
l_error_name string_util_pkg.t_max_pl_varchar2;
|
||||
l_error_message string_util_pkg.t_max_pl_varchar2;
|
||||
l_error_info_url string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: check response for errors
|
||||
|
||||
Remarks: see https://developer.paypal.com/webapps/developer/docs/api/#errors
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.08.2014 Created
|
||||
|
||||
*/
|
||||
|
||||
-- TODO: should pass the HTTP error code to this procedure as well (is it possible to get it via apex_web_service.g_headers???), for now just check response body
|
||||
|
||||
debug_pkg.printf('response length = %1', length(p_response));
|
||||
debug_pkg.printf('first 32K characters of response = %1', substr(p_response,1,32000));
|
||||
|
||||
-- note: this type of error response is not mentioned in the docs (linked above), but has been seen "in the wild"
|
||||
l_error_name := get_json_value (p_response, 'error');
|
||||
l_error_message := get_json_value (p_response, 'error_description');
|
||||
|
||||
if l_error_name is not null then
|
||||
raise_application_error (-20000, 'The PayPal API returned error ' || l_error_name || ': ' || l_error_message, true);
|
||||
end if;
|
||||
|
||||
-- check for errors as described by API documentation
|
||||
l_error_name := get_json_value (p_response, 'name');
|
||||
l_error_message := get_json_value (p_response, 'message');
|
||||
l_error_info_url := get_json_value (p_response, 'information_link');
|
||||
|
||||
if l_error_name is not null then
|
||||
raise_application_error (-20000, 'The PayPal API returned error ' || l_error_name || ': ' || l_error_message || ', see ' || l_error_info_url, true);
|
||||
end if;
|
||||
|
||||
end check_response_for_errors;
|
||||
|
||||
|
||||
procedure switch_to_sandbox
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: switch to sandbox (test) environment
|
||||
|
||||
Remarks: the default environment is live (production), use this procedure to switch to the sandbox for testing
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.08.2014 Created
|
||||
|
||||
*/
|
||||
|
||||
g_api_base_url := g_api_base_url_sandbox;
|
||||
|
||||
end switch_to_sandbox;
|
||||
|
||||
|
||||
procedure set_wallet (p_wallet_path in varchar2,
|
||||
p_wallet_password in varchar2)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: set SSL wallet properties
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.08.2014 Created
|
||||
|
||||
*/
|
||||
|
||||
g_wallet_path := p_wallet_path;
|
||||
g_wallet_password := p_wallet_password;
|
||||
|
||||
end set_wallet;
|
||||
|
||||
|
||||
function get_access_token (p_client_id in varchar2,
|
||||
p_secret in varchar2) return t_access_token
|
||||
as
|
||||
l_request clob;
|
||||
l_response clob;
|
||||
l_returnvalue t_access_token;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get access token for other API requests
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.08.2014 Created
|
||||
|
||||
*/
|
||||
|
||||
l_request := 'grant_type=client_credentials';
|
||||
|
||||
l_response := make_request (p_url => g_api_base_url || '/v1/oauth2/token', p_body => l_request, p_username => p_client_id, p_password => p_secret);
|
||||
|
||||
check_response_for_errors (l_response);
|
||||
|
||||
l_returnvalue.access_token := get_json_value (l_response, 'access_token');
|
||||
l_returnvalue.token_type := get_json_value (l_response, 'token_type');
|
||||
-- TODO: retrieving this value fails because the current JSON parser only handles strings (ie values in double quotes), will be fixed by using APEX_JSON as the parser
|
||||
l_returnvalue.duration_seconds := to_number(get_json_value (l_response, 'expires_in'));
|
||||
l_returnvalue.created_date := sysdate;
|
||||
l_returnvalue.expires_date := l_returnvalue.created_date + (l_returnvalue.duration_seconds / (60*60));
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_access_token;
|
||||
|
||||
|
||||
function get_payment_from_response (p_response in clob) return t_payment
|
||||
as
|
||||
l_clob clob;
|
||||
l_end_pos pls_integer;
|
||||
l_returnvalue t_payment;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: parse the response into a payment record
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.08.2014 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue.payment_id := get_json_value (p_response, 'id');
|
||||
l_returnvalue.intent := get_json_value (p_response, 'intent');
|
||||
l_returnvalue.state := get_json_value (p_response, 'state');
|
||||
|
||||
-- TODO: this ain't pretty, use a real JSON parser (APEX_JSON) instead... ! (code will break if rel/href tags switch position)
|
||||
|
||||
l_end_pos := instr(p_response, '"approval_url"');
|
||||
if l_end_pos > 0 then
|
||||
l_clob := p_response;
|
||||
l_clob := substr(l_clob, 1, l_end_pos);
|
||||
l_returnvalue.approval_url := substr(l_clob, instr(l_clob, '"href"', -1));
|
||||
l_returnvalue.approval_url := get_json_value (l_returnvalue.approval_url, 'href');
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_payment_from_response;
|
||||
|
||||
|
||||
function create_payment (p_access_token in t_access_token,
|
||||
p_amount in number,
|
||||
p_currency in varchar2,
|
||||
p_description in varchar2,
|
||||
p_return_url in varchar2,
|
||||
p_cancel_url in varchar2,
|
||||
p_payment_experience_id in varchar2 := null) return t_payment
|
||||
as
|
||||
l_request clob;
|
||||
l_response clob;
|
||||
l_returnvalue t_payment;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: create payment
|
||||
|
||||
Remarks: after calling this, redirect the user to the "approval_url" on the PayPal site,
|
||||
so that the user can approve the payment.
|
||||
The user must approve the payment before you can execute and complete the sale.
|
||||
|
||||
When the user approves the payment, PayPal redirects the user to the "return_url"
|
||||
that was specified when the payment was created. A payer ID is appended to the return URL, as PayerID:
|
||||
http://<return_url>?token=EC-60U79048BN7719609(ampersand)PayerID=7E7MGXCWTTKK2
|
||||
The token value appended to the return URL is not needed when you execute the payment.
|
||||
|
||||
To execute the payment after the user's approval, make a call to execute_payment and pass the payer_id received via the return_url
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.08.2014 Created
|
||||
MBR 17.11.2015 Added optional payment experience parameter
|
||||
|
||||
*/
|
||||
|
||||
-- TODO: use a JSON builder to generate the request
|
||||
|
||||
l_request := '{
|
||||
"intent":"sale",' || case when p_payment_experience_id is not null then '"experience_profile_id":"' || p_payment_experience_id || '",' end ||
|
||||
'"redirect_urls":{
|
||||
"return_url":"' || encode_json_value (p_return_url) || '",
|
||||
"cancel_url":"' || encode_json_value (p_cancel_url) || '"
|
||||
},
|
||||
"payer":{
|
||||
"payment_method":"paypal"
|
||||
},
|
||||
"transactions":[
|
||||
{
|
||||
"amount":{
|
||||
"total":"' || trim(to_char(p_amount, '999999D99', 'NLS_NUMERIC_CHARACTERS = ''. ''')) || '",
|
||||
"currency":"' || p_currency || '"
|
||||
},
|
||||
"description":"' || encode_json_value (p_description) || '"
|
||||
}
|
||||
]
|
||||
} ]
|
||||
}';
|
||||
|
||||
l_response := make_request (p_url => g_api_base_url || '/v1/payments/payment', p_body => l_request, p_access_token => p_access_token);
|
||||
|
||||
check_response_for_errors (l_response);
|
||||
|
||||
l_returnvalue := get_payment_from_response (l_response);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end create_payment;
|
||||
|
||||
|
||||
function execute_payment (p_access_token in t_access_token,
|
||||
p_payment_id in varchar2,
|
||||
p_payer_id in varchar2) return t_payment
|
||||
as
|
||||
l_request clob;
|
||||
l_response clob;
|
||||
l_returnvalue t_payment;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: execute payment
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.08.2014 Created
|
||||
|
||||
*/
|
||||
|
||||
l_request := '{"payer_id":"' || p_payer_id || '"}';
|
||||
|
||||
l_response := make_request (p_url => g_api_base_url || '/v1/payments/payment/' || p_payment_id || '/execute/', p_body => l_request, p_access_token => p_access_token);
|
||||
|
||||
check_response_for_errors (l_response);
|
||||
|
||||
l_returnvalue := get_payment_from_response (l_response);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end execute_payment;
|
||||
|
||||
|
||||
function get_payment (p_access_token in t_access_token,
|
||||
p_payment_id in varchar2) return t_payment
|
||||
as
|
||||
l_response clob;
|
||||
l_returnvalue t_payment;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get payment
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.08.2014 Created
|
||||
|
||||
*/
|
||||
|
||||
l_response := make_request (p_url => g_api_base_url || '/v1/payments/payment/' || p_payment_id, p_http_method => 'GET', p_access_token => p_access_token);
|
||||
|
||||
check_response_for_errors (l_response);
|
||||
|
||||
l_returnvalue := get_payment_from_response (l_response);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_payment;
|
||||
|
||||
|
||||
function create_payment_experience (p_access_token in t_access_token,
|
||||
p_payment_experience in t_payment_experience) return varchar2
|
||||
as
|
||||
l_request clob;
|
||||
l_response clob;
|
||||
l_returnvalue varchar2(255);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: create payment experience
|
||||
|
||||
Remarks: see https://developer.paypal.com/docs/integration/direct/rest-experience-overview/
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 17.11.2015 Created
|
||||
|
||||
*/
|
||||
|
||||
-- TODO: use a JSON builder to generate the request
|
||||
|
||||
l_request := '{
|
||||
"name":"' || encode_json_value (p_payment_experience.payment_experience_name) || '",
|
||||
"presentation":{
|
||||
"brand_name":"' || encode_json_value (p_payment_experience.presentation.brand_name) || '",
|
||||
"logo_image":"' || encode_json_value (p_payment_experience.presentation.logo_image) || '",
|
||||
"locale_code":"' || encode_json_value (p_payment_experience.presentation.locale_code) || '"
|
||||
},
|
||||
"input_fields":{
|
||||
"allow_note":"' || encode_json_boolean (p_payment_experience.input_fields.allow_note) || '",
|
||||
"no_shipping":"' || p_payment_experience.input_fields.no_shipping || '",
|
||||
"address_override":"' || p_payment_experience.input_fields.address_override || '"
|
||||
},
|
||||
"flow_config":{
|
||||
"landing_page_type":"' || encode_json_value (p_payment_experience.flow_config.landing_page_type) || '"
|
||||
}
|
||||
}';
|
||||
|
||||
l_response := make_request (p_url => g_api_base_url || '/v1/payment-experience/web-profiles', p_body => l_request, p_access_token => p_access_token);
|
||||
|
||||
-- TODO: according to the docs, the response should only contain "id",
|
||||
-- but the response actually contains the "name" of the payment experience, which throws a false error
|
||||
--check_response_for_errors (l_response);
|
||||
|
||||
l_returnvalue := get_json_value (l_response, 'id');
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end create_payment_experience;
|
||||
|
||||
|
||||
procedure delete_payment_experience (p_access_token in t_access_token,
|
||||
p_payment_experience_id in varchar2)
|
||||
as
|
||||
l_response clob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: delete payment experience
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 17.11.2015 Created
|
||||
|
||||
*/
|
||||
|
||||
l_response := make_request (p_url => g_api_base_url || '/v1/payment-experience/web-profiles/' || p_payment_experience_id, p_http_method => 'DELETE', p_access_token => p_access_token);
|
||||
|
||||
check_response_for_errors (l_response);
|
||||
|
||||
end delete_payment_experience;
|
||||
|
||||
|
||||
end paypal_util_pkg;
|
||||
/
|
||||
|
||||
115
ora/paypal_util_pkg.pks
Normal file
115
ora/paypal_util_pkg.pks
Normal file
@ -0,0 +1,115 @@
|
||||
create or replace package paypal_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles PayPal REST API
|
||||
|
||||
Remarks: see https://developer.paypal.com/webapps/developer/docs/api/
|
||||
see https://developer.paypal.com/webapps/developer/docs/integration/direct/make-your-first-call/
|
||||
see https://devtools-paypal.com/hateoas/index.html
|
||||
see https://www.youtube.com/watch?v=EdkQahMUvAY
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.08.2014 Created
|
||||
MBR 06.03.2016 Procedure to set API base URL
|
||||
|
||||
*/
|
||||
|
||||
-- access token
|
||||
type t_access_token is record (
|
||||
access_token varchar2(4000),
|
||||
token_type varchar2(255),
|
||||
duration_seconds number,
|
||||
created_date date,
|
||||
expires_date date
|
||||
);
|
||||
|
||||
-- payment
|
||||
type t_payment is record (
|
||||
payment_id varchar2(255),
|
||||
intent varchar2(255),
|
||||
state varchar2(255),
|
||||
approval_url varchar2(4000)
|
||||
);
|
||||
|
||||
-- payment experience flow config
|
||||
type t_pe_flow_config is record (
|
||||
landing_page_type varchar2(255)
|
||||
);
|
||||
|
||||
-- payment experience input fields
|
||||
type t_pe_input_fields is record (
|
||||
allow_note boolean,
|
||||
no_shipping pls_integer,
|
||||
address_override pls_integer
|
||||
);
|
||||
|
||||
-- payment experience presentation
|
||||
type t_pe_presentation is record (
|
||||
brand_name varchar2(255),
|
||||
logo_image varchar2(255),
|
||||
locale_code varchar2(255)
|
||||
);
|
||||
|
||||
-- payment web experience profile
|
||||
type t_payment_experience is record (
|
||||
payment_experience_id varchar2(255),
|
||||
payment_experience_name varchar2(255),
|
||||
flow_config t_pe_flow_config,
|
||||
input_fields t_pe_input_fields,
|
||||
presentation t_pe_presentation
|
||||
);
|
||||
|
||||
-- payment states
|
||||
g_state_created constant varchar2(255) := 'created';
|
||||
g_state_approved constant varchar2(255) := 'approved';
|
||||
g_state_failed constant varchar2(255) := 'failed';
|
||||
g_state_canceled constant varchar2(255) := 'canceled';
|
||||
g_state_expired constant varchar2(255) := 'expired';
|
||||
|
||||
-- set API base URL
|
||||
procedure set_api_base_url (p_sandbox_url in varchar2,
|
||||
p_live_url in varchar2);
|
||||
|
||||
-- switch to sandbox (test) environment
|
||||
procedure switch_to_sandbox;
|
||||
|
||||
-- set SSL wallet properties
|
||||
procedure set_wallet (p_wallet_path in varchar2,
|
||||
p_wallet_password in varchar2);
|
||||
|
||||
-- get access token for other API requests
|
||||
function get_access_token (p_client_id in varchar2,
|
||||
p_secret in varchar2) return t_access_token;
|
||||
|
||||
-- create payment
|
||||
function create_payment (p_access_token in t_access_token,
|
||||
p_amount in number,
|
||||
p_currency in varchar2,
|
||||
p_description in varchar2,
|
||||
p_return_url in varchar2,
|
||||
p_cancel_url in varchar2,
|
||||
p_payment_experience_id in varchar2 := null) return t_payment;
|
||||
|
||||
-- execute payment
|
||||
function execute_payment (p_access_token in t_access_token,
|
||||
p_payment_id in varchar2,
|
||||
p_payer_id in varchar2) return t_payment;
|
||||
|
||||
-- get payment
|
||||
function get_payment (p_access_token in t_access_token,
|
||||
p_payment_id in varchar2) return t_payment;
|
||||
|
||||
-- create payment experience
|
||||
function create_payment_experience (p_access_token in t_access_token,
|
||||
p_payment_experience in t_payment_experience) return varchar2;
|
||||
|
||||
-- delete payment experience
|
||||
procedure delete_payment_experience (p_access_token in t_access_token,
|
||||
p_payment_experience_id in varchar2);
|
||||
|
||||
end paypal_util_pkg;
|
||||
/
|
||||
|
||||
@ -16,7 +16,7 @@ as
|
||||
g_exp_bind_vars constant varchar2(255) := ':\w+';
|
||||
g_exp_hyperlinks constant varchar2(255) := '<a href="[^"]+">[^<]+</a>';
|
||||
g_exp_ip_addresses constant varchar2(255) := '(\d{1,3}\.){3}\d{1,3}';
|
||||
g_exp_email_addresses constant varchar2(255) := '[A-Z0-9._%+-]+@[A-Z0-9.-]+\.[A-Z]{2,4}';
|
||||
g_exp_email_addresses constant varchar2(255) := '^[A-Za-z0-9._%+-]+@[A-Za-z0-9.-]+\.[A-Za-z]{2,4}$';
|
||||
g_exp_email_address_list constant varchar2(255) := '^((\s*[a-zA-Z0-9\._%-]+@[a-zA-Z0-9\.-]+\.[a-zA-Z]{2,4}\s*[,;:]){1,100}?)?(\s*[a-zA-Z0-9\._%-]+@[a-zA-Z0-9\.-]+\.[a-zA-Z]{2,4})*$';
|
||||
g_exp_double_words constant varchar2(255) := ' ([A-Za-z]+) \1';
|
||||
g_exp_cc_visa constant varchar2(255) := '^4[0-9]{12}(?:[0-9]{3})?$';
|
||||
|
||||
@ -12,59 +12,9 @@ as
|
||||
MBR 23.10.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
|
||||
|
||||
function is_valid_email (p_value in varchar2) return boolean
|
||||
as
|
||||
l_dot_pos number;
|
||||
l_at_pos number;
|
||||
l_str_length number;
|
||||
l_returnvalue boolean := true;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: returns true if value is valid email address
|
||||
|
||||
Remarks: Written by Anil Passi, see http://oracle.anilpassi.com/validate-email-pl-sql-2.html
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.10.2011 Created
|
||||
MBR 26.10.2011 Added check against multiple at signs
|
||||
|
||||
*/
|
||||
|
||||
if p_value is null then
|
||||
l_returnvalue := false;
|
||||
else
|
||||
|
||||
l_dot_pos := instr(p_value, '.');
|
||||
l_at_pos := instr(p_value, '@');
|
||||
|
||||
l_str_length := length(p_value);
|
||||
|
||||
if ((l_dot_pos = 0) or (l_at_pos = 0) or (l_dot_pos = l_at_pos + 1) or (l_at_pos = 1) or (l_at_pos = l_str_length) or (l_dot_pos = l_str_length)) then
|
||||
l_returnvalue := false;
|
||||
end if;
|
||||
|
||||
if instr(substr(p_value, l_at_pos), '.') = 0 then
|
||||
l_returnvalue := false;
|
||||
end if;
|
||||
|
||||
if instr(substr(p_value, l_at_pos + 1), '@') > 0 then
|
||||
l_returnvalue := false;
|
||||
end if;
|
||||
|
||||
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end is_valid_email;
|
||||
|
||||
|
||||
function is_valid_email2 (p_value in varchar2) return boolean
|
||||
as
|
||||
l_value varchar2(32000);
|
||||
l_returnvalue boolean;
|
||||
@ -79,19 +29,31 @@ begin
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.10.2011 Created
|
||||
Tim N 01.04.2016 Enhancements
|
||||
|
||||
*/
|
||||
|
||||
if p_value is null then
|
||||
l_returnvalue := false;
|
||||
else
|
||||
l_returnvalue := regexp_replace(p_value, regexp_util_pkg.g_exp_email_addresses, null) is null;
|
||||
end if;
|
||||
|
||||
|
||||
l_returnvalue := regexp_like(p_value, regexp_util_pkg.g_exp_email_addresses);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end is_valid_email;
|
||||
|
||||
|
||||
function is_valid_email2 (p_value in varchar2) return boolean
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: backward compatibility only
|
||||
|
||||
*/
|
||||
|
||||
return is_valid_email(p_value);
|
||||
|
||||
end is_valid_email2;
|
||||
|
||||
|
||||
|
||||
function is_valid_email_list (p_value in varchar2) return boolean
|
||||
as
|
||||
@ -107,17 +69,14 @@ begin
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.10.2011 Created
|
||||
Tim N 01.04.2016 Enhancements
|
||||
|
||||
*/
|
||||
|
||||
if p_value is null then
|
||||
l_returnvalue := false;
|
||||
else
|
||||
l_returnvalue := regexp_replace(p_value, regexp_util_pkg.g_exp_email_address_list, null) is null;
|
||||
end if;
|
||||
|
||||
l_returnvalue := regexp_like(p_value, regexp_util_pkg.g_exp_email_address_list);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
|
||||
end is_valid_email_list;
|
||||
|
||||
|
||||
|
||||
@ -19,7 +19,7 @@ as
|
||||
|
||||
-- returns true if value is valid email address
|
||||
function is_valid_email2 (p_value in varchar2) return boolean;
|
||||
|
||||
|
||||
-- returns true if value is valid email address list
|
||||
function is_valid_email_list (p_value in varchar2) return boolean;
|
||||
|
||||
|
||||
@ -1,5 +1,9 @@
|
||||
CREATE OR REPLACE package body xlsx_builder_pkg
|
||||
as
|
||||
--
|
||||
c_LOCAL_FILE_HEADER constant raw(4) := hextoraw( '504B0304' ); -- Local file header signature
|
||||
c_END_OF_CENTRAL_DIRECTORY constant raw(4) := hextoraw( '504B0506' ); -- End of central directory signature
|
||||
--
|
||||
type tp_XF_fmt is record
|
||||
( numFmtId pls_integer
|
||||
, fontId pls_integer
|
||||
@ -10,7 +14,6 @@ as
|
||||
type tp_col_fmts is table of tp_XF_fmt index by pls_integer;
|
||||
type tp_row_fmts is table of tp_XF_fmt index by pls_integer;
|
||||
type tp_widths is table of number index by pls_integer;
|
||||
type tp_strings is table of varchar2(32767) index by pls_integer;
|
||||
type tp_cell is record
|
||||
( value number
|
||||
, style varchar2(50)
|
||||
@ -29,11 +32,11 @@ as
|
||||
, url varchar2(1000)
|
||||
);
|
||||
type tp_hyperlinks is table of tp_hyperlink index by pls_integer;
|
||||
subtype tp_author is varchar2(32767);
|
||||
subtype tp_author is varchar2(32767 char);
|
||||
type tp_authors is table of pls_integer index by tp_author;
|
||||
authors tp_authors;
|
||||
type tp_comment is record
|
||||
( text varchar2(32767)
|
||||
( text varchar2(32767 char)
|
||||
, author tp_author
|
||||
, row pls_integer
|
||||
, column pls_integer
|
||||
@ -42,6 +45,21 @@ as
|
||||
);
|
||||
type tp_comments is table of tp_comment index by pls_integer;
|
||||
type tp_mergecells is table of varchar2(21) index by pls_integer;
|
||||
type tp_validation is record
|
||||
( type varchar2(10)
|
||||
, errorstyle varchar2(32)
|
||||
, showinputmessage boolean
|
||||
, prompt varchar2(32767 char)
|
||||
, title varchar2(32767 char)
|
||||
, error_title varchar2(32767 char)
|
||||
, error_txt varchar2(32767 char)
|
||||
, showerrormessage boolean
|
||||
, formula1 varchar2(32767 char)
|
||||
, formula2 varchar2(32767 char)
|
||||
, allowBlank boolean
|
||||
, sqref varchar2(32767 char)
|
||||
);
|
||||
type tp_validations is table of tp_validation index by pls_integer;
|
||||
type tp_sheet is record
|
||||
( rows tp_rows
|
||||
, widths tp_widths
|
||||
@ -54,6 +72,7 @@ as
|
||||
, row_fmts tp_row_fmts
|
||||
, comments tp_comments
|
||||
, mergecells tp_mergecells
|
||||
, validations tp_validations
|
||||
);
|
||||
type tp_sheets is table of tp_sheet index by pls_integer;
|
||||
type tp_numFmt is record
|
||||
@ -72,6 +91,7 @@ as
|
||||
, family pls_integer
|
||||
, fontsize number
|
||||
, theme pls_integer
|
||||
, RGB varchar2(8)
|
||||
, underline boolean
|
||||
, italic boolean
|
||||
, bold boolean
|
||||
@ -85,15 +105,26 @@ as
|
||||
);
|
||||
type tp_borders is table of tp_border index by pls_integer;
|
||||
type tp_numFmtIndexes is table of pls_integer index by pls_integer;
|
||||
type tp_strings is table of pls_integer index by varchar2(32767 char);
|
||||
type tp_str_ind is table of varchar2(32767 char) index by pls_integer;
|
||||
type tp_defined_name is record
|
||||
( name varchar2(32767 char)
|
||||
, ref varchar2(32767 char)
|
||||
, sheet pls_integer
|
||||
);
|
||||
type tp_defined_names is table of tp_defined_name index by pls_integer;
|
||||
type tp_book is record
|
||||
( sheets tp_sheets
|
||||
, strings tp_strings
|
||||
, str_ind tp_str_ind
|
||||
, str_cnt pls_integer := 0
|
||||
, fonts tp_fonts
|
||||
, fills tp_fills
|
||||
, borders tp_borders
|
||||
, numFmts tp_numFmts
|
||||
, cellXfs tp_cellXfs
|
||||
, numFmtIndexes tp_numFmtIndexes
|
||||
, defined_names tp_defined_names
|
||||
);
|
||||
workbook tp_book;
|
||||
--
|
||||
@ -121,6 +152,13 @@ as
|
||||
end loop;
|
||||
utl_file.fclose( t_fh );
|
||||
end;
|
||||
--
|
||||
function raw2num( p_raw raw, p_len integer, p_pos integer )
|
||||
return number
|
||||
is
|
||||
begin
|
||||
return utl_raw.cast_to_binary_integer( utl_raw.substr( p_raw, p_pos, p_len ), utl_raw.little_endian );
|
||||
end;
|
||||
--
|
||||
function little_endian( p_big number, p_bytes pls_integer := 4 )
|
||||
return raw
|
||||
@ -128,29 +166,58 @@ as
|
||||
begin
|
||||
return utl_raw.substr( utl_raw.cast_from_binary_integer( p_big, utl_raw.little_endian ), 1, p_bytes );
|
||||
end;
|
||||
--
|
||||
function blob2num( p_blob blob, p_len integer, p_pos integer )
|
||||
return number
|
||||
is
|
||||
begin
|
||||
return utl_raw.cast_to_binary_integer( dbms_lob.substr( p_blob, p_len, p_pos ), utl_raw.little_endian );
|
||||
end;
|
||||
--
|
||||
procedure add1file
|
||||
( p_zipped_blob in out nocopy blob
|
||||
( p_zipped_blob in out blob
|
||||
, p_name varchar2
|
||||
, p_content blob
|
||||
)
|
||||
is
|
||||
t_now date;
|
||||
t_blob blob;
|
||||
t_len integer;
|
||||
t_clen integer;
|
||||
t_crc32 raw(4) := hextoraw( '00000000' );
|
||||
t_compressed boolean := false;
|
||||
t_name raw(32767);
|
||||
begin
|
||||
t_now := sysdate;
|
||||
t_blob := utl_compress.lz_compress( p_content );
|
||||
t_clen := dbms_lob.getlength( t_blob );
|
||||
t_len := nvl( dbms_lob.getlength( p_content ), 0 );
|
||||
if t_len > 0
|
||||
then
|
||||
t_blob := utl_compress.lz_compress( p_content );
|
||||
t_clen := dbms_lob.getlength( t_blob ) - 18;
|
||||
t_compressed := t_clen < t_len;
|
||||
t_crc32 := dbms_lob.substr( t_blob, 4, t_clen + 11 );
|
||||
end if;
|
||||
if not t_compressed
|
||||
then
|
||||
t_clen := t_len;
|
||||
t_blob := p_content;
|
||||
end if;
|
||||
if p_zipped_blob is null
|
||||
then
|
||||
dbms_lob.createtemporary( p_zipped_blob, true );
|
||||
end if;
|
||||
t_name := utl_i18n.string_to_raw( p_name, 'AL32UTF8' );
|
||||
dbms_lob.append( p_zipped_blob
|
||||
, utl_raw.concat( hextoraw( '504B0304' ) -- Local file header signature
|
||||
, hextoraw( '1400' ) -- version 2.0
|
||||
, hextoraw( '0000' ) -- no General purpose bits
|
||||
, hextoraw( '0800' ) -- deflate
|
||||
, utl_raw.concat( c_LOCAL_FILE_HEADER -- Local file header signature
|
||||
, hextoraw( '1400' ) -- version 2.0
|
||||
, case when t_name = utl_i18n.string_to_raw( p_name, 'US8PC437' )
|
||||
then hextoraw( '0000' ) -- no General purpose bits
|
||||
else hextoraw( '0008' ) -- set Language encoding flag (EFS)
|
||||
end
|
||||
, case when t_compressed
|
||||
then hextoraw( '0800' ) -- deflate
|
||||
else hextoraw( '0000' ) -- stored
|
||||
end
|
||||
, little_endian( to_number( to_char( t_now, 'ss' ) ) / 2
|
||||
+ to_number( to_char( t_now, 'mi' ) ) * 32
|
||||
+ to_number( to_char( t_now, 'hh24' ) ) * 2048
|
||||
@ -161,29 +228,38 @@ as
|
||||
+ ( to_number( to_char( t_now, 'yyyy' ) ) - 1980 ) * 512
|
||||
, 2
|
||||
) -- File last modification date
|
||||
, dbms_lob.substr( t_blob, 4, t_clen - 7 ) -- CRC-32
|
||||
, little_endian( t_clen - 18 ) -- compressed size
|
||||
, little_endian( dbms_lob.getlength( p_content ) ) -- uncompressed size
|
||||
, little_endian( length( p_name ), 2 ) -- File name length
|
||||
, hextoraw( '0000' ) -- Extra field length
|
||||
, utl_raw.cast_to_raw( p_name ) -- File name
|
||||
, t_crc32 -- CRC-32
|
||||
, little_endian( t_clen ) -- compressed size
|
||||
, little_endian( t_len ) -- uncompressed size
|
||||
, little_endian( utl_raw.length( t_name ), 2 ) -- File name length
|
||||
, hextoraw( '0000' ) -- Extra field length
|
||||
, t_name -- File name
|
||||
)
|
||||
);
|
||||
dbms_lob.copy( p_zipped_blob, t_blob, t_clen - 18, dbms_lob.getlength( p_zipped_blob ) + 1, 11 ); -- compressed content
|
||||
dbms_lob.freetemporary( t_blob );
|
||||
if t_compressed
|
||||
then
|
||||
dbms_lob.copy( p_zipped_blob, t_blob, t_clen, dbms_lob.getlength( p_zipped_blob ) + 1, 11 ); -- compressed content
|
||||
elsif t_clen > 0
|
||||
then
|
||||
dbms_lob.copy( p_zipped_blob, t_blob, t_clen, dbms_lob.getlength( p_zipped_blob ) + 1, 1 ); -- content
|
||||
end if;
|
||||
if dbms_lob.istemporary( t_blob ) = 1
|
||||
then
|
||||
dbms_lob.freetemporary( t_blob );
|
||||
end if;
|
||||
end;
|
||||
--
|
||||
procedure finish_zip( p_zipped_blob in out nocopy blob )
|
||||
procedure finish_zip( p_zipped_blob in out blob )
|
||||
is
|
||||
t_cnt pls_integer := 0;
|
||||
t_offs integer;
|
||||
t_offs_dir_header integer;
|
||||
t_offs_end_header integer;
|
||||
t_comment raw(32767) := utl_raw.cast_to_raw( 'Zip-implementation by Anton Scheffer' );
|
||||
t_comment raw(32767) := utl_raw.cast_to_raw( 'Implementation by Anton Scheffer' );
|
||||
begin
|
||||
t_offs_dir_header := dbms_lob.getlength( p_zipped_blob );
|
||||
t_offs := dbms_lob.instr( p_zipped_blob, hextoraw( '504B0304' ), 1 );
|
||||
while t_offs > 0
|
||||
t_offs := 1;
|
||||
while dbms_lob.substr( p_zipped_blob, utl_raw.length( c_LOCAL_FILE_HEADER ), t_offs ) = c_LOCAL_FILE_HEADER
|
||||
loop
|
||||
t_cnt := t_cnt + 1;
|
||||
dbms_lob.append( p_zipped_blob
|
||||
@ -192,26 +268,39 @@ as
|
||||
, dbms_lob.substr( p_zipped_blob, 26, t_offs + 4 )
|
||||
, hextoraw( '0000' ) -- File comment length
|
||||
, hextoraw( '0000' ) -- Disk number where file starts
|
||||
, hextoraw( '0100' ) -- Internal file attributes
|
||||
, hextoraw( '2000B681' ) -- External file attributes
|
||||
, hextoraw( '0000' ) -- Internal file attributes =>
|
||||
-- 0000 binary file
|
||||
-- 0100 (ascii)text file
|
||||
, case
|
||||
when dbms_lob.substr( p_zipped_blob
|
||||
, 1
|
||||
, t_offs + 30 + blob2num( p_zipped_blob, 2, t_offs + 26 ) - 1
|
||||
) in ( hextoraw( '2F' ) -- /
|
||||
, hextoraw( '5C' ) -- \
|
||||
)
|
||||
then hextoraw( '10000000' ) -- a directory/folder
|
||||
else hextoraw( '2000B681' ) -- a file
|
||||
end -- External file attributes
|
||||
, little_endian( t_offs - 1 ) -- Relative offset of local file header
|
||||
, dbms_lob.substr( p_zipped_blob
|
||||
, utl_raw.cast_to_binary_integer( dbms_lob.substr( p_zipped_blob, 2, t_offs + 26 ), utl_raw.little_endian )
|
||||
, blob2num( p_zipped_blob, 2, t_offs + 26 )
|
||||
, t_offs + 30
|
||||
) -- File name
|
||||
)
|
||||
);
|
||||
t_offs := dbms_lob.instr( p_zipped_blob, hextoraw( '504B0304' ), t_offs + 32 );
|
||||
t_offs := t_offs + 30 + blob2num( p_zipped_blob, 4, t_offs + 18 ) -- compressed size
|
||||
+ blob2num( p_zipped_blob, 2, t_offs + 26 ) -- File name length
|
||||
+ blob2num( p_zipped_blob, 2, t_offs + 28 ); -- Extra field length
|
||||
end loop;
|
||||
t_offs_end_header := dbms_lob.getlength( p_zipped_blob );
|
||||
dbms_lob.append( p_zipped_blob
|
||||
, utl_raw.concat( hextoraw( '504B0506' ) -- End of central directory signature
|
||||
, utl_raw.concat( c_END_OF_CENTRAL_DIRECTORY -- End of central directory signature
|
||||
, hextoraw( '0000' ) -- Number of this disk
|
||||
, hextoraw( '0000' ) -- Disk where central directory starts
|
||||
, little_endian( t_cnt, 2 ) -- Number of central directory records on this disk
|
||||
, little_endian( t_cnt, 2 ) -- Total number of central directory records
|
||||
, little_endian( t_offs_end_header - t_offs_dir_header ) -- Size of central directory
|
||||
, little_endian( t_offs_dir_header ) -- Relative offset of local file header
|
||||
, little_endian( t_offs_dir_header ) -- Offset of start of central directory, relative to start of archive
|
||||
, little_endian( nvl( utl_raw.length( t_comment ), 0 ), 2 ) -- ZIP file comment length
|
||||
, t_comment
|
||||
)
|
||||
@ -258,13 +347,16 @@ as
|
||||
workbook.sheets( s ).row_fmts.delete();
|
||||
workbook.sheets( s ).comments.delete();
|
||||
workbook.sheets( s ).mergecells.delete();
|
||||
workbook.sheets( s ).validations.delete();
|
||||
end loop;
|
||||
workbook.strings.delete();
|
||||
workbook.str_ind.delete();
|
||||
workbook.fonts.delete();
|
||||
workbook.fills.delete();
|
||||
workbook.borders.delete();
|
||||
workbook.numFmts.delete();
|
||||
workbook.cellXfs.delete();
|
||||
workbook.defined_names.delete();
|
||||
workbook := null;
|
||||
end;
|
||||
--
|
||||
@ -274,6 +366,10 @@ as
|
||||
t_ind pls_integer;
|
||||
begin
|
||||
workbook.sheets( t_nr ).name := nvl( dbms_xmlgen.convert( translate( p_sheetname, 'a/\[]*:?', 'a' ) ), 'Sheet' || t_nr );
|
||||
if workbook.strings.count() = 0
|
||||
then
|
||||
workbook.str_cnt := 0;
|
||||
end if;
|
||||
if workbook.fonts.count() = 0
|
||||
then
|
||||
t_ind := get_font( 'Calibri' );
|
||||
@ -375,6 +471,7 @@ as
|
||||
, p_underline boolean := false
|
||||
, p_italic boolean := false
|
||||
, p_bold boolean := false
|
||||
, p_rgb varchar2 := null -- this is a hex ALPHA Red Green Blue value
|
||||
)
|
||||
return pls_integer
|
||||
is
|
||||
@ -391,6 +488,9 @@ as
|
||||
and workbook.fonts( f ).underline = p_underline
|
||||
and workbook.fonts( f ).italic = p_italic
|
||||
and workbook.fonts( f ).bold = p_bold
|
||||
and ( workbook.fonts( f ).rgb = p_rgb
|
||||
or ( workbook.fonts( f ).rgb is null and p_rgb is null )
|
||||
)
|
||||
)
|
||||
then
|
||||
return f;
|
||||
@ -405,6 +505,7 @@ as
|
||||
workbook.fonts( t_ind ).underline := p_underline;
|
||||
workbook.fonts( t_ind ).italic := p_italic;
|
||||
workbook.fonts( t_ind ).bold := p_bold;
|
||||
workbook.fonts( t_ind ).rgb := p_rgb;
|
||||
return t_ind;
|
||||
end;
|
||||
--
|
||||
@ -548,19 +649,6 @@ as
|
||||
end if;
|
||||
return 's="' || t_XfId || '"';
|
||||
end;
|
||||
--
|
||||
function clean_string (p_string in varchar2)
|
||||
return varchar2
|
||||
is
|
||||
invalid_ascii constant varchar2(32) :=
|
||||
chr(00)||chr(01)||chr(02)||chr(03)||chr(04)||chr(05)||chr(06)||chr(07)||
|
||||
chr(08)|| chr(11)||chr(12)|| chr(14)||chr(15)||
|
||||
chr(16)||chr(17)||chr(18)||chr(19)||chr(20)||chr(21)||chr(22)||chr(23)||
|
||||
chr(24)||chr(25)||chr(26)||chr(27)||chr(28)||chr(29)||chr(30)||chr(31)
|
||||
;
|
||||
begin
|
||||
return translate(translate( p_string, invalid_ascii, chr(1)), chr(0)||chr(1), ' ');
|
||||
end;
|
||||
--
|
||||
procedure cell
|
||||
( p_col pls_integer
|
||||
@ -580,6 +668,23 @@ as
|
||||
workbook.sheets( t_sheet ).rows( p_row )( p_col ).style := null;
|
||||
workbook.sheets( t_sheet ).rows( p_row )( p_col ).style := get_XfId( t_sheet, p_col, p_row, p_numFmtId, p_fontId, p_fillId, p_borderId, p_alignment );
|
||||
end;
|
||||
--
|
||||
function add_string( p_string varchar2 )
|
||||
return pls_integer
|
||||
is
|
||||
t_cnt pls_integer;
|
||||
begin
|
||||
if workbook.strings.exists( p_string )
|
||||
then
|
||||
t_cnt := workbook.strings( p_string );
|
||||
else
|
||||
t_cnt := workbook.strings.count();
|
||||
workbook.str_ind( t_cnt ) := p_string;
|
||||
workbook.strings( nvl( p_string, '' ) ) := t_cnt;
|
||||
end if;
|
||||
workbook.str_cnt := workbook.str_cnt + 1;
|
||||
return t_cnt;
|
||||
end;
|
||||
--
|
||||
procedure cell
|
||||
( p_col pls_integer
|
||||
@ -596,8 +701,7 @@ as
|
||||
t_sheet pls_integer := nvl( p_sheet, workbook.sheets.count() );
|
||||
t_alignment tp_alignment := p_alignment;
|
||||
begin
|
||||
workbook.sheets( t_sheet ).rows( p_row )( p_col ).value := workbook.strings.count();
|
||||
workbook.strings( workbook.strings.count() ) := clean_string( p_value );
|
||||
workbook.sheets( t_sheet ).rows( p_row )( p_col ).value := add_string( p_value );
|
||||
if t_alignment.wrapText is null and instr( p_value, chr(13) ) > 0
|
||||
then
|
||||
t_alignment.wrapText := true;
|
||||
@ -645,8 +749,7 @@ as
|
||||
t_ind pls_integer;
|
||||
t_sheet pls_integer := nvl( p_sheet, workbook.sheets.count() );
|
||||
begin
|
||||
workbook.sheets( t_sheet ).rows( p_row )( p_col ).value := workbook.strings.count();
|
||||
workbook.strings( workbook.strings.count() ) := clean_string( nvl( p_value, p_url ) );
|
||||
workbook.sheets( t_sheet ).rows( p_row )( p_col ).value := add_string( nvl( p_value, p_url ) );
|
||||
workbook.sheets( t_sheet ).rows( p_row )( p_col ).style := 't="s" ' || get_XfId( t_sheet, p_col, p_row, '', get_font( 'Calibri', p_theme => 10, p_underline => true ) );
|
||||
t_ind := workbook.sheets( t_sheet ).hyperlinks.count() + 1;
|
||||
workbook.sheets( t_sheet ).hyperlinks( t_ind ).cell := alfan_col( p_col ) || p_row;
|
||||
@ -689,6 +792,111 @@ as
|
||||
t_ind := workbook.sheets( t_sheet ).mergecells.count() + 1;
|
||||
workbook.sheets( t_sheet ).mergecells( t_ind ) := alfan_col( p_tl_col ) || p_tl_row || ':' || alfan_col( p_br_col ) || p_br_row;
|
||||
end;
|
||||
--
|
||||
procedure add_validation
|
||||
( p_type varchar2
|
||||
, p_sqref varchar2
|
||||
, p_style varchar2 := 'stop' -- stop, warning, information
|
||||
, p_formula1 varchar2 := null
|
||||
, p_formula2 varchar2 := null
|
||||
, p_title varchar2 := null
|
||||
, p_prompt varchar := null
|
||||
, p_show_error boolean := false
|
||||
, p_error_title varchar2 := null
|
||||
, p_error_txt varchar2 := null
|
||||
, p_sheet pls_integer := null
|
||||
)
|
||||
is
|
||||
t_ind pls_integer;
|
||||
t_sheet pls_integer := nvl( p_sheet, workbook.sheets.count() );
|
||||
begin
|
||||
t_ind := workbook.sheets( t_sheet ).validations.count() + 1;
|
||||
workbook.sheets( t_sheet ).validations( t_ind ).type := p_type;
|
||||
workbook.sheets( t_sheet ).validations( t_ind ).errorstyle := p_style;
|
||||
workbook.sheets( t_sheet ).validations( t_ind ).sqref := p_sqref;
|
||||
workbook.sheets( t_sheet ).validations( t_ind ).formula1 := p_formula1;
|
||||
workbook.sheets( t_sheet ).validations( t_ind ).error_title := p_error_title;
|
||||
workbook.sheets( t_sheet ).validations( t_ind ).error_txt := p_error_txt;
|
||||
workbook.sheets( t_sheet ).validations( t_ind ).title := p_title;
|
||||
workbook.sheets( t_sheet ).validations( t_ind ).prompt := p_prompt;
|
||||
workbook.sheets( t_sheet ).validations( t_ind ).showerrormessage := p_show_error;
|
||||
end;
|
||||
--
|
||||
procedure list_validation
|
||||
( p_sqref_col pls_integer
|
||||
, p_sqref_row pls_integer
|
||||
, p_tl_col pls_integer -- top left
|
||||
, p_tl_row pls_integer
|
||||
, p_br_col pls_integer -- bottom right
|
||||
, p_br_row pls_integer
|
||||
, p_style varchar2 := 'stop' -- stop, warning, information
|
||||
, p_title varchar2 := null
|
||||
, p_prompt varchar := null
|
||||
, p_show_error boolean := false
|
||||
, p_error_title varchar2 := null
|
||||
, p_error_txt varchar2 := null
|
||||
, p_sheet pls_integer := null
|
||||
)
|
||||
is
|
||||
begin
|
||||
add_validation( 'list'
|
||||
, alfan_col( p_sqref_col ) || p_sqref_row
|
||||
, p_style => lower( p_style )
|
||||
, p_formula1 => '$' || alfan_col( p_tl_col ) || '$' || p_tl_row || ':$' || alfan_col( p_br_col ) || '$' || p_br_row
|
||||
, p_title => p_title
|
||||
, p_prompt => p_prompt
|
||||
, p_show_error => p_show_error
|
||||
, p_error_title => p_error_title
|
||||
, p_error_txt => p_error_txt
|
||||
, p_sheet => p_sheet
|
||||
);
|
||||
end;
|
||||
--
|
||||
procedure list_validation
|
||||
( p_sqref_col pls_integer
|
||||
, p_sqref_row pls_integer
|
||||
, p_defined_name varchar2
|
||||
, p_style varchar2 := 'stop' -- stop, warning, information
|
||||
, p_title varchar2 := null
|
||||
, p_prompt varchar := null
|
||||
, p_show_error boolean := false
|
||||
, p_error_title varchar2 := null
|
||||
, p_error_txt varchar2 := null
|
||||
, p_sheet pls_integer := null
|
||||
)
|
||||
is
|
||||
begin
|
||||
add_validation( 'list'
|
||||
, alfan_col( p_sqref_col ) || p_sqref_row
|
||||
, p_style => lower( p_style )
|
||||
, p_formula1 => p_defined_name
|
||||
, p_title => p_title
|
||||
, p_prompt => p_prompt
|
||||
, p_show_error => p_show_error
|
||||
, p_error_title => p_error_title
|
||||
, p_error_txt => p_error_txt
|
||||
, p_sheet => p_sheet
|
||||
);
|
||||
end;
|
||||
--
|
||||
procedure defined_name
|
||||
( p_tl_col pls_integer -- top left
|
||||
, p_tl_row pls_integer
|
||||
, p_br_col pls_integer -- bottom right
|
||||
, p_br_row pls_integer
|
||||
, p_name varchar2
|
||||
, p_sheet pls_integer := null
|
||||
, p_localsheet pls_integer := null
|
||||
)
|
||||
is
|
||||
t_ind pls_integer;
|
||||
t_sheet pls_integer := nvl( p_sheet, workbook.sheets.count() );
|
||||
begin
|
||||
t_ind := workbook.defined_names.count() + 1;
|
||||
workbook.defined_names( t_ind ).name := p_name;
|
||||
workbook.defined_names( t_ind ).ref := 'Sheet' || t_sheet || '!$' || alfan_col( p_tl_col ) || '$' || p_tl_row || ':$' || alfan_col( p_br_col ) || '$' || p_br_row;
|
||||
workbook.defined_names( t_ind ).sheet := p_localsheet;
|
||||
end;
|
||||
--
|
||||
procedure set_column_width
|
||||
( p_col pls_integer
|
||||
@ -743,8 +951,10 @@ as
|
||||
, p_sheet pls_integer := null
|
||||
)
|
||||
is
|
||||
t_sheet pls_integer := nvl( p_sheet, workbook.sheets.count() );
|
||||
begin
|
||||
workbook.sheets( nvl( p_sheet, workbook.sheets.count() ) ).freeze_rows := p_nr_rows;
|
||||
workbook.sheets( t_sheet ).freeze_cols := null;
|
||||
workbook.sheets( t_sheet ).freeze_rows := p_nr_rows;
|
||||
end;
|
||||
--
|
||||
procedure freeze_cols
|
||||
@ -752,8 +962,22 @@ as
|
||||
, p_sheet pls_integer := null
|
||||
)
|
||||
is
|
||||
t_sheet pls_integer := nvl( p_sheet, workbook.sheets.count() );
|
||||
begin
|
||||
workbook.sheets( nvl( p_sheet, workbook.sheets.count() ) ).freeze_cols := p_nr_cols;
|
||||
workbook.sheets( t_sheet ).freeze_rows := null;
|
||||
workbook.sheets( t_sheet ).freeze_cols := p_nr_cols;
|
||||
end;
|
||||
--
|
||||
procedure freeze_pane
|
||||
( p_col pls_integer
|
||||
, p_row pls_integer
|
||||
, p_sheet pls_integer := null
|
||||
)
|
||||
is
|
||||
t_sheet pls_integer := nvl( p_sheet, workbook.sheets.count() );
|
||||
begin
|
||||
workbook.sheets( t_sheet ).freeze_rows := p_row;
|
||||
workbook.sheets( t_sheet ).freeze_cols := p_col;
|
||||
end;
|
||||
--
|
||||
procedure set_autofilter
|
||||
@ -767,12 +991,41 @@ as
|
||||
t_ind pls_integer;
|
||||
t_sheet pls_integer := nvl( p_sheet, workbook.sheets.count() );
|
||||
begin
|
||||
t_ind := workbook.sheets( t_sheet ).autofilters.count() + 1;
|
||||
t_ind := 1;
|
||||
workbook.sheets( t_sheet ).autofilters( t_ind ).column_start := p_column_start;
|
||||
workbook.sheets( t_sheet ).autofilters( t_ind ).column_end := p_column_end;
|
||||
workbook.sheets( t_sheet ).autofilters( t_ind ).row_start := p_row_start;
|
||||
workbook.sheets( t_sheet ).autofilters( t_ind ).row_end := p_row_end;
|
||||
defined_name
|
||||
( p_column_start
|
||||
, p_row_start
|
||||
, p_column_end
|
||||
, p_row_end
|
||||
, '_xlnm._FilterDatabase'
|
||||
, t_sheet
|
||||
, t_sheet - 1
|
||||
);
|
||||
end;
|
||||
--
|
||||
/*
|
||||
procedure add1xml
|
||||
( p_excel in out nocopy blob
|
||||
, p_filename varchar2
|
||||
, p_xml clob
|
||||
)
|
||||
is
|
||||
t_tmp blob;
|
||||
c_step constant number := 24396;
|
||||
begin
|
||||
dbms_lob.createtemporary( t_tmp, true );
|
||||
for i in 0 .. trunc( length( p_xml ) / c_step )
|
||||
loop
|
||||
dbms_lob.append( t_tmp, utl_i18n.string_to_raw( substr( p_xml, i * c_step + 1, c_step ), 'AL32UTF8' ) );
|
||||
end loop;
|
||||
add1file( p_excel, p_filename, t_tmp );
|
||||
dbms_lob.freetemporary( t_tmp );
|
||||
end;
|
||||
*/
|
||||
--
|
||||
procedure add1xml
|
||||
( p_excel in out nocopy blob
|
||||
@ -781,12 +1034,23 @@ as
|
||||
)
|
||||
is
|
||||
t_tmp blob;
|
||||
dest_offset integer := 1;
|
||||
src_offset integer := 1;
|
||||
lang_context integer;
|
||||
warning integer;
|
||||
begin
|
||||
lang_context := dbms_lob.DEFAULT_LANG_CTX;
|
||||
dbms_lob.createtemporary( t_tmp, true );
|
||||
for i in 0 .. trunc( length( p_xml ) / 4000 )
|
||||
loop
|
||||
dbms_lob.append( t_tmp, utl_i18n.string_to_raw( substr( p_xml, i * 4000 + 1, 4000 ), 'AL32UTF8' ) );
|
||||
end loop;
|
||||
dbms_lob.converttoblob
|
||||
( t_tmp
|
||||
, p_xml
|
||||
, dbms_lob.lobmaxsize
|
||||
, dest_offset
|
||||
, src_offset
|
||||
, nls_charset_id( 'AL32UTF8' )
|
||||
, lang_context
|
||||
, warning
|
||||
);
|
||||
add1file( p_excel, p_filename, t_tmp );
|
||||
dbms_lob.freetemporary( t_tmp );
|
||||
end;
|
||||
@ -796,16 +1060,19 @@ as
|
||||
is
|
||||
t_excel blob;
|
||||
t_xxx clob;
|
||||
t_tmp clob;
|
||||
t_tmp varchar2(32767 char);
|
||||
t_str varchar2(32767 char);
|
||||
t_c number;
|
||||
t_h number;
|
||||
t_w number;
|
||||
t_cw number;
|
||||
t_cell varchar2(1000);
|
||||
t_cell varchar2(1000 char);
|
||||
t_row_ind pls_integer;
|
||||
t_col_min pls_integer;
|
||||
t_col_max pls_integer;
|
||||
t_col_ind pls_integer;
|
||||
t_len pls_integer;
|
||||
ts timestamp := systimestamp;
|
||||
begin
|
||||
dbms_lob.createtemporary( t_excel, true );
|
||||
t_xxx := '<?xml version="1.0" encoding="UTF-8" standalone="yes"?>
|
||||
@ -900,10 +1167,13 @@ as
|
||||
case when workbook.fonts( f ).italic then '<i/>' end ||
|
||||
case when workbook.fonts( f ).underline then '<u/>' end ||
|
||||
'<sz val="' || to_char( workbook.fonts( f ).fontsize, 'TM9', 'NLS_NUMERIC_CHARACTERS=.,' ) || '"/>
|
||||
<color theme="' || workbook.fonts( f ).theme || '"/>
|
||||
<color ' || case when workbook.fonts( f ).rgb is not null
|
||||
then 'rgb="' || workbook.fonts( f ).rgb
|
||||
else 'theme="' || workbook.fonts( f ).theme
|
||||
end || '"/>
|
||||
<name val="' || workbook.fonts( f ).name || '"/>
|
||||
<family val="' || workbook.fonts( f ).family || '"/>
|
||||
<scheme val="minor"/>
|
||||
<scheme val="none"/>
|
||||
</font>';
|
||||
end loop;
|
||||
t_xxx := t_xxx || '</fonts>
|
||||
@ -972,10 +1242,20 @@ as
|
||||
t_xxx := t_xxx || '
|
||||
<sheet name="' || workbook.sheets( s ).name || '" sheetId="' || s || '" r:id="rId' || ( 9 + s ) || '"/>';
|
||||
end loop;
|
||||
t_xxx := t_xxx || '
|
||||
</sheets>
|
||||
<calcPr calcId="144525"/>
|
||||
</workbook>';
|
||||
t_xxx := t_xxx || '</sheets>';
|
||||
if workbook.defined_names.count() > 0
|
||||
then
|
||||
t_xxx := t_xxx || '<definedNames>';
|
||||
for s in 1 .. workbook.defined_names.count()
|
||||
loop
|
||||
t_xxx := t_xxx || '
|
||||
<definedName name="' || workbook.defined_names( s ).name || '"' ||
|
||||
case when workbook.defined_names( s ).sheet is not null then ' localSheetId="' || to_char( workbook.defined_names( s ).sheet ) || '"' end ||
|
||||
'>' || workbook.defined_names( s ).ref || '</definedName>';
|
||||
end loop;
|
||||
t_xxx := t_xxx || '</definedNames>';
|
||||
end if;
|
||||
t_xxx := t_xxx || '<calcPr calcId="144525"/></workbook>';
|
||||
add1xml( t_excel, 'xl/workbook.xml', t_xxx );
|
||||
t_xxx := '<?xml version="1.0" encoding="UTF-8" standalone="yes"?>
|
||||
<a:theme xmlns:a="http://schemas.openxmlformats.org/drawingml/2006/main" name="Office Theme">
|
||||
@ -1277,13 +1557,22 @@ as
|
||||
<dimension ref="' || alfan_col( t_col_min ) || workbook.sheets( s ).rows.first() || ':' || alfan_col( t_col_max ) || workbook.sheets( s ).rows.last() || '"/>
|
||||
<sheetViews>
|
||||
<sheetView' || case when s = 1 then ' tabSelected="1"' end || ' workbookViewId="0">';
|
||||
if workbook.sheets( s ).freeze_rows > 0
|
||||
if workbook.sheets( s ).freeze_rows > 0 and workbook.sheets( s ).freeze_cols > 0
|
||||
then
|
||||
t_xxx := t_xxx || '<pane ySplit="' || workbook.sheets( s ).freeze_rows || '" topLeftCell="A' || ( workbook.sheets( s ).freeze_rows + 1 ) || '" activePane="bottomLeft" state="frozen"/>';
|
||||
end if;
|
||||
if workbook.sheets( s ).freeze_cols > 0
|
||||
then
|
||||
t_xxx := t_xxx || '<pane xSplit="' || workbook.sheets( s ).freeze_cols || '" topLeftCell="' || alfan_col( workbook.sheets( s ).freeze_cols + 1 ) || '1" activePane="bottomLeft" state="frozen"/>';
|
||||
t_xxx := t_xxx || ( '<pane xSplit="' || workbook.sheets( s ).freeze_cols || '" '
|
||||
|| 'ySplit="' || workbook.sheets( s ).freeze_rows || '" '
|
||||
|| 'topLeftCell="' || alfan_col( workbook.sheets( s ).freeze_cols + 1 ) || ( workbook.sheets( s ).freeze_rows + 1 ) || '" '
|
||||
|| 'activePane="bottomLeft" state="frozen"/>'
|
||||
);
|
||||
else
|
||||
if workbook.sheets( s ).freeze_rows > 0
|
||||
then
|
||||
t_xxx := t_xxx || '<pane ySplit="' || workbook.sheets( s ).freeze_rows || '" topLeftCell="A' || ( workbook.sheets( s ).freeze_rows + 1 ) || '" activePane="bottomLeft" state="frozen"/>';
|
||||
end if;
|
||||
if workbook.sheets( s ).freeze_cols > 0
|
||||
then
|
||||
t_xxx := t_xxx || '<pane xSplit="' || workbook.sheets( s ).freeze_cols || '" topLeftCell="' || alfan_col( workbook.sheets( s ).freeze_cols + 1 ) || '1" activePane="bottomLeft" state="frozen"/>';
|
||||
end if;
|
||||
end if;
|
||||
t_xxx := t_xxx || '</sheetView>
|
||||
</sheetViews>
|
||||
@ -1295,7 +1584,7 @@ as
|
||||
while t_col_ind is not null
|
||||
loop
|
||||
t_xxx := t_xxx ||
|
||||
'<col min="' || t_col_ind || '" max="' || t_col_ind || '" width="' || workbook.sheets( s ).widths( t_col_ind ) || '" customWidth="1"/>';
|
||||
'<col min="' || t_col_ind || '" max="' || t_col_ind || '" width="' || to_char( workbook.sheets( s ).widths( t_col_ind ), 'TM9', 'NLS_NUMERIC_CHARACTERS=.,' ) || '" customWidth="1"/>';
|
||||
t_col_ind := workbook.sheets( s ).widths.next( t_col_ind );
|
||||
end loop;
|
||||
t_xxx := t_xxx || '</cols>';
|
||||
@ -1306,26 +1595,31 @@ as
|
||||
while t_row_ind is not null
|
||||
loop
|
||||
t_tmp := t_tmp || '<row r="' || t_row_ind || '" spans="' || t_col_min || ':' || t_col_max || '">';
|
||||
t_len := length( t_tmp );
|
||||
t_col_ind := workbook.sheets( s ).rows( t_row_ind ).first();
|
||||
while t_col_ind is not null
|
||||
loop
|
||||
t_cell := '<c r="' || alfan_col( t_col_ind ) || t_row_ind || '"';
|
||||
t_cell := t_cell || ' ' || workbook.sheets( s ).rows( t_row_ind )( t_col_ind ).style;
|
||||
t_cell := t_cell || '><v>';
|
||||
t_cell := t_cell || to_char( workbook.sheets( s ).rows( t_row_ind )( t_col_ind ).value, 'TM9', 'NLS_NUMERIC_CHARACTERS=.,' );
|
||||
t_cell := t_cell || '</v></c>';
|
||||
t_cell := '<c r="' || alfan_col( t_col_ind ) || t_row_ind || '"'
|
||||
|| ' ' || workbook.sheets( s ).rows( t_row_ind )( t_col_ind ).style
|
||||
|| '><v>'
|
||||
|| to_char( workbook.sheets( s ).rows( t_row_ind )( t_col_ind ).value, 'TM9', 'NLS_NUMERIC_CHARACTERS=.,' )
|
||||
|| '</v></c>';
|
||||
if t_len > 32000
|
||||
then
|
||||
dbms_lob.writeappend( t_xxx, t_len, t_tmp );
|
||||
t_tmp := null;
|
||||
t_len := 0;
|
||||
end if;
|
||||
t_tmp := t_tmp || t_cell;
|
||||
t_len := t_len + length( t_cell );
|
||||
t_col_ind := workbook.sheets( s ).rows( t_row_ind ).next( t_col_ind );
|
||||
end loop;
|
||||
t_tmp := t_tmp || '</row>';
|
||||
if length( t_tmp ) > 8000
|
||||
then
|
||||
t_xxx := t_xxx || t_tmp;
|
||||
t_tmp := null;
|
||||
end if;
|
||||
t_row_ind := workbook.sheets( s ).rows.next( t_row_ind );
|
||||
end loop;
|
||||
t_xxx := t_xxx || t_tmp || '</sheetData>';
|
||||
t_tmp := t_tmp || '</sheetData>';
|
||||
t_len := length( t_tmp );
|
||||
dbms_lob.writeappend( t_xxx, t_len, t_tmp );
|
||||
for a in 1 .. workbook.sheets( s ).autofilters.count()
|
||||
loop
|
||||
t_xxx := t_xxx || '<autoFilter ref="' ||
|
||||
@ -1343,6 +1637,51 @@ as
|
||||
end loop;
|
||||
t_xxx := t_xxx || '</mergeCells>';
|
||||
end if;
|
||||
--
|
||||
if workbook.sheets( s ).validations.count() > 0
|
||||
then
|
||||
t_xxx := t_xxx || '<dataValidations count="' || to_char( workbook.sheets( s ).validations.count() ) || '">';
|
||||
for m in 1 .. workbook.sheets( s ).validations.count()
|
||||
loop
|
||||
t_xxx := t_xxx || '<dataValidation' ||
|
||||
' type="' || workbook.sheets( s ).validations( m ).type || '"' ||
|
||||
' errorStyle="' || workbook.sheets( s ).validations( m ).errorstyle || '"' ||
|
||||
' allowBlank="' || case when nvl( workbook.sheets( s ).validations( m ).allowBlank, true ) then '1' else '0' end || '"' ||
|
||||
' sqref="' || workbook.sheets( s ).validations( m ).sqref || '"';
|
||||
if workbook.sheets( s ).validations( m ).prompt is not null
|
||||
then
|
||||
t_xxx := t_xxx || ' showInputMessage="1" prompt="' || workbook.sheets( s ).validations( m ).prompt || '"';
|
||||
if workbook.sheets( s ).validations( m ).title is not null
|
||||
then
|
||||
t_xxx := t_xxx || ' promptTitle="' || workbook.sheets( s ).validations( m ).title || '"';
|
||||
end if;
|
||||
end if;
|
||||
if workbook.sheets( s ).validations( m ).showerrormessage
|
||||
then
|
||||
t_xxx := t_xxx || ' showErrorMessage="1"';
|
||||
if workbook.sheets( s ).validations( m ).error_title is not null
|
||||
then
|
||||
t_xxx := t_xxx || ' errorTitle="' || workbook.sheets( s ).validations( m ).error_title || '"';
|
||||
end if;
|
||||
if workbook.sheets( s ).validations( m ).error_txt is not null
|
||||
then
|
||||
t_xxx := t_xxx || ' error="' || workbook.sheets( s ).validations( m ).error_txt || '"';
|
||||
end if;
|
||||
end if;
|
||||
t_xxx := t_xxx || '>';
|
||||
if workbook.sheets( s ).validations( m ).formula1 is not null
|
||||
then
|
||||
t_xxx := t_xxx || '<formula1>' || workbook.sheets( s ).validations( m ).formula1 || '</formula1>';
|
||||
end if;
|
||||
if workbook.sheets( s ).validations( m ).formula2 is not null
|
||||
then
|
||||
t_xxx := t_xxx || '<formula2>' || workbook.sheets( s ).validations( m ).formula2 || '</formula2>';
|
||||
end if;
|
||||
t_xxx := t_xxx || '</dataValidation>';
|
||||
end loop;
|
||||
t_xxx := t_xxx || '</dataValidations>';
|
||||
end if;
|
||||
--
|
||||
if workbook.sheets( s ).hyperlinks.count() > 0
|
||||
then
|
||||
t_xxx := t_xxx || '<hyperlinks>';
|
||||
@ -1357,6 +1696,7 @@ as
|
||||
then
|
||||
t_xxx := t_xxx || '<legacyDrawing r:id="rId' || ( workbook.sheets( s ).hyperlinks.count() + 1 ) || '"/>';
|
||||
end if;
|
||||
--
|
||||
t_xxx := t_xxx || '</worksheet>';
|
||||
add1xml( t_excel, 'xl/worksheets/sheet' || s || '.xml', t_xxx );
|
||||
if workbook.sheets( s ).hyperlinks.count() > 0 or workbook.sheets( s ).comments.count() > 0
|
||||
@ -1469,16 +1809,17 @@ style="position:absolute;margin-left:35.25pt;margin-top:3pt;z-index:' || to_char
|
||||
t_xxx := t_xxx || '</Relationships>';
|
||||
add1xml( t_excel, 'xl/_rels/workbook.xml.rels', t_xxx );
|
||||
t_xxx := '<?xml version="1.0" encoding="UTF-8" standalone="yes"?>
|
||||
<sst xmlns="http://schemas.openxmlformats.org/spreadsheetml/2006/main" count="' || workbook.strings.count() || '" uniqueCount="' || workbook.strings.count() || '">';
|
||||
<sst xmlns="http://schemas.openxmlformats.org/spreadsheetml/2006/main" count="' || workbook.str_cnt || '" uniqueCount="' || workbook.strings.count() || '">';
|
||||
t_tmp := null;
|
||||
for i in 0 .. workbook.strings.count() - 1
|
||||
for i in 0 .. workbook.str_ind.count() - 1
|
||||
loop
|
||||
t_tmp := t_tmp || '<si><t>' || dbms_xmlgen.convert( substr( workbook.strings( i ), 1, 32000 ) ) || '</t></si>';
|
||||
if length( t_tmp ) > 8000
|
||||
t_str := '<si><t>' || dbms_xmlgen.convert( substr( workbook.str_ind( i ), 1, 32000 ) ) || '</t></si>';
|
||||
if length( t_tmp ) + length( t_str ) > 32000
|
||||
then
|
||||
t_xxx := t_xxx || t_tmp;
|
||||
t_tmp := null;
|
||||
end if;
|
||||
t_tmp := t_tmp || t_str;
|
||||
end loop;
|
||||
t_xxx := t_xxx || t_tmp || '</sst>';
|
||||
add1xml( t_excel, 'xl/sharedStrings.xml', t_xxx );
|
||||
@ -1560,7 +1901,10 @@ style="position:absolute;margin-left:35.25pt;margin-top:3pt;z-index:' || to_char
|
||||
dbms_sql.column_value( t_c, c, n_tab );
|
||||
for i in 0 .. t_r - 1
|
||||
loop
|
||||
cell( c, t_cur_row + i, n_tab( i + n_tab.first() ), p_sheet => t_sheet );
|
||||
if n_tab( i + n_tab.first() ) is not null
|
||||
then
|
||||
cell( c, t_cur_row + i, n_tab( i + n_tab.first() ), p_sheet => t_sheet );
|
||||
end if;
|
||||
end loop;
|
||||
n_tab.delete;
|
||||
when t_desc_tab( c ).col_type in ( 12, 178, 179, 180, 181 , 231 )
|
||||
@ -1568,7 +1912,10 @@ style="position:absolute;margin-left:35.25pt;margin-top:3pt;z-index:' || to_char
|
||||
dbms_sql.column_value( t_c, c, d_tab );
|
||||
for i in 0 .. t_r - 1
|
||||
loop
|
||||
cell( c, t_cur_row + i, d_tab( i + d_tab.first() ), p_sheet => t_sheet );
|
||||
if d_tab( i + d_tab.first() ) is not null
|
||||
then
|
||||
cell( c, t_cur_row + i, d_tab( i + d_tab.first() ), p_sheet => t_sheet );
|
||||
end if;
|
||||
end loop;
|
||||
d_tab.delete;
|
||||
when t_desc_tab( c ).col_type in ( 1, 8, 9, 96, 112 )
|
||||
@ -1576,7 +1923,10 @@ style="position:absolute;margin-left:35.25pt;margin-top:3pt;z-index:' || to_char
|
||||
dbms_sql.column_value( t_c, c, v_tab );
|
||||
for i in 0 .. t_r - 1
|
||||
loop
|
||||
cell( c, t_cur_row + i, v_tab( i + v_tab.first() ), p_sheet => t_sheet );
|
||||
if v_tab( i + v_tab.first() ) is not null
|
||||
then
|
||||
cell( c, t_cur_row + i, v_tab( i + v_tab.first() ), p_sheet => t_sheet );
|
||||
end if;
|
||||
end loop;
|
||||
v_tab.delete;
|
||||
else
|
||||
|
||||
@ -6,6 +6,7 @@ as
|
||||
** Date: 19-02-2011
|
||||
** Website: http://technology.amis.nl/blog
|
||||
** See also: http://technology.amis.nl/blog/?p=10995
|
||||
** See also: https://technology.amis.nl/2011/02/19/create-an-excel-file-with-plsql/
|
||||
**
|
||||
** Changelog:
|
||||
** Date: 21-02-2011
|
||||
@ -18,7 +19,43 @@ as
|
||||
** Fixed issue with timezone's set to a region(name) instead of a offset
|
||||
** Date: 08-04-2011
|
||||
** Fixed issue with XML-escaping from text
|
||||
** Date: 27-05-2011
|
||||
** Added MIT-license
|
||||
** Date: 11-08-2011
|
||||
** Fixed NLS-issue with column width
|
||||
** Date: 29-09-2011
|
||||
** Added font color
|
||||
** Date: 16-10-2011
|
||||
** fixed bug in add_string
|
||||
** Date: 26-04-2012
|
||||
** Fixed set_autofilter (only one autofilter per sheet, added _xlnm._FilterDatabase)
|
||||
** Added list_validation = drop-down
|
||||
** Date: 27-08-2013
|
||||
** Added freeze_pane
|
||||
**
|
||||
******************************************************************************
|
||||
******************************************************************************
|
||||
Copyright (C) 2011, 2012 by Anton Scheffer
|
||||
|
||||
Permission is hereby granted, free of charge, to any person obtaining a copy
|
||||
of this software and associated documentation files (the "Software"), to deal
|
||||
in the Software without restriction, including without limitation the rights
|
||||
to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
|
||||
copies of the Software, and to permit persons to whom the Software is
|
||||
furnished to do so, subject to the following conditions:
|
||||
|
||||
The above copyright notice and this permission notice shall be included in
|
||||
all copies or substantial portions of the Software.
|
||||
|
||||
THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
|
||||
IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
|
||||
FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
|
||||
AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
|
||||
LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
|
||||
OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN
|
||||
THE SOFTWARE.
|
||||
|
||||
******************************************************************************
|
||||
******************************************** */
|
||||
--
|
||||
type tp_alignment is record
|
||||
@ -45,6 +82,7 @@ as
|
||||
, p_underline boolean := false
|
||||
, p_italic boolean := false
|
||||
, p_bold boolean := false
|
||||
, p_rgb varchar2 := null -- this is a hex ALPHA Red Green Blue value
|
||||
)
|
||||
return pls_integer;
|
||||
--
|
||||
@ -163,6 +201,45 @@ top
|
||||
, p_br_row pls_integer
|
||||
, p_sheet pls_integer := null
|
||||
);
|
||||
--
|
||||
procedure list_validation
|
||||
( p_sqref_col pls_integer
|
||||
, p_sqref_row pls_integer
|
||||
, p_tl_col pls_integer -- top left
|
||||
, p_tl_row pls_integer
|
||||
, p_br_col pls_integer -- bottom right
|
||||
, p_br_row pls_integer
|
||||
, p_style varchar2 := 'stop' -- stop, warning, information
|
||||
, p_title varchar2 := null
|
||||
, p_prompt varchar := null
|
||||
, p_show_error boolean := false
|
||||
, p_error_title varchar2 := null
|
||||
, p_error_txt varchar2 := null
|
||||
, p_sheet pls_integer := null
|
||||
);
|
||||
--
|
||||
procedure list_validation
|
||||
( p_sqref_col pls_integer
|
||||
, p_sqref_row pls_integer
|
||||
, p_defined_name varchar2
|
||||
, p_style varchar2 := 'stop' -- stop, warning, information
|
||||
, p_title varchar2 := null
|
||||
, p_prompt varchar := null
|
||||
, p_show_error boolean := false
|
||||
, p_error_title varchar2 := null
|
||||
, p_error_txt varchar2 := null
|
||||
, p_sheet pls_integer := null
|
||||
);
|
||||
--
|
||||
procedure defined_name
|
||||
( p_tl_col pls_integer -- top left
|
||||
, p_tl_row pls_integer
|
||||
, p_br_col pls_integer -- bottom right
|
||||
, p_br_row pls_integer
|
||||
, p_name varchar2
|
||||
, p_sheet pls_integer := null
|
||||
, p_localsheet pls_integer := null
|
||||
);
|
||||
--
|
||||
procedure set_column_width
|
||||
( p_col pls_integer
|
||||
@ -199,6 +276,12 @@ top
|
||||
( p_nr_cols pls_integer := 1
|
||||
, p_sheet pls_integer := null
|
||||
);
|
||||
--
|
||||
procedure freeze_pane
|
||||
( p_col pls_integer
|
||||
, p_row pls_integer
|
||||
, p_sheet pls_integer := null
|
||||
);
|
||||
--
|
||||
procedure set_autofilter
|
||||
( p_column_start pls_integer := null
|
||||
@ -223,8 +306,5 @@ top
|
||||
, p_filename varchar2 := null
|
||||
, p_sheet pls_integer := null
|
||||
);
|
||||
--
|
||||
|
||||
end xlsx_builder_pkg;
|
||||
end;
|
||||
/
|
||||
|
||||
|
||||
@ -4,3 +4,5 @@
|
||||
-- required for NTLM utilities
|
||||
grant execute on dbms_crypto to &&your_schema;
|
||||
|
||||
-- Required for XLSX_BUILDER_PKG
|
||||
grant execute on sys.utl_file to &&your_schema;
|
||||
|
||||
@ -34,6 +34,7 @@ prompt Creating package specifications
|
||||
@../ora/ntlm_http_pkg.pks
|
||||
@../ora/ooxml_util_pkg.pks
|
||||
@../ora/owa_util_pkg.pks
|
||||
@../ora/paypal_util_pkg.pks
|
||||
@../ora/pdf_builder_pkg.pks
|
||||
@../ora/random_util_pkg.pks
|
||||
@../ora/raw_util_pkg.pks
|
||||
@ -85,6 +86,7 @@ prompt Creating package bodies
|
||||
@../ora/ntlm_http_pkg.pkb
|
||||
@../ora/ooxml_util_pkg.pkb
|
||||
@../ora/owa_util_pkg.pkb
|
||||
@../ora/paypal_util_pkg.pkb
|
||||
@../ora/pdf_builder_pkg.pkb
|
||||
@../ora/random_util_pkg.pkb
|
||||
@../ora/raw_util_pkg.pkb
|
||||
|
||||
15
setup/install_paypal.sql
Executable file
15
setup/install_paypal.sql
Executable file
@ -0,0 +1,15 @@
|
||||
|
||||
set scan off;
|
||||
|
||||
|
||||
prompt Creating PAYPAL package specifications
|
||||
|
||||
@../ora/paypal_util_pkg.pks
|
||||
|
||||
prompt Creating PAYPAL package bodies
|
||||
|
||||
@../ora/paypal_util_pkg.pkb
|
||||
|
||||
|
||||
prompt Done!
|
||||
|
||||
Loading…
x
Reference in New Issue
Block a user