Initial commit, based on v1.7.0
This commit is contained in:
commit
e04a305aa7
118
demos/01_create_demo_tables.sql
Executable file
118
demos/01_create_demo_tables.sql
Executable file
@ -0,0 +1,118 @@
|
||||
--
|
||||
-- Copyright (c) Oracle Corporation 1999. All Rights Reserved.
|
||||
--
|
||||
-- NAME
|
||||
-- demobld.sql
|
||||
--
|
||||
-- DESCRIPTION
|
||||
-- This script creates the SQL*Plus demonstration tables in the
|
||||
-- current schema. It should be STARTed by each user wishing to
|
||||
-- access the tables. To remove the tables use the demodrop.sql
|
||||
-- script.
|
||||
--
|
||||
-- USAGE
|
||||
-- SQL> START demobld.sql
|
||||
--
|
||||
--
|
||||
|
||||
SET TERMOUT ON
|
||||
PROMPT Building demonstration tables. Please wait.
|
||||
SET TERMOUT OFF
|
||||
|
||||
DROP TABLE EMP;
|
||||
DROP TABLE DEPT;
|
||||
DROP TABLE BONUS;
|
||||
DROP TABLE SALGRADE;
|
||||
DROP TABLE DUMMY;
|
||||
|
||||
CREATE TABLE EMP
|
||||
(EMPNO NUMBER(4) NOT NULL,
|
||||
ENAME VARCHAR2(10),
|
||||
JOB VARCHAR2(9),
|
||||
MGR NUMBER(4),
|
||||
HIREDATE DATE,
|
||||
SAL NUMBER(7, 2),
|
||||
COMM NUMBER(7, 2),
|
||||
DEPTNO NUMBER(2));
|
||||
|
||||
INSERT INTO EMP VALUES
|
||||
(7369, 'SMITH', 'CLERK', 7902,
|
||||
TO_DATE('17-12-1980', 'DD-MM-YYYY'), 800, NULL, 20);
|
||||
INSERT INTO EMP VALUES
|
||||
(7499, 'ALLEN', 'SALESMAN', 7698,
|
||||
TO_DATE('20-02-1981', 'DD-MM-YYYY'), 1600, 300, 30);
|
||||
INSERT INTO EMP VALUES
|
||||
(7521, 'WARD', 'SALESMAN', 7698,
|
||||
TO_DATE('22-02-1981', 'DD-MM-YYYY'), 1250, 500, 30);
|
||||
INSERT INTO EMP VALUES
|
||||
(7566, 'JONES', 'MANAGER', 7839,
|
||||
TO_DATE('2-04-1981', 'DD-MM-YYYY'), 2975, NULL, 20);
|
||||
INSERT INTO EMP VALUES
|
||||
(7654, 'MARTIN', 'SALESMAN', 7698,
|
||||
TO_DATE('28-09-1981', 'DD-MM-YYYY'), 1250, 1400, 30);
|
||||
INSERT INTO EMP VALUES
|
||||
(7698, 'BLAKE', 'MANAGER', 7839,
|
||||
TO_DATE('1-05-1981', 'DD-MM-YYYY'), 2850, NULL, 30);
|
||||
INSERT INTO EMP VALUES
|
||||
(7782, 'CLARK', 'MANAGER', 7839,
|
||||
TO_DATE('9-06-1981', 'DD-MM-YYYY'), 2450, NULL, 10);
|
||||
INSERT INTO EMP VALUES
|
||||
(7788, 'SCOTT', 'ANALYST', 7566,
|
||||
TO_DATE('09-12-1982', 'DD-MM-YYYY'), 3000, NULL, 20);
|
||||
INSERT INTO EMP VALUES
|
||||
(7839, 'KING', 'PRESIDENT', NULL,
|
||||
TO_DATE('17-11-1981', 'DD-MM-YYYY'), 5000, NULL, 10);
|
||||
INSERT INTO EMP VALUES
|
||||
(7844, 'TURNER', 'SALESMAN', 7698,
|
||||
TO_DATE('8-09-1981', 'DD-MM-YYYY'), 1500, 0, 30);
|
||||
INSERT INTO EMP VALUES
|
||||
(7876, 'ADAMS', 'CLERK', 7788,
|
||||
TO_DATE('12-01-1983', 'DD-MM-YYYY'), 1100, NULL, 20);
|
||||
INSERT INTO EMP VALUES
|
||||
(7900, 'JAMES', 'CLERK', 7698,
|
||||
TO_DATE('3-12-1981', 'DD-MM-YYYY'), 950, NULL, 30);
|
||||
INSERT INTO EMP VALUES
|
||||
(7902, 'FORD', 'ANALYST', 7566,
|
||||
TO_DATE('3-12-1981', 'DD-MM-YYYY'), 3000, NULL, 20);
|
||||
INSERT INTO EMP VALUES
|
||||
(7934, 'MILLER', 'CLERK', 7782,
|
||||
TO_DATE('23-01-1982', 'DD-MM-YYYY'), 1300, NULL, 10);
|
||||
|
||||
CREATE TABLE DEPT
|
||||
(DEPTNO NUMBER(2),
|
||||
DNAME VARCHAR2(14),
|
||||
LOC VARCHAR2(13) );
|
||||
|
||||
INSERT INTO DEPT VALUES (10, 'ACCOUNTING', 'NEW YORK');
|
||||
INSERT INTO DEPT VALUES (20, 'RESEARCH', 'DALLAS');
|
||||
INSERT INTO DEPT VALUES (30, 'SALES', 'CHICAGO');
|
||||
INSERT INTO DEPT VALUES (40, 'OPERATIONS', 'BOSTON');
|
||||
|
||||
CREATE TABLE BONUS
|
||||
(ENAME VARCHAR2(10),
|
||||
JOB VARCHAR2(9),
|
||||
SAL NUMBER,
|
||||
COMM NUMBER);
|
||||
|
||||
CREATE TABLE SALGRADE
|
||||
(GRADE NUMBER,
|
||||
LOSAL NUMBER,
|
||||
HISAL NUMBER);
|
||||
|
||||
INSERT INTO SALGRADE VALUES (1, 700, 1200);
|
||||
INSERT INTO SALGRADE VALUES (2, 1201, 1400);
|
||||
INSERT INTO SALGRADE VALUES (3, 1401, 2000);
|
||||
INSERT INTO SALGRADE VALUES (4, 2001, 3000);
|
||||
INSERT INTO SALGRADE VALUES (5, 3001, 9999);
|
||||
|
||||
CREATE TABLE DUMMY
|
||||
(DUMMY NUMBER);
|
||||
|
||||
INSERT INTO DUMMY VALUES (0);
|
||||
|
||||
COMMIT;
|
||||
|
||||
SET TERMOUT ON
|
||||
PROMPT Demonstration table build is complete.
|
||||
|
||||
EXIT
|
||||
6
demos/02_create_temp_directory.sql
Executable file
6
demos/02_create_temp_directory.sql
Executable file
@ -0,0 +1,6 @@
|
||||
|
||||
-- required for demos that read/write files on disk
|
||||
|
||||
CREATE DIRECTORY devtest_temp_dir AS 'c:\temp\devtest';
|
||||
|
||||
|
||||
197
demos/amazon_aws_s3_pkg_demo.sql
Executable file
197
demos/amazon_aws_s3_pkg_demo.sql
Executable file
@ -0,0 +1,197 @@
|
||||
-- NOTE: all the following examples assume that the authentication package
|
||||
-- has been initialized by running the following code:
|
||||
|
||||
begin
|
||||
amazon_aws_auth_pkg.init ('my_aws_id', 'my_aws_key', p_gmt_offset => -1);
|
||||
end;
|
||||
|
||||
-- create new bucket (default region)
|
||||
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
amazon_aws_s3_pkg.new_bucket('my-bucket-name');
|
||||
end;
|
||||
|
||||
|
||||
-- create new bucket (in specific region)
|
||||
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
amazon_aws_s3_pkg.new_bucket('my-bucket-name', amazon_aws_s3_pkg.g_region_eu);
|
||||
end;
|
||||
|
||||
|
||||
-- get list of buckets
|
||||
|
||||
declare
|
||||
l_list amazon_aws_s3_pkg.t_bucket_list;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_list := amazon_aws_s3_pkg.get_bucket_list;
|
||||
if l_list.count > 0 then
|
||||
for i in 1..l_list.count loop
|
||||
debug_pkg.printf('list(%1) = %2, creation date = %3', i, l_list(i).bucket_name, l_list(i).creation_date);
|
||||
end loop;
|
||||
end if;
|
||||
end;
|
||||
|
||||
-- get list of buckets via SQL
|
||||
|
||||
select *
|
||||
from table(amazon_aws_s3_pkg.get_bucket_tab()) t
|
||||
order by 1
|
||||
|
||||
|
||||
-- get list of objects
|
||||
|
||||
declare
|
||||
l_list amazon_aws_s3_pkg.t_object_list;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_list := amazon_aws_s3_pkg.get_object_list ('my-bucket-name');
|
||||
if l_list.count > 0 then
|
||||
for i in 1..l_list.count loop
|
||||
debug_pkg.printf('list(%1) = %2, last modified = %3', i, l_list(i).key, l_list(i).last_modified);
|
||||
end loop;
|
||||
end if;
|
||||
end;
|
||||
|
||||
-- get list of objects via SQL
|
||||
|
||||
select *
|
||||
from table(amazon_aws_s3_pkg.get_object_tab('my-bucket-name')) t
|
||||
order by 2 desc
|
||||
|
||||
-- with some filtering, and restricting number of keys returned
|
||||
|
||||
select *
|
||||
from table(amazon_aws_s3_pkg.get_object_tab('my-bucket-name', 'my', 4)) t
|
||||
order by 2 desc
|
||||
|
||||
|
||||
-- get download link (with expiry date)
|
||||
|
||||
select amazon_aws_s3_pkg.get_download_url('my-bucket-name', 'my_pdf.pdf', sysdate +1)
|
||||
from dual
|
||||
|
||||
-- download file (and save to disk)
|
||||
|
||||
declare
|
||||
l_url varchar2(2000);
|
||||
l_blob blob;
|
||||
begin
|
||||
l_url := amazon_aws_s3_pkg.get_download_url ('my-bucket-name', 'my-uploaded-pdf.pdf', sysdate + 1);
|
||||
l_blob := http_util_pkg.get_blob_from_url (l_url);
|
||||
file_util_pkg.save_blob_to_file ('DEVTEST_TEMP_DIR', 'my_pdf_downloaded_from_s3_' || to_char(sysdate, 'yyyyhh24miss') || '.pdf', l_blob);
|
||||
end;
|
||||
|
||||
|
||||
-- download file (and save to disk) -- shorter version
|
||||
|
||||
declare
|
||||
l_blob blob;
|
||||
begin
|
||||
l_blob := amazon_aws_s3_pkg.get_object ('my-bucket-name', 'my-uploaded-pdf.pdf');
|
||||
file_util_pkg.save_blob_to_file ('DEVTEST_TEMP_DIR', 'my_pdf_downloaded_from_s3_' || to_char(sysdate, 'yyyyhh24miss') || '.pdf', l_blob);
|
||||
end;
|
||||
|
||||
|
||||
-- upload new object (retrieved from URL)
|
||||
|
||||
declare
|
||||
l_blob blob;
|
||||
begin
|
||||
l_blob := http_util_pkg.get_blob_from_url ('http://docs.amazonwebservices.com/AmazonS3/latest/API/images/title-swoosh-logo.gif');
|
||||
amazon_aws_s3_pkg.new_object ('my-bucket-name', 'my-uploaded-image3.gif', l_blob, 'image/gif');
|
||||
end;
|
||||
|
||||
|
||||
-- upload file into a folder-like structure
|
||||
-- note: there is no concept of folders in S3, but you can use slash in key names, which some clients present as folders
|
||||
-- see http://stackoverflow.com/questions/1939743/amazon-s3-boto-how-to-create-folder
|
||||
|
||||
declare
|
||||
l_blob blob;
|
||||
begin
|
||||
l_blob := http_util_pkg.get_blob_from_url ('http://docs.amazonwebservices.com/AmazonS3/latest/API/images/title-swoosh-logo.gif');
|
||||
amazon_aws_s3_pkg.new_object ('my-bucket-name', 'my-new-folder/some-subfolder/the-amazon-logo.gif', l_blob, 'image/gif');
|
||||
end;
|
||||
|
||||
-- upload object and set ACL
|
||||
|
||||
declare
|
||||
l_blob blob;
|
||||
begin
|
||||
l_blob := http_util_pkg.get_blob_from_url ('http://docs.amazonwebservices.com/AmazonS3/latest/API/images/title-swoosh-logo.gif');
|
||||
amazon_aws_s3_pkg.new_object ('my-bucket-name', 'my-new-folder/some-subfolder/the-amazon-logo3.gif', l_blob, 'image/gif', amazon_aws_s3_pkg.g_acl_public_read);
|
||||
end;
|
||||
|
||||
-- upload new object from file
|
||||
|
||||
declare
|
||||
l_blob blob;
|
||||
begin
|
||||
l_blob := file_util_pkg.get_blob_from_file ('DEVTEST_TEMP_DIR', 'my_pdf.pdf');
|
||||
amazon_aws_s3_pkg.new_object ('my-bucket-name', 'my-uploaded-pdf2.pdf', l_blob, 'application/pdf');
|
||||
end;
|
||||
|
||||
|
||||
-- get file from disk, zip it, and upload it
|
||||
|
||||
|
||||
declare
|
||||
l_blob blob;
|
||||
l_zip blob;
|
||||
begin
|
||||
l_blob := file_util_pkg.get_blob_from_file ('DEVTEST_TEMP_DIR', 'GeoIPCountryWhois2.csv');
|
||||
zip_util_pkg.add_file (l_zip, 'my-csv-inside-a-zip.csv', l_blob);
|
||||
zip_util_pkg.finish_zip (l_zip);
|
||||
amazon_aws_s3_pkg.new_object ('my-bucket-name', 'my-compressed-file.zip', l_zip, 'application/zip');
|
||||
end;
|
||||
|
||||
|
||||
-- delete object
|
||||
|
||||
begin
|
||||
amazon_aws_s3_pkg.delete_object ('my-bucket-name', 'my-uploaded-pdf2.pdf');
|
||||
end;
|
||||
|
||||
|
||||
-- delete bucket
|
||||
|
||||
begin
|
||||
amazon_aws_s3_pkg.delete_bucket ('my-bucket-name');
|
||||
end;
|
||||
|
||||
-- set object ACL
|
||||
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
amazon_aws_s3_pkg.set_object_acl ('my-bucket-name', 'my-uploaded-pdf2.pdf', amazon_aws_s3_pkg.g_acl_public_read);
|
||||
end;
|
||||
|
||||
|
||||
-- get object owner
|
||||
|
||||
declare
|
||||
l_owner amazon_aws_s3_pkg.t_owner;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_owner := amazon_aws_s3_pkg.get_object_owner ('my-bucket-name', 'my-uploaded-pdf2.pdf');
|
||||
debug_pkg.printf('owner name = %1, owner id = %2', l_owner.user_name, l_owner.user_id);
|
||||
end;
|
||||
|
||||
-- get object grantee list
|
||||
|
||||
declare
|
||||
l_list amazon_aws_s3_pkg.t_grantee_list;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_list := amazon_aws_s3_pkg.get_object_grantee_list ('my-bucket-name', 'my-uploaded-pdf2.pdf');
|
||||
if l_list.count > 0 then
|
||||
for i in 1..l_list.count loop
|
||||
debug_pkg.printf('%1 - grantee type = %2, user id = %3, user name = %4, group = %5, permission = %6', i, l_list(i).grantee_type, l_list(i).user_id, l_list(i).user_name, l_list(i).group_uri, l_list(i).permission);
|
||||
end loop;
|
||||
end if;
|
||||
end;
|
||||
|
||||
23
demos/crypto_util_pkg_demo.sql
Executable file
23
demos/crypto_util_pkg_demo.sql
Executable file
@ -0,0 +1,23 @@
|
||||
-- read file from disk, encrypt it, and save it
|
||||
-- note that the key must be exactly 32 characters (bytes) long
|
||||
|
||||
declare
|
||||
l_blob blob;
|
||||
l_enc blob;
|
||||
begin
|
||||
l_blob := file_util_pkg.get_blob_from_file ('DEVTEST_TEMP_DIR', 'my_pdf.pdf');
|
||||
l_enc := crypto_util_pkg.encrypt_aes256 (l_blob, '12345678901234567890123456789012');
|
||||
file_util_pkg.save_blob_to_file('DEVTEST_TEMP_DIR', 'my_encrypted_pdf.xxx', l_enc);
|
||||
end;
|
||||
|
||||
-- read encrypted file from disk, decrypt it, and save it
|
||||
-- note that the key must be exactly 32 characters (bytes) long
|
||||
|
||||
declare
|
||||
l_blob blob;
|
||||
l_enc blob;
|
||||
begin
|
||||
l_blob := file_util_pkg.get_blob_from_file ('DEVTEST_TEMP_DIR', 'my_encrypted_pdf.xxx');
|
||||
l_enc := crypto_util_pkg.decrypt_aes256 (l_blob, '12345678901234567890123456789012');
|
||||
file_util_pkg.save_blob_to_file('DEVTEST_TEMP_DIR', 'my_decrypted_pdf.pdf', l_enc);
|
||||
end;
|
||||
104
demos/csv_util_pkg_demo.sql
Executable file
104
demos/csv_util_pkg_demo.sql
Executable file
@ -0,0 +1,104 @@
|
||||
-- retrieve a download a CSV file as a clob directly from the web and return it as a table with a single statement:
|
||||
|
||||
select *
|
||||
from table(csv_util_pkg.clob_to_csv(httpuritype('http://www.foo.example/bar.csv').getclob()))
|
||||
|
||||
-- do a direct insert via INSERT .. SELECT
|
||||
|
||||
insert into my_table (first_column, second_column)
|
||||
select c001, c002
|
||||
from table(csv_util_pkg.clob_to_csv(httpuritype('http://www.foo.example/bar.csv').getclob()))
|
||||
|
||||
|
||||
-- use SQL to filter the results (although this may affect performance)
|
||||
|
||||
select *
|
||||
from table(csv_util_pkg.clob_to_csv(httpuritype('http://www.foo.example/bar.csv').getclob()))
|
||||
where c002 = 'Chevy'
|
||||
|
||||
|
||||
-- do it in a more procedural fashion
|
||||
|
||||
create table x_dump
|
||||
(clob_value clob,
|
||||
dump_date date default sysdate,
|
||||
dump_id number);
|
||||
|
||||
|
||||
declare
|
||||
l_clob clob;
|
||||
|
||||
cursor l_cursor
|
||||
is
|
||||
select csv.*
|
||||
from x_dump d, table(csv_util_pkg.clob_to_csv(d.clob_value)) csv
|
||||
where d.dump_id = 1;
|
||||
|
||||
begin
|
||||
|
||||
l_clob := httpuritype('http://www.foo.example/bar.csv').getclob();
|
||||
insert into x_dump (clob_value, dump_id) values (l_clob, 1);
|
||||
commit;
|
||||
dbms_lob.freetemporary (l_clob);
|
||||
|
||||
for l_rec in l_cursor loop
|
||||
dbms_output.put_line ('row ' || l_rec.line_number || ', col 1 = ' || l_rec.c001);
|
||||
end loop;
|
||||
|
||||
end;
|
||||
|
||||
/*
|
||||
|
||||
There are a few additional functions in the package that are not necessary for normal usage,
|
||||
but may be useful if you are doing any sort of lower-level CSV parsing.
|
||||
|
||||
The csv_to_array function operates on a single CSV-encoded line
|
||||
(so to use this you would have to split the CSV lines yourself first,
|
||||
and feed them one by one to this function):
|
||||
|
||||
*/
|
||||
|
||||
declare
|
||||
l_array t_str_array;
|
||||
l_val varchar2(4000);
|
||||
begin
|
||||
|
||||
l_array := csv_util_pkg.csv_to_array ('10,SMITH,CLERK,"1200,50"');
|
||||
|
||||
for i in l_array.first .. l_array.last loop
|
||||
dbms_output.put_line('value ' || i || ' = ' || l_array(i));
|
||||
end loop;
|
||||
|
||||
-- should output SMITH
|
||||
l_val := csv_util_pkg.get_array_value(l_array, 2);
|
||||
dbms_output.put_line('value = ' || l_val);
|
||||
|
||||
-- should give an error message stating that there is no column called DEPTNO because the array does not contain seven elements
|
||||
-- leave the column name out to fail silently and return NULL instead of raising exception
|
||||
l_val := csv_util_pkg.get_array_value(l_array, 7, 'DEPTNO');
|
||||
dbms_output.put_line('value = ' || l_val);
|
||||
|
||||
end;
|
||||
|
||||
|
||||
-- You can also use this package to export CSV data, for example by using a query like this.
|
||||
|
||||
select csv_util_pkg.array_to_csv (t_str_array(company_id, company_name, company_type)) as the_csv_data
|
||||
from company
|
||||
order by company_name
|
||||
|
||||
/*
|
||||
|
||||
THE_CSV_DATA
|
||||
--------------------------------
|
||||
260,Acorn Oil & Gas,EXT
|
||||
261,Altinex,EXT
|
||||
262,Amerada Hess,EXT
|
||||
263,Atlantic Petroleum,EXT
|
||||
264,Beryl,EXT
|
||||
265,BG,EXT
|
||||
266,Bow Valley Energy,EXT
|
||||
267,BP,EXT
|
||||
|
||||
*/
|
||||
|
||||
183
demos/datapump_cloud_pkg.pkb
Executable file
183
demos/datapump_cloud_pkg.pkb
Executable file
@ -0,0 +1,183 @@
|
||||
create or replace package body datapump_cloud_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles backup to and restore from "the cloud" (Amazon S3)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 05.11.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
procedure send_mail (p_to in varchar2,
|
||||
p_subject in varchar2,
|
||||
p_body in varchar2)
|
||||
as
|
||||
l_host string_util_pkg.t_max_db_varchar2 := sys_context('userenv', 'server_host');
|
||||
l_instance string_util_pkg.t_max_db_varchar2 := sys_context('userenv', 'instance_name');
|
||||
l_body string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: send email
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 16.11.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
if p_to is not null then
|
||||
|
||||
l_body := p_body || chr(10) || chr(10) || 'Host: ' || l_host || chr(10) || 'Instance: ' || l_instance;
|
||||
|
||||
-- Apex security context (required for sending emails via Apex from background jobs)
|
||||
apex_util_pkg.set_apex_security_context (p_schema => user);
|
||||
|
||||
debug_pkg.printf('Sending email to %1 with subject "%2"', p_to, p_subject);
|
||||
|
||||
apex_mail.send (p_to => p_to, p_from => 'backup-agent@' || l_host, p_body => l_body, p_subj => p_subject);
|
||||
apex_mail.push_queue;
|
||||
|
||||
end if;
|
||||
|
||||
end send_mail;
|
||||
|
||||
|
||||
procedure add_progress (p_progress in out varchar2,
|
||||
p_message in varchar2)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: add message to progress string
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 06.11.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
p_progress := p_progress || chr(10) || to_char(sysdate, 'dd.mm.yyyy hh24:mi:ss') || ' : ' || p_message;
|
||||
|
||||
end add_progress;
|
||||
|
||||
|
||||
procedure backup_schema_to_s3 (p_aws_key in varchar2,
|
||||
p_aws_password in varchar2,
|
||||
p_aws_bucket in varchar2,
|
||||
p_aws_folder in varchar2,
|
||||
p_directory_name in varchar2,
|
||||
p_file_name in varchar2 := null,
|
||||
p_email_failure in varchar2 := null,
|
||||
p_email_success in varchar2 := null,
|
||||
p_encrypt in boolean := false,
|
||||
p_compress in boolean := false,
|
||||
p_version in varchar2 := null,
|
||||
p_gmt_offset in number := null)
|
||||
as
|
||||
l_start_date date := sysdate;
|
||||
l_progress string_util_pkg.t_max_pl_varchar2;
|
||||
l_error_code number;
|
||||
l_error_message string_util_pkg.t_max_pl_varchar2;
|
||||
l_error_backtrace string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: backup schema to Amazon S3
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 05.11.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
begin
|
||||
|
||||
add_progress (l_progress, 'Starting export...');
|
||||
datapump_util_pkg.export_schema_to_file (p_directory_name, p_file_name, p_version, null, p_compress);
|
||||
|
||||
add_progress (l_progress, 'Setting AWS authentication, GMT offset = ' || p_gmt_offset);
|
||||
amazon_aws_auth_pkg.init (p_aws_key, p_aws_password, p_gmt_offset);
|
||||
|
||||
add_progress (l_progress, 'Uploading remote file ' || p_aws_folder || '/' || p_file_name || '.dmp');
|
||||
amazon_aws_s3_pkg.new_object(p_aws_bucket, p_aws_folder || '/' || p_file_name || '.dmp', file_util_pkg.get_blob_from_file(p_directory_name, p_file_name || '.dmp'), 'application/octet-stream');
|
||||
add_progress (l_progress, 'Uploading remote file ' || p_aws_folder || '/' || p_file_name || '.log');
|
||||
amazon_aws_s3_pkg.new_object(p_aws_bucket, p_aws_folder || '/' || p_file_name || '.log', file_util_pkg.get_blob_from_file(p_directory_name, p_file_name || '.log'), 'text/plain');
|
||||
|
||||
-- delete the dump file, leave the log file
|
||||
add_progress (l_progress, 'Deleting local file ' || p_file_name || '.dmp');
|
||||
utl_file.fremove (p_directory_name, p_file_name || '.dmp');
|
||||
|
||||
add_progress (l_progress, 'SUCCESS! Time elapsed: ' || date_util_pkg.fmt_time(sysdate - l_start_date));
|
||||
|
||||
send_mail (p_email_success, 'Backup Success: ' || p_file_name, l_progress);
|
||||
|
||||
exception
|
||||
when others then
|
||||
l_error_code := sqlcode;
|
||||
l_error_message := sqlerrm;
|
||||
l_error_backtrace := dbms_utility.format_error_backtrace;
|
||||
add_progress (l_progress, 'ERROR: ' || l_error_message);
|
||||
add_progress (l_progress, 'Error Stack: ' || l_error_backtrace);
|
||||
send_mail (p_email_failure, 'BACKUP FAILURE: ' || p_file_name || ', ORA' || l_error_code, l_progress);
|
||||
end;
|
||||
|
||||
end backup_schema_to_s3;
|
||||
|
||||
|
||||
procedure restore_schema_from_s3 (p_aws_key in varchar2,
|
||||
p_aws_password in varchar2,
|
||||
p_aws_bucket in varchar2,
|
||||
p_aws_folder in varchar2,
|
||||
p_file_name in varchar2,
|
||||
p_directory_name in varchar2,
|
||||
p_decrypt in boolean := false,
|
||||
p_decompress in boolean := false,
|
||||
p_remap_to_schema in varchar2 := null,
|
||||
p_gmt_offset in number := null)
|
||||
as
|
||||
l_blob blob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: restore schema from Amazon S3
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 05.11.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
amazon_aws_auth_pkg.init (p_aws_key, p_aws_password, p_gmt_offset);
|
||||
|
||||
l_blob := amazon_aws_s3_pkg.get_object (p_aws_bucket, p_aws_folder || '/' || p_file_name || '.dmp');
|
||||
|
||||
file_util_pkg.save_blob_to_file (p_directory_name, p_file_name || '.dmp', l_blob);
|
||||
|
||||
datapump_util_pkg.import_schema_from_file (p_directory_name, p_file_name || '.dmp', p_file_name || '.log', p_remap_to_schema => p_remap_to_schema);
|
||||
|
||||
end restore_schema_from_s3;
|
||||
|
||||
end datapump_cloud_pkg;
|
||||
/
|
||||
|
||||
|
||||
|
||||
46
demos/datapump_cloud_pkg.pks
Executable file
46
demos/datapump_cloud_pkg.pks
Executable file
@ -0,0 +1,46 @@
|
||||
create or replace package datapump_cloud_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles backup to and restore from "the cloud" (Amazon S3)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 05.11.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
-- backup schema to Amazon S3
|
||||
procedure backup_schema_to_s3 (p_aws_key in varchar2,
|
||||
p_aws_password in varchar2,
|
||||
p_aws_bucket in varchar2,
|
||||
p_aws_folder in varchar2,
|
||||
p_directory_name in varchar2,
|
||||
p_file_name in varchar2 := null,
|
||||
p_email_failure in varchar2 := null,
|
||||
p_email_success in varchar2 := null,
|
||||
p_encrypt in boolean := false,
|
||||
p_compress in boolean := false,
|
||||
p_version in varchar2 := null,
|
||||
p_gmt_offset in number := null);
|
||||
|
||||
-- restore schema from Amazon S3
|
||||
procedure restore_schema_from_s3 (p_aws_key in varchar2,
|
||||
p_aws_password in varchar2,
|
||||
p_aws_bucket in varchar2,
|
||||
p_aws_folder in varchar2,
|
||||
p_file_name in varchar2,
|
||||
p_directory_name in varchar2,
|
||||
p_decrypt in boolean := false,
|
||||
p_decompress in boolean := false,
|
||||
p_remap_to_schema in varchar2 := null,
|
||||
p_gmt_offset in number := null);
|
||||
|
||||
|
||||
end datapump_cloud_pkg;
|
||||
/
|
||||
|
||||
27
demos/datapump_util_pkg_demo.sql
Executable file
27
demos/datapump_util_pkg_demo.sql
Executable file
@ -0,0 +1,27 @@
|
||||
|
||||
-- monitor jobs
|
||||
|
||||
select *
|
||||
from dba_datapump_jobs;
|
||||
|
||||
select *
|
||||
from dba_datapump_sessions;
|
||||
|
||||
|
||||
-- export current schema to file, use default file name, and make the export compatible with XE 10g
|
||||
-- include a custom message
|
||||
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
datapump_util_pkg.export_schema_to_file ('DEVTEST_TEMP_DIR', p_version => '10.2', p_log_message => 'it is possible to include custom messages in the log');
|
||||
end;
|
||||
/
|
||||
|
||||
-- import dump file to backup schema
|
||||
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
datapump_util_pkg.import_schema_from_file ('DEVTEST_TEMP_DIR', 'export_111105183000.dmp', p_remap_to_schema => 'DEVTEST_BACKUP');
|
||||
end;
|
||||
/
|
||||
|
||||
5
demos/date_util_pkg_demo.sql
Executable file
5
demos/date_util_pkg_demo.sql
Executable file
@ -0,0 +1,5 @@
|
||||
-- "explode" a specific year/month into one row for each day
|
||||
|
||||
select *
|
||||
from table(date_util_pkg.explode_month(2011, 2))
|
||||
|
||||
119
demos/employee_service.pkb
Executable file
119
demos/employee_service.pkb
Executable file
@ -0,0 +1,119 @@
|
||||
create or replace package body employee_service
|
||||
as
|
||||
|
||||
function get_employee_name (p_empno in number) return varchar2
|
||||
as
|
||||
l_returnvalue emp.ename%type;
|
||||
begin
|
||||
|
||||
begin
|
||||
select ename
|
||||
into l_returnvalue
|
||||
from emp
|
||||
where empno = p_empno;
|
||||
exception
|
||||
when no_data_found then
|
||||
l_returnvalue := null;
|
||||
end;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_employee_name;
|
||||
|
||||
|
||||
function get_employee (p_empno in number) return emp%rowtype
|
||||
as
|
||||
l_returnvalue emp%rowtype;
|
||||
begin
|
||||
|
||||
begin
|
||||
select *
|
||||
into l_returnvalue
|
||||
from emp
|
||||
where empno = p_empno;
|
||||
exception
|
||||
when no_data_found then
|
||||
l_returnvalue := null;
|
||||
end;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_employee;
|
||||
|
||||
|
||||
function get_employees (p_search_filter in varchar2) return clob
|
||||
as
|
||||
l_context dbms_xmlgen.ctxhandle;
|
||||
l_returnvalue clob;
|
||||
begin
|
||||
|
||||
-- there are many ways to generate XML in Oracle, this is one of them...
|
||||
|
||||
l_context := dbms_xmlgen.newcontext('select * from emp where lower(ename) like :p_filter_str order by empno');
|
||||
|
||||
-- let's make Tom Kyte happy :-)
|
||||
dbms_xmlgen.setbindvalue (l_context, 'p_filter_str', lower(p_search_filter) || '%');
|
||||
|
||||
l_returnvalue := dbms_xmlgen.getxml (l_context);
|
||||
|
||||
dbms_xmlgen.closecontext (l_context);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_employees;
|
||||
|
||||
|
||||
procedure some_procedure (p_param1 in varchar2)
|
||||
as
|
||||
begin
|
||||
-- just to show that procedures will not be exposed in the WSDL
|
||||
null;
|
||||
end some_procedure;
|
||||
|
||||
|
||||
function new_employee (p_ename in varchar2) return number
|
||||
as
|
||||
begin
|
||||
|
||||
-- this would normally insert into a table and return the new primary key value
|
||||
|
||||
return 666;
|
||||
|
||||
end new_employee;
|
||||
|
||||
|
||||
function get_employees_by_date (p_from_date in date,
|
||||
p_to_date in date) return clob
|
||||
as
|
||||
begin
|
||||
|
||||
-- show/test that functions can accept date parameters
|
||||
|
||||
return 'You searched for employees between ' || to_char(p_from_date, 'dd.mm.yyyy') || ' and ' || to_char(p_to_date, 'dd.mm.yyyy');
|
||||
|
||||
end get_employees_by_date;
|
||||
|
||||
|
||||
function no_input_parameters return varchar2
|
||||
as
|
||||
begin
|
||||
return 'Hello There';
|
||||
end no_input_parameters;
|
||||
|
||||
|
||||
function get_first_hire_date return date
|
||||
as
|
||||
l_returnvalue date;
|
||||
begin
|
||||
|
||||
select min(hiredate)
|
||||
into l_returnvalue
|
||||
from emp;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_first_hire_date;
|
||||
|
||||
end employee_service;
|
||||
/
|
||||
|
||||
26
demos/employee_service.pks
Executable file
26
demos/employee_service.pks
Executable file
@ -0,0 +1,26 @@
|
||||
create or replace package employee_service
|
||||
as
|
||||
|
||||
-- test package to showcase "PL/SQL SOAP Server" features (see soap_server_pkg)
|
||||
|
||||
function get_employee_name (p_empno in number) return varchar2;
|
||||
|
||||
function get_employee (p_empno in number) return emp%rowtype;
|
||||
|
||||
function get_employees (p_search_filter in varchar2) return clob;
|
||||
|
||||
procedure some_procedure (p_param1 in varchar2);
|
||||
|
||||
function new_employee (p_ename in varchar2) return number;
|
||||
|
||||
function get_employees_by_date (p_from_date in date,
|
||||
p_to_date in date) return clob;
|
||||
|
||||
function no_input_parameters return varchar2;
|
||||
|
||||
function get_first_hire_date return date;
|
||||
|
||||
end employee_service;
|
||||
/
|
||||
|
||||
|
||||
16
demos/file_util_pkg_demo.sql
Executable file
16
demos/file_util_pkg_demo.sql
Executable file
@ -0,0 +1,16 @@
|
||||
-- generate a clob and save it to file
|
||||
|
||||
declare
|
||||
l_clob clob;
|
||||
begin
|
||||
|
||||
l_clob := '<html><body>';
|
||||
for l_rec in (select * from emp) loop
|
||||
l_clob := l_clob || '<li>' || l_rec.ename || '</li>';
|
||||
end loop;
|
||||
l_clob := l_clob || '</body></html>';
|
||||
|
||||
file_util_pkg.save_clob_to_file ('DEVTEST_TEMP_DIR', 'my_generated_web_page.html', l_clob);
|
||||
|
||||
end;
|
||||
|
||||
6
demos/html_util_pkg.sql
Executable file
6
demos/html_util_pkg.sql
Executable file
@ -0,0 +1,6 @@
|
||||
|
||||
-- add clickable links to text with URLs in it
|
||||
|
||||
select html_util_pkg.add_hyperlinks('hey check out http://www.oracle.com and http://www.microsoft.com', 'my_link_css_class')
|
||||
from dual
|
||||
|
||||
10
demos/icalendar_util_pkg_demo.sql
Executable file
10
demos/icalendar_util_pkg_demo.sql
Executable file
@ -0,0 +1,10 @@
|
||||
-- get iCalendar event
|
||||
|
||||
declare
|
||||
l_event_str varchar2(32000);
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_event_str := icalendar_util_pkg.get_event (icalendar_util_pkg.create_event (p_start_date => sysdate, p_end_date => sysdate + 2, p_summary => 'PAARTY!!!'));
|
||||
debug_pkg.printf('l_event_str = %1', chr(10) || l_event_str);
|
||||
end;
|
||||
|
||||
28
demos/image_util_pkg_demo.sql
Executable file
28
demos/image_util_pkg_demo.sql
Executable file
@ -0,0 +1,28 @@
|
||||
-- check if given file is actually an image
|
||||
|
||||
declare
|
||||
l_is_image boolean;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_is_image := image_util_pkg.is_image (file_util_pkg.get_blob_from_file('DEVTEST_TEMP_DIR', 'some_image.jpg'));
|
||||
debug_pkg.print('result (should be true)', l_is_image);
|
||||
l_is_image := image_util_pkg.is_image (file_util_pkg.get_blob_from_file('DEVTEST_TEMP_DIR', 'some_text_file.txt'));
|
||||
debug_pkg.print('result (should be false)', l_is_image);
|
||||
l_is_image := image_util_pkg.is_image (file_util_pkg.get_blob_from_file('DEVTEST_TEMP_DIR', 'image74.png'), p_format => image_util_pkg.g_format_gif);
|
||||
debug_pkg.print('result (should be false)', l_is_image);
|
||||
end;
|
||||
|
||||
|
||||
-- get image info
|
||||
|
||||
declare
|
||||
l_info image_util_pkg.t_image_info;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_info := image_util_pkg.get_image_info (file_util_pkg.get_blob_from_file('DEVTEST_TEMP_DIR', 'some_image.jpg'));
|
||||
debug_pkg.printf('type = %1, height = %2, width = %3', l_info.type, l_info.height, l_info.width);
|
||||
end;
|
||||
|
||||
|
||||
|
||||
|
||||
230
demos/ms_ews_util_pkg_demo.sql
Executable file
230
demos/ms_ews_util_pkg_demo.sql
Executable file
@ -0,0 +1,230 @@
|
||||
|
||||
-- package must be initialized before use, at least once per session (in Apex, once per page view)
|
||||
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
ms_ews_util_pkg.init('https://thycompany.com/ews/Exchange.asmx', 'domain\user.name', 'your_password', 'file:c:\path\to\Oracle\wallet\folder\on\db\server', 'wallet_password');
|
||||
end;
|
||||
|
||||
|
||||
-- resolve names
|
||||
|
||||
declare
|
||||
l_names ms_ews_util_pkg.t_resolution_list;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_names := ms_ews_util_pkg.resolve_names_as_list('john');
|
||||
for i in 1 .. l_names.count loop
|
||||
debug_pkg.printf('name %1, name = %2, email = %3', i, l_names(i).mailbox.name, l_names(i).mailbox.email_address);
|
||||
end loop;
|
||||
end;
|
||||
|
||||
|
||||
-- resolve names (via SQL)
|
||||
|
||||
select *
|
||||
from table(ms_ews_util_pkg.resolve_names ('john'))
|
||||
|
||||
|
||||
-- expand distribution list
|
||||
|
||||
declare
|
||||
l_names ms_ews_util_pkg.t_dl_expansion_list;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_names := ms_ews_util_pkg.expand_public_dl_as_list('some_mailing_list@your.company');
|
||||
for i in 1 .. l_names.count loop
|
||||
debug_pkg.printf('name %1, name = %2, email = %3', i, l_names(i).name, l_names(i).email_address);
|
||||
end loop;
|
||||
end;
|
||||
|
||||
|
||||
-- get folder
|
||||
|
||||
declare
|
||||
l_folder ms_ews_util_pkg.t_folder;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_folder := ms_ews_util_pkg.get_folder (ms_ews_util_pkg.g_folder_id_inbox);
|
||||
debug_pkg.printf('folder id = %1, display name = %2', l_folder.folder_id, l_folder.display_name);
|
||||
debug_pkg.printf('total count = %1', l_folder.total_count);
|
||||
debug_pkg.printf('child folder count = %1', l_folder.child_folder_count);
|
||||
debug_pkg.printf('unread count = %1', l_folder.unread_count);
|
||||
end;
|
||||
|
||||
|
||||
-- find up to 3 items in specified folder
|
||||
|
||||
declare
|
||||
l_items ms_ews_util_pkg.t_item_list;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_items := ms_ews_util_pkg.find_items_as_list('inbox', p_max_rows => 3);
|
||||
for i in 1 .. l_items.count loop
|
||||
debug_pkg.printf('item %1, subject = %2', i, l_items(i).subject);
|
||||
end loop;
|
||||
end;
|
||||
|
||||
|
||||
-- get items in predefined folder
|
||||
|
||||
select *
|
||||
from table(ms_ews_util_pkg.find_folders('inbox'))
|
||||
|
||||
-- hide it behind a view...
|
||||
|
||||
create or replace view my_inbox_v
|
||||
as
|
||||
select datetime_received, subject, from_mailbox_name, is_read, has_attachments, item_id
|
||||
from table(ms_ews_util_pkg.find_items('inbox'));
|
||||
|
||||
-- get items in predefined folder, and search subject
|
||||
|
||||
select *
|
||||
from table(ms_ews_util_pkg.find_items('inbox', 'the search term'))
|
||||
|
||||
-- get items in user-defined folder
|
||||
|
||||
select *
|
||||
from table(ms_ews_util_pkg.find_items('the_folder_id'))
|
||||
|
||||
-- get items in user-defined folder, by name
|
||||
|
||||
select *
|
||||
from table(ms_ews_util_pkg.find_items(
|
||||
ms_ews_util_pkg.get_folder_id_by_name('Some Folder Name', 'inbox')
|
||||
)
|
||||
)
|
||||
|
||||
|
||||
|
||||
-- get item (email message)
|
||||
|
||||
declare
|
||||
l_item ms_ews_util_pkg.t_item;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_item := ms_ews_util_pkg.get_item ('the_item_id', p_include_mime_content => true);
|
||||
debug_pkg.printf('item %1, subject = %2', l_item.item_id, l_item.subject);
|
||||
debug_pkg.printf('body = %1', substr(l_item.body,1,2000));
|
||||
debug_pkg.printf('length of MIME content = %1', length(l_item.mime_content));
|
||||
end;
|
||||
|
||||
-- get item (calendar item)
|
||||
|
||||
declare
|
||||
l_item ms_ews_util_pkg.t_item;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_item := ms_ews_util_pkg.get_item ('the_item_id', p_body_type => 'Text', p_include_mime_content => true);
|
||||
debug_pkg.printf('item %1, class = %2, subject = %3', l_item.item_id, l_item.item_class, l_item.subject);
|
||||
debug_pkg.printf('body = %1', substr(l_item.body,1,2000));
|
||||
debug_pkg.printf('length of MIME content = %1', length(l_item.mime_content));
|
||||
debug_pkg.printf('start date = %1, location = %2, organizer = %3', l_item.start_date, l_item.location, l_item.organizer_mailbox_name);
|
||||
end;
|
||||
|
||||
|
||||
-- create calendar item
|
||||
|
||||
declare
|
||||
l_item ms_ews_util_pkg.t_item;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_item.subject := 'Appointment added via PL/SQL';
|
||||
l_item.body := 'Some text here...';
|
||||
l_item.start_date := sysdate + 1;
|
||||
l_item.end_date := sysdate + 2;
|
||||
l_item.item_id := ms_ews_util_pkg.create_calendar_item (l_item);
|
||||
debug_pkg.printf('created item with id = %1', l_item.item_id);
|
||||
end;
|
||||
|
||||
|
||||
-- create task item
|
||||
|
||||
declare
|
||||
l_item ms_ews_util_pkg.t_item;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_item.subject := 'Task added via PL/SQL';
|
||||
l_item.body := 'Some text here...';
|
||||
l_item.due_date := sysdate + 1;
|
||||
l_item.status := ms_ews_util_pkg.g_task_status_in_progress;
|
||||
l_item.item_id := ms_ews_util_pkg.create_task_item (l_item);
|
||||
debug_pkg.printf('created item with id = %1', l_item.item_id);
|
||||
end;
|
||||
|
||||
|
||||
-- create message item
|
||||
|
||||
declare
|
||||
l_item ms_ews_util_pkg.t_item;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_item.subject := 'Message added via PL/SQL';
|
||||
l_item.body := 'Some text here...';
|
||||
l_item.item_id := ms_ews_util_pkg.create_message_item (l_item, p_to_recipients => t_str_array('recipient1@some.company', 'recipient2@another.company'));
|
||||
debug_pkg.printf('created item with id = %1', l_item.item_id);
|
||||
end;
|
||||
|
||||
-- update item
|
||||
-- item id and change key can be retrieved with following query:
|
||||
-- select item_id, change_key, subject, is_read from table(ms_ews_util_pkg.find_items('inbox'))
|
||||
|
||||
declare
|
||||
l_item_id varchar2(2000) := 'the_item_id';
|
||||
l_change_key varchar2(2000) := 'the_change_key';
|
||||
begin
|
||||
ms_ews_util_pkg.update_item_is_read (l_item_id, l_change_key, p_is_read => true);
|
||||
end;
|
||||
|
||||
|
||||
-- get list of attachments
|
||||
|
||||
select *
|
||||
from table(ms_ews_util_pkg.get_file_attachments('the_item_id'))
|
||||
|
||||
-- download and save 1 attachment
|
||||
|
||||
declare
|
||||
l_attachment ms_ews_util_pkg.t_file_attachment;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_attachment := ms_ews_util_pkg.get_file_attachment ('the_attachment_id');
|
||||
file_util_pkg.save_blob_to_file('DEVTEST_TEMP_DIR', l_attachment.name, l_attachment.content);
|
||||
end;
|
||||
|
||||
|
||||
-- create attachment (attach file to existing item/email)
|
||||
|
||||
declare
|
||||
l_attachment ms_ews_util_pkg.t_file_attachment;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_attachment.item_id := 'the_item_id';
|
||||
l_attachment.name := 'Attachment added via PL/SQL';
|
||||
l_attachment.content := file_util_pkg.get_blob_from_file('DEVTEST_TEMP_DIR', 'some_file_such_as_a_nice_picture.jpg');
|
||||
l_attachment.attachment_id := ms_ews_util_pkg.create_file_attachment (l_attachment);
|
||||
debug_pkg.printf('created attachment with id = %1', l_attachment.attachment_id);
|
||||
end;
|
||||
|
||||
|
||||
|
||||
-- sqlplus demo
|
||||
|
||||
set pagesize 999
|
||||
column subject format a30
|
||||
column from_mailbox_name format a20
|
||||
column is_read format a20
|
||||
|
||||
exec ms_ews_util_pkg.init('...');
|
||||
|
||||
-- find items in specified folder with given search term, received between 6 to 3 months ago
|
||||
|
||||
select subject, from_mailbox_name, is_read
|
||||
from table(
|
||||
ms_ews_util_pkg.find_items(
|
||||
ms_ews_util_pkg.get_folder_id_by_name('Development', 'inbox'),
|
||||
'your search term',
|
||||
sysdate - 120, sysdate - 60
|
||||
)
|
||||
);
|
||||
44
demos/ntlm_http_pkg_demo.sql
Executable file
44
demos/ntlm_http_pkg_demo.sql
Executable file
@ -0,0 +1,44 @@
|
||||
-- simple request
|
||||
|
||||
declare
|
||||
l_clob clob;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_clob := ntlm_http_pkg.get_response_clob('http://servername/page', 'domain\username', 'password');
|
||||
debug_pkg.print(substr(l_clob, 1, 32000));
|
||||
end;
|
||||
|
||||
-- begin/end request with one or more calls in-between
|
||||
|
||||
declare
|
||||
l_url varchar2(2000) := 'http://servername/page';
|
||||
l_ntlm_auth_str varchar2(2000);
|
||||
l_xml xmltype;
|
||||
l_soap_env clob := 'your_soap_envelope_here';
|
||||
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
|
||||
-- perform the initial request to set up a persistent, authenticated connection
|
||||
l_ntlm_auth_str := ntlm_http_pkg.begin_request (l_url, 'domain\username', 'password');
|
||||
|
||||
-- pass authorization header to next call(s)
|
||||
apex_web_service.g_request_headers(1).name := 'Authorization';
|
||||
apex_web_service.g_request_headers(1).value := l_ntlm_auth_str;
|
||||
|
||||
-- perform the actual call
|
||||
-- NOTE: for this to work, you must be using a version of apex_web_service that does allows persistent connections (fixed in Apex 4.1 ???)
|
||||
-- see http://jastraub.blogspot.com/2008/06/flexible-web-service-api.html?showComment=1310198286769#c8685039598916415836
|
||||
l_xml := apex_web_service.make_request(l_url, 'soap_action_name_here', '1.1', l_soap_env);
|
||||
|
||||
-- or use the latest version of flex_ws_api
|
||||
-- flex_ws_api.g_request_headers(1).name := 'Authorization';
|
||||
-- flex_ws_api.g_request_headers(1).value := l_ntlm_auth_str;
|
||||
-- l_xml := flex_ws_api.make_request(l_url, 'soap_action_name_here', '1.1', l_soap_env);
|
||||
|
||||
-- this will close the persistent connection
|
||||
ntlm_http_pkg.end_request;
|
||||
|
||||
debug_pkg.print('XML response from webservice', l_xml);
|
||||
end;
|
||||
|
||||
122
demos/ooxml_util_pkg_demo.sql
Executable file
122
demos/ooxml_util_pkg_demo.sql
Executable file
@ -0,0 +1,122 @@
|
||||
-- get document properties from Word file
|
||||
|
||||
declare
|
||||
l_blob blob;
|
||||
l_props ooxml_util_pkg.t_docx_properties;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_blob := file_util_pkg.get_blob_from_file ('DEVTEST_TEMP_DIR', 'my_word_doc.docx');
|
||||
l_props := ooxml_util_pkg.get_docx_properties (l_blob);
|
||||
debug_pkg.printf('title = %1, modified = %2, creator = %3, pages = %4', l_props.core.title, l_props.core.modified_date, l_props.core.creator, l_props.app.pages);
|
||||
end;
|
||||
|
||||
|
||||
-- extract plain text from Word 2007 (docx) file
|
||||
|
||||
declare
|
||||
l_blob blob;
|
||||
l_clob clob;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_blob := file_util_pkg.get_blob_from_file ('DEVTEST_TEMP_DIR', 'my_word_doc.docx');
|
||||
l_clob := ooxml_util_pkg.get_docx_plaintext (l_blob);
|
||||
debug_pkg.printf(substr(l_clob, 1, 32000));
|
||||
end;
|
||||
|
||||
-- load a template (a normal document containing #TAGS#)
|
||||
-- in this case a Powerpoint file, but works for any ooxml file (Word, Excel, Powerpoint)
|
||||
-- replace the tags with actual values, and save the result as a new file
|
||||
|
||||
declare
|
||||
l_template blob;
|
||||
l_new_file blob;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_template := file_util_pkg.get_blob_from_file ('DEVTEST_TEMP_DIR', 'powerpoint_2007_template_3.pptx');
|
||||
l_new_file := ooxml_util_pkg.get_file_from_template (l_template, t_str_array('#PRODUCT_NAME#', '#PRODUCT_VERSION#', '#CUSTOMER#'), t_str_array('FooBar', 'v2', 'MyCompany'));
|
||||
file_util_pkg.save_blob_to_file ('DEVTEST_TEMP_DIR', 'powerpoint_2007_template_3_copy.pptx', l_new_file);
|
||||
end;
|
||||
|
||||
|
||||
|
||||
-- get document properties from Excel file
|
||||
|
||||
declare
|
||||
l_blob blob;
|
||||
l_props ooxml_util_pkg.t_xlsx_properties;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_blob := file_util_pkg.get_blob_from_file ('DEVTEST_TEMP_DIR', 'test_spreadsheet.xlsx');
|
||||
l_props := ooxml_util_pkg.get_xlsx_properties (l_blob);
|
||||
debug_pkg.printf('title = %1, modified = %2, creator = %3, application = %4', l_props.core.title, l_props.core.modified_date, l_props.core.creator, l_props.app.application);
|
||||
end;
|
||||
|
||||
|
||||
-- get single value from Excel worksheet
|
||||
|
||||
declare
|
||||
l_blob blob;
|
||||
l_value varchar2(255);
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_blob := file_util_pkg.get_blob_from_file ('DEVTEST_TEMP_DIR', 'test_spreadsheet.xlsx');
|
||||
l_value := ooxml_util_pkg.get_xlsx_cell_value (l_blob, 'Sheet1', 'C2');
|
||||
debug_pkg.printf('value = %1', l_value);
|
||||
end;
|
||||
|
||||
|
||||
-- get multiple values from Excel worksheet
|
||||
|
||||
declare
|
||||
l_blob blob;
|
||||
l_names t_str_array := t_str_array('B2', 'C2', 'C3', 'C4', 'A1');
|
||||
l_values t_str_array;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_blob := file_util_pkg.get_blob_from_file ('DEVTEST_TEMP_DIR', 'test_spreadsheet.xlsx');
|
||||
l_values := ooxml_util_pkg.get_xlsx_cell_values (l_blob, 'Sheet1', l_names);
|
||||
for i in 1 .. l_values.count loop
|
||||
debug_pkg.printf('count = %1, name = %2, value = %3', i, l_names(i), l_values(i));
|
||||
end loop;
|
||||
end;
|
||||
|
||||
|
||||
-- get document properties from Powerpoint file
|
||||
|
||||
declare
|
||||
l_blob blob;
|
||||
l_props ooxml_util_pkg.t_pptx_properties;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_blob := file_util_pkg.get_blob_from_file ('DEVTEST_TEMP_DIR', 'powerpoint_2007_template.pptx');
|
||||
l_props := ooxml_util_pkg.get_pptx_properties (l_blob);
|
||||
debug_pkg.printf('title = %1, modified = %2, creator = %3, slides = %4, template = %5', l_props.core.title, l_props.core.modified_date, l_props.core.creator, l_props.app.slides, l_props.app.template);
|
||||
end;
|
||||
|
||||
|
||||
-- list media files in Powerpoint file
|
||||
|
||||
declare
|
||||
l_blob blob;
|
||||
l_list t_str_array;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_blob := file_util_pkg.get_blob_from_file ('DEVTEST_TEMP_DIR', 'powerpoint_2007_template.pptx');
|
||||
l_list := ooxml_util_pkg.get_pptx_media_list (l_blob);
|
||||
for i in 1 .. l_list.count loop
|
||||
debug_pkg.printf('file %1 = %2', i, l_list(i));
|
||||
end loop;
|
||||
end;
|
||||
|
||||
|
||||
-- extract plain text from Powerpoint 2007 (pptx) slide
|
||||
|
||||
declare
|
||||
l_blob blob;
|
||||
l_clob clob;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_blob := file_util_pkg.get_blob_from_file ('DEVTEST_TEMP_DIR', 'powerpoint_2007_template.pptx');
|
||||
l_clob := ooxml_util_pkg.get_pptx_plaintext (l_blob, p_slide => 2);
|
||||
debug_pkg.printf(substr(l_clob, 1, 32000));
|
||||
end;
|
||||
43
demos/owa_util_pkg_demo.sql
Executable file
43
demos/owa_util_pkg_demo.sql
Executable file
@ -0,0 +1,43 @@
|
||||
-- grab the contents of a page generated by the PL/SQL Web Toolkit (without invoking it through a web server/gateway)
|
||||
|
||||
declare
|
||||
l_clob clob;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
owa_util_pkg.init_owa;
|
||||
|
||||
-- call any procedure that outputs something via htp.p
|
||||
--apex; -- the standalone "apex" procedure is a shortcut to the apex login page
|
||||
f(p => '4550:1'); -- note that since we are not logged in, this will simply return a Location header that tells the browser to redirect to a login page
|
||||
|
||||
l_clob := owa_util_pkg.get_page;
|
||||
debug_pkg.print(l_clob);
|
||||
file_util_pkg.save_clob_to_file ('DEVTEST_TEMP_DIR', 'my_web_page_generated_by_owa.htm', l_clob);
|
||||
end;
|
||||
|
||||
|
||||
-- use the (undocumented) APEX_UTIL.EXPORT_APPLICATION procedure to generate an export file
|
||||
-- then grab the output and save it to file
|
||||
|
||||
declare
|
||||
l_workspace_id number;
|
||||
l_app_id number;
|
||||
l_clob clob;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
|
||||
select workspace_id, application_id
|
||||
into l_workspace_id, l_app_id
|
||||
from apex_applications
|
||||
where workspace = 'DEVTEST'
|
||||
and application_name = 'AlexandriaLibraryTestApp';
|
||||
|
||||
owa_util_pkg.init_owa;
|
||||
apex_util.export_application (p_workspace_id => l_workspace_id, p_application_id => l_app_id);
|
||||
--apex_util.export_application_page (p_workspace_id => l_workspace_id, p_application_id => l_app_id, p_page_id => 9);
|
||||
l_clob := owa_util_pkg.get_page (p_include_headers => false);
|
||||
|
||||
--debug_pkg.print (l_clob);
|
||||
file_util_pkg.save_clob_to_file ('DEVTEST_TEMP_DIR', 'my_export_of_f' || l_app_id || '_' || to_char(sysdate, 'yyyymmddhh24miss') || '.sql', l_clob);
|
||||
|
||||
end;
|
||||
279
demos/pdf_builder_pkg_demo.sql
Executable file
279
demos/pdf_builder_pkg_demo.sql
Executable file
@ -0,0 +1,279 @@
|
||||
|
||||
-- see http://technology.amis.nl/blog/8650/as_pdf-generating-a-pdf-document-with-some-plsql
|
||||
|
||||
begin
|
||||
pdf_builder_pkg.init;
|
||||
pdf_builder_pkg.write( 'Minimal usage' );
|
||||
pdf_builder_pkg.save_pdf;
|
||||
end;
|
||||
/
|
||||
|
||||
begin
|
||||
pdf_builder_pkg.init;
|
||||
pdf_builder_pkg.write( 'Some text with a newline-character included at this "
|
||||
" place.' );
|
||||
pdf_builder_pkg.write( 'Normally text written with pdf_builder_pkg.write() is appended after the previous text. But the text wraps automaticly to a new line.' );
|
||||
pdf_builder_pkg.write( 'But you can place your text at any place', -1, 700 );
|
||||
pdf_builder_pkg.write( 'you want', 100, 650 );
|
||||
pdf_builder_pkg.write( 'You can even align it, left, right, or centered', p_y => 600, p_alignment => 'right' );
|
||||
pdf_builder_pkg.save_pdf;
|
||||
end;
|
||||
/
|
||||
|
||||
begin
|
||||
pdf_builder_pkg.init;
|
||||
pdf_builder_pkg.write( 'The mini version of AS_PDF is restricted to the 14 standard PDF-fonts and the WINDOWS-1252 encoding.' );
|
||||
pdf_builder_pkg.set_font( 'helvetica' );
|
||||
pdf_builder_pkg.write( 'helvetica, normal: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, 700 );
|
||||
pdf_builder_pkg.set_font( 'helvetica', 'I' );
|
||||
pdf_builder_pkg.write( 'helvetica, italic: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
pdf_builder_pkg.set_font( 'helvetica', 'b' );
|
||||
pdf_builder_pkg.write( 'helvetica, bold: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
pdf_builder_pkg.set_font( 'helvetica', 'BI' );
|
||||
pdf_builder_pkg.write( 'helvetica, bold italic: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
pdf_builder_pkg.set_font( 'times' );
|
||||
pdf_builder_pkg.write( 'times, normal: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, 625 );
|
||||
pdf_builder_pkg.set_font( 'times', 'I' );
|
||||
pdf_builder_pkg.write( 'times, italic: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
pdf_builder_pkg.set_font( 'times', 'b' );
|
||||
pdf_builder_pkg.write( 'times, bold: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
pdf_builder_pkg.set_font( 'times', 'BI' );
|
||||
pdf_builder_pkg.write( 'times, bold italic: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
pdf_builder_pkg.set_font( 'courier' );
|
||||
pdf_builder_pkg.write( 'courier, normal: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, 550 );
|
||||
pdf_builder_pkg.set_font( 'courier', 'I' );
|
||||
pdf_builder_pkg.write( 'courier, italic: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
pdf_builder_pkg.set_font( 'courier', 'b' );
|
||||
pdf_builder_pkg.write( 'courier, bold: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
pdf_builder_pkg.set_font( 'courier', 'BI' );
|
||||
pdf_builder_pkg.write( 'courier, bold italic: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
|
||||
pdf_builder_pkg.set_font( 'courier' );
|
||||
pdf_builder_pkg.write( 'symbol:', -1, 475 );
|
||||
pdf_builder_pkg.set_font( 'symbol' );
|
||||
pdf_builder_pkg.write( 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
pdf_builder_pkg.set_font( 'courier' );
|
||||
pdf_builder_pkg.write( 'zapfdingbats:', -1, -1 );
|
||||
pdf_builder_pkg.set_font( 'zapfdingbats' );
|
||||
pdf_builder_pkg.write( 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
|
||||
pdf_builder_pkg.set_font( 'times', 'N', 20 );
|
||||
pdf_builder_pkg.write( 'times, normal with fontsize 20pt', -1, 400 );
|
||||
pdf_builder_pkg.set_font( 'times', 'N', 6 );
|
||||
pdf_builder_pkg.write( 'times, normal with fontsize 5pt', -1, -1 );
|
||||
pdf_builder_pkg.save_pdf;
|
||||
end;
|
||||
/
|
||||
|
||||
begin
|
||||
pdf_builder_pkg.init;
|
||||
for i in 1 .. 10
|
||||
loop
|
||||
pdf_builder_pkg.horizontal_line( 30, 700 - i * 15, 100, i );
|
||||
end loop;
|
||||
for i in 1 .. 10
|
||||
loop
|
||||
pdf_builder_pkg.vertical_line( 150 + i * 15, 700, 100, i );
|
||||
end loop;
|
||||
for i in 0 .. 255
|
||||
loop
|
||||
pdf_builder_pkg.horizontal_line( 330, 700 - i, 100, p_line_color => to_char( i, 'fm0x' ) || to_char( i, 'fm0x' ) || to_char( i, 'fm0x' ) );
|
||||
end loop;
|
||||
pdf_builder_pkg.save_pdf;
|
||||
end;
|
||||
/
|
||||
|
||||
declare
|
||||
t_logo varchar2(32767) :=
|
||||
'/9j/4AAQSkZJRgABAQEAYABgAAD/2wBDAAgGBgcGBQgHBwcJCQgKDBQNDAsLDBkS' ||
|
||||
'Ew8UHRofHh0aHBwgJC4nICIsIxwcKDcpLDAxNDQ0Hyc5PTgyPC4zNDL/2wBDAQkJ' ||
|
||||
'CQwLDBgNDRgyIRwhMjIyMjIyMjIyMjIyMjIyMjIyMjIyMjIyMjIyMjIyMjIyMjIy' ||
|
||||
'MjIyMjIyMjIyMjIyMjL/wAARCABqAJYDASIAAhEBAxEB/8QAHwAAAQUBAQEBAQEA' ||
|
||||
'AAAAAAAAAAECAwQFBgcICQoL/8QAtRAAAgEDAwIEAwUFBAQAAAF9AQIDAAQRBRIh' ||
|
||||
'MUEGE1FhByJxFDKBkaEII0KxwRVS0fAkM2JyggkKFhcYGRolJicoKSo0NTY3ODk6' ||
|
||||
'Q0RFRkdISUpTVFVWV1hZWmNkZWZnaGlqc3R1dnd4eXqDhIWGh4iJipKTlJWWl5iZ' ||
|
||||
'mqKjpKWmp6ipqrKztLW2t7i5usLDxMXGx8jJytLT1NXW19jZ2uHi4+Tl5ufo6erx' ||
|
||||
'8vP09fb3+Pn6/8QAHwEAAwEBAQEBAQEBAQAAAAAAAAECAwQFBgcICQoL/8QAtREA' ||
|
||||
'AgECBAQDBAcFBAQAAQJ3AAECAxEEBSExBhJBUQdhcRMiMoEIFEKRobHBCSMzUvAV' ||
|
||||
'YnLRChYkNOEl8RcYGRomJygpKjU2Nzg5OkNERUZHSElKU1RVVldYWVpjZGVmZ2hp' ||
|
||||
'anN0dXZ3eHl6goOEhYaHiImKkpOUlZaXmJmaoqOkpaanqKmqsrO0tba3uLm6wsPE' ||
|
||||
'xcbHyMnK0tPU1dbX2Nna4uPk5ebn6Onq8vP09fb3+Pn6/9oADAMBAAIRAxEAPwD3' ||
|
||||
'+iiigAooooAKKKKACiiigAooooAKKKKACiiigAooooAKKKKACiiigAoorifiX4pk' ||
|
||||
'8PaCILR9t9eExxsOqL/E315AHuaUmkrs1oUZVqipw3ZU8X/FCz0KeSw02Jb2+Thy' ||
|
||||
'WxHGfQkdT7D8686ufih4suGJW/jgXssUC8fnk1ydvbz3lzHb28bzTyttRF5LMa7H' ||
|
||||
'Uvh+3hvRI9T1+7kUPIsf2ezUMykgnlmIHbtXI5znqtj66ng8DhFGFRJyffVv5Fnw' ||
|
||||
'r8QfEEvinTodR1N5rSaYRyIyIAd3A5A9SK7X4qeINV0Gz019LvGtmlkcOVVTkADH' ||
|
||||
'UGvNdDsPDepa7ZWdtPrMU8syiN3EWFbqCcfSu3+NXGnaOM5/ev8A+giqi5ezepy1' ||
|
||||
'6NF4+koxsne6scronxO1+01i2l1K/e6st2Joyij5T1IwByOv4V75BPHc28c8Lh45' ||
|
||||
'FDKynIIPINfJleheGPiPJong+802Ul7uEYsCRkYbsfZev04pUqttJF5rlSqKM6Eb' ||
|
||||
'PZpGv8RfiFf2etDTNDu/I+zf8fEqqG3Of4eQen8z7VB8O/GGv6x4vhs9Q1J57don' ||
|
||||
'YoUUZIHHQV5fI7yyNJIxd3JZmY5JJ6k12nwo/wCR8t/+uEn8qUajlM6K+Ao0MFJc' ||
|
||||
'qbS363O1+KviTWNBuNMXS71rYTLIZAqqd2NuOoPqayvht4u17WvFf2TUdRe4g+zu' ||
|
||||
'+woo5BXB4HuaX42f8fOj/wC7L/Naw/hH/wAjv/26yfzWqcn7W1zjpUKTytzcVez1' ||
|
||||
'sdt8QviJN4euhpelJG16VDSyuMiIHoMdz3rzZviN4tZif7YkHsIkx/6DTPiAkqeO' ||
|
||||
'9WE2dxlBXP8Ad2jH6VJ4H8LWfizUp7S51FrV40DoiKC0nPOM+nH51MpTlOyOvDYX' ||
|
||||
'C4fCKrUinpdu1zovAfjvXL7xfZ2ep6i89tOGTayKPmxkHgD0/WvbK83074RWWman' ||
|
||||
'a30Wr3Zkt5VlUFVwSDnHSvQZ7u2tU3XE8cSju7gD9a6Kakl7x89mVTD1aqlh1pbt' ||
|
||||
'YnorDfxj4eWTy11W3lfpthbzD+S5q7ZavBfy7IIrrGM75Ld41/NgKu6OB05pXaL9' ||
|
||||
'FFFMgK8A+K+ote+NZYM5jtIliA9yNx/mPyr37tXzP42cv421gseftLD8sCsK7909' ||
|
||||
'zIIKWJcn0Rf8Aa5o3h3WJtR1VZmdY9kAjj3YJ+8fbjj8TW/8QPHuj+J/D6WNgLjz' ||
|
||||
'lnWQ+ZHtGAD3z71wNno2qahEZbLTrq5jB2l4oiwB9Mii80XVNPhE17p11bxE7d8s' ||
|
||||
'RUZ9MmsFOSjZLQ9+phMNUxKqyl7y6XNHwR/yO+j/APXyP5GvQ/jX/wAg/SP+ur/+' ||
|
||||
'givPPBH/ACO+j/8AXyP5GvQ/jX/yD9I/66v/AOgirh/CZyYv/kZ0vT/M8y8PaM/i' ||
|
||||
'DV106J9kskcjRk9NyqSAfY4xWbLFJBM8UqFJI2KurDBUjgg11nww/wCR/sP92T/0' ||
|
||||
'A16B4p+Gq614xtNQg2pZznN+AcH5e4/3uh/OojT5o3R0V8xjh8S6dT4bX+ev5nk1' ||
|
||||
'7oU+n+HtP1W4yv26RxEhH8CgfN+JP5V0Hwo/5Hy3/wCuEn8q6b4zxJBY6JFEgSNG' ||
|
||||
'kVVUYAAC4Fcn8MbqG08bQyzyBEEMnJ78dB6mq5VGokZ+3licunUe7TOn+Nn/AB86' ||
|
||||
'P/uy/wA1rD+EZA8bEk4AtJMn8Vru/GHhW58c3lhKrmws7ZX3yzp875x91e3Tvj6V' ||
|
||||
'zduPDPh6/GneGtOl8Qa2wKmRnzGvrk/dx9B+NXKL9pzHDQxEHgPq8dZWd/L1exf+' ||
|
||||
'JHhuPxFdw6hozLPeIPLnCnCbBkhi5+UEfXofauEtLWy8OX0N7L4hQ3sDBli01POI' ||
|
||||
'PoXOF9j1r1O18E6nrhSfxbqJkjHK6baHy4E9jjlq84+IXg4+GNWE1qh/sy5JMX/T' ||
|
||||
'Nu6f1Ht9KVSL+OxeXYiMrYSU/wCu13/l8zudCn1jx3avcxaybO1Vijorbph9Qu1V' ||
|
||||
'z/wKt+y+HHh63fzrq3k1CfqZbyQyc/Tp+leL+CvE0vhjxDDc7z9klIjuU7FSev1H' ||
|
||||
'X8/WvpNWDqGUggjIIrSk1NXe5wZpTq4Spywdova2hFbWVrZxiO2t4oUH8MaBR+lT' ||
|
||||
'0UVseM23uFFFFAgr5y+I9obPx5qQIwsrLKvuCo/qDX0bXkPxn0YiSw1mNflINvKf' ||
|
||||
'Tuv/ALNWNdXiexklZU8Uk/tKxb+C16j6bqVgSN8cyygezDH81rR+MQ/4o6L/AK+0' ||
|
||||
'/k1cV8JrXVv+Em+2WkJNgEaO5kY4XHUAerZxxXpHxB0b/hIdBSxjv7W1kWdZC1w2' ||
|
||||
'BgA/40oXdOxti1CjmanfS6b8jxbwR/yO+j/9fI/ka9D+Nf8AyD9I/wCur/8AoIrG' ||
|
||||
'8PeCJtJ8RWOoHVLa7S2lDslpFJIT7AgY/Ouu8a+HNT8bx2EVvB9hit3ZmkuiMkEY' ||
|
||||
'4VST+eKiMGqbR1YnFUZY+nWT91L/ADPN/hh/yP8AYf7sn/oBr3y51O1tHEbybpj0' ||
|
||||
'ijBZz/wEc1xXh34WafoVyl7PqNzNcoD8yN5SgEYPTn9auar438K+FI3hhkjluB1h' ||
|
||||
'tQGYn/abp+ZzWlNckfeOHMakcbiL0E5aW2F8SeFJPG01kb7fYWlqWYKCDLJnHXsv' ||
|
||||
'T3/Cqdzqngz4cwGC0hje+xjyofnmY/7THp+P5VjHUvHfjxWXToBoult/y1clWcfX' ||
|
||||
'GT+AH1qx4Q+GN/oXiSLUtQurO5iRW+UKxbceh5HX3ovd3ivmChGnT5MRU0X2U/zZ' ||
|
||||
'yfjXxR4p1K2ga/gfTNOu9xhtlOGdRjl+56j0HtS/CL/kd/8At1k/mteg/EHwRfeL' ||
|
||||
'ZbB7O5t4RbhwwlB53Y6Y+lZ/gf4c6l4Y8Q/2jdXlrLH5LR7Yw2ckj1+lRyS9pc7F' ||
|
||||
'jsM8BKmrRk09EQeNviHrnhnxLLp8FtZvBsWSNpFbcQRznB9Qa4bxF8Q9Y8S6abC8' ||
|
||||
'htI4CwY+Wh3ZByOSTivS/H/gC78V6haXllcwQPHGY5PNB+YZyMY+prkP+FMa3/0E' ||
|
||||
'rH8n/wAKKiqNtLYeBrZdCnCc7Ka9TzcKzkKoJZuAB3NfVWjwS22i2UE3MscCI/1C' ||
|
||||
'gGuE8LfCe20e/i1DU7sXk8Lbo40TbGrdic8nFekVVGm46s485x9PEyjGlql1Ciii' ||
|
||||
'tzxAooooAKo6vpFnrmmS6ffRl7eXG4A4PByCD26VeooHGTi7rcxL3w9btpEen2Nr' ||
|
||||
'aRxRDEcciHaP++SDXG3fhzxxZzCTSpNICDpGqE5/77BP616bRUuKZ0UsVOn5+up5' ||
|
||||
'd/wkfxI0vi98Nw3ajq0A5/8AHWP8qgfxz461aQwaX4Za2boWljY7T9W2ivWKTA9K' ||
|
||||
'nkfc3WNpbujG/wA/yPKl8DeM/EZ3eI/EDW8DdYITn8MDC/zrqtC+HXh3QiskdmLi' ||
|
||||
'4XkTXHzkH2HQfgK6yimoJamdTH1prlTsuy0QgAHAGKWsvWHvVNsLcS+QXIuGhAMg' ||
|
||||
'G04wD74z3rHmfxAxkEJuFk3SL8yIUEe07GHq+duR67uMYqm7GEaXNrdHWUVx7z+K' ||
|
||||
'y+/yiCixnylC4coX389t+Fx6ZHvTbj/hKHjufmmV1ineLywmN+UMa89cAsPfFLmL' ||
|
||||
'+r/3l952VFcpqdvrcEt0bO4vJI1SAx/dOSZCJO2eFxSwPrZ1IBTc+WJ4wBIoEZh2' ||
|
||||
'DeScZ3bt2O+cdqLi9j7t+ZHVUVzFzHrUN/dNFLdPaiaMADaSIyMuUGOSDgfTOKWV' ||
|
||||
'/ES6XCbcF7j7S4XzAoJi2vs39hzt6e3vTuL2O2qOmormjHqU32F4ptRUGbFysgQE' ||
|
||||
'LsY+n97aOK6KJzJEjlGTcoO1uo9j70XIlDl6j6KKKZAUUUUAFFFFABRRRQAUUUUA' ||
|
||||
'Y3iDV59JjgNvCkrylwA5IAKxsw6e6gVnnxTchjmwZMSm2MbZ3LMUDKvoVJyN3Toa' ||
|
||||
'6ggHqAaMD0FKzNYzglZxuci3i26jghmeCAiXG9Fc7rf94qEP/wB9H05HfrUl74ou' ||
|
||||
'4PtKxW0TG3lQM+4lTG7KI2HrkMe/8JrqTGhzlF568daPLTbt2Lt6YxxSs+5ftKd/' ||
|
||||
'hOah8SXL6iLcxwSL9ojgKITvIaMMXHJGBn8h1qO48V3Vs1y5sA8EJmVnQklSrbUJ' ||
|
||||
'Hoe5HTjtXUrGinKooOMcCl2r6D8qLMXtKd/hOX1fxFqNjd3qW1ik0VpAszkkjgq5' ||
|
||||
'zn2Kjjqc0j+JrmNeIoGZIkk25wZ9zEbY8E8jHqeSOldTtU5yBz1poiRcAIox0wOl' ||
|
||||
'Fn3D2lOyXKcvZeJ72W5tPtVpFDaXErxiZmK4KiTjnr9wc+9aHh/W21W0WW4MMckh' ||
|
||||
'OyNTzx178/pWyY0ZdrIpHoRQsaISVRQT6ChJinUhJO0bDqKKKoxCiiigAooooAKK' ||
|
||||
'KKACiiigAooooAKKKKACiiigAooooAKKKKACiiigD//Z';
|
||||
begin
|
||||
pdf_builder_pkg.init;
|
||||
pdf_builder_pkg.put_image( to_blob( utl_encode.base64_decode( utl_raw.cast_to_raw( t_logo ) ) )
|
||||
, - ( pdf_builder_pkg.get_settings().page_width
|
||||
+ pdf_builder_pkg.get_settings().margin_left
|
||||
- pdf_builder_pkg.get_settings().margin_right
|
||||
) / 2
|
||||
, pdf_builder_pkg.get_settings().page_height - 260
|
||||
);
|
||||
pdf_builder_pkg.write( 'jpg and png images are supported.' );
|
||||
pdf_builder_pkg.write( 'And because PDF 1.3 (thats the format I use) doesn''t support alpha channels, neither does pdf_builder_pkg.', -1, -1 );
|
||||
pdf_builder_pkg.save_pdf;
|
||||
end;
|
||||
/
|
||||
|
||||
|
||||
declare
|
||||
t_rc sys_refcursor;
|
||||
procedure refcursor2pdf( p_rc sys_refcursor )
|
||||
is
|
||||
t_xml xmltype;
|
||||
type tp_node_rec is record
|
||||
( name varchar2(1000)
|
||||
, str_size number
|
||||
);
|
||||
type tp_nodes is table of tp_node_rec index by pls_integer;
|
||||
nodes tp_nodes;
|
||||
t_x number;
|
||||
t_y number;
|
||||
t_set number;
|
||||
t_padding number := 5.4;
|
||||
t_total_width number;
|
||||
begin
|
||||
pdf_builder_pkg.init;
|
||||
t_set := pdf_builder_pkg.get_settings().page_width
|
||||
+ pdf_builder_pkg.get_settings().margin_left
|
||||
- pdf_builder_pkg.get_settings().margin_right;
|
||||
t_xml := xmltype( p_rc );
|
||||
--
|
||||
select nds.name
|
||||
, greatest( max( pdf_builder_pkg.string_width( nds.val ) )
|
||||
, pdf_builder_pkg.string_width( nds.name )
|
||||
) val
|
||||
bulk collect into nodes
|
||||
from ( select xmltype( xmltype.getclobval( nds.column_value ) ).getrootelement() name
|
||||
, xmltype.extract( nds.column_value, '* /text()' ).getclobval() val
|
||||
from table( xmlsequence( t_xml.extract( '/ROWSET/ROW/node()' ) ) ) nds
|
||||
) nds
|
||||
, ( select rownum i
|
||||
, xmltype( xmltype.getclobval( frw.column_value ) ).getrootelement() name
|
||||
from table( xmlsequence( t_xml.extract( '/ROWSET/ROW[1]/node()' ) ) ) frw
|
||||
) frw
|
||||
where frw.name = nds.name
|
||||
group by nds.name, frw.i
|
||||
order by frw.i;
|
||||
--
|
||||
t_total_width := 0;
|
||||
for i in nodes.first .. nodes.last
|
||||
loop
|
||||
nodes( i ).str_size := nodes( i ).str_size + 2 * t_padding;
|
||||
t_total_width := t_total_width + nodes( i ).str_size;
|
||||
end loop;
|
||||
--
|
||||
t_y := -12345;
|
||||
for r_rows in ( select rws.column_value cv
|
||||
from table( xmlsequence( t_xml.extract( '/ROWSET/ROW' ) ) ) rws
|
||||
)
|
||||
loop
|
||||
if t_y <= pdf_builder_pkg.get_settings().margin_bottom + t_padding / 2
|
||||
then
|
||||
if t_y != -12345
|
||||
then
|
||||
pdf_builder_pkg.new_page;
|
||||
end if;
|
||||
t_y := pdf_builder_pkg.get_settings().page_height
|
||||
- pdf_builder_pkg.get_settings().margin_top;
|
||||
t_x := ( t_set - t_total_width ) / 2;
|
||||
for i in nodes.first .. nodes.last
|
||||
loop
|
||||
pdf_builder_pkg.rect( t_x, t_y - t_padding / 2, nodes( i ).str_size, pdf_builder_pkg.get_settings().current_fontsizePt + t_padding, p_fill_color => '#9bafde' );
|
||||
pdf_builder_pkg.write( nodes( i ).name, t_x + t_padding, t_y );
|
||||
t_x := t_x + nodes( i ).str_size;
|
||||
end loop;
|
||||
t_y := t_y - pdf_builder_pkg.get_settings().current_fontsizePt - t_padding;
|
||||
end if;
|
||||
t_x := ( t_set - t_total_width ) / 2;
|
||||
for i in nodes.first .. nodes.last
|
||||
loop
|
||||
pdf_builder_pkg.rect( t_x, t_y - t_padding / 2, nodes( i ).str_size, pdf_builder_pkg.get_settings().current_fontsizePt + t_padding );
|
||||
if r_rows.cv.extract( '/ROW/' || nodes( i ).name ) is not null
|
||||
then
|
||||
pdf_builder_pkg.write( r_rows.cv.extract( '/ROW/' || nodes( i ).name || '/text()' ).getclobval(), t_x + t_padding, t_y );
|
||||
end if;
|
||||
t_x := t_x + nodes( i ).str_size;
|
||||
end loop;
|
||||
t_y := t_y - pdf_builder_pkg.get_settings().current_fontsizePt - t_padding;
|
||||
end loop;
|
||||
pdf_builder_pkg.save_pdf;
|
||||
end;
|
||||
begin
|
||||
open t_rc for select 'x123' x, 'wat' w, 1 xxxx from dual
|
||||
union all select 'abc', 'x', 3 from dual
|
||||
union all select 'abc', '', 3 from dual
|
||||
union all select 'abcef', null, 5 from dual
|
||||
union all select 'HXFG', 'HGJ', 8 from dual
|
||||
union all select 'abc', 'x', rownum from dual connect by rownum < 50;
|
||||
refcursor2pdf( t_rc );
|
||||
end;
|
||||
/
|
||||
|
||||
206
demos/plsql_status_web_pkg.pkb
Executable file
206
demos/plsql_status_web_pkg.pkb
Executable file
@ -0,0 +1,206 @@
|
||||
create or replace package body plsql_status_web_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package provides a dynamic RSS feed of PL/SQL compilation status/errors
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 22.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
g_package_name constant varchar2(30) := 'plsql_status_web_pkg';
|
||||
g_host_name constant varchar2(255) := owa_util.get_cgi_env('HTTP_HOST');
|
||||
g_service_path constant varchar2(255) := owa_util.get_owa_service_path;
|
||||
|
||||
function get_errors return sys_refcursor
|
||||
as
|
||||
l_returnvalue sys_refcursor;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: query to get errors in schema
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 22.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
open l_returnvalue
|
||||
for
|
||||
select null as id,
|
||||
name || ': ' || substr(text,1,100) as title,
|
||||
attribute || ': ' || text as description,
|
||||
'http://' || g_host_name || g_service_path || g_package_name || '.show?p_type=' || type || '&p_name=' || name || '&p_seq=' || sequence as link,
|
||||
sysdate as updated_on
|
||||
from user_errors
|
||||
order by type, name, sequence;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_errors;
|
||||
|
||||
|
||||
procedure rss
|
||||
as
|
||||
l_cursor sys_refcursor;
|
||||
l_rss clob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: generate the RSS feed
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 22.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_cursor := get_errors;
|
||||
|
||||
l_rss := rss_util_pkg.ref_cursor_to_feed (l_cursor, 'PL/SQL Errors', 'This is a feed of compilation errors in the database schema.');
|
||||
|
||||
owa_util.mime_header('application/xml', false);
|
||||
owa_util.http_header_close;
|
||||
|
||||
owa_util_pkg.htp_print_clob (l_rss);
|
||||
|
||||
end rss;
|
||||
|
||||
|
||||
|
||||
procedure show (p_type in varchar2,
|
||||
p_name in varchar2,
|
||||
p_seq in number)
|
||||
as
|
||||
l_error user_errors%rowtype;
|
||||
l_object user_objects%rowtype;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: print details for specific error
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 22.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
begin
|
||||
select *
|
||||
into l_error
|
||||
from user_errors
|
||||
where type = p_type
|
||||
and name = p_name
|
||||
and sequence = p_seq;
|
||||
exception
|
||||
when no_data_found then
|
||||
l_error := null;
|
||||
end;
|
||||
|
||||
begin
|
||||
select *
|
||||
into l_object
|
||||
from user_objects
|
||||
where object_type = l_error.type
|
||||
and object_name = l_error.name;
|
||||
exception
|
||||
when no_data_found then
|
||||
l_object := null;
|
||||
end;
|
||||
|
||||
htp.p('<title>Error Details</title><style>
|
||||
* { font-family: tahoma; }
|
||||
div.errormsg { border: 1px solid black; background-color:orange; font-size: 18px; font-weight: bold; width: 75%; margin-top: 10px; margin-bottom: 10px; padding: 20px; }
|
||||
div.code { border: 1px dotted #999999; background-color: #dddddd; width: 75%; margin-top: 10px; margin-bottom: 10px; padding: 20px; }
|
||||
pre, pre b { font-family: lucida console, courier new, courier; font-size: 13px; }
|
||||
b.error_line { border: 1px dotted red; background-color: pink; }
|
||||
a { padding: 3px; border: 1px dotted #999999; }
|
||||
div.credits { font-size: 9px; }
|
||||
</style>');
|
||||
|
||||
htp.header (1, l_error.name || ' (' || l_error.type || ')');
|
||||
|
||||
if (l_object.object_name is not null) then
|
||||
htp.p('Status: <b>' || l_object.status || '</b>, Created: ' || apex_util.get_since (l_object.created) || ', Last Modified: ' || apex_util.get_since (l_object.last_ddl_time) || ', Timestamp: ' || l_object.timestamp);
|
||||
end if;
|
||||
|
||||
htp.p ('<div class="errormsg">' || l_error.attribute || ': ' || l_error.text || '</div>');
|
||||
|
||||
htp.prn('Search for this error on ');
|
||||
htp.anchor('http://www.google.com/search?q=' || utl_url.escape (l_error.text), 'Google');
|
||||
htp.prn(' ');
|
||||
htp.anchor('http://www.oracle.com/pls/db102/search?remark=advanced_search&word=' || utl_url.escape (l_error.text), 'Oracle Docs');
|
||||
htp.prn(' ');
|
||||
htp.anchor('http://forums.oracle.com/forums/search.jspa?q=' || utl_url.escape (l_error.text), 'Oracle Forums');
|
||||
htp.prn(' ');
|
||||
htp.anchor('http://asktom.oracle.com/pls/ask/search?p_string=' || utl_url.escape (l_error.text), 'AskTom');
|
||||
htp.prn(' ');
|
||||
htp.anchor('http://stackoverflow.com/search?q=' || utl_url.escape (l_error.text), 'StackOverflow');
|
||||
|
||||
|
||||
|
||||
if l_error.line <> 0 then
|
||||
|
||||
htp.p('<div class="code"><pre>');
|
||||
for l_rec in (select line, replace(text, chr(10), '') as text from user_source where type = p_type and name = p_name and line between l_error.line - 20 and l_error.line + 20 order by line) loop
|
||||
|
||||
if l_rec.line = l_error.line then
|
||||
htp.p('<b class="error_line">' || lpad(l_rec.line, 3, ' ') || ' ' || l_rec.text || '</b>');
|
||||
else
|
||||
htp.p(lpad(l_rec.line, 4, ' ') || ' ' || l_rec.text);
|
||||
end if;
|
||||
|
||||
end loop;
|
||||
htp.p('</pre></div>');
|
||||
|
||||
end if;
|
||||
|
||||
htp.p('<hr><div class="credits">This is a sample from the free, open source <a href="http://code.google.com/p/plsql-utils/">PL/SQL Utility Library</a>.</div>');
|
||||
|
||||
|
||||
end show;
|
||||
|
||||
|
||||
procedure home
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Main page
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 22.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
htp.p('<h1>Welcome</h1>');
|
||||
|
||||
htp.p('<a href="' || g_package_name || '.rss">Get the RSS feed here</a>');
|
||||
|
||||
end home;
|
||||
|
||||
|
||||
|
||||
|
||||
end plsql_status_web_pkg;
|
||||
/
|
||||
|
||||
30
demos/plsql_status_web_pkg.pks
Executable file
30
demos/plsql_status_web_pkg.pks
Executable file
@ -0,0 +1,30 @@
|
||||
create or replace package plsql_status_web_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package provides a dynamic RSS feed of PL/SQL compilation status/errors
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 22.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
-- list errors
|
||||
procedure rss;
|
||||
|
||||
-- show details
|
||||
procedure show (p_type in varchar2,
|
||||
p_name in varchar2,
|
||||
p_seq in number);
|
||||
|
||||
-- main page
|
||||
procedure home;
|
||||
|
||||
|
||||
end plsql_status_web_pkg;
|
||||
/
|
||||
|
||||
52
demos/random_util_pkg_demo.sql
Executable file
52
demos/random_util_pkg_demo.sql
Executable file
@ -0,0 +1,52 @@
|
||||
|
||||
-- generate random test data of various types
|
||||
|
||||
select random_util_pkg.get_integer,
|
||||
random_util_Pkg.get_date,
|
||||
random_util_pkg.get_amount,
|
||||
random_util_pkg.get_file_type,
|
||||
random_util_pkg.get_file_name,
|
||||
random_util_pkg.get_mime_type,
|
||||
random_util_pkg.get_text (10,50) as some_text
|
||||
from dual
|
||||
connect by rownum <= 10
|
||||
|
||||
-- generate random user information
|
||||
|
||||
select random_util_pkg.get_person_name as person_name,
|
||||
random_util_pkg.get_value (t_str_array('super user', 'administrator', 'accountant', 'manager')) as user_type,
|
||||
random_util_pkg.get_password as password,
|
||||
random_util_pkg.get_date as last_login_date
|
||||
from dual
|
||||
connect by rownum <= 10
|
||||
|
||||
-- same as above, but with email address (matching the person's name)
|
||||
|
||||
select t.*,
|
||||
random_util_pkg.get_email_address (t_str_array('company1.example', 'company2.example', 'company3.example'), t.person_name) as email_address
|
||||
from (
|
||||
select random_util_pkg.get_person_name as person_name,
|
||||
random_util_pkg.get_value (t_str_array('super user', 'administrator', 'accountant', 'manager')) as user_type,
|
||||
random_util_pkg.get_password as password
|
||||
from dual
|
||||
connect by rownum <= 10) t
|
||||
|
||||
-- generate some data from the Sales department
|
||||
|
||||
select random_util_pkg.get_date as purchase_date,
|
||||
random_util_pkg.get_value (t_str_array('jacket', 'shoes', 'socks (3-pack)', 'hat')) as product_name,
|
||||
random_util_pkg.get_amount (10, 200) as purchase_amount,
|
||||
random_util_pkg.get_person_name as customer_name
|
||||
from dual
|
||||
connect by rownum <= 25
|
||||
|
||||
|
||||
|
||||
-- some not-so-serious generators, just for fun :-)
|
||||
|
||||
select random_util_pkg.get_buzzword,
|
||||
random_util_pkg.get_business_concept,
|
||||
random_util_pkg.get_wait_message,
|
||||
random_util_Pkg.get_error_message
|
||||
from dual
|
||||
connect by rownum <= 10
|
||||
48
demos/rss_util_pkg_demo.sql
Executable file
48
demos/rss_util_pkg_demo.sql
Executable file
@ -0,0 +1,48 @@
|
||||
-- generate RSS feed from ref cursor (supports different output formats: rss/rdf/atom)
|
||||
|
||||
declare
|
||||
l_clob clob;
|
||||
l_cursor sys_refcursor;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
open l_cursor for select empno, ename, job as descr, 'http://127.0.0.1:8080/devtest/demo.employee?p_id=' || empno as link, hiredate from emp order by ename;
|
||||
l_clob := rss_util_pkg.ref_cursor_to_feed (l_cursor, 'my feed from pl/sql', p_format => rss_util_pkg.g_format_rss);
|
||||
debug_pkg.print(substr(l_clob, 1, 32000));
|
||||
end;
|
||||
|
||||
|
||||
-- parse RSS feed into rows
|
||||
-- NOTE: feed format will be autodetected if you leave out the format parameter
|
||||
|
||||
select *
|
||||
from table(rss_util_pkg.rss_to_table(httpuritype('http://127.0.0.1:8080/devtest/demo.employee_rss').getclob(), 'rss'))
|
||||
|
||||
select *
|
||||
from table(rss_util_pkg.rss_to_table(httpuritype('http://www.dagbladet.no/rss/forsida/').getclob(), 'rss'))
|
||||
|
||||
-- RDF variety
|
||||
|
||||
select *
|
||||
from table(rss_util_pkg.rss_to_table(httpuritype('http://www.aftenposten.no/eksport/rss-1_0/').getclob(), 'rdf'))
|
||||
|
||||
select *
|
||||
from table(rss_util_pkg.rss_to_table(httpuritype('http://rss.slashdot.org/Slashdot/slashdot').getclob(), 'rdf'))
|
||||
|
||||
-- Atom variety
|
||||
|
||||
select *
|
||||
from table(rss_util_pkg.rss_to_table(httpuritype('http://stackoverflow.com/feeds').getclob(), 'atom'))
|
||||
|
||||
|
||||
-- process feed items via PL/SQL
|
||||
|
||||
declare
|
||||
l_items rss_util_pkg.t_feed_item_list;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_items := rss_util_pkg.rss_to_list(httpuritype('http://stackoverflow.com/feeds').getclob());
|
||||
for i in 1 .. l_items.count loop
|
||||
debug_pkg.printf('item %1, title = %2', i, l_items(i).item_title);
|
||||
end loop;
|
||||
end;
|
||||
|
||||
17
demos/sql_builder_pkg_demo.sql
Executable file
17
demos/sql_builder_pkg_demo.sql
Executable file
@ -0,0 +1,17 @@
|
||||
|
||||
-- a simple API to build an SQL string
|
||||
|
||||
declare
|
||||
l_my_query sql_builder_pkg.t_query;
|
||||
l_sql varchar2(32000);
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
sql_builder_pkg.add_select (l_my_query, 'ename');
|
||||
sql_builder_pkg.add_select (l_my_query, 'sal');
|
||||
sql_builder_pkg.add_select (l_my_query, 'deptno');
|
||||
sql_builder_pkg.add_from (l_my_query, 'emp');
|
||||
sql_builder_pkg.add_where (l_my_query, 'ename = :p_ename');
|
||||
sql_builder_pkg.add_where (l_my_query, 'sal > :p_sal');
|
||||
l_sql := sql_builder_pkg.get_sql (l_my_query);
|
||||
debug_pkg.printf(l_sql);
|
||||
end;
|
||||
12
demos/sql_util_pkg_demo.sql
Executable file
12
demos/sql_util_pkg_demo.sql
Executable file
@ -0,0 +1,12 @@
|
||||
|
||||
|
||||
-- make a number of rows
|
||||
|
||||
select *
|
||||
from table(sql_util_pkg.make_rows (10))
|
||||
|
||||
-- make rows in specified range
|
||||
|
||||
select *
|
||||
from table(sql_util_pkg.make_rows (10, 13))
|
||||
|
||||
56
demos/string_util_pkg_demo.sql
Executable file
56
demos/string_util_pkg_demo.sql
Executable file
@ -0,0 +1,56 @@
|
||||
-- replace several strings at once (useful for processing text templates such as emails or web pages)
|
||||
|
||||
select string_util_pkg.multi_replace ('this is my #COLOR# string (not only #COLOR# but also #SIZE#)', t_str_array('#COLOR#', '#SIZE#'), t_str_array('green', 'great'))
|
||||
from dual
|
||||
|
||||
-- split string into rows
|
||||
|
||||
select *
|
||||
from table(string_util_pkg.split_str ('CLOSED,IN PROGRESS,REJECTED', ','))
|
||||
|
||||
-- useful for variable IN clauses
|
||||
|
||||
select *
|
||||
from emp
|
||||
where ename in (select column_value
|
||||
from table(string_util_pkg.split_str ('SMITH,ADAMS,JAMES', ',')))
|
||||
|
||||
|
||||
-- join together many rows into one string (SQL query)
|
||||
|
||||
select string_util_pkg.join_str(cursor(select ename from emp order by ename))
|
||||
from dual
|
||||
|
||||
-- join together many rows into one string (PL/SQL)
|
||||
|
||||
declare
|
||||
l_val varchar2(32000);
|
||||
l_cursor sys_refcursor;
|
||||
begin
|
||||
open l_cursor for select ename from emp order by ename;
|
||||
l_val := string_util_pkg.join_str(l_cursor);
|
||||
dbms_output.put_line(l_val);
|
||||
end;
|
||||
|
||||
|
||||
-- randomize array of strings
|
||||
|
||||
declare
|
||||
l_test1 t_str_array ('one', 'two', 'three', 'four');
|
||||
begin
|
||||
|
||||
debug_pkg.debug_on;
|
||||
|
||||
for i in l_test1.first .. l_test1.last loop
|
||||
debug_pkg.printf('%1 = %2', i, l_test1(i));
|
||||
end loop;
|
||||
|
||||
l_test1 := randomize_array (l_test1);
|
||||
|
||||
for i in l_test1.first .. l_test1.last loop
|
||||
debug_pkg.printf('%1 = %2', i, l_test1(i));
|
||||
end loop;
|
||||
|
||||
end;
|
||||
|
||||
|
||||
131
demos/sylk_util_pkg_demo.sql
Executable file
131
demos/sylk_util_pkg_demo.sql
Executable file
@ -0,0 +1,131 @@
|
||||
|
||||
-- see http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:728625409049
|
||||
|
||||
Rem
|
||||
Rem $Id$
|
||||
Rem
|
||||
Rem Copyright (c) 1991, 1996, 1997 by Oracle Corporation
|
||||
Rem NAME
|
||||
Rem owasylk.sql - Dump to Spreadsheet with formatting
|
||||
Rem DESCRIPTION
|
||||
Rem This package provides an API to generate a file in the
|
||||
Rem SYLK file format. This allow for formatting in a
|
||||
Rem spreadsheet with only a ascii text file. This version
|
||||
Rem of owa_sylk is specific to Oracle8.
|
||||
Rem NOTES
|
||||
Rem
|
||||
Rem MODIFIED (MM/DD/YY)
|
||||
Rem clbeck 04/08/98 - Created.
|
||||
Rem tkyte 09/10/00 - Made it use UTL_FILE.
|
||||
Rem
|
||||
Rem
|
||||
|
||||
/*
|
||||
This package allows you to send the results of any query to
|
||||
a spreadsheet using UTL_FILE
|
||||
|
||||
parameters:
|
||||
p_query - a text string of the query. The query
|
||||
can be parameterized
|
||||
using the :VARAIBLE syntax. See example
|
||||
below.
|
||||
|
||||
p_parm_names - an owaSylkArray of the paramter names
|
||||
used as bind variables in p_query
|
||||
|
||||
p_parm_values - an owaSylkArray of the values of the
|
||||
bind variable names. The values
|
||||
muse reside in the same index as the
|
||||
name it corresponds to.
|
||||
|
||||
p_cursor - an open cursor that has had the query
|
||||
parsed already.
|
||||
|
||||
p_sum_column - a owaSylkArray of 'Y's and 'N's
|
||||
corresponding to the location
|
||||
of the columns selected in p_query.
|
||||
A value of NYNYY will result
|
||||
in the 2nd, 4th and 5th columns being
|
||||
summed in the resulting
|
||||
spreadsheet.
|
||||
|
||||
p_max_rows - the maxium number of row to return.
|
||||
|
||||
p_show_null_as - how to display nulls in the spreadsheet
|
||||
|
||||
p_show_grid - show/hide the grid in the spreadsheet.
|
||||
|
||||
p_show_col_headers - show/hide the row/column headers
|
||||
in the spreadsheet.
|
||||
|
||||
p_font_name - the name of the font
|
||||
|
||||
p_widths - a owaSylkArray of column widths. This
|
||||
will override the default column widths.
|
||||
|
||||
p_headings - a owaSylkArray of column titles.
|
||||
This will override the default column
|
||||
titles.
|
||||
|
||||
p_strip_html - this will remove the HTML tags from the
|
||||
results before
|
||||
displaying them in the spreadsheet cells.
|
||||
Useful when the
|
||||
query selects an anchor tag. Only the
|
||||
text between <a href>
|
||||
and </a> tags will be sent to the
|
||||
spreadsheet.
|
||||
|
||||
*/
|
||||
|
||||
|
||||
-- examples:
|
||||
|
||||
-- This example will create a spreadsheet of all the MANAGERS
|
||||
-- in the scott.emp table and will sum up the salaries
|
||||
-- and commissions for them. No grid will be in the
|
||||
-- spreadsheet.
|
||||
|
||||
|
||||
|
||||
declare
|
||||
output utl_file.file_type;
|
||||
begin
|
||||
output := utl_file.fopen( 'DEVTEST_TEMP_DIR', 'emp1.slk', 'w', 32000 );
|
||||
|
||||
sylk_util_pkg.show(
|
||||
p_file => output,
|
||||
p_query => 'select empno id, ename employee, sal Salary, comm commission from emp where job = :JOB and sal > :SAL',
|
||||
p_parm_names => sylk_util_pkg.owaSylkArray( 'JOB', 'SAL'),
|
||||
p_parm_values => sylk_util_pkg.owaSylkArray( 'MANAGER', '2000' ),
|
||||
p_sum_column => sylk_util_pkg.owaSylkArray( 'N', 'N', 'Y', 'Y'),
|
||||
p_show_grid => 'NO' );
|
||||
|
||||
utl_file.fflush ( output );
|
||||
utl_file.fclose ( output );
|
||||
end;
|
||||
|
||||
|
||||
|
||||
-- This example will create the same spreadsheet but will
|
||||
-- send in a pre-parsed cursor instead
|
||||
|
||||
declare
|
||||
l_cursor number := dbms_sql.open_cursor;
|
||||
output utl_file.file_type;
|
||||
begin
|
||||
output := utl_file.fopen( 'DEVTEST_TEMP_DIR', 'emp2.slk', 'w',32000 );
|
||||
|
||||
dbms_sql.parse( l_cursor, 'select empno id, ename employee, sal Salary, comm commission from emp where job = ''MANAGER'' and sal > 2000', dbms_sql.native );
|
||||
|
||||
sylk_util_pkg.show(
|
||||
p_file => output ,
|
||||
p_cursor => l_cursor,
|
||||
p_sum_column => sylk_util_pkg.owaSylkArray( 'N', 'N', 'Y', 'Y' ),
|
||||
p_show_grid => 'NO' );
|
||||
|
||||
dbms_sql.close_cursor( l_cursor );
|
||||
utl_file.fflush ( output );
|
||||
utl_file.fclose ( output );
|
||||
|
||||
end;
|
||||
23
demos/t_soap_envelope_demo.sql
Executable file
23
demos/t_soap_envelope_demo.sql
Executable file
@ -0,0 +1,23 @@
|
||||
declare
|
||||
l_env t_soap_envelope;
|
||||
l_xml xmltype;
|
||||
begin
|
||||
|
||||
-- the t_soap_envelope type can be used to generate a typical SOAP request envelope with just a few lines of code
|
||||
|
||||
debug_pkg.debug_on;
|
||||
|
||||
l_env := t_soap_envelope ('http://www.webserviceX.NET', 'globalweather.asmx', 'GetWeather', 'xmlns="http://www.webserviceX.NET"');
|
||||
|
||||
l_env.add_param ('CityName', 'Stockholm');
|
||||
l_env.add_param ('CountryName', 'Sweden');
|
||||
|
||||
l_xml := flex_ws_api.make_request (p_url => l_env.service_url, p_action => l_env.soap_action, p_envelope => l_env.envelope);
|
||||
|
||||
-- if Apex 4+ is available:
|
||||
-- l_xml := apex_web_service.make_request (p_url => l_env.service_url, p_action => l_env.soap_action, p_envelope => l_env.envelope);
|
||||
|
||||
debug_pkg.print (l_xml);
|
||||
|
||||
end;
|
||||
|
||||
59
demos/uri_template_util_pkg_demo.sql
Executable file
59
demos/uri_template_util_pkg_demo.sql
Executable file
@ -0,0 +1,59 @@
|
||||
-- get URI by substituting values for placeholders
|
||||
|
||||
select uri_template_util_pkg.expand('/employees/{department}/{id}', t_str_array('Accounting', '1234'))
|
||||
from dual
|
||||
|
||||
|
||||
-- determine which URI template matches the URI
|
||||
-- note: put most specific URI templates first
|
||||
|
||||
select uri_template_util_pkg.match('/employees/Accounting/1234', t_str_array('/employees/{department}/list',
|
||||
'/employees/{department}/{id}',
|
||||
'/employees/{id}')
|
||||
) as the_first_match
|
||||
from dual
|
||||
|
||||
|
||||
-- get name/value pairs from URI
|
||||
|
||||
declare
|
||||
l_values uri_template_util_pkg.t_dictionary;
|
||||
l_name varchar2(255);
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_values := uri_template_util_pkg.parse ('/employees/{department}/{id}', '/employees/Accounting/1234');
|
||||
l_name := l_values.first;
|
||||
while l_name is not null loop
|
||||
debug_pkg.printf('%1 = %2', l_name, l_values(l_name));
|
||||
l_name := l_values.next(l_name);
|
||||
end loop;
|
||||
end;
|
||||
|
||||
|
||||
-- combined example
|
||||
-- in real-world usage, you would probably get the URI from an actual web request (for example through mod_plsql)
|
||||
|
||||
declare
|
||||
l_uri varchar2(255);
|
||||
l_template varchar2(255);
|
||||
l_values uri_template_util_pkg.t_dictionary;
|
||||
l_name varchar2(255);
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
|
||||
l_uri := uri_template_util_pkg.expand('/employees/{department}/{id}', t_str_array('Accounting', '1234'));
|
||||
debug_pkg.printf('expanded uri = %1', l_uri);
|
||||
|
||||
l_template := uri_template_util_pkg.match(l_uri, t_str_array('/employees/{department}/list',
|
||||
'/employees/{department}/{id}',
|
||||
'/employees/{id}'));
|
||||
debug_pkg.printf('the uri %1 matches the template %2', l_uri, l_template);
|
||||
|
||||
l_values := uri_template_util_pkg.parse (l_template, l_uri);
|
||||
l_name := l_values.first;
|
||||
while l_name is not null loop
|
||||
debug_pkg.printf('%1 = %2', l_name, l_values(l_name));
|
||||
l_name := l_values.next(l_name);
|
||||
end loop;
|
||||
end;
|
||||
|
||||
13
demos/utl_file_nonstandard_demo.sql
Executable file
13
demos/utl_file_nonstandard_demo.sql
Executable file
@ -0,0 +1,13 @@
|
||||
-- get list of files in specified directory
|
||||
|
||||
declare
|
||||
l_file_list sys.utl_file_nonstandard.t_file_list;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_file_list := sys.utl_file_nonstandard.get_file_list('DEVTEST_TEMP_DIR', '*.xls');
|
||||
for i in 1 .. l_file_list.count loop
|
||||
debug_pkg.printf('File %1, file name = %2', i, l_file_list(i));
|
||||
end loop;
|
||||
end;
|
||||
|
||||
|
||||
39
demos/validation_util_pkg_demo.sql
Executable file
39
demos/validation_util_pkg_demo.sql
Executable file
@ -0,0 +1,39 @@
|
||||
-- email validation
|
||||
|
||||
declare
|
||||
l_validation boolean;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_validation := validation_util_pkg.is_valid_email ('someone@somewhere.net');
|
||||
debug_pkg.print('validation result (should be true)', l_validation);
|
||||
l_validation := validation_util_pkg.is_valid_email ('someone');
|
||||
debug_pkg.print('validation result (should be false)', l_validation);
|
||||
l_validation := validation_util_pkg.is_valid_email ('someone@');
|
||||
debug_pkg.print('validation result (should be false)', l_validation);
|
||||
l_validation := validation_util_pkg.is_valid_email ('someone@sdfsdf');
|
||||
debug_pkg.print('validation result (should be false)', l_validation);
|
||||
l_validation := validation_util_pkg.is_valid_email ('someone@sfdsf.safdsfsf');
|
||||
debug_pkg.print('validation result (should be false)', l_validation);
|
||||
l_validation := validation_util_pkg.is_valid_email ('someone@dsfsfd.sdf;sdfsfs');
|
||||
debug_pkg.print('validation result (should be false)', l_validation);
|
||||
end;
|
||||
|
||||
|
||||
|
||||
-- email list validation
|
||||
|
||||
|
||||
declare
|
||||
l_validation boolean;
|
||||
begin
|
||||
debug_pkg.debug_on;
|
||||
l_validation := validation_util_pkg.is_valid_email_list ('someone@somewhere.net');
|
||||
debug_pkg.print('validation result (should be true)', l_validation);
|
||||
l_validation := validation_util_pkg.is_valid_email_list ('user1@somewhere.net;user2@somewhere.net');
|
||||
debug_pkg.print('validation result (should be true)', l_validation);
|
||||
l_validation := validation_util_pkg.is_valid_email_list ('sdfsff dsfsfsdfs ; sdfsf @');
|
||||
debug_pkg.print('validation result (should be false)', l_validation);
|
||||
l_validation := validation_util_pkg.is_valid_email_list ('user1@somewhere.net;user2@somewhere.net;sdfsff');
|
||||
debug_pkg.print('validation result (should be false)', l_validation);
|
||||
end;
|
||||
|
||||
5
demos/web_util_pkg_demo.sql
Executable file
5
demos/web_util_pkg_demo.sql
Executable file
@ -0,0 +1,5 @@
|
||||
-- get domain name from email address
|
||||
|
||||
select web_util_pkg.get_email_domain('someone@somewhere.net')
|
||||
from dual
|
||||
|
||||
37
demos/xlsx_builder_pkg_demo.sql
Executable file
37
demos/xlsx_builder_pkg_demo.sql
Executable file
@ -0,0 +1,37 @@
|
||||
-- see http://technology.amis.nl/blog/10995/create-an-excel-file-with-plsql
|
||||
|
||||
begin
|
||||
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( 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' ) );
|
||||
xlsx_builder_pkg.cell( 2, 3, 33 );
|
||||
xlsx_builder_pkg.hyperlink( 1, 6, 'http://www.amis.nl', 'Amis site' );
|
||||
xlsx_builder_pkg.cell( 1, 7, 'Some merged cells', p_alignment => xlsx_builder_pkg.get_alignment( p_horizontal => 'center' ) );
|
||||
xlsx_builder_pkg.mergecells( 1, 7, 3, 7 );
|
||||
for i in 1 .. 5
|
||||
loop
|
||||
xlsx_builder_pkg.comment( 3, i + 3, 'Row ' || (i+3), 'Anton' );
|
||||
end loop;
|
||||
xlsx_builder_pkg.new_sheet;
|
||||
xlsx_builder_pkg.set_row( 1, p_fillId => xlsx_builder_pkg.get_fill( 'solid', 'FFFF0000' ) ) ;
|
||||
for i in 1 .. 5
|
||||
loop
|
||||
xlsx_builder_pkg.cell( 1, i, i );
|
||||
xlsx_builder_pkg.cell( 2, i, i * 3 );
|
||||
xlsx_builder_pkg.cell( 3, i, 'x ' || i * 3 );
|
||||
end loop;
|
||||
xlsx_builder_pkg.query2sheet( 'select rownum, x.*
|
||||
, case when mod( rownum, 2 ) = 0 then rownum * 3 end demo
|
||||
, case when mod( rownum, 2 ) = 1 then ''demo '' || rownum end demo2 from dual x connect by rownum <= 5' );
|
||||
xlsx_builder_pkg.save( 'MY_DIR', 'my.xlsx' );
|
||||
end;
|
||||
/
|
||||
|
||||
|
||||
|
||||
69
demos/zip_util_pkg_demo.sql
Executable file
69
demos/zip_util_pkg_demo.sql
Executable file
@ -0,0 +1,69 @@
|
||||
-- create a zip file
|
||||
|
||||
declare
|
||||
l_file1 blob;
|
||||
l_file2 blob;
|
||||
l_zip blob;
|
||||
|
||||
begin
|
||||
|
||||
l_file1 := http_util_pkg.get_blob_from_url ('http://www.oracleimg.com/admin/images/ocom/hp/oralogo_small.gif');
|
||||
l_file2 := http_util_pkg.get_blob_from_url ('http://www.oracle.com/ocom/groups/public/@ocom/documents/webcontent/oracle-footer-tagline.gif');
|
||||
|
||||
zip_util_pkg.add_file (l_zip, 'some_folder/some_filename.gif', l_file1);
|
||||
zip_util_pkg.add_file (l_zip, 'some_other_filename.gif', l_file2);
|
||||
zip_util_pkg.finish_zip (l_zip);
|
||||
|
||||
zip_util_pkg.save_zip (l_zip, 'DEVTEST_TEMP_DIR', 'my_zip_file.zip');
|
||||
|
||||
end;
|
||||
|
||||
|
||||
-- unzip files, list file names only
|
||||
|
||||
declare
|
||||
fl zip_util_pkg.t_file_list;
|
||||
begin
|
||||
fl := zip_util_pkg.get_file_list( 'DEVTEST_TEMP_DIR', 'my_zip_file.zip' );
|
||||
if fl.count() > 0
|
||||
then
|
||||
for i in fl.first .. fl.last
|
||||
loop
|
||||
dbms_output.put_line( fl( i ) );
|
||||
end loop;
|
||||
end if;
|
||||
end;
|
||||
/
|
||||
|
||||
-- unzip files, retrieve file into blob, print info, and save it to disk
|
||||
|
||||
declare
|
||||
fl zip_util_pkg.t_file_list;
|
||||
l_file blob;
|
||||
begin
|
||||
fl := zip_util_pkg.get_file_list( 'DEVTEST_TEMP_DIR', 'my_zip_file.zip' );
|
||||
if fl.count() > 0
|
||||
then
|
||||
for i in fl.first .. fl.last
|
||||
loop
|
||||
dbms_output.put_line ( fl( i ) );
|
||||
l_file := zip_util_pkg.GET_FILE( 'DEVTEST_TEMP_DIR', 'my_zip_file.zip', fl( i ) );
|
||||
dbms_output.put_line( ' ' || nvl( dbms_lob.getlength( l_file ), -1 ) );
|
||||
file_util_pkg.save_blob_to_file ('DEVTEST_TEMP_DIR', 'unzipped_file_' || fl(i), l_file);
|
||||
end loop;
|
||||
end if;
|
||||
end;
|
||||
/
|
||||
|
||||
-- Office 2007 files (.docx, .xlsx, etc) are in fact zip files, with contents stored as xml files
|
||||
-- we can extract the xml content from the file and query it
|
||||
|
||||
-- see also ooxml_util_pkg
|
||||
|
||||
begin
|
||||
file_util_pkg.save_blob_to_file ('DEVTEST_TEMP_DIR', 'my_word_doc.docx', http_util_pkg.get_blob_from_url ('http://foobar.example/document1.docx'));
|
||||
end;
|
||||
|
||||
select extractvalue( column_value, '*/text()')
|
||||
from table( xmlsequence( xmltype( zip_util_pkg.get_file( 'DEVTEST_TEMP_DIR', 'my_word_doc.docx', 'word/document.xml' ), nls_charset_id( 'UTF8' )).extract( 'w:document/w:body/w:p/w:r/w:t', 'xmlns:w="http://schemas.openxmlformats.org/wordprocessingml/2006/main"' )))
|
||||
|
||||
33
doc/changelog.txt
Executable file
33
doc/changelog.txt
Executable file
@ -0,0 +1,33 @@
|
||||
|
||||
Version 1.7.0
|
||||
=============
|
||||
- Split installation script into various modules (core, xml, amazon, microsoft, etc.)
|
||||
- Added icalendar_util_pkg (based on sample code by Dan McGhan and others)
|
||||
- Added image_util_pkg (based on image parsing code in Anton Scheffer's AS_PDF3 package)
|
||||
- Added uri_template_util_pkg
|
||||
- Major enhancements to amazon_aws_s3_pkg (thanks to Jeffrey Kemp, see http://code.google.com/p/plsql-utils/issues/detail?id=14 ++)
|
||||
- Minor enhancements to datapump_util_pkg
|
||||
- Minor enhancements to datapump_cloud_pkg
|
||||
- Minor enhancements to date_util_pkg
|
||||
- Minor enhancements to owa_util_pkg
|
||||
- Minor enhancements to string_util_pkg
|
||||
- Bug fix for csv_util_pkg, see http://code.google.com/p/plsql-utils/issues/detail?id=13
|
||||
|
||||
Version 1.6.0
|
||||
=============
|
||||
|
||||
- Added as_pdf3 (by Anton Scheffer, see /extras)
|
||||
- Added datapump_util_pkg
|
||||
- Added datapump_cloud_pkg (see /demos)
|
||||
- Added flex_ws_api (by Jason Straub)
|
||||
- Added ms_ews_util_pkg
|
||||
- Added validation_util_pkg
|
||||
- Added web_util_pkg
|
||||
- Minor enhancements to ooxml_util_pkg
|
||||
- Minor enhancements to owa_util_pkg
|
||||
- Minor enhancements to rss_util_pkg
|
||||
- Minor enhancements to string_util_pkg
|
||||
- Minor enhancements to utl_file_nonstandard (see /extras)
|
||||
- Bug fixes for date_util_pkg
|
||||
- Bug fixes for zip_util_pkg
|
||||
|
||||
31
doc/license.txt
Executable file
31
doc/license.txt
Executable file
@ -0,0 +1,31 @@
|
||||
This license applies to all source code and examples in this software distribution,
|
||||
UNLESS a specific file contains a different license, copyright notice, or attribution to another author.
|
||||
|
||||
=============
|
||||
|
||||
The Alexandria Utility Library for PL/SQL (http://code.google.com/p/plsql-utils) is released as open source under the BSD license:
|
||||
|
||||
http://www.opensource.org/licenses/bsd-license.php
|
||||
|
||||
|
||||
Copyright (c) 2010-2012, MORTEN BRATEN (http://ora-00001.blogspot.com)
|
||||
All rights reserved.
|
||||
|
||||
Redistribution and use in source and binary forms, with or without modification, are permitted provided that the following conditions are met:
|
||||
|
||||
Redistributions of source code must retain the above copyright notice, this list of conditions and the following disclaimer.
|
||||
|
||||
Redistributions in binary form must reproduce the above copyright notice, this list of conditions and the following disclaimer in the documentation and/or other materials provided with the distribution.
|
||||
|
||||
The names of the contributors may not be used to endorse or promote products derived from this software without specific prior written permission.
|
||||
|
||||
THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND ANY EXPRESS OR IMPLIED WARRANTIES,
|
||||
INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE
|
||||
ARE DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE FOR ANY DIRECT, INDIRECT,
|
||||
INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE
|
||||
GOODS OR SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON ANY
|
||||
THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE)
|
||||
ARISING IN ANY WAY OUT OF THE USE OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
|
||||
|
||||
|
||||
|
||||
20
doc/readme.txt
Executable file
20
doc/readme.txt
Executable file
@ -0,0 +1,20 @@
|
||||
|
||||
The Alexandria Utility Library for PL/SQL
|
||||
=========================================
|
||||
|
||||
This library is a collection of utility packages for PL/SQL,
|
||||
as well as links to selected libraries hosted and maintained elsewhere.
|
||||
|
||||
For more details and the latest source code, see
|
||||
|
||||
http://code.google.com/p/plsql-utils/
|
||||
|
||||
Also check out the "demos" folder for some examples.
|
||||
|
||||
This is (and will always be!) a work in progress... :-)
|
||||
|
||||
Regards,
|
||||
Morten Braten
|
||||
Chief Scribe of the Library
|
||||
http://ora-00001.blogspot.com
|
||||
|
||||
3431
extras/as_pdf3.pkb
Executable file
3431
extras/as_pdf3.pkb
Executable file
File diff suppressed because it is too large
Load Diff
295
extras/as_pdf3.pks
Executable file
295
extras/as_pdf3.pks
Executable file
@ -0,0 +1,295 @@
|
||||
CREATE OR REPLACE package as_pdf3
|
||||
is
|
||||
/**********************************************
|
||||
**
|
||||
** Author: Anton Scheffer
|
||||
** Date: 11-04-2012
|
||||
** Website: http://technology.amis.nl
|
||||
** See also: http://technology.amis.nl/?p=17718
|
||||
**
|
||||
** Changelog:
|
||||
** Date: 16-04-2012
|
||||
** changed code for parse_png
|
||||
** Date: 15-04-2012
|
||||
** only dbms_lob.freetemporary for temporary blobs
|
||||
** Date: 11-04-2012
|
||||
** Initial release of as_pdf3
|
||||
**
|
||||
******************************************************************************
|
||||
******************************************************************************
|
||||
Copyright (C) 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.
|
||||
|
||||
******************************************************************************
|
||||
******************************************** */
|
||||
--
|
||||
c_get_page_width constant pls_integer := 0;
|
||||
c_get_page_height constant pls_integer := 1;
|
||||
c_get_margin_top constant pls_integer := 2;
|
||||
c_get_margin_right constant pls_integer := 3;
|
||||
c_get_margin_bottom constant pls_integer := 4;
|
||||
c_get_margin_left constant pls_integer := 5;
|
||||
c_get_x constant pls_integer := 6;
|
||||
c_get_y constant pls_integer := 7;
|
||||
c_get_fontsize constant pls_integer := 8;
|
||||
c_get_current_font constant pls_integer := 9;
|
||||
--
|
||||
function file2blob( p_dir varchar2, p_file_name varchar2 )
|
||||
return blob;
|
||||
--
|
||||
function conv2uu( p_value number, p_unit varchar2 )
|
||||
return number;
|
||||
--
|
||||
procedure set_page_size
|
||||
( p_width number
|
||||
, p_height number
|
||||
, p_unit varchar2 := 'cm'
|
||||
);
|
||||
--
|
||||
procedure set_page_format( p_format varchar2 := 'A4' );
|
||||
--
|
||||
procedure set_page_orientation( p_orientation varchar2 := 'PORTRAIT' );
|
||||
--
|
||||
procedure set_margins
|
||||
( p_top number := null
|
||||
, p_left number := null
|
||||
, p_bottom number := null
|
||||
, p_right number := null
|
||||
, p_unit varchar2 := 'cm'
|
||||
);
|
||||
--
|
||||
procedure set_info
|
||||
( p_title varchar2 := null
|
||||
, p_author varchar2 := null
|
||||
, p_subject varchar2 := null
|
||||
, p_keywords varchar2 := null
|
||||
);
|
||||
--
|
||||
procedure init;
|
||||
--
|
||||
function get_pdf
|
||||
return blob;
|
||||
--
|
||||
procedure save_pdf
|
||||
( p_dir varchar2 := 'MY_DIR'
|
||||
, p_filename varchar2 := 'my.pdf'
|
||||
, p_freeblob boolean := true
|
||||
);
|
||||
--
|
||||
procedure txt2page( p_txt varchar2 );
|
||||
--
|
||||
procedure put_txt( p_x number, p_y number, p_txt varchar2, p_degrees_rotation number := null );
|
||||
--
|
||||
function str_len( p_txt varchar2 )
|
||||
return number;
|
||||
--
|
||||
procedure write
|
||||
( p_txt in varchar2
|
||||
, p_x in number := null
|
||||
, p_y in number := null
|
||||
, p_line_height in number := null
|
||||
, p_start in number := null -- left side of the available text box
|
||||
, p_width in number := null -- width of the available text box
|
||||
, p_alignment in varchar2 := null
|
||||
);
|
||||
--
|
||||
procedure set_font
|
||||
( p_index pls_integer
|
||||
, p_fontsize_pt number
|
||||
, p_output_to_doc boolean := true
|
||||
);
|
||||
--
|
||||
function set_font
|
||||
( p_fontname varchar2
|
||||
, p_fontsize_pt number
|
||||
, p_output_to_doc boolean := true
|
||||
)
|
||||
return pls_integer;
|
||||
--
|
||||
procedure set_font
|
||||
( p_fontname varchar2
|
||||
, p_fontsize_pt number
|
||||
, p_output_to_doc boolean := true
|
||||
);
|
||||
--
|
||||
function set_font
|
||||
( p_family varchar2
|
||||
, p_style varchar2 := 'N'
|
||||
, p_fontsize_pt number := null
|
||||
, p_output_to_doc boolean := true
|
||||
)
|
||||
return pls_integer;
|
||||
--
|
||||
procedure set_font
|
||||
( p_family varchar2
|
||||
, p_style varchar2 := 'N'
|
||||
, p_fontsize_pt number := null
|
||||
, p_output_to_doc boolean := true
|
||||
);
|
||||
--
|
||||
procedure new_page;
|
||||
--
|
||||
function load_ttf_font
|
||||
( p_font blob
|
||||
, p_encoding varchar2 := 'WINDOWS-1252'
|
||||
, p_embed boolean := false
|
||||
, p_compress boolean := true
|
||||
, p_offset number := 1
|
||||
)
|
||||
return pls_integer;
|
||||
--
|
||||
procedure load_ttf_font
|
||||
( p_font blob
|
||||
, p_encoding varchar2 := 'WINDOWS-1252'
|
||||
, p_embed boolean := false
|
||||
, p_compress boolean := true
|
||||
, p_offset number := 1
|
||||
);
|
||||
--
|
||||
function load_ttf_font
|
||||
( p_dir varchar2 := 'MY_FONTS'
|
||||
, p_filename varchar2 := 'BAUHS93.TTF'
|
||||
, p_encoding varchar2 := 'WINDOWS-1252'
|
||||
, p_embed boolean := false
|
||||
, p_compress boolean := true
|
||||
)
|
||||
return pls_integer;
|
||||
--
|
||||
procedure load_ttf_font
|
||||
( p_dir varchar2 := 'MY_FONTS'
|
||||
, p_filename varchar2 := 'BAUHS93.TTF'
|
||||
, p_encoding varchar2 := 'WINDOWS-1252'
|
||||
, p_embed boolean := false
|
||||
, p_compress boolean := true
|
||||
);
|
||||
--
|
||||
procedure load_ttc_fonts
|
||||
( p_ttc blob
|
||||
, p_encoding varchar2 := 'WINDOWS-1252'
|
||||
, p_embed boolean := false
|
||||
, p_compress boolean := true
|
||||
);
|
||||
--
|
||||
procedure load_ttc_fonts
|
||||
( p_dir varchar2 := 'MY_FONTS'
|
||||
, p_filename varchar2 := 'CAMBRIA.TTC'
|
||||
, p_encoding varchar2 := 'WINDOWS-1252'
|
||||
, p_embed boolean := false
|
||||
, p_compress boolean := true
|
||||
);
|
||||
--
|
||||
procedure set_color( p_rgb varchar2 := '000000' );
|
||||
--
|
||||
procedure set_color
|
||||
( p_red number := 0
|
||||
, p_green number := 0
|
||||
, p_blue number := 0
|
||||
);
|
||||
--
|
||||
procedure set_bk_color( p_rgb varchar2 := 'ffffff' );
|
||||
--
|
||||
procedure set_bk_color
|
||||
( p_red number := 0
|
||||
, p_green number := 0
|
||||
, p_blue number := 0
|
||||
);
|
||||
--
|
||||
procedure horizontal_line
|
||||
( p_x in number
|
||||
, p_y in number
|
||||
, p_width in number
|
||||
, p_line_width in number := 0.5
|
||||
, p_line_color in varchar2 := '000000'
|
||||
);
|
||||
--
|
||||
procedure vertical_line
|
||||
( p_x in number
|
||||
, p_y in number
|
||||
, p_height in number
|
||||
, p_line_width in number := 0.5
|
||||
, p_line_color in varchar2 := '000000'
|
||||
);
|
||||
--
|
||||
procedure rect
|
||||
( p_x in number
|
||||
, p_y in number
|
||||
, p_width in number
|
||||
, p_height in number
|
||||
, p_line_color in varchar2 := null
|
||||
, p_fill_color in varchar2 := null
|
||||
, p_line_width in number := 0.5
|
||||
);
|
||||
--
|
||||
function get( p_what in pls_integer )
|
||||
return number;
|
||||
--
|
||||
procedure put_image
|
||||
( p_img blob
|
||||
, p_x number
|
||||
, p_y number
|
||||
, p_width number := null
|
||||
, p_height number := null
|
||||
, p_align varchar2 := 'center'
|
||||
, p_valign varchar2 := 'top'
|
||||
);
|
||||
--
|
||||
procedure put_image
|
||||
( p_dir varchar2
|
||||
, p_file_name varchar2
|
||||
, p_x number
|
||||
, p_y number
|
||||
, p_width number := null
|
||||
, p_height number := null
|
||||
, p_align varchar2 := 'center'
|
||||
, p_valign varchar2 := 'top'
|
||||
);
|
||||
--
|
||||
procedure put_image
|
||||
( p_url varchar2
|
||||
, p_x number
|
||||
, p_y number
|
||||
, p_width number := null
|
||||
, p_height number := null
|
||||
, p_align varchar2 := 'center'
|
||||
, p_valign varchar2 := 'top'
|
||||
);
|
||||
--
|
||||
procedure set_page_proc( p_src clob );
|
||||
--
|
||||
type tp_col_widths is table of number;
|
||||
type tp_headers is table of varchar2(32767);
|
||||
--
|
||||
procedure query2table
|
||||
( p_query varchar2
|
||||
, p_widths tp_col_widths := null
|
||||
, p_headers tp_headers := null
|
||||
);
|
||||
--
|
||||
$IF not DBMS_DB_VERSION.VER_LE_10 $THEN
|
||||
procedure refcursor2table
|
||||
( p_rc sys_refcursor
|
||||
, p_widths tp_col_widths := null
|
||||
, p_headers tp_headers := null
|
||||
);
|
||||
--
|
||||
$END
|
||||
end as_pdf3;
|
||||
/
|
||||
|
||||
241
extras/as_pdf3_demo.sql
Executable file
241
extras/as_pdf3_demo.sql
Executable file
@ -0,0 +1,241 @@
|
||||
|
||||
-- see http://technology.amis.nl/2012/04/11/generating-a-pdf-document-with-some-plsql-as_pdf_mini-as_pdf3/
|
||||
|
||||
begin
|
||||
as_pdf3.init;
|
||||
as_pdf3.write( 'Minimal usage' );
|
||||
as_pdf3.save_pdf;
|
||||
end;
|
||||
--
|
||||
begin
|
||||
as_pdf3.init;
|
||||
as_pdf3.write( 'Some text with a newline-character included at this "
|
||||
" place.' );
|
||||
as_pdf3.write( 'Normally text written with as_pdf3.write() is appended after the previous text. But the text wraps automaticly to a new line.' );
|
||||
as_pdf3.write( 'But you can place your text at any place', -1, 700 );
|
||||
as_pdf3.write( 'you want', 100, 650 );
|
||||
as_pdf3.write( 'You can even align it, left, right, or centered', p_y => 600, p_alignment => 'right' );
|
||||
as_pdf3.save_pdf;
|
||||
end;
|
||||
--
|
||||
begin
|
||||
as_pdf3.init;
|
||||
as_pdf3.write( 'The 14 standard PDF-fonts and the WINDOWS-1252 encoding.' );
|
||||
as_pdf3.set_font( 'helvetica' );
|
||||
as_pdf3.write( 'helvetica, normal: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, 700 );
|
||||
as_pdf3.set_font( 'helvetica', 'I' );
|
||||
as_pdf3.write( 'helvetica, italic: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
as_pdf3.set_font( 'helvetica', 'b' );
|
||||
as_pdf3.write( 'helvetica, bold: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
as_pdf3.set_font( 'helvetica', 'BI' );
|
||||
as_pdf3.write( 'helvetica, bold italic: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
as_pdf3.set_font( 'times' );
|
||||
as_pdf3.write( 'times, normal: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, 625 );
|
||||
as_pdf3.set_font( 'times', 'I' );
|
||||
as_pdf3.write( 'times, italic: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
as_pdf3.set_font( 'times', 'b' );
|
||||
as_pdf3.write( 'times, bold: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
as_pdf3.set_font( 'times', 'BI' );
|
||||
as_pdf3.write( 'times, bold italic: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
as_pdf3.set_font( 'courier' );
|
||||
as_pdf3.write( 'courier, normal: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, 550 );
|
||||
as_pdf3.set_font( 'courier', 'I' );
|
||||
as_pdf3.write( 'courier, italic: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
as_pdf3.set_font( 'courier', 'b' );
|
||||
as_pdf3.write( 'courier, bold: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
as_pdf3.set_font( 'courier', 'BI' );
|
||||
as_pdf3.write( 'courier, bold italic: ' || 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
--
|
||||
as_pdf3.set_font( 'courier' );
|
||||
as_pdf3.write( 'symbol:', -1, 475 );
|
||||
as_pdf3.set_font( 'symbol' );
|
||||
as_pdf3.write( 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
as_pdf3.set_font( 'courier' );
|
||||
as_pdf3.write( 'zapfdingbats:', -1, -1 );
|
||||
as_pdf3.set_font( 'zapfdingbats' );
|
||||
as_pdf3.write( 'The quick brown fox jumps over the lazy dog. 1234567890', -1, -1 );
|
||||
--
|
||||
as_pdf3.set_font( 'times', 'N', 20 );
|
||||
as_pdf3.write( 'times, normal with fontsize 20pt', -1, 400 );
|
||||
as_pdf3.set_font( 'times', 'N', 6 );
|
||||
as_pdf3.write( 'times, normal with fontsize 5pt', -1, -1 );
|
||||
as_pdf3.save_pdf;
|
||||
end;
|
||||
--
|
||||
declare
|
||||
x pls_integer;
|
||||
begin
|
||||
as_pdf3.init;
|
||||
as_pdf3.write( 'But others fonts and encodings are possible using TrueType fontfiles.' );
|
||||
x := as_pdf3.load_ttf_font( 'MY_FONTS', 'refsan.ttf', 'CID', p_compress => false );
|
||||
as_pdf3.set_font( x, 12 );
|
||||
as_pdf3.write( 'The Windows MSReference SansSerif font contains a lot of encodings, for instance', -1, 700 );
|
||||
as_pdf3.set_font( x, 15 );
|
||||
as_pdf3.write( 'Albanian: Kush mund të lexoni këtë diçka si kjo', -1, -1 );
|
||||
as_pdf3.write( 'Croatic: Tko može citati to nešto poput ovoga', -1, -1 );
|
||||
as_pdf3.write( 'Russian: ??? ????? ????????? ??? ???-?? ????? ?????', -1, -1);
|
||||
as_pdf3.write( 'Greek: ????? µp??e? ?a d?aß?se? a?t? t? ??t? sa? a?t?', -1, -1 );
|
||||
--
|
||||
as_pdf3.set_font( 'helvetica', 12 );
|
||||
as_pdf3.write( 'Or by using a TrueType collection file (ttc).', -1, 600 );
|
||||
as_pdf3.load_ttc_fonts( 'MY_FONTS', 'cambria.ttc', p_embed => true, p_compress => false );
|
||||
as_pdf3.set_font( 'cambria', 15 ); -- font family
|
||||
as_pdf3.write( 'Anton, testing 1,2,3 with Cambria', -1, -1 );
|
||||
as_pdf3.set_font( 'CambriaMT', 15 ); -- fontname
|
||||
as_pdf3.write( 'Anton, testing 1,2,3 with CambriaMath', -1, -1 );
|
||||
as_pdf3.save_pdf;
|
||||
end;
|
||||
--
|
||||
begin
|
||||
as_pdf3.init;
|
||||
for i in 1 .. 10
|
||||
loop
|
||||
as_pdf3.horizontal_line( 30, 700 - i * 15, 100, i );
|
||||
end loop;
|
||||
for i in 1 .. 10
|
||||
loop
|
||||
as_pdf3.vertical_line( 150 + i * 15, 700, 100, i );
|
||||
end loop;
|
||||
for i in 0 .. 255
|
||||
loop
|
||||
as_pdf3.horizontal_line( 330, 700 - i, 100, 2, p_line_color => to_char( i, 'fm0x' ) || to_char( i, 'fm0x' ) || to_char( i, 'fm0x' ) );
|
||||
end loop;
|
||||
as_pdf3.save_pdf;
|
||||
end;
|
||||
--
|
||||
declare
|
||||
t_logo varchar2(32767) :=
|
||||
'/9j/4AAQSkZJRgABAQEAYABgAAD/2wBDAAgGBgcGBQgHBwcJCQgKDBQNDAsLDBkS' ||
|
||||
'Ew8UHRofHh0aHBwgJC4nICIsIxwcKDcpLDAxNDQ0Hyc5PTgyPC4zNDL/2wBDAQkJ' ||
|
||||
'CQwLDBgNDRgyIRwhMjIyMjIyMjIyMjIyMjIyMjIyMjIyMjIyMjIyMjIyMjIyMjIy' ||
|
||||
'MjIyMjIyMjIyMjIyMjL/wAARCABqAJYDASIAAhEBAxEB/8QAHwAAAQUBAQEBAQEA' ||
|
||||
'AAAAAAAAAAECAwQFBgcICQoL/8QAtRAAAgEDAwIEAwUFBAQAAAF9AQIDAAQRBRIh' ||
|
||||
'MUEGE1FhByJxFDKBkaEII0KxwRVS0fAkM2JyggkKFhcYGRolJicoKSo0NTY3ODk6' ||
|
||||
'Q0RFRkdISUpTVFVWV1hZWmNkZWZnaGlqc3R1dnd4eXqDhIWGh4iJipKTlJWWl5iZ' ||
|
||||
'mqKjpKWmp6ipqrKztLW2t7i5usLDxMXGx8jJytLT1NXW19jZ2uHi4+Tl5ufo6erx' ||
|
||||
'8vP09fb3+Pn6/8QAHwEAAwEBAQEBAQEBAQAAAAAAAAECAwQFBgcICQoL/8QAtREA' ||
|
||||
'AgECBAQDBAcFBAQAAQJ3AAECAxEEBSExBhJBUQdhcRMiMoEIFEKRobHBCSMzUvAV' ||
|
||||
'YnLRChYkNOEl8RcYGRomJygpKjU2Nzg5OkNERUZHSElKU1RVVldYWVpjZGVmZ2hp' ||
|
||||
'anN0dXZ3eHl6goOEhYaHiImKkpOUlZaXmJmaoqOkpaanqKmqsrO0tba3uLm6wsPE' ||
|
||||
'xcbHyMnK0tPU1dbX2Nna4uPk5ebn6Onq8vP09fb3+Pn6/9oADAMBAAIRAxEAPwD3' ||
|
||||
'+iiigAooooAKKKKACiiigAooooAKKKKACiiigAooooAKKKKACiiigAoorifiX4pk' ||
|
||||
'8PaCILR9t9eExxsOqL/E315AHuaUmkrs1oUZVqipw3ZU8X/FCz0KeSw02Jb2+Thy' ||
|
||||
'WxHGfQkdT7D8686ufih4suGJW/jgXssUC8fnk1ydvbz3lzHb28bzTyttRF5LMa7H' ||
|
||||
'Uvh+3hvRI9T1+7kUPIsf2ezUMykgnlmIHbtXI5znqtj66ng8DhFGFRJyffVv5Fnw' ||
|
||||
'r8QfEEvinTodR1N5rSaYRyIyIAd3A5A9SK7X4qeINV0Gz019LvGtmlkcOVVTkADH' ||
|
||||
'UGvNdDsPDepa7ZWdtPrMU8syiN3EWFbqCcfSu3+NXGnaOM5/ev8A+giqi5ezepy1' ||
|
||||
'6NF4+koxsne6scronxO1+01i2l1K/e6st2Joyij5T1IwByOv4V75BPHc28c8Lh45' ||
|
||||
'FDKynIIPINfJleheGPiPJong+802Ul7uEYsCRkYbsfZev04pUqttJF5rlSqKM6Eb' ||
|
||||
'PZpGv8RfiFf2etDTNDu/I+zf8fEqqG3Of4eQen8z7VB8O/GGv6x4vhs9Q1J57don' ||
|
||||
'YoUUZIHHQV5fI7yyNJIxd3JZmY5JJ6k12nwo/wCR8t/+uEn8qUajlM6K+Ao0MFJc' ||
|
||||
'qbS363O1+KviTWNBuNMXS71rYTLIZAqqd2NuOoPqayvht4u17WvFf2TUdRe4g+zu' ||
|
||||
'+woo5BXB4HuaX42f8fOj/wC7L/Naw/hH/wAjv/26yfzWqcn7W1zjpUKTytzcVez1' ||
|
||||
'sdt8QviJN4euhpelJG16VDSyuMiIHoMdz3rzZviN4tZif7YkHsIkx/6DTPiAkqeO' ||
|
||||
'9WE2dxlBXP8Ad2jH6VJ4H8LWfizUp7S51FrV40DoiKC0nPOM+nH51MpTlOyOvDYX' ||
|
||||
'C4fCKrUinpdu1zovAfjvXL7xfZ2ep6i89tOGTayKPmxkHgD0/WvbK83074RWWman' ||
|
||||
'a30Wr3Zkt5VlUFVwSDnHSvQZ7u2tU3XE8cSju7gD9a6Kakl7x89mVTD1aqlh1pbt' ||
|
||||
'YnorDfxj4eWTy11W3lfpthbzD+S5q7ZavBfy7IIrrGM75Ld41/NgKu6OB05pXaL9' ||
|
||||
'FFFMgK8A+K+ote+NZYM5jtIliA9yNx/mPyr37tXzP42cv421gseftLD8sCsK7909' ||
|
||||
'zIIKWJcn0Rf8Aa5o3h3WJtR1VZmdY9kAjj3YJ+8fbjj8TW/8QPHuj+J/D6WNgLjz' ||
|
||||
'lnWQ+ZHtGAD3z71wNno2qahEZbLTrq5jB2l4oiwB9Mii80XVNPhE17p11bxE7d8s' ||
|
||||
'RUZ9MmsFOSjZLQ9+phMNUxKqyl7y6XNHwR/yO+j/APXyP5GvQ/jX/wAg/SP+ur/+' ||
|
||||
'givPPBH/ACO+j/8AXyP5GvQ/jX/yD9I/66v/AOgirh/CZyYv/kZ0vT/M8y8PaM/i' ||
|
||||
'DV106J9kskcjRk9NyqSAfY4xWbLFJBM8UqFJI2KurDBUjgg11nww/wCR/sP92T/0' ||
|
||||
'A16B4p+Gq614xtNQg2pZznN+AcH5e4/3uh/OojT5o3R0V8xjh8S6dT4bX+ev5nk1' ||
|
||||
'7oU+n+HtP1W4yv26RxEhH8CgfN+JP5V0Hwo/5Hy3/wCuEn8q6b4zxJBY6JFEgSNG' ||
|
||||
'kVVUYAAC4Fcn8MbqG08bQyzyBEEMnJ78dB6mq5VGokZ+3licunUe7TOn+Nn/AB86' ||
|
||||
'P/uy/wA1rD+EZA8bEk4AtJMn8Vru/GHhW58c3lhKrmws7ZX3yzp875x91e3Tvj6V' ||
|
||||
'zduPDPh6/GneGtOl8Qa2wKmRnzGvrk/dx9B+NXKL9pzHDQxEHgPq8dZWd/L1exf+' ||
|
||||
'JHhuPxFdw6hozLPeIPLnCnCbBkhi5+UEfXofauEtLWy8OX0N7L4hQ3sDBli01POI' ||
|
||||
'PoXOF9j1r1O18E6nrhSfxbqJkjHK6baHy4E9jjlq84+IXg4+GNWE1qh/sy5JMX/T' ||
|
||||
'Nu6f1Ht9KVSL+OxeXYiMrYSU/wCu13/l8zudCn1jx3avcxaybO1Vijorbph9Qu1V' ||
|
||||
'z/wKt+y+HHh63fzrq3k1CfqZbyQyc/Tp+leL+CvE0vhjxDDc7z9klIjuU7FSev1H' ||
|
||||
'X8/WvpNWDqGUggjIIrSk1NXe5wZpTq4Spywdova2hFbWVrZxiO2t4oUH8MaBR+lT' ||
|
||||
'0UVseM23uFFFFAgr5y+I9obPx5qQIwsrLKvuCo/qDX0bXkPxn0YiSw1mNflINvKf' ||
|
||||
'Tuv/ALNWNdXiexklZU8Uk/tKxb+C16j6bqVgSN8cyygezDH81rR+MQ/4o6L/AK+0' ||
|
||||
'/k1cV8JrXVv+Em+2WkJNgEaO5kY4XHUAerZxxXpHxB0b/hIdBSxjv7W1kWdZC1w2' ||
|
||||
'BgA/40oXdOxti1CjmanfS6b8jxbwR/yO+j/9fI/ka9D+Nf8AyD9I/wCur/8AoIrG' ||
|
||||
'8PeCJtJ8RWOoHVLa7S2lDslpFJIT7AgY/Ouu8a+HNT8bx2EVvB9hit3ZmkuiMkEY' ||
|
||||
'4VST+eKiMGqbR1YnFUZY+nWT91L/ADPN/hh/yP8AYf7sn/oBr3y51O1tHEbybpj0' ||
|
||||
'ijBZz/wEc1xXh34WafoVyl7PqNzNcoD8yN5SgEYPTn9auar438K+FI3hhkjluB1h' ||
|
||||
'tQGYn/abp+ZzWlNckfeOHMakcbiL0E5aW2F8SeFJPG01kb7fYWlqWYKCDLJnHXsv' ||
|
||||
'T3/Cqdzqngz4cwGC0hje+xjyofnmY/7THp+P5VjHUvHfjxWXToBoult/y1clWcfX' ||
|
||||
'GT+AH1qx4Q+GN/oXiSLUtQurO5iRW+UKxbceh5HX3ovd3ivmChGnT5MRU0X2U/zZ' ||
|
||||
'yfjXxR4p1K2ga/gfTNOu9xhtlOGdRjl+56j0HtS/CL/kd/8At1k/mteg/EHwRfeL' ||
|
||||
'ZbB7O5t4RbhwwlB53Y6Y+lZ/gf4c6l4Y8Q/2jdXlrLH5LR7Yw2ckj1+lRyS9pc7F' ||
|
||||
'jsM8BKmrRk09EQeNviHrnhnxLLp8FtZvBsWSNpFbcQRznB9Qa4bxF8Q9Y8S6abC8' ||
|
||||
'htI4CwY+Wh3ZByOSTivS/H/gC78V6haXllcwQPHGY5PNB+YZyMY+prkP+FMa3/0E' ||
|
||||
'rH8n/wAKKiqNtLYeBrZdCnCc7Ka9TzcKzkKoJZuAB3NfVWjwS22i2UE3MscCI/1C' ||
|
||||
'gGuE8LfCe20e/i1DU7sXk8Lbo40TbGrdic8nFekVVGm46s485x9PEyjGlql1Ciii' ||
|
||||
'tzxAooooAKo6vpFnrmmS6ffRl7eXG4A4PByCD26VeooHGTi7rcxL3w9btpEen2Nr' ||
|
||||
'aRxRDEcciHaP++SDXG3fhzxxZzCTSpNICDpGqE5/77BP616bRUuKZ0UsVOn5+up5' ||
|
||||
'd/wkfxI0vi98Nw3ajq0A5/8AHWP8qgfxz461aQwaX4Za2boWljY7T9W2ivWKTA9K' ||
|
||||
'nkfc3WNpbujG/wA/yPKl8DeM/EZ3eI/EDW8DdYITn8MDC/zrqtC+HXh3QiskdmLi' ||
|
||||
'4XkTXHzkH2HQfgK6yimoJamdTH1prlTsuy0QgAHAGKWsvWHvVNsLcS+QXIuGhAMg' ||
|
||||
'G04wD74z3rHmfxAxkEJuFk3SL8yIUEe07GHq+duR67uMYqm7GEaXNrdHWUVx7z+K' ||
|
||||
'y+/yiCixnylC4coX389t+Fx6ZHvTbj/hKHjufmmV1ineLywmN+UMa89cAsPfFLmL' ||
|
||||
'+r/3l952VFcpqdvrcEt0bO4vJI1SAx/dOSZCJO2eFxSwPrZ1IBTc+WJ4wBIoEZh2' ||
|
||||
'DeScZ3bt2O+cdqLi9j7t+ZHVUVzFzHrUN/dNFLdPaiaMADaSIyMuUGOSDgfTOKWV' ||
|
||||
'/ES6XCbcF7j7S4XzAoJi2vs39hzt6e3vTuL2O2qOmormjHqU32F4ptRUGbFysgQE' ||
|
||||
'LsY+n97aOK6KJzJEjlGTcoO1uo9j70XIlDl6j6KKKZAUUUUAFFFFABRRRQAUUUUA' ||
|
||||
'Y3iDV59JjgNvCkrylwA5IAKxsw6e6gVnnxTchjmwZMSm2MbZ3LMUDKvoVJyN3Toa' ||
|
||||
'6ggHqAaMD0FKzNYzglZxuci3i26jghmeCAiXG9Fc7rf94qEP/wB9H05HfrUl74ou' ||
|
||||
'4PtKxW0TG3lQM+4lTG7KI2HrkMe/8JrqTGhzlF568daPLTbt2Lt6YxxSs+5ftKd/' ||
|
||||
'hOah8SXL6iLcxwSL9ojgKITvIaMMXHJGBn8h1qO48V3Vs1y5sA8EJmVnQklSrbUJ' ||
|
||||
'Hoe5HTjtXUrGinKooOMcCl2r6D8qLMXtKd/hOX1fxFqNjd3qW1ik0VpAszkkjgq5' ||
|
||||
'zn2Kjjqc0j+JrmNeIoGZIkk25wZ9zEbY8E8jHqeSOldTtU5yBz1poiRcAIox0wOl' ||
|
||||
'Fn3D2lOyXKcvZeJ72W5tPtVpFDaXErxiZmK4KiTjnr9wc+9aHh/W21W0WW4MMckh' ||
|
||||
'OyNTzx178/pWyY0ZdrIpHoRQsaISVRQT6ChJinUhJO0bDqKKKoxCiiigAooooAKK' ||
|
||||
'KKACiiigAooooAKKKKACiiigAooooAKKKKACiiigD//Z';
|
||||
begin
|
||||
as_pdf3.init;
|
||||
as_pdf3.put_image( to_blob( utl_encode.base64_decode( utl_raw.cast_to_raw( t_logo ) ) )
|
||||
, 0
|
||||
, as_pdf3.get( as_pdf3.C_GET_PAGE_HEIGHT ) - 260
|
||||
, as_pdf3.get( as_pdf3.C_GET_PAGE_WIDTH )
|
||||
);
|
||||
as_pdf3.write( 'jpg, gif and png images are supported.' );
|
||||
as_pdf3.write( 'And because PDF 1.3 (thats the format I use) doesn''t support alpha channels, neither does AS_PDF.', -1, -1 );
|
||||
as_pdf3.save_pdf;
|
||||
end;
|
||||
--
|
||||
declare
|
||||
t_rc sys_refcursor;
|
||||
t_query varchar2(1000);
|
||||
begin
|
||||
as_pdf3.init;
|
||||
as_pdf3.load_ttf_font( 'MY_FONTS', 'COLONNA.TTF', 'CID' );
|
||||
as_pdf3.set_page_proc( q'~
|
||||
begin
|
||||
as_pdf3.set_font( 'helvetica', 8 );
|
||||
as_pdf3.put_txt( 10, 15, 'Page #PAGE_NR# of "PAGE_COUNT#' );
|
||||
as_pdf3.set_font( 'helvetica', 12 );
|
||||
as_pdf3.put_txt( 350, 15, 'This is a footer text' );
|
||||
as_pdf3.set_font( 'helvetica', 'B', 15 );
|
||||
as_pdf3.put_txt( 200, 780, 'This is a header text' );
|
||||
as_pdf3.put_image( 'MY_DIR', 'amis.jpg', 500, 15 );
|
||||
end;~' );
|
||||
as_pdf3.set_page_proc( q'~
|
||||
begin
|
||||
as_pdf3.set_font( 'Colonna MT', 'N', 50 );
|
||||
as_pdf3.put_txt( 150, 200, 'Watermark Watermark Watermark', 60 );
|
||||
end;~' );
|
||||
t_query := 'select rownum, sysdate + level, ''example'' || level from dual connect by level <= 50';
|
||||
as_pdf3.query2table( t_query );
|
||||
open t_rc for t_query;
|
||||
as_pdf3.refcursor2table( t_rc );
|
||||
as_pdf3.save_pdf;
|
||||
end;
|
||||
|
||||
|
||||
declare
|
||||
ts timestamp;
|
||||
begin
|
||||
ts := systimestamp;
|
||||
as_pdf3.init;
|
||||
as_pdf3.set_font( as_pdf3.load_ttf_font( as_pdf3.file2blob( 'MY_FONTS', 'arial.ttf' ), 'CID' ), 15 );
|
||||
as_pdf3.write( 'Anton, testing 1,2,3!' );
|
||||
as_pdf3.save_pdf;
|
||||
dbms_output.put_line( systimestamp - ts );
|
||||
end;
|
||||
|
||||
3559
extras/pdfgen_pkg.pkb
Executable file
3559
extras/pdfgen_pkg.pkb
Executable file
File diff suppressed because it is too large
Load Diff
138
extras/pdfgen_pkg.pks
Executable file
138
extras/pdfgen_pkg.pks
Executable file
@ -0,0 +1,138 @@
|
||||
CREATE OR REPLACE PACKAGE pdfgen_pkg AS
|
||||
/*******************************************************************************
|
||||
* Logiciel : PL_FPDF *
|
||||
* Version : 0.9.1 *
|
||||
* Date : 13/06/2006 *
|
||||
* Auteur : Pierre-Gilles Levallois *
|
||||
* Licence : GPL *
|
||||
* *
|
||||
********************************************************************************
|
||||
* Cette librairie PL/SQL est un portage de la version 1.53 de FPDF, célèbre *
|
||||
* classe PHP développée par Olivier PLATHEY (http://www.fpdf.org/) *
|
||||
********************************************************************************
|
||||
This program is free software; you can redistribute it and/or modify
|
||||
it under the terms of the GNU General Public License as published by
|
||||
the Free Software Foundation; either version 2 of the License, or
|
||||
(at your option) any later version.
|
||||
|
||||
This program is distributed in the hope that it will be useful,
|
||||
but WITHOUT ANY WARRANTY; without even the implied warranty of
|
||||
MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
|
||||
GNU General Public License for more details.
|
||||
|
||||
You should have received a copy of the GNU General Public License
|
||||
along with this program; if not, write to the Free Software
|
||||
Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1301 USA
|
||||
********************************************************************************/
|
||||
|
||||
/*
|
||||
|
||||
Original by Pierre-Gilles Levallois, with modifications and additions by several others;
|
||||
see package body for details.
|
||||
|
||||
*/
|
||||
|
||||
|
||||
-- Public types and subtypes.
|
||||
subtype word is varchar2(80);
|
||||
type tv4000a is table of varchar2(4000) index by word;
|
||||
|
||||
|
||||
-- Constantes globales
|
||||
FPDF_VERSION constant varchar2(10) := '1.53';
|
||||
PL_FPDF_VERSION constant varchar2(10) := '0.9.5';
|
||||
noParam tv4000a;
|
||||
|
||||
-- methods added to FPDF
|
||||
function GetCurrentFontSize return number;
|
||||
function GetCurrentFontStyle return varchar2;
|
||||
function GetCurrentFontFamily return varchar2;
|
||||
procedure SetDash(pblack number default 0, pwhite number default 0);
|
||||
function GetLineSpacing return number;
|
||||
Procedure SetLineSpacing (pls number);
|
||||
|
||||
-- FPDF public methods
|
||||
procedure Ln(h number default null);
|
||||
function GetX return number;
|
||||
procedure SetX(px number);
|
||||
function GetY return number;
|
||||
procedure SetY(py number);
|
||||
procedure SetXY(x number,y number);
|
||||
procedure SetHeaderProc(headerprocname in varchar2, paramTable tv4000a default noParam);
|
||||
procedure SetFooterProc(footerprocname in varchar2, paramTable tv4000a default noParam);
|
||||
procedure SetMargins(left number,top number ,right number default -1);
|
||||
procedure SetLeftMargin( pMargin number);
|
||||
procedure SetTopMargin(pMargin number);
|
||||
procedure SetRightMargin(pMargin number);
|
||||
procedure SetAutoPageBreak(pauto boolean,pMargin number default 0);
|
||||
procedure SetDisplayMode(zoom varchar2,layout varchar2 default 'continuous');
|
||||
procedure SetCompression(p_compress boolean default false);
|
||||
procedure SetTitle(ptitle varchar2);
|
||||
procedure SetSubject(psubject varchar2);
|
||||
procedure SetAuthor(pauthor varchar2);
|
||||
procedure SetKeywords(pkeywords varchar2);
|
||||
procedure SetCreator(pcreator varchar2);
|
||||
procedure SetAliasNbPages(palias varchar2 default '{nb}');
|
||||
procedure Header;
|
||||
procedure Footer;
|
||||
function PageNo return number;
|
||||
procedure SetDrawColor(r number,g number default -1,b number default -1);
|
||||
procedure SetFillColor (r number,g number default -1,b number default -1);
|
||||
procedure SetTextColor (r number,g number default -1,b number default -1);
|
||||
procedure SetLineWidth(width number);
|
||||
procedure Line(x1 number,y1 number,x2 number,y2 number);
|
||||
procedure Rect(px number,py number,pw number,ph number,pstyle varchar2 default '');
|
||||
function AddLink return number;
|
||||
procedure SetLink(plink number,py number default 0,ppage number default -1);
|
||||
procedure Link(px number,py number,pw number,ph number,plink varchar2);
|
||||
procedure Text(px number,py number,ptxt varchar2);
|
||||
function AcceptPageBreak return boolean;
|
||||
procedure AddFont (family varchar2, style varchar2 default '',filename varchar2 default '');
|
||||
procedure SetFont(pfamily varchar2,pstyle varchar2 default '',psize number default 0);
|
||||
function GetStringWidth(pstr varchar2) return number;
|
||||
procedure SetFontSize(psize number);
|
||||
procedure Cell
|
||||
(pw number,
|
||||
ph number default 0,
|
||||
ptxt varchar2 default '',
|
||||
pborder varchar2 default '0',
|
||||
pln number default 0,
|
||||
palign varchar2 default '',
|
||||
pfill number default 0,
|
||||
plink varchar2 default '');
|
||||
procedure MultiCell
|
||||
( pw number,
|
||||
ph number default 0,
|
||||
ptxt varchar2,
|
||||
pborder varchar2 default '0',
|
||||
palign varchar2 default 'J',
|
||||
pfill number default 0,
|
||||
phMax number default 0);
|
||||
procedure Write(pH varchar2,ptxt varchar2,plink varchar2 default null);
|
||||
procedure image ( pFile varchar2,
|
||||
pX number,
|
||||
pY number,
|
||||
pWidth number default 0,
|
||||
pHeight number default 0,
|
||||
pType varchar2 default null,
|
||||
pLink varchar2 default null);
|
||||
|
||||
procedure Output(pname varchar2 default null,pdest varchar2 default null);
|
||||
|
||||
procedure OpenPDF;
|
||||
procedure ClosePDF;
|
||||
procedure AddPage(orientation varchar2 default '');
|
||||
procedure fpdf (orientation varchar2 default 'P', unit varchar2 default 'mm', format varchar2 default 'A4');
|
||||
procedure Error(pmsg varchar2);
|
||||
procedure DebugEnabled;
|
||||
procedure DebugDisabled;
|
||||
function GetScaleFactor return number;
|
||||
function getImageFromUrl(p_Url varchar2) return ordsys.ordImage;
|
||||
|
||||
procedure jsSet(theJs varchar2);
|
||||
procedure jsAutoPrint(silent boolean default false, closeWindow boolean default false);
|
||||
|
||||
function get_output return blob;
|
||||
|
||||
END pdfgen_pkg;
|
||||
/
|
||||
112
extras/utl_file_nonstandard.pkb
Executable file
112
extras/utl_file_nonstandard.pkb
Executable file
@ -0,0 +1,112 @@
|
||||
create or replace package body sys.utl_file_nonstandard
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package contains functionality missing from the standard UTL_FILE package
|
||||
|
||||
Remarks: This package MUST be created in the SYS schema due to a dependency on an X$ table
|
||||
See http://www.chrispoole.co.uk/tips/plsqltip2.htm
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 30.07.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
function get_file_list (p_directory_name in varchar2,
|
||||
p_file_pattern in varchar2 := null,
|
||||
p_max_files in number := null) return t_file_list
|
||||
as
|
||||
l_user dba_tab_privs.grantee%type := user;
|
||||
l_directory_name dba_directories.directory_name%type := upper(p_directory_name);
|
||||
l_directory_path dba_directories.directory_path%type;
|
||||
l_pattern varchar2(2000);
|
||||
l_dummy varchar2(2000) := null;
|
||||
l_dir_sep varchar2(1) := null;
|
||||
l_returnvalue t_file_list;
|
||||
|
||||
e_bug_data_conv exception;
|
||||
pragma exception_init (e_bug_data_conv, -6502);
|
||||
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get list of files in directory
|
||||
|
||||
Remarks: This package MUST be created in the SYS schema due to a dependence on an X$ table
|
||||
See http://www.chrispoole.co.uk/tips/plsqltip2.htm
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 30.07.2011 Created
|
||||
MBR 16.08.2011 Workaround for ORA-06502, see http://forums.oracle.com/forums/thread.jspa?threadID=662413
|
||||
|
||||
*/
|
||||
|
||||
begin
|
||||
select table_name
|
||||
into l_directory_name
|
||||
from dba_tab_privs
|
||||
where table_name = l_directory_name
|
||||
and grantee = l_user
|
||||
and privilege = 'READ'
|
||||
and rownum = 1;
|
||||
exception
|
||||
when no_data_found then
|
||||
raise_application_error (-20000, 'User ' || l_user || ' does not have READ privilege on directory ' || l_directory_name);
|
||||
end;
|
||||
|
||||
begin
|
||||
select directory_path
|
||||
into l_directory_path
|
||||
from dba_directories
|
||||
where directory_name = l_directory_name;
|
||||
exception
|
||||
when no_data_found then
|
||||
raise_application_error (-20000, 'Directory ' || l_directory_name || ' not found');
|
||||
end;
|
||||
|
||||
-- Unix or Windows system?
|
||||
|
||||
if instr(l_directory_path, '/') > 0 then
|
||||
l_dir_sep := '/';
|
||||
else
|
||||
l_dir_sep := '\';
|
||||
end if;
|
||||
|
||||
-- make sure the path has a trailing directory separator
|
||||
|
||||
if instr(l_directory_path, l_dir_sep, length(l_directory_path)) = 0 then
|
||||
l_directory_path := l_directory_path || l_dir_sep;
|
||||
end if;
|
||||
|
||||
if p_file_pattern is not null then
|
||||
l_pattern := l_directory_path || '\' || p_file_pattern;
|
||||
else
|
||||
l_pattern := l_directory_path;
|
||||
end if;
|
||||
|
||||
begin
|
||||
dbms_backup_restore.searchfiles (l_pattern, ns => l_dummy);
|
||||
exception
|
||||
when e_bug_data_conv then
|
||||
-- workaround: just try again
|
||||
dbms_backup_restore.searchfiles (l_pattern, ns => l_dummy);
|
||||
end;
|
||||
|
||||
select fname_krbmsft as file_name
|
||||
bulk collect into l_returnvalue
|
||||
from x$krbmsft
|
||||
order by 1;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_file_list;
|
||||
|
||||
|
||||
end utl_file_nonstandard;
|
||||
/
|
||||
|
||||
26
extras/utl_file_nonstandard.pks
Executable file
26
extras/utl_file_nonstandard.pks
Executable file
@ -0,0 +1,26 @@
|
||||
create or replace package sys.utl_file_nonstandard
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package contains functionality missing from the standard UTL_FILE package
|
||||
|
||||
Remarks: This package MUST be created in the SYS schema due to a dependency on an X$ table
|
||||
See http://www.chrispoole.co.uk/tips/plsqltip2.htm
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 30.07.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
type t_file_list is table of varchar2(4000) index by binary_integer;
|
||||
|
||||
-- get list of files in directory
|
||||
function get_file_list (p_directory_name in varchar2,
|
||||
p_file_pattern in varchar2 := null,
|
||||
p_max_files in number := null) return t_file_list;
|
||||
|
||||
end utl_file_nonstandard;
|
||||
/
|
||||
|
||||
238
ora/amazon_aws_auth_pkg.pkb
Executable file
238
ora/amazon_aws_auth_pkg.pkb
Executable file
@ -0,0 +1,238 @@
|
||||
create or replace package body amazon_aws_auth_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: PL/SQL wrapper package for Amazon AWS authentication API
|
||||
|
||||
Remarks: inspired by the whitepaper "Building an Amazon S3 Client with Application Express 4.0" by Jason Straub
|
||||
see http://jastraub.blogspot.com/2011/01/building-amazon-s3-client-with.html
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 09.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
g_aws_id varchar2(20) := 'my_aws_id'; -- AWS access key ID
|
||||
g_aws_key varchar2(40) := 'my_aws_key'; -- AWS secret key
|
||||
|
||||
g_gmt_offset number := 0; -- your timezone GMT adjustment
|
||||
|
||||
|
||||
function get_auth_string (p_string in varchar2) return varchar2
|
||||
as
|
||||
l_returnvalue varchar2(32000);
|
||||
l_encrypted_raw raw (2000); -- stores encrypted binary text
|
||||
l_decrypted_raw raw (2000); -- stores decrypted binary text
|
||||
l_key_bytes_raw raw (64); -- stores 256-bit encryption key
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get authentication string
|
||||
|
||||
Remarks: see http://docs.amazonwebservices.com/AmazonS3/latest/dev/RESTAuthentication.html#ConstructingTheAuthenticationHeader
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 09.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_key_bytes_raw := utl_i18n.string_to_raw (g_aws_key, 'AL32UTF8');
|
||||
l_decrypted_raw := utl_i18n.string_to_raw (p_string, 'AL32UTF8');
|
||||
|
||||
l_encrypted_raw := dbms_crypto.mac (src => l_decrypted_raw, typ => dbms_crypto.hmac_sh1, key => l_key_bytes_raw);
|
||||
|
||||
l_returnvalue := utl_i18n.raw_to_char (utl_encode.base64_encode(l_encrypted_raw), 'AL32UTF8');
|
||||
|
||||
l_returnvalue := 'AWS ' || g_aws_id || ':' || l_returnvalue;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_auth_string;
|
||||
|
||||
|
||||
function get_signature (p_string in varchar2) return varchar2
|
||||
as
|
||||
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get signature part of authentication string
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 09.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
return substr(get_auth_string(p_string),26);
|
||||
|
||||
end get_signature;
|
||||
|
||||
|
||||
function get_aws_id return varchar2
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get AWS access key ID
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 09.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
return g_aws_id;
|
||||
|
||||
end get_aws_id;
|
||||
|
||||
|
||||
function get_date_string (p_date in date := sysdate) return varchar2
|
||||
as
|
||||
l_returnvalue varchar2(255);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get AWS access key ID
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 09.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := to_char(p_date + g_gmt_offset/24, 'Dy, DD Mon YYYY HH24:MI:SS', 'NLS_DATE_LANGUAGE = AMERICAN') || ' GMT';
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_date_string;
|
||||
|
||||
|
||||
function get_epoch (p_date in date) return number
|
||||
as
|
||||
l_returnvalue number;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get epoch (number of seconds since January 1, 1970)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 09.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := trunc((p_date - to_date('01-01-1970','MM-DD-YYYY')) * 24 * 60 * 60);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_epoch;
|
||||
|
||||
|
||||
procedure set_aws_id (p_aws_id in varchar2)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: set AWS access key id
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 18.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
g_aws_id := p_aws_id;
|
||||
|
||||
|
||||
end set_aws_id;
|
||||
|
||||
|
||||
procedure set_aws_key (p_aws_key in varchar2)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: set AWS secret key
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 18.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
g_aws_key := p_aws_key;
|
||||
|
||||
end set_aws_key;
|
||||
|
||||
|
||||
procedure set_gmt_offset (p_gmt_offset in number)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: set GMT offset
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 03.03.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
g_gmt_offset := p_gmt_offset;
|
||||
|
||||
end set_gmt_offset;
|
||||
|
||||
|
||||
procedure init (p_aws_id in varchar2,
|
||||
p_aws_key in varchar2,
|
||||
p_gmt_offset in number)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: initialize package for use
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 03.03.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
g_aws_id := p_aws_id;
|
||||
g_aws_key := p_aws_key;
|
||||
g_gmt_offset := nvl(p_gmt_offset, g_gmt_offset);
|
||||
|
||||
end init;
|
||||
|
||||
end amazon_aws_auth_pkg;
|
||||
/
|
||||
|
||||
50
ora/amazon_aws_auth_pkg.pks
Executable file
50
ora/amazon_aws_auth_pkg.pks
Executable file
@ -0,0 +1,50 @@
|
||||
create or replace package amazon_aws_auth_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: PL/SQL wrapper package for Amazon AWS authentication API
|
||||
|
||||
Remarks: inspired by the whitepaper "Building an Amazon S3 Client with Application Express 4.0" by Jason Straub
|
||||
see http://jastraub.blogspot.com/2011/01/building-amazon-s3-client-with.html
|
||||
|
||||
dependencies: owner of this package needs execute on dbms_crypto
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 09.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
-- get "Authorization" (actually authentication) header string
|
||||
function get_auth_string (p_string in varchar2) return varchar2;
|
||||
|
||||
-- get signature string
|
||||
function get_signature (p_string in varchar2) return varchar2;
|
||||
|
||||
-- get AWS access key ID
|
||||
function get_aws_id return varchar2;
|
||||
|
||||
-- get date string
|
||||
function get_date_string (p_date in date := sysdate) return varchar2;
|
||||
|
||||
-- get epoch (number of seconds since January 1, 1970)
|
||||
function get_epoch (p_date in date) return number;
|
||||
|
||||
-- set AWS access key id
|
||||
procedure set_aws_id (p_aws_id in varchar2);
|
||||
|
||||
-- set AWS secret key
|
||||
procedure set_aws_key (p_aws_key in varchar2);
|
||||
|
||||
-- set GMT offset
|
||||
procedure set_gmt_offset (p_gmt_offset in number);
|
||||
|
||||
-- initialize package for use
|
||||
procedure init (p_aws_id in varchar2,
|
||||
p_aws_key in varchar2,
|
||||
p_gmt_offset in number := null);
|
||||
|
||||
end amazon_aws_auth_pkg;
|
||||
/
|
||||
|
||||
1206
ora/amazon_aws_s3_pkg.pkb
Executable file
1206
ora/amazon_aws_s3_pkg.pkb
Executable file
File diff suppressed because it is too large
Load Diff
144
ora/amazon_aws_s3_pkg.pks
Executable file
144
ora/amazon_aws_s3_pkg.pks
Executable file
@ -0,0 +1,144 @@
|
||||
create or replace package amazon_aws_s3_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: PL/SQL wrapper package for Amazon AWS S3 API
|
||||
|
||||
Remarks: inspired by the whitepaper "Building an Amazon S3 Client with Application Express 4.0" by Jason Straub
|
||||
see http://jastraub.blogspot.com/2011/01/building-amazon-s3-client-with.html
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 09.01.2011 Created
|
||||
MBR 16.02.2013 Added enhancements from Jeffrey Kemp, see http://code.google.com/p/plsql-utils/issues/detail?id=14 to http://code.google.com/p/plsql-utils/issues/detail?id=17
|
||||
|
||||
*/
|
||||
|
||||
type t_bucket is record (
|
||||
bucket_name varchar2(255),
|
||||
creation_date date
|
||||
);
|
||||
|
||||
type t_bucket_list is table of t_bucket index by binary_integer;
|
||||
type t_bucket_tab is table of t_bucket;
|
||||
|
||||
type t_object is record (
|
||||
key varchar2(4000),
|
||||
size_bytes number,
|
||||
last_modified date
|
||||
);
|
||||
|
||||
type t_object_list is table of t_object index by binary_integer;
|
||||
type t_object_tab is table of t_object;
|
||||
|
||||
type t_owner is record (
|
||||
user_id varchar2(200),
|
||||
user_name varchar2(200)
|
||||
);
|
||||
|
||||
type t_grantee is record (
|
||||
grantee_type varchar2(20), -- CanonicalUser or Group
|
||||
user_id varchar2(200), -- for users
|
||||
user_name varchar2(200), -- for users
|
||||
group_uri varchar2(200), -- for groups
|
||||
permission varchar2(20) -- FULL_CONTROL, WRITE, READ_ACP
|
||||
);
|
||||
|
||||
type t_grantee_list is table of t_grantee index by binary_integer;
|
||||
type t_grantee_tab is table of t_grantee;
|
||||
|
||||
-- bucket regions
|
||||
-- see http://aws.amazon.com/articles/3912?_encoding=UTF8&jiveRedirect=1#s3
|
||||
-- see http://docs.aws.amazon.com/general/latest/gr/rande.html#s3_region
|
||||
g_region_us_standard constant varchar2(255) := null;
|
||||
g_region_us_west_california constant varchar2(255) := 'us-west-1';
|
||||
g_region_us_west_oregon constant varchar2(255) := 'us-west-2';
|
||||
g_region_eu_ireland constant varchar2(255) := 'EU';
|
||||
g_region_asia_pacific_singapor constant varchar2(255) := 'ap-southeast-1';
|
||||
g_region_asia_pacific_sydney constant varchar2(255) := 'ap-southeast-2';
|
||||
g_region_asia_pacific_tokyo constant varchar2(255) := 'ap-northeast-1';
|
||||
g_region_south_america_sao_p constant varchar2(255) := 'sa-east-1';
|
||||
|
||||
-- deprecated region constants, will be removed in next release (use constants above instead)
|
||||
g_region_eu constant varchar2(255) := 'EU';
|
||||
g_region_us_west_1 constant varchar2(255) := 'us-west-1';
|
||||
g_region_us_west_2 constant varchar2(255) := 'us-west-2';
|
||||
g_region_asia_pacific_1 constant varchar2(255) := 'ap-southeast-1';
|
||||
|
||||
-- predefined access policies
|
||||
-- see http://docs.amazonwebservices.com/AmazonS3/latest/dev/index.html?RESTAccessPolicy.html
|
||||
|
||||
g_acl_private constant varchar2(255) := 'private';
|
||||
g_acl_public_read constant varchar2(255) := 'public-read';
|
||||
g_acl_public_read_write constant varchar2(255) := 'public-read-write';
|
||||
g_acl_authenticated_read constant varchar2(255) := 'authenticated-read';
|
||||
g_acl_bucket_owner_read constant varchar2(255) := 'bucket-owner-read';
|
||||
g_acl_bucket_owner_full_ctrl constant varchar2(255) := 'bucket-owner-full-control';
|
||||
|
||||
-- get buckets
|
||||
function get_bucket_list return t_bucket_list;
|
||||
|
||||
-- get buckets
|
||||
function get_bucket_tab return t_bucket_tab pipelined;
|
||||
|
||||
-- create bucket
|
||||
procedure new_bucket (p_bucket_name in varchar2,
|
||||
p_region in varchar2 := null);
|
||||
|
||||
-- get bucket region
|
||||
function get_bucket_region (p_bucket_name in varchar2) return varchar2;
|
||||
|
||||
-- get objects
|
||||
function get_object_list (p_bucket_name in varchar2,
|
||||
p_prefix in varchar2 := null,
|
||||
p_max_keys in number := null) return t_object_list;
|
||||
|
||||
-- get objects
|
||||
function get_object_tab (p_bucket_name in varchar2,
|
||||
p_prefix in varchar2 := null,
|
||||
p_max_keys in number := null) return t_object_tab pipelined;
|
||||
|
||||
-- get download URL
|
||||
function get_download_url (p_bucket_name in varchar2,
|
||||
p_key in varchar2,
|
||||
p_expiry_date in date) return varchar2;
|
||||
|
||||
-- new object
|
||||
procedure new_object (p_bucket_name in varchar2,
|
||||
p_key in varchar2,
|
||||
p_object in blob,
|
||||
p_content_type in varchar2,
|
||||
p_acl in varchar2 := null);
|
||||
|
||||
-- delete object
|
||||
procedure delete_object (p_bucket_name in varchar2,
|
||||
p_key in varchar2);
|
||||
|
||||
-- get object
|
||||
function get_object (p_bucket_name in varchar2,
|
||||
p_key in varchar2) return blob;
|
||||
|
||||
-- delete bucket
|
||||
procedure delete_bucket (p_bucket_name in varchar2);
|
||||
|
||||
-- get owner for an object
|
||||
function get_object_owner (p_bucket_name in varchar2,
|
||||
p_key in varchar2) return t_owner;
|
||||
|
||||
-- get grantees for an object
|
||||
function get_object_grantee_list (p_bucket_name in varchar2,
|
||||
p_key in varchar2) return t_grantee_list;
|
||||
|
||||
-- get grantees for an object
|
||||
function get_object_grantee_tab (p_bucket_name in varchar2,
|
||||
p_key in varchar2) return t_grantee_tab pipelined;
|
||||
|
||||
-- modify the access control list for an object
|
||||
procedure set_object_acl (p_bucket_name in varchar2,
|
||||
p_key in varchar2,
|
||||
p_acl in varchar2);
|
||||
|
||||
end amazon_aws_s3_pkg;
|
||||
/
|
||||
|
||||
736
ora/apex_util_pkg.pkb
Executable file
736
ora/apex_util_pkg.pkb
Executable file
@ -0,0 +1,736 @@
|
||||
create or replace package body apex_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: package provides general apex utilities
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 12.06.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
function get_page_name (p_application_id in number,
|
||||
p_page_id in number) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_db_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: purpose
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 12.06.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
begin
|
||||
select page_name
|
||||
into l_returnvalue
|
||||
from apex_application_pages
|
||||
where application_id = p_application_id
|
||||
and page_id = p_page_id;
|
||||
exception
|
||||
when no_data_found then
|
||||
l_returnvalue := null;
|
||||
end;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_page_name;
|
||||
|
||||
|
||||
function get_item_name (p_page_id in number,
|
||||
p_item_name in varchar2) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_db_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get item name for page and item
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 10.01.2009 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := upper('P' || p_page_id || '_' || p_item_name);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_item_name;
|
||||
|
||||
|
||||
function get_page_help_text (p_application_id in number,
|
||||
p_page_id in number) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_db_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: purpose
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 12.06.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
begin
|
||||
select help_text
|
||||
into l_returnvalue
|
||||
from apex_application_pages
|
||||
where application_id = p_application_id
|
||||
and page_id = p_page_id;
|
||||
exception
|
||||
when no_data_found then
|
||||
l_returnvalue := null;
|
||||
end;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_page_help_text;
|
||||
|
||||
|
||||
function get_apex_url (p_page_id in varchar2,
|
||||
p_request in varchar2 := null,
|
||||
p_item_names in varchar2 := null,
|
||||
p_item_values in varchar2 := null,
|
||||
p_debug in varchar2 := null,
|
||||
p_application_id in varchar2 := null,
|
||||
p_session_id in number := null,
|
||||
p_clear_cache in varchar2 := null) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_db_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return apex url
|
||||
|
||||
Remarks: url format: f?p=App:Page:Session:Request:Debug:ClearCache:itemNames:itemValues:PrinterFriendly
|
||||
App: Application Id
|
||||
Page: Page Id
|
||||
Session: Session ID
|
||||
Request: GET Request (button pressed)
|
||||
Debug: Whether show debug or not (YES/NO)
|
||||
ClearCache: Comma delimited string for page(s) for which cache is to be cleared
|
||||
itemNames: Used to set session state for page items, comma delimited
|
||||
itemValues: Partner to itemNames, actual session value
|
||||
PrinterFriendly: Set to YES if page is to be rendered printer friendly
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 26.03.2008 Created
|
||||
MBR 12.07.2011 Added clear cache parameter
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := 'f?p=' || nvl(p_application_id, v('APP_ID'))
|
||||
|| ':'|| p_page_id
|
||||
|| ':' || nvl(p_session_id, v('APP_SESSION'))
|
||||
|| ':' || p_request
|
||||
|| ':' || nvl(p_debug, 'NO')
|
||||
|| ':' || p_clear_cache
|
||||
|| ':' || p_item_names
|
||||
|| ':' || utl_url.escape(p_item_values)
|
||||
|| ':';
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_apex_url;
|
||||
|
||||
|
||||
function get_apex_url_simple (p_page_id in varchar2,
|
||||
p_item_name in varchar2 := null,
|
||||
p_item_value in varchar2 := null,
|
||||
p_request in varchar2 := null) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_db_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return apex url (simple syntax)
|
||||
|
||||
Remarks: assumes only one parameter, and prefixes the parameter name with page number
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 03.08.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := 'f?p=' || v('APP_ID')
|
||||
|| ':'|| p_page_id
|
||||
|| ':' || v('APP_SESSION')
|
||||
|| ':' || p_request
|
||||
|| ':' || 'NO'
|
||||
|| ':'
|
||||
|| ':' || case when p_item_name is not null then 'P' || p_page_id || '_' || p_item_name else null end
|
||||
|| ':' || utl_url.escape(p_item_value)
|
||||
|| ':';
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_apex_url_simple;
|
||||
|
||||
|
||||
function get_apex_url_item_names (p_page_id in number,
|
||||
p_item_name_array in t_str_array) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_db_varchar2;
|
||||
l_str string_util_pkg.t_max_db_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get item name
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
THH 28.05.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
for i in 1..p_item_name_array.count loop
|
||||
|
||||
l_str := 'P' || p_page_id || '_' || p_item_name_array(i);
|
||||
l_returnvalue := string_util_pkg.add_item_to_list(l_str, l_returnvalue, ',');
|
||||
end loop;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_apex_url_item_names;
|
||||
|
||||
|
||||
function get_apex_url_item_values (p_item_value_array in t_str_array) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_db_varchar2;
|
||||
l_str string_util_pkg.t_max_db_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get item values
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
THH 28.05.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
for i in 1..p_item_value_array.count loop
|
||||
|
||||
l_str := p_item_value_array(i);
|
||||
l_returnvalue := string_util_pkg.add_item_to_list(l_str, l_returnvalue, ',');
|
||||
|
||||
end loop;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_apex_url_item_values;
|
||||
|
||||
|
||||
function get_dynamic_lov_query (p_application_id in number,
|
||||
p_lov_name in varchar2) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get query of dynamic lov
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 08.07.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
begin
|
||||
|
||||
select list_of_values_query
|
||||
into l_returnvalue
|
||||
from apex_application_lovs
|
||||
where application_id = p_application_id
|
||||
and list_of_values_name = p_lov_name;
|
||||
|
||||
exception
|
||||
when no_data_found then
|
||||
l_returnvalue := null;
|
||||
end;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_dynamic_lov_query;
|
||||
|
||||
|
||||
procedure set_apex_security_context (p_schema in varchar2)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: set Apex security context
|
||||
|
||||
Remarks: to be able to run Apex APIs that require a context (security group ID) to be set
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 04.12.2009 Created
|
||||
|
||||
*/
|
||||
|
||||
wwv_flow_api.set_security_group_id(apex_util.find_security_group_id(p_schema));
|
||||
|
||||
|
||||
end set_apex_security_context;
|
||||
|
||||
|
||||
procedure setup_apex_session_context (p_application_id in number,
|
||||
p_raise_exception_if_invalid in boolean := true)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: setup Apex session context
|
||||
|
||||
Remarks: required before calling packages via the URL, outside the Apex framework
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 20.10.2009 Created
|
||||
MBR 22.12.2012 Added fix for breaking change in Apex 4.2, see http://code.google.com/p/plsql-utils/issues/detail?id=18
|
||||
MBR 22.12.2012 Added parameter to specify if no valid session should raise an exception
|
||||
|
||||
*/
|
||||
|
||||
apex_application.g_flow_id := p_application_id;
|
||||
|
||||
if apex_custom_auth.is_session_valid then
|
||||
|
||||
apex_custom_auth.set_session_id (apex_custom_auth.get_session_id_from_cookie);
|
||||
apex_custom_auth.set_user (apex_custom_auth.get_username);
|
||||
wwv_flow_api.set_security_group_id (apex_custom_auth.get_security_group_id);
|
||||
|
||||
else
|
||||
if p_raise_exception_if_invalid then
|
||||
raise_application_error (-20000, 'Session not valid.');
|
||||
end if;
|
||||
end if;
|
||||
|
||||
end setup_apex_session_context;
|
||||
|
||||
|
||||
function get_str_value (p_str in varchar2) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get string value
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 03.05.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
if p_str in (g_apex_null_str, g_apex_undefined_str) then
|
||||
l_returnvalue := null;
|
||||
else
|
||||
l_returnvalue := p_str;
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_str_value;
|
||||
|
||||
|
||||
function get_num_value (p_str in varchar2) return number
|
||||
as
|
||||
l_returnvalue number;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get number value
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 03.05.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
if p_str in (g_apex_null_str, g_apex_undefined_str) then
|
||||
l_returnvalue := null;
|
||||
else
|
||||
-- assuming the NLS parameters are set correctly, we do NOT specify decimal or thousand separator
|
||||
l_returnvalue := string_util_pkg.str_to_num (p_str, null, null);
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_num_value;
|
||||
|
||||
|
||||
function get_date_value (p_str in varchar2) return date
|
||||
as
|
||||
l_returnvalue date;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get date value
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 03.05.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
if p_str in (g_apex_null_str, g_apex_undefined_str) then
|
||||
l_returnvalue := null;
|
||||
else
|
||||
l_returnvalue := string_util_pkg.parse_date (p_str);
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_date_value;
|
||||
|
||||
|
||||
procedure set_item (p_page_id in varchar2,
|
||||
p_item_name in varchar2,
|
||||
p_value in varchar2)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: set Apex item value (string)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 02.11.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
apex_util.set_session_state ('P' || p_page_id || '_' || upper(p_item_name), p_value);
|
||||
|
||||
end set_item;
|
||||
|
||||
|
||||
procedure set_date_item (p_page_id in varchar2,
|
||||
p_item_name in varchar2,
|
||||
p_value in date,
|
||||
p_date_format in varchar2 := null)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: set Apex item value (date)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 02.11.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
apex_util.set_session_state ('P' || p_page_id || '_' || upper(p_item_name), to_char(p_value, nvl(p_date_format, date_util_pkg.g_date_fmt_date_hour_min)));
|
||||
|
||||
end set_date_item;
|
||||
|
||||
|
||||
function get_item (p_page_id in varchar2,
|
||||
p_item_name in varchar2,
|
||||
p_max_length in number := null) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get Apex item value (string)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 02.11.2010 Created
|
||||
MBR 01.12.2010 Added parameter for max length
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := get_str_value (apex_util.get_session_state ('P' || p_page_id || '_' || upper(p_item_name)));
|
||||
|
||||
if p_max_length is not null then
|
||||
l_returnvalue := substr(l_returnvalue, 1, p_max_length);
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_item;
|
||||
|
||||
|
||||
function get_num_item (p_page_id in varchar2,
|
||||
p_item_name in varchar2) return number
|
||||
as
|
||||
l_returnvalue number;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get Apex item value (number)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 02.11.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := get_num_value (apex_util.get_session_state ('P' || p_page_id || '_' || upper(p_item_name)));
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_num_item;
|
||||
|
||||
|
||||
function get_date_item (p_page_id in varchar2,
|
||||
p_item_name in varchar2) return date
|
||||
as
|
||||
l_returnvalue date;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get Apex item value (date)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 02.11.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := get_date_value (apex_util.get_session_state ('P' || p_page_id || '_' || upper(p_item_name)));
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_date_item;
|
||||
|
||||
|
||||
procedure get_items (p_app_id in number,
|
||||
p_page_id in number,
|
||||
p_target in varchar2,
|
||||
p_exclude_items in t_str_array := null)
|
||||
as
|
||||
|
||||
cursor l_item_cursor
|
||||
is
|
||||
select item_name, substr(lower(item_name), length('p' || p_page_id || '_') +1 ) as field_name,
|
||||
display_as
|
||||
from apex_application_page_items
|
||||
where application_id = p_app_id
|
||||
and page_id = p_page_id
|
||||
and item_name not in (select upper(column_value) from table(p_exclude_items))
|
||||
and display_as not like '%does not save state%'
|
||||
order by item_name;
|
||||
|
||||
l_sql string_util_pkg.t_max_pl_varchar2;
|
||||
l_cursor pls_integer;
|
||||
l_rows pls_integer;
|
||||
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get multiple item values from page into custom record type
|
||||
|
||||
Remarks: this procedure grabs all the values from a page, so we don't have to write code to retrieve each item separately
|
||||
since a PL/SQL function cannot return a dynamic type (%ROWTYPE and PL/SQL records are not supported by ANYDATA/ANYTYPE),
|
||||
we must populate a global package variable as a workaround
|
||||
the global package variable (specified using the p_target parameter) must have fields matching the item names on the page
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 15.02.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
for l_rec in l_item_cursor loop
|
||||
l_sql := l_sql || ' ' || p_target || '.' || l_rec.field_name || ' := :b' || l_item_cursor%rowcount || ';' || chr(10);
|
||||
end loop;
|
||||
|
||||
l_sql := 'begin' || chr(10) || l_sql || 'end;';
|
||||
|
||||
--debug_pkg.printf('sql = %1', l_sql);
|
||||
|
||||
begin
|
||||
l_cursor := dbms_sql.open_cursor;
|
||||
dbms_sql.parse (l_cursor, l_sql, dbms_sql.native);
|
||||
|
||||
for l_rec in l_item_cursor loop
|
||||
if l_rec.display_as like '%Date Picker%' then
|
||||
dbms_sql.bind_variable (l_cursor, ':b' || l_item_cursor%rowcount, get_date_value(apex_util.get_session_state(l_rec.item_name)));
|
||||
else
|
||||
dbms_sql.bind_variable (l_cursor, ':b' || l_item_cursor%rowcount, get_str_value(apex_util.get_session_state(l_rec.item_name)));
|
||||
end if;
|
||||
end loop;
|
||||
|
||||
l_rows := dbms_sql.execute (l_cursor);
|
||||
dbms_sql.close_cursor (l_cursor);
|
||||
exception
|
||||
when others then
|
||||
if dbms_sql.is_open (l_cursor) then
|
||||
dbms_sql.close_cursor (l_cursor);
|
||||
end if;
|
||||
raise;
|
||||
end;
|
||||
|
||||
end get_items;
|
||||
|
||||
|
||||
procedure set_items (p_app_id in number,
|
||||
p_page_id in number,
|
||||
p_source in varchar2,
|
||||
p_exclude_items in t_str_array := null)
|
||||
as
|
||||
|
||||
cursor l_item_cursor
|
||||
is
|
||||
select item_name, substr(lower(item_name), length('p' || p_page_id || '_') +1 ) as field_name,
|
||||
display_as
|
||||
from apex_application_page_items
|
||||
where application_id = p_app_id
|
||||
and page_id = p_page_id
|
||||
and item_name not in (select upper(column_value) from table(p_exclude_items))
|
||||
and display_as not like '%does not save state%'
|
||||
order by item_name;
|
||||
|
||||
l_sql string_util_pkg.t_max_pl_varchar2;
|
||||
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: set multiple item values on page based on custom record type
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 15.02.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
for l_rec in l_item_cursor loop
|
||||
l_sql := l_sql || ' apex_util.set_session_state(''' || l_rec.item_name || ''', ' || p_source || '.' || l_rec.field_name || ');' || chr(10);
|
||||
end loop;
|
||||
|
||||
l_sql := 'begin' || chr(10) || l_sql || 'end;';
|
||||
|
||||
execute immediate l_sql;
|
||||
|
||||
end set_items;
|
||||
|
||||
|
||||
function is_item_in_list (p_item in varchar2,
|
||||
p_list in apex_application_global.vc_arr2) return boolean
|
||||
as
|
||||
l_index binary_integer;
|
||||
l_returnvalue boolean := false;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return true if specified item exists in list
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 09.07.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_index := p_list.first;
|
||||
while (l_index is not null) loop
|
||||
if p_list(l_index) = p_item then
|
||||
l_returnvalue := true;
|
||||
exit;
|
||||
end if;
|
||||
l_index := p_list.next(l_index);
|
||||
end loop;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end is_item_in_list;
|
||||
|
||||
|
||||
function get_apex_session_value (p_value_name in varchar2) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get Apex session value
|
||||
|
||||
Remarks: if a package is called outside the Apex framework (but in a valid session -- see setup_apex_session_context),
|
||||
the session values are not available via apex_util.get_session_state or the V function, see http://forums.oracle.com/forums/thread.jspa?threadID=916301
|
||||
a workaround is to use the "do_substitutions" function, see http://apex-smb.blogspot.com/2009/07/apexapplicationdosubstitutions.html
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 26.01.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := apex_application.do_substitutions(chr(38) || upper(p_value_name) || '.');
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_apex_session_value;
|
||||
|
||||
|
||||
|
||||
end apex_util_pkg;
|
||||
/
|
||||
134
ora/apex_util_pkg.pks
Executable file
134
ora/apex_util_pkg.pks
Executable file
@ -0,0 +1,134 @@
|
||||
create or replace package apex_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: package provides general Apex utilities
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 12.06.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
g_apex_null_str constant varchar2(6) := chr(37) || 'null' || chr(37);
|
||||
g_apex_undefined_str constant varchar2(9) := 'undefined';
|
||||
g_apex_list_separator constant varchar2(1) := ':';
|
||||
|
||||
-- use these in combination with apex_util.ir_filter
|
||||
g_ir_filter_equals constant varchar2(10) := 'EQ';
|
||||
g_ir_filter_less_than constant varchar2(10) := 'LT';
|
||||
g_ir_filter_less_than_or_eq constant varchar2(10) := 'LTE';
|
||||
g_ir_filter_greater_than constant varchar2(10) := 'GT';
|
||||
g_ir_filter_greater_than_or_eq constant varchar2(10) := 'GTE';
|
||||
g_ir_filter_like constant varchar2(10) := 'LIKE';
|
||||
g_ir_filter_null constant varchar2(10) := 'N';
|
||||
g_ir_filter_not_null constant varchar2(10) := 'NN';
|
||||
|
||||
g_ir_reset constant varchar2(10) := 'RIR';
|
||||
|
||||
-- get page name
|
||||
function get_page_name (p_application_id in number,
|
||||
p_page_id in number) return varchar2;
|
||||
|
||||
-- get item name for page and item
|
||||
function get_item_name (p_page_id in number,
|
||||
p_item_name in varchar2) return varchar2;
|
||||
|
||||
-- get page help text
|
||||
function get_page_help_text (p_application_id in number,
|
||||
p_page_id in number) return varchar2;
|
||||
|
||||
-- return apex url
|
||||
function get_apex_url (p_page_id in varchar2,
|
||||
p_request in varchar2 := null,
|
||||
p_item_names in varchar2 := null,
|
||||
p_item_values in varchar2 := null,
|
||||
p_debug in varchar2 := null,
|
||||
p_application_id in varchar2 := null,
|
||||
p_session_id in number := null,
|
||||
p_clear_cache in varchar2 := null) return varchar2;
|
||||
|
||||
-- return apex url (simple syntax)
|
||||
function get_apex_url_simple (p_page_id in varchar2,
|
||||
p_item_name in varchar2 := null,
|
||||
p_item_value in varchar2 := null,
|
||||
p_request in varchar2 := null) return varchar2;
|
||||
|
||||
-- get apex url item names
|
||||
function get_apex_url_item_names (p_page_id in number,
|
||||
p_item_name_array in t_str_array) return varchar2;
|
||||
|
||||
-- get item values
|
||||
function get_apex_url_item_values (p_item_value_array in t_str_array) return varchar2;
|
||||
|
||||
-- get query of dynamic lov
|
||||
function get_dynamic_lov_query (p_application_id in number,
|
||||
p_lov_name in varchar2) return varchar2;
|
||||
|
||||
-- set Apex security context
|
||||
procedure set_apex_security_context (p_schema in varchar2);
|
||||
|
||||
-- setup Apex session context
|
||||
procedure setup_apex_session_context (p_application_id in number,
|
||||
p_raise_exception_if_invalid in boolean := true);
|
||||
|
||||
-- get string value
|
||||
function get_str_value (p_str in varchar2) return varchar2;
|
||||
|
||||
-- get number value
|
||||
function get_num_value (p_str in varchar2) return number;
|
||||
|
||||
-- get date value
|
||||
function get_date_value (p_str in varchar2) return date;
|
||||
|
||||
-- set Apex item value (string)
|
||||
procedure set_item (p_page_id in varchar2,
|
||||
p_item_name in varchar2,
|
||||
p_value in varchar2);
|
||||
|
||||
-- set Apex item value (date)
|
||||
procedure set_date_item (p_page_id in varchar2,
|
||||
p_item_name in varchar2,
|
||||
p_value in date,
|
||||
p_date_format in varchar2 := null);
|
||||
|
||||
-- get Apex item value (string)
|
||||
function get_item (p_page_id in varchar2,
|
||||
p_item_name in varchar2,
|
||||
p_max_length in number := null) return varchar2;
|
||||
|
||||
-- get Apex item value (number)
|
||||
function get_num_item (p_page_id in varchar2,
|
||||
p_item_name in varchar2) return number;
|
||||
|
||||
-- get Apex item value (date)
|
||||
function get_date_item (p_page_id in varchar2,
|
||||
p_item_name in varchar2) return date;
|
||||
|
||||
-- get multiple item values from page into custom record type
|
||||
procedure get_items (p_app_id in number,
|
||||
p_page_id in number,
|
||||
p_target in varchar2,
|
||||
p_exclude_items in t_str_array := null);
|
||||
|
||||
-- set multiple item values on page based on custom record type
|
||||
procedure set_items (p_app_id in number,
|
||||
p_page_id in number,
|
||||
p_source in varchar2,
|
||||
p_exclude_items in t_str_array := null);
|
||||
|
||||
-- return true if item is in list
|
||||
function is_item_in_list (p_item in varchar2,
|
||||
p_list in apex_application_global.vc_arr2) return boolean;
|
||||
|
||||
-- get Apex session value
|
||||
function get_apex_session_value (p_value_name in varchar2) return varchar2;
|
||||
|
||||
|
||||
end apex_util_pkg;
|
||||
/
|
||||
|
||||
82
ora/crypto_util_pkg.pkb
Executable file
82
ora/crypto_util_pkg.pkb
Executable file
@ -0,0 +1,82 @@
|
||||
create or replace package body crypto_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles encryption/decryption
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 20.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
g_encryption_type_aes constant pls_integer := dbms_crypto.encrypt_aes256 + dbms_crypto.chain_cbc + dbms_crypto.pad_pkcs5;
|
||||
|
||||
|
||||
function encrypt_aes256 (p_blob in blob,
|
||||
p_key in varchar2) return blob
|
||||
as
|
||||
l_key_raw raw(32);
|
||||
l_returnvalue blob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: encrypt blob
|
||||
|
||||
Remarks: p_key should be 32 characters (256 bits / 8 = 32 bytes)
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 20.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_key_raw := utl_raw.cast_to_raw (p_key);
|
||||
|
||||
dbms_lob.createtemporary (l_returnvalue, false);
|
||||
|
||||
dbms_crypto.encrypt (l_returnvalue, p_blob, g_encryption_type_aes, l_key_raw);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end encrypt_aes256;
|
||||
|
||||
|
||||
function decrypt_aes256 (p_blob in blob,
|
||||
p_key in varchar2) return blob
|
||||
as
|
||||
l_key_raw raw(32);
|
||||
l_returnvalue blob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: decrypt blob
|
||||
|
||||
Remarks: p_key should be 32 characters (256 bits / 8 = 32 bytes)
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 20.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_key_raw := utl_raw.cast_to_raw (p_key);
|
||||
|
||||
dbms_lob.createtemporary (l_returnvalue, false);
|
||||
|
||||
dbms_crypto.decrypt (l_returnvalue, p_blob, g_encryption_type_aes, l_key_raw);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end decrypt_aes256;
|
||||
|
||||
|
||||
end crypto_util_pkg;
|
||||
/
|
||||
|
||||
|
||||
29
ora/crypto_util_pkg.pks
Executable file
29
ora/crypto_util_pkg.pks
Executable file
@ -0,0 +1,29 @@
|
||||
create or replace package crypto_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles encryption/decryption
|
||||
|
||||
Remarks: see http://download.oracle.com/docs/cd/B14117_01/network.101/b10773/apdvncrp.htm
|
||||
see "Effective Oracle Database 10g Security" by David Knox (McGraw Hill 2004)
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 20.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
-- encrypt blob
|
||||
function encrypt_aes256 (p_blob in blob,
|
||||
p_key in varchar2) return blob;
|
||||
|
||||
-- decrypt blob
|
||||
function decrypt_aes256 (p_blob in blob,
|
||||
p_key in varchar2) return blob;
|
||||
|
||||
|
||||
end crypto_util_pkg;
|
||||
/
|
||||
|
||||
311
ora/csv_util_pkg.pkb
Executable file
311
ora/csv_util_pkg.pkb
Executable file
@ -0,0 +1,311 @@
|
||||
create or replace package body csv_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles comma-separated values (CSV)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 31.03.2010 Created
|
||||
KJS 20.04.2011 Modified to allow double-quote escaping
|
||||
|
||||
*/
|
||||
|
||||
|
||||
function csv_to_array (p_csv_line in varchar2,
|
||||
p_separator in varchar2 := g_default_separator) return t_str_array
|
||||
as
|
||||
l_returnvalue t_str_array := t_str_array();
|
||||
l_length pls_integer := length(p_csv_line);
|
||||
l_idx binary_integer := 1;
|
||||
l_quoted boolean := false;
|
||||
l_quote constant varchar2(1) := '"';
|
||||
l_start boolean := true;
|
||||
l_current varchar2(1 char);
|
||||
l_next varchar2(1 char);
|
||||
l_position pls_integer := 1;
|
||||
l_current_column varchar2(32767);
|
||||
|
||||
--Set the start flag, save our column value
|
||||
procedure save_column is
|
||||
begin
|
||||
l_start := true;
|
||||
l_returnvalue.extend;
|
||||
l_returnvalue(l_idx) := l_current_column;
|
||||
l_idx := l_idx + 1;
|
||||
l_current_column := null;
|
||||
end save_column;
|
||||
|
||||
--Append the value of l_current to l_current_column
|
||||
procedure append_current is
|
||||
begin
|
||||
l_current_column := l_current_column || l_current;
|
||||
end append_current;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: convert CSV line to array of values
|
||||
|
||||
Remarks: based on code from http://www.experts-exchange.com/Database/Oracle/PL_SQL/Q_23106446.html
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 31.03.2010 Created
|
||||
KJS 20.04.2011 Modified to allow double-quote escaping
|
||||
MBR 23.07.2012 Fixed issue with multibyte characters, thanks to Vadi..., see http://code.google.com/p/plsql-utils/issues/detail?id=13
|
||||
|
||||
*/
|
||||
|
||||
while l_position <= l_length loop
|
||||
|
||||
--Set our variables with the current and next characters
|
||||
l_current := substr(p_csv_line, l_position, 1);
|
||||
l_next := substr(p_csv_line, l_position + 1, 1);
|
||||
|
||||
if l_start then
|
||||
l_start := false;
|
||||
l_current_column := null;
|
||||
|
||||
--Check for leading quote and set our flag
|
||||
l_quoted := l_current = l_quote;
|
||||
|
||||
--We skip a leading quote character
|
||||
if l_quoted then goto loop_again; end if;
|
||||
end if;
|
||||
|
||||
--Check to see if we are inside of a quote
|
||||
if l_quoted then
|
||||
|
||||
--The current character is a quote - is it the end of our quote or does
|
||||
--it represent an escaped quote?
|
||||
if l_current = l_quote then
|
||||
|
||||
--If the next character is a quote, this is an escaped quote.
|
||||
if l_next = l_quote then
|
||||
|
||||
--Append the literal quote to our column
|
||||
append_current;
|
||||
|
||||
--Advance the pointer to ignore the duplicated (escaped) quote
|
||||
l_position := l_position + 1;
|
||||
|
||||
--If the next character is a separator, current is the end quote
|
||||
elsif l_next = p_separator then
|
||||
|
||||
--Get out of the quote and loop again - we will hit the separator next loop
|
||||
l_quoted := false;
|
||||
goto loop_again;
|
||||
|
||||
--Ending quote, no more columns
|
||||
elsif l_next is null then
|
||||
|
||||
--Save our current value, and iterate (end loop)
|
||||
save_column;
|
||||
goto loop_again;
|
||||
|
||||
--Next character is not a quote
|
||||
else
|
||||
append_current;
|
||||
end if;
|
||||
else
|
||||
|
||||
--The current character is not a quote - append it to our column value
|
||||
append_current;
|
||||
end if;
|
||||
|
||||
-- Not quoted
|
||||
else
|
||||
|
||||
--Check if the current value is a separator, save or append as appropriate
|
||||
if l_current = p_separator then
|
||||
save_column;
|
||||
else
|
||||
append_current;
|
||||
end if;
|
||||
end if;
|
||||
|
||||
--Check to see if we've used all our characters
|
||||
if l_next is null then
|
||||
save_column;
|
||||
end if;
|
||||
|
||||
--The continue statement was not added to PL/SQL until 11g. Use GOTO in 9i.
|
||||
<<loop_again>> l_position := l_position + 1;
|
||||
end loop ;
|
||||
|
||||
return l_returnvalue;
|
||||
end csv_to_array;
|
||||
|
||||
|
||||
function array_to_csv (p_values in t_str_array,
|
||||
p_separator in varchar2 := g_default_separator) return varchar2
|
||||
as
|
||||
l_value varchar2(32767);
|
||||
l_returnvalue varchar2(32767);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: convert array of values to CSV
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 31.03.2010 Created
|
||||
KJS 20.04.2011 Modified to allow quoted data, fixed a bug when 1st col was null
|
||||
*/
|
||||
|
||||
for i in p_values.first .. p_values.last loop
|
||||
|
||||
--Double quotes must be escaped
|
||||
l_value := replace(p_values(i), '"', '""');
|
||||
|
||||
--Values containing the separator, a double quote, or a new line must be quoted.
|
||||
if instr(l_value, p_separator) > 0 or instr(l_value, '"') > 0 or instr(l_value, chr(10)) > 0 then
|
||||
l_value := '"' || l_value || '"';
|
||||
end if;
|
||||
|
||||
--Append our value to our return value
|
||||
if i = p_values.first then
|
||||
l_returnvalue := l_value;
|
||||
else
|
||||
l_returnvalue := l_returnvalue || p_separator || l_value;
|
||||
end if;
|
||||
end loop;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end array_to_csv;
|
||||
|
||||
|
||||
function get_array_value (p_values in t_str_array,
|
||||
p_position in number,
|
||||
p_column_name in varchar2 := null) return varchar2
|
||||
as
|
||||
l_returnvalue varchar2(4000);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get value from array by position
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 31.03.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
if p_values.count >= p_position then
|
||||
l_returnvalue := p_values(p_position);
|
||||
else
|
||||
if p_column_name is not null then
|
||||
raise_application_error (-20000, 'Column number ' || p_position || ' does not exist. Expected column: ' || p_column_name);
|
||||
else
|
||||
l_returnvalue := null;
|
||||
end if;
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_array_value;
|
||||
|
||||
|
||||
function clob_to_csv (p_csv_clob in clob,
|
||||
p_separator in varchar2 := g_default_separator,
|
||||
p_skip_rows in number := 0) return t_csv_tab pipelined
|
||||
as
|
||||
l_line_separator varchar2(2) := chr(13) || chr(10);
|
||||
l_last pls_integer;
|
||||
l_current pls_integer;
|
||||
l_line varchar2(32000);
|
||||
l_line_number pls_integer := 0;
|
||||
l_from_line pls_integer := p_skip_rows + 1;
|
||||
l_line_array t_str_array;
|
||||
l_row t_csv_line := t_csv_line (null, null, -- line number, line raw
|
||||
null, null, null, null, null, null, null, null, null, null, -- lines 1-10
|
||||
null, null, null, null, null, null, null, null, null, null); -- lines 11-20
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: convert clob to CSV
|
||||
|
||||
Remarks: based on code from http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:1352202934074
|
||||
and http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:744825627183
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 31.03.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
-- If the file has a DOS newline (cr+lf), use that
|
||||
-- If the file does not have a DOS newline, use a Unix newline (lf)
|
||||
if (nvl(dbms_lob.instr(p_csv_clob, l_line_separator, 1, 1),0) = 0) then
|
||||
l_line_separator := chr(10);
|
||||
end if;
|
||||
|
||||
l_last := 1;
|
||||
|
||||
loop
|
||||
|
||||
l_current := dbms_lob.instr (p_csv_clob || l_line_separator, l_line_separator, l_last, 1);
|
||||
exit when (nvl(l_current,0) = 0);
|
||||
|
||||
l_line_number := l_line_number + 1;
|
||||
|
||||
if l_from_line <= l_line_number then
|
||||
|
||||
l_line := dbms_lob.substr(p_csv_clob || l_line_separator, l_current - l_last + 1, l_last);
|
||||
--l_line := replace(l_line, l_line_separator, '');
|
||||
l_line := replace(l_line, chr(10), '');
|
||||
l_line := replace(l_line, chr(13), '');
|
||||
|
||||
l_line_array := csv_to_array (l_line, p_separator);
|
||||
|
||||
l_row.line_number := l_line_number;
|
||||
l_row.line_raw := substr(l_line,1,4000);
|
||||
l_row.c001 := get_array_value (l_line_array, 1);
|
||||
l_row.c002 := get_array_value (l_line_array, 2);
|
||||
l_row.c003 := get_array_value (l_line_array, 3);
|
||||
l_row.c004 := get_array_value (l_line_array, 4);
|
||||
l_row.c005 := get_array_value (l_line_array, 5);
|
||||
l_row.c006 := get_array_value (l_line_array, 6);
|
||||
l_row.c007 := get_array_value (l_line_array, 7);
|
||||
l_row.c008 := get_array_value (l_line_array, 8);
|
||||
l_row.c009 := get_array_value (l_line_array, 9);
|
||||
l_row.c010 := get_array_value (l_line_array, 10);
|
||||
l_row.c011 := get_array_value (l_line_array, 11);
|
||||
l_row.c012 := get_array_value (l_line_array, 12);
|
||||
l_row.c013 := get_array_value (l_line_array, 13);
|
||||
l_row.c014 := get_array_value (l_line_array, 14);
|
||||
l_row.c015 := get_array_value (l_line_array, 15);
|
||||
l_row.c016 := get_array_value (l_line_array, 16);
|
||||
l_row.c017 := get_array_value (l_line_array, 17);
|
||||
l_row.c018 := get_array_value (l_line_array, 18);
|
||||
l_row.c019 := get_array_value (l_line_array, 19);
|
||||
l_row.c020 := get_array_value (l_line_array, 20);
|
||||
|
||||
pipe row (l_row);
|
||||
|
||||
end if;
|
||||
|
||||
l_last := l_current + length (l_line_separator);
|
||||
|
||||
end loop;
|
||||
|
||||
return;
|
||||
|
||||
end clob_to_csv;
|
||||
|
||||
|
||||
end csv_util_pkg;
|
||||
/
|
||||
|
||||
39
ora/csv_util_pkg.pks
Executable file
39
ora/csv_util_pkg.pks
Executable file
@ -0,0 +1,39 @@
|
||||
create or replace package csv_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles comma-separated values (CSV)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 31.03.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
g_default_separator constant varchar2(1) := ',';
|
||||
|
||||
|
||||
-- convert CSV line to array of values
|
||||
function csv_to_array (p_csv_line in varchar2,
|
||||
p_separator in varchar2 := g_default_separator) return t_str_array;
|
||||
|
||||
-- convert array of values to CSV
|
||||
function array_to_csv (p_values in t_str_array,
|
||||
p_separator in varchar2 := g_default_separator) return varchar2;
|
||||
|
||||
-- get value from array by position
|
||||
function get_array_value (p_values in t_str_array,
|
||||
p_position in number,
|
||||
p_column_name in varchar2 := null) return varchar2;
|
||||
|
||||
-- convert clob to CSV
|
||||
function clob_to_csv (p_csv_clob in clob,
|
||||
p_separator in varchar2 := g_default_separator,
|
||||
p_skip_rows in number := 0) return t_csv_tab pipelined;
|
||||
|
||||
end csv_util_pkg;
|
||||
/
|
||||
|
||||
146
ora/datapump_util_pkg.pkb
Executable file
146
ora/datapump_util_pkg.pkb
Executable file
@ -0,0 +1,146 @@
|
||||
create or replace package body datapump_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package contains Data Pump utilities
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 04.11.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
procedure export_schema_to_file (p_directory_name in varchar2,
|
||||
p_file_name in varchar2 := null,
|
||||
p_version in varchar2 := null,
|
||||
p_log_message in varchar2 := null,
|
||||
p_compress in boolean := false)
|
||||
as
|
||||
l_job_handle number;
|
||||
l_job_status varchar2(30); -- COMPLETED or STOPPED
|
||||
l_file_name varchar2(2000) := nvl(p_file_name, 'export_' || lower(user) || '_' || to_char(sysdate, 'yyyymmddhh24miss'));
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: export (current) schema to file
|
||||
|
||||
Remarks: the file name, if specified, should not include the extension, as it will be used for both dump and log files
|
||||
specify the p_version parameter if intending to import into an older database (such as '10.2' for XE)
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 04.11.2011 Created
|
||||
MBR 07.08.2012 Added parameter to specify compression
|
||||
|
||||
*/
|
||||
|
||||
l_job_handle := dbms_datapump.open ('EXPORT', 'SCHEMA', version => nvl(p_version, 'COMPATIBLE'));
|
||||
|
||||
dbms_datapump.add_file (l_job_handle, l_file_name || '.dmp', p_directory_name);
|
||||
dbms_datapump.add_file (l_job_handle, l_file_name || '.log', p_directory_name, filetype => dbms_datapump.ku$_file_type_log_file);
|
||||
|
||||
-- may set additional filters, not neccessary for full export of current schema
|
||||
-- see http://forums.oracle.com/forums/thread.jspa?messageID=9726231
|
||||
--dbms_datapump.metadata_filter (l_job_handle, 'SCHEMA_LIST', user);
|
||||
|
||||
-- compression (note: p_version should be at least 11.1 to support this)
|
||||
if p_compress then
|
||||
dbms_datapump.set_parameter (l_job_handle, 'COMPRESSION', 'ALL');
|
||||
end if;
|
||||
|
||||
dbms_datapump.start_job (l_job_handle);
|
||||
|
||||
if p_log_message is not null then
|
||||
dbms_datapump.log_entry (l_job_handle, p_log_message);
|
||||
end if;
|
||||
|
||||
dbms_datapump.wait_for_job (l_job_handle, l_job_status);
|
||||
|
||||
dbms_datapump.detach (l_job_handle);
|
||||
|
||||
debug_pkg.printf('Job status = %1, file name = %2', l_job_status, l_file_name);
|
||||
|
||||
if l_job_status not in ('COMPLETED', 'STOPPED') then
|
||||
raise_application_error (-20000, string_util_pkg.get_str('The data pump job exited with status = %1 (file name = %2).', l_job_status, l_file_name));
|
||||
end if;
|
||||
|
||||
end export_schema_to_file;
|
||||
|
||||
|
||||
procedure import_schema_from_file (p_directory_name in varchar2,
|
||||
p_file_name in varchar2,
|
||||
p_log_file_name in varchar2 := null,
|
||||
p_remap_from_schema in varchar2 := null,
|
||||
p_remap_to_schema in varchar2 := null,
|
||||
p_table_data_only in boolean := false)
|
||||
as
|
||||
|
||||
l_job_handle number;
|
||||
l_job_status varchar2(30); -- COMPLETED or STOPPED
|
||||
|
||||
l_from_schema varchar2(30) := nvl(p_remap_from_schema, user);
|
||||
l_to_schema varchar2(30) := nvl(p_remap_to_schema, user);
|
||||
|
||||
l_log_file_name varchar2(2000) := nvl(p_log_file_name, p_file_name || '_import_' || to_char(sysdate, 'yyyymmddhh24miss') || '.log');
|
||||
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: import schema from file
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 04.11.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_job_handle := dbms_datapump.open ('IMPORT', 'SCHEMA');
|
||||
|
||||
dbms_datapump.add_file (l_job_handle, p_file_name, p_directory_name);
|
||||
dbms_datapump.add_file (l_job_handle, l_log_file_name, p_directory_name, filetype => dbms_datapump.ku$_file_type_log_file);
|
||||
|
||||
-- see http://download.oracle.com/docs/cd/B28359_01/server.111/b28319/dp_import.htm
|
||||
|
||||
-- "If your dump file set does not contain the metadata necessary to create a schema, or if you do not have privileges, then the target schema must be created before the import operation is performed."
|
||||
-- "Nonprivileged users can perform schema remaps only if their schema is the target schema of the remap."
|
||||
|
||||
if l_from_schema <> l_to_schema then
|
||||
dbms_datapump.metadata_remap (l_job_handle, 'REMAP_SCHEMA', l_from_schema, l_to_schema);
|
||||
end if;
|
||||
|
||||
-- workaround for performance bug in 10.2, see http://forums.oracle.com/forums/thread.jspa?threadID=401886
|
||||
dbms_datapump.metadata_filter (l_job_handle, 'EXCLUDE_PATH_LIST', '''STATISTICS'''); -- note the double quotes
|
||||
|
||||
if p_table_data_only then
|
||||
dbms_datapump.metadata_filter (l_job_handle, 'INCLUDE_PATH_LIST', '''TABLE'''); -- note the double quotes
|
||||
-- TODO: investigate the "TABLE_EXISTS_ACTION" parameter
|
||||
end if;
|
||||
|
||||
dbms_datapump.start_job (l_job_handle);
|
||||
|
||||
dbms_datapump.wait_for_job (l_job_handle, l_job_status);
|
||||
|
||||
dbms_datapump.detach (l_job_handle);
|
||||
|
||||
if l_job_status in ('COMPLETED', 'STOPPED') then
|
||||
debug_pkg.printf ('SUCCESS: Job status %1, log file name %2', l_job_status, l_log_file_name);
|
||||
else
|
||||
debug_pkg.printf ('WARNING: The job exited with status %1, log file name %2', l_job_status, l_log_file_name);
|
||||
end if;
|
||||
|
||||
end import_schema_from_file;
|
||||
|
||||
|
||||
end datapump_util_pkg;
|
||||
/
|
||||
|
||||
|
||||
|
||||
35
ora/datapump_util_pkg.pks
Executable file
35
ora/datapump_util_pkg.pks
Executable file
@ -0,0 +1,35 @@
|
||||
create or replace package datapump_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package contains Data Pump utilities
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 04.11.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
-- export (current) schema to file
|
||||
procedure export_schema_to_file (p_directory_name in varchar2,
|
||||
p_file_name in varchar2 := null,
|
||||
p_version in varchar2 := null,
|
||||
p_log_message in varchar2 := null,
|
||||
p_compress in boolean := false);
|
||||
|
||||
-- import schema from file
|
||||
procedure import_schema_from_file (p_directory_name in varchar2,
|
||||
p_file_name in varchar2,
|
||||
p_log_file_name in varchar2 := null,
|
||||
p_remap_from_schema in varchar2 := null,
|
||||
p_remap_to_schema in varchar2 := null,
|
||||
p_table_data_only in boolean := false);
|
||||
|
||||
|
||||
end datapump_util_pkg;
|
||||
/
|
||||
|
||||
632
ora/date_util_pkg.pkb
Executable file
632
ora/date_util_pkg.pkb
Executable file
@ -0,0 +1,632 @@
|
||||
CREATE OR REPLACE package body date_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles functionality related to date and time
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 19.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
function get_year (p_date in date) return number
|
||||
as
|
||||
l_returnvalue number;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return year based on date
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 19.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue:=to_number(to_char(p_date, 'YYYY'));
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_year;
|
||||
|
||||
|
||||
function get_month (p_date in date) return number
|
||||
as
|
||||
l_returnvalue number;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return month based on date
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 19.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue:=to_number(to_char(p_date, 'MM'));
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_month;
|
||||
|
||||
|
||||
function get_start_date_year (p_date in date) return date
|
||||
as
|
||||
l_returnvalue date;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return start date of year based on date
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 19.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue:=to_date('01.01.' || to_char(get_year(p_date)), 'DD.MM.YYYY');
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_start_date_year;
|
||||
|
||||
|
||||
function get_start_date_year (p_year in number) return date
|
||||
as
|
||||
l_returnvalue date;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return start date of year
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 19.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue:=to_date('01.01.' || to_char(p_year), 'DD.MM.YYYY');
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_start_date_year;
|
||||
|
||||
|
||||
function get_end_date_year (p_date in date) return date
|
||||
as
|
||||
l_returnvalue date;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return end date of year based on date
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 19.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue:=to_date('31.12.' || to_char(get_year(p_date)), 'DD.MM.YYYY');
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_end_date_year;
|
||||
|
||||
|
||||
function get_end_date_year (p_year in number) return date
|
||||
as
|
||||
l_returnvalue date;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return end date of year
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 19.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue:=to_date('31.12.' || to_char(p_year), 'DD.MM.YYYY');
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_end_date_year;
|
||||
|
||||
|
||||
function get_start_date_month (p_date in date) return date
|
||||
as
|
||||
l_returnvalue date;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return start date of month based on date
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 19.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue:=to_date('01.' || to_char(lpad(get_month(p_date),2,'0')) || '.' || to_char(get_year(p_date)), 'DD.MM.YYYY');
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_start_date_month;
|
||||
|
||||
|
||||
function get_start_date_month (p_year in number,
|
||||
p_month in number) return date
|
||||
as
|
||||
l_returnvalue date;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return start date of month
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 19.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue:=to_date('01.' || to_char(lpad(p_month,2,'0')) || '.' || to_char(p_year), 'DD.MM.YYYY');
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_start_date_month;
|
||||
|
||||
|
||||
function get_end_date_month (p_date in date) return date
|
||||
as
|
||||
l_returnvalue date;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return end date of month based on date
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 19.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue:=last_day(trunc(p_date));
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_end_date_month;
|
||||
|
||||
|
||||
function get_end_date_month (p_year in number,
|
||||
p_month in number) return date
|
||||
as
|
||||
l_returnvalue date;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return end date of month
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 19.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue:=last_day(trunc(get_start_date_month(p_year, p_month)));
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_end_date_month;
|
||||
|
||||
|
||||
function get_days_in_month (p_year in number,
|
||||
p_month in number) return number
|
||||
as
|
||||
l_returnvalue number;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return number of days in given month
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 19.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue:=get_end_date_month(p_year, p_month) - get_start_date_month(p_year, p_month) + 1;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_days_in_month;
|
||||
|
||||
|
||||
function get_days_in_period (p_from_date_1 in date,
|
||||
p_to_date_1 in date,
|
||||
p_from_date_2 in date,
|
||||
p_to_date_2 in date) return number
|
||||
as
|
||||
l_returnvalue number;
|
||||
l_begin_date date;
|
||||
l_end_date date;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return number of days in one period that fall within another period
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 19.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
if p_to_date_2 > p_from_date_1 then
|
||||
|
||||
if p_from_date_1 < p_from_date_2 then
|
||||
l_begin_date := p_from_date_2;
|
||||
else
|
||||
l_begin_date := p_from_date_1;
|
||||
end if;
|
||||
|
||||
if p_to_date_1 > p_to_date_2 then
|
||||
l_end_date := p_to_date_2;
|
||||
else
|
||||
l_end_date := p_to_date_1;
|
||||
end if;
|
||||
|
||||
l_returnvalue := l_end_date - l_begin_date;
|
||||
|
||||
else
|
||||
l_returnvalue := 0;
|
||||
end if;
|
||||
|
||||
if l_returnvalue < 0 then
|
||||
l_returnvalue := 0;
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_days_in_period;
|
||||
|
||||
|
||||
function is_period_in_range (p_year in number,
|
||||
p_month in number,
|
||||
p_from_year in number,
|
||||
p_from_month in number,
|
||||
p_to_year in number,
|
||||
p_to_month in number) return boolean
|
||||
as
|
||||
l_returnvalue boolean := false;
|
||||
|
||||
l_date date;
|
||||
l_start_date date;
|
||||
l_end_date date;
|
||||
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: returns true if period falls within range
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 26.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
-- if (p_year between p_from_year and p_to_year) then
|
||||
-- if (p_year < p_to_year) or (p_year = p_to_year and p_month <= p_to_month) or (p_year = p_from_year and p_month >= p_from_month) then
|
||||
-- l_returnvalue:=true;
|
||||
-- end if;
|
||||
-- end if;
|
||||
|
||||
l_date:=get_start_date_month(p_year, p_month);
|
||||
l_start_date:=get_start_date_month (p_from_year, p_from_month);
|
||||
l_end_date:=get_end_date_month (p_to_year, p_to_month);
|
||||
|
||||
if l_date between l_start_date and l_end_date then
|
||||
l_returnvalue:=true;
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end is_period_in_range;
|
||||
|
||||
|
||||
function get_quarter (p_month in number) return number
|
||||
as
|
||||
l_returnvalue number;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get quarter based on month
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 24.11.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
if p_month in (1,2,3) then
|
||||
l_returnvalue:=1;
|
||||
elsif p_month in (4,5,6) then
|
||||
l_returnvalue:=2;
|
||||
elsif p_month in (7,8,9) then
|
||||
l_returnvalue:=3;
|
||||
elsif p_month in (10,11,12) then
|
||||
l_returnvalue:=4;
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_quarter;
|
||||
|
||||
|
||||
function fmt_time (p_days in number) return varchar2
|
||||
as
|
||||
l_days number;
|
||||
l_hours number;
|
||||
l_minutes number;
|
||||
l_seconds number;
|
||||
l_sign varchar2(6);
|
||||
l_returnvalue string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get time formatted as days, hours, minutes, seconds
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 18.12.2006 Created
|
||||
MBR 19.01.2012 Fixed: Sometimes incorrect results due to rounding minutes
|
||||
MBR 02.09.2012 Improved formatting
|
||||
MBR 11.11.2012 Removed seconds from display of "X hours, Y minutes"
|
||||
|
||||
*/
|
||||
|
||||
l_days := nvl(trunc(p_days),0);
|
||||
l_hours := nvl(((p_days - l_days) * 24), 0);
|
||||
l_minutes := nvl(((l_hours - trunc(l_hours))) * 60, 0);
|
||||
l_seconds := nvl(((l_minutes - trunc(l_minutes))) * 60, 0);
|
||||
|
||||
if p_days < 0 then
|
||||
l_sign:='minus ';
|
||||
else
|
||||
l_sign:='';
|
||||
end if;
|
||||
|
||||
l_days:=abs(l_days);
|
||||
l_hours:=trunc(abs(l_hours));
|
||||
--l_minutes:=round(abs(l_minutes));
|
||||
l_minutes:=trunc(abs(l_minutes));
|
||||
l_seconds:=round(abs(l_seconds));
|
||||
|
||||
if l_minutes = 60 then
|
||||
l_hours:=l_hours + 1;
|
||||
l_minutes:=0;
|
||||
end if;
|
||||
|
||||
if (l_days > 0) and (l_hours = 0) then
|
||||
l_returnvalue:=string_util_pkg.get_str('%1 days', l_days);
|
||||
elsif (l_days > 0) then
|
||||
l_returnvalue:=string_util_pkg.get_str('%1 days, %2 hours, %3 minutes', l_days, l_hours, l_minutes);
|
||||
elsif (l_hours > 0) and (l_minutes = 0) then
|
||||
l_returnvalue:=string_util_pkg.get_str('%1 hours', l_hours);
|
||||
elsif (l_hours > 0) then
|
||||
l_returnvalue:=string_util_pkg.get_str('%1 hours, %2 minutes', l_hours, l_minutes);
|
||||
elsif (l_minutes > 0) and (l_seconds = 0) then
|
||||
l_returnvalue:=string_util_pkg.get_str('%1 minutes', l_minutes);
|
||||
elsif (l_minutes > 0) then
|
||||
l_returnvalue:=string_util_pkg.get_str('%1 minutes, %2 seconds', l_minutes, l_seconds);
|
||||
else
|
||||
l_returnvalue:=string_util_pkg.get_str('%1 seconds', l_seconds);
|
||||
end if;
|
||||
|
||||
l_returnvalue:=l_sign || l_returnvalue;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end fmt_time;
|
||||
|
||||
|
||||
function fmt_time (p_from_date in date,
|
||||
p_to_date in date) return varchar2
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get time between two dates formatted as days, hours, minutes, seconds
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 18.12.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
return fmt_time (p_to_date - p_from_date);
|
||||
|
||||
end fmt_time;
|
||||
|
||||
|
||||
function fmt_date (p_date in date) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: format date as date
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 06.10.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := to_char(p_date, g_date_fmt_date);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end fmt_date;
|
||||
|
||||
|
||||
function fmt_datetime (p_date in date) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: format date as datetime
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
FDL 15.04.2010 Created
|
||||
MBR 06.10.2010 Use date format defined in appl_pkg
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := to_char(p_date, g_date_fmt_date_hour_min);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end fmt_datetime;
|
||||
|
||||
|
||||
function get_days_in_year (p_year in number) return number
|
||||
as
|
||||
l_returnvalue number;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get number of days in year
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
FDL 21.04.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := get_start_date_month ((p_year + 1), 1) - get_start_date_month (p_year, 1);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_days_in_year;
|
||||
|
||||
|
||||
function explode_month (p_year in number,
|
||||
p_month in number) return t_period_date_tab pipelined
|
||||
as
|
||||
l_date date;
|
||||
l_start_date date;
|
||||
l_end_date date;
|
||||
l_day pls_integer := 0;
|
||||
l_returnvalue t_period_date;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: returns collection of dates in specified month
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 30.06.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue.year := p_year;
|
||||
l_returnvalue.month := p_month;
|
||||
|
||||
l_start_date := get_start_date_month (p_year, p_month);
|
||||
l_end_date := get_end_date_month (p_year, p_month);
|
||||
|
||||
l_returnvalue.days_in_month := l_end_date - l_start_date + 1;
|
||||
|
||||
l_date := l_start_date;
|
||||
|
||||
loop
|
||||
|
||||
l_day := l_day + 1;
|
||||
l_returnvalue.day := l_day;
|
||||
l_returnvalue.the_date := l_date;
|
||||
|
||||
pipe row (l_returnvalue);
|
||||
|
||||
if l_date >= l_end_date then
|
||||
exit;
|
||||
end if;
|
||||
|
||||
l_date := l_date + 1;
|
||||
|
||||
end loop;
|
||||
|
||||
return;
|
||||
|
||||
end explode_month;
|
||||
|
||||
|
||||
end date_util_pkg;
|
||||
/
|
||||
107
ora/date_util_pkg.pks
Executable file
107
ora/date_util_pkg.pks
Executable file
@ -0,0 +1,107 @@
|
||||
CREATE OR REPLACE package date_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles functionality related to date and time
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 19.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
g_date_fmt_date constant varchar2(30) := 'dd.mm.yyyy';
|
||||
g_date_fmt_date_hour_min constant varchar2(30) := 'dd.mm.yyyy hh24:mi';
|
||||
g_date_fmt_date_hour_min_sec constant varchar2(30) := 'dd.mm.yyyy hh24:mi:ss';
|
||||
|
||||
g_months_in_quarter constant number := 3;
|
||||
g_months_in_year constant number := 12;
|
||||
|
||||
type t_period_date is record (
|
||||
year number,
|
||||
month number,
|
||||
day number,
|
||||
days_in_month number,
|
||||
the_date date
|
||||
);
|
||||
|
||||
type t_period_date_tab is table of t_period_date;
|
||||
|
||||
-- return year based on date
|
||||
function get_year (p_date in date) return number;
|
||||
|
||||
-- return month based on date
|
||||
function get_month (p_date in date) return number;
|
||||
|
||||
-- return start date of year based on date
|
||||
function get_start_date_year (p_date in date) return date;
|
||||
|
||||
-- return start date of year
|
||||
function get_start_date_year (p_year in number) return date;
|
||||
|
||||
-- return end date of year based on date
|
||||
function get_end_date_year (p_date in date) return date;
|
||||
|
||||
-- return end date of year
|
||||
function get_end_date_year (p_year in number) return date;
|
||||
|
||||
-- return start date of month based on date
|
||||
function get_start_date_month (p_date in date) return date;
|
||||
|
||||
-- return start date of month
|
||||
function get_start_date_month (p_year in number,
|
||||
p_month in number) return date;
|
||||
|
||||
-- return end date of month based on date
|
||||
function get_end_date_month (p_date in date) return date;
|
||||
|
||||
-- return end date of month
|
||||
function get_end_date_month (p_year in number,
|
||||
p_month in number) return date;
|
||||
|
||||
-- return number of days in given month
|
||||
function get_days_in_month (p_year in number,
|
||||
p_month in number) return number;
|
||||
|
||||
-- return number of days in one period that fall within another period
|
||||
function get_days_in_period (p_from_date_1 in date,
|
||||
p_to_date_1 in date,
|
||||
p_from_date_2 in date,
|
||||
p_to_date_2 in date) return number;
|
||||
|
||||
-- returns true if period falls within range
|
||||
function is_period_in_range (p_year in number,
|
||||
p_month in number,
|
||||
p_from_year in number,
|
||||
p_from_month in number,
|
||||
p_to_year in number,
|
||||
p_to_month in number) return boolean;
|
||||
|
||||
-- get quarter based on month
|
||||
function get_quarter (p_month in number) return number;
|
||||
|
||||
-- get time formatted as days, hours, minutes, seconds
|
||||
function fmt_time (p_days in number) return varchar2;
|
||||
|
||||
-- get time between two dates formatted as days, hours, minutes, seconds
|
||||
function fmt_time (p_from_date in date,
|
||||
p_to_date in date) return varchar2;
|
||||
|
||||
-- get date formatted as date
|
||||
function fmt_date (p_date in date) return varchar2;
|
||||
|
||||
-- get date formatted as date and time
|
||||
function fmt_datetime (p_date in date) return varchar2;
|
||||
|
||||
-- get number of days in year
|
||||
function get_days_in_year (p_year in number) return number;
|
||||
|
||||
-- returns collection of dates in specified month
|
||||
function explode_month (p_year in number,
|
||||
p_month in number) return t_period_date_tab pipelined;
|
||||
|
||||
end date_util_pkg;
|
||||
/
|
||||
427
ora/debug_pkg.pkb
Executable file
427
ora/debug_pkg.pkb
Executable file
@ -0,0 +1,427 @@
|
||||
create or replace package body debug_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: The package handles debug information
|
||||
|
||||
Remarks: Debugging is turned OFF by default
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 14.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
m_debugging boolean := false;
|
||||
|
||||
|
||||
procedure debug_off
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Turn off debugging
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 14.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
m_debugging:=false;
|
||||
|
||||
end debug_off;
|
||||
|
||||
|
||||
procedure debug_on
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Turn on debugging
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 14.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
m_debugging:=true;
|
||||
|
||||
end debug_on;
|
||||
|
||||
|
||||
procedure print (p_msg in varchar2)
|
||||
as
|
||||
l_text varchar2(32000);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Print debug information
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 14.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
if (apex_application.g_debug) then
|
||||
|
||||
apex_application.debug (p_msg);
|
||||
|
||||
elsif (m_debugging) then
|
||||
|
||||
l_text:=to_char(sysdate, 'dd.mm.yyyy hh24:mi:ss') || ': ' || nvl(p_msg, '(null)');
|
||||
|
||||
loop
|
||||
exit when l_text is null;
|
||||
dbms_output.put_line(substr(l_text,1,250));
|
||||
l_text:=substr(l_text, 251);
|
||||
end loop;
|
||||
|
||||
end if;
|
||||
|
||||
end print;
|
||||
|
||||
|
||||
procedure print (p_msg in varchar2,
|
||||
p_value in varchar2)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Print debug information (name/value pair)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 14.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
print (p_msg || ': ' || p_value);
|
||||
|
||||
end print;
|
||||
|
||||
|
||||
procedure print (p_msg in varchar2,
|
||||
p_value in number)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Print debug information (numeric value)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 14.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
print (p_msg || ': ' || nvl(to_char(p_value), '(null)'));
|
||||
|
||||
end print;
|
||||
|
||||
|
||||
procedure print (p_msg in varchar2,
|
||||
p_value in date)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Print debug information (date value)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 14.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
print (p_msg || ': ' || nvl(to_char(p_value, 'dd.mm.yyyy hh24:mi:ss'), '(null)'));
|
||||
|
||||
end print;
|
||||
|
||||
|
||||
procedure print (p_msg in varchar2,
|
||||
p_value in boolean)
|
||||
as
|
||||
l_str varchar2(20);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Print debug information (boolean value)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 23.02.2009 Created
|
||||
|
||||
*/
|
||||
|
||||
if p_value is null then
|
||||
l_str := '(null)';
|
||||
elsif p_value = true then
|
||||
l_str := 'true';
|
||||
else
|
||||
l_str := 'false';
|
||||
end if;
|
||||
|
||||
print (p_msg || ': ' || l_str);
|
||||
|
||||
end print;
|
||||
|
||||
|
||||
procedure print (p_refcursor in sys_refcursor,
|
||||
p_null_handling in number := 0)
|
||||
as
|
||||
l_xml xmltype;
|
||||
l_context dbms_xmlgen.ctxhandle;
|
||||
l_clob clob;
|
||||
|
||||
l_null_self_argument_exc exception;
|
||||
pragma exception_init (l_null_self_argument_exc, -30625);
|
||||
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: print debug information (ref cursor)
|
||||
|
||||
Remarks: outputs weakly typed cursor as XML
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 27.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
-- get a handle on the ref cursor
|
||||
l_context:=dbms_xmlgen.newcontext (p_refcursor);
|
||||
|
||||
/*
|
||||
|
||||
# DROP_NULLS CONSTANT NUMBER:= 0; (Default) Leaves out the tag for NULL elements.
|
||||
# NULL_ATTR CONSTANT NUMBER:= 1; Sets xsi:nil="true".
|
||||
# EMPTY_TAG CONSTANT NUMBER:= 2; Sets, for example, <foo/>.
|
||||
|
||||
*/
|
||||
|
||||
-- how to handle null values
|
||||
dbms_xmlgen.setnullhandling (l_context, p_null_handling);
|
||||
|
||||
-- create XML from ref cursor
|
||||
l_xml:=dbms_xmlgen.getxmltype (l_context, dbms_xmlgen.none);
|
||||
|
||||
print('Number of rows in ref cursor', dbms_xmlgen.getnumrowsprocessed (l_context));
|
||||
|
||||
begin
|
||||
l_clob:=l_xml.getclobval();
|
||||
if length(l_clob) > 32000 then
|
||||
print('Size of XML document (anything over 32K will be truncated)', length(l_clob));
|
||||
end if;
|
||||
print(p_msg => substr(l_clob,1,32000));
|
||||
exception
|
||||
when l_null_self_argument_exc then
|
||||
print('Empty dataset.');
|
||||
end;
|
||||
|
||||
end print;
|
||||
|
||||
|
||||
procedure print (p_xml in xmltype)
|
||||
as
|
||||
l_clob clob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: print debug information (XMLType)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 18.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
begin
|
||||
l_clob:=p_xml.getclobval();
|
||||
if length(l_clob) > 32000 then
|
||||
print('Size of XML document (anything over 32K will be truncated)', length(l_clob));
|
||||
end if;
|
||||
print(p_msg => substr(l_clob,1,32000));
|
||||
exception
|
||||
when others then
|
||||
print(sqlerrm);
|
||||
end;
|
||||
|
||||
end print;
|
||||
|
||||
|
||||
procedure print (p_clob in clob)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: print debug information (clob)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 03.03.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
begin
|
||||
if length(p_clob) > 4000 then
|
||||
print('Size of CLOB (anything over 4K will be truncated)', length(p_clob));
|
||||
end if;
|
||||
print(p_msg => substr(p_clob,1,4000));
|
||||
exception
|
||||
when others then
|
||||
print(sqlerrm);
|
||||
end;
|
||||
|
||||
end print;
|
||||
|
||||
|
||||
procedure printf (p_msg in varchar2,
|
||||
p_value1 in varchar2 := null,
|
||||
p_value2 in varchar2 := null,
|
||||
p_value3 in varchar2 := null,
|
||||
p_value4 in varchar2 := null,
|
||||
p_value5 in varchar2 := null,
|
||||
p_value6 in varchar2 := null,
|
||||
p_value7 in varchar2 := null,
|
||||
p_value8 in varchar2 := null)
|
||||
as
|
||||
l_text varchar2(32000);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Print debug information (multiple values)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 14.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
if (m_debugging or apex_application.g_debug) then
|
||||
|
||||
l_text:=p_msg;
|
||||
|
||||
l_text:=replace(l_text, '%1', nvl (p_value1, '(blank)'));
|
||||
l_text:=replace(l_text, '%2', nvl (p_value2, '(blank)'));
|
||||
l_text:=replace(l_text, '%3', nvl (p_value3, '(blank)'));
|
||||
l_text:=replace(l_text, '%4', nvl (p_value4, '(blank)'));
|
||||
l_text:=replace(l_text, '%5', nvl (p_value5, '(blank)'));
|
||||
l_text:=replace(l_text, '%6', nvl (p_value6, '(blank)'));
|
||||
l_text:=replace(l_text, '%7', nvl (p_value7, '(blank)'));
|
||||
l_text:=replace(l_text, '%8', nvl (p_value8, '(blank)'));
|
||||
|
||||
print (l_text);
|
||||
|
||||
end if;
|
||||
|
||||
end printf;
|
||||
|
||||
|
||||
function get_fdate(p_date in date) return varchar2
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Get date string in debug format
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 14.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
return nvl(to_char(p_date, 'dd.mm.yyyy hh24:mi:ss'), '(null)');
|
||||
|
||||
end get_fdate;
|
||||
|
||||
|
||||
procedure set_info (p_action in varchar2,
|
||||
p_module in varchar2 := null)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: set session info (will be available in v$session)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 25.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
if p_module is not null then
|
||||
dbms_application_info.set_module (p_module, p_action);
|
||||
else
|
||||
dbms_application_info.set_action (p_action);
|
||||
end if;
|
||||
|
||||
end set_info;
|
||||
|
||||
|
||||
procedure clear_info
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: clear session info
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 25.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
dbms_application_info.set_module (null, null);
|
||||
|
||||
end clear_info;
|
||||
|
||||
|
||||
end debug_pkg;
|
||||
/
|
||||
|
||||
74
ora/debug_pkg.pks
Executable file
74
ora/debug_pkg.pks
Executable file
@ -0,0 +1,74 @@
|
||||
create or replace package debug_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: The package handles debug information
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 14.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
-- turn off debugging
|
||||
procedure debug_off;
|
||||
|
||||
-- turn on debugging
|
||||
procedure debug_on;
|
||||
|
||||
-- print debug information
|
||||
procedure print (p_msg in varchar2);
|
||||
|
||||
-- print debug information (name/value pair)
|
||||
procedure print (p_msg in varchar2,
|
||||
p_value in varchar2);
|
||||
|
||||
-- print debug information (number)
|
||||
procedure print (p_msg in varchar2,
|
||||
p_value in number);
|
||||
|
||||
-- print debug information (date)
|
||||
procedure print (p_msg in varchar2,
|
||||
p_value in date);
|
||||
|
||||
-- print debug information (boolean)
|
||||
procedure print (p_msg in varchar2,
|
||||
p_value in boolean);
|
||||
|
||||
-- print debug information (ref cursor)
|
||||
procedure print (p_refcursor in sys_refcursor,
|
||||
p_null_handling in number := 0);
|
||||
|
||||
-- print debug information (xmltype)
|
||||
procedure print (p_xml in xmltype);
|
||||
|
||||
-- print debug information (clob)
|
||||
procedure print (p_clob in clob);
|
||||
|
||||
-- print debug information (multiple values)
|
||||
procedure printf (p_msg in varchar2,
|
||||
p_value1 in varchar2 := null,
|
||||
p_value2 in varchar2 := null,
|
||||
p_value3 in varchar2 := null,
|
||||
p_value4 in varchar2 := null,
|
||||
p_value5 in varchar2 := null,
|
||||
p_value6 in varchar2 := null,
|
||||
p_value7 in varchar2 := null,
|
||||
p_value8 in varchar2 := null);
|
||||
|
||||
-- get date string in debug format
|
||||
function get_fdate(p_date in date) return varchar2;
|
||||
|
||||
-- set session info (will be available in v$session)
|
||||
procedure set_info (p_action in varchar2,
|
||||
p_module in varchar2 := null);
|
||||
|
||||
-- clear session info
|
||||
procedure clear_info;
|
||||
|
||||
end debug_pkg;
|
||||
/
|
||||
|
||||
220
ora/encode_util_pkg.pkb
Executable file
220
ora/encode_util_pkg.pkb
Executable file
@ -0,0 +1,220 @@
|
||||
create or replace package body encode_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package contains utility functions related to encoding/decoding (of strings)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 11.05.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
function str_to_base64 (p_str in varchar2) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: encode string using base64
|
||||
|
||||
Remarks: http://stackoverflow.com/questions/3804279/base64-encoding-and-decoding-in-oracle/3806265#3806265
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 11.05.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := utl_raw.cast_to_varchar2(utl_encode.base64_encode(utl_raw.cast_to_raw(p_str)));
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end str_to_base64;
|
||||
|
||||
|
||||
function clob_to_base64 (p_clob in clob) return clob
|
||||
as
|
||||
l_pos pls_integer := 1;
|
||||
l_buffer varchar2 (32767);
|
||||
l_lob_len integer := dbms_lob.getlength (p_clob);
|
||||
l_width pls_integer := (76 / 4 * 3)-9;
|
||||
l_returnvalue clob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: encode clob using base64
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 11.05.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
if p_clob is not null then
|
||||
|
||||
dbms_lob.createtemporary (l_returnvalue, true);
|
||||
dbms_lob.open (l_returnvalue, dbms_lob.lob_readwrite);
|
||||
|
||||
while (l_pos < l_lob_len) loop
|
||||
l_buffer := utl_raw.cast_to_varchar2 (utl_encode.base64_encode (dbms_lob.substr (p_clob, l_width, l_pos)));
|
||||
dbms_lob.writeappend (l_returnvalue, length (l_buffer), l_buffer);
|
||||
l_pos := l_pos + l_width;
|
||||
end loop;
|
||||
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end clob_to_base64;
|
||||
|
||||
|
||||
function blob_to_base64 (p_blob in blob) return clob
|
||||
as
|
||||
l_pos pls_integer := 1;
|
||||
l_buffer varchar2 (32767);
|
||||
l_lob_len integer := dbms_lob.getlength (p_blob);
|
||||
l_width pls_integer := (76 / 4 * 3)-9;
|
||||
l_returnvalue clob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: encode blob using base64
|
||||
|
||||
Remarks: based on Jason Straub's blob2clobbase64 in package flex_ws_api (aka apex_web_service)
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 11.05.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
dbms_lob.createtemporary (l_returnvalue, true);
|
||||
dbms_lob.open (l_returnvalue, dbms_lob.lob_readwrite);
|
||||
|
||||
while (l_pos < l_lob_len) loop
|
||||
l_buffer := utl_raw.cast_to_varchar2 (utl_encode.base64_encode (dbms_lob.substr (p_blob, l_width, l_pos)));
|
||||
dbms_lob.writeappend (l_returnvalue, length (l_buffer), l_buffer);
|
||||
l_pos := l_pos + l_width;
|
||||
end loop;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end blob_to_base64;
|
||||
|
||||
|
||||
function base64_to_str (p_str in varchar2) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: decode base64-encoded string
|
||||
|
||||
Remarks: http://stackoverflow.com/questions/3804279/base64-encoding-and-decoding-in-oracle/3806265#3806265
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 11.05.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := utl_raw.cast_to_varchar2(utl_encode.base64_decode(utl_raw.cast_to_raw(p_str)));
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end base64_to_str;
|
||||
|
||||
|
||||
function base64_to_clob (p_clob in varchar2) return clob
|
||||
as
|
||||
|
||||
l_pos pls_integer := 1;
|
||||
l_buffer raw(36);
|
||||
l_buffer_str varchar2(2000);
|
||||
l_lob_len integer := dbms_lob.getlength (p_clob);
|
||||
l_width pls_integer := (76 / 4 * 3)-9;
|
||||
l_returnvalue clob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: decode base64-encoded clob
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 11.05.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
if p_clob is not null then
|
||||
|
||||
dbms_lob.createtemporary (l_returnvalue, true);
|
||||
dbms_lob.open (l_returnvalue, dbms_lob.lob_readwrite);
|
||||
|
||||
while (l_pos < l_lob_len) loop
|
||||
l_buffer := utl_encode.base64_decode(utl_raw.cast_to_raw(dbms_lob.substr (p_clob, l_width, l_pos)));
|
||||
l_buffer_str := utl_raw.cast_to_varchar2(l_buffer);
|
||||
dbms_lob.writeappend (l_returnvalue, length(l_buffer_str), l_buffer_str);
|
||||
l_pos := l_pos + l_width;
|
||||
end loop;
|
||||
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end base64_to_clob;
|
||||
|
||||
|
||||
function base64_to_blob (p_clob in clob) return blob
|
||||
as
|
||||
l_pos pls_integer := 1;
|
||||
l_buffer raw(36);
|
||||
l_lob_len integer := dbms_lob.getlength (p_clob);
|
||||
l_width pls_integer := (76 / 4 * 3)-9;
|
||||
l_returnvalue blob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: decode base64-encoded clob to blob
|
||||
|
||||
Remarks: based on Jason Straub's clobbase642blob in package flex_ws_api (aka apex_web_service)
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 11.05.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
dbms_lob.createtemporary (l_returnvalue, true);
|
||||
dbms_lob.open (l_returnvalue, dbms_lob.lob_readwrite);
|
||||
|
||||
while (l_pos < l_lob_len) loop
|
||||
l_buffer := utl_encode.base64_decode(utl_raw.cast_to_raw(dbms_lob.substr (p_clob, l_width, l_pos)));
|
||||
dbms_lob.writeappend (l_returnvalue, utl_raw.length(l_buffer), l_buffer);
|
||||
l_pos := l_pos + l_width;
|
||||
end loop;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end base64_to_blob;
|
||||
|
||||
|
||||
end encode_util_pkg;
|
||||
/
|
||||
|
||||
|
||||
|
||||
37
ora/encode_util_pkg.pks
Executable file
37
ora/encode_util_pkg.pks
Executable file
@ -0,0 +1,37 @@
|
||||
create or replace package encode_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package contains utility functions related to encoding/decoding (of strings)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 11.05.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
-- encode string using base64
|
||||
function str_to_base64 (p_str in varchar2) return varchar2;
|
||||
|
||||
-- encode clob using base64
|
||||
function clob_to_base64 (p_clob in clob) return clob;
|
||||
|
||||
-- encode blob using base64
|
||||
function blob_to_base64 (p_blob in blob) return clob;
|
||||
|
||||
-- decode base64-encoded string
|
||||
function base64_to_str (p_str in varchar2) return varchar2;
|
||||
|
||||
-- decode base64-encoded clob
|
||||
function base64_to_clob (p_clob in varchar2) return clob;
|
||||
|
||||
-- decode base64-encoded clob to blob
|
||||
function base64_to_blob (p_clob in clob) return blob;
|
||||
|
||||
end encode_util_pkg;
|
||||
/
|
||||
|
||||
483
ora/file_util_pkg.pkb
Executable file
483
ora/file_util_pkg.pkb
Executable file
@ -0,0 +1,483 @@
|
||||
create or replace package body file_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package contains file utilities
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 01.01.2005 Created
|
||||
MBR 18.01.2011 Added blob/clob operations
|
||||
|
||||
*/
|
||||
|
||||
|
||||
function resolve_filename (p_dir in varchar2,
|
||||
p_file_name in varchar2,
|
||||
p_os in varchar2 := g_os_windows) return varchar2
|
||||
as
|
||||
l_returnvalue t_file_name;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: resolve filename, ie. properly concatenate dir and filename
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 01.01.2005 Created
|
||||
|
||||
*/
|
||||
|
||||
if lower(p_os) = g_os_windows then
|
||||
|
||||
if substr(p_dir,-1) = g_dir_sep_win then
|
||||
l_returnvalue:=p_dir || p_file_name;
|
||||
else
|
||||
if p_dir is not null then
|
||||
l_returnvalue:=p_dir || g_dir_sep_win || p_file_name;
|
||||
else
|
||||
l_returnvalue:=p_file_name;
|
||||
end if;
|
||||
end if;
|
||||
|
||||
elsif lower(p_os) = g_os_unix then
|
||||
|
||||
if substr(p_dir,-1) = g_dir_sep_unix then
|
||||
l_returnvalue:=p_dir || p_file_name;
|
||||
else
|
||||
if p_dir is not null then
|
||||
l_returnvalue:=p_dir || g_dir_sep_unix || p_file_name;
|
||||
else
|
||||
l_returnvalue:=p_file_name;
|
||||
end if;
|
||||
end if;
|
||||
|
||||
else
|
||||
l_returnvalue:=null;
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end resolve_filename;
|
||||
|
||||
|
||||
function extract_filename (p_file_name in varchar2,
|
||||
p_os in varchar2 := g_os_windows) return varchar2
|
||||
as
|
||||
l_returnvalue t_file_name;
|
||||
l_dir_sep t_dir_sep;
|
||||
l_dir_sep_pos pls_integer;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return the filename portion of the full file name
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 01.01.2005 Created
|
||||
|
||||
*/
|
||||
|
||||
if lower(p_os) = g_os_windows then
|
||||
l_dir_sep:=g_dir_sep_win;
|
||||
elsif lower(p_os) = g_os_unix then
|
||||
l_dir_sep:=g_dir_sep_unix;
|
||||
end if;
|
||||
|
||||
if lower(p_os) in (g_os_windows, g_os_unix) then
|
||||
|
||||
l_dir_sep_pos:=instr(p_file_name, l_dir_sep, -1);
|
||||
if l_dir_sep_pos = 0 then
|
||||
-- no directory found
|
||||
l_returnvalue:=p_file_name;
|
||||
else
|
||||
-- copy filename part
|
||||
l_returnvalue:=string_util_pkg.copy_str(p_file_name, l_dir_sep_pos + 1);
|
||||
end if;
|
||||
|
||||
else
|
||||
l_returnvalue:=null;
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end extract_filename;
|
||||
|
||||
|
||||
function get_file_ext (p_file_name in varchar2) return varchar2
|
||||
as
|
||||
l_sep_pos pls_integer;
|
||||
l_returnvalue t_file_name;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get file extension
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 01.01.2005 Created
|
||||
|
||||
*/
|
||||
|
||||
l_sep_pos:=instr(p_file_name, g_file_ext_sep, -1);
|
||||
|
||||
if l_sep_pos = 0 then
|
||||
-- no extension found
|
||||
l_returnvalue:=null;
|
||||
else
|
||||
-- copy extension
|
||||
l_returnvalue:=string_util_pkg.copy_str(p_file_name, l_sep_pos + 1);
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_file_ext;
|
||||
|
||||
|
||||
function strip_file_ext (p_file_name in varchar2) return varchar2
|
||||
as
|
||||
l_sep_pos pls_integer;
|
||||
l_file_ext t_file_name;
|
||||
l_returnvalue t_file_name;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: strip file extension
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 01.01.2005 Created
|
||||
|
||||
*/
|
||||
|
||||
l_file_ext:=get_file_ext (p_file_name);
|
||||
|
||||
if l_file_ext is not null then
|
||||
l_sep_pos:=instr(p_file_name, g_file_ext_sep || l_file_ext, -1);
|
||||
-- copy everything except extension
|
||||
if l_sep_pos > 0 then
|
||||
l_returnvalue:=string_util_pkg.copy_str(p_file_name, 1, l_sep_pos - 1);
|
||||
else
|
||||
l_returnvalue:=p_file_name;
|
||||
end if;
|
||||
else
|
||||
l_returnvalue:=p_file_name;
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end strip_file_ext;
|
||||
|
||||
|
||||
function get_filename_str (p_str in varchar2,
|
||||
p_extension in varchar2 := null) return varchar2
|
||||
as
|
||||
l_returnvalue t_file_name;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: returns string suitable for file names, ie. no whitespace or special path characters
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 16.11.2009 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := replace(replace(replace(replace(trim(p_str), ' ', '_'), '\', '_'), '/', '_'), ':', '');
|
||||
|
||||
if p_extension is not null then
|
||||
l_returnvalue := l_returnvalue || '.' || p_extension;
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_filename_str;
|
||||
|
||||
|
||||
function get_blob_from_file (p_directory_name in varchar2,
|
||||
p_file_name in varchar2) return blob
|
||||
as
|
||||
l_bfile bfile;
|
||||
l_returnvalue blob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Get blob from file
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 18.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
dbms_lob.createtemporary (l_returnvalue, false);
|
||||
l_bfile := bfilename (p_directory_name, p_file_name);
|
||||
dbms_lob.fileopen (l_bfile, dbms_lob.file_readonly);
|
||||
dbms_lob.loadfromfile (l_returnvalue, l_bfile, dbms_lob.getlength(l_bfile));
|
||||
dbms_lob.fileclose (l_bfile);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
exception
|
||||
when others then
|
||||
if dbms_lob.fileisopen (l_bfile) = 1 then
|
||||
dbms_lob.fileclose (l_bfile);
|
||||
end if;
|
||||
dbms_lob.freetemporary(l_returnvalue);
|
||||
raise;
|
||||
|
||||
end get_blob_from_file;
|
||||
|
||||
|
||||
function get_clob_from_file (p_directory_name in varchar2,
|
||||
p_file_name in varchar2) return clob
|
||||
as
|
||||
l_bfile bfile;
|
||||
l_returnvalue clob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Get clob from file
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 18.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
dbms_lob.createtemporary (l_returnvalue, false);
|
||||
l_bfile := bfilename (p_directory_name, p_file_name);
|
||||
dbms_lob.fileopen (l_bfile, dbms_lob.file_readonly);
|
||||
dbms_lob.loadfromfile (l_returnvalue, l_bfile, dbms_lob.getlength(l_bfile));
|
||||
dbms_lob.fileclose (l_bfile);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
exception
|
||||
when others then
|
||||
if dbms_lob.fileisopen (l_bfile) = 1 then
|
||||
dbms_lob.fileclose (l_bfile);
|
||||
end if;
|
||||
dbms_lob.freetemporary(l_returnvalue);
|
||||
raise;
|
||||
|
||||
end get_clob_from_file;
|
||||
|
||||
|
||||
procedure save_blob_to_file (p_directory_name in varchar2,
|
||||
p_file_name in varchar2,
|
||||
p_blob in blob)
|
||||
as
|
||||
l_file utl_file.file_type;
|
||||
l_buffer raw(32767);
|
||||
l_amount binary_integer := 32767;
|
||||
l_pos integer := 1;
|
||||
l_blob_len integer;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: save blob to file
|
||||
|
||||
Remarks: see http://www.oracle-base.com/articles/9i/ExportBlob9i.php
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 20.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_blob_len := dbms_lob.getlength (p_blob);
|
||||
|
||||
l_file := utl_file.fopen (p_directory_name, p_file_name, g_file_mode_write_byte, 32767);
|
||||
|
||||
while l_pos < l_blob_len loop
|
||||
dbms_lob.read (p_blob, l_amount, l_pos, l_buffer);
|
||||
utl_file.put_raw (l_file, l_buffer, true);
|
||||
l_pos := l_pos + l_amount;
|
||||
end loop;
|
||||
|
||||
utl_file.fclose (l_file);
|
||||
|
||||
exception
|
||||
when others then
|
||||
if utl_file.is_open (l_file) then
|
||||
utl_file.fclose (l_file);
|
||||
end if;
|
||||
raise;
|
||||
|
||||
end save_blob_to_file;
|
||||
|
||||
|
||||
procedure save_clob_to_file (p_directory_name in varchar2,
|
||||
p_file_name in varchar2,
|
||||
p_clob in clob)
|
||||
as
|
||||
l_file utl_file.file_type;
|
||||
l_buffer varchar2(32767);
|
||||
l_amount binary_integer := 8000;
|
||||
l_pos integer := 1;
|
||||
l_clob_len integer;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: save clob to file
|
||||
|
||||
Remarks: see http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:744825627183
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 20.01.2011 Created
|
||||
MBR 04.03.2011 Fixed issue with ORA-06502 on dbms_lob.read (reduced l_amount from 32k to 8k)
|
||||
|
||||
*/
|
||||
|
||||
l_clob_len := dbms_lob.getlength (p_clob);
|
||||
|
||||
l_file := utl_file.fopen (p_directory_name, p_file_name, g_file_mode_write_text, 32767);
|
||||
|
||||
while l_pos < l_clob_len loop
|
||||
dbms_lob.read (p_clob, l_amount, l_pos, l_buffer);
|
||||
utl_file.put (l_file, l_buffer);
|
||||
utl_file.fflush (l_file);
|
||||
l_pos := l_pos + l_amount;
|
||||
end loop;
|
||||
|
||||
utl_file.fclose (l_file);
|
||||
|
||||
exception
|
||||
when others then
|
||||
if utl_file.is_open (l_file) then
|
||||
utl_file.fclose (l_file);
|
||||
end if;
|
||||
raise;
|
||||
|
||||
end save_clob_to_file;
|
||||
|
||||
|
||||
procedure save_clob_to_file_raw (p_directory_name in varchar2,
|
||||
p_file_name in varchar2,
|
||||
p_clob in clob)
|
||||
as
|
||||
l_file utl_file.file_type;
|
||||
l_chunk_size pls_integer := 3000;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: save clob to file
|
||||
|
||||
Remarks: see http://forums.oracle.com/forums/thread.jspa?threadID=622875
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 04.03.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_file := utl_file.fopen (p_directory_name, p_file_name, g_file_mode_write_byte, max_linesize => 32767 );
|
||||
|
||||
for i in 1 .. ceil (length( p_clob ) / l_chunk_size) loop
|
||||
utl_file.put_raw (l_file, utl_raw.cast_to_raw (substr(p_clob, ( i - 1 ) * l_chunk_size + 1, l_chunk_size )));
|
||||
utl_file.fflush(l_file);
|
||||
end loop;
|
||||
|
||||
utl_file.fclose (l_file);
|
||||
|
||||
exception
|
||||
when others then
|
||||
if utl_file.is_open (l_file) then
|
||||
utl_file.fclose (l_file);
|
||||
end if;
|
||||
raise;
|
||||
|
||||
end save_clob_to_file_raw;
|
||||
|
||||
|
||||
function file_exists (p_directory_name in varchar2,
|
||||
p_file_name in varchar2) return boolean
|
||||
as
|
||||
l_length number;
|
||||
l_block_size number;
|
||||
l_returnvalue boolean := false;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: does file exist?
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 25.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
utl_file.fgetattr (p_directory_name, p_file_name, l_returnvalue, l_length, l_block_size);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end file_exists;
|
||||
|
||||
|
||||
function fmt_bytes (p_bytes in number) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_db_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: format bytes
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 09.10.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := case
|
||||
when p_bytes is null then null
|
||||
when p_bytes < 1024 then to_char(p_bytes) || ' bytes'
|
||||
when p_bytes < 1048576 then to_char(round(p_bytes / 1024, 1)) || ' kB'
|
||||
when p_bytes < 1073741824 then to_char(round(p_bytes / 1048576, 1)) || ' MB'
|
||||
when p_bytes < 1099511627776 then to_char(round(p_bytes / 1073741824, 1)) || ' GB'
|
||||
else to_char(round(p_bytes / 1099511627776, 1)) || ' TB'
|
||||
end;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end fmt_bytes;
|
||||
|
||||
|
||||
end file_util_pkg;
|
||||
/
|
||||
|
||||
94
ora/file_util_pkg.pks
Executable file
94
ora/file_util_pkg.pks
Executable file
@ -0,0 +1,94 @@
|
||||
create or replace package file_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package contains file utilities
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 01.01.2005 Created
|
||||
MBR 18.01.2011 Added blob/clob operations
|
||||
|
||||
*/
|
||||
|
||||
-- operating system types
|
||||
g_os_windows constant varchar2(1) := 'w';
|
||||
g_os_unix constant varchar2(1) := 'u';
|
||||
|
||||
g_dir_sep_win constant varchar2(1) := '\';
|
||||
g_dir_sep_unix constant varchar2(1) := '/';
|
||||
|
||||
g_file_ext_sep constant varchar2(1) := '.';
|
||||
|
||||
-- file open modes
|
||||
g_file_mode_append_text constant varchar2(1) := 'a';
|
||||
g_file_mode_append_byte constant varchar2(2) := 'ab';
|
||||
g_file_mode_read_text constant varchar2(1) := 'r';
|
||||
g_file_mode_read_byte constant varchar2(2) := 'rb';
|
||||
g_file_mode_write_text constant varchar2(1) := 'w';
|
||||
g_file_mode_write_byte constant varchar2(2) := 'wb';
|
||||
|
||||
g_file_name_def varchar2(2000);
|
||||
subtype t_file_name is g_file_name_def%type;
|
||||
|
||||
g_file_ext_def varchar2(50);
|
||||
subtype t_file_ext is g_file_ext_def%type;
|
||||
|
||||
g_dir_sep_def varchar2(1);
|
||||
subtype t_dir_sep is g_dir_sep_def%type;
|
||||
|
||||
-- resolve filename
|
||||
function resolve_filename (p_dir in varchar2,
|
||||
p_file_name in varchar2,
|
||||
p_os in varchar2 := g_os_windows) return varchar2;
|
||||
|
||||
-- extract filename
|
||||
function extract_filename (p_file_name in varchar2,
|
||||
p_os in varchar2 := g_os_windows) return varchar2;
|
||||
|
||||
-- get file extension
|
||||
function get_file_ext (p_file_name in varchar2) return varchar2;
|
||||
|
||||
-- strip file extension
|
||||
function strip_file_ext (p_file_name in varchar2) return varchar2;
|
||||
|
||||
-- get filename string (no whitespace)
|
||||
function get_filename_str (p_str in varchar2,
|
||||
p_extension in varchar2 := null) return varchar2;
|
||||
|
||||
-- get blob from file
|
||||
function get_blob_from_file (p_directory_name in varchar2,
|
||||
p_file_name in varchar2) return blob;
|
||||
|
||||
-- get clob from file
|
||||
function get_clob_from_file (p_directory_name in varchar2,
|
||||
p_file_name in varchar2) return clob;
|
||||
|
||||
-- save blob to file
|
||||
procedure save_blob_to_file (p_directory_name in varchar2,
|
||||
p_file_name in varchar2,
|
||||
p_blob in blob);
|
||||
|
||||
-- save clob to file
|
||||
procedure save_clob_to_file (p_directory_name in varchar2,
|
||||
p_file_name in varchar2,
|
||||
p_clob in clob);
|
||||
|
||||
-- save clob to file (raw)
|
||||
procedure save_clob_to_file_raw (p_directory_name in varchar2,
|
||||
p_file_name in varchar2,
|
||||
p_clob in clob);
|
||||
|
||||
-- does file exist?
|
||||
function file_exists (p_directory_name in varchar2,
|
||||
p_file_name in varchar2) return boolean;
|
||||
|
||||
-- format bytes
|
||||
function fmt_bytes (p_bytes in number) return varchar2;
|
||||
|
||||
end file_util_pkg;
|
||||
/
|
||||
|
||||
699
ora/flex_ws_api.pkb
Executable file
699
ora/flex_ws_api.pkb
Executable file
@ -0,0 +1,699 @@
|
||||
create or replace package body flex_ws_api
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Web Service callouts from PL/SQL
|
||||
|
||||
Remarks: By Jason Straub, see http://jastraub.blogspot.com/2008/06/flexible-web-service-api.html
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 21.05.2012 Added to Alexandria Library because this is a prerequisite for the EWS (MS Exchange Web Service) API
|
||||
|
||||
*/
|
||||
|
||||
|
||||
function blob2clobbase64 (
|
||||
p_blob in blob ) return clob
|
||||
is
|
||||
pos pls_integer := 1;
|
||||
buffer varchar2 (32767);
|
||||
res clob;
|
||||
lob_len integer := dbms_lob.getlength (p_blob);
|
||||
l_width pls_integer := (76 / 4 * 3)-9;
|
||||
begin
|
||||
dbms_lob.createtemporary (res, true);
|
||||
dbms_lob.open (res, dbms_lob.lob_readwrite);
|
||||
|
||||
while (pos < lob_len) loop
|
||||
buffer :=
|
||||
utl_raw.cast_to_varchar2
|
||||
(utl_encode.base64_encode (dbms_lob.substr (p_blob, l_width, pos)));
|
||||
|
||||
dbms_lob.writeappend (res, length (buffer), buffer);
|
||||
|
||||
pos := pos + l_width;
|
||||
end loop;
|
||||
|
||||
return res;
|
||||
|
||||
end blob2clobbase64;
|
||||
|
||||
function clobbase642blob (
|
||||
p_clob in clob ) return blob
|
||||
is
|
||||
pos pls_integer := 1;
|
||||
buffer raw(36);
|
||||
res blob;
|
||||
lob_len integer := dbms_lob.getlength (p_clob);
|
||||
l_width pls_integer := (76 / 4 * 3)-9;
|
||||
begin
|
||||
dbms_lob.createtemporary (res, true);
|
||||
dbms_lob.open (res, dbms_lob.lob_readwrite);
|
||||
|
||||
while (pos < lob_len) loop
|
||||
buffer := utl_encode.base64_decode(utl_raw.cast_to_raw(dbms_lob.substr (p_clob, l_width, pos)));
|
||||
|
||||
dbms_lob.writeappend (res, utl_raw.length(buffer), buffer);
|
||||
|
||||
pos := pos + l_width;
|
||||
end loop;
|
||||
|
||||
return res;
|
||||
|
||||
end clobbase642blob;
|
||||
|
||||
procedure make_request (
|
||||
p_url in varchar2,
|
||||
p_action in varchar2 default null,
|
||||
p_version in varchar2 default '1.1',
|
||||
p_collection_name in varchar2 default null,
|
||||
p_envelope in clob,
|
||||
p_username in varchar2 default null,
|
||||
p_password in varchar2 default null,
|
||||
p_proxy_override in varchar2 default null,
|
||||
p_wallet_path in varchar2 default null,
|
||||
p_wallet_pwd in varchar2 default null,
|
||||
p_extra_headers in wwv_flow_global.vc_arr2 default empty_vc_arr )
|
||||
is
|
||||
l_clob clob;
|
||||
l_http_req utl_http.req;
|
||||
l_http_resp utl_http.resp;
|
||||
l_amount binary_integer := 8000;
|
||||
l_offset integer := 1;
|
||||
l_buffer varchar2(32000);
|
||||
l_db_charset varchar2(100);
|
||||
l_env_lenb integer := 0;
|
||||
i integer := 0;
|
||||
l_headers wwv_flow_global.vc_arr2;
|
||||
l_response varchar2(2000);
|
||||
l_name varchar2(256);
|
||||
l_hdr_value varchar2(1024);
|
||||
l_hdr header;
|
||||
l_hdrs header_table;
|
||||
begin
|
||||
|
||||
-- determine database characterset, if not AL32UTF8, conversion will be necessary
|
||||
select value into l_db_charset from nls_database_parameters where parameter='NLS_CHARACTERSET';
|
||||
|
||||
-- determine length for content-length header
|
||||
loop
|
||||
exit when wwv_flow_utilities.clob_to_varchar2(p_envelope,i*32767) is null;
|
||||
if l_db_charset = 'AL32UTF8' then
|
||||
l_env_lenb := l_env_lenb + lengthb(wwv_flow_utilities.clob_to_varchar2(p_envelope,i*32767));
|
||||
else
|
||||
l_env_lenb := l_env_lenb + utl_raw.length(
|
||||
utl_raw.convert(utl_raw.cast_to_raw(wwv_flow_utilities.clob_to_varchar2(p_envelope,i*32767)),
|
||||
'american_america.al32utf8','american_america.'||l_db_charset));
|
||||
end if;
|
||||
i := i + 1;
|
||||
end loop;
|
||||
|
||||
-- set a proxy if required
|
||||
if apex_application.g_proxy_server is not null and p_proxy_override is null then
|
||||
utl_http.set_proxy (proxy => apex_application.g_proxy_server);
|
||||
elsif p_proxy_override is not null then
|
||||
utl_http.set_proxy (proxy => p_proxy_override);
|
||||
end if;
|
||||
|
||||
--utl_http.set_persistent_conn_support(true);
|
||||
utl_http.set_transfer_timeout(600);
|
||||
|
||||
-- set wallet if necessary
|
||||
if instr(lower(p_url),'https') = 1 then
|
||||
utl_http.set_wallet(p_wallet_path, p_wallet_pwd);
|
||||
end if;
|
||||
|
||||
-- set cookies if necessary
|
||||
begin
|
||||
if g_request_cookies.count > 0 then
|
||||
utl_http.clear_cookies;
|
||||
utl_http.add_cookies(g_request_cookies);
|
||||
end if;
|
||||
exception when others then
|
||||
raise_application_error(-20001,'The provided cookie is invalid.');
|
||||
end;
|
||||
|
||||
-- begin the request
|
||||
if wwv_flow_utilities.db_version like '9.%' then
|
||||
l_http_req := utl_http.begin_request(p_url, 'POST', 'HTTP/1.0');
|
||||
else
|
||||
l_http_req := utl_http.begin_request(p_url, 'POST');
|
||||
end if;
|
||||
|
||||
-- set basic authentication if required
|
||||
if p_username is not null then
|
||||
utl_http.set_authentication (
|
||||
r => l_http_req,
|
||||
username => p_username,
|
||||
password => p_password,
|
||||
scheme => 'Basic',
|
||||
for_proxy => false );
|
||||
end if;
|
||||
|
||||
-- set standard HTTP headers for a SOAP request
|
||||
utl_http.set_header(l_http_req, 'Proxy-Connection', 'Keep-Alive');
|
||||
if p_version = '1.2' then
|
||||
utl_http.set_header(l_http_req, 'Content-Type', 'application/soap+xml; charset=UTF-8; action="'||p_action||'";');
|
||||
else
|
||||
utl_http.set_header(l_http_req, 'SOAPAction', p_action);
|
||||
utl_http.set_header(l_http_req, 'Content-Type', 'text/xml; charset=UTF-8');
|
||||
end if;
|
||||
utl_http.set_header(l_http_req, 'Content-Length', l_env_lenb);
|
||||
|
||||
-- set additional headers if supplied, these are separated by a colon (:) as name/value pairs
|
||||
for i in 1.. p_extra_headers.count loop
|
||||
l_headers := apex_util.string_to_table(p_extra_headers(i));
|
||||
utl_http.set_header(l_http_req, l_headers(1), l_headers(2));
|
||||
end loop;
|
||||
|
||||
--set headers from g_request_headers
|
||||
for i in 1.. g_request_headers.count loop
|
||||
utl_http.set_header(l_http_req, g_request_headers(i).name, g_request_headers(i).value);
|
||||
end loop;
|
||||
|
||||
-- read the envelope, convert to UTF8 if necessary, then write it to the HTTP request
|
||||
begin
|
||||
loop
|
||||
dbms_lob.read( p_envelope, l_amount, l_offset, l_buffer );
|
||||
if l_db_charset = 'AL32UTF8' then
|
||||
utl_http.write_text(l_http_req, l_buffer);
|
||||
else
|
||||
utl_http.write_raw(l_http_req,utl_raw.convert(utl_raw.cast_to_raw(l_buffer),'american_america.al32utf8','american_america.'||l_db_charset));
|
||||
end if;
|
||||
l_offset := l_offset + l_amount;
|
||||
l_amount := 8000;
|
||||
end loop;
|
||||
exception
|
||||
when no_data_found then
|
||||
null;
|
||||
end;
|
||||
|
||||
-- get the response
|
||||
l_http_resp := utl_http.get_response(l_http_req);
|
||||
|
||||
-- set response code, response http header and response cookies global
|
||||
g_status_code := l_http_resp.status_code;
|
||||
utl_http.get_cookies(g_response_cookies);
|
||||
for i in 1..utl_http.get_header_count(l_http_resp) loop
|
||||
utl_http.get_header(l_http_resp, i, l_name, l_hdr_value);
|
||||
l_hdr.name := l_name;
|
||||
l_hdr.value := l_hdr_value;
|
||||
l_hdrs(i) := l_hdr;
|
||||
end loop;
|
||||
|
||||
g_headers := l_hdrs;
|
||||
|
||||
-- put the response in a collection if necessary
|
||||
if p_collection_name is not null then
|
||||
|
||||
apex_collection.create_or_truncate_collection(p_collection_name);
|
||||
|
||||
dbms_lob.createtemporary( l_clob, FALSE );
|
||||
dbms_lob.open( l_clob, dbms_lob.lob_readwrite );
|
||||
begin
|
||||
loop
|
||||
utl_http.read_text(l_http_resp, l_buffer);
|
||||
dbms_lob.writeappend( l_clob, length(l_buffer), l_buffer );
|
||||
end loop;
|
||||
exception
|
||||
when others then
|
||||
if sqlcode <> -29266 then
|
||||
raise;
|
||||
end if;
|
||||
end;
|
||||
|
||||
apex_collection.add_member(
|
||||
p_collection_name => p_collection_name,
|
||||
p_clob001 => l_clob);
|
||||
end if;
|
||||
--
|
||||
utl_http.end_response(l_http_resp);
|
||||
|
||||
end make_request;
|
||||
|
||||
function make_request (
|
||||
p_url in varchar2,
|
||||
p_action in varchar2 default null,
|
||||
p_version in varchar2 default '1.1',
|
||||
p_envelope in clob,
|
||||
p_username in varchar2 default null,
|
||||
p_password in varchar2 default null,
|
||||
p_proxy_override in varchar2 default null,
|
||||
p_wallet_path in varchar2 default null,
|
||||
p_wallet_pwd in varchar2 default null,
|
||||
p_extra_headers in wwv_flow_global.vc_arr2 default empty_vc_arr ) return xmltype
|
||||
is
|
||||
l_clob clob;
|
||||
l_http_req utl_http.req;
|
||||
l_http_resp utl_http.resp;
|
||||
l_amount binary_integer := 8000;
|
||||
l_offset integer := 1;
|
||||
l_buffer varchar2(32000);
|
||||
l_db_charset varchar2(100);
|
||||
l_env_lenb integer := 0;
|
||||
i integer := 0;
|
||||
l_headers wwv_flow_global.vc_arr2;
|
||||
l_response varchar2(2000);
|
||||
l_name varchar2(256);
|
||||
l_hdr_value varchar2(1024);
|
||||
l_hdr header;
|
||||
l_hdrs header_table;
|
||||
begin
|
||||
|
||||
-- determine database characterset, if not AL32UTF8, conversion will be necessary
|
||||
select value into l_db_charset from nls_database_parameters where parameter='NLS_CHARACTERSET';
|
||||
|
||||
-- determine length for content-length header
|
||||
loop
|
||||
exit when wwv_flow_utilities.clob_to_varchar2(p_envelope,i*32767) is null;
|
||||
if l_db_charset = 'AL32UTF8' then
|
||||
l_env_lenb := l_env_lenb + lengthb(wwv_flow_utilities.clob_to_varchar2(p_envelope,i*32767));
|
||||
else
|
||||
l_env_lenb := l_env_lenb + utl_raw.length(
|
||||
utl_raw.convert(utl_raw.cast_to_raw(wwv_flow_utilities.clob_to_varchar2(p_envelope,i*32767)),
|
||||
'american_america.al32utf8','american_america.'||l_db_charset));
|
||||
end if;
|
||||
i := i + 1;
|
||||
end loop;
|
||||
|
||||
-- set a proxy if required
|
||||
if apex_application.g_proxy_server is not null and p_proxy_override is null then
|
||||
utl_http.set_proxy (proxy => apex_application.g_proxy_server);
|
||||
elsif p_proxy_override is not null then
|
||||
utl_http.set_proxy (proxy => p_proxy_override);
|
||||
end if;
|
||||
|
||||
--utl_http.set_persistent_conn_support(true);
|
||||
utl_http.set_transfer_timeout(600);
|
||||
|
||||
-- set wallet if necessary
|
||||
if instr(lower(p_url),'https') = 1 then
|
||||
utl_http.set_wallet(p_wallet_path, p_wallet_pwd);
|
||||
end if;
|
||||
|
||||
-- set cookies if necessary
|
||||
begin
|
||||
if g_request_cookies.count > 0 then
|
||||
utl_http.clear_cookies;
|
||||
utl_http.add_cookies(g_request_cookies);
|
||||
end if;
|
||||
exception when others then
|
||||
raise_application_error(-20001,'The provided cookie is invalid.');
|
||||
end;
|
||||
|
||||
-- begin the request
|
||||
if wwv_flow_utilities.db_version like '9.%' then
|
||||
l_http_req := utl_http.begin_request(p_url, 'POST', 'HTTP/1.0');
|
||||
else
|
||||
l_http_req := utl_http.begin_request(p_url, 'POST');
|
||||
end if;
|
||||
|
||||
-- set basic authentication if required
|
||||
if p_username is not null then
|
||||
utl_http.set_authentication (
|
||||
r => l_http_req,
|
||||
username => p_username,
|
||||
password => p_password,
|
||||
scheme => 'Basic',
|
||||
for_proxy => false );
|
||||
end if;
|
||||
|
||||
-- set standard HTTP headers for a SOAP request
|
||||
utl_http.set_header(l_http_req, 'Proxy-Connection', 'Keep-Alive');
|
||||
if p_version = '1.2' then
|
||||
utl_http.set_header(l_http_req, 'Content-Type', 'application/soap+xml; charset=UTF-8; action="'||p_action||'";');
|
||||
else
|
||||
utl_http.set_header(l_http_req, 'SOAPAction', p_action);
|
||||
utl_http.set_header(l_http_req, 'Content-Type', 'text/xml; charset=UTF-8');
|
||||
end if;
|
||||
utl_http.set_header(l_http_req, 'Content-Length', l_env_lenb);
|
||||
|
||||
-- set additional headers if supplied, these are separated by a colon (:) as name/value pairs
|
||||
for i in 1.. p_extra_headers.count loop
|
||||
l_headers := apex_util.string_to_table(p_extra_headers(i));
|
||||
utl_http.set_header(l_http_req, l_headers(1), l_headers(2));
|
||||
end loop;
|
||||
|
||||
--set headers from g_request_headers
|
||||
for i in 1.. g_request_headers.count loop
|
||||
utl_http.set_header(l_http_req, g_request_headers(i).name, g_request_headers(i).value);
|
||||
end loop;
|
||||
|
||||
-- read the envelope, convert to UTF8 if necessary, then write it to the HTTP request
|
||||
begin
|
||||
loop
|
||||
dbms_lob.read( p_envelope, l_amount, l_offset, l_buffer );
|
||||
if l_db_charset = 'AL32UTF8' then
|
||||
utl_http.write_text(l_http_req, l_buffer);
|
||||
else
|
||||
utl_http.write_raw(l_http_req,utl_raw.convert(utl_raw.cast_to_raw(l_buffer),'american_america.al32utf8','american_america.'||l_db_charset));
|
||||
end if;
|
||||
l_offset := l_offset + l_amount;
|
||||
l_amount := 8000;
|
||||
end loop;
|
||||
exception
|
||||
when no_data_found then
|
||||
null;
|
||||
end;
|
||||
|
||||
-- get the response
|
||||
l_http_resp := utl_http.get_response(l_http_req);
|
||||
|
||||
-- set response code, response http header and response cookies global
|
||||
g_status_code := l_http_resp.status_code;
|
||||
utl_http.get_cookies(g_response_cookies);
|
||||
for i in 1..utl_http.get_header_count(l_http_resp) loop
|
||||
utl_http.get_header(l_http_resp, i, l_name, l_hdr_value);
|
||||
l_hdr.name := l_name;
|
||||
l_hdr.value := l_hdr_value;
|
||||
l_hdrs(i) := l_hdr;
|
||||
end loop;
|
||||
|
||||
g_headers := l_hdrs;
|
||||
|
||||
-- put the response in a clob
|
||||
dbms_lob.createtemporary( l_clob, FALSE );
|
||||
dbms_lob.open( l_clob, dbms_lob.lob_readwrite );
|
||||
begin
|
||||
loop
|
||||
utl_http.read_text(l_http_resp, l_buffer);
|
||||
dbms_lob.writeappend( l_clob, length(l_buffer), l_buffer );
|
||||
end loop;
|
||||
exception
|
||||
when others then
|
||||
if sqlcode <> -29266 then
|
||||
raise;
|
||||
end if;
|
||||
end;
|
||||
|
||||
utl_http.end_response(l_http_resp);
|
||||
|
||||
return xmltype.createxml(l_clob);
|
||||
|
||||
exception when others then
|
||||
if sqlcode = -31011 then -- its not xml
|
||||
return null;
|
||||
end if;
|
||||
end make_request;
|
||||
|
||||
function make_rest_request(
|
||||
p_url in varchar2,
|
||||
p_http_method in varchar2,
|
||||
p_username in varchar2 default null,
|
||||
p_password in varchar2 default null,
|
||||
p_proxy_override in varchar2 default null,
|
||||
p_body in clob default empty_clob(),
|
||||
p_body_blob in blob default empty_blob(),
|
||||
p_parm_name in wwv_flow_global.vc_arr2 default empty_vc_arr,
|
||||
p_parm_value in wwv_flow_global.vc_arr2 default empty_vc_arr,
|
||||
p_http_headers in wwv_flow_global.vc_arr2 default empty_vc_arr,
|
||||
p_http_hdr_values in wwv_flow_global.vc_arr2 default empty_vc_arr,
|
||||
p_wallet_path in varchar2 default null,
|
||||
p_wallet_pwd in varchar2 default null )
|
||||
return clob
|
||||
is
|
||||
l_http_req utl_http.req;
|
||||
l_http_resp utl_http.resp;
|
||||
--
|
||||
l_body clob default empty_clob();
|
||||
i integer;
|
||||
l_env_lenb number := 0;
|
||||
l_db_charset varchar2(100) := 'AL32UTF8';
|
||||
l_buffer varchar2(32767);
|
||||
l_raw raw(48);
|
||||
l_amount number;
|
||||
l_offset number;
|
||||
l_value clob;
|
||||
l_url varchar2(32767);
|
||||
l_parm_value varchar2(32767);
|
||||
l_name varchar2(256);
|
||||
l_hdr_value varchar2(1024);
|
||||
l_hdr header;
|
||||
l_hdrs header_table;
|
||||
begin
|
||||
|
||||
-- determine database characterset, if not AL32UTF8, conversion will be necessary
|
||||
select value into l_db_charset from nls_database_parameters where parameter='NLS_CHARACTERSET';
|
||||
|
||||
-- set a proxy if required
|
||||
if apex_application.g_proxy_server is not null and p_proxy_override is null then
|
||||
utl_http.set_proxy (proxy => apex_application.g_proxy_server);
|
||||
elsif p_proxy_override is not null then
|
||||
utl_http.set_proxy (proxy => p_proxy_override);
|
||||
end if;
|
||||
|
||||
--utl_http.set_persistent_conn_support(TRUE);
|
||||
utl_http.set_transfer_timeout(180);
|
||||
|
||||
if instr(lower(p_url),'https') = 1 then
|
||||
utl_http.set_wallet(p_wallet_path, p_wallet_pwd);
|
||||
end if;
|
||||
|
||||
if dbms_lob.getlength(p_body) = 0 then
|
||||
for i in 1.. p_parm_name.count loop
|
||||
if p_http_method = 'GET' then
|
||||
l_parm_value := apex_util.url_encode(p_parm_value(i));
|
||||
else
|
||||
l_parm_value := p_parm_value(i);
|
||||
end if;
|
||||
if i = 1 then
|
||||
l_body := p_parm_name(i)||'='||l_parm_value;
|
||||
else
|
||||
l_body := l_body||'&'||p_parm_name(i)||'='||l_parm_value;
|
||||
end if;
|
||||
end loop;
|
||||
else
|
||||
l_body := p_body;
|
||||
end if;
|
||||
|
||||
i := 0;
|
||||
|
||||
l_url := p_url;
|
||||
|
||||
if p_http_method = 'GET' then
|
||||
l_url := l_url||'?'||wwv_flow_utilities.clob_to_varchar2(l_body);
|
||||
end if;
|
||||
|
||||
-- determine length in bytes of l_body;
|
||||
if dbms_lob.getlength(p_body_blob) > 0 then
|
||||
l_env_lenb := dbms_lob.getlength(p_body_blob);
|
||||
else
|
||||
loop
|
||||
exit when wwv_flow_utilities.clob_to_varchar2(l_body,i*32767) is null;
|
||||
if l_db_charset = 'AL32UTF8' then
|
||||
l_env_lenb := l_env_lenb + lengthb(wwv_flow_utilities.clob_to_varchar2(l_body,i*32767));
|
||||
else
|
||||
l_env_lenb := l_env_lenb + utl_raw.length(
|
||||
utl_raw.convert(utl_raw.cast_to_raw(wwv_flow_utilities.clob_to_varchar2(l_body,i*32767)),
|
||||
'american_america.al32utf8','american_america.' || l_db_charset));
|
||||
end if;
|
||||
i := i + 1;
|
||||
end loop;
|
||||
end if;
|
||||
|
||||
-- set cookies if necessary
|
||||
begin
|
||||
if g_request_cookies.count > 0 then
|
||||
utl_http.clear_cookies;
|
||||
utl_http.add_cookies(g_request_cookies);
|
||||
end if;
|
||||
exception when others then
|
||||
raise_application_error(-20001,'The provided cookie is invalid.');
|
||||
end;
|
||||
|
||||
begin
|
||||
l_http_req := utl_http.begin_request(l_url, p_http_method);
|
||||
-- set basic authentication if necessary
|
||||
if p_username is not null then
|
||||
utl_http.set_authentication(l_http_req, p_username, p_password);
|
||||
end if;
|
||||
utl_http.set_header(l_http_req, 'Proxy-Connection', 'Keep-Alive');
|
||||
if p_http_method != 'GET' then
|
||||
utl_http.set_header(l_http_req, 'Content-Length', l_env_lenb);
|
||||
end if;
|
||||
-- set additional headers if supplied, these are separated by a colon (:) as name/value pairs
|
||||
for i in 1.. p_http_headers.count loop
|
||||
utl_http.set_header(l_http_req, p_http_headers(i), p_http_hdr_values(i));
|
||||
end loop;
|
||||
exception when others then
|
||||
raise_application_error(-20001,'The URL provided is invalid or you need to set a proxy.');
|
||||
end;
|
||||
|
||||
--set headers from g_request_headers
|
||||
for i in 1.. g_request_headers.count loop
|
||||
utl_http.set_header(l_http_req, g_request_headers(i).name, g_request_headers(i).value);
|
||||
end loop;
|
||||
|
||||
--
|
||||
l_amount := 8000;
|
||||
l_offset := 1;
|
||||
if p_http_method != 'GET' then
|
||||
if dbms_lob.getlength(l_body) > 0 then
|
||||
begin
|
||||
loop
|
||||
dbms_lob.read( l_body, l_amount, l_offset, l_buffer );
|
||||
if l_db_charset = 'AL32UTF8' then
|
||||
utl_http.write_text(l_http_req, l_buffer);
|
||||
else
|
||||
utl_http.write_raw(l_http_req,
|
||||
utl_raw.convert(utl_raw.cast_to_raw(l_buffer),
|
||||
'american_america.al32utf8',
|
||||
'american_america.' || l_db_charset
|
||||
)
|
||||
);
|
||||
end if;
|
||||
l_offset := l_offset + l_amount;
|
||||
l_amount := 8000;
|
||||
end loop;
|
||||
exception
|
||||
when no_data_found then
|
||||
null;
|
||||
end;
|
||||
elsif dbms_lob.getlength(p_body_blob) > 0 then
|
||||
begin
|
||||
l_amount := 48;
|
||||
while (l_offset < l_env_lenb) loop
|
||||
dbms_lob.read(p_body_blob, l_amount, l_offset, l_raw);
|
||||
utl_http.write_raw(l_http_req, l_raw);
|
||||
l_offset := l_offset + l_amount;
|
||||
end loop;
|
||||
exception
|
||||
when no_data_found then
|
||||
null;
|
||||
end;
|
||||
end if;
|
||||
end if;
|
||||
--
|
||||
begin
|
||||
l_http_resp := utl_http.get_response(l_http_req);
|
||||
exception when others then
|
||||
raise_application_error(-20001,'The URL provided is invalid or you need to set a proxy.');
|
||||
end;
|
||||
--
|
||||
|
||||
-- set response code, response http header and response cookies global
|
||||
g_status_code := l_http_resp.status_code;
|
||||
utl_http.get_cookies(g_response_cookies);
|
||||
for i in 1..utl_http.get_header_count(l_http_resp) loop
|
||||
utl_http.get_header(l_http_resp, i, l_name, l_hdr_value);
|
||||
l_hdr.name := l_name;
|
||||
l_hdr.value := l_hdr_value;
|
||||
l_hdrs(i) := l_hdr;
|
||||
end loop;
|
||||
|
||||
g_headers := l_hdrs;
|
||||
|
||||
--
|
||||
dbms_lob.createtemporary( l_value, FALSE );
|
||||
dbms_lob.open( l_value, dbms_lob.lob_readwrite );
|
||||
|
||||
begin
|
||||
loop
|
||||
utl_http.read_text(l_http_resp, l_buffer);
|
||||
dbms_lob.writeappend( l_value, length(l_buffer), l_buffer );
|
||||
end loop;
|
||||
exception
|
||||
when others then
|
||||
if sqlcode <> -29266 then
|
||||
raise;
|
||||
end if;
|
||||
end;
|
||||
--
|
||||
utl_http.end_response(l_http_resp);
|
||||
|
||||
return l_value;
|
||||
|
||||
end make_rest_request;
|
||||
|
||||
function parse_xml (
|
||||
p_xml in xmltype,
|
||||
p_xpath in varchar2,
|
||||
p_ns in varchar2 default null ) return varchar2
|
||||
is
|
||||
l_response varchar2(32767);
|
||||
begin
|
||||
|
||||
l_response := dbms_xmlgen.convert(p_xml.extract(p_xpath,p_ns).getstringval(),1);
|
||||
|
||||
return l_response;
|
||||
|
||||
exception when others then
|
||||
if sqlcode = -30625 then -- path not found
|
||||
return null;
|
||||
end if;
|
||||
end parse_xml;
|
||||
|
||||
function parse_xml_clob (
|
||||
p_xml in xmltype,
|
||||
p_xpath in varchar2,
|
||||
p_ns in varchar2 default null ) return clob
|
||||
is
|
||||
l_response clob;
|
||||
begin
|
||||
|
||||
l_response := p_xml.extract(p_xpath,p_ns).getclobval();
|
||||
|
||||
return l_response;
|
||||
|
||||
exception when others then
|
||||
if sqlcode = -30625 then -- path not found
|
||||
return null;
|
||||
end if;
|
||||
end parse_xml_clob;
|
||||
|
||||
function parse_response (
|
||||
p_collection_name in varchar2,
|
||||
p_xpath in varchar2,
|
||||
p_ns in varchar2 default null ) return varchar2
|
||||
is
|
||||
l_response varchar2(32767);
|
||||
l_xml xmltype;
|
||||
begin
|
||||
|
||||
for c1 in (select clob001
|
||||
from apex_collections
|
||||
where collection_name = p_collection_name ) loop
|
||||
l_xml := xmltype.createxml(c1.clob001);
|
||||
exit;
|
||||
end loop;
|
||||
|
||||
l_response := parse_xml(l_xml, p_xpath, p_ns);
|
||||
|
||||
return l_response;
|
||||
|
||||
exception when others then
|
||||
if sqlcode = -31011 then -- its not xml
|
||||
return null;
|
||||
end if;
|
||||
end parse_response;
|
||||
|
||||
function parse_response_clob (
|
||||
p_collection_name in varchar2,
|
||||
p_xpath in varchar2,
|
||||
p_ns in varchar2 default null ) return clob
|
||||
is
|
||||
l_response clob;
|
||||
l_xml xmltype;
|
||||
begin
|
||||
|
||||
for c1 in (select clob001
|
||||
from apex_collections
|
||||
where collection_name = p_collection_name ) loop
|
||||
l_xml := xmltype.createxml(c1.clob001);
|
||||
exit;
|
||||
end loop;
|
||||
|
||||
l_response := parse_xml_clob(l_xml, p_xpath, p_ns);
|
||||
|
||||
return l_response;
|
||||
|
||||
exception when others then
|
||||
if sqlcode = -31011 then -- its not xml
|
||||
return null;
|
||||
end if;
|
||||
end parse_response_clob;
|
||||
|
||||
end flex_ws_api;
|
||||
/
|
||||
98
ora/flex_ws_api.pks
Executable file
98
ora/flex_ws_api.pks
Executable file
@ -0,0 +1,98 @@
|
||||
create or replace package flex_ws_api
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Web Service callouts from PL/SQL
|
||||
|
||||
Remarks: By Jason Straub, see http://jastraub.blogspot.com/2008/06/flexible-web-service-api.html
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 21.05.2012 Added to Alexandria Library because this is a prerequisite for the EWS (MS Exchange Web Service) API
|
||||
|
||||
*/
|
||||
|
||||
|
||||
empty_vc_arr wwv_flow_global.vc_arr2;
|
||||
|
||||
g_request_cookies utl_http.cookie_table;
|
||||
g_response_cookies utl_http.cookie_table;
|
||||
|
||||
type header is record (name varchar2(256), value varchar2(1024));
|
||||
type header_table is table of header index by binary_integer;
|
||||
|
||||
g_headers header_table;
|
||||
g_request_headers header_table;
|
||||
|
||||
g_status_code pls_integer;
|
||||
|
||||
|
||||
function blob2clobbase64 (
|
||||
p_blob in blob ) return clob;
|
||||
|
||||
function clobbase642blob (
|
||||
p_clob in clob ) return blob;
|
||||
|
||||
procedure make_request (
|
||||
p_url in varchar2,
|
||||
p_action in varchar2 default null,
|
||||
p_version in varchar2 default '1.1',
|
||||
p_collection_name in varchar2 default null,
|
||||
p_envelope in clob,
|
||||
p_username in varchar2 default null,
|
||||
p_password in varchar2 default null,
|
||||
p_proxy_override in varchar2 default null,
|
||||
p_wallet_path in varchar2 default null,
|
||||
p_wallet_pwd in varchar2 default null,
|
||||
p_extra_headers in wwv_flow_global.vc_arr2 default empty_vc_arr );
|
||||
|
||||
function make_request (
|
||||
p_url in varchar2,
|
||||
p_action in varchar2 default null,
|
||||
p_version in varchar2 default '1.1',
|
||||
p_envelope in clob,
|
||||
p_username in varchar2 default null,
|
||||
p_password in varchar2 default null,
|
||||
p_proxy_override in varchar2 default null,
|
||||
p_wallet_path in varchar2 default null,
|
||||
p_wallet_pwd in varchar2 default null,
|
||||
p_extra_headers in wwv_flow_global.vc_arr2 default empty_vc_arr ) return xmltype;
|
||||
|
||||
function make_rest_request(
|
||||
p_url in varchar2,
|
||||
p_http_method in varchar2,
|
||||
p_username in varchar2 default null,
|
||||
p_password in varchar2 default null,
|
||||
p_proxy_override in varchar2 default null,
|
||||
p_body in clob default empty_clob(),
|
||||
p_body_blob in blob default empty_blob(),
|
||||
p_parm_name in wwv_flow_global.vc_arr2 default empty_vc_arr,
|
||||
p_parm_value in wwv_flow_global.vc_arr2 default empty_vc_arr,
|
||||
p_http_headers in wwv_flow_global.vc_arr2 default empty_vc_arr,
|
||||
p_http_hdr_values in wwv_flow_global.vc_arr2 default empty_vc_arr,
|
||||
p_wallet_path in varchar2 default null,
|
||||
p_wallet_pwd in varchar2 default null ) return clob;
|
||||
|
||||
function parse_xml (
|
||||
p_xml in xmltype,
|
||||
p_xpath in varchar2,
|
||||
p_ns in varchar2 default null ) return varchar2;
|
||||
|
||||
function parse_xml_clob (
|
||||
p_xml in xmltype,
|
||||
p_xpath in varchar2,
|
||||
p_ns in varchar2 default null ) return clob;
|
||||
|
||||
function parse_response (
|
||||
p_collection_name in varchar2,
|
||||
p_xpath in varchar2,
|
||||
p_ns in varchar2 default null ) return varchar2;
|
||||
|
||||
function parse_response_clob (
|
||||
p_collection_name in varchar2,
|
||||
p_xpath in varchar2,
|
||||
p_ns in varchar2 default null ) return clob;
|
||||
|
||||
end flex_ws_api;
|
||||
/
|
||||
800
ora/ftp_util_pkg.pkb
Executable file
800
ora/ftp_util_pkg.pkb
Executable file
@ -0,0 +1,800 @@
|
||||
CREATE OR REPLACE PACKAGE BODY ftp_util_pkg
|
||||
AS
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
-- Name : http://www.oracle-base.com/dba/miscellaneous/ftp.pkb
|
||||
-- Author : DR Timothy S Hall
|
||||
-- Description : Basic FTP API. For usage notes see:
|
||||
-- http://www.oracle-base.com/articles/misc/FTPFromPLSQL.php
|
||||
-- Requirements : http://www.oracle-base.com/dba/miscellaneous/ftp.pks
|
||||
-- Ammedments :
|
||||
-- When Who What
|
||||
-- =========== ======== =================================================
|
||||
-- 14-AUG-2003 Tim Hall Initial Creation
|
||||
-- 10-MAR-2004 Tim Hall Add convert_crlf procedure.
|
||||
-- Incorporate CRLF conversion functionality into
|
||||
-- put_local_ascii_data and put_remote_ascii_data
|
||||
-- functions.
|
||||
-- Make get_passive function visible.
|
||||
-- Added get_direct and put_direct procedures.
|
||||
-- 23-DEC-2004 Tim Hall The get_reply procedure was altered to deal with
|
||||
-- banners starting with 4 white spaces. This fix is
|
||||
-- a small variation on the resolution provided by
|
||||
-- Gary Mason who spotted the bug.
|
||||
-- 10-NOV-2005 Tim Hall Addition of get_reply after doing a transfer to
|
||||
-- pickup the 226 Transfer complete message. This
|
||||
-- allows gets and puts with a single connection.
|
||||
-- Issue spotted by Trevor Woolnough.
|
||||
-- 03-OCT-2006 Tim Hall Add list, rename, delete, mkdir, rmdir procedures.
|
||||
-- 12-JAN-2007 Tim Hall A final call to get_reply was added to the get_remote%
|
||||
-- procedures to allow multiple transfers per connection.
|
||||
-- 15-Jan-2008 Tim Hall login: Include timeout parameter (suggested by Dmitry Bogomolov).
|
||||
-- 21-Jan-2008 Tim Hall put_%: "l_pos < l_clob_len" to "l_pos <= l_clob_len" to prevent
|
||||
-- potential loss of one character for single-byte files or files
|
||||
-- sized 1 byte bigger than a number divisible by the buffer size
|
||||
-- (spotted by Michael Surikov).
|
||||
-- 23-Jan-2008 Tim Hall send_command: Possible solution for ORA-29260 errors included,
|
||||
-- but commented out (suggested by Kevin Phillips).
|
||||
-- 12-Feb-2008 Tim Hall put_local_binary_data and put_direct: Open file with "wb" for
|
||||
-- binary writes (spotted by Dwayne Hoban).
|
||||
-- 03-Mar-2008 Tim Hall list: get_reply call and close of passive connection added
|
||||
-- (suggested by Julian, Bavaria).
|
||||
-- 12-Jun-2008 Tim Hall A final call to get_reply was added to the put_remote%
|
||||
-- procedures, but commented out. If uncommented, it may cause the
|
||||
-- operation to hang, but it has been reported (morgul) to allow
|
||||
-- multiple transfers per connection.
|
||||
-- get_reply: Moved to pakage specification.
|
||||
-- 24-Jun-2008 Tim Hall get_remote% and put_remote%: Exception handler added to close the passive
|
||||
-- connection and reraise the error (suggested by Mark Reichman).
|
||||
-- 22-Apr-2009 Tim Hall get_remote_ascii_data: Remove unnecessary logout (suggested by John Duncan).
|
||||
-- get_reply and list: Handle 400 messages as well as 500 messages (suggested by John Duncan).
|
||||
-- logout: Added a call to UTL_TCP.close_connection, so not necessary to close
|
||||
-- any connections manually (suggested by Victor Munoz).
|
||||
-- get_local_*_data: Check for zero length files to prevent exception (suggested by Daniel)
|
||||
-- nlst: Added to return list of file names only (suggested by Julian and John Duncan)
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
g_reply t_string_table := t_string_table();
|
||||
g_binary BOOLEAN := TRUE;
|
||||
g_debug BOOLEAN := TRUE;
|
||||
g_convert_crlf BOOLEAN := TRUE;
|
||||
|
||||
PROCEDURE debug (p_text IN VARCHAR2);
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
FUNCTION login (p_host IN VARCHAR2,
|
||||
p_port IN VARCHAR2,
|
||||
p_user IN VARCHAR2,
|
||||
p_pass IN VARCHAR2,
|
||||
p_timeout IN NUMBER := NULL)
|
||||
RETURN UTL_TCP.connection IS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_conn UTL_TCP.connection;
|
||||
BEGIN
|
||||
g_reply.delete;
|
||||
|
||||
l_conn := UTL_TCP.open_connection(p_host, p_port, tx_timeout => p_timeout);
|
||||
get_reply (l_conn);
|
||||
send_command(l_conn, 'USER ' || p_user);
|
||||
send_command(l_conn, 'PASS ' || p_pass);
|
||||
RETURN l_conn;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
FUNCTION get_passive (p_conn IN OUT NOCOPY UTL_TCP.connection)
|
||||
RETURN UTL_TCP.connection IS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_conn UTL_TCP.connection;
|
||||
l_reply VARCHAR2(32767);
|
||||
l_host VARCHAR(100);
|
||||
l_port1 NUMBER(10);
|
||||
l_port2 NUMBER(10);
|
||||
BEGIN
|
||||
send_command(p_conn, 'PASV');
|
||||
l_reply := g_reply(g_reply.last);
|
||||
|
||||
l_reply := REPLACE(SUBSTR(l_reply, INSTR(l_reply, '(') + 1, (INSTR(l_reply, ')')) - (INSTR(l_reply, '('))-1), ',', '.');
|
||||
l_host := SUBSTR(l_reply, 1, INSTR(l_reply, '.', 1, 4)-1);
|
||||
|
||||
l_port1 := TO_NUMBER(SUBSTR(l_reply, INSTR(l_reply, '.', 1, 4)+1, (INSTR(l_reply, '.', 1, 5)-1) - (INSTR(l_reply, '.', 1, 4))));
|
||||
l_port2 := TO_NUMBER(SUBSTR(l_reply, INSTR(l_reply, '.', 1, 5)+1));
|
||||
|
||||
l_conn := utl_tcp.open_connection(l_host, 256 * l_port1 + l_port2);
|
||||
return l_conn;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE logout(p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_reply IN BOOLEAN := TRUE) AS
|
||||
-- --------------------------------------------------------------------------
|
||||
BEGIN
|
||||
send_command(p_conn, 'QUIT', p_reply);
|
||||
UTL_TCP.close_connection(p_conn);
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE send_command (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_command IN VARCHAR2,
|
||||
p_reply IN BOOLEAN := TRUE) IS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_result PLS_INTEGER;
|
||||
BEGIN
|
||||
l_result := UTL_TCP.write_line(p_conn, p_command);
|
||||
-- If you get ORA-29260 after the PASV call, replace the above line with the following line.
|
||||
-- l_result := UTL_TCP.write_text(p_conn, p_command || utl_tcp.crlf, length(p_command || utl_tcp.crlf));
|
||||
|
||||
IF p_reply THEN
|
||||
get_reply(p_conn);
|
||||
END IF;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE get_reply (p_conn IN OUT NOCOPY UTL_TCP.connection) IS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_reply_code VARCHAR2(3) := NULL;
|
||||
BEGIN
|
||||
LOOP
|
||||
g_reply.extend;
|
||||
g_reply(g_reply.last) := UTL_TCP.get_line(p_conn, TRUE);
|
||||
debug(g_reply(g_reply.last));
|
||||
IF l_reply_code IS NULL THEN
|
||||
l_reply_code := SUBSTR(g_reply(g_reply.last), 1, 3);
|
||||
END IF;
|
||||
IF SUBSTR(l_reply_code, 1, 1) IN ('4', '5') THEN
|
||||
RAISE_APPLICATION_ERROR(-20000, g_reply(g_reply.last));
|
||||
ELSIF (SUBSTR(g_reply(g_reply.last), 1, 3) = l_reply_code AND
|
||||
SUBSTR(g_reply(g_reply.last), 4, 1) = ' ') THEN
|
||||
EXIT;
|
||||
END IF;
|
||||
END LOOP;
|
||||
EXCEPTION
|
||||
WHEN UTL_TCP.END_OF_INPUT THEN
|
||||
NULL;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
FUNCTION get_local_ascii_data (p_dir IN VARCHAR2,
|
||||
p_file IN VARCHAR2)
|
||||
RETURN CLOB IS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_bfile BFILE;
|
||||
l_data CLOB;
|
||||
BEGIN
|
||||
DBMS_LOB.createtemporary (lob_loc => l_data,
|
||||
cache => TRUE,
|
||||
dur => DBMS_LOB.call);
|
||||
|
||||
l_bfile := BFILENAME(p_dir, p_file);
|
||||
DBMS_LOB.fileopen(l_bfile, DBMS_LOB.file_readonly);
|
||||
|
||||
IF DBMS_LOB.getlength(l_bfile) > 0 THEN
|
||||
DBMS_LOB.loadfromfile(l_data, l_bfile, DBMS_LOB.getlength(l_bfile));
|
||||
END IF;
|
||||
|
||||
DBMS_LOB.fileclose(l_bfile);
|
||||
|
||||
RETURN l_data;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
FUNCTION get_local_binary_data (p_dir IN VARCHAR2,
|
||||
p_file IN VARCHAR2)
|
||||
RETURN BLOB IS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_bfile BFILE;
|
||||
l_data BLOB;
|
||||
BEGIN
|
||||
DBMS_LOB.createtemporary (lob_loc => l_data,
|
||||
cache => TRUE,
|
||||
dur => DBMS_LOB.call);
|
||||
|
||||
l_bfile := BFILENAME(p_dir, p_file);
|
||||
DBMS_LOB.fileopen(l_bfile, DBMS_LOB.file_readonly);
|
||||
IF DBMS_LOB.getlength(l_bfile) > 0 THEN
|
||||
DBMS_LOB.loadfromfile(l_data, l_bfile, DBMS_LOB.getlength(l_bfile));
|
||||
END IF;
|
||||
DBMS_LOB.fileclose(l_bfile);
|
||||
|
||||
RETURN l_data;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
FUNCTION get_remote_ascii_data (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_file IN VARCHAR2)
|
||||
RETURN CLOB IS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_conn UTL_TCP.connection;
|
||||
l_amount PLS_INTEGER;
|
||||
l_buffer VARCHAR2(32767);
|
||||
l_data CLOB;
|
||||
BEGIN
|
||||
DBMS_LOB.createtemporary (lob_loc => l_data,
|
||||
cache => TRUE,
|
||||
dur => DBMS_LOB.call);
|
||||
|
||||
l_conn := get_passive(p_conn);
|
||||
send_command(p_conn, 'RETR ' || p_file, TRUE);
|
||||
--logout(l_conn, FALSE);
|
||||
|
||||
BEGIN
|
||||
LOOP
|
||||
l_amount := UTL_TCP.read_text (l_conn, l_buffer, 32767);
|
||||
DBMS_LOB.writeappend(l_data, l_amount, l_buffer);
|
||||
END LOOP;
|
||||
EXCEPTION
|
||||
WHEN UTL_TCP.END_OF_INPUT THEN
|
||||
NULL;
|
||||
WHEN OTHERS THEN
|
||||
NULL;
|
||||
END;
|
||||
UTL_TCP.close_connection(l_conn);
|
||||
get_reply(p_conn);
|
||||
|
||||
RETURN l_data;
|
||||
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
UTL_TCP.close_connection(l_conn);
|
||||
RAISE;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
FUNCTION get_remote_binary_data (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_file IN VARCHAR2)
|
||||
RETURN BLOB IS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_conn UTL_TCP.connection;
|
||||
l_amount PLS_INTEGER;
|
||||
l_buffer RAW(32767);
|
||||
l_data BLOB;
|
||||
BEGIN
|
||||
DBMS_LOB.createtemporary (lob_loc => l_data,
|
||||
cache => TRUE,
|
||||
dur => DBMS_LOB.call);
|
||||
|
||||
l_conn := get_passive(p_conn);
|
||||
send_command(p_conn, 'RETR ' || p_file, TRUE);
|
||||
|
||||
BEGIN
|
||||
LOOP
|
||||
l_amount := UTL_TCP.read_raw (l_conn, l_buffer, 32767);
|
||||
DBMS_LOB.writeappend(l_data, l_amount, l_buffer);
|
||||
END LOOP;
|
||||
EXCEPTION
|
||||
WHEN UTL_TCP.END_OF_INPUT THEN
|
||||
NULL;
|
||||
WHEN OTHERS THEN
|
||||
NULL;
|
||||
END;
|
||||
UTL_TCP.close_connection(l_conn);
|
||||
get_reply(p_conn);
|
||||
|
||||
RETURN l_data;
|
||||
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
UTL_TCP.close_connection(l_conn);
|
||||
RAISE;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE put_local_ascii_data (p_data IN CLOB,
|
||||
p_dir IN VARCHAR2,
|
||||
p_file IN VARCHAR2) IS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_out_file UTL_FILE.file_type;
|
||||
l_buffer VARCHAR2(32767);
|
||||
l_amount BINARY_INTEGER := 32767;
|
||||
l_pos INTEGER := 1;
|
||||
l_clob_len INTEGER;
|
||||
BEGIN
|
||||
l_clob_len := DBMS_LOB.getlength(p_data);
|
||||
|
||||
l_out_file := UTL_FILE.fopen(p_dir, p_file, 'w', 32767);
|
||||
|
||||
WHILE l_pos <= l_clob_len LOOP
|
||||
DBMS_LOB.read (p_data, l_amount, l_pos, l_buffer);
|
||||
IF g_convert_crlf THEN
|
||||
l_buffer := REPLACE(l_buffer, CHR(13), NULL);
|
||||
END IF;
|
||||
|
||||
UTL_FILE.put(l_out_file, l_buffer);
|
||||
UTL_FILE.fflush(l_out_file);
|
||||
l_pos := l_pos + l_amount;
|
||||
END LOOP;
|
||||
|
||||
UTL_FILE.fclose(l_out_file);
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
IF UTL_FILE.is_open(l_out_file) THEN
|
||||
UTL_FILE.fclose(l_out_file);
|
||||
END IF;
|
||||
RAISE;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE put_local_binary_data (p_data IN BLOB,
|
||||
p_dir IN VARCHAR2,
|
||||
p_file IN VARCHAR2) IS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_out_file UTL_FILE.file_type;
|
||||
l_buffer RAW(32767);
|
||||
l_amount BINARY_INTEGER := 32767;
|
||||
l_pos INTEGER := 1;
|
||||
l_blob_len INTEGER;
|
||||
BEGIN
|
||||
l_blob_len := DBMS_LOB.getlength(p_data);
|
||||
|
||||
l_out_file := UTL_FILE.fopen(p_dir, p_file, 'wb', 32767);
|
||||
|
||||
WHILE l_pos <= l_blob_len LOOP
|
||||
DBMS_LOB.read (p_data, l_amount, l_pos, l_buffer);
|
||||
UTL_FILE.put_raw(l_out_file, l_buffer, TRUE);
|
||||
UTL_FILE.fflush(l_out_file);
|
||||
l_pos := l_pos + l_amount;
|
||||
END LOOP;
|
||||
|
||||
UTL_FILE.fclose(l_out_file);
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
IF UTL_FILE.is_open(l_out_file) THEN
|
||||
UTL_FILE.fclose(l_out_file);
|
||||
END IF;
|
||||
RAISE;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE put_remote_ascii_data (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_file IN VARCHAR2,
|
||||
p_data IN CLOB) IS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_conn UTL_TCP.connection;
|
||||
l_result PLS_INTEGER;
|
||||
l_buffer VARCHAR2(32767);
|
||||
l_amount BINARY_INTEGER := 32767;
|
||||
l_pos INTEGER := 1;
|
||||
l_clob_len INTEGER;
|
||||
BEGIN
|
||||
l_conn := get_passive(p_conn);
|
||||
send_command(p_conn, 'STOR ' || p_file, TRUE);
|
||||
|
||||
l_clob_len := DBMS_LOB.getlength(p_data);
|
||||
|
||||
WHILE l_pos <= l_clob_len LOOP
|
||||
DBMS_LOB.READ (p_data, l_amount, l_pos, l_buffer);
|
||||
IF g_convert_crlf THEN
|
||||
l_buffer := REPLACE(l_buffer, CHR(13), NULL);
|
||||
END IF;
|
||||
l_result := UTL_TCP.write_text(l_conn, l_buffer, LENGTH(l_buffer));
|
||||
UTL_TCP.flush(l_conn);
|
||||
l_pos := l_pos + l_amount;
|
||||
END LOOP;
|
||||
|
||||
UTL_TCP.close_connection(l_conn);
|
||||
-- The following line allows some people to make multiple calls from one connection.
|
||||
-- It causes the operation to hang for me, hence it is commented out by default.
|
||||
-- get_reply(p_conn);
|
||||
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
UTL_TCP.close_connection(l_conn);
|
||||
RAISE;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE put_remote_binary_data (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_file IN VARCHAR2,
|
||||
p_data IN BLOB) IS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_conn UTL_TCP.connection;
|
||||
l_result PLS_INTEGER;
|
||||
l_buffer RAW(32767);
|
||||
l_amount BINARY_INTEGER := 32767;
|
||||
l_pos INTEGER := 1;
|
||||
l_blob_len INTEGER;
|
||||
BEGIN
|
||||
l_conn := get_passive(p_conn);
|
||||
send_command(p_conn, 'STOR ' || p_file, TRUE);
|
||||
|
||||
l_blob_len := DBMS_LOB.getlength(p_data);
|
||||
|
||||
WHILE l_pos <= l_blob_len LOOP
|
||||
DBMS_LOB.READ (p_data, l_amount, l_pos, l_buffer);
|
||||
l_result := UTL_TCP.write_raw(l_conn, l_buffer, l_amount);
|
||||
UTL_TCP.flush(l_conn);
|
||||
l_pos := l_pos + l_amount;
|
||||
END LOOP;
|
||||
|
||||
UTL_TCP.close_connection(l_conn);
|
||||
-- The following line allows some people to make multiple calls from one connection.
|
||||
-- It causes the operation to hang for me, hence it is commented out by default.
|
||||
-- get_reply(p_conn);
|
||||
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
UTL_TCP.close_connection(l_conn);
|
||||
RAISE;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE get (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_from_file IN VARCHAR2,
|
||||
p_to_dir IN VARCHAR2,
|
||||
p_to_file IN VARCHAR2) AS
|
||||
-- --------------------------------------------------------------------------
|
||||
BEGIN
|
||||
IF g_binary THEN
|
||||
put_local_binary_data(p_data => get_remote_binary_data (p_conn, p_from_file),
|
||||
p_dir => p_to_dir,
|
||||
p_file => p_to_file);
|
||||
ELSE
|
||||
put_local_ascii_data(p_data => get_remote_ascii_data (p_conn, p_from_file),
|
||||
p_dir => p_to_dir,
|
||||
p_file => p_to_file);
|
||||
END IF;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE put (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_from_dir IN VARCHAR2,
|
||||
p_from_file IN VARCHAR2,
|
||||
p_to_file IN VARCHAR2) AS
|
||||
-- --------------------------------------------------------------------------
|
||||
BEGIN
|
||||
IF g_binary THEN
|
||||
put_remote_binary_data(p_conn => p_conn,
|
||||
p_file => p_to_file,
|
||||
p_data => get_local_binary_data(p_from_dir, p_from_file));
|
||||
ELSE
|
||||
put_remote_ascii_data(p_conn => p_conn,
|
||||
p_file => p_to_file,
|
||||
p_data => get_local_ascii_data(p_from_dir, p_from_file));
|
||||
END IF;
|
||||
get_reply(p_conn);
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE get_direct (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_from_file IN VARCHAR2,
|
||||
p_to_dir IN VARCHAR2,
|
||||
p_to_file IN VARCHAR2) IS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_conn UTL_TCP.connection;
|
||||
l_out_file UTL_FILE.file_type;
|
||||
l_amount PLS_INTEGER;
|
||||
l_buffer VARCHAR2(32767);
|
||||
l_raw_buffer RAW(32767);
|
||||
BEGIN
|
||||
l_conn := get_passive(p_conn);
|
||||
send_command(p_conn, 'RETR ' || p_from_file, TRUE);
|
||||
IF g_binary THEN
|
||||
l_out_file := UTL_FILE.fopen(p_to_dir, p_to_file, 'wb', 32767);
|
||||
ELSE
|
||||
l_out_file := UTL_FILE.fopen(p_to_dir, p_to_file, 'w', 32767);
|
||||
END IF;
|
||||
|
||||
BEGIN
|
||||
LOOP
|
||||
IF g_binary THEN
|
||||
l_amount := UTL_TCP.read_raw (l_conn, l_raw_buffer, 32767);
|
||||
UTL_FILE.put_raw(l_out_file, l_raw_buffer, TRUE);
|
||||
ELSE
|
||||
l_amount := UTL_TCP.read_text (l_conn, l_buffer, 32767);
|
||||
IF g_convert_crlf THEN
|
||||
l_buffer := REPLACE(l_buffer, CHR(13), NULL);
|
||||
END IF;
|
||||
UTL_FILE.put(l_out_file, l_buffer);
|
||||
END IF;
|
||||
UTL_FILE.fflush(l_out_file);
|
||||
END LOOP;
|
||||
EXCEPTION
|
||||
WHEN UTL_TCP.END_OF_INPUT THEN
|
||||
NULL;
|
||||
WHEN OTHERS THEN
|
||||
NULL;
|
||||
END;
|
||||
UTL_FILE.fclose(l_out_file);
|
||||
UTL_TCP.close_connection(l_conn);
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
IF UTL_FILE.is_open(l_out_file) THEN
|
||||
UTL_FILE.fclose(l_out_file);
|
||||
END IF;
|
||||
RAISE;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE put_direct (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_from_dir IN VARCHAR2,
|
||||
p_from_file IN VARCHAR2,
|
||||
p_to_file IN VARCHAR2) IS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_conn UTL_TCP.connection;
|
||||
l_bfile BFILE;
|
||||
l_result PLS_INTEGER;
|
||||
l_amount PLS_INTEGER := 32767;
|
||||
l_raw_buffer RAW(32767);
|
||||
l_len NUMBER;
|
||||
l_pos NUMBER := 1;
|
||||
ex_ascii EXCEPTION;
|
||||
BEGIN
|
||||
IF NOT g_binary THEN
|
||||
RAISE ex_ascii;
|
||||
END IF;
|
||||
|
||||
l_conn := get_passive(p_conn);
|
||||
send_command(p_conn, 'STOR ' || p_to_file, TRUE);
|
||||
|
||||
l_bfile := BFILENAME(p_from_dir, p_from_file);
|
||||
|
||||
DBMS_LOB.fileopen(l_bfile, DBMS_LOB.file_readonly);
|
||||
l_len := DBMS_LOB.getlength(l_bfile);
|
||||
|
||||
WHILE l_pos <= l_len LOOP
|
||||
DBMS_LOB.READ (l_bfile, l_amount, l_pos, l_raw_buffer);
|
||||
debug(l_amount);
|
||||
l_result := UTL_TCP.write_raw(l_conn, l_raw_buffer, l_amount);
|
||||
l_pos := l_pos + l_amount;
|
||||
END LOOP;
|
||||
|
||||
DBMS_LOB.fileclose(l_bfile);
|
||||
UTL_TCP.close_connection(l_conn);
|
||||
EXCEPTION
|
||||
WHEN ex_ascii THEN
|
||||
RAISE_APPLICATION_ERROR(-20000, 'PUT_DIRECT not available in ASCII mode.');
|
||||
WHEN OTHERS THEN
|
||||
IF DBMS_LOB.fileisopen(l_bfile) = 1 THEN
|
||||
DBMS_LOB.fileclose(l_bfile);
|
||||
END IF;
|
||||
RAISE;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE help (p_conn IN OUT NOCOPY UTL_TCP.connection) AS
|
||||
-- --------------------------------------------------------------------------
|
||||
BEGIN
|
||||
send_command(p_conn, 'HELP', TRUE);
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE ascii (p_conn IN OUT NOCOPY UTL_TCP.connection) AS
|
||||
-- --------------------------------------------------------------------------
|
||||
BEGIN
|
||||
send_command(p_conn, 'TYPE A', TRUE);
|
||||
g_binary := FALSE;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE binary (p_conn IN OUT NOCOPY UTL_TCP.connection) AS
|
||||
-- --------------------------------------------------------------------------
|
||||
BEGIN
|
||||
send_command(p_conn, 'TYPE I', TRUE);
|
||||
g_binary := TRUE;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE list (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_dir IN VARCHAR2,
|
||||
p_list OUT t_string_table) AS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_conn UTL_TCP.connection;
|
||||
l_list t_string_table := t_string_table();
|
||||
l_reply_code VARCHAR2(3) := NULL;
|
||||
BEGIN
|
||||
l_conn := get_passive(p_conn);
|
||||
send_command(p_conn, 'LIST ' || p_dir, TRUE);
|
||||
|
||||
BEGIN
|
||||
LOOP
|
||||
l_list.extend;
|
||||
l_list(l_list.last) := UTL_TCP.get_line(l_conn, TRUE);
|
||||
debug(l_list(l_list.last));
|
||||
IF l_reply_code IS NULL THEN
|
||||
l_reply_code := SUBSTR(l_list(l_list.last), 1, 3);
|
||||
END IF;
|
||||
IF SUBSTR(l_reply_code, 1, 1) IN ('4', '5') THEN
|
||||
RAISE_APPLICATION_ERROR(-20000, l_list(l_list.last));
|
||||
ELSIF (SUBSTR(g_reply(g_reply.last), 1, 3) = l_reply_code AND
|
||||
SUBSTR(g_reply(g_reply.last), 4, 1) = ' ') THEN
|
||||
EXIT;
|
||||
END IF;
|
||||
END LOOP;
|
||||
EXCEPTION
|
||||
WHEN UTL_TCP.END_OF_INPUT THEN
|
||||
NULL;
|
||||
END;
|
||||
|
||||
l_list.delete(l_list.last);
|
||||
p_list := l_list;
|
||||
|
||||
utl_tcp.close_connection(l_conn);
|
||||
get_reply (p_conn);
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE nlst (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_dir IN VARCHAR2,
|
||||
p_list OUT t_string_table) AS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_conn UTL_TCP.connection;
|
||||
l_list t_string_table := t_string_table();
|
||||
l_reply_code VARCHAR2(3) := NULL;
|
||||
BEGIN
|
||||
l_conn := get_passive(p_conn);
|
||||
send_command(p_conn, 'NLST ' || p_dir, TRUE);
|
||||
|
||||
BEGIN
|
||||
LOOP
|
||||
l_list.extend;
|
||||
l_list(l_list.last) := UTL_TCP.get_line(l_conn, TRUE);
|
||||
debug(l_list(l_list.last));
|
||||
IF l_reply_code IS NULL THEN
|
||||
l_reply_code := SUBSTR(l_list(l_list.last), 1, 3);
|
||||
END IF;
|
||||
IF SUBSTR(l_reply_code, 1, 1) IN ('4', '5') THEN
|
||||
RAISE_APPLICATION_ERROR(-20000, l_list(l_list.last));
|
||||
ELSIF (SUBSTR(g_reply(g_reply.last), 1, 3) = l_reply_code AND
|
||||
SUBSTR(g_reply(g_reply.last), 4, 1) = ' ') THEN
|
||||
EXIT;
|
||||
END IF;
|
||||
END LOOP;
|
||||
EXCEPTION
|
||||
WHEN UTL_TCP.END_OF_INPUT THEN
|
||||
NULL;
|
||||
END;
|
||||
|
||||
l_list.delete(l_list.last);
|
||||
p_list := l_list;
|
||||
|
||||
utl_tcp.close_connection(l_conn);
|
||||
get_reply (p_conn);
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE rename (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_from IN VARCHAR2,
|
||||
p_to IN VARCHAR2) AS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_conn UTL_TCP.connection;
|
||||
BEGIN
|
||||
l_conn := get_passive(p_conn);
|
||||
send_command(p_conn, 'RNFR ' || p_from, TRUE);
|
||||
send_command(p_conn, 'RNTO ' || p_to, TRUE);
|
||||
logout(l_conn, FALSE);
|
||||
END rename;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE delete (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_file IN VARCHAR2) AS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_conn UTL_TCP.connection;
|
||||
BEGIN
|
||||
l_conn := get_passive(p_conn);
|
||||
send_command(p_conn, 'DELE ' || p_file, TRUE);
|
||||
logout(l_conn, FALSE);
|
||||
END delete;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE mkdir (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_dir IN VARCHAR2) AS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_conn UTL_TCP.connection;
|
||||
BEGIN
|
||||
l_conn := get_passive(p_conn);
|
||||
send_command(p_conn, 'MKD ' || p_dir, TRUE);
|
||||
logout(l_conn, FALSE);
|
||||
END mkdir;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE rmdir (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_dir IN VARCHAR2) AS
|
||||
-- --------------------------------------------------------------------------
|
||||
l_conn UTL_TCP.connection;
|
||||
BEGIN
|
||||
l_conn := get_passive(p_conn);
|
||||
send_command(p_conn, 'RMD ' || p_dir, TRUE);
|
||||
logout(l_conn, FALSE);
|
||||
END rmdir;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE convert_crlf (p_status IN BOOLEAN) AS
|
||||
-- --------------------------------------------------------------------------
|
||||
BEGIN
|
||||
g_convert_crlf := p_status;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
PROCEDURE debug (p_text IN VARCHAR2) IS
|
||||
-- --------------------------------------------------------------------------
|
||||
BEGIN
|
||||
IF g_debug THEN
|
||||
DBMS_OUTPUT.put_line(SUBSTR(p_text, 1, 255));
|
||||
END IF;
|
||||
END;
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
END ftp_util_pkg;
|
||||
/
|
||||
|
||||
|
||||
122
ora/ftp_util_pkg.pks
Executable file
122
ora/ftp_util_pkg.pks
Executable file
@ -0,0 +1,122 @@
|
||||
CREATE OR REPLACE PACKAGE ftp_util_pkg
|
||||
AS
|
||||
|
||||
-- --------------------------------------------------------------------------
|
||||
-- Name : http://www.oracle-base.com/dba/miscellaneous/ftp.pks
|
||||
-- Author : DR Timothy S Hall
|
||||
-- Description : Basic FTP API. For usage notes see:
|
||||
-- http://www.oracle-base.com/articles/misc/FTPFromPLSQL.php
|
||||
-- Requirements : UTL_TCP
|
||||
-- Ammedments :
|
||||
-- When Who What
|
||||
-- =========== ======== =================================================
|
||||
-- 14-AUG-2003 Tim Hall Initial Creation
|
||||
-- 10-MAR-2004 Tim Hall Add convert_crlf procedure.
|
||||
-- Make get_passive function visible.
|
||||
-- Added get_direct and put_direct procedures.
|
||||
-- 03-OCT-2006 Tim Hall Add list, rename, delete, mkdir, rmdir procedures.
|
||||
-- 15-Jan-2008 Tim Hall login: Include timeout parameter (suggested by Dmitry Bogomolov).
|
||||
-- 12-Jun-2008 Tim Hall get_reply: Moved to pakage specification.
|
||||
-- 22-Apr-2009 Tim Hall nlst: Added to return list of file names only (suggested by Julian and John Duncan)
|
||||
-- --------------------------------------------------------------------------
|
||||
|
||||
TYPE t_string_table IS TABLE OF VARCHAR2(32767);
|
||||
|
||||
FUNCTION login (p_host IN VARCHAR2,
|
||||
p_port IN VARCHAR2,
|
||||
p_user IN VARCHAR2,
|
||||
p_pass IN VARCHAR2,
|
||||
p_timeout IN NUMBER := NULL) RETURN UTL_TCP.connection;
|
||||
|
||||
FUNCTION get_passive (p_conn IN OUT NOCOPY UTL_TCP.connection) RETURN UTL_TCP.connection;
|
||||
|
||||
PROCEDURE logout (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_reply IN BOOLEAN := TRUE);
|
||||
|
||||
PROCEDURE send_command (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_command IN VARCHAR2,
|
||||
p_reply IN BOOLEAN := TRUE);
|
||||
|
||||
PROCEDURE get_reply (p_conn IN OUT NOCOPY UTL_TCP.connection);
|
||||
|
||||
FUNCTION get_local_ascii_data (p_dir IN VARCHAR2,
|
||||
p_file IN VARCHAR2) RETURN CLOB;
|
||||
|
||||
FUNCTION get_local_binary_data (p_dir IN VARCHAR2,
|
||||
p_file IN VARCHAR2) RETURN BLOB;
|
||||
|
||||
FUNCTION get_remote_ascii_data (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_file IN VARCHAR2) RETURN CLOB;
|
||||
|
||||
FUNCTION get_remote_binary_data (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_file IN VARCHAR2) RETURN BLOB;
|
||||
|
||||
PROCEDURE put_local_ascii_data (p_data IN CLOB,
|
||||
p_dir IN VARCHAR2,
|
||||
p_file IN VARCHAR2);
|
||||
|
||||
PROCEDURE put_local_binary_data (p_data IN BLOB,
|
||||
p_dir IN VARCHAR2,
|
||||
p_file IN VARCHAR2);
|
||||
|
||||
PROCEDURE put_remote_ascii_data (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_file IN VARCHAR2,
|
||||
p_data IN CLOB);
|
||||
|
||||
PROCEDURE put_remote_binary_data (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_file IN VARCHAR2,
|
||||
p_data IN BLOB);
|
||||
|
||||
PROCEDURE get (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_from_file IN VARCHAR2,
|
||||
p_to_dir IN VARCHAR2,
|
||||
p_to_file IN VARCHAR2);
|
||||
|
||||
PROCEDURE put (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_from_dir IN VARCHAR2,
|
||||
p_from_file IN VARCHAR2,
|
||||
p_to_file IN VARCHAR2);
|
||||
|
||||
PROCEDURE get_direct (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_from_file IN VARCHAR2,
|
||||
p_to_dir IN VARCHAR2,
|
||||
p_to_file IN VARCHAR2);
|
||||
|
||||
PROCEDURE put_direct (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_from_dir IN VARCHAR2,
|
||||
p_from_file IN VARCHAR2,
|
||||
p_to_file IN VARCHAR2);
|
||||
|
||||
PROCEDURE help (p_conn IN OUT NOCOPY UTL_TCP.connection);
|
||||
|
||||
PROCEDURE ascii (p_conn IN OUT NOCOPY UTL_TCP.connection);
|
||||
|
||||
PROCEDURE binary (p_conn IN OUT NOCOPY UTL_TCP.connection);
|
||||
|
||||
PROCEDURE list (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_dir IN VARCHAR2,
|
||||
p_list OUT t_string_table);
|
||||
|
||||
PROCEDURE nlst (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_dir IN VARCHAR2,
|
||||
p_list OUT t_string_table);
|
||||
|
||||
PROCEDURE rename (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_from IN VARCHAR2,
|
||||
p_to IN VARCHAR2);
|
||||
|
||||
PROCEDURE delete (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_file IN VARCHAR2);
|
||||
|
||||
PROCEDURE mkdir (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_dir IN VARCHAR2);
|
||||
|
||||
PROCEDURE rmdir (p_conn IN OUT NOCOPY UTL_TCP.connection,
|
||||
p_dir IN VARCHAR2);
|
||||
|
||||
PROCEDURE convert_crlf (p_status IN BOOLEAN);
|
||||
|
||||
END ftp_util_pkg;
|
||||
/
|
||||
|
||||
|
||||
88
ora/gis_util_pkg.pkb
Executable file
88
ora/gis_util_pkg.pkb
Executable file
@ -0,0 +1,88 @@
|
||||
create or replace package body gis_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package contains utility functions related to Geographical Information Systems (GIS)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 06.02.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
g_degrees_to_radians_factor constant number := 57.29577951;
|
||||
|
||||
|
||||
function get_ecliptic_degree (p_degree in number,
|
||||
p_direction in varchar2) return number
|
||||
as
|
||||
l_returnvalue number;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get degrees (ecliptic)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
FDL 26.05.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
if p_direction in (g_longitude_direction_west, g_latitude_direction_south) then
|
||||
l_returnvalue := 360 - p_degree;
|
||||
else
|
||||
l_returnvalue := p_degree;
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_ecliptic_degree;
|
||||
|
||||
|
||||
|
||||
function get_ecliptic_distance (p_from_latitude in number,
|
||||
p_from_longitude in number,
|
||||
p_to_latitude in number,
|
||||
p_to_longitude in number,
|
||||
p_radius in number := g_radius_earth_miles) return number
|
||||
as
|
||||
l_returnvalue number;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: calculate distance based on latitude and longitude
|
||||
|
||||
Remarks: see http://en.wikipedia.org/wiki/Ecliptic_coordinate_system
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
FDL 27.05.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
begin
|
||||
l_returnvalue := (p_radius * acos((sin(p_from_latitude / g_degrees_to_radians_factor) * sin(p_to_latitude / g_degrees_to_radians_factor)) +
|
||||
(cos(p_from_latitude / g_degrees_to_radians_factor) * cos(p_to_latitude /g_degrees_to_radians_factor) *
|
||||
cos(p_to_longitude / g_degrees_to_radians_factor - p_from_longitude/ g_degrees_to_radians_factor))));
|
||||
exception
|
||||
when others then
|
||||
l_returnvalue := null;
|
||||
end;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_ecliptic_distance;
|
||||
|
||||
|
||||
end gis_util_pkg;
|
||||
/
|
||||
|
||||
|
||||
|
||||
35
ora/gis_util_pkg.pks
Executable file
35
ora/gis_util_pkg.pks
Executable file
@ -0,0 +1,35 @@
|
||||
create or replace package gis_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package contains utility functions related to Geographical Information Systems (GIS)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 06.02.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
g_radius_earth_miles constant number := 3443.917;
|
||||
|
||||
g_latitude_direction_north constant varchar2(1) := 'N';
|
||||
g_latitude_direction_south constant varchar2(1) := 'S';
|
||||
g_longitude_direction_east constant varchar2(1) := 'E';
|
||||
g_longitude_direction_west constant varchar2(1) := 'W';
|
||||
|
||||
-- get ecliptic degree of position
|
||||
function get_ecliptic_degree (p_degree in number,
|
||||
p_direction in varchar2) return number;
|
||||
|
||||
-- get distance between to geographic position
|
||||
function get_ecliptic_distance (p_from_latitude in number,
|
||||
p_from_longitude in number,
|
||||
p_to_latitude in number,
|
||||
p_to_longitude in number,
|
||||
p_radius in number := g_radius_earth_miles) return number;
|
||||
|
||||
end gis_util_pkg;
|
||||
/
|
||||
156
ora/google_maps_js_pkg.pkb
Executable file
156
ora/google_maps_js_pkg.pkb
Executable file
@ -0,0 +1,156 @@
|
||||
create or replace package body google_maps_js_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles Google Maps integration with JavaScript
|
||||
|
||||
Remarks: see http://code.google.com/apis/maps/documentation/javascript/v2/reference.html
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 05.02.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
g_map_id varchar2(255);
|
||||
g_map_options t_map_options;
|
||||
g_point_list google_maps_pkg.t_point_list;
|
||||
|
||||
|
||||
procedure init_map (p_map_id in varchar2,
|
||||
p_options in t_map_options := null)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: initialize map
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 05.02.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
g_map_id := p_map_id;
|
||||
g_map_options := p_options;
|
||||
g_point_list.delete;
|
||||
|
||||
end init_map;
|
||||
|
||||
|
||||
procedure add_point (p_point in google_maps_pkg.t_point)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: add point to map
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 05.02.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
if g_point_list.count = 0 then
|
||||
g_point_list(1) := p_point;
|
||||
else
|
||||
g_point_list(g_point_list.last+1) := p_point;
|
||||
end if;
|
||||
|
||||
|
||||
end add_point;
|
||||
|
||||
|
||||
procedure render_map_script
|
||||
as
|
||||
l_str string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: render map script
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 05.02.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
htp.p('<script src="http://maps.google.com/maps?file=api&v=2&key=' || google_maps_pkg.get_api_key || '" type="text/javascript"></script>
|
||||
<script type="text/javascript">
|
||||
//<![CDATA[
|
||||
//globals
|
||||
var bounds = new GLatLngBounds();
|
||||
function initMap() {
|
||||
if (GBrowserIsCompatible()) {
|
||||
var map = new GMap2(document.getElementById("' || g_map_id || '"));
|
||||
map.setUIToDefault();');
|
||||
|
||||
|
||||
for i in 1 .. g_point_list.count loop
|
||||
|
||||
l_str := string_util_pkg.get_str('var point = new GLatLng(%2, %3);
|
||||
bounds.extend(point);
|
||||
map.setCenter(point);
|
||||
map.setZoom(map.getBoundsZoomLevel(bounds)-1);
|
||||
var markerOption%1 = { title: "%4"};
|
||||
var marker%1 = new GMarker(point, markerOption%1);
|
||||
map.addOverlay(marker%1);', i, g_point_list(i).latitude, g_point_list(i).longitude, g_point_list(i).name);
|
||||
|
||||
htp.p(l_str);
|
||||
|
||||
if g_point_list(i).info is not null then
|
||||
--l_str := string_util_pkg.get_str('GEvent.addListener(marker%1, "click", function() { marker%1.openInfoWindowHtml("%2"); } );', i, replace(g_point_list(i).info, '"', ''''));
|
||||
--htp.p(l_str);
|
||||
owa_util_pkg.htp_printf('GEvent.addListener(marker%1, "click", function() { marker%1.openInfoWindowHtml("%2"); } );', i, replace(g_point_list(i).info, '"', ''''));
|
||||
end if;
|
||||
|
||||
end loop;
|
||||
|
||||
htp.p('
|
||||
}
|
||||
}
|
||||
//]]>
|
||||
</script>');
|
||||
|
||||
|
||||
end render_map_script;
|
||||
|
||||
|
||||
procedure render_map_placeholder (p_style in varchar2 := null,
|
||||
p_attributes in varchar2 := null)
|
||||
as
|
||||
l_str string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: render map placeholder
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 05.02.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
htp.p('<div id="' || g_map_id || '" style="' || nvl(p_style, 'width: 800px; height: 600px') || '" ' || p_attributes || '></div>');
|
||||
|
||||
end render_map_placeholder;
|
||||
|
||||
|
||||
end google_maps_js_pkg;
|
||||
/
|
||||
|
||||
|
||||
38
ora/google_maps_js_pkg.pks
Executable file
38
ora/google_maps_js_pkg.pks
Executable file
@ -0,0 +1,38 @@
|
||||
create or replace package google_maps_js_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles Google Maps integration with JavaScript
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 05.02.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
type t_map_options is record (
|
||||
map_control_enabled boolean,
|
||||
map_type_control_enabled boolean
|
||||
);
|
||||
|
||||
|
||||
-- initialize map
|
||||
procedure init_map (p_map_id in varchar2,
|
||||
p_options in t_map_options := null);
|
||||
|
||||
-- add point to map
|
||||
procedure add_point (p_point in google_maps_pkg.t_point);
|
||||
|
||||
-- render map script
|
||||
procedure render_map_script;
|
||||
|
||||
-- render map placeholder
|
||||
procedure render_map_placeholder (p_style in varchar2 := null,
|
||||
p_attributes in varchar2 := null);
|
||||
|
||||
end google_maps_js_pkg;
|
||||
/
|
||||
|
||||
265
ora/google_maps_pkg.pkb
Executable file
265
ora/google_maps_pkg.pkb
Executable file
@ -0,0 +1,265 @@
|
||||
create or replace package body google_maps_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles Google Maps integration
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 01.01.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
-- Google Maps API key
|
||||
g_api_key varchar2(255) := 'put_your_google_api_key_here';
|
||||
g_url_geocode constant varchar2(255) := 'http://maps.google.com/maps/geo';
|
||||
|
||||
g_nls_decimal_separator varchar2(1);
|
||||
|
||||
g_type_point constant number := 2001; -- From Oracle Spatial, the code for 2 dimensional point.
|
||||
g_sys_lat_long constant number := 8307; -- From Oracle Spatial, the code for the latitude, longitude coordinate system.
|
||||
|
||||
|
||||
procedure set_api_key (p_api_key in varchar2)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: set API key
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 05.02.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
g_api_key := p_api_key;
|
||||
|
||||
end set_api_key;
|
||||
|
||||
|
||||
function get_api_key return varchar2
|
||||
as
|
||||
l_returnvalue varchar2(255);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get API key
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 05.02.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := g_api_key;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_api_key;
|
||||
|
||||
|
||||
function get_nls_decimal_separator return varchar2
|
||||
as
|
||||
l_returnvalue varchar2(1);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Get decimal separator for session
|
||||
|
||||
Remarks: The value is cached to avoid looking it up dynamically each time this function is called
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 11.05.2007 Created
|
||||
|
||||
*/
|
||||
|
||||
if g_nls_decimal_separator is null then
|
||||
|
||||
begin
|
||||
select substr(value,1,1)
|
||||
into l_returnvalue
|
||||
from nls_session_parameters
|
||||
where parameter = 'NLS_NUMERIC_CHARACTERS';
|
||||
exception
|
||||
when no_data_found then
|
||||
l_returnvalue:='.';
|
||||
end;
|
||||
|
||||
g_nls_decimal_separator := l_returnvalue;
|
||||
|
||||
end if;
|
||||
|
||||
l_returnvalue := g_nls_decimal_separator;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_nls_decimal_separator;
|
||||
|
||||
|
||||
function get_geocode (p_address in varchar2) return sdo_geometry
|
||||
as
|
||||
l_url varchar2(4000);
|
||||
l_response varchar2(32000);
|
||||
l_lat_long varchar2(32000);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Get geocode from address
|
||||
|
||||
Remarks: see http://christopherbeck.wordpress.com/2008/08/05/quick-geocoding-using-google/
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 01.01.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
l_url := g_url_geocode || '?q=' || utl_url.escape (p_address) || '&output=csv&oe=utf8&key=' || g_api_key;
|
||||
|
||||
l_response := utl_http.request(l_url);
|
||||
|
||||
-- response in CSV format is on format: status, accuracy, latitude, longitude
|
||||
debug_pkg.printf (l_response);
|
||||
|
||||
-- a little hack to handle string to number conversion when running with European-style NLS settings (see nls_session_parameters)
|
||||
l_response := replace (l_response, ',', ';');
|
||||
if get_nls_decimal_separator = ',' then
|
||||
l_response := replace (l_response, '.', ',');
|
||||
end if;
|
||||
|
||||
l_lat_long := substr( l_response, instr( l_response, ';', 1, 2 ) + 1 );
|
||||
|
||||
-- for more on Spatial Data Types and Metadata,
|
||||
-- see http://download.oracle.com/docs/cd/B19306_01/appdev.102/b14255/sdo_objrelschema.htm#SPATL020
|
||||
|
||||
return sdo_geometry (
|
||||
g_type_point, g_sys_lat_long,
|
||||
sdo_point_type (to_number( substr( l_lat_long, instr( l_lat_long, ';' )+1 )),
|
||||
to_number( substr( l_lat_long, 1, instr( l_lat_long, ';' )-1 )),
|
||||
null),
|
||||
null, null);
|
||||
|
||||
end get_geocode;
|
||||
|
||||
|
||||
function get_point (p_geocode in sdo_geometry,
|
||||
p_name in varchar2 := null) return t_point
|
||||
as
|
||||
l_returnvalue t_point;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get point from geocode
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 05.02.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue.longitude := p_geocode.sdo_point.x;
|
||||
l_returnvalue.latitude := p_geocode.sdo_point.y;
|
||||
l_returnvalue.name := substr(p_name,1,255);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_point;
|
||||
|
||||
|
||||
function get_point (p_address in varchar2) return t_point
|
||||
as
|
||||
l_returnvalue t_point;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get point from address
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 05.02.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := get_point (get_geocode (p_address), p_address);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_point;
|
||||
|
||||
|
||||
function get_point (p_longitude in number,
|
||||
p_longitude_direction in varchar2,
|
||||
p_latitude in number,
|
||||
p_latitude_direction in varchar2,
|
||||
p_name in varchar2 := null) return t_point
|
||||
as
|
||||
l_returnvalue t_point;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get point from degree
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 05.02.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue.longitude := gis_util_pkg.get_ecliptic_degree (p_longitude, p_longitude_direction);
|
||||
l_returnvalue.latitude := gis_util_pkg.get_ecliptic_degree (p_latitude, p_latitude_direction);
|
||||
l_returnvalue.name := substr(p_name,1,255);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_point;
|
||||
|
||||
|
||||
procedure debug_geocode (p_address in varchar2)
|
||||
as
|
||||
l_geo sdo_geometry;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get geocode and print it
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 01.01.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
l_geo := get_geocode (p_address);
|
||||
|
||||
debug_pkg.printf ('x = %1, y = %2', l_geo.sdo_point.x, l_geo.sdo_point.y);
|
||||
|
||||
end debug_geocode;
|
||||
|
||||
|
||||
end google_maps_pkg;
|
||||
/
|
||||
|
||||
58
ora/google_maps_pkg.pks
Executable file
58
ora/google_maps_pkg.pks
Executable file
@ -0,0 +1,58 @@
|
||||
create or replace package google_maps_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles Google Maps integration
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 01.01.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
g_map_type_normal constant varchar2(30) := 'G_NORMAL_MAP';
|
||||
g_map_type_satellite constant varchar2(30) := 'G_SATELLITE_MAP';
|
||||
g_map_type_hybrid constant varchar2(30) := 'G_HYBRID_MAP';
|
||||
g_map_type_physical constant varchar2(30) := 'G_PHYSICAL_MAP';
|
||||
|
||||
type t_point is record (
|
||||
longitude number,
|
||||
latitude number,
|
||||
name varchar2(255),
|
||||
info varchar2(2000)
|
||||
);
|
||||
|
||||
type t_point_list is table of t_point index by binary_integer;
|
||||
|
||||
-- set API key
|
||||
procedure set_api_key (p_api_key in varchar2);
|
||||
|
||||
-- get API key
|
||||
function get_api_key return varchar2;
|
||||
|
||||
-- get geocode from address
|
||||
function get_geocode (p_address in varchar2) return sdo_geometry;
|
||||
|
||||
-- get point from geocode
|
||||
function get_point (p_geocode in sdo_geometry,
|
||||
p_name in varchar2 := null) return t_point;
|
||||
|
||||
-- get point from address
|
||||
function get_point (p_address in varchar2) return t_point;
|
||||
|
||||
-- get point from degree
|
||||
function get_point (p_longitude in number,
|
||||
p_longitude_direction in varchar2,
|
||||
p_latitude in number,
|
||||
p_latitude_direction in varchar2,
|
||||
p_name in varchar2 := null) return t_point;
|
||||
|
||||
-- get geocode and print it
|
||||
procedure debug_geocode (p_address in varchar2);
|
||||
|
||||
end google_maps_pkg;
|
||||
/
|
||||
|
||||
291
ora/google_translate_pkg.pkb
Executable file
291
ora/google_translate_pkg.pkb
Executable file
@ -0,0 +1,291 @@
|
||||
create or replace package body google_translate_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: PL/SQL wrapper package for Google Translate API
|
||||
|
||||
Remarks: see http://code.google.com/apis/ajaxlanguage/documentation/
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 25.12.2009 Created
|
||||
|
||||
*/
|
||||
|
||||
m_http_referrer constant varchar2(255) := 'your-domain-name-or-website-here'; -- insert your domain/website here (required by Google's terms of use)
|
||||
m_api_key constant varchar2(255) := null; -- insert your Google API Key here (optional but recommended)
|
||||
|
||||
m_service_url constant varchar2(255) := 'http://ajax.googleapis.com/ajax/services/language/';
|
||||
m_service_version constant varchar2(10) := '1.0';
|
||||
|
||||
m_max_text_size constant pls_integer := 500; -- can be increased up towards 32k, the cache name size (below) must be increased accordingly
|
||||
|
||||
type t_translation_cache is table of varchar2(32000) index by varchar2(550);
|
||||
|
||||
m_translation_cache t_translation_cache;
|
||||
m_cache_id_separator constant varchar2(1) := '|';
|
||||
|
||||
|
||||
procedure add_to_cache (p_from_text in varchar2,
|
||||
p_from_lang in varchar2,
|
||||
p_to_text in varchar2,
|
||||
p_to_lang in varchar2)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: add translation to cache
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 25.12.2009 Created
|
||||
|
||||
*/
|
||||
|
||||
m_translation_cache (p_from_lang || m_cache_id_separator || p_to_lang || m_cache_id_separator || replace(substr(p_from_text,1,m_max_text_size), m_cache_id_separator, '')) := p_to_text;
|
||||
|
||||
end add_to_cache;
|
||||
|
||||
|
||||
function get_from_cache (p_text in varchar2,
|
||||
p_from_lang in varchar2,
|
||||
p_to_lang in varchar2) return varchar2
|
||||
as
|
||||
l_returnvalue varchar2(32000);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get translation from cache
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 25.12.2009 Created
|
||||
|
||||
*/
|
||||
|
||||
begin
|
||||
l_returnvalue := m_translation_cache (p_from_lang || m_cache_id_separator || p_to_lang || m_cache_id_separator || replace(substr(p_text,1,m_max_text_size), m_cache_id_separator, ''));
|
||||
exception
|
||||
when no_data_found then
|
||||
l_returnvalue := null;
|
||||
end;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_from_cache;
|
||||
|
||||
|
||||
function get_clob_from_http_post (p_url in varchar2,
|
||||
p_values in varchar2) return clob
|
||||
as
|
||||
l_request utl_http.req;
|
||||
l_response utl_http.resp;
|
||||
l_buffer varchar2(32767);
|
||||
l_returnvalue clob := ' ';
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: do a HTTP POST and get results back in a CLOB
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 25.12.2009 Created
|
||||
|
||||
*/
|
||||
|
||||
l_request := utl_http.begin_request (p_url, 'POST', utl_http.http_version_1_1);
|
||||
|
||||
utl_http.set_header (l_request, 'Referer', m_http_referrer); -- note that the actual header name is misspelled in the HTTP protocol
|
||||
utl_http.set_header (l_request, 'Content-Type', 'application/x-www-form-urlencoded');
|
||||
utl_http.set_header (l_request, 'Content-Length', to_char(length(p_values)));
|
||||
utl_http.write_text (l_request, p_values);
|
||||
|
||||
l_response := utl_http.get_response (l_request);
|
||||
|
||||
if l_response.status_code = utl_http.http_ok then
|
||||
|
||||
begin
|
||||
loop
|
||||
utl_http.read_text (l_response, l_buffer);
|
||||
dbms_lob.writeappend (l_returnvalue, length(l_buffer), l_buffer);
|
||||
end loop;
|
||||
exception
|
||||
when utl_http.end_of_body then
|
||||
null;
|
||||
end;
|
||||
|
||||
end if;
|
||||
|
||||
utl_http.end_response (l_response);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_clob_from_http_post;
|
||||
|
||||
|
||||
function translate_text (p_text in varchar2,
|
||||
p_to_lang in varchar2,
|
||||
p_from_lang in varchar2 := null,
|
||||
p_use_cache in varchar2 := 'YES') return varchar2
|
||||
as
|
||||
l_values varchar2(2000);
|
||||
l_response clob;
|
||||
l_start_pos pls_integer;
|
||||
l_end_pos pls_integer;
|
||||
l_returnvalue varchar2(32000) := null;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: translate a piece of text
|
||||
|
||||
Remarks: if the "from" language is left blank, Google Translate will attempt to autodetect the language
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 25.12.2009 Created
|
||||
MBR 25.12.2009 Added cache for translations
|
||||
|
||||
*/
|
||||
|
||||
if trim(p_text) is not null then
|
||||
|
||||
if p_use_cache = 'YES' then
|
||||
l_returnvalue := get_from_cache (p_text, p_from_lang, p_to_lang);
|
||||
end if;
|
||||
|
||||
if l_returnvalue is null then
|
||||
|
||||
l_values := 'v=' || m_service_version || '&q=' || utl_url.escape (substr(p_text,1,m_max_text_size), false, 'UTF8') || '&langpair=' || p_from_lang || '|' || p_to_lang;
|
||||
|
||||
if m_api_key is not null then
|
||||
l_values := l_values || '&key=' || m_api_key;
|
||||
end if;
|
||||
|
||||
l_response := get_clob_from_http_post (m_service_url || 'translate', l_values);
|
||||
|
||||
if l_response is not null then
|
||||
|
||||
l_start_pos := instr(l_response, '{"translatedText":"');
|
||||
l_start_pos := l_start_pos + 19;
|
||||
l_end_pos := instr(l_response, '"', l_start_pos);
|
||||
|
||||
l_returnvalue := substr(l_response, l_start_pos, l_end_pos - l_start_pos);
|
||||
|
||||
if (p_use_cache = 'YES') and (l_returnvalue is not null) then
|
||||
add_to_cache (p_text, p_from_lang, l_returnvalue, p_to_lang);
|
||||
end if;
|
||||
|
||||
end if;
|
||||
|
||||
end if;
|
||||
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end translate_text;
|
||||
|
||||
|
||||
function detect_lang (p_text in varchar2) return varchar2
|
||||
as
|
||||
l_url varchar2(2000);
|
||||
l_response clob;
|
||||
l_start_pos pls_integer;
|
||||
l_end_pos pls_integer;
|
||||
l_returnvalue varchar2(255);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: detect language code for text
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 25.12.2009 Created
|
||||
|
||||
*/
|
||||
|
||||
if trim(p_text) is not null then
|
||||
|
||||
l_url := m_service_url || 'detect?v=' || m_service_version || '&q=' || utl_url.escape (substr(p_text,1,m_max_text_size), false, 'UTF8');
|
||||
|
||||
if m_api_key is not null then
|
||||
l_url := l_url || '&key=' || m_api_key;
|
||||
end if;
|
||||
|
||||
l_response := httpuritype(l_url).getclob();
|
||||
|
||||
l_start_pos := instr(l_response, '{"language":"');
|
||||
l_start_pos := l_start_pos + 13;
|
||||
l_end_pos := instr(l_response, '",', l_start_pos);
|
||||
|
||||
l_returnvalue := substr(l_response, l_start_pos, l_end_pos - l_start_pos);
|
||||
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end detect_lang;
|
||||
|
||||
|
||||
function get_translation_cache_count return number
|
||||
as
|
||||
l_returnvalue number;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get number of texts in cache
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 25.12.2009 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := m_translation_cache.count;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_translation_cache_count;
|
||||
|
||||
|
||||
procedure clear_translation_cache
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: clear translation cache
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 25.12.2009 Created
|
||||
|
||||
*/
|
||||
|
||||
m_translation_cache.delete;
|
||||
|
||||
end clear_translation_cache;
|
||||
|
||||
|
||||
end google_translate_pkg;
|
||||
/
|
||||
|
||||
128
ora/google_translate_pkg.pks
Executable file
128
ora/google_translate_pkg.pks
Executable file
@ -0,0 +1,128 @@
|
||||
create or replace package google_translate_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: PL/SQL wrapper package for Google Translate API
|
||||
|
||||
Remarks: see http://code.google.com/apis/ajaxlanguage/documentation/
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 25.12.2009 Created
|
||||
|
||||
*/
|
||||
|
||||
-- http://code.google.com/apis/ajaxlanguage/documentation/reference.html#LangNameArray
|
||||
g_lang_AFRIKAANS constant varchar2(5) := 'af';
|
||||
g_lang_ALBANIAN constant varchar2(5) := 'sq';
|
||||
g_lang_AMHARIC constant varchar2(5) := 'am';
|
||||
g_lang_ARABIC constant varchar2(5) := 'ar';
|
||||
g_lang_ARMENIAN constant varchar2(5) := 'hy';
|
||||
g_lang_AZERBAIJANI constant varchar2(5) := 'az';
|
||||
g_lang_BASQUE constant varchar2(5) := 'eu';
|
||||
g_lang_BELARUSIAN constant varchar2(5) := 'be';
|
||||
g_lang_BENGALI constant varchar2(5) := 'bn';
|
||||
g_lang_BIHARI constant varchar2(5) := 'bh';
|
||||
g_lang_BULGARIAN constant varchar2(5) := 'bg';
|
||||
g_lang_BURMESE constant varchar2(5) := 'my';
|
||||
g_lang_CATALAN constant varchar2(5) := 'ca';
|
||||
g_lang_CHEROKEE constant varchar2(5) := 'chr';
|
||||
g_lang_CHINESE constant varchar2(5) := 'zh';
|
||||
g_lang_CHINESE_SIMPLIFIED constant varchar2(5) := 'zh-CN';
|
||||
g_lang_CHINESE_TRADITIONAL constant varchar2(5) := 'zh-TW';
|
||||
g_lang_CROATIAN constant varchar2(5) := 'hr';
|
||||
g_lang_CZECH constant varchar2(5) := 'cs';
|
||||
g_lang_DANISH constant varchar2(5) := 'da';
|
||||
g_lang_DHIVEHI constant varchar2(5) := 'dv';
|
||||
g_lang_DUTCH constant varchar2(5) := 'nl';
|
||||
g_lang_ENGLISH constant varchar2(5) := 'en';
|
||||
g_lang_ESPERANTO constant varchar2(5) := 'eo';
|
||||
g_lang_ESTONIAN constant varchar2(5) := 'et';
|
||||
g_lang_FILIPINO constant varchar2(5) := 'tl';
|
||||
g_lang_FINNISH constant varchar2(5) := 'fi';
|
||||
g_lang_FRENCH constant varchar2(5) := 'fr';
|
||||
g_lang_GALICIAN constant varchar2(5) := 'gl';
|
||||
g_lang_GEORGIAN constant varchar2(5) := 'ka';
|
||||
g_lang_GERMAN constant varchar2(5) := 'de';
|
||||
g_lang_GREEK constant varchar2(5) := 'el';
|
||||
g_lang_GUARANI constant varchar2(5) := 'gn';
|
||||
g_lang_GUJARATI constant varchar2(5) := 'gu';
|
||||
g_lang_HEBREW constant varchar2(5) := 'iw';
|
||||
g_lang_HINDI constant varchar2(5) := 'hi';
|
||||
g_lang_HUNGARIAN constant varchar2(5) := 'hu';
|
||||
g_lang_ICELANDIC constant varchar2(5) := 'is';
|
||||
g_lang_INDONESIAN constant varchar2(5) := 'id';
|
||||
g_lang_INUKTITUT constant varchar2(5) := 'iu';
|
||||
g_lang_IRISH constant varchar2(5) := 'ga';
|
||||
g_lang_ITALIAN constant varchar2(5) := 'it';
|
||||
g_lang_JAPANESE constant varchar2(5) := 'ja';
|
||||
g_lang_KANNADA constant varchar2(5) := 'kn';
|
||||
g_lang_KAZAKH constant varchar2(5) := 'kk';
|
||||
g_lang_KHMER constant varchar2(5) := 'km';
|
||||
g_lang_KOREAN constant varchar2(5) := 'ko';
|
||||
g_lang_KURDISH constant varchar2(5) := 'ku';
|
||||
g_lang_KYRGYZ constant varchar2(5) := 'ky';
|
||||
g_lang_LAOTHIAN constant varchar2(5) := 'lo';
|
||||
g_lang_LATVIAN constant varchar2(5) := 'lv';
|
||||
g_lang_LITHUANIAN constant varchar2(5) := 'lt';
|
||||
g_lang_MACEDONIAN constant varchar2(5) := 'mk';
|
||||
g_lang_MALAY constant varchar2(5) := 'ms';
|
||||
g_lang_MALAYALAM constant varchar2(5) := 'ml';
|
||||
g_lang_MALTESE constant varchar2(5) := 'mt';
|
||||
g_lang_MARATHI constant varchar2(5) := 'mr';
|
||||
g_lang_MONGOLIAN constant varchar2(5) := 'mn';
|
||||
g_lang_NEPALI constant varchar2(5) := 'ne';
|
||||
g_lang_NORWEGIAN constant varchar2(5) := 'no';
|
||||
g_lang_ORIYA constant varchar2(5) := 'or';
|
||||
g_lang_PASHTO constant varchar2(5) := 'ps';
|
||||
g_lang_PERSIAN constant varchar2(5) := 'fa';
|
||||
g_lang_POLISH constant varchar2(5) := 'pl';
|
||||
g_lang_PORTUGUESE constant varchar2(5) := 'pt-PT';
|
||||
g_lang_PUNJABI constant varchar2(5) := 'pa';
|
||||
g_lang_ROMANIAN constant varchar2(5) := 'ro';
|
||||
g_lang_RUSSIAN constant varchar2(5) := 'ru';
|
||||
g_lang_SANSKRIT constant varchar2(5) := 'sa';
|
||||
g_lang_SERBIAN constant varchar2(5) := 'sr';
|
||||
g_lang_SINDHI constant varchar2(5) := 'sd';
|
||||
g_lang_SINHALESE constant varchar2(5) := 'si';
|
||||
g_lang_SLOVAK constant varchar2(5) := 'sk';
|
||||
g_lang_SLOVENIAN constant varchar2(5) := 'sl';
|
||||
g_lang_SPANISH constant varchar2(5) := 'es';
|
||||
g_lang_SWAHILI constant varchar2(5) := 'sw';
|
||||
g_lang_SWEDISH constant varchar2(5) := 'sv';
|
||||
g_lang_TAJIK constant varchar2(5) := 'tg';
|
||||
g_lang_TAMIL constant varchar2(5) := 'ta';
|
||||
g_lang_TAGALOG constant varchar2(5) := 'tl';
|
||||
g_lang_TELUGU constant varchar2(5) := 'te';
|
||||
g_lang_THAI constant varchar2(5) := 'th';
|
||||
g_lang_TIBETAN constant varchar2(5) := 'bo';
|
||||
g_lang_TURKISH constant varchar2(5) := 'tr';
|
||||
g_lang_UKRAINIAN constant varchar2(5) := 'uk';
|
||||
g_lang_URDU constant varchar2(5) := 'ur';
|
||||
g_lang_UZBEK constant varchar2(5) := 'uz';
|
||||
g_lang_UIGHUR constant varchar2(5) := 'ug';
|
||||
g_lang_VIETNAMESE constant varchar2(5) := 'vi';
|
||||
g_lang_WELSH constant varchar2(5) := 'cy';
|
||||
g_lang_YIDDISH constant varchar2(5) := 'yi';
|
||||
g_lang_UNKNOWN constant varchar2(5) := '';
|
||||
|
||||
|
||||
-- translate a piece of text
|
||||
function translate_text (p_text in varchar2,
|
||||
p_to_lang in varchar2,
|
||||
p_from_lang in varchar2 := null,
|
||||
p_use_cache in varchar2 := 'YES') return varchar2;
|
||||
|
||||
-- detect language code for text
|
||||
function detect_lang (p_text in varchar2) return varchar2;
|
||||
|
||||
-- get number of texts in cache
|
||||
function get_translation_cache_count return number;
|
||||
|
||||
-- clear translation cache
|
||||
procedure clear_translation_cache;
|
||||
|
||||
end google_translate_pkg;
|
||||
/
|
||||
|
||||
92
ora/html_util_pkg.pkb
Executable file
92
ora/html_util_pkg.pkb
Executable file
@ -0,0 +1,92 @@
|
||||
CREATE OR REPLACE package body html_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package contains HTML utilities
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 03.12.2009 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
function get_html_with_line_breaks (p_html in varchar2) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: replace normal line breaks with html line breaks
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 10.01.2009 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := replace(p_html, chr(10), '<br>');
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_html_with_line_breaks;
|
||||
|
||||
|
||||
function add_hyperlinks (p_text in varchar2,
|
||||
p_class in varchar2 := null) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: make URLs in text into hyperlinks
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := regexp_replace(p_text, 'http://([[:alnum:]|.]+)', '<a href="http://\1" class="' || p_class || '">\1</a>');
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end add_hyperlinks;
|
||||
|
||||
|
||||
function add_hyperlinks (p_text in clob,
|
||||
p_class in varchar2 := null) return clob
|
||||
as
|
||||
l_returnvalue clob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: make URLs in text into hyperlinks
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := regexp_replace(p_text, 'http://([[:alnum:]|.]+)', '<a href="http://\1" class="' || p_class || '">\1</a>');
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end add_hyperlinks;
|
||||
|
||||
|
||||
end html_util_pkg;
|
||||
/
|
||||
28
ora/html_util_pkg.pks
Executable file
28
ora/html_util_pkg.pks
Executable file
@ -0,0 +1,28 @@
|
||||
CREATE OR REPLACE package html_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package contains HTML utilities
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 03.12.2009 Created
|
||||
|
||||
*/
|
||||
|
||||
-- replace normal line breaks with html line breaks
|
||||
function get_html_with_line_breaks (p_html in varchar2) return varchar2;
|
||||
|
||||
-- make URLs in text into hyperlinks
|
||||
function add_hyperlinks (p_text in varchar2,
|
||||
p_class in varchar2 := null) return varchar2;
|
||||
|
||||
-- make URLs in text into hyperlinks
|
||||
function add_hyperlinks (p_text in clob,
|
||||
p_class in varchar2 := null) return clob;
|
||||
|
||||
end html_util_pkg;
|
||||
/
|
||||
114
ora/http_util_pkg.pkb
Executable file
114
ora/http_util_pkg.pkb
Executable file
@ -0,0 +1,114 @@
|
||||
create or replace package body http_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package contains HTTP utilities
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 01.01.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
function get_clob_from_url (p_url in varchar2) return clob
|
||||
as
|
||||
l_http_request utl_http.req;
|
||||
l_http_response utl_http.resp;
|
||||
l_text varchar2(32767);
|
||||
l_returnvalue clob;
|
||||
|
||||
begin
|
||||
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get clob from URL
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 01.01.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
dbms_lob.createtemporary(l_returnvalue, false);
|
||||
|
||||
l_http_request := utl_http.begin_request (p_url);
|
||||
l_http_response := utl_http.get_response (l_http_request);
|
||||
|
||||
begin
|
||||
loop
|
||||
utl_http.read_text (l_http_response, l_text, 32767);
|
||||
dbms_lob.writeappend (l_returnvalue, length(l_text), l_text);
|
||||
end loop;
|
||||
exception
|
||||
when utl_http.end_of_body then
|
||||
utl_http.end_response (l_http_response);
|
||||
end;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
exception
|
||||
when others then
|
||||
utl_http.end_response (l_http_response);
|
||||
dbms_lob.freetemporary(l_returnvalue);
|
||||
raise;
|
||||
|
||||
end get_clob_from_url;
|
||||
|
||||
|
||||
function get_blob_from_url (p_url in varchar2) return blob
|
||||
as
|
||||
l_http_request utl_http.req;
|
||||
l_http_response utl_http.resp;
|
||||
l_raw raw(32767);
|
||||
l_returnvalue blob;
|
||||
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Get blob from URL
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 01.01.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
dbms_lob.createtemporary (l_returnvalue, false);
|
||||
|
||||
l_http_request := utl_http.begin_request (p_url);
|
||||
l_http_response := utl_http.get_response (l_http_request);
|
||||
|
||||
begin
|
||||
loop
|
||||
utl_http.read_raw(l_http_response, l_raw, 32767);
|
||||
dbms_lob.writeappend (l_returnvalue, utl_raw.length(l_raw), l_raw);
|
||||
end loop;
|
||||
exception
|
||||
when utl_http.end_of_body then
|
||||
utl_http.end_response(l_http_response);
|
||||
end;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
exception
|
||||
when others then
|
||||
utl_http.end_response (l_http_response);
|
||||
dbms_lob.freetemporary (l_returnvalue);
|
||||
raise;
|
||||
|
||||
end get_blob_from_url;
|
||||
|
||||
|
||||
end http_util_pkg;
|
||||
/
|
||||
|
||||
24
ora/http_util_pkg.pks
Executable file
24
ora/http_util_pkg.pks
Executable file
@ -0,0 +1,24 @@
|
||||
create or replace package http_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package contains HTTP utilities
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 01.01.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
-- get clob from URL
|
||||
function get_clob_from_url (p_url in varchar2) return clob;
|
||||
|
||||
-- get blob from URL
|
||||
function get_blob_from_url (p_url in varchar2) return blob;
|
||||
|
||||
end http_util_pkg;
|
||||
/
|
||||
|
||||
232
ora/icalendar_util_pkg.pkb
Executable file
232
ora/icalendar_util_pkg.pkb
Executable file
@ -0,0 +1,232 @@
|
||||
create or replace package body icalendar_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles the iCalendar protocol (RFC 5545)
|
||||
|
||||
Remarks: see http://en.wikipedia.org/wiki/ICalendar and http://tools.ietf.org/html/rfc5545
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 26.10.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
m_protocol_version constant varchar2(3) := '2.0';
|
||||
m_date_format constant varchar2(30) := 'YYYYMMDD"T"HH24MISS';
|
||||
m_line_delimiter constant varchar2(2) := chr(13) || chr(10);
|
||||
|
||||
|
||||
function fmt_date (p_date in date) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_db_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: format date
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 26.10.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := to_char(p_date, m_date_format);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end fmt_date;
|
||||
|
||||
|
||||
function fmt_organizer (p_organizer_name in varchar2,
|
||||
p_organizer_email in varchar2) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_db_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: format date
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 26.10.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := 'CN="' || p_organizer_name || '":MAILTO:' || p_organizer_email;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end fmt_organizer;
|
||||
|
||||
|
||||
function fmt_text (p_text in varchar2) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_db_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: format text
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 26.10.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
-- TODO: "Actual line feeds in data items are encoded as a backslash followed by the letter N (the bytes 5C 6E or 5C 4E in UTF-8). "
|
||||
|
||||
l_returnvalue := p_text;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end fmt_text;
|
||||
|
||||
|
||||
function add_core_object (p_ical_body in varchar2,
|
||||
p_prod_id in varchar2 := null) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: wrap core object around iCalendar body
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 26.10.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := 'BEGIN:VCALENDAR' || m_line_delimiter ||
|
||||
'VERSION:' || m_protocol_version || m_line_delimiter ||
|
||||
'PRODID:' || nvl(p_prod_id, '-//My Company//NONSGML My Product//EN') || m_line_delimiter ||
|
||||
p_ical_body || m_line_delimiter ||
|
||||
'END:VCALENDAR';
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end add_core_object;
|
||||
|
||||
|
||||
function get_event (p_event in t_event) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get event
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 26.10.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := 'BEGIN:VEVENT' || m_line_delimiter ||
|
||||
'SUMMARY:' || fmt_text(p_event.summary) || m_line_delimiter ||
|
||||
'DESCRIPTION:' || fmt_text(p_event.description) || m_line_delimiter ||
|
||||
'LOCATION:' || fmt_text(p_event.location) || m_line_delimiter ||
|
||||
'ORGANIZER;' || fmt_organizer (p_event.organizer_name, p_event.organizer_email) || m_line_delimiter ||
|
||||
'DTSTART:' || fmt_date(p_event.start_date) || m_line_delimiter ||
|
||||
'DTEND:' || fmt_date(nvl(p_event.end_date, p_event.start_date)) || m_line_delimiter ||
|
||||
'DTSTAMP:' || fmt_date(sysdate) || m_line_delimiter ||
|
||||
'UID:' || nvl(p_event.uid, rawtohex(sys_guid()) || '@domain.example') || m_line_delimiter ||
|
||||
'STATUS:NEEDS-ACTION' || m_line_delimiter ||
|
||||
'END:VEVENT';
|
||||
|
||||
l_returnvalue := add_core_object (l_returnvalue);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_event;
|
||||
|
||||
|
||||
procedure download_event (p_event in t_event)
|
||||
as
|
||||
l_event_str string_util_pkg.t_max_pl_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: download event
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 26.10.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
l_event_str := get_event (p_event);
|
||||
|
||||
owa_util.mime_header('text/calendar', false);
|
||||
htp.p('Content-length: ' || length(l_event_str));
|
||||
htp.p('Content-Disposition: attachment; filename="' || file_util_pkg.get_filename_str(p_event.summary, 'ics') || '"');
|
||||
owa_util.http_header_close;
|
||||
|
||||
htp.prn (l_event_str);
|
||||
|
||||
end download_event;
|
||||
|
||||
|
||||
function create_event (p_start_date in date,
|
||||
p_end_date in date,
|
||||
p_summary in varchar2,
|
||||
p_description in varchar2 := null,
|
||||
p_location in varchar2 := null,
|
||||
p_organizer_name in varchar2 := null,
|
||||
p_organizer_email in varchar2 := null,
|
||||
p_uid in varchar2 := null) return t_event
|
||||
as
|
||||
l_returnvalue t_event;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: create event
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 26.10.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue.start_date := p_start_date;
|
||||
l_returnvalue.end_date := p_end_date;
|
||||
l_returnvalue.summary := p_summary;
|
||||
l_returnvalue.description := p_description;
|
||||
l_returnvalue.location := p_location;
|
||||
l_returnvalue.organizer_name := p_organizer_name;
|
||||
l_returnvalue.organizer_email := p_organizer_email;
|
||||
l_returnvalue.uid := p_uid;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end create_event;
|
||||
|
||||
|
||||
end icalendar_util_pkg;
|
||||
/
|
||||
|
||||
|
||||
|
||||
46
ora/icalendar_util_pkg.pks
Executable file
46
ora/icalendar_util_pkg.pks
Executable file
@ -0,0 +1,46 @@
|
||||
create or replace package icalendar_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles the iCalendar protocol (RFC 5545)
|
||||
|
||||
Remarks: see http://en.wikipedia.org/wiki/ICalendar and http://tools.ietf.org/html/rfc5545
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 26.10.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
type t_event is record (
|
||||
start_date date,
|
||||
end_date date,
|
||||
summary varchar2(2000),
|
||||
description varchar2(2000),
|
||||
location varchar2(2000),
|
||||
organizer_name varchar2(2000),
|
||||
organizer_email varchar2(2000),
|
||||
uid varchar2(2000)
|
||||
);
|
||||
|
||||
|
||||
-- get event
|
||||
function get_event (p_event in t_event) return varchar2;
|
||||
|
||||
-- download event
|
||||
procedure download_event (p_event in t_event);
|
||||
|
||||
-- create event
|
||||
function create_event (p_start_date in date,
|
||||
p_end_date in date,
|
||||
p_summary in varchar2,
|
||||
p_description in varchar2 := null,
|
||||
p_location in varchar2 := null,
|
||||
p_organizer_name in varchar2 := null,
|
||||
p_organizer_email in varchar2 := null,
|
||||
p_uid in varchar2 := null) return t_event;
|
||||
|
||||
end icalendar_util_pkg;
|
||||
/
|
||||
|
||||
577
ora/image_util_pkg.pkb
Executable file
577
ora/image_util_pkg.pkb
Executable file
@ -0,0 +1,577 @@
|
||||
create or replace package body image_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles images
|
||||
|
||||
Remarks: Based on image parsing code from Anton Scheffer's AS_PDF3 package
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.06.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
type tp_pls_tab is table of pls_integer index by pls_integer;
|
||||
|
||||
|
||||
function blob2num (p_blob blob,
|
||||
p_len integer,
|
||||
p_pos integer) return number
|
||||
is
|
||||
begin
|
||||
return to_number( rawtohex( dbms_lob.substr( p_blob, p_len, p_pos ) ), 'xxxxxxxx' );
|
||||
end blob2num;
|
||||
|
||||
|
||||
function raw2num (p_value raw) return number
|
||||
is
|
||||
begin
|
||||
return to_number( rawtohex( p_value ), 'XXXXXXXX' );
|
||||
end raw2num;
|
||||
|
||||
|
||||
function raw2num (p_value raw,
|
||||
p_pos pls_integer,
|
||||
p_len pls_integer) return pls_integer
|
||||
is
|
||||
begin
|
||||
return to_number( rawtohex( utl_raw.substr( p_value, p_pos, p_len ) ), 'XXXXXXXX' );
|
||||
end raw2num;
|
||||
|
||||
|
||||
function adler32 (p_src in blob) return varchar2
|
||||
is
|
||||
s1 pls_integer := 1;
|
||||
s2 pls_integer := 0;
|
||||
n pls_integer;
|
||||
step_size number;
|
||||
tmp varchar2(32766);
|
||||
c65521 constant pls_integer := 65521;
|
||||
begin
|
||||
|
||||
step_size := trunc( 16383 / dbms_lob.getchunksize( p_src ) ) * dbms_lob.getchunksize( p_src );
|
||||
for j in 0 .. trunc( ( dbms_lob.getlength( p_src ) - 1 ) / step_size )
|
||||
loop
|
||||
tmp := rawtohex( dbms_lob.substr( p_src, step_size, j * step_size + 1 ) );
|
||||
for i in 1 .. length( tmp ) / 2
|
||||
loop
|
||||
n := to_number( substr( tmp, i * 2 - 1, 2 ), 'xx' );
|
||||
s1 := s1 + n;
|
||||
if s1 >= c65521
|
||||
then
|
||||
s1 := s1 - c65521;
|
||||
end if;
|
||||
s2 := s2 + s1;
|
||||
if s2 >= c65521
|
||||
then
|
||||
s2 := s2 - c65521;
|
||||
end if;
|
||||
end loop;
|
||||
end loop;
|
||||
return to_char( s2, 'fm0XXX' ) || to_char( s1, 'fm0XXX' );
|
||||
|
||||
end adler32;
|
||||
|
||||
|
||||
function parse_jpg (p_img_blob blob) return t_image_info
|
||||
is
|
||||
buf raw(4);
|
||||
t_img t_image_info;
|
||||
t_ind integer;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Parse JPG
|
||||
|
||||
Remarks: From Anton Scheffer's AS_PDF3 package
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.06.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
if ( dbms_lob.substr( p_img_blob, 2, 1 ) != hextoraw( 'FFD8' ) -- SOI Start of Image
|
||||
or dbms_lob.substr( p_img_blob, 2, dbms_lob.getlength( p_img_blob ) - 1 ) != hextoraw( 'FFD9' ) -- EOI End of Image
|
||||
)
|
||||
then -- this is not a jpg I can handle
|
||||
return null;
|
||||
end if;
|
||||
--
|
||||
t_img.pixels := p_img_blob;
|
||||
t_img.type := 'jpg';
|
||||
if dbms_lob.substr( t_img.pixels, 2, 3 ) in ( hextoraw( 'FFE0' ) -- a APP0 jpg
|
||||
, hextoraw( 'FFE1' ) -- a APP1 jpg
|
||||
)
|
||||
then
|
||||
t_img.color_res := 8;
|
||||
t_img.height := 1;
|
||||
t_img.width := 1;
|
||||
--
|
||||
t_ind := 3;
|
||||
t_ind := t_ind + 2 + blob2num( t_img.pixels, 2, t_ind + 2 );
|
||||
loop
|
||||
buf := dbms_lob.substr( t_img.pixels, 2, t_ind );
|
||||
exit when buf = hextoraw( 'FFDA' ); -- SOS Start of Scan
|
||||
exit when buf = hextoraw( 'FFD9' ); -- EOI End Of Image
|
||||
exit when substr( rawtohex( buf ), 1, 2 ) != 'FF';
|
||||
if rawtohex( buf ) in ( 'FFD0' -- RSTn
|
||||
, 'FFD1', 'FFD2', 'FFD3', 'FFD4', 'FFD5', 'FFD6', 'FFD7', 'FF01' -- TEM
|
||||
)
|
||||
then
|
||||
t_ind := t_ind + 2;
|
||||
else
|
||||
if buf = hextoraw( 'FFC0' ) -- SOF0 (Start Of Frame 0) marker
|
||||
then
|
||||
t_img.color_res := blob2num( t_img.pixels, 1, t_ind + 4 );
|
||||
t_img.height := blob2num( t_img.pixels, 2, t_ind + 5 );
|
||||
t_img.width := blob2num( t_img.pixels, 2, t_ind + 7 );
|
||||
end if;
|
||||
t_ind := t_ind + 2 + blob2num( t_img.pixels, 2, t_ind + 2 );
|
||||
end if;
|
||||
end loop;
|
||||
end if;
|
||||
--
|
||||
return t_img;
|
||||
|
||||
end parse_jpg;
|
||||
|
||||
|
||||
function parse_png (p_img_blob blob) return t_image_info
|
||||
is
|
||||
t_img t_image_info;
|
||||
buf raw(32767);
|
||||
len integer;
|
||||
ind integer;
|
||||
color_type pls_integer;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Parse PNG
|
||||
|
||||
Remarks: From Anton Scheffer's AS_PDF3 package
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.06.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
if rawtohex( dbms_lob.substr( p_img_blob, 8, 1 ) ) != '89504E470D0A1A0A' -- not the right signature
|
||||
then
|
||||
return null;
|
||||
end if;
|
||||
dbms_lob.createtemporary( t_img.pixels, true );
|
||||
ind := 9;
|
||||
loop
|
||||
len := blob2num( p_img_blob, 4, ind ); -- length
|
||||
exit when len is null or ind > dbms_lob.getlength( p_img_blob );
|
||||
case utl_raw.cast_to_varchar2( dbms_lob.substr( p_img_blob, 4, ind + 4 ) ) -- Chunk type
|
||||
when 'IHDR'
|
||||
then
|
||||
t_img.width := blob2num( p_img_blob, 4, ind + 8 );
|
||||
t_img.height := blob2num( p_img_blob, 4, ind + 12 );
|
||||
t_img.color_res := blob2num( p_img_blob, 1, ind + 16 );
|
||||
color_type := blob2num( p_img_blob, 1, ind + 17 );
|
||||
t_img.greyscale := color_type in ( 0, 4 );
|
||||
when 'PLTE'
|
||||
then
|
||||
t_img.color_tab := dbms_lob.substr( p_img_blob, len, ind + 8 );
|
||||
when 'IDAT'
|
||||
then
|
||||
dbms_lob.copy( t_img.pixels, p_img_blob, len, dbms_lob.getlength( t_img.pixels ) + 1, ind + 8 );
|
||||
when 'IEND'
|
||||
then
|
||||
exit;
|
||||
else
|
||||
null;
|
||||
end case;
|
||||
ind := ind + 4 + 4 + len + 4; -- Length + Chunk type + Chunk data + CRC
|
||||
end loop;
|
||||
--
|
||||
t_img.type := g_format_png;
|
||||
t_img.nr_colors := case color_type
|
||||
when 0 then 1
|
||||
when 2 then 3
|
||||
when 3 then 1
|
||||
when 4 then 2
|
||||
else 4
|
||||
end;
|
||||
--
|
||||
return t_img;
|
||||
|
||||
end parse_png;
|
||||
|
||||
|
||||
function lzw_decompress (p_blob blob,
|
||||
p_bits pls_integer) return blob
|
||||
is
|
||||
|
||||
powers tp_pls_tab;
|
||||
--
|
||||
g_lzw_ind pls_integer;
|
||||
g_lzw_bits pls_integer;
|
||||
g_lzw_buffer pls_integer;
|
||||
g_lzw_bits_used pls_integer;
|
||||
--
|
||||
type tp_lzw_dict is table of raw(1000) index by pls_integer;
|
||||
t_lzw_dict tp_lzw_dict;
|
||||
t_clr_code pls_integer;
|
||||
t_nxt_code pls_integer;
|
||||
t_new_code pls_integer;
|
||||
t_old_code pls_integer;
|
||||
t_blob blob;
|
||||
--
|
||||
function get_lzw_code
|
||||
return pls_integer
|
||||
is
|
||||
t_rv pls_integer;
|
||||
begin
|
||||
while g_lzw_bits_used < g_lzw_bits
|
||||
loop
|
||||
g_lzw_ind := g_lzw_ind + 1;
|
||||
g_lzw_buffer := blob2num( p_blob, 1, g_lzw_ind ) * powers( g_lzw_bits_used ) + g_lzw_buffer;
|
||||
g_lzw_bits_used := g_lzw_bits_used + 8;
|
||||
end loop;
|
||||
t_rv := bitand( g_lzw_buffer, powers( g_lzw_bits ) - 1 );
|
||||
g_lzw_bits_used := g_lzw_bits_used - g_lzw_bits;
|
||||
g_lzw_buffer := trunc( g_lzw_buffer / powers( g_lzw_bits ) );
|
||||
return t_rv;
|
||||
end;
|
||||
--
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: LZW decompression
|
||||
|
||||
Remarks: From Anton Scheffer's AS_PDF3 package
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.06.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
for i in 0 .. 30
|
||||
loop
|
||||
powers( i ) := power( 2, i );
|
||||
end loop;
|
||||
--
|
||||
t_clr_code := powers( p_bits - 1 );
|
||||
t_nxt_code := t_clr_code + 2;
|
||||
for i in 0 .. least( t_clr_code - 1, 255 )
|
||||
loop
|
||||
t_lzw_dict( i ) := hextoraw( to_char( i, 'fm0X' ) );
|
||||
end loop;
|
||||
dbms_lob.createtemporary( t_blob, true );
|
||||
g_lzw_ind := 0;
|
||||
g_lzw_bits := p_bits;
|
||||
g_lzw_buffer := 0;
|
||||
g_lzw_bits_used := 0;
|
||||
--
|
||||
t_old_code := null;
|
||||
t_new_code := get_lzw_code( );
|
||||
loop
|
||||
case nvl( t_new_code, t_clr_code + 1 )
|
||||
when t_clr_code + 1
|
||||
then
|
||||
exit;
|
||||
when t_clr_code
|
||||
then
|
||||
t_new_code := null;
|
||||
g_lzw_bits := p_bits;
|
||||
t_nxt_code := t_clr_code + 2;
|
||||
else
|
||||
if t_new_code = t_nxt_code
|
||||
then
|
||||
t_lzw_dict( t_nxt_code ) :=
|
||||
utl_raw.concat( t_lzw_dict( t_old_code )
|
||||
, utl_raw.substr( t_lzw_dict( t_old_code ), 1, 1 )
|
||||
);
|
||||
dbms_lob.append( t_blob, t_lzw_dict( t_nxt_code ) );
|
||||
t_nxt_code := t_nxt_code + 1;
|
||||
elsif t_new_code > t_nxt_code
|
||||
then
|
||||
exit;
|
||||
else
|
||||
dbms_lob.append( t_blob, t_lzw_dict( t_new_code ) );
|
||||
if t_old_code is not null
|
||||
then
|
||||
t_lzw_dict( t_nxt_code ) := utl_raw.concat( t_lzw_dict( t_old_code )
|
||||
, utl_raw.substr( t_lzw_dict( t_new_code ), 1, 1 )
|
||||
);
|
||||
t_nxt_code := t_nxt_code + 1;
|
||||
end if;
|
||||
end if;
|
||||
if bitand( t_nxt_code, powers( g_lzw_bits ) - 1 ) = 0
|
||||
and g_lzw_bits < 12
|
||||
then
|
||||
g_lzw_bits := g_lzw_bits + 1;
|
||||
end if;
|
||||
end case;
|
||||
t_old_code := t_new_code;
|
||||
t_new_code := get_lzw_code( );
|
||||
end loop;
|
||||
t_lzw_dict.delete;
|
||||
--
|
||||
return t_blob;
|
||||
|
||||
end lzw_decompress;
|
||||
|
||||
|
||||
function parse_gif (p_img_blob blob) return t_image_info
|
||||
is
|
||||
img t_image_info;
|
||||
buf raw(4000);
|
||||
ind integer;
|
||||
t_len pls_integer;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Parse GIF
|
||||
|
||||
Remarks: From Anton Scheffer's AS_PDF3 package
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.06.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
if dbms_lob.substr( p_img_blob, 3, 1 ) != utl_raw.cast_to_raw( 'GIF' )
|
||||
then
|
||||
return null;
|
||||
end if;
|
||||
ind := 7;
|
||||
buf := dbms_lob.substr( p_img_blob, 7, 7 ); -- Logical Screen Descriptor
|
||||
ind := ind + 7;
|
||||
img.color_res := raw2num( utl_raw.bit_and( utl_raw.substr( buf, 5, 1 ), hextoraw( '70' ) ) ) / 16 + 1;
|
||||
img.color_res := 8;
|
||||
if raw2num( buf, 5, 1 ) > 127
|
||||
then
|
||||
t_len := 3 * power( 2, raw2num( utl_raw.bit_and( utl_raw.substr( buf, 5, 1 ), hextoraw( '07' ) ) ) + 1 );
|
||||
img.color_tab := dbms_lob.substr( p_img_blob, t_len, ind ); -- Global Color Table
|
||||
ind := ind + t_len;
|
||||
end if;
|
||||
--
|
||||
loop
|
||||
case dbms_lob.substr( p_img_blob, 1, ind )
|
||||
when hextoraw( '3B' ) -- trailer
|
||||
then
|
||||
exit;
|
||||
when hextoraw( '21' ) -- extension
|
||||
then
|
||||
if dbms_lob.substr( p_img_blob, 1, ind + 1 ) = hextoraw( 'F9' )
|
||||
then -- Graphic Control Extension
|
||||
if utl_raw.bit_and( dbms_lob.substr( p_img_blob, 1, ind + 3 ), hextoraw( '01' ) ) = hextoraw( '01' )
|
||||
then -- Transparent Color Flag set
|
||||
img.transparency_index := blob2num( p_img_blob, 1, ind + 6 );
|
||||
end if;
|
||||
end if;
|
||||
ind := ind + 2; -- skip sentinel + label
|
||||
loop
|
||||
t_len := blob2num( p_img_blob, 1, ind ); -- Block Size
|
||||
exit when t_len = 0;
|
||||
ind := ind + 1 + t_len; -- skip Block Size + Data Sub-block
|
||||
end loop;
|
||||
ind := ind + 1; -- skip last Block Size
|
||||
when hextoraw( '2C' ) -- image
|
||||
then
|
||||
declare
|
||||
img_blob blob;
|
||||
min_code_size pls_integer;
|
||||
code_size pls_integer;
|
||||
flags raw(1);
|
||||
begin
|
||||
img.width := utl_raw.cast_to_binary_integer( dbms_lob.substr( p_img_blob, 2, ind + 5 )
|
||||
, utl_raw.little_endian
|
||||
);
|
||||
img.height := utl_raw.cast_to_binary_integer( dbms_lob.substr( p_img_blob, 2, ind + 7 )
|
||||
, utl_raw.little_endian
|
||||
);
|
||||
img.greyscale := false;
|
||||
ind := ind + 1 + 8; -- skip sentinel + img sizes
|
||||
flags := dbms_lob.substr( p_img_blob, 1, ind );
|
||||
if utl_raw.bit_and( flags, hextoraw( '80' ) ) = hextoraw( '80' )
|
||||
then
|
||||
t_len := 3 * power( 2, raw2num( utl_raw.bit_and( flags, hextoraw( '07' ) ) ) + 1 );
|
||||
img.color_tab := dbms_lob.substr( p_img_blob, t_len, ind + 1 ); -- Local Color Table
|
||||
end if;
|
||||
ind := ind + 1; -- skip image Flags
|
||||
min_code_size := blob2num( p_img_blob, 1, ind );
|
||||
ind := ind + 1; -- skip LZW Minimum Code Size
|
||||
dbms_lob.createtemporary( img_blob, true );
|
||||
loop
|
||||
t_len := blob2num( p_img_blob, 1, ind ); -- Block Size
|
||||
exit when t_len = 0;
|
||||
dbms_lob.append( img_blob, dbms_lob.substr( p_img_blob, t_len, ind + 1 ) ); -- Data Sub-block
|
||||
ind := ind + 1 + t_len; -- skip Block Size + Data Sub-block
|
||||
end loop;
|
||||
ind := ind + 1; -- skip last Block Size
|
||||
img.pixels := lzw_decompress( img_blob, min_code_size + 1 );
|
||||
--
|
||||
if utl_raw.bit_and( flags, hextoraw( '40' ) ) = hextoraw( '40' )
|
||||
then -- interlaced
|
||||
declare
|
||||
pass pls_integer;
|
||||
pass_ind tp_pls_tab;
|
||||
l_mod number;
|
||||
begin
|
||||
dbms_lob.createtemporary( img_blob, true );
|
||||
pass_ind( 1 ) := 1;
|
||||
pass_ind( 2 ) := trunc( ( img.height - 1 ) / 8 ) + 1;
|
||||
pass_ind( 3 ) := pass_ind( 2 ) + trunc( ( img.height + 3 ) / 8 );
|
||||
pass_ind( 4 ) := pass_ind( 3 ) + trunc( ( img.height + 1 ) / 4 );
|
||||
pass_ind( 2 ) := pass_ind( 2 ) * img.width + 1;
|
||||
pass_ind( 3 ) := pass_ind( 3 ) * img.width + 1;
|
||||
pass_ind( 4 ) := pass_ind( 4 ) * img.width + 1;
|
||||
for i in 0 .. img.height - 1
|
||||
loop
|
||||
l_mod := mod( i, 8 );
|
||||
pass := case l_mod
|
||||
when 0 then 1
|
||||
when 4 then 2
|
||||
when 2 then 3
|
||||
when 6 then 3
|
||||
else 4
|
||||
end;
|
||||
dbms_lob.append( img_blob, dbms_lob.substr( img.pixels, img.width, pass_ind( pass ) ) );
|
||||
pass_ind( pass ) := pass_ind( pass ) + img.width;
|
||||
end loop;
|
||||
img.pixels := img_blob;
|
||||
end;
|
||||
end if;
|
||||
--
|
||||
dbms_lob.freetemporary( img_blob );
|
||||
end;
|
||||
else
|
||||
exit;
|
||||
end case;
|
||||
end loop;
|
||||
--
|
||||
img.type := g_format_gif;
|
||||
return img;
|
||||
|
||||
end parse_gif;
|
||||
|
||||
|
||||
function parse_img (p_blob in blob,
|
||||
p_adler32 in varchar2 := null,
|
||||
p_type in varchar2 := null) return t_image_info
|
||||
is
|
||||
t_img t_image_info;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Parse image file
|
||||
|
||||
Remarks: From Anton Scheffer's AS_PDF3 package
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.06.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
t_img.type := p_type;
|
||||
if t_img.type is null
|
||||
then
|
||||
if rawtohex( dbms_lob.substr( p_blob, 8, 1 ) ) = '89504E470D0A1A0A'
|
||||
then
|
||||
t_img.type := g_format_png;
|
||||
elsif dbms_lob.substr( p_blob , 3, 1 ) = utl_raw.cast_to_raw( 'GIF' )
|
||||
then
|
||||
t_img.type := g_format_gif;
|
||||
else
|
||||
t_img.type := g_format_jpg;
|
||||
end if;
|
||||
end if;
|
||||
--
|
||||
t_img := case lower( t_img.type )
|
||||
when g_format_gif then parse_gif( p_blob )
|
||||
when g_format_png then parse_png( p_blob )
|
||||
when g_format_jpg then parse_jpg( p_blob )
|
||||
else null
|
||||
end;
|
||||
--
|
||||
if t_img.type is not null
|
||||
then
|
||||
t_img.adler32 := coalesce( p_adler32, adler32( p_blob ) );
|
||||
end if;
|
||||
return t_img;
|
||||
|
||||
end parse_img;
|
||||
|
||||
|
||||
|
||||
function is_image (p_file in blob,
|
||||
p_format in varchar2 := null) return boolean
|
||||
as
|
||||
l_info t_image_info;
|
||||
l_returnvalue boolean := false;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: returns true if blob is image
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.06.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
l_info := get_image_info (p_file);
|
||||
|
||||
if l_info.type is not null then
|
||||
|
||||
if p_format is null then
|
||||
l_returnvalue := l_info.type in (g_format_jpg, g_format_png, g_format_gif);
|
||||
else
|
||||
l_returnvalue := l_info.type = p_format;
|
||||
end if;
|
||||
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end is_image;
|
||||
|
||||
|
||||
function get_image_info (p_file in blob) return t_image_info
|
||||
as
|
||||
l_returnvalue t_image_info;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get image information
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.06.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := parse_img (p_file);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_image_info;
|
||||
|
||||
end image_util_pkg;
|
||||
/
|
||||
|
||||
|
||||
|
||||
44
ora/image_util_pkg.pks
Executable file
44
ora/image_util_pkg.pks
Executable file
@ -0,0 +1,44 @@
|
||||
create or replace package image_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles images
|
||||
|
||||
Remarks: Based on image parsing code from Anton Scheffer's AS_PDF3 package
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 23.06.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
g_format_jpg constant varchar2(3) := 'jpg';
|
||||
g_format_png constant varchar2(3) := 'png';
|
||||
g_format_gif constant varchar2(3) := 'gif';
|
||||
|
||||
|
||||
type t_image_info is record (
|
||||
adler32 varchar2(8),
|
||||
width pls_integer,
|
||||
height pls_integer,
|
||||
color_res pls_integer,
|
||||
color_tab raw(768),
|
||||
greyscale boolean,
|
||||
pixels blob,
|
||||
type varchar2(5),
|
||||
nr_colors pls_integer,
|
||||
transparency_index pls_integer
|
||||
);
|
||||
|
||||
-- returns true if blob is image
|
||||
function is_image (p_file in blob,
|
||||
p_format in varchar2 := null) return boolean;
|
||||
|
||||
-- get image information
|
||||
function get_image_info (p_file in blob) return t_image_info;
|
||||
|
||||
|
||||
end image_util_pkg;
|
||||
/
|
||||
|
||||
355
ora/json_util_pkg.pkb
Executable file
355
ora/json_util_pkg.pkb
Executable file
@ -0,0 +1,355 @@
|
||||
create or replace package body json_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: JSON utilities for PL/SQL
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 30.01.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
g_json_null_object constant varchar2(20) := '{ }';
|
||||
|
||||
|
||||
function get_xml_to_json_stylesheet return varchar2
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return XSLT stylesheet for XML to JSON transformation
|
||||
|
||||
Remarks: see http://code.google.com/p/xml2json-xslt/
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 30.01.2010 Created
|
||||
MBR 30.01.2010 Added fix for nulls
|
||||
|
||||
*/
|
||||
|
||||
|
||||
return '<?xml version="1.0" encoding="UTF-8"?>
|
||||
<xsl:stylesheet version="1.0" xmlns:xsl="http://www.w3.org/1999/XSL/Transform">
|
||||
<!--
|
||||
Copyright (c) 2006, Doeke Zanstra
|
||||
All rights reserved.
|
||||
|
||||
Redistribution and use in source and binary forms, with or without modification,
|
||||
are permitted provided that the following conditions are met:
|
||||
|
||||
Redistributions of source code must retain the above copyright notice, this
|
||||
list of conditions and the following disclaimer. Redistributions in binary
|
||||
form must reproduce the above copyright notice, this list of conditions and the
|
||||
following disclaimer in the documentation and/or other materials provided with
|
||||
the distribution.
|
||||
|
||||
Neither the name of the dzLib nor the names of its contributors may be used to
|
||||
endorse or promote products derived from this software without specific prior
|
||||
written permission.
|
||||
|
||||
THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND
|
||||
ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED
|
||||
WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE DISCLAIMED.
|
||||
IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR ANY DIRECT,
|
||||
INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES (INCLUDING,
|
||||
BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; LOSS OF USE,
|
||||
DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON ANY THEORY OF
|
||||
LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT (INCLUDING NEGLIGENCE OR
|
||||
OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS SOFTWARE, EVEN IF ADVISED OF
|
||||
THE POSSIBILITY OF SUCH DAMAGE.
|
||||
-->
|
||||
|
||||
<xsl:output indent="no" omit-xml-declaration="yes" method="text" encoding="UTF-8" media-type="text/x-json"/>
|
||||
<xsl:strip-space elements="*"/>
|
||||
<!--contant-->
|
||||
<xsl:variable name="d">0123456789</xsl:variable>
|
||||
|
||||
<!-- ignore document text -->
|
||||
<xsl:template match="text()[preceding-sibling::node() or following-sibling::node()]"/>
|
||||
|
||||
<!-- string -->
|
||||
<xsl:template match="text()">
|
||||
<xsl:call-template name="escape-string">
|
||||
<xsl:with-param name="s" select="."/>
|
||||
</xsl:call-template>
|
||||
</xsl:template>
|
||||
|
||||
<!-- Main template for escaping strings; used by above template and for object-properties
|
||||
Responsibilities: placed quotes around string, and chain up to next filter, escape-bs-string -->
|
||||
<xsl:template name="escape-string">
|
||||
<xsl:param name="s"/>
|
||||
<xsl:text>"</xsl:text>
|
||||
<xsl:call-template name="escape-bs-string">
|
||||
<xsl:with-param name="s" select="$s"/>
|
||||
</xsl:call-template>
|
||||
<xsl:text>"</xsl:text>
|
||||
</xsl:template>
|
||||
|
||||
<!-- Escape the backslash (\) before everything else. -->
|
||||
<xsl:template name="escape-bs-string">
|
||||
<xsl:param name="s"/>
|
||||
<xsl:choose>
|
||||
<xsl:when test="contains($s,''\'')">
|
||||
<xsl:call-template name="escape-quot-string">
|
||||
<xsl:with-param name="s" select="concat(substring-before($s,''\''),''\\'')"/>
|
||||
</xsl:call-template>
|
||||
<xsl:call-template name="escape-bs-string">
|
||||
<xsl:with-param name="s" select="substring-after($s,''\'')"/>
|
||||
</xsl:call-template>
|
||||
</xsl:when>
|
||||
<xsl:otherwise>
|
||||
<xsl:call-template name="escape-quot-string">
|
||||
<xsl:with-param name="s" select="$s"/>
|
||||
</xsl:call-template>
|
||||
</xsl:otherwise>
|
||||
</xsl:choose>
|
||||
</xsl:template>
|
||||
|
||||
<!-- Escape the double quote ("). -->
|
||||
<xsl:template name="escape-quot-string">
|
||||
<xsl:param name="s"/>
|
||||
<xsl:choose>
|
||||
<xsl:when test="contains($s,''"'')">
|
||||
<xsl:call-template name="encode-string">
|
||||
<xsl:with-param name="s" select="concat(substring-before($s,''"''),''\"'')"/>
|
||||
</xsl:call-template>
|
||||
<xsl:call-template name="escape-quot-string">
|
||||
<xsl:with-param name="s" select="substring-after($s,''"'')"/>
|
||||
</xsl:call-template>
|
||||
</xsl:when>
|
||||
<xsl:otherwise>
|
||||
<xsl:call-template name="encode-string">
|
||||
<xsl:with-param name="s" select="$s"/>
|
||||
</xsl:call-template>
|
||||
</xsl:otherwise>
|
||||
</xsl:choose>
|
||||
</xsl:template>
|
||||
|
||||
<!-- Replace tab, line feed and/or carriage return by its matching escape code. Can''t escape backslash
|
||||
or double quote here, because they don''t replace characters (� becomes \t), but they prefix
|
||||
characters (\ becomes \\). Besides, backslash should be seperate anyway, because it should be
|
||||
processed first. This function can''t do that. -->
|
||||
<xsl:template name="encode-string">
|
||||
<xsl:param name="s"/>
|
||||
<xsl:choose>
|
||||
<!-- tab -->
|
||||
<xsl:when test="contains($s,''	'')">
|
||||
<xsl:call-template name="encode-string">
|
||||
<xsl:with-param name="s" select="concat(substring-before($s,''	''),''\t'',substring-after($s,''	''))"/>
|
||||
</xsl:call-template>
|
||||
</xsl:when>
|
||||
<!-- line feed -->
|
||||
<xsl:when test="contains($s,''
'')">
|
||||
<xsl:call-template name="encode-string">
|
||||
<xsl:with-param name="s" select="concat(substring-before($s,''
''),''\n'',substring-after($s,''
''))"/>
|
||||
</xsl:call-template>
|
||||
</xsl:when>
|
||||
<!-- carriage return -->
|
||||
<xsl:when test="contains($s,''
'')">
|
||||
<xsl:call-template name="encode-string">
|
||||
<xsl:with-param name="s" select="concat(substring-before($s,''
''),''\r'',substring-after($s,''
''))"/>
|
||||
</xsl:call-template>
|
||||
</xsl:when>
|
||||
<xsl:otherwise><xsl:value-of select="$s"/></xsl:otherwise>
|
||||
</xsl:choose>
|
||||
</xsl:template>
|
||||
|
||||
<!-- number (no support for javascript mantise) -->
|
||||
<xsl:template match="text()[not(string(number())=''NaN'')]">
|
||||
<xsl:value-of select="."/>
|
||||
</xsl:template>
|
||||
|
||||
<!-- boolean, case-insensitive -->
|
||||
<xsl:template match="text()[translate(.,''TRUE'',''true'')=''true'']">true</xsl:template>
|
||||
<xsl:template match="text()[translate(.,''FALSE'',''false'')=''false'']">false</xsl:template>
|
||||
|
||||
<!-- item:null -->
|
||||
<xsl:template match="*[count(child::node())=0]">
|
||||
<xsl:call-template name="escape-string">
|
||||
<xsl:with-param name="s" select="local-name()"/>
|
||||
</xsl:call-template>
|
||||
<xsl:text>:null</xsl:text>
|
||||
<xsl:if test="following-sibling::*">,</xsl:if>
|
||||
<xsl:if test="not(following-sibling::*)">}</xsl:if> <!-- MBR 30.01.2010: added this line as it appeared to be missing from stylesheet -->
|
||||
</xsl:template>
|
||||
|
||||
<!-- object -->
|
||||
<xsl:template match="*" name="base">
|
||||
<xsl:if test="not(preceding-sibling::*)">{</xsl:if>
|
||||
<xsl:call-template name="escape-string">
|
||||
<xsl:with-param name="s" select="name()"/>
|
||||
</xsl:call-template>
|
||||
<xsl:text>:</xsl:text>
|
||||
<xsl:apply-templates select="child::node()"/>
|
||||
<xsl:if test="following-sibling::*">,</xsl:if>
|
||||
<xsl:if test="not(following-sibling::*)">}</xsl:if>
|
||||
</xsl:template>
|
||||
|
||||
<!-- array -->
|
||||
<xsl:template match="*[count(../*[name(../*)=name(.)])=count(../*) and count(../*)>1]">
|
||||
<xsl:if test="not(preceding-sibling::*)">[</xsl:if>
|
||||
<xsl:choose>
|
||||
<xsl:when test="not(child::node())">
|
||||
<xsl:text>null</xsl:text>
|
||||
</xsl:when>
|
||||
<xsl:otherwise>
|
||||
<xsl:apply-templates select="child::node()"/>
|
||||
</xsl:otherwise>
|
||||
</xsl:choose>
|
||||
<xsl:if test="following-sibling::*">,</xsl:if>
|
||||
<xsl:if test="not(following-sibling::*)">]</xsl:if>
|
||||
</xsl:template>
|
||||
|
||||
<!-- convert root element to an anonymous container -->
|
||||
<xsl:template match="/">
|
||||
<xsl:apply-templates select="node()"/>
|
||||
</xsl:template>
|
||||
|
||||
</xsl:stylesheet>';
|
||||
|
||||
end get_xml_to_json_stylesheet;
|
||||
|
||||
|
||||
function ref_cursor_to_json (p_ref_cursor in sys_refcursor,
|
||||
p_max_rows in number := null,
|
||||
p_skip_rows in number := null) return clob
|
||||
as
|
||||
l_ctx dbms_xmlgen.ctxhandle;
|
||||
l_num_rows pls_integer;
|
||||
l_xml xmltype;
|
||||
l_json xmltype;
|
||||
l_returnvalue clob;
|
||||
begin
|
||||
|
||||
|
||||
/*
|
||||
|
||||
Purpose: generate JSON from REF Cursor
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 30.01.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
l_ctx := dbms_xmlgen.newcontext (p_ref_cursor);
|
||||
|
||||
dbms_xmlgen.setnullhandling (l_ctx, dbms_xmlgen.empty_tag);
|
||||
|
||||
-- for pagination
|
||||
|
||||
if p_max_rows is not null then
|
||||
dbms_xmlgen.setmaxrows (l_ctx, p_max_rows);
|
||||
end if;
|
||||
|
||||
if p_skip_rows is not null then
|
||||
dbms_xmlgen.setskiprows (l_ctx, p_skip_rows);
|
||||
end if;
|
||||
|
||||
-- get the XML content
|
||||
l_xml := dbms_xmlgen.getxmltype (l_ctx, dbms_xmlgen.none);
|
||||
|
||||
l_num_rows := dbms_xmlgen.getnumrowsprocessed (l_ctx);
|
||||
|
||||
dbms_xmlgen.closecontext (l_ctx);
|
||||
|
||||
close p_ref_cursor;
|
||||
|
||||
if l_num_rows > 0 then
|
||||
-- perform the XSL transformation
|
||||
l_json := l_xml.transform (xmltype(get_xml_to_json_stylesheet));
|
||||
l_returnvalue := l_json.getclobval();
|
||||
else
|
||||
l_returnvalue := g_json_null_object;
|
||||
end if;
|
||||
|
||||
l_returnvalue := dbms_xmlgen.convert (l_returnvalue, dbms_xmlgen.entity_decode);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end ref_cursor_to_json;
|
||||
|
||||
|
||||
function sql_to_json (p_sql in varchar2,
|
||||
p_param_names in t_str_array := null,
|
||||
p_param_values in t_str_array := null,
|
||||
p_max_rows in number := null,
|
||||
p_skip_rows in number := null) return clob
|
||||
as
|
||||
l_ctx dbms_xmlgen.ctxhandle;
|
||||
l_num_rows pls_integer;
|
||||
l_xml xmltype;
|
||||
l_json xmltype;
|
||||
l_returnvalue clob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: generate JSON from SQL statement
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 30.01.2010 Created
|
||||
MBR 28.07.2010 Handle null value in bind variable value (issue and solution reported by Matt Nolan)
|
||||
|
||||
*/
|
||||
|
||||
|
||||
l_ctx := dbms_xmlgen.newcontext (p_sql);
|
||||
|
||||
dbms_xmlgen.setnullhandling (l_ctx, dbms_xmlgen.empty_tag);
|
||||
|
||||
-- bind variables, if any
|
||||
if p_param_names is not null then
|
||||
|
||||
for i in 1..p_param_names.count loop
|
||||
dbms_xmlgen.setbindvalue (l_ctx, p_param_names(i), nvl(p_param_values(i), ''));
|
||||
end loop;
|
||||
|
||||
end if;
|
||||
|
||||
-- for pagination
|
||||
|
||||
if p_max_rows is not null then
|
||||
dbms_xmlgen.setmaxrows (l_ctx, p_max_rows);
|
||||
end if;
|
||||
|
||||
if p_skip_rows is not null then
|
||||
dbms_xmlgen.setskiprows (l_ctx, p_skip_rows);
|
||||
end if;
|
||||
|
||||
-- get the XML content
|
||||
l_xml := dbms_xmlgen.getxmltype (l_ctx, dbms_xmlgen.none);
|
||||
|
||||
l_num_rows := dbms_xmlgen.getnumrowsprocessed (l_ctx);
|
||||
|
||||
dbms_xmlgen.closecontext (l_ctx);
|
||||
|
||||
-- perform the XSL transformation
|
||||
if l_num_rows > 0 then
|
||||
l_json := l_xml.transform (xmltype(get_xml_to_json_stylesheet));
|
||||
l_returnvalue := l_json.getclobval();
|
||||
l_returnvalue := dbms_xmlgen.convert (l_returnvalue, dbms_xmlgen.entity_decode);
|
||||
else
|
||||
l_returnvalue := g_json_null_object;
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end sql_to_json;
|
||||
|
||||
|
||||
end json_util_pkg;
|
||||
/
|
||||
|
||||
31
ora/json_util_pkg.pks
Executable file
31
ora/json_util_pkg.pks
Executable file
@ -0,0 +1,31 @@
|
||||
create or replace package json_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: JSON utilities for PL/SQL
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 30.01.2010 Created
|
||||
|
||||
*/
|
||||
|
||||
-- generate JSON from REF Cursor
|
||||
function ref_cursor_to_json (p_ref_cursor in sys_refcursor,
|
||||
p_max_rows in number := null,
|
||||
p_skip_rows in number := null) return clob;
|
||||
|
||||
-- generate JSON from SQL statement
|
||||
function sql_to_json (p_sql in varchar2,
|
||||
p_param_names in t_str_array := null,
|
||||
p_param_values in t_str_array := null,
|
||||
p_max_rows in number := null,
|
||||
p_skip_rows in number := null) return clob;
|
||||
|
||||
|
||||
end json_util_pkg;
|
||||
/
|
||||
|
||||
105
ora/math_util_pkg.pkb
Executable file
105
ora/math_util_pkg.pkb
Executable file
@ -0,0 +1,105 @@
|
||||
create or replace package body math_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles general math functionality
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 22.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
function safediv (p_value_1 in number,
|
||||
p_value_2 in number) return number
|
||||
as
|
||||
l_returnvalue number;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: safe division by zero
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 22.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
if p_value_2 = 0 then
|
||||
l_returnvalue:=0;
|
||||
else
|
||||
l_returnvalue:=p_value_1 / p_value_2;
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end safediv;
|
||||
|
||||
|
||||
function get_fnum (p_value in number,
|
||||
p_decimals in number := 2) return number
|
||||
as
|
||||
l_returnvalue number;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get number formatted with specified number of decimals
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 22.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
return round(p_value, p_decimals);
|
||||
|
||||
end get_fnum;
|
||||
|
||||
|
||||
function is_within_pct_of_value (p_value1 in number,
|
||||
p_value2 in number,
|
||||
p_pct in number) return boolean
|
||||
as
|
||||
l_returnvalue boolean;
|
||||
l_pct_value number;
|
||||
begin
|
||||
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return true if value is within given percentage of other value
|
||||
|
||||
Remarks: for example, 90 (and 110) is within 10 percent of 100
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 22.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
l_pct_value := nvl(p_value2,0) * nvl(p_pct / 100,0);
|
||||
|
||||
if p_value1 between (p_value2 - l_pct_value) and (p_value2 + l_pct_value) then
|
||||
l_returnvalue := true;
|
||||
else
|
||||
l_returnvalue := false;
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end is_within_pct_of_value;
|
||||
|
||||
|
||||
|
||||
end math_util_pkg;
|
||||
/
|
||||
31
ora/math_util_pkg.pks
Executable file
31
ora/math_util_pkg.pks
Executable file
@ -0,0 +1,31 @@
|
||||
create or replace package math_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles general math functionality
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 22.09.2006 Created
|
||||
|
||||
*/
|
||||
|
||||
-- safe division by zero
|
||||
function safediv (p_value_1 in number,
|
||||
p_value_2 in number) return number;
|
||||
|
||||
-- get number formatted with specified number of decimals
|
||||
function get_fnum (p_value in number,
|
||||
p_decimals in number := 2) return number;
|
||||
|
||||
-- return true if value is within given percentage of other value
|
||||
function is_within_pct_of_value (p_value1 in number,
|
||||
p_value2 in number,
|
||||
p_pct in number) return boolean;
|
||||
|
||||
|
||||
end math_util_pkg;
|
||||
/
|
||||
1992
ora/ms_ews_util_pkg.pkb
Executable file
1992
ora/ms_ews_util_pkg.pkb
Executable file
File diff suppressed because it is too large
Load Diff
322
ora/ms_ews_util_pkg.pks
Executable file
322
ora/ms_ews_util_pkg.pks
Executable file
@ -0,0 +1,322 @@
|
||||
create or replace package ms_ews_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles Microsoft Exchange Web Services (EWS)
|
||||
|
||||
Remarks: see http://msdn.microsoft.com/en-us/library/bb204119(v=exchg.140).aspx
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 19.02.2012 Created
|
||||
MBR 24.04.2012 Added item and attachment operations
|
||||
MBR 07.05.2012 Added utility operations (resolve names, expand distribution list)
|
||||
|
||||
*/
|
||||
|
||||
--------
|
||||
-- types
|
||||
--------
|
||||
|
||||
-- see http://msdn.microsoft.com/en-us/library/aa565036(v=exchg.140).aspx
|
||||
type t_mailbox is record (
|
||||
name varchar2(2000),
|
||||
email_address varchar2(2000),
|
||||
routing_type varchar2(255),
|
||||
mailbox_type varchar2(255),
|
||||
item_id varchar2(2000)
|
||||
);
|
||||
|
||||
type t_mailbox_tab is table of t_mailbox;
|
||||
|
||||
-- see http://msdn.microsoft.com/en-us/library/aa581315(v=exchg.140).aspx
|
||||
type t_contact is record (
|
||||
item_id varchar2(2000)
|
||||
-- TODO: lots more fields
|
||||
);
|
||||
|
||||
-- see http://msdn.microsoft.com/en-us/library/aa581011(v=exchg.140).aspx
|
||||
type t_resolution is record (
|
||||
mailbox t_mailbox,
|
||||
contact t_contact
|
||||
);
|
||||
|
||||
-- see http://msdn.microsoft.com/en-us/library/aa580614(v=exchg.140).aspx
|
||||
type t_resolution_list is table of t_resolution index by binary_integer;
|
||||
|
||||
-- see http://msdn.microsoft.com/en-us/library/aa564322(v=exchg.140).aspx
|
||||
type t_dl_expansion_list is table of t_mailbox index by binary_integer;
|
||||
type t_dl_expansion_tab is table of t_mailbox;
|
||||
|
||||
-- see http://msdn.microsoft.com/en-us/library/aa581334(v=exchg.140).aspx
|
||||
type t_folder is record (
|
||||
sequence_number number,
|
||||
folder_id varchar2(2000),
|
||||
display_name varchar2(2000),
|
||||
total_count number,
|
||||
child_folder_count number,
|
||||
unread_count number
|
||||
);
|
||||
|
||||
type t_folder_list is table of t_folder index by binary_integer;
|
||||
type t_folder_tab is table of t_folder;
|
||||
|
||||
type t_item is record (
|
||||
-- general Item info, see http://msdn.microsoft.com/en-us/library/aa580790(v=exchg.140).aspx
|
||||
sequence_number number,
|
||||
item_id varchar2(2000),
|
||||
change_key varchar2(2000),
|
||||
parent_folder_id varchar2(2000),
|
||||
item_class varchar2(255),
|
||||
item_size number,
|
||||
subject varchar2(2000),
|
||||
sensitivity varchar2(255),
|
||||
datetime_created date,
|
||||
datetime_sent date,
|
||||
datetime_received date,
|
||||
has_attachments varchar2(10),
|
||||
mime_content clob,
|
||||
body clob,
|
||||
-- (mail) Message, see http://msdn.microsoft.com/en-us/library/aa494306(v=exchg.140).aspx
|
||||
from_mailbox_name varchar2(2000),
|
||||
is_read varchar2(10),
|
||||
-- CalendarItem, see http://msdn.microsoft.com/en-us/library/aa564765(v=exchg.140).aspx
|
||||
location varchar2(2000),
|
||||
organizer_mailbox_name varchar2(2000),
|
||||
start_date date,
|
||||
end_date date,
|
||||
legacy_free_busy_status varchar2(255),
|
||||
reminder_is_set varchar2(10),
|
||||
reminder_minutes_before_start number,
|
||||
is_all_day_event varchar2(10),
|
||||
-- Task item, see http://msdn.microsoft.com/en-us/library/aa563930(v=exchg.140).aspx
|
||||
due_date date,
|
||||
status varchar2(255),
|
||||
percent_complete number,
|
||||
total_work number
|
||||
);
|
||||
|
||||
type t_item_list is table of t_item index by binary_integer;
|
||||
type t_item_tab is table of t_item;
|
||||
|
||||
-- see http://msdn.microsoft.com/en-us/library/aa580492(v=exchg.140).aspx
|
||||
type t_file_attachment is record (
|
||||
sequence_number number,
|
||||
attachment_id varchar2(2000),
|
||||
item_id varchar2(2000),
|
||||
name varchar2(2000),
|
||||
content_type varchar2(2000),
|
||||
content_id varchar2(2000),
|
||||
attachment_size number,
|
||||
content blob
|
||||
);
|
||||
|
||||
type t_file_attachment_list is table of t_file_attachment index by binary_integer;
|
||||
type t_file_attachment_tab is table of t_file_attachment;
|
||||
|
||||
------------
|
||||
-- constants
|
||||
------------
|
||||
|
||||
g_true constant varchar2(10) := 'true';
|
||||
g_false constant varchar2(10) := 'false';
|
||||
|
||||
-- "Distinguished Folders", folders that can be referenced by name, see http://msdn.microsoft.com/en-us/library/aa580808(v=exchg.140).aspx
|
||||
-- for other folders, use find_folders to get folder id
|
||||
-- NOTE: when adding to this list, make sure to update the internal function is_distinguished_folder_id ()
|
||||
g_folder_id_root constant varchar2(255) := 'root';
|
||||
g_folder_id_message_root constant varchar2(255) := 'msgfolderroot';
|
||||
g_folder_id_inbox constant varchar2(255) := 'inbox';
|
||||
g_folder_id_sent_items constant varchar2(255) := 'sentitems';
|
||||
g_folder_id_deleted_items constant varchar2(255) := 'deleteditems';
|
||||
g_folder_id_outbox constant varchar2(255) := 'outbox';
|
||||
g_folder_id_junk_email constant varchar2(255) := 'junkemail';
|
||||
g_folder_id_drafts constant varchar2(255) := 'drafts';
|
||||
g_folder_id_calendar constant varchar2(255) := 'calendar';
|
||||
|
||||
-- item classes, see http://msdn.microsoft.com/en-us/library/ff861573.aspx
|
||||
g_item_class_unknown constant varchar2(255) := 'IPM';
|
||||
g_item_class_appointment constant varchar2(255) := 'IPM.Appointment';
|
||||
g_item_class_contact constant varchar2(255) := 'IPM.Contact';
|
||||
g_item_class_message constant varchar2(255) := 'IPM.Note';
|
||||
g_item_class_task constant varchar2(255) := 'IPM.Task';
|
||||
g_item_class_meeting_request constant varchar2(255) := 'IPM.Schedule.Meeting.Request';
|
||||
|
||||
-- Body Type, see http://msdn.microsoft.com/en-us/library/aa565622(v=exchg.140).aspx
|
||||
g_body_type_best constant varchar2(255) := 'Best';
|
||||
g_body_type_html constant varchar2(255) := 'HTML';
|
||||
g_body_type_text constant varchar2(255) := 'Text';
|
||||
|
||||
-- Delete Type, see http://msdn.microsoft.com/en-us/library/ff406163(v=exchg.140).aspx
|
||||
g_delete_type_hard_delete constant varchar2(255) := 'HardDelete';
|
||||
g_delete_type_move_to_d_items constant varchar2(255) := 'MoveToDeletedItems';
|
||||
g_delete_type_soft_delete constant varchar2(255) := 'SoftDelete';
|
||||
|
||||
-- Message Disposition attribute, see http://msdn.microsoft.com/en-us/library/aa565209(v=exchg.140).aspx
|
||||
g_message_disp_save_only constant varchar2(255) := 'SaveOnly';
|
||||
g_message_disp_send_only constant varchar2(255) := 'SendOnly';
|
||||
g_message_disp_send_and_save constant varchar2(255) := 'SendAndSaveCopy';
|
||||
|
||||
-- Send Meeting Invitations attribute, see http://msdn.microsoft.com/en-us/library/aa565209(v=exchg.140).aspx
|
||||
g_meeting_inv_send_to_none constant varchar2(255) := 'SendToNone';
|
||||
g_meeting_inv_send_only_to_all constant varchar2(255) := 'SendOnlyToAll';
|
||||
g_meeting_inv_send_to_all_save constant varchar2(255) := 'SendToAllAndSaveCopy';
|
||||
|
||||
-- Legacy Free Busy Status, see http://msdn.microsoft.com/en-us/library/aa566143(v=exchg.140).aspx
|
||||
g_free_busy_status_free constant varchar2(255) := 'Free';
|
||||
g_free_busy_status_tentative constant varchar2(255) := 'Tentative';
|
||||
g_free_busy_status_busy constant varchar2(255) := 'Busy';
|
||||
g_free_busy_status_out_of_off constant varchar2(255) := 'OOF';
|
||||
g_free_busy_status_no_data constant varchar2(255) := 'NoData';
|
||||
|
||||
-- task status, see http://msdn.microsoft.com/en-us/library/aa563980(v=exchg.140).aspx
|
||||
g_task_status_not_started constant varchar2(255) := 'NotStarted';
|
||||
g_task_status_in_progress constant varchar2(255) := 'InProgress';
|
||||
g_task_status_completed constant varchar2(255) := 'Completed';
|
||||
g_task_status_waiting_on_other constant varchar2(255) := 'WaitingOnOthers';
|
||||
g_task_status_deferred constant varchar2(255) := 'Deferred';
|
||||
|
||||
-- mailbox type, see http://msdn.microsoft.com/en-us/library/aa563493(v=exchg.140).aspx
|
||||
g_mailbox_type_mailbox constant varchar2(255) := 'Mailbox';
|
||||
g_mailbox_type_public_dl constant varchar2(255) := 'PublicDL';
|
||||
g_mailbox_type_private_dl constant varchar2(255) := 'PrivateDL';
|
||||
g_mailbox_type_contact constant varchar2(255) := 'Contact';
|
||||
g_mailbox_type_public_folder constant varchar2(255) := 'PublicFolder';
|
||||
g_mailbox_type_unknown constant varchar2(255) := 'Unknown';
|
||||
g_mailbox_type_one_off constant varchar2(255) := 'OneOff';
|
||||
|
||||
-----------------
|
||||
-- authentication
|
||||
-----------------
|
||||
|
||||
-- initialize settings
|
||||
procedure init (p_service_url in varchar2,
|
||||
p_username in varchar2,
|
||||
p_password in varchar2,
|
||||
p_wallet_path in varchar2 := null,
|
||||
p_wallet_password in varchar2 := null);
|
||||
|
||||
--------------------
|
||||
-- folder operations
|
||||
--------------------
|
||||
|
||||
-- find folders
|
||||
function find_folders_as_list (p_parent_folder_id in varchar2 := null) return t_folder_list;
|
||||
|
||||
-- find folder
|
||||
function find_folders (p_parent_folder_id in varchar2 := null) return t_folder_tab pipelined;
|
||||
|
||||
-- get folder id by name
|
||||
function get_folder_id_by_name (p_folder_name in varchar2,
|
||||
p_parent_folder_id in varchar2 := null) return varchar2;
|
||||
|
||||
-- get folder
|
||||
function get_folder (p_folder_id in varchar2) return t_folder;
|
||||
|
||||
------------------
|
||||
-- item operations
|
||||
------------------
|
||||
|
||||
-- find items
|
||||
function find_items_as_list (p_folder_id in varchar2 := null,
|
||||
p_search_string in varchar2 := null,
|
||||
p_search_from_date in date := null,
|
||||
p_search_to_date in date := null,
|
||||
p_max_rows in number := null,
|
||||
p_offset in number := null,
|
||||
p_username in varchar2 := null) return t_item_list;
|
||||
|
||||
-- find items
|
||||
function find_items (p_folder_id in varchar2 := null,
|
||||
p_search_string in varchar2 := null,
|
||||
p_search_from_date in date := null,
|
||||
p_search_to_date in date := null,
|
||||
p_max_rows in number := null,
|
||||
p_offset in number := null,
|
||||
p_username in varchar2 := null) return t_item_tab pipelined;
|
||||
|
||||
-- get item
|
||||
function get_item (p_item_id in varchar2,
|
||||
p_body_type in varchar2 := null,
|
||||
p_include_mime_content in boolean := false) return t_item;
|
||||
|
||||
-- move item
|
||||
procedure move_item (p_item_id in varchar2,
|
||||
p_folder_id in varchar2);
|
||||
|
||||
-- copy item
|
||||
procedure copy_item (p_item_id in varchar2,
|
||||
p_folder_id in varchar2);
|
||||
|
||||
-- delete item
|
||||
procedure delete_item (p_item_id in varchar2,
|
||||
p_delete_type in varchar2 := null);
|
||||
|
||||
-- send item
|
||||
procedure send_item (p_item_id in varchar2,
|
||||
p_save_item_to_folder in boolean := true);
|
||||
|
||||
-- create calendar item
|
||||
function create_calendar_item (p_item in t_item,
|
||||
p_send_meeting_invitations in varchar2 := null,
|
||||
p_required_attendees in t_str_array := null) return varchar2;
|
||||
|
||||
-- create task item
|
||||
function create_task_item (p_item in t_item) return varchar2;
|
||||
|
||||
-- create message item
|
||||
function create_message_item (p_item in t_item,
|
||||
p_message_disposition in varchar2 := null,
|
||||
p_to_recipients in t_str_array := null) return varchar2;
|
||||
|
||||
-- TODO: generic update_item ()
|
||||
-- the following is just a proof-of-concept that demonstrates an update
|
||||
procedure update_item_is_read (p_item_id in varchar2,
|
||||
p_change_key in varchar2,
|
||||
p_is_read in boolean);
|
||||
|
||||
------------------------
|
||||
-- attachment operations
|
||||
------------------------
|
||||
|
||||
-- note: attachments can be either file attachments, or item attachments (ie other messages)
|
||||
-- currently, just the file attachment operations are supported
|
||||
|
||||
-- get item file attachments
|
||||
function get_file_attachments_as_list (p_item_id in varchar2,
|
||||
p_include_content in boolean := false) return t_file_attachment_list;
|
||||
|
||||
-- get item file attachments
|
||||
function get_file_attachments (p_item_id in varchar2) return t_file_attachment_tab pipelined;
|
||||
|
||||
-- get file attachment
|
||||
function get_file_attachment (p_attachment_id in varchar2) return t_file_attachment;
|
||||
|
||||
-- create file attachment
|
||||
function create_file_attachment (p_file_attachment in t_file_attachment) return varchar2;
|
||||
|
||||
-- delete attachment
|
||||
procedure delete_attachment (p_attachment_id in varchar2);
|
||||
|
||||
---------------------
|
||||
-- utility operations
|
||||
---------------------
|
||||
|
||||
-- resolve names
|
||||
function resolve_names_as_list (p_unresolved_entry in varchar2,
|
||||
p_return_full_contact_data in boolean := false) return t_resolution_list;
|
||||
|
||||
-- resolve names
|
||||
function resolve_names (p_unresolved_entry in varchar2) return t_mailbox_tab pipelined;
|
||||
|
||||
-- expand (public) distribution list
|
||||
function expand_public_dl_as_list (p_email_address in varchar2) return t_dl_expansion_list;
|
||||
|
||||
-- expand (public) distribution list
|
||||
function expand_public_dl (p_email_address in varchar2) return t_dl_expansion_tab pipelined;
|
||||
|
||||
|
||||
end ms_ews_util_pkg;
|
||||
/
|
||||
|
||||
476
ora/ntlm_http_pkg.pkb
Executable file
476
ora/ntlm_http_pkg.pkb
Executable file
@ -0,0 +1,476 @@
|
||||
create or replace package body ntlm_http_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles HTTP connections using NTLM authentication
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 03.06.2011 Created
|
||||
MBR 03.06.2011 Troubleshooting, bug fixes, handle persistent connection issues
|
||||
MBR 24.06.2011 Cleaned up code
|
||||
MBR 24.06.2011 Added begin/end_request
|
||||
|
||||
*/
|
||||
|
||||
|
||||
function headers_contain_value (p_resp in out utl_http.resp,
|
||||
p_name in varchar2,
|
||||
p_value in varchar2) return boolean
|
||||
as
|
||||
l_name varchar2(2000);
|
||||
l_value varchar2(2000);
|
||||
l_returnvalue boolean := false;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: return true if response headers contain a specific name/value pair
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 25.07.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
for i in 1 .. utl_http.get_header_count (p_resp) loop
|
||||
utl_http.get_header (p_resp, i, l_name, l_value);
|
||||
if (l_name = p_name) and (l_value = p_value) then
|
||||
l_returnvalue := true;
|
||||
exit;
|
||||
end if;
|
||||
end loop;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end headers_contain_value;
|
||||
|
||||
|
||||
function get_response_clob (p_url in varchar2,
|
||||
p_username in varchar2,
|
||||
p_password in varchar2,
|
||||
p_wallet_path in varchar2 := null,
|
||||
p_wallet_password in varchar2 := null,
|
||||
p_proxy_server in varchar2 := null) return clob
|
||||
as
|
||||
|
||||
l_req utl_http.req;
|
||||
l_resp utl_http.resp;
|
||||
l_returnvalue clob;
|
||||
|
||||
l_authenticate_with_ntlm boolean;
|
||||
|
||||
l_name varchar2(500);
|
||||
l_value varchar2(500);
|
||||
|
||||
l_ntlm_message varchar2(500);
|
||||
|
||||
l_negotiate_message varchar2(500);
|
||||
|
||||
l_server_challenge raw(4000);
|
||||
l_negotiate_flags raw(4000);
|
||||
|
||||
l_authenticate_message varchar2(500);
|
||||
|
||||
|
||||
function get_response_body (p_resp in out utl_http.resp) return clob
|
||||
as
|
||||
l_data string_util_pkg.t_max_pl_varchar2;
|
||||
l_returnvalue clob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get the response body as a clob
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 24.06.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
begin
|
||||
loop
|
||||
utl_http.read_text(r => p_resp, data => l_data);
|
||||
l_returnvalue := l_returnvalue || l_data;
|
||||
end loop;
|
||||
exception
|
||||
when utl_http.end_of_body then
|
||||
null;
|
||||
end;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_response_body;
|
||||
|
||||
|
||||
procedure debug_response (p_resp in out utl_http.resp)
|
||||
as
|
||||
l_name varchar2(255);
|
||||
l_value varchar2(2000);
|
||||
l_body clob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: print debug info about the response
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 24.06.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
debug_pkg.printf('Response Status Code: %1', p_resp.status_code);
|
||||
|
||||
for i in 1 .. utl_http.get_header_count (p_resp) loop
|
||||
utl_http.get_header (p_resp, i, l_name, l_value);
|
||||
debug_pkg.printf('#%1 %2 : %3', i, l_name, l_value);
|
||||
end loop;
|
||||
|
||||
l_returnvalue := get_response_body (p_resp);
|
||||
|
||||
debug_pkg.printf('Body length = %1', dbms_lob.getlength (l_returnvalue));
|
||||
debug_pkg.printf('Persistent connection count: %1', utl_http.get_persistent_conn_count);
|
||||
|
||||
end debug_response;
|
||||
|
||||
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Get response clob from URL
|
||||
|
||||
Remarks: see http://davenport.sourceforge.net/ntlm.html#ntlmHttpAuthentication
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 11.05.2011 Created
|
||||
MBR 03.06.2011 Lots of changes
|
||||
|
||||
*/
|
||||
|
||||
utl_http.set_detailed_excp_support (enable => true);
|
||||
utl_http.set_response_error_check (false);
|
||||
|
||||
utl_http.set_persistent_conn_support (true, 10);
|
||||
|
||||
debug_pkg.printf('Persistent connection count: %1', utl_http.get_persistent_conn_count);
|
||||
|
||||
-- support for HTTPS
|
||||
if instr(lower(p_url),'https') = 1 then
|
||||
utl_http.set_wallet (p_wallet_path, p_wallet_password);
|
||||
end if;
|
||||
|
||||
-- support for proxy server
|
||||
if p_proxy_server is not null then
|
||||
utl_http.set_proxy (p_proxy_server);
|
||||
end if;
|
||||
|
||||
------------
|
||||
-- Request 1
|
||||
------------
|
||||
|
||||
debug_pkg.printf(' ');
|
||||
debug_pkg.printf(p_url);
|
||||
|
||||
l_req := utl_http.begin_request(p_url);
|
||||
|
||||
l_resp := utl_http.get_response (l_req);
|
||||
|
||||
debug_response (l_resp);
|
||||
|
||||
if l_resp.status_code = utl_http.HTTP_UNAUTHORIZED then
|
||||
|
||||
l_authenticate_with_ntlm := headers_contain_value (l_resp, 'WWW-Authenticate', 'NTLM');
|
||||
|
||||
utl_http.end_response (l_resp);
|
||||
|
||||
if l_authenticate_with_ntlm then
|
||||
|
||||
l_negotiate_message := 'NTLM ' || ntlm_util_pkg.get_negotiate_message(p_username);
|
||||
-- need to send negotiation message
|
||||
|
||||
debug_pkg.printf('Negotiate message: %1', l_negotiate_message);
|
||||
|
||||
------------
|
||||
-- Request 2
|
||||
------------
|
||||
|
||||
debug_pkg.printf(' ');
|
||||
debug_pkg.printf(p_url);
|
||||
l_req := utl_http.begin_request(p_url);
|
||||
utl_http.set_header (l_req, 'Authorization', l_negotiate_message);
|
||||
|
||||
l_resp := utl_http.get_response(l_req);
|
||||
|
||||
debug_response (l_resp);
|
||||
|
||||
if l_resp.status_code = utl_http.HTTP_UNAUTHORIZED then
|
||||
|
||||
-- received server challenge
|
||||
utl_http.get_header_by_name(l_resp, 'WWW-Authenticate', l_value, 1);
|
||||
|
||||
utl_http.end_response(l_resp);
|
||||
|
||||
if substr(l_value, 1, 4) = 'NTLM' then
|
||||
|
||||
-- get value
|
||||
l_value := substr(l_value, 6);
|
||||
|
||||
ntlm_util_pkg.parse_challenge_message (l_value, l_server_challenge, l_negotiate_flags);
|
||||
|
||||
l_authenticate_message := 'NTLM ' || ntlm_util_pkg.get_authenticate_message(p_username, p_password, l_server_challenge, l_negotiate_flags);
|
||||
debug_pkg.printf('Authenticate message: "%1"', l_authenticate_message);
|
||||
|
||||
------------
|
||||
-- Request 3
|
||||
------------
|
||||
|
||||
-- sending NTLM message 3
|
||||
debug_pkg.printf(' ');
|
||||
debug_pkg.printf(p_url);
|
||||
l_req := utl_http.begin_request(p_url);
|
||||
|
||||
utl_http.set_header (l_req, 'Connection', 'close');
|
||||
utl_http.set_header (l_req, 'Authorization', l_authenticate_message);
|
||||
|
||||
l_resp := utl_http.get_response (l_req);
|
||||
|
||||
debug_response (l_resp);
|
||||
|
||||
-- this is already done inside debug_response
|
||||
--l_returnvalue := get_response_body (l_resp);
|
||||
|
||||
utl_http.end_response(l_resp);
|
||||
|
||||
end if;
|
||||
|
||||
end if;
|
||||
|
||||
else
|
||||
debug_pkg.printf('Server is not configured with NTLM security (missing "WWW-Authenticate: NTLM" header).');
|
||||
end if;
|
||||
|
||||
end if;
|
||||
|
||||
|
||||
utl_http.close_persistent_conns;
|
||||
debug_pkg.printf('Persistent connection count (should be zero): %1', utl_http.get_persistent_conn_count);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
|
||||
end get_response_clob;
|
||||
|
||||
|
||||
function begin_request (p_url in varchar2,
|
||||
p_username in varchar2,
|
||||
p_password in varchar2,
|
||||
p_wallet_path in varchar2 := null,
|
||||
p_wallet_password in varchar2 := null,
|
||||
p_proxy_server in varchar2 := null) return varchar2
|
||||
as
|
||||
|
||||
l_method varchar2(255) := 'GET';
|
||||
|
||||
l_req utl_http.req;
|
||||
l_resp utl_http.resp;
|
||||
l_response_body clob;
|
||||
|
||||
l_returnvalue varchar2(2000);
|
||||
|
||||
l_name varchar2(500);
|
||||
l_value varchar2(500);
|
||||
|
||||
l_ntlm_message varchar2(500);
|
||||
l_negotiate_message varchar2(500);
|
||||
l_server_challenge raw(4000);
|
||||
l_negotiate_flags raw(4000);
|
||||
l_authenticate_message varchar2(500);
|
||||
|
||||
|
||||
function get_response_body (p_resp in out utl_http.resp) return clob
|
||||
as
|
||||
l_data string_util_pkg.t_max_pl_varchar2;
|
||||
l_returnvalue clob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get the response body as a clob
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 24.06.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
begin
|
||||
loop
|
||||
utl_http.read_text(r => p_resp, data => l_data);
|
||||
l_returnvalue := l_returnvalue || l_data;
|
||||
end loop;
|
||||
exception
|
||||
when utl_http.end_of_body then
|
||||
null;
|
||||
end;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_response_body;
|
||||
|
||||
|
||||
procedure debug_response (p_resp in out utl_http.resp)
|
||||
as
|
||||
l_name varchar2(255);
|
||||
l_value varchar2(2000);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: print debug info about the response
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 24.06.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
debug_pkg.printf('Response Status Code: %1', p_resp.status_code);
|
||||
|
||||
for i in 1 .. utl_http.get_header_count (p_resp) loop
|
||||
utl_http.get_header (p_resp, i, l_name, l_value);
|
||||
debug_pkg.printf('#%1 %2 : %3', i, l_name, l_value);
|
||||
end loop;
|
||||
|
||||
l_response_body := get_response_body (p_resp);
|
||||
|
||||
debug_pkg.printf('Body length = %1', dbms_lob.getlength (l_response_body));
|
||||
debug_pkg.printf('Persistent connection count: %1', utl_http.get_persistent_conn_count);
|
||||
|
||||
end debug_response;
|
||||
|
||||
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: begin NTLM request
|
||||
|
||||
Remarks: it is assumed that the request will be against an NTLM-protected URL, so the initial request (where the server responds with WWW-Authenticate: NTLM) is skipped
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 24.06.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
utl_http.set_detailed_excp_support (enable => true);
|
||||
utl_http.set_response_error_check (enable => false);
|
||||
|
||||
utl_http.set_persistent_conn_support (true, 10);
|
||||
|
||||
-- support for HTTPS
|
||||
if instr(lower(p_url),'https') = 1 then
|
||||
utl_http.set_wallet (p_wallet_path, p_wallet_password);
|
||||
end if;
|
||||
|
||||
-- support for proxy server
|
||||
if p_proxy_server is not null then
|
||||
utl_http.set_proxy (p_proxy_server);
|
||||
end if;
|
||||
|
||||
|
||||
l_negotiate_message := 'NTLM ' || ntlm_util_pkg.get_negotiate_message (p_username);
|
||||
|
||||
debug_pkg.printf('Negotiate Message: %1', l_negotiate_message);
|
||||
|
||||
------------
|
||||
-- Request 1
|
||||
------------
|
||||
|
||||
debug_pkg.printf(' ');
|
||||
debug_pkg.printf(l_method || ' ' || p_url);
|
||||
|
||||
l_req := utl_http.begin_request (p_url, l_method);
|
||||
utl_http.set_header (l_req, 'Authorization', l_negotiate_message);
|
||||
|
||||
l_resp := utl_http.get_response(l_req);
|
||||
|
||||
debug_response (l_resp);
|
||||
|
||||
if l_resp.status_code = utl_http.http_unauthorized then
|
||||
|
||||
-- received server challenge
|
||||
utl_http.get_header_by_name (l_resp, 'WWW-Authenticate', l_value, 1);
|
||||
utl_http.end_response (l_resp);
|
||||
|
||||
if substr(l_value, 1, 4) = 'NTLM' then
|
||||
|
||||
l_value := substr(l_value, 6);
|
||||
|
||||
ntlm_util_pkg.parse_challenge_message (l_value, l_server_challenge, l_negotiate_flags);
|
||||
l_authenticate_message := 'NTLM ' || ntlm_util_pkg.get_authenticate_message (p_username, p_password, l_server_challenge, l_negotiate_flags);
|
||||
|
||||
debug_pkg.printf('Authenticate Message: "%1"', l_authenticate_message);
|
||||
|
||||
-- this is what needs to be passed as the Authorization header in the next call (and TCP connection must be kept persistent)
|
||||
l_returnvalue := l_authenticate_message;
|
||||
|
||||
end if;
|
||||
|
||||
else
|
||||
|
||||
utl_http.end_response (l_resp);
|
||||
l_returnvalue := null;
|
||||
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end begin_request;
|
||||
|
||||
|
||||
procedure end_request
|
||||
as
|
||||
begin
|
||||
|
||||
|
||||
/*
|
||||
|
||||
Purpose: end NTLM request
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 24.06.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
debug_pkg.printf('Persistent connection count: %1', utl_http.get_persistent_conn_count);
|
||||
utl_http.close_persistent_conns;
|
||||
debug_pkg.printf('Persistent connection count (should be zero): %1', utl_http.get_persistent_conn_count);
|
||||
|
||||
end end_request;
|
||||
|
||||
|
||||
|
||||
end ntlm_http_pkg;
|
||||
/
|
||||
|
||||
42
ora/ntlm_http_pkg.pks
Executable file
42
ora/ntlm_http_pkg.pks
Executable file
@ -0,0 +1,42 @@
|
||||
create or replace package ntlm_http_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles HTTP connections using NTLM authentication
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 03.06.2011 Created
|
||||
MBR 03.06.2011 Troubleshooting, bug fixes, handle persistent connection issues
|
||||
MBR 24.06.2011 Cleaned up code
|
||||
MBR 24.06.2011 Added begin/end_request
|
||||
MBR 25.07.2011 Added support for HTTPS and proxy server
|
||||
|
||||
*/
|
||||
|
||||
-- get clob from url
|
||||
function get_response_clob (p_url in varchar2,
|
||||
p_username in varchar2,
|
||||
p_password in varchar2,
|
||||
p_wallet_path in varchar2 := null,
|
||||
p_wallet_password in varchar2 := null,
|
||||
p_proxy_server in varchar2 := null) return clob;
|
||||
|
||||
-- begin NTLM request
|
||||
function begin_request (p_url in varchar2,
|
||||
p_username in varchar2,
|
||||
p_password in varchar2,
|
||||
p_wallet_path in varchar2 := null,
|
||||
p_wallet_password in varchar2 := null,
|
||||
p_proxy_server in varchar2 := null) return varchar2;
|
||||
|
||||
-- end NTLM request
|
||||
procedure end_request;
|
||||
|
||||
|
||||
end ntlm_http_pkg;
|
||||
/
|
||||
|
||||
938
ora/ntlm_util_pkg.pkb
Executable file
938
ora/ntlm_util_pkg.pkb
Executable file
@ -0,0 +1,938 @@
|
||||
create or replace package body ntlm_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package implements NTLM authentication protocol
|
||||
|
||||
Remarks: A PL/SQL port of the Python code at http://code.google.com/p/python-ntlm/
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 11.05.2011 Created
|
||||
MBR 11.05.2011 Miscellaneous contributions
|
||||
|
||||
*/
|
||||
|
||||
m_NTLM_NegotiateUnicode constant raw(4) := utl_raw.cast_from_binary_integer(1); --'00000001';
|
||||
m_NTLM_NegotiateOEM constant raw(4) := utl_raw.cast_from_binary_integer(2); --'00000002';
|
||||
m_NTLM_RequestTarget constant raw(4) := utl_raw.cast_from_binary_integer(4); --'00000004';
|
||||
m_NTLM_Unknown9 constant raw(4) := utl_raw.cast_from_binary_integer(8); -- '00000008';
|
||||
m_NTLM_NegotiateSign constant raw(4) := utl_raw.cast_from_binary_integer(16); --'00000010';
|
||||
m_NTLM_NegotiateSeal constant raw(4) := utl_raw.cast_from_binary_integer(32); --'00000020';
|
||||
m_NTLM_NegotiateDatagram constant raw(4) := utl_raw.cast_from_binary_integer(64); --'00000040';
|
||||
m_NTLM_NegotiateLanManagerKey constant raw(4) := utl_raw.cast_from_binary_integer(128); --'00000080';
|
||||
m_NTLM_Unknown8 constant raw(4) := utl_raw.cast_from_binary_integer(256); --'00000100';
|
||||
m_NTLM_NegotiateNTLM constant raw(4) := utl_raw.cast_from_binary_integer(512); --'00000200';
|
||||
m_NTLM_NegotiateNTOnly constant raw(4) := utl_raw.cast_from_binary_integer(1024); --'00000400';
|
||||
m_NTLM_Anonymous constant raw(4) := utl_raw.cast_from_binary_integer(2048); --'00000800';
|
||||
m_NTLM_NegotiateOemDomainSuppl constant raw(4) := utl_raw.cast_from_binary_integer(4096); --'00001000';
|
||||
m_NTLM_NegotiateOemWorkstation constant raw(4) := utl_raw.cast_from_binary_integer(8192); --'00002000';
|
||||
m_NTLM_Unknown6 constant raw(4) := utl_raw.cast_from_binary_integer(16384); --'00004000';
|
||||
m_NTLM_NegotiateAlwaysSign constant raw(4) := utl_raw.cast_from_binary_integer(32768); --'00008000';
|
||||
m_NTLM_TargetTypeDomain constant raw(4) := utl_raw.cast_from_binary_integer(65536); --'00010000';
|
||||
m_NTLM_TargetTypeServer constant raw(4) := utl_raw.cast_from_binary_integer(131072); --'00020000';
|
||||
m_NTLM_TargetTypeShare constant raw(4) := utl_raw.cast_from_binary_integer(262144); --'00040000';
|
||||
m_NTLM_NegotiateExtendedSec constant raw(4) := utl_raw.cast_from_binary_integer(524288); --'00080000';
|
||||
m_NTLM_NegotiateIdentify constant raw(4) := utl_raw.cast_from_binary_integer(1048576); --'00100000';
|
||||
m_NTLM_Unknown5 constant raw(4) := utl_raw.cast_from_binary_integer(2097152); --'00200000';
|
||||
m_NTLM_RequestNonNTSessionKey constant raw(4) := utl_raw.cast_from_binary_integer(4194304); --'00400000';
|
||||
m_NTLM_NegotiateTargetInfo constant raw(4) := utl_raw.cast_from_binary_integer(8388608); --'00800000';
|
||||
m_NTLM_Unknown4 constant raw(4) := utl_raw.cast_from_binary_integer(16777216); --'01000000';
|
||||
m_NTLM_NegotiateVersion constant raw(4) := utl_raw.cast_from_binary_integer(33554432); --'02000000';
|
||||
m_NTLM_Unknown3 constant raw(4) := utl_raw.cast_from_binary_integer(67108864); --'04000000';
|
||||
m_NTLM_Unknown2 constant raw(4) := utl_raw.cast_from_binary_integer(134217728); --'08000000';
|
||||
m_NTLM_Unknown1 constant raw(4) := utl_raw.cast_from_binary_integer(268435456); --'10000000';
|
||||
m_NTLM_Negotiate128 constant raw(4) := utl_raw.cast_from_binary_integer(536870912); --'20000000';
|
||||
m_NTLM_NegotiateKeyExchange constant raw(4) := utl_raw.cast_from_binary_integer(1073741824); --'40000000';
|
||||
m_NTLM_Negotiate56 constant raw(4) := utl_raw.cast_from_binary_integer(128, utl_raw.little_endian); -- '80000000'; -- using little endian instead of big beacuse utl_raw.cast_from_binary_integer(2147483648) results in overflow
|
||||
|
||||
|
||||
function bit_or_multi (p_raw1 in raw,
|
||||
p_raw2 in raw,
|
||||
p_raw3 in raw := null,
|
||||
p_raw4 in raw := null,
|
||||
p_raw5 in raw := null,
|
||||
p_raw6 in raw := null,
|
||||
p_raw7 in raw := null,
|
||||
p_raw8 in raw := null,
|
||||
p_raw9 in raw := null,
|
||||
p_raw10 in raw := null,
|
||||
p_raw11 in raw := null,
|
||||
p_raw12 in raw := null) return raw
|
||||
as
|
||||
l_returnvalue raw(5000);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Perform bitwise OR operations on multiple RAWs
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 12.05.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := utl_raw.bit_or(p_raw1, p_raw2);
|
||||
|
||||
if p_raw3 is not null then
|
||||
l_returnvalue := utl_raw.bit_or(l_returnvalue, p_raw3);
|
||||
end if;
|
||||
|
||||
if p_raw4 is not null then
|
||||
l_returnvalue := utl_raw.bit_or(l_returnvalue, p_raw4);
|
||||
end if;
|
||||
|
||||
if p_raw5 is not null then
|
||||
l_returnvalue := utl_raw.bit_or(l_returnvalue, p_raw5);
|
||||
end if;
|
||||
|
||||
if p_raw6 is not null then
|
||||
l_returnvalue := utl_raw.bit_or(l_returnvalue, p_raw6);
|
||||
end if;
|
||||
|
||||
if p_raw7 is not null then
|
||||
l_returnvalue := utl_raw.bit_or(l_returnvalue, p_raw7);
|
||||
end if;
|
||||
|
||||
if p_raw8 is not null then
|
||||
l_returnvalue := utl_raw.bit_or(l_returnvalue, p_raw8);
|
||||
end if;
|
||||
|
||||
if p_raw9 is not null then
|
||||
l_returnvalue := utl_raw.bit_or(l_returnvalue, p_raw9);
|
||||
end if;
|
||||
|
||||
if p_raw10 is not null then
|
||||
l_returnvalue := utl_raw.bit_or(l_returnvalue, p_raw10);
|
||||
end if;
|
||||
|
||||
if p_raw11 is not null then
|
||||
l_returnvalue := utl_raw.bit_or(l_returnvalue, p_raw11);
|
||||
end if;
|
||||
|
||||
if p_raw12 is not null then
|
||||
l_returnvalue := utl_raw.bit_or(l_returnvalue, p_raw12);
|
||||
end if;
|
||||
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end bit_or_multi;
|
||||
|
||||
|
||||
function int_to_raw_little_endian (p_number in number,
|
||||
p_length in number) return raw
|
||||
as
|
||||
l_returnvalue raw(5000);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Returning little endian value of integer of specified length
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 12.05.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := utl_raw.substr(utl_raw.cast_from_binary_integer(p_number, utl_raw.little_endian), 1, p_length);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end int_to_raw_little_endian;
|
||||
|
||||
|
||||
function get_workstation_name return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_db_varchar2;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Get workstation name for executing user
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 12.05.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
--l_returnvalue := sys_context('USERENV', 'TERMINAL');
|
||||
l_returnvalue := upper(sys_context('USERENV', 'server_host'));
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_workstation_name;
|
||||
|
||||
|
||||
procedure parse_username (p_username in varchar2,
|
||||
p_domain out varchar2,
|
||||
p_user out varchar2)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Parse username as domain\user
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 12.05.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
if instr(p_username, '\') > 0 then
|
||||
p_domain := upper (substr(p_username, 1, instr(p_username, '\')-1));
|
||||
p_user := substr(p_username, instr(p_username, '\') + 1, length(p_username) - instr(p_username, '\') + 1);
|
||||
else
|
||||
p_domain := null;
|
||||
p_user := p_username;
|
||||
end if;
|
||||
|
||||
end parse_username;
|
||||
|
||||
|
||||
function get_negotiate_message (p_username in varchar2) return varchar2
|
||||
as
|
||||
|
||||
l_body_length number;
|
||||
l_payload_start number;
|
||||
|
||||
l_domain_str varchar2(500);
|
||||
l_user_str varchar2(500);
|
||||
|
||||
--l_protocol raw(8);
|
||||
l_protocol raw(16);
|
||||
l_workstation raw(16);
|
||||
l_domain raw(16);
|
||||
|
||||
l_type raw(4);
|
||||
l_flags raw(4);
|
||||
|
||||
l_workstation_length raw(2);
|
||||
l_workstation_max_length raw(2);
|
||||
l_workstation_buffer_offset raw(4);
|
||||
|
||||
l_domain_length raw(2);
|
||||
l_domain_max_length raw(2);
|
||||
l_domain_buffer_offset raw(4);
|
||||
|
||||
l_product_major_version raw(1);
|
||||
l_product_minor_version raw(1);
|
||||
l_product_build raw(2);
|
||||
|
||||
l_version_reserved1 raw(1);
|
||||
l_version_reserved2 raw(1);
|
||||
l_version_reserved3 raw(1);
|
||||
|
||||
l_ntlm_revision_current raw(1);
|
||||
|
||||
l_return raw(100);
|
||||
|
||||
l_returnvalue string_util_pkg.t_max_pl_varchar2;
|
||||
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Get negotiate message
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 12.05.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_body_length := 40;
|
||||
l_payload_start := l_body_length;
|
||||
|
||||
--l_protocol := utl_raw.cast_to_raw('NTLMSSP' || chr(256));
|
||||
l_protocol := utl_raw.cast_to_raw('NTLMSSP' || chr(0));
|
||||
|
||||
l_type := int_to_raw_little_endian(1, 4); --- Type 1
|
||||
|
||||
l_flags := bit_or_multi (m_NTLM_NegotiateUnicode,
|
||||
m_NTLM_NegotiateOEM,
|
||||
m_NTLM_RequestTarget,
|
||||
m_NTLM_NegotiateNTLM,
|
||||
m_NTLM_NegotiateOemDomainSuppl,
|
||||
m_NTLM_NegotiateOemWorkstation,
|
||||
m_NTLM_NegotiateAlwaysSign,
|
||||
m_NTLM_NegotiateExtendedSec,
|
||||
m_NTLM_NegotiateVersion,
|
||||
m_NTLM_Negotiate128,
|
||||
m_NTLM_Negotiate56);
|
||||
|
||||
-- need to convert flags to little endian
|
||||
l_flags := int_to_raw_little_endian (utl_raw.cast_to_binary_integer(l_flags), 4);
|
||||
|
||||
l_workstation := utl_raw.cast_to_raw(get_workstation_name);
|
||||
parse_username (p_username, l_domain_str, l_user_str);
|
||||
l_domain := utl_raw.cast_to_raw(l_domain_str);
|
||||
|
||||
l_workstation_length := int_to_raw_little_endian (utl_raw.length(l_workstation), 2);
|
||||
l_workstation_max_length := int_to_raw_little_endian (utl_raw.length(l_workstation), 2);
|
||||
l_workstation_buffer_offset := int_to_raw_little_endian (l_payload_start, 4);
|
||||
|
||||
l_payload_start := l_payload_start + utl_raw.length (l_workstation);
|
||||
|
||||
l_domain_length := int_to_raw_little_endian (utl_raw.length(l_domain), 2);
|
||||
l_domain_max_length := int_to_raw_little_endian (utl_raw.length(l_domain), 2);
|
||||
l_domain_buffer_offset := int_to_raw_little_endian (l_payload_start, 4);
|
||||
|
||||
l_payload_start := l_payload_start + utl_raw.length(l_domain);
|
||||
|
||||
l_product_major_version := int_to_raw_little_endian (5, 1);
|
||||
l_product_minor_version := int_to_raw_little_endian (1, 1);
|
||||
l_product_build := int_to_raw_little_endian (2600, 2);
|
||||
|
||||
l_version_reserved1 := int_to_raw_little_endian (0, 1);
|
||||
l_version_reserved2 := int_to_raw_little_endian (0, 1);
|
||||
l_version_reserved3 := int_to_raw_little_endian (0, 1);
|
||||
|
||||
l_ntlm_revision_current := int_to_raw_little_endian (15, 1);
|
||||
|
||||
l_return := utl_raw.concat(l_protocol,
|
||||
l_type,
|
||||
l_flags,
|
||||
l_domain_length,
|
||||
l_domain_max_length,
|
||||
l_domain_buffer_offset,
|
||||
l_workstation_length,
|
||||
l_workstation_max_length,
|
||||
l_workstation_buffer_offset,
|
||||
l_product_major_version,
|
||||
l_product_minor_version,
|
||||
l_product_build);
|
||||
|
||||
l_return := utl_raw.concat(l_return,
|
||||
l_version_reserved1,
|
||||
l_version_reserved2,
|
||||
l_version_reserved3,
|
||||
l_ntlm_revision_current);
|
||||
|
||||
if utl_raw.length (l_return) <> l_body_length then
|
||||
raise_application_error(-20000, 'Length of negotiate message is ' || utl_raw.length(l_return) || ' (should be ' || l_body_length ||')');
|
||||
end if;
|
||||
|
||||
l_return := utl_raw.concat (l_return, l_workstation, l_domain);
|
||||
|
||||
l_returnvalue := utl_raw.cast_to_varchar2(l_return);
|
||||
l_returnvalue := encode_util_pkg.str_to_base64(l_returnvalue);
|
||||
l_returnvalue := replace(l_returnvalue, chr(13) || chr(10), '');
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_negotiate_message;
|
||||
|
||||
|
||||
procedure parse_challenge_message (p_message2 in varchar2,
|
||||
p_server_challenge out raw,
|
||||
p_negotiate_flags out raw)
|
||||
as
|
||||
l_message string_util_pkg.t_max_pl_varchar2;
|
||||
|
||||
l_msg raw(4000);
|
||||
|
||||
l_signature raw(8);
|
||||
l_msg_type raw(4);
|
||||
|
||||
l_target_name_length raw(2);
|
||||
l_target_name_maxlength raw(2);
|
||||
l_target_name_offset raw(4);
|
||||
|
||||
l_target_name raw(100);
|
||||
|
||||
l_negotiate_flags raw(4);
|
||||
|
||||
l_server_challenge raw(8);
|
||||
l_reserved raw(8);
|
||||
|
||||
l_target_info_length raw(2);
|
||||
l_target_info_maxlength raw(2);
|
||||
l_target_info_offset raw(4);
|
||||
|
||||
l_target_info raw(100);
|
||||
|
||||
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Parse challenge message from server
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 31.05.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_msg := utl_encode.base64_decode(utl_raw.cast_to_raw(p_message2));
|
||||
|
||||
l_signature := utl_raw.substr(l_msg, 1, 8);
|
||||
l_msg_type := utl_raw.substr(l_msg, 9, 4);
|
||||
|
||||
l_target_name_length := utl_raw.substr(l_msg, 13, 2);
|
||||
l_target_name_maxlength := utl_raw.substr(l_msg, 15, 2);
|
||||
l_target_name_offset := utl_raw.substr(l_msg, 17, 4);
|
||||
|
||||
-- using reverse because the flags are in little endian order?
|
||||
l_negotiate_flags := utl_raw.reverse(utl_raw.substr(l_msg, 21, 4));
|
||||
--l_negotiate_flags := utl_raw.substr(l_msg, 21, 4);
|
||||
|
||||
l_server_challenge := utl_raw.substr(l_msg, 25, 8);
|
||||
l_reserved := utl_raw.substr(l_msg, 33, 8);
|
||||
|
||||
l_target_info_length := utl_raw.substr(l_msg, 41, 2);
|
||||
l_target_info_maxlength := utl_raw.substr(l_msg, 43, 2);
|
||||
l_target_info_offset := utl_raw.substr(l_msg, 45, 4);
|
||||
|
||||
debug_pkg.printf('Signature: "%1", Message Type: "%2", Negotiate Flags: "%3", Server Challenge: "%4"', l_signature, l_msg_type, l_negotiate_flags, l_server_challenge);
|
||||
|
||||
p_server_challenge := l_server_challenge;
|
||||
p_negotiate_flags := l_negotiate_flags;
|
||||
|
||||
end parse_challenge_message;
|
||||
|
||||
|
||||
function create_des_key (p_bytes in raw) return raw
|
||||
as
|
||||
l_byte1 raw(1);
|
||||
l_byte2 raw(1);
|
||||
l_byte3 raw(1);
|
||||
l_byte4 raw(1);
|
||||
l_byte5 raw(1);
|
||||
l_byte6 raw(1);
|
||||
l_byte7 raw(1);
|
||||
l_byte8 raw(1);
|
||||
l_returnvalue raw(8);
|
||||
|
||||
function raw2num(p_raw in raw) return number
|
||||
is
|
||||
begin
|
||||
return utl_raw.cast_to_binary_integer(p_raw, utl_raw.little_endian);
|
||||
end;
|
||||
|
||||
function get_8bit_mask return raw
|
||||
as
|
||||
begin
|
||||
return utl_raw.cast_from_binary_integer(255, utl_raw.little_endian);
|
||||
end get_8bit_mask;
|
||||
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: create an 8-byte DES key from a 7-byte key
|
||||
|
||||
Remarks: insert a null bit after every seven bits (so 1010100 becomes 01010100)
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 03.06.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
raw_util_pkg.set_endianness (utl_raw.little_endian);
|
||||
|
||||
--debug_pkg.printf('input byte 1 = %1', raw2num(utl_raw.substr(p_bytes, 1, 1)));
|
||||
--debug_pkg.printf('input byte 2 = %1', raw2num(utl_raw.substr(p_bytes, 2, 1)));
|
||||
--debug_pkg.printf('input byte 3 = %1', raw2num(utl_raw.substr(p_bytes, 3, 1)));
|
||||
--debug_pkg.printf('input byte 4 = %1', raw2num(utl_raw.substr(p_bytes, 4, 1)));
|
||||
--debug_pkg.printf('input byte 5 = %1', raw2num(utl_raw.substr(p_bytes, 5, 1)));
|
||||
--debug_pkg.printf('input byte 6 = %1', raw2num(utl_raw.substr(p_bytes, 6, 1)));
|
||||
--debug_pkg.printf('input byte 7 = %1', raw2num(utl_raw.substr(p_bytes, 7, 1)));
|
||||
|
||||
l_byte1 := utl_raw.substr(p_bytes, 1, 1);
|
||||
l_byte2 := utl_raw.substr( utl_raw.bit_or(utl_raw.bit_and(raw_util_pkg.bit_shift_left_raw (utl_raw.substr(p_bytes, 1, 1), 7), get_8bit_mask), raw_util_pkg.bit_shift_right_raw (utl_raw.substr(p_bytes, 2, 1), 1)) , 1, 1);
|
||||
l_byte3 := utl_raw.substr( utl_raw.bit_or(utl_raw.bit_and(raw_util_pkg.bit_shift_left_raw (utl_raw.substr(p_bytes, 2, 1), 6), get_8bit_mask), raw_util_pkg.bit_shift_right_raw (utl_raw.substr(p_bytes, 3, 1), 2)) , 1, 1);
|
||||
l_byte4 := utl_raw.substr( utl_raw.bit_or(utl_raw.bit_and(raw_util_pkg.bit_shift_left_raw (utl_raw.substr(p_bytes, 3, 1), 5), get_8bit_mask), raw_util_pkg.bit_shift_right_raw (utl_raw.substr(p_bytes, 4, 1), 3)) , 1, 1);
|
||||
l_byte5 := utl_raw.substr( utl_raw.bit_or(utl_raw.bit_and(raw_util_pkg.bit_shift_left_raw (utl_raw.substr(p_bytes, 4, 1), 4), get_8bit_mask), raw_util_pkg.bit_shift_right_raw (utl_raw.substr(p_bytes, 5, 1), 4)) , 1, 1);
|
||||
l_byte6 := utl_raw.substr( utl_raw.bit_or(utl_raw.bit_and(raw_util_pkg.bit_shift_left_raw (utl_raw.substr(p_bytes, 5, 1), 3), get_8bit_mask), raw_util_pkg.bit_shift_right_raw (utl_raw.substr(p_bytes, 6, 1), 5)) , 1, 1);
|
||||
l_byte7 := utl_raw.substr( utl_raw.bit_or(utl_raw.bit_and(raw_util_pkg.bit_shift_left_raw (utl_raw.substr(p_bytes, 6, 1), 2), get_8bit_mask), raw_util_pkg.bit_shift_right_raw (utl_raw.substr(p_bytes, 7, 1), 6)) , 1, 1);
|
||||
l_byte8 := utl_raw.substr( utl_raw.bit_and (raw_util_pkg.bit_shift_left_raw (utl_raw.substr(p_bytes, 7, 1), 1), get_8bit_mask), 1, 1);
|
||||
|
||||
--debug_pkg.printf('output byte 1 = %1', raw2num(l_byte1));
|
||||
--debug_pkg.printf('output byte 2 = %1', raw2num(l_byte2));
|
||||
--debug_pkg.printf('output byte 3 = %1', raw2num(l_byte3));
|
||||
--debug_pkg.printf('output byte 4 = %1', raw2num(l_byte4));
|
||||
--debug_pkg.printf('output byte 5 = %1', raw2num(l_byte5));
|
||||
--debug_pkg.printf('output byte 6 = %1', raw2num(l_byte6));
|
||||
--debug_pkg.printf('output byte 7 = %1', raw2num(l_byte7));
|
||||
--debug_pkg.printf('output byte 8 = %1', raw2num(l_byte8));
|
||||
|
||||
l_returnvalue := utl_raw.concat (l_byte1, l_byte2, l_byte3, l_byte4, l_byte5, l_byte6, l_byte7, l_byte8);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end create_des_key;
|
||||
|
||||
|
||||
function get_lm_hashed_password_v1 (p_password in raw) return raw
|
||||
as
|
||||
|
||||
-- http://en.wikipedia.org/wiki/LM_hash - "The DES CipherMode should be set to ECB, and PaddingMode should be set to NONE."
|
||||
l_algorithm constant pls_integer := dbms_crypto.encrypt_des + dbms_crypto.chain_ecb + dbms_crypto.pad_none;
|
||||
|
||||
l_user_pw_length pls_integer;
|
||||
l_lm_password raw(255);
|
||||
l_magic_str constant raw(20) := utl_raw.cast_to_raw('KGS!@#$%'); -- page 57 in [MS-NLMP]
|
||||
|
||||
l_low_key raw(8);
|
||||
l_high_key raw(8);
|
||||
l_low_hash raw(255);
|
||||
l_high_hash raw(255);
|
||||
|
||||
l_returnvalue raw(2000);
|
||||
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: create LanManager (LM) hashed password
|
||||
|
||||
Remarks: see http://en.wikipedia.org/wiki/LM_hash#Algorithm
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 03.06.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_lm_password := p_password;
|
||||
|
||||
--debug_pkg.printf('user password byte 1 = %1', utl_raw.cast_to_varchar2(utl_raw.substr(l_lm_password, 1, 1)));
|
||||
|
||||
l_user_pw_length := utl_raw.length (l_lm_password);
|
||||
--debug_pkg.printf('user password byte length = %1', l_user_pw_length);
|
||||
|
||||
-- pad the password length to 14 bytes
|
||||
if l_user_pw_length < 14 then
|
||||
for i in 1..(14-l_user_pw_length) loop
|
||||
l_lm_password := utl_raw.concat(l_lm_password, hextoraw('0'));
|
||||
end loop;
|
||||
end if;
|
||||
--debug_pkg.printf('new byte length = %1', utl_raw.length (l_lm_password));
|
||||
l_lm_password := utl_raw.substr(l_lm_password, 1, 14);
|
||||
|
||||
-- do hash
|
||||
l_low_key := create_des_key (utl_raw.substr(l_lm_password, 1, 7));
|
||||
l_high_key := create_des_key (utl_raw.substr(l_lm_password, 8, 7));
|
||||
l_low_hash := dbms_crypto.encrypt (l_magic_str, l_algorithm, l_low_key);
|
||||
l_high_hash := dbms_crypto.encrypt (l_magic_str, l_algorithm, l_high_key);
|
||||
|
||||
l_returnvalue := utl_raw.concat (l_low_hash, l_high_hash);
|
||||
--debug_pkg.printf('LM hashed password returnvalue (base64 encoded for readability) = %1', utl_raw.cast_to_varchar2(utl_encode.base64_encode(l_returnvalue)));
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_lm_hashed_password_v1;
|
||||
|
||||
|
||||
function get_nt_hashed_password_v1 (p_password in varchar2) return raw
|
||||
|
||||
as
|
||||
l_returnvalue raw(4000);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Get NT hashed password
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 01.06.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := dbms_crypto.hash(utl_raw.cast_to_raw(convert (p_password, 'AL16UTF16LE')), dbms_crypto.HASH_MD4);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_nt_hashed_password_v1;
|
||||
|
||||
|
||||
function get_nt_hashed_password_v2 (p_password in varchar2,
|
||||
p_user in varchar2,
|
||||
p_domain in varchar2) return raw
|
||||
|
||||
as
|
||||
l_returnvalue raw(4000);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Get NT hashed password
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 01.06.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := get_nt_hashed_password_v1 (p_password);
|
||||
|
||||
l_returnvalue := dbms_crypto.mac(utl_raw.cast_to_raw(convert(upper(p_user) || p_domain, 'AL16UTF16LE')), dbms_crypto.HMAC_MD5, l_returnvalue);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_nt_hashed_password_v2;
|
||||
|
||||
|
||||
function get_response (p_password_hash in raw,
|
||||
p_server_challenge in raw) return raw
|
||||
as
|
||||
l_raw raw(21);
|
||||
l_password_hash_length pls_integer;
|
||||
l_password_hash raw(21);
|
||||
l_server_challenge raw(8);
|
||||
|
||||
l_hash1 raw(8);
|
||||
l_hash2 raw(8);
|
||||
l_hash3 raw(8);
|
||||
|
||||
l_algorithm constant pls_integer := dbms_crypto.encrypt_des + dbms_crypto.chain_ecb + dbms_crypto.pad_none;
|
||||
|
||||
l_returnvalue raw (24);
|
||||
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get LM response
|
||||
|
||||
Remarks: generates the LM response given a 16-byte password hash and
|
||||
the 8 byte server challenge from the Type-2 message
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 01.06.2011 Created
|
||||
MBR 16.06.2011 Fixed padding
|
||||
|
||||
*/
|
||||
|
||||
l_password_hash_length := utl_raw.length (p_password_hash);
|
||||
--debug_pkg.printf('get_response: password hash length = %1', l_password_hash_length);
|
||||
|
||||
if l_password_hash_length < 21 then
|
||||
l_password_hash := utl_raw.substr(p_password_hash, 1, least(21, l_password_hash_length));
|
||||
for i in 1..(21-l_password_hash_length) loop
|
||||
l_password_hash := utl_raw.concat(l_password_hash, hextoraw('0'));
|
||||
end loop;
|
||||
end if;
|
||||
|
||||
--debug_pkg.printf('new byte length = %1', utl_raw.length (l_password_hash));
|
||||
|
||||
l_password_hash := utl_raw.substr(l_password_hash, 1, 21);
|
||||
|
||||
l_server_challenge := utl_raw.substr(p_server_challenge, 1, 8);
|
||||
|
||||
l_hash1 := dbms_crypto.encrypt(l_server_challenge, l_algorithm, create_des_key(utl_raw.substr(l_password_hash, 1, 7)));
|
||||
l_hash2 := dbms_crypto.encrypt(l_server_challenge, l_algorithm, create_des_key(utl_raw.substr(l_password_hash, 8, 7)));
|
||||
l_hash3 := dbms_crypto.encrypt(l_server_challenge, l_algorithm, create_des_key(utl_raw.substr(l_password_hash, 15, 7)));
|
||||
|
||||
l_returnvalue := utl_raw.concat(l_hash1, l_hash2, l_hash3);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_response;
|
||||
|
||||
|
||||
procedure calc_response_2sr (p_password_hash in raw,
|
||||
p_server_challenge in raw,
|
||||
p_nt_challenge out raw,
|
||||
p_lm_challenge out raw)
|
||||
as
|
||||
l_client_challenge raw(16);
|
||||
l_sess raw(4000);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Calculate response for extended security
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 06.06.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_client_challenge := hextoraw('AAAAAAAAAAAAAAAA');
|
||||
--l_client_challenge := hextoraw('39e3f4cd59c5d860');
|
||||
--l_client_challenge := hextoraw('5487e2f40422146a');
|
||||
|
||||
-- generating random client challenge of 16 bytes
|
||||
--l_client_challenge := utl_raw.concat(utl_raw.cast_from_binary_integer(floor(dbms_random.value(1, 2147483648))), utl_raw.cast_from_binary_integer(floor(dbms_random.value(1, 2147483648))));
|
||||
|
||||
p_lm_challenge := utl_raw.concat (l_client_challenge, hextoraw('00000000000000000000000000000000'));
|
||||
l_sess := dbms_crypto.hash(utl_raw.concat(p_server_challenge, l_client_challenge), dbms_crypto.HASH_MD5);
|
||||
|
||||
p_nt_challenge := get_response (p_password_hash, utl_raw.substr(l_sess, 1, 8));
|
||||
debug_pkg.printf('Challenge: "%3", NT: "%1", LM: ="%2", Sess: "%4", Client Challenge: "%5"', p_nt_challenge, p_lm_challenge, utl_raw.concat(p_server_challenge, p_lm_challenge), l_sess, l_client_challenge);
|
||||
|
||||
end calc_response_2sr;
|
||||
|
||||
|
||||
function get_authenticate_message (p_username in varchar2,
|
||||
p_password in varchar2,
|
||||
p_server_challenge in raw,
|
||||
p_negotiate_flags in raw) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_pl_varchar2;
|
||||
|
||||
l_body_length number;
|
||||
l_payload_start number;
|
||||
|
||||
l_is_unicode boolean;
|
||||
l_negotiate_ext_sec boolean;
|
||||
|
||||
l_workstation_str varchar2(500);
|
||||
l_domain_str varchar2(500);
|
||||
l_user_str varchar2(500);
|
||||
|
||||
--l_protocol raw(8);
|
||||
l_protocol raw(16);
|
||||
l_workstation raw(32);
|
||||
l_domain raw(32);
|
||||
l_username raw(32); -- was: raw(16)
|
||||
|
||||
l_password_hash raw(32);
|
||||
l_client_challenge raw(8);
|
||||
|
||||
l_type raw(4);
|
||||
l_flags raw(4);
|
||||
|
||||
l_workstation_length raw(2);
|
||||
l_workstation_max_length raw(2);
|
||||
l_workstation_buffer_offset raw(4);
|
||||
|
||||
l_domain_length raw(2);
|
||||
l_domain_max_length raw(2);
|
||||
l_domain_buffer_offset raw(4);
|
||||
|
||||
l_username_length raw(2);
|
||||
l_username_max_length raw(2);
|
||||
l_username_buffer_offset raw(4);
|
||||
|
||||
l_lm_challenge_response raw(100);
|
||||
l_nt_challenge_response raw(100);
|
||||
l_enc_rand_session_key raw(100);
|
||||
|
||||
l_lm_challenge_length raw(2);
|
||||
l_lm_challenge_max_length raw(2);
|
||||
l_lm_challenge_buffer_offset raw(4);
|
||||
|
||||
l_nt_challenge_length raw(2);
|
||||
l_nt_challenge_max_length raw(2);
|
||||
l_nt_challenge_buffer_offset raw(4);
|
||||
|
||||
l_encrandsesskey_length raw(2);
|
||||
l_encrandsesskey_max_length raw(2);
|
||||
l_encrandsesskey_buffer_offset raw(4);
|
||||
|
||||
l_product_major_version raw(1);
|
||||
l_product_minor_version raw(1);
|
||||
l_product_build raw(2);
|
||||
|
||||
l_version_reserved1 raw(1);
|
||||
l_version_reserved2 raw(1);
|
||||
l_version_reserved3 raw(1);
|
||||
|
||||
l_ntlm_revision_current raw(1);
|
||||
|
||||
l_return raw(2000);
|
||||
|
||||
l_lm_hashed_password raw(2000);
|
||||
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Get authenticate (type 3) message
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 01.06.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_body_length := 72;
|
||||
l_payload_start := l_body_length;
|
||||
|
||||
parse_username (p_username, l_domain_str, l_user_str);
|
||||
l_workstation_str := get_workstation_name;
|
||||
|
||||
debug_pkg.printf('username = %1, domain = %2, workstation = %3', l_user_str, l_domain_str, l_workstation_str);
|
||||
|
||||
l_flags := bit_or_multi (m_NTLM_NegotiateUnicode,
|
||||
m_NTLM_RequestTarget,
|
||||
m_NTLM_NegotiateNTLM,
|
||||
m_NTLM_NegotiateAlwaysSign,
|
||||
m_NTLM_NegotiateExtendedSec,
|
||||
m_NTLM_NegotiateTargetInfo,
|
||||
m_NTLM_NegotiateVersion,
|
||||
m_NTLM_Negotiate128,
|
||||
m_NTLM_Negotiate56);
|
||||
|
||||
-- need to convert flags to little endian
|
||||
l_flags := int_to_raw_little_endian(utl_raw.cast_to_binary_integer(l_flags), 4);
|
||||
|
||||
l_lm_challenge_response := get_response (get_lm_hashed_password_v1(utl_raw.cast_to_raw(upper(p_password))), p_server_challenge);
|
||||
l_nt_challenge_response := get_response (get_nt_hashed_password_v1(p_password), p_server_challenge);
|
||||
l_enc_rand_session_key := null;
|
||||
|
||||
if utl_raw.bit_and (p_negotiate_flags, m_NTLM_NegotiateUnicode) = m_NTLM_NegotiateUnicode then
|
||||
l_is_unicode := true;
|
||||
else
|
||||
l_is_unicode := false;
|
||||
end if;
|
||||
|
||||
if utl_raw.bit_and (p_negotiate_flags, m_NTLM_NegotiateExtendedSec) = m_NTLM_NegotiateExtendedSec then
|
||||
l_negotiate_ext_sec := true;
|
||||
else
|
||||
l_negotiate_ext_sec := false;
|
||||
end if;
|
||||
|
||||
if l_is_unicode then
|
||||
--debug_pkg.printf('l_is_unicode is TRUE...');
|
||||
l_workstation_str := convert (l_workstation_str, 'AL16UTF16LE');
|
||||
l_domain_str := convert (l_domain_str, 'AL16UTF16LE');
|
||||
l_user_str := convert (l_user_str, 'AL16UTF16LE');
|
||||
--l_enc_rand_session_key := convert (utl_raw.cast_to_varchar2(l_enc_rand_session_key), 'AL16UTF16LE');
|
||||
end if;
|
||||
|
||||
if l_negotiate_ext_sec then
|
||||
l_password_hash := get_nt_hashed_password_v1 (p_password);
|
||||
calc_response_2sr (l_password_hash, p_server_challenge, l_nt_challenge_response, l_lm_challenge_response);
|
||||
end if;
|
||||
|
||||
--l_protocol := utl_raw.cast_to_raw('NTLMSSP' || chr(256));
|
||||
l_protocol := utl_raw.cast_to_raw('NTLMSSP' || chr(0));
|
||||
l_type := int_to_raw_little_endian(3, 4); --- Type 3
|
||||
|
||||
l_workstation := utl_raw.cast_to_raw(l_workstation_str);
|
||||
l_domain := utl_raw.cast_to_raw(l_domain_str);
|
||||
l_username := utl_raw.cast_to_raw(l_user_str);
|
||||
|
||||
l_domain_length := int_to_raw_little_endian(utl_raw.length(l_domain), 2);
|
||||
l_domain_max_length := int_to_raw_little_endian(utl_raw.length(l_domain), 2);
|
||||
l_domain_buffer_offset := int_to_raw_little_endian(l_payload_start, 4);
|
||||
l_payload_start := l_payload_start + utl_raw.length(l_domain);
|
||||
|
||||
l_username_length := int_to_raw_little_endian(utl_raw.length(l_username), 2);
|
||||
l_username_max_length := int_to_raw_little_endian(utl_raw.length(l_username), 2);
|
||||
l_username_buffer_offset := int_to_raw_little_endian(l_payload_start, 4);
|
||||
l_payload_start := l_payload_start + utl_raw.length(l_username);
|
||||
|
||||
l_workstation_length := int_to_raw_little_endian(utl_raw.length(l_workstation), 2);
|
||||
l_workstation_max_length := int_to_raw_little_endian(utl_raw.length(l_workstation), 2);
|
||||
l_workstation_buffer_offset := int_to_raw_little_endian(l_payload_start, 4);
|
||||
l_payload_start := l_payload_start + utl_raw.length(l_workstation);
|
||||
|
||||
l_lm_challenge_length := int_to_raw_little_endian(utl_raw.length(l_lm_challenge_response), 2);
|
||||
l_lm_challenge_max_length := int_to_raw_little_endian(utl_raw.length(l_lm_challenge_response), 2);
|
||||
l_lm_challenge_buffer_offset := int_to_raw_little_endian(l_payload_start, 4);
|
||||
l_payload_start := l_payload_start + utl_raw.length(l_lm_challenge_response);
|
||||
|
||||
l_nt_challenge_length := int_to_raw_little_endian(utl_raw.length(l_nt_challenge_response), 2);
|
||||
l_nt_challenge_max_length := int_to_raw_little_endian(utl_raw.length(l_nt_challenge_response), 2);
|
||||
l_nt_challenge_buffer_offset := int_to_raw_little_endian(l_payload_start, 4);
|
||||
l_payload_start := l_payload_start + utl_raw.length(l_nt_challenge_response);
|
||||
|
||||
--l_encrandsesskey_length := int_to_raw_little_endian(utl_raw.length(l_enc_rand_session_key), 2);
|
||||
l_encrandsesskey_length := int_to_raw_little_endian(0, 2);
|
||||
--l_encrandsesskey_max_length := int_to_raw_little_endian(utl_raw.length(l_enc_rand_session_key), 2);
|
||||
l_encrandsesskey_max_length := int_to_raw_little_endian(0, 2);
|
||||
l_encrandsesskey_buffer_offset := int_to_raw_little_endian(l_payload_start, 4);
|
||||
--l_payload_start := l_payload_start + utl_raw.length(l_enc_rand_session_key);
|
||||
l_payload_start := l_payload_start + 0;
|
||||
|
||||
l_product_major_version := int_to_raw_little_endian(5, 1);
|
||||
l_product_minor_version := int_to_raw_little_endian(1, 1);
|
||||
l_product_build := int_to_raw_little_endian(2600, 2);
|
||||
|
||||
l_version_reserved1 := int_to_raw_little_endian(0, 1);
|
||||
l_version_reserved2 := int_to_raw_little_endian(0, 1);
|
||||
l_version_reserved3 := int_to_raw_little_endian(0, 1);
|
||||
|
||||
l_ntlm_revision_current := int_to_raw_little_endian(15, 1);
|
||||
|
||||
l_return := utl_raw.concat(l_protocol,
|
||||
l_type,
|
||||
l_lm_challenge_length,
|
||||
l_lm_challenge_max_length,
|
||||
l_lm_challenge_buffer_offset,
|
||||
l_nt_challenge_length,
|
||||
l_nt_challenge_max_length,
|
||||
l_nt_challenge_buffer_offset,
|
||||
l_domain_length,
|
||||
l_domain_max_length,
|
||||
l_domain_buffer_offset);
|
||||
|
||||
l_return := utl_raw.concat (l_return,
|
||||
l_username_length,
|
||||
l_username_max_length,
|
||||
l_username_buffer_offset,
|
||||
l_workstation_length,
|
||||
l_workstation_max_length,
|
||||
l_workstation_buffer_offset,
|
||||
l_encrandsesskey_length,
|
||||
l_encrandsesskey_max_length,
|
||||
l_encrandsesskey_buffer_offset);
|
||||
|
||||
l_return := utl_raw.concat (l_return,
|
||||
l_flags,
|
||||
l_product_major_version,
|
||||
l_product_minor_version,
|
||||
l_product_build,
|
||||
l_version_reserved1,
|
||||
l_version_reserved2,
|
||||
l_version_reserved3,
|
||||
l_ntlm_revision_current);
|
||||
|
||||
if utl_raw.length (l_return) <> l_body_length then
|
||||
raise_application_error (-20000, 'Length of authenticate message is ' || utl_raw.length(l_return) || ' (should be ' || l_body_length ||')');
|
||||
end if;
|
||||
|
||||
--l_return := utl_raw.concat (l_return, l_domain, l_username, l_workstation, l_lm_challenge_response, l_nt_challenge_response, l_enc_rand_session_key);
|
||||
--l_return := utl_raw.concat (l_return, l_domain, l_username, l_workstation, l_lm_challenge_response, l_nt_challenge_response);
|
||||
l_return := utl_raw.concat (l_return, l_domain, l_username, l_workstation, l_lm_challenge_response, l_nt_challenge_response);
|
||||
|
||||
--l_return := utl_raw.concat (l_domain, l_username, l_workstation, l_lm_challenge_response, l_nt_challenge_response);
|
||||
|
||||
l_returnvalue := utl_raw.cast_to_varchar2(l_return);
|
||||
l_returnvalue := encode_util_pkg.str_to_base64(l_returnvalue);
|
||||
l_returnvalue := replace(l_returnvalue, chr(13) || chr(10), '');
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_authenticate_message;
|
||||
|
||||
|
||||
|
||||
end ntlm_util_pkg;
|
||||
/
|
||||
|
||||
41
ora/ntlm_util_pkg.pks
Executable file
41
ora/ntlm_util_pkg.pks
Executable file
@ -0,0 +1,41 @@
|
||||
create or replace package ntlm_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package implements NTLM authentication protocol
|
||||
|
||||
Remarks: A PL/SQL port of the Python code at http://code.google.com/p/python-ntlm/
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
FDL 11.05.2011 Created
|
||||
MBR 11.05.2011 Miscellaneous contributions (create DES key, calculate LM hashed password, troubleshooting, bug fixes)
|
||||
|
||||
*/
|
||||
|
||||
-- get negotiate message
|
||||
function get_negotiate_message (p_username in varchar2) return varchar2;
|
||||
|
||||
-- parse challenge message from server
|
||||
procedure parse_challenge_message (p_message2 in varchar2,
|
||||
p_server_challenge out raw,
|
||||
p_negotiate_flags out raw);
|
||||
|
||||
-- get authenticate message
|
||||
function get_authenticate_message (p_username in varchar2,
|
||||
p_password in varchar2,
|
||||
p_server_challenge in raw,
|
||||
p_negotiate_flags in raw) return varchar2;
|
||||
|
||||
-- get LM hashed password v1
|
||||
function get_lm_hashed_password_v1 (p_password in raw) return raw;
|
||||
|
||||
-- get response hash
|
||||
function get_response (p_password_hash in raw,
|
||||
p_server_challenge in raw) return raw;
|
||||
|
||||
|
||||
end ntlm_util_pkg;
|
||||
/
|
||||
|
||||
844
ora/ooxml_util_pkg.pkb
Executable file
844
ora/ooxml_util_pkg.pkb
Executable file
@ -0,0 +1,844 @@
|
||||
create or replace package body ooxml_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles Office Open XML (OOXML) formats, ie Office 2007 docx, xlsx, etc.
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 25.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
--g_date_format constant varchar2(30) := 'YYYY-MM-DD"T"HH24:MI:SS".00Z"';
|
||||
|
||||
g_namespace_coreprops constant string_util_pkg.t_max_db_varchar2 := 'xmlns:cp="http://schemas.openxmlformats.org/package/2006/metadata/core-properties" xmlns:dc="http://purl.org/dc/elements/1.1/" xmlns:dcterms="http://purl.org/dc/terms/" xmlns:dcmitype="http://purl.org/dc/dcmitype/" xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance"';
|
||||
g_namespace_extendedprops constant string_util_pkg.t_max_db_varchar2 := 'xmlns="http://schemas.openxmlformats.org/officeDocument/2006/extended-properties" xmlns:vt="http://schemas.openxmlformats.org/officeDocument/2006/docPropsVTypes"';
|
||||
|
||||
g_namespace_xlsx_worksheet constant string_util_pkg.t_max_db_varchar2 := 'xmlns="http://schemas.openxmlformats.org/spreadsheetml/2006/main" xmlns:r="http://schemas.openxmlformats.org/officeDocument/2006/relationships"';
|
||||
g_namespace_xlsx_sharedstrings constant string_util_pkg.t_max_db_varchar2 := 'xmlns="http://schemas.openxmlformats.org/spreadsheetml/2006/main"';
|
||||
g_namespace_xlsx_relationships constant string_util_pkg.t_max_db_varchar2 := 'xmlns="http://schemas.openxmlformats.org/spreadsheetml/2006/main" xmlns:r="http://schemas.openxmlformats.org/officeDocument/2006/relationships"';
|
||||
g_namespace_package_rels constant string_util_pkg.t_max_db_varchar2 := 'xmlns="http://schemas.openxmlformats.org/package/2006/relationships"';
|
||||
g_namespace_pptx_slide constant string_util_pkg.t_max_db_varchar2 := 'xmlns:a="http://schemas.openxmlformats.org/drawingml/2006/main" xmlns:r="http://schemas.openxmlformats.org/officeDocument/2006/relationships" xmlns:p="http://schemas.openxmlformats.org/presentationml/2006/main"';
|
||||
|
||||
g_line_break_hack constant varchar2(10) := chr(24) || chr(164) || chr(164);
|
||||
|
||||
|
||||
function get_xml (p_blob in blob,
|
||||
p_file_name in varchar2) return xmltype
|
||||
as
|
||||
l_blob blob;
|
||||
l_clob clob;
|
||||
l_returnvalue xmltype;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get xml file from ooxml document
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 25.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_blob := zip_util_pkg.get_file (p_blob, p_file_name);
|
||||
|
||||
l_clob := sql_util_pkg.blob_to_clob (l_blob);
|
||||
|
||||
l_returnvalue := xmltype (l_clob);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_xml;
|
||||
|
||||
|
||||
function get_docx_properties (p_docx in blob) return t_docx_properties
|
||||
as
|
||||
l_returnvalue t_docx_properties;
|
||||
l_xml xmltype;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get docx properties
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 25.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_xml := get_xml (p_docx, 'docProps/core.xml');
|
||||
|
||||
l_returnvalue.core.title := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/dc:title/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.subject := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/dc:subject/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.creator := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/dc:creator/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.keywords := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/cp:keywords/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.description := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/dc:description/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.last_modified_by := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/cp:lastModifiedBy/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.revision := xml_util_pkg.extract_value_number (l_xml, '/cp:coreProperties/cp:revision/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.created_date := xml_util_pkg.extract_value_date (l_xml, '/cp:coreProperties/dcterms:created/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.modified_date := xml_util_pkg.extract_value_date (l_xml, '/cp:coreProperties/dcterms:modified/text()', g_namespace_coreprops);
|
||||
|
||||
l_xml := get_xml (p_docx, 'docProps/app.xml');
|
||||
|
||||
l_returnvalue.app.application := xml_util_pkg.extract_value (l_xml, '/Properties/Application/text()', g_namespace_extendedprops);
|
||||
l_returnvalue.app.app_version := xml_util_pkg.extract_value (l_xml, '/Properties/AppVersion/text()', g_namespace_extendedprops);
|
||||
l_returnvalue.app.company := xml_util_pkg.extract_value (l_xml, '/Properties/Company/text()', g_namespace_extendedprops);
|
||||
l_returnvalue.app.pages := xml_util_pkg.extract_value_number (l_xml, '/Properties/Pages/text()', g_namespace_extendedprops);
|
||||
l_returnvalue.app.words := xml_util_pkg.extract_value_number (l_xml, '/Properties/Words/text()', g_namespace_extendedprops);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_docx_properties;
|
||||
|
||||
|
||||
function get_docx_to_txt_stylesheet return varchar2
|
||||
as
|
||||
l_returnvalue varchar2(32000);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get XSL stylesheet that transforms docx to plain text
|
||||
|
||||
Remarks: see http://forums.oracle.com/forums/thread.jspa?messageID=3368284087
|
||||
abbreviated quite a bit, check out original posting by "user304344" for the original
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 25.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := '<?xml version="1.0" encoding="utf-8"?>'
|
||||
||chr(10)||'<xsl:stylesheet version="1.0" xmlns:xsl="http://www.w3.org/1999/XSL/Transform" '
|
||||
||chr(10)||'xmlns:w="http://schemas.openxmlformats.org/wordprocessingml/2006/main"'
|
||||
||chr(10)||'xmlns:v="urn:schemas-microsoft-com:vml"'
|
||||
||chr(10)||'exclude-result-prefixes="w v">'
|
||||
||chr(10)||'<xsl:output method="text" indent="no" encoding="UTF-8" version="1.0"/>'
|
||||
||chr(10)||'<!-- document root -->'
|
||||
||chr(10)||'<xsl:template match="/">'
|
||||
||chr(10)||'<!-- root element in document --> '
|
||||
||chr(10)||'<xsl:apply-templates select="w:document"/> '
|
||||
||chr(10)||'</xsl:template>'
|
||||
||chr(10)||'<!-- ****************************start document**************************** -->'
|
||||
||chr(10)||'<xsl:template match="w:document">'
|
||||
||chr(10)||'<xsl:for-each select="//w:p">'
|
||||
||chr(10)||'<xsl:apply-templates select="*/w:t"/> '
|
||||
||chr(10)||'<xsl:text>' || g_line_break_hack || '</xsl:text> '
|
||||
||chr(10)||'</xsl:for-each> '
|
||||
||chr(10)||'</xsl:template>'
|
||||
||chr(10)||'<!-- get all text nodes within a para -->'
|
||||
||chr(10)||'<xsl:template match="*/w:t">'
|
||||
||chr(10)||'<xsl:value-of select="."/>'
|
||||
||chr(10)||'</xsl:template>'
|
||||
||chr(10)||'<!-- **************************** end document**************************** -->'
|
||||
||chr(10)||'</xsl:stylesheet>';
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_docx_to_txt_stylesheet;
|
||||
|
||||
|
||||
function get_docx_plaintext (p_docx in blob) return clob
|
||||
as
|
||||
l_document_blob blob;
|
||||
l_document_clob clob;
|
||||
l_returnvalue clob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: extracts plain text from docx
|
||||
|
||||
Remarks: based on concepts from http://monkeyonoracle.blogspot.com/2010/03/docx-part-i-how-to-extract-document.html
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 25.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_document_blob := zip_util_pkg.get_file (p_docx, 'word/document.xml');
|
||||
l_document_clob := sql_util_pkg.blob_to_clob (l_document_blob);
|
||||
l_returnvalue := xml_stylesheet_pkg.transform_clob(l_document_clob, get_docx_to_txt_stylesheet);
|
||||
l_returnvalue := replace (l_returnvalue, g_line_break_hack, chr(10));
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_docx_plaintext;
|
||||
|
||||
|
||||
function get_file_from_template (p_template in blob,
|
||||
p_names in t_str_array,
|
||||
p_values in t_str_array) return blob
|
||||
as
|
||||
l_file_list zip_util_pkg.t_file_list;
|
||||
l_docx blob;
|
||||
l_blob blob;
|
||||
l_clob clob;
|
||||
|
||||
l_returnvalue blob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: performs substitutions on a template
|
||||
|
||||
Remarks: template file can be Word (docx), Excel (xlsx), or Powerpoint (pptx)
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 25.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_file_list := zip_util_pkg.get_file_list (p_template);
|
||||
|
||||
for i in 1 .. l_file_list.count loop
|
||||
|
||||
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
|
||||
|
||||
l_clob := sql_util_pkg.blob_to_clob (l_blob);
|
||||
l_clob := string_util_pkg.multi_replace (l_clob, p_names, p_values);
|
||||
l_blob := sql_util_pkg.clob_to_blob (l_clob);
|
||||
|
||||
end if;
|
||||
|
||||
zip_util_pkg.add_file (l_returnvalue, l_file_list(i), l_blob);
|
||||
|
||||
end loop;
|
||||
|
||||
zip_util_pkg.finish_zip (l_returnvalue);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_file_from_template;
|
||||
|
||||
|
||||
function get_xlsx_properties (p_xlsx in blob) return t_xlsx_properties
|
||||
as
|
||||
l_returnvalue t_xlsx_properties;
|
||||
l_xml xmltype;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get xlsx properties
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 30.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_xml := get_xml (p_xlsx, 'docProps/core.xml');
|
||||
|
||||
l_returnvalue.core.title := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/dc:title/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.subject := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/dc:subject/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.creator := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/dc:creator/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.keywords := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/cp:keywords/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.description := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/dc:description/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.last_modified_by := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/cp:lastModifiedBy/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.revision := xml_util_pkg.extract_value_number (l_xml, '/cp:coreProperties/cp:revision/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.created_date := xml_util_pkg.extract_value_date (l_xml, '/cp:coreProperties/dcterms:created/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.modified_date := xml_util_pkg.extract_value_date (l_xml, '/cp:coreProperties/dcterms:modified/text()', g_namespace_coreprops);
|
||||
|
||||
l_xml := get_xml (p_xlsx, 'docProps/app.xml');
|
||||
|
||||
l_returnvalue.app.application := xml_util_pkg.extract_value (l_xml, '/Properties/Application/text()', g_namespace_extendedprops);
|
||||
l_returnvalue.app.app_version := xml_util_pkg.extract_value (l_xml, '/Properties/AppVersion/text()', g_namespace_extendedprops);
|
||||
l_returnvalue.app.company := xml_util_pkg.extract_value (l_xml, '/Properties/Company/text()', g_namespace_extendedprops);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_xlsx_properties;
|
||||
|
||||
|
||||
function get_xlsx_column_number (p_column_ref in varchar2) return number
|
||||
as
|
||||
l_returnvalue number;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get column number from column reference
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 11.07.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
if length(p_column_ref) > 1 then
|
||||
l_returnvalue := ascii(substr(p_column_ref,1,1)) - 64;
|
||||
l_returnvalue := l_returnvalue * 26;
|
||||
l_returnvalue := l_returnvalue + (ascii(substr(p_column_ref,2,1)) - 64);
|
||||
else
|
||||
l_returnvalue := ascii(p_column_ref) - 64;
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_xlsx_column_number;
|
||||
|
||||
|
||||
function get_xlsx_column_ref (p_column_number in varchar2) return varchar2
|
||||
as
|
||||
l_offset number;
|
||||
l_returnvalue varchar2(2);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get column reference from column number
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 11.07.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
if p_column_number < 27 then
|
||||
l_returnvalue := chr(p_column_number + 64);
|
||||
else
|
||||
l_offset := trunc(p_column_number/26);
|
||||
l_returnvalue := chr(l_offset + 64);
|
||||
l_returnvalue := l_returnvalue || chr(p_column_number - (l_offset * 26) + 64);
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_xlsx_column_ref;
|
||||
|
||||
|
||||
function get_worksheet_file_name (p_xlsx in blob,
|
||||
p_worksheet in varchar2) return varchar2
|
||||
as
|
||||
l_relationship_id varchar2(255);
|
||||
l_returnvalue string_util_pkg.t_max_pl_varchar2;
|
||||
l_xml xmltype;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get file name of worksheet based on worksheet name
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 30.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_xml := get_xml (p_xlsx, 'xl/workbook.xml');
|
||||
|
||||
l_relationship_id := xml_util_pkg.extract_value (l_xml, '/workbook/sheets/sheet[@name="' || p_worksheet || '"]/@r:id', g_namespace_xlsx_relationships);
|
||||
|
||||
if l_relationship_id is not null then
|
||||
l_xml := get_xml (p_xlsx, 'xl/_rels/workbook.xml.rels');
|
||||
l_returnvalue := xml_util_pkg.extract_value (l_xml, '/Relationships/Relationship[@Id="' || l_relationship_id || '"]/@Target', g_namespace_package_rels);
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_worksheet_file_name;
|
||||
|
||||
|
||||
function get_xlsx_cell_value (p_xlsx in blob,
|
||||
p_worksheet in varchar2,
|
||||
p_cell in varchar2) return varchar2
|
||||
as
|
||||
l_returnvalue string_util_pkg.t_max_pl_varchar2;
|
||||
l_file_name string_util_pkg.t_max_db_varchar2;
|
||||
l_type varchar2(20);
|
||||
l_string_index pls_integer;
|
||||
l_xml xmltype;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get cell value from XLSX file
|
||||
|
||||
Remarks: see http://msdn.microsoft.com/en-us/library/bb332058(v=office.12).aspx
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 30.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_file_name := get_worksheet_file_name (p_xlsx, p_worksheet);
|
||||
|
||||
if l_file_name is null then
|
||||
raise_application_error (-20000, 'Worksheet not found!');
|
||||
end if;
|
||||
|
||||
l_xml := get_xml (p_xlsx, 'xl/' || l_file_name);
|
||||
|
||||
l_returnvalue := xml_util_pkg.extract_value (l_xml, '/worksheet/sheetData/row/c[@r="' || p_cell || '"]/v/text()', g_namespace_xlsx_worksheet);
|
||||
|
||||
l_type := xml_util_pkg.extract_value (l_xml, '/worksheet/sheetData/row/c[@r="' || p_cell || '"]/@t', g_namespace_xlsx_worksheet);
|
||||
|
||||
if l_type = 's' then
|
||||
l_string_index := to_number (l_returnvalue);
|
||||
l_xml := get_xml (p_xlsx, 'xl/sharedStrings.xml');
|
||||
l_returnvalue := xml_util_pkg.extract_value (l_xml, '/sst/si[' || (l_string_index + 1) || ']/t/text()', g_namespace_xlsx_sharedstrings);
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_xlsx_cell_value;
|
||||
|
||||
|
||||
function get_xlsx_cell_values (p_xlsx in blob,
|
||||
p_worksheet in varchar2,
|
||||
p_cells in t_str_array) return t_str_array
|
||||
as
|
||||
l_returnvalue t_str_array := t_str_array ();
|
||||
l_file_name string_util_pkg.t_max_db_varchar2;
|
||||
l_type varchar2(20);
|
||||
l_string_index pls_integer;
|
||||
l_xml xmltype;
|
||||
l_shared_strings xmltype;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get multiple cell values from XLSX file
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 30.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue.extend (p_cells.count);
|
||||
|
||||
l_file_name := get_worksheet_file_name (p_xlsx, p_worksheet);
|
||||
|
||||
if l_file_name is null then
|
||||
raise_application_error (-20000, 'Worksheet not found!');
|
||||
end if;
|
||||
|
||||
l_xml := get_xml (p_xlsx, 'xl/' || l_file_name);
|
||||
|
||||
l_shared_strings := get_xml (p_xlsx, 'xl/sharedStrings.xml');
|
||||
|
||||
for i in 1 .. p_cells.count loop
|
||||
|
||||
l_returnvalue(i) := xml_util_pkg.extract_value (l_xml, '/worksheet/sheetData/row/c[@r="' || p_cells(i) || '"]/v/text()', g_namespace_xlsx_worksheet);
|
||||
|
||||
l_type := xml_util_pkg.extract_value (l_xml, '/worksheet/sheetData/row/c[@r="' || p_cells(i) || '"]/@t', g_namespace_xlsx_worksheet);
|
||||
|
||||
if l_type = 's' then
|
||||
l_string_index := to_number (l_returnvalue(i));
|
||||
l_returnvalue(i) := xml_util_pkg.extract_value (l_shared_strings, '/sst/si[' || (l_string_index + 1) || ']/t/text()', g_namespace_xlsx_sharedstrings);
|
||||
end if;
|
||||
|
||||
end loop;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_xlsx_cell_values;
|
||||
|
||||
|
||||
function get_xlsx_cell (p_cell_reference in varchar2) return t_xlsx_cell
|
||||
as
|
||||
l_returnvalue t_xlsx_cell;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get cell by string reference
|
||||
|
||||
Remarks: given a reference of "A42", returns "A" (column) and 42 (row) as separate values
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 26.03.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
if p_cell_reference is not null then
|
||||
|
||||
l_returnvalue.column := rtrim(upper(p_cell_reference), '1234567890');
|
||||
l_returnvalue.row := to_number(ltrim(upper(p_cell_reference), 'ABCDEFGHIJKLMNOPQRSTUVWXYZ'));
|
||||
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_xlsx_cell;
|
||||
|
||||
|
||||
function get_xlsx_cell_values_as_sheet (p_xlsx in blob,
|
||||
p_worksheet in varchar2,
|
||||
p_cells in t_str_array) return t_xlsx_sheet
|
||||
as
|
||||
l_values t_str_array;
|
||||
l_cell t_xlsx_cell;
|
||||
l_returnvalue t_xlsx_sheet;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get multiple cell values from XLSX file
|
||||
|
||||
Remarks: return the values as an index-by table, allowing them to be referenced by name like this: l_sheet('A1').value
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 28.03.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_values := get_xlsx_cell_values (p_xlsx, p_worksheet, p_cells);
|
||||
|
||||
for i in 1 .. p_cells.count loop
|
||||
l_cell := get_xlsx_cell (p_cells(i));
|
||||
l_cell.value := l_values(i);
|
||||
l_returnvalue (p_cells(i)) := l_cell;
|
||||
end loop;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_xlsx_cell_values_as_sheet;
|
||||
|
||||
|
||||
function get_xlsx_cell_array_by_range (p_from_cell in varchar2,
|
||||
p_to_cell in varchar2) return t_str_array
|
||||
as
|
||||
l_from_cell t_xlsx_cell;
|
||||
l_to_cell t_xlsx_cell;
|
||||
l_returnvalue t_str_array := t_str_array();
|
||||
|
||||
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get an array of cell references by range
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 26.03.2011 Created
|
||||
MBR 11.07.2011 Handle two-letter column references
|
||||
|
||||
*/
|
||||
|
||||
l_from_cell := get_xlsx_cell (p_from_cell);
|
||||
l_to_cell := get_xlsx_cell (p_to_cell);
|
||||
|
||||
/*
|
||||
for l_column in ascii(l_from_cell.column) .. ascii(l_to_cell.column) loop
|
||||
for l_row in l_from_cell.row .. l_to_cell.row loop
|
||||
l_returnvalue.extend;
|
||||
l_returnvalue (l_returnvalue.last) := chr(l_column) || l_row;
|
||||
end loop;
|
||||
end loop;
|
||||
*/
|
||||
|
||||
for l_column in get_xlsx_column_number (l_from_cell.column) .. get_xlsx_column_number(l_to_cell.column) loop
|
||||
for l_row in l_from_cell.row .. l_to_cell.row loop
|
||||
l_returnvalue.extend;
|
||||
l_returnvalue (l_returnvalue.last) := get_xlsx_column_ref (l_column) || l_row;
|
||||
end loop;
|
||||
end loop;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_xlsx_cell_array_by_range;
|
||||
|
||||
|
||||
function get_xlsx_number (p_str in varchar2) return number
|
||||
as
|
||||
l_str string_util_pkg.t_max_db_varchar2;
|
||||
l_e_pos pls_integer;
|
||||
l_power pls_integer;
|
||||
l_returnvalue number;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get number from Excel internal format
|
||||
|
||||
Remarks: note that values may not be exactly what you expect,
|
||||
see http://stackoverflow.com/questions/606730/numeric-precision-issue-in-excel-2007-when-saving-as-xml
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 26.03.2011 Created
|
||||
MBR 11.07.2011 Handle scientific notation
|
||||
MBR 18.05.2012 Handle exception when string fails conversion to number
|
||||
|
||||
*/
|
||||
|
||||
l_str := p_str;
|
||||
|
||||
l_e_pos := instr(l_str, 'E');
|
||||
|
||||
if l_e_pos > 0 then
|
||||
l_power := to_number(substr(l_str, l_e_pos + 1));
|
||||
l_str := substr(l_str, 1, l_e_pos - 1);
|
||||
end if;
|
||||
|
||||
begin
|
||||
l_returnvalue := to_number(l_str, '999999999999999999999999D99999999999999999999999999999999999999', 'NLS_NUMERIC_CHARACTERS=.,');
|
||||
exception
|
||||
when value_error then
|
||||
-- conversion failed
|
||||
l_returnvalue := null;
|
||||
end;
|
||||
|
||||
if l_e_pos > 0 then
|
||||
l_returnvalue := l_returnvalue * power (10, l_power);
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_xlsx_number;
|
||||
|
||||
|
||||
function get_xlsx_date (p_date_str in varchar2,
|
||||
p_time_str in varchar2 := null) return date
|
||||
as
|
||||
l_days number;
|
||||
l_returnvalue date;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get date from Excel internal format
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 26.03.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_days := get_xlsx_number (p_date_str);
|
||||
|
||||
if p_time_str is not null then
|
||||
l_days := l_days + get_xlsx_number (p_time_str);
|
||||
end if;
|
||||
|
||||
l_returnvalue := to_date('01.01.1900', 'dd.mm.yyyy') + l_days - 2;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_xlsx_date;
|
||||
|
||||
|
||||
function get_pptx_properties (p_pptx in blob) return t_pptx_properties
|
||||
as
|
||||
l_returnvalue t_pptx_properties;
|
||||
l_xml xmltype;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get pptx properties
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 11.07.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_xml := get_xml (p_pptx, 'docProps/core.xml');
|
||||
|
||||
l_returnvalue.core.title := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/dc:title/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.subject := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/dc:subject/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.creator := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/dc:creator/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.keywords := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/cp:keywords/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.description := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/dc:description/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.last_modified_by := xml_util_pkg.extract_value (l_xml, '/cp:coreProperties/cp:lastModifiedBy/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.revision := xml_util_pkg.extract_value_number (l_xml, '/cp:coreProperties/cp:revision/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.created_date := xml_util_pkg.extract_value_date (l_xml, '/cp:coreProperties/dcterms:created/text()', g_namespace_coreprops);
|
||||
l_returnvalue.core.modified_date := xml_util_pkg.extract_value_date (l_xml, '/cp:coreProperties/dcterms:modified/text()', g_namespace_coreprops);
|
||||
|
||||
l_xml := get_xml (p_pptx, 'docProps/app.xml');
|
||||
|
||||
l_returnvalue.app.application := xml_util_pkg.extract_value (l_xml, '/Properties/Application/text()', g_namespace_extendedprops);
|
||||
l_returnvalue.app.app_version := xml_util_pkg.extract_value (l_xml, '/Properties/AppVersion/text()', g_namespace_extendedprops);
|
||||
l_returnvalue.app.company := xml_util_pkg.extract_value (l_xml, '/Properties/Company/text()', g_namespace_extendedprops);
|
||||
l_returnvalue.app.slides := xml_util_pkg.extract_value_number (l_xml, '/Properties/Slides/text()', g_namespace_extendedprops);
|
||||
l_returnvalue.app.hidden_slides := xml_util_pkg.extract_value_number (l_xml, '/Properties/HiddenSlides/text()', g_namespace_extendedprops);
|
||||
l_returnvalue.app.paragraphs := xml_util_pkg.extract_value_number (l_xml, '/Properties/Paragraphs/text()', g_namespace_extendedprops);
|
||||
l_returnvalue.app.words := xml_util_pkg.extract_value_number (l_xml, '/Properties/Words/text()', g_namespace_extendedprops);
|
||||
l_returnvalue.app.notes := xml_util_pkg.extract_value_number (l_xml, '/Properties/Notes/text()', g_namespace_extendedprops);
|
||||
l_returnvalue.app.template := xml_util_pkg.extract_value (l_xml, '/Properties/Template/text()', g_namespace_extendedprops);
|
||||
l_returnvalue.app.presentation_format := xml_util_pkg.extract_value (l_xml, '/Properties/PresentationFormat/text()', g_namespace_extendedprops);
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_pptx_properties;
|
||||
|
||||
|
||||
function get_pptx_media_list (p_pptx in blob,
|
||||
p_slide in number := null) return t_str_array
|
||||
as
|
||||
l_xml xmltype;
|
||||
l_file_list zip_util_pkg.t_file_list;
|
||||
l_returnvalue t_str_array := t_str_array();
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get list of media files embedded in presentation
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 11.07.2011 Created
|
||||
MBR 28.04.2012 Specify specific slide number to get media (images) related to that slide
|
||||
|
||||
*/
|
||||
|
||||
if p_slide is not null then
|
||||
|
||||
-- see http://msdn.microsoft.com/en-us/library/bb332455(v=office.12).aspx
|
||||
|
||||
l_xml := get_xml (p_pptx, 'ppt/slides/_rels/slide' || p_slide || '.xml.rels');
|
||||
|
||||
for l_rec in (
|
||||
select extractValue(value(t), '*/@Target', g_namespace_package_rels) as target
|
||||
from table(xmlsequence(l_xml.extract('//Relationship[@Type="http://schemas.openxmlformats.org/officeDocument/2006/relationships/image"]', g_namespace_package_rels))) t
|
||||
)
|
||||
loop
|
||||
l_returnvalue.extend();
|
||||
l_returnvalue(l_returnvalue.last) := replace(l_rec.target, '../media', 'ppt/media');
|
||||
end loop;
|
||||
|
||||
else
|
||||
|
||||
l_file_list := zip_util_pkg.get_file_list (p_pptx);
|
||||
|
||||
for i in 1 .. l_file_list.count loop
|
||||
|
||||
if substr(l_file_list(i), 1, 10) = 'ppt/media/' then
|
||||
l_returnvalue.extend();
|
||||
l_returnvalue(l_returnvalue.last) := l_file_list(i);
|
||||
end if;
|
||||
|
||||
end loop;
|
||||
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_pptx_media_list;
|
||||
|
||||
|
||||
function get_pptx_to_txt_stylesheet return varchar2
|
||||
as
|
||||
l_returnvalue varchar2(32000);
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get XSL stylesheet that transforms pptx to plain text
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 11.07.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := '<?xml version="1.0" encoding="utf-8"?>
|
||||
<xsl:stylesheet version="1.0" xmlns:xsl="http://www.w3.org/1999/XSL/Transform" ' || g_namespace_pptx_slide || '>
|
||||
<xsl:template match="/">
|
||||
<xsl:for-each select="//a:r">
|
||||
<xsl:value-of select="a:t"/><xsl:text>' || g_line_break_hack || '</xsl:text>
|
||||
</xsl:for-each>
|
||||
</xsl:template>
|
||||
</xsl:stylesheet>';
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_pptx_to_txt_stylesheet;
|
||||
|
||||
|
||||
function get_pptx_plaintext (p_pptx in blob,
|
||||
p_slide in number := null,
|
||||
p_note in number := null) return clob
|
||||
as
|
||||
l_null_argument_exception exception; -- ORA-30625: method dispatch on NULL SELF argument is disallowed
|
||||
pragma exception_init (l_null_argument_exception, -30625);
|
||||
l_document_blob blob;
|
||||
l_document_clob clob;
|
||||
l_returnvalue clob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get plain text from slide
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 11.07.2011 Created
|
||||
MBR 08.07.2011 Handle empty slides
|
||||
|
||||
*/
|
||||
|
||||
if p_note is not null then
|
||||
l_document_blob := zip_util_pkg.get_file (p_pptx, 'ppt/notesSlides/notesSlide' || p_note || '.xml');
|
||||
elsif p_slide is not null then
|
||||
l_document_blob := zip_util_pkg.get_file (p_pptx, 'ppt/slides/slide' || p_slide || '.xml');
|
||||
end if;
|
||||
|
||||
if l_document_blob is not null then
|
||||
l_document_clob := sql_util_pkg.blob_to_clob (l_document_blob);
|
||||
begin
|
||||
l_returnvalue := xml_stylesheet_pkg.transform_clob(l_document_clob, get_pptx_to_txt_stylesheet);
|
||||
exception
|
||||
when l_null_argument_exception then
|
||||
l_returnvalue := null;
|
||||
end;
|
||||
l_returnvalue := replace (l_returnvalue, g_line_break_hack, chr(10));
|
||||
else
|
||||
l_returnvalue := 'Slide or note must be specified.';
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_pptx_plaintext;
|
||||
|
||||
|
||||
end ooxml_util_pkg;
|
||||
/
|
||||
|
||||
|
||||
|
||||
141
ora/ooxml_util_pkg.pks
Executable file
141
ora/ooxml_util_pkg.pks
Executable file
@ -0,0 +1,141 @@
|
||||
create or replace package ooxml_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package handles Office Open XML (OOXML) formats, ie Office 2007 docx, xlsx, etc.
|
||||
|
||||
Remarks: see http://en.wikipedia.org/wiki/Office_Open_XML
|
||||
see http://msdn.microsoft.com/en-us/library/bb266220(v=office.12).aspx
|
||||
see http://www.infoq.com/articles/cracking-office-2007-with-java
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 25.01.2011 Created
|
||||
MBR 11.07.2011 Added Powerpoint-specific features
|
||||
|
||||
*/
|
||||
|
||||
type t_core_properties is record (
|
||||
title varchar2(2000),
|
||||
subject varchar2(2000),
|
||||
creator varchar2(2000),
|
||||
keywords varchar2(2000),
|
||||
description varchar2(2000),
|
||||
last_modified_by varchar2(2000),
|
||||
revision number,
|
||||
created_date date,
|
||||
modified_date date
|
||||
);
|
||||
|
||||
type t_app_docx is record (
|
||||
application varchar2(2000),
|
||||
app_version varchar2(2000),
|
||||
company varchar2(2000),
|
||||
pages number,
|
||||
words number
|
||||
);
|
||||
|
||||
type t_docx_properties is record (
|
||||
core t_core_properties,
|
||||
app t_app_docx
|
||||
);
|
||||
|
||||
type t_app_xlsx is record (
|
||||
application varchar2(2000),
|
||||
app_version varchar2(2000),
|
||||
company varchar2(2000)
|
||||
);
|
||||
|
||||
type t_xlsx_properties is record (
|
||||
core t_core_properties,
|
||||
app t_app_xlsx
|
||||
);
|
||||
|
||||
type t_app_pptx is record (
|
||||
application varchar2(2000),
|
||||
app_version varchar2(2000),
|
||||
company varchar2(2000),
|
||||
slides number,
|
||||
hidden_slides number,
|
||||
paragraphs number,
|
||||
words number,
|
||||
notes number,
|
||||
presentation_format varchar2(2000),
|
||||
template varchar2(2000)
|
||||
);
|
||||
|
||||
type t_pptx_properties is record (
|
||||
core t_core_properties,
|
||||
app t_app_pptx
|
||||
);
|
||||
|
||||
type t_xlsx_cell is record (
|
||||
column varchar2(2),
|
||||
row number,
|
||||
value varchar2(4000)
|
||||
);
|
||||
|
||||
type t_xlsx_sheet is table of t_xlsx_cell index by varchar2(20);
|
||||
|
||||
-- get docx properties
|
||||
function get_docx_properties (p_docx in blob) return t_docx_properties;
|
||||
|
||||
-- extracts plain text from docx
|
||||
function get_docx_plaintext (p_docx in blob) return clob;
|
||||
|
||||
-- performs substitutions on a template
|
||||
function get_file_from_template (p_template in blob,
|
||||
p_names in t_str_array,
|
||||
p_values in t_str_array) return blob;
|
||||
|
||||
-- get XLSX properties
|
||||
function get_xlsx_properties (p_xlsx in blob) return t_xlsx_properties;
|
||||
|
||||
-- get column number from column reference
|
||||
function get_xlsx_column_number (p_column_ref in varchar2) return number;
|
||||
|
||||
-- get column reference from column number
|
||||
function get_xlsx_column_ref (p_column_number in varchar2) return varchar2;
|
||||
|
||||
-- get cell value from XLSX file
|
||||
function get_xlsx_cell_value (p_xlsx in blob,
|
||||
p_worksheet in varchar2,
|
||||
p_cell in varchar2) return varchar2;
|
||||
|
||||
-- get multiple cell values from XLSX file
|
||||
function get_xlsx_cell_values (p_xlsx in blob,
|
||||
p_worksheet in varchar2,
|
||||
p_cells in t_str_array) return t_str_array;
|
||||
|
||||
-- get multiple cell values from XLSX file (as sheet)
|
||||
function get_xlsx_cell_values_as_sheet (p_xlsx in blob,
|
||||
p_worksheet in varchar2,
|
||||
p_cells in t_str_array) return t_xlsx_sheet;
|
||||
|
||||
-- get an array of cell references by range
|
||||
function get_xlsx_cell_array_by_range (p_from_cell in varchar2,
|
||||
p_to_cell in varchar2) return t_str_array;
|
||||
|
||||
-- get number from Excel internal format
|
||||
function get_xlsx_number (p_str in varchar2) return number;
|
||||
|
||||
-- get date from Excel internal format
|
||||
function get_xlsx_date (p_date_str in varchar2,
|
||||
p_time_str in varchar2 := null) return date;
|
||||
|
||||
-- get pptx properties
|
||||
function get_pptx_properties (p_pptx in blob) return t_pptx_properties;
|
||||
|
||||
-- get list of media files embedded in presentation
|
||||
function get_pptx_media_list (p_pptx in blob,
|
||||
p_slide in number := null) return t_str_array;
|
||||
|
||||
-- get plain text from slide
|
||||
function get_pptx_plaintext (p_pptx in blob,
|
||||
p_slide in number := null,
|
||||
p_note in number := null) return clob;
|
||||
|
||||
end ooxml_util_pkg;
|
||||
/
|
||||
|
||||
230
ora/owa_util_pkg.pkb
Executable file
230
ora/owa_util_pkg.pkb
Executable file
@ -0,0 +1,230 @@
|
||||
create or replace package body owa_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package contains utilities related to PL/SQL Web Toolkit (OWA)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 12.06.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
|
||||
procedure htp_print_clob (p_clob in clob,
|
||||
p_add_newline in boolean := true)
|
||||
as
|
||||
l_buffer varchar2(32767);
|
||||
l_max_size constant integer := 8000;
|
||||
l_start integer := 1;
|
||||
l_cloblen integer;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: print clob to HTTP buffer
|
||||
|
||||
Remarks: from http://francis.blog-city.com/ora20103_null_input_is_not_allowed.htm
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 19.01.2009 Created
|
||||
|
||||
*/
|
||||
|
||||
if p_clob is not null then
|
||||
|
||||
l_cloblen := dbms_lob.getlength (p_clob );
|
||||
|
||||
loop
|
||||
l_buffer := dbms_lob.substr (p_clob, l_max_size, l_start);
|
||||
htp.prn (l_buffer);
|
||||
l_start := l_start + l_max_size;
|
||||
exit when l_start > l_cloblen;
|
||||
end loop ;
|
||||
|
||||
if p_add_newline then
|
||||
htp.p;
|
||||
end if;
|
||||
|
||||
end if;
|
||||
|
||||
end htp_print_clob;
|
||||
|
||||
|
||||
procedure htp_printf (p_str in varchar2,
|
||||
p_value1 in varchar2 := null,
|
||||
p_value2 in varchar2 := null,
|
||||
p_value3 in varchar2 := null,
|
||||
p_value4 in varchar2 := null,
|
||||
p_value5 in varchar2 := null,
|
||||
p_value6 in varchar2 := null,
|
||||
p_value7 in varchar2 := null,
|
||||
p_value8 in varchar2 := null)
|
||||
as
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: print string with substitution values to HTTP buffer
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 06.02.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
htp.p(string_util_pkg.get_str(p_str, p_value1, p_value2, p_value3, p_value4, p_value5, p_value6, p_value7, p_value8));
|
||||
|
||||
end htp_printf;
|
||||
|
||||
|
||||
|
||||
procedure init_owa (p_names in owa.vc_arr := g_empty_vc_arr,
|
||||
p_values in owa.vc_arr := g_empty_vc_arr)
|
||||
as
|
||||
l_version pls_integer;
|
||||
l_names owa.vc_arr := p_names;
|
||||
l_values owa.vc_arr := p_values;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: initialize OWA environment
|
||||
|
||||
Remarks: all gateways (mod_plsql, DBMS_EPG, Apex Listener, Thoth Gateway, etc.)
|
||||
will do this automatically before a procedure is invoked via a web server
|
||||
|
||||
but this is useful (and required) for calling web procedures via sqlplus or other (non-gateway) tools
|
||||
|
||||
see http://asktom.oracle.com/pls/apex/f?p=100:11:0::::P11_QUESTION_ID:347617533333
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 22.01.2011 Created
|
||||
|
||||
*/
|
||||
|
||||
l_version := owa.initialize;
|
||||
|
||||
if l_names.count = 0 then
|
||||
l_names(1) := 'PLSQL_GATEWAY';
|
||||
l_values(1) := 'Dummy Gateway';
|
||||
l_names(2) := 'GATEWAY_IVERSION';
|
||||
l_values(2) := '2';
|
||||
l_names(3) := 'HTTP_USER_AGENT';
|
||||
l_values(3) := 'Mozilla/5.0 (compatible); SQL*Plus';
|
||||
l_names(4) := 'REQUEST_CHARSET';
|
||||
l_values(4) := 'AL32UTF8';
|
||||
l_names(5) := 'REQUEST_IANA_CHARSET';
|
||||
l_values(5) := 'UTF-8';
|
||||
end if;
|
||||
|
||||
owa.init_cgi_env(l_names.count, l_names, l_values);
|
||||
|
||||
htp.init;
|
||||
htp.htbuf_len := 63;
|
||||
|
||||
|
||||
end init_owa;
|
||||
|
||||
|
||||
function get_page (p_include_headers in boolean := true) return clob
|
||||
as
|
||||
l_page htp.htbuf_arr;
|
||||
l_lines pls_integer := 99999999;
|
||||
l_returnvalue clob;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: get page from HTTP buffer
|
||||
|
||||
Remarks: see http://asktom.oracle.com/pls/apex/f?p=100:11:0::::P11_QUESTION_ID:347617533333
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 22.01.2011 Created
|
||||
MBR 20.03.2011 Added option to exclude headers
|
||||
|
||||
*/
|
||||
|
||||
owa.get_page (l_page, l_lines);
|
||||
|
||||
for i in 1 .. l_lines loop
|
||||
l_returnvalue := l_returnvalue || l_page(i);
|
||||
end loop;
|
||||
|
||||
if (not p_include_headers) then
|
||||
l_returnvalue := substr(l_returnvalue, instr(l_returnvalue, owa.nl_char || owa.nl_char));
|
||||
end if;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end get_page;
|
||||
|
||||
|
||||
function is_user_agent_ie return boolean
|
||||
as
|
||||
l_returnvalue boolean;
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: is user agent Internet Explorer ?
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 27.02.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
l_returnvalue := instr(owa_util.get_cgi_env('HTTP_USER_AGENT'), ' MSIE ') > 0;
|
||||
|
||||
return l_returnvalue;
|
||||
|
||||
end is_user_agent_ie;
|
||||
|
||||
|
||||
procedure download_file (p_file in blob,
|
||||
p_mime_type in varchar2,
|
||||
p_file_name in varchar2,
|
||||
p_expires in date := null)
|
||||
as
|
||||
l_file blob := p_file; -- need a local copy as wpg_docload.download_file uses an IN OUT parameter
|
||||
begin
|
||||
|
||||
/*
|
||||
|
||||
Purpose: download file
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- -------------------------------------
|
||||
MBR 23.09.2012 Created
|
||||
|
||||
*/
|
||||
|
||||
owa_util.mime_header(nvl(p_mime_type, 'application/octet'), false);
|
||||
htp.p('Content-length: ' || dbms_lob.getlength(p_file));
|
||||
if p_expires is not null then
|
||||
htp.p('Expires:' || to_char(p_expires, 'FMDy, DD Month YYYY HH24:MI:SS') || 'GMT');
|
||||
end if;
|
||||
htp.p('Content-Disposition: attachment; filename="' || nvl(p_file_name, 'untitled') || '"');
|
||||
owa_util.http_header_close;
|
||||
|
||||
wpg_docload.download_file (l_file);
|
||||
|
||||
end download_file;
|
||||
|
||||
|
||||
end owa_util_pkg;
|
||||
/
|
||||
51
ora/owa_util_pkg.pks
Executable file
51
ora/owa_util_pkg.pks
Executable file
@ -0,0 +1,51 @@
|
||||
create or replace package owa_util_pkg
|
||||
as
|
||||
|
||||
/*
|
||||
|
||||
Purpose: Package contains utilities related to PL/SQL Web Toolkit (OWA)
|
||||
|
||||
Remarks:
|
||||
|
||||
Who Date Description
|
||||
------ ---------- --------------------------------
|
||||
MBR 12.06.2008 Created
|
||||
|
||||
*/
|
||||
|
||||
g_empty_vc_arr owa.vc_arr;
|
||||
|
||||
-- print clob to HTTP buffer
|
||||
procedure htp_print_clob (p_clob in clob,
|
||||
p_add_newline in boolean := true);
|
||||
|
||||
-- print string with substitution values to HTTP buffer
|
||||
procedure htp_printf (p_str in varchar2,
|
||||
p_value1 in varchar2 := null,
|
||||
p_value2 in varchar2 := null,
|
||||
p_value3 in varchar2 := null,
|
||||
p_value4 in varchar2 := null,
|
||||
p_value5 in varchar2 := null,
|
||||
p_value6 in varchar2 := null,
|
||||
p_value7 in varchar2 := null,
|
||||
p_value8 in varchar2 := null);
|
||||
|
||||
-- initialize OWA environment
|
||||
procedure init_owa (p_names in owa.vc_arr := g_empty_vc_arr,
|
||||
p_values in owa.vc_arr := g_empty_vc_arr);
|
||||
|
||||
-- get page from HTTP buffer
|
||||
function get_page (p_include_headers in boolean := true) return clob;
|
||||
|
||||
-- is user agent Internet Explorer ?
|
||||
function is_user_agent_ie return boolean;
|
||||
|
||||
-- download file
|
||||
procedure download_file (p_file in blob,
|
||||
p_mime_type in varchar2,
|
||||
p_file_name in varchar2,
|
||||
p_expires in date := null);
|
||||
|
||||
end owa_util_pkg;
|
||||
/
|
||||
|
||||
1361
ora/pdf_builder_pkg.pkb
Executable file
1361
ora/pdf_builder_pkg.pkb
Executable file
File diff suppressed because it is too large
Load Diff
Some files were not shown because too many files have changed in this diff Show More
Loading…
x
Reference in New Issue
Block a user