F.29. Orafce Documentation#

F.29. Orafce Documentation

F.29. Orafce Documentation #

F.29.1. About Orafce #

Version: 4.9.0

GitHub

F.29.2. Oracle functions and Oracle packages #

This module contains some useful functions that can help with porting Oracle application to Tantor SE or that can be generally useful.

Built-in Oracle date functions have been tested against Oracle 10 for conformance. Date ranges from 1960 to 2070 work correctly. Dates before 1100-03-01 cannot be verified due to a bug in Oracle.

All functions are fully compatibles with Oracle and respect all known format strings. Detailed descriptions can be found on the internet. Use keywords like : oracle round trunc date iyyy.

F.29.3. List of format strings for trunc, round functions #

Y,YY,YYY,YYYY,SYYY,SYEAR	year
I,IY,IYY,IYYY			iso year
Q,				quarter
WW				week, day as first day of year
IW				week, beginning Monday
W				week, day as first day of month
DAY,DY,D			first day of week, sunday
MONTH,MON,MM,RM			month
CC,SCC				century
DDD,DD,J			day
HH,HH12,HH24			hour
MI				minute

Functions round up. That is, a date of July 1st will be rounded to the next year. The 16th of July will be rounded to August.

F.29.4. Date Functions #

  • add_months(date, integer) date - Returns date plus n months

    add_months(date '2005-05-31',1) -> 2005-06-30
  • last_date(date) date - Returns last day of the month based on a date value

    last_day(date '2005-05-24') -> 2005-05-31
  • next_day(date, text) date - Returns the first weekday that is greater than a date value

    next_day(date '2005-05-24', 'monday') -> 2005-05-30
  • next_day(date, integer) date - Same as above. The second argument should be 1..7 and interpreted as Sunday..Satday.

    next_day(date '2005-05-24', 1) -> 2005-05-30
  • months_between(date, date) numeric - Returns the number of months between date1 and date2. If a fractional month is calculated, the months_between function calculates the fraction based on a 31-day month.

    months_between(date '1995-02-02', date '1995-01-01') -> 1.0322580645161
  • trunc(date, text) date - truncate date according to the specified format

    trunc(date '2005-07-12', 'iw') -> 2005-07-11
  • round(date, text) date - will round dates according to the specified format

    round(date '2005-07-12', 'yyyy') -> 2006-01-01
  • to_date(text) timestamp - will typecast input text to timestamp. The GUC orafce.nls_date_format is used to specify input text format for this function. If the value is left blank or set as DEFAULT then input text format according to Tantor SE’s datestyle GUC setting.

    orafce.nls_date_format value to DEFAULT
    to_date('2014-05-19 17:23:53+5:30') -> 2014-05-19 17:23:53
    orafce.nls_date_format='YYYY-MMDD HH24:MI:SS'
    to_date('2014-0519 17:23:53+5:30')  -> 2014-05-19 17:23:53

F.29.5. oracle.date data type #

This module contains implementation of oracle compatible DATE data type "oracle.date" and functions which are using DATE data type like oracle.add_months,oracle.last_day(),oracle.next_day(),oracle.months_between() etc.

Example:

set search_path TO oracle,"$user", public, pg_catalog;
create table oracle_date(col1 date);
insert into oracle_date values('2014-06-24 12:12:11'::date);
select * from oracle_date;
        col1
---------------------
  2014-06-24 12:12:11
(1 row)

F.29.6. oracle.date functions #

  • oracle.add_months(timestamp with time zone, integer) - Returns date and time plus n months

    oracle.add_months(oracle.date'2005-05-31 10:12:12',1) -> 2005-06-30 10:12:12
  • oracle.last_day(timestamp with time zone) - Returns last day of the month based on a date value

    oracle.last_day(oracle.date '2005-05-24 11:12:12') -> 2005-05-31 11:12:12
  • oracle.next_day(timestamp with time zone, text) - Returns the first weekday that is greater than a date value

    oracle.next_day(oracle.date '2005-05-24 10:12:12', 'monday') -> 2005-05-30 10:12:12
  • oracle.next_day(timestamp with time zone, integer) - Same as above. The second argument should be 1..7 and interpreted as Sunday..Saturday.

    oracle.next_day(oracle.date '2005-05-24 11:21:12', 1) -> 2005-05-29 11:21:12
  • oracle.months_between(timestamp with time zone, timestamp with time zone) - Returns the number of months between timestamp1 and timestamp2. If a fractional month is calculated, the months_between function calculates the fraction based on a 31-day month.

    oracle.months_between(oracle.date '1995-02-02 10:00:00', oracle.date '1995-01-01 10:21:11') -> 1.03225806451613
  • oracle.to_date(text,text) - Returns timestamp without time zone.

    oracle.to_date('02/16/09 04:12:12', 'MM/DD/YY HH24:MI:SS') -> 2009-02-16 04:12:12
  • oracle.to_date(text) - Returns oracle.date

    oracle.to_date('02/16/09 04:12:12') -> 2009-02-16 04:12:12
  • oracle.sysdate() - Returns statement timestamp at server timezone (orafce.timezone)

    oracle.sysdate() -> 2015-12-09 17:47:56
  • oracle.dbtimezone - Returns server time zone - emulated via orafce.timezone

    oracle.dbtimezone() -> GMT
  • oracle.sessiontimezone() - Returns session timezone - current Tantor SE timezone

    oracle.sessiontimezone() -> Europe/Prague
  • oracle.to_char(timestamp) - Returns timestamp in nls_date_format.

    orafce.nls_date_format='YY-MonDD HH24:MI:SS'
    oracle.to_char(to_date('14-Jan08 11:44:49+05:30')) -> 14-Jan08 11:44:49
    orafce.nls_date_format='YY-MonDD HH24:MI:SS'
    oracle.to_char(oracle.to_date('21052014 12:13:44+05:30','DDMMYYYY HH24:MI:SS')) -> 14-May21 12:13:44

F.29.7. oracle.date Operators #

  • oracle.+(oracle.date,smallint) - Returns oracle.date

    oracle.to_date('2014-07-02 10:08:55','YYYY-MM-DD HH:MI:SS') + 9::smallint -> 2014-07-11 10:08:55
  • oracle.+(oracle.date,integer) - Returns oracle.date

    oracle.to_date('2014-07-02 10:08:55','YYYY-MM-DD HH:MI:SS') + 9::integer -> 2014-07-11 10:08:55
  • oracle.+(oracle.date,bigint) - Returns oracle.date

    oracle.to_date('2014-07-02 10:08:55','YYYY-MM-DD HH:MI:SS') + 9::bigint -> 2014-07-11 10:08:55
  • oracle.+(oracle.date,numeric) - Returns oracle.date

    oracle.to_date('2014-07-02 10:08:55','YYYY-MM-DD HH:MI:SS') + 9::numeric -> 2014-07-11 10:08:55
  • oracle.-(oracle.date,smallint) - Returns oracle.date

    oracle.to_date('2014-07-02 10:08:55','YYYY-MM-DD HH:MI:SS') - 9::smallint -> 2014-06-23 10:08:55
  • oracle.-(oracle.date,integer) - Returns oracle.date

    oracle.to_date('2014-07-02 10:08:55','YYYY-MM-DD HH:MI:SS') - 9::integer -> 2014-06-23 10:08:55
  • oracle.-(oracle.date,bigint) - Returns oracle.date

    oracle.to_date('2014-07-02 10:08:55','YYYY-MM-DD HH:MI:SS') - 9::bigint -> 2014-06-23 10:08:55
  • oracle.-(oracle.date,numeric) - Returns oracle.date

    oracle.to_date('2014-07-02 10:08:55','YYYY-MM-DD HH:MI:SS') - 9::numeric -> 2014-06-23 10:08:55
  • oracle.-(oracle.date,oracle.date) - Returns double precision

    oracle.to_date('2014-07-17 11:10:15', 'yyyy-mm-dd hh24:mi:ss') - oracle.to_date('2014-02-01 10:00:00', 'yyyy-mm-dd hh24:mi:ss') -> 166.048785

You need to set search_path TO oracle,"$user", public, pg_catalog because functions like oracle.add_months,oracle.last_day,oracle.next_day,oracle.months_between are installed side-by-side with pg_catalog.add_months,pg_catalog.last_day,pg_catalog.next_day,pg_catalog.months_between.

F.29.8. Table dual #

Tantor SE does not need Oracle’s table 'dual', but since it is intensively used by Oracle users, it has been added in orafce. This table is in schema oracle. Usually you want allow unqualified access - so you should to add this schema to search_path configuration (like search_path = 'oracle, pg_catalog, "$user", public' in postgresql.conf).

F.29.9. Package dbms_output #

Tantor SE sends information to the client via RAISE NOTICE. Oracle uses dbms_output.put_line(). This works differently from RAISE NOTICE. Oracle has a session queue, put_line() adds a line to the queue and the function get_line() reads from queue. If flag 'serveroutput' is set, then client over all sql statements reads queue. You can use:

select dbms_output.enable();
select dbms_output.put_line('first_line');
select dbms_output.put_line('next_line');
select * from dbms_output.get_lines(0);

or

select dbms_output.enable();
select dbms_output.serveroutput('t');
select dbms_output.put_line('first_line');

This package contains the following functions: enable(), disable(), serveroutput(), put(), put_line(), new_line(), get_line(), get_lines(). The package queue is implemented in the session’s local memory.

F.29.10. Package utl_file #

This package allows PL/pgSQL programs to read from and write to any files that are accessible from server. Every session can open a maximum of ten files and max line size is 32K. This package contains following functions:

  • utl_file.fclose(file utl_file.file_type) - close file

  • utl_file.fclose_all() - close all files

  • utl_file.fcopy(src_location, src_filename, dest_location, dest_filename[, start_line][, end_line]) - copy text file

  • utl_file.fflush(file utl_file.file_type) - flushes all data from buffers

  • utl_file.fgetattr(location, filename) - get file attributes

  • utl_file.fopen(location text, filename text, file_mode text [, maxlinesize int] [, encoding name]) utl_file.file_type - open file

  • utl_file.fremove(location, filename) - remove file

  • utl_file.frename(location, filename, dest_dir, dest_file[, overwrite]) - rename file

  • utl_file.get_line(file utl_file.file_type) text - read one line from file

  • utl_file.get_nextline(file utl_file.file_type) text - read one line from file or returns NULL

  • utl_file.is_open(file utl_file.file_type) bool - returns true, if file is opened

  • utl_file.new_line(file utl_file.file_type [,rows int]) - puts some new line chars to file

  • utl_file.put(file utl_file.file_type, buffer text) - puts buffer to file

  • utl_file.put_line(file utl_file.file_type, buffer text) - puts line to file

  • utl_file.putf(file utl_file.file_type, format buffer [,arg1 text][,arg2 text][..][,arg5 text]) - put formatted text into file

  • utl_file.tmpdir() - get path of temp directory

Because Tantor SE doesn’t support call by reference, some functions are slightly different: fclose and get_line.

declare f utl_file.file_type;
begin
  f := utl_file.fopen('/tmp', 'sample.txt', 'r');
  <<readl>>
  loop
    begin
      raise notice '%', utl_file.get_line(f);
    exception
      when no_data_found then
        exit readl;
    end;
  end loop;
  f := fclose(f);
end;

or second (with Tantor SE specific function get_nextline)

declare
  f utl_file.file_type;
  line text;
begin
  f := utl_file.fopen('/tmp', 'sample.txt', 'r');
  loop
    line := utl_file.get_nextline(f);
    exit when line is NULL;
    raise notice '%', line;
exception
  when others then
    utl_file.fclose_all();
end;

Before using the package you have to set the utl_file.utl_file_dir table. It contains all allowed directories without ending symbol ('/' or '\'). On WinNT platform, the paths have to end with symbol '\' every time.

Directory entries can be named (second column in table utl_file.utl_file_dir). The location parameter can be either the directory name or the dictionary path. The location is first interpreted and checked as a directory name. If not found (in 2nd column), then the location is interpreted and checked as a path.

Functions from utl_file package (schema on Postgres) requires a access to table utl_file.utl_file_dir. This fact can be used to control what users can use these functions or not. Default setting is READ for PUBLIC. INSERT, UPDATE can do only privileged user (super user). So unprivileged user can use functions from this package, but cannot to change list of safe directories (content of utl_file.utl_file_dir table). The content of this table is visible for PUBLIC (or should be visible for users who uses functions from this package).

F.29.11. Package dbms_sql #

This is implementation of Oracle’s API of package DBMS_SQL

It doesn’t ensure full compatibility, but should to decrease a work necessary for successful migration.

Attention: Tantor SE architecture is different than Oracle’s architecture. PL/pgSQL is executed in same context like SQL engine. Then is not any reason to use Oracle’s patterns like bulk collect and iteration over collection in Postgres to get good performance. This code is designed to reduce work related to porting some applications from Oracle to Postgres, and it can work well. But there will not be any performance advantage aganst buildin PL/pgSQL statements. The emulation of Oracle’s API has memory and CPU overhead, that can be significant on bigger data.

F.29.11.1. Functionality #

This extension implements subset of Oracle’s dbms_sql interface. The goal of this extension is not a compatibility with Oracle, it is designed to reduce some work related migration Oracle’s applications to Postgres. Some basic bulk DML functionality is supported:

do $$
declare
  c int;
  a int[];
  b varchar[];
  ca numeric[];
begin
  c := dbms_sql.open_cursor();
  call dbms_sql.parse(c, 'insert into foo values(:a, :b, :c)');
  a := ARRAY[1, 2, 3, 4, 5];
  b := ARRAY['Ahoj', 'Nazdar', 'Bazar'];
  ca := ARRAY[3.14, 2.22, 3.8, 4];

  call dbms_sql.bind_array(c, 'a', a, 2, 3);
  call dbms_sql.bind_array(c, 'b', b, 3, 4);
  call dbms_sql.bind_array(c, 'c', ca);
  raise notice 'inserted rows %d', dbms_sql.execute(c);
end;
$$;

do $$
declare
  c int;
  a int[];
  b varchar[];
  ca numeric[];
begin
  c := dbms_sql.open_cursor();
  call dbms_sql.parse(c, 'select i, ''Ahoj'' || i, i + 0.003 from generate_series(1, 35) g(i)');
  call dbms_sql.define_array(c, 1, a, 10, 1);
  call dbms_sql.define_array(c, 2, b, 10, 1);
  call dbms_sql.define_array(c, 3, ca, 10, 1);

  perform dbms_sql.execute(c);
  while dbms_sql.fetch_rows(c) > 0
  loop
    call dbms_sql.column_value(c, 1, a);
    call dbms_sql.column_value(c, 2, b);
    call dbms_sql.column_value(c, 3, ca);
    raise notice 'a = %', a;
    raise notice 'b = %', b;
    raise notice 'c = %', ca;
  end loop;
  call dbms_sql.close_cursor(c);
end;
$$;

There is function dbms_sql.describe_columns_f, that is like procedure dbms_sql.describe_columns. Attention, the type ids are related to Tantor SE type system. The values are not converted to Oracle’s numbers

do $$
declare
  c int;
  r record;
  d dbms_sql.desc_rec;
begin
  c := dbms_sql.open_cursor();
  call dbms_sql.parse(c, 'select * from pg_class');
  r := dbms_sql.describe_columns(c);
  raise notice '%', r.col_cnt;

  foreach d in array r.desc_t
  loop
    raise notice '% %', d.col_name, d.col_type::regtype;
  end loop;

  call dbms_sql.close_cursor(c);
end;
$$;

do $$
declare
  c int;
  n int;
  d dbms_sql.desc_rec;
  da dbms_sql.desc_rec[];
begin
  c := dbms_sql.open_cursor();
  call dbms_sql.parse(c, 'select * from pg_class');
  call dbms_sql.describe_columns(c, n, da);
  raise notice '%', n;

  foreach d in array da
  loop
    raise notice '% %', d.col_name, d.col_type::regtype;
  end loop;

  call dbms_sql.close_cursor(c);
end;
$$;

F.29.12. Package dbms_pipe #

This package is an emulation of dbms_pipe Oracle package. It provides inter-session communication. You can send and read any message with or without waiting; list active pipes; set a pipe as private or public; and, use explicit or implicit pipes.

The maximum number of pipes is 50.

Shared memory is used to send messages.

An example follows:

-- Session A
select dbms_pipe.create_pipe('my_pipe',10,true); -- explicit pipe creating
select dbms_pipe.pack_message('neco je jinak');
select dbms_pipe.pack_message('anything is else');
select dbms_pipe.send_message('my_pipe',20,0); -- change limit and send without waiting
select * from dbms_pipe.db_pipes; -- list of current pipes

-- Session B
select dbms_pipe.receive_message('my_pipe',1); -- wait max 1 sec for message
select dbms_pipe.next_item_type(); -- -> 11, text
select dbms_pipe.unpack_message_text();
select dbms_pipe.next_item_type(); -- -> 11, text
select dbms_pipe.unpack_message_text();
select dbms_pipe.next_item_type(); -- -> 0, no more items
select dbms_pipe.remove_pipe('my_pipe');

There are some differences compared to Oracle, however:

  • limit for pipes isn’t in bytes but in elements in pipe

  • you can send message without waiting

  • you can send empty messages

  • next_item_type knows about TIMESTAMP (type 13)

  • Tantor SE doesn’t know about the RAW type, use bytea instead

F.29.13. Package dbms_alert #

Another means of inter-process communication.

-- Session A
select dbms_alert.register('boo');
select * from dbms_alert.waitany(10);

-- Session B
select dbms_alert.register('boo');
select * from dbms_alert.waitany(10);

-- Session C
select dbms_alert.signal('boo','Nice day');

F.29.14. Package PLVdate #

This module contains some functions for working with business days from package PLVdate. Detailed documentation can be found in PLVision library. This package is multicultural, but default configurations are only for european countries (see source code).

You should define your own non-business days (max 50 days) and own holidays (max 30 days). A holiday is any non-business day, which is the same every year. For example, Christmas day in Western countries.

F.29.14.1. Functions #

  • plvdate.add_bizdays(day date, days int) date - Get the date created by adding <n> business days to a date

  • plvdate.nearest_bizday(day date) date - Get the nearest business date to a given date, user defined

  • plvdate.next_bizday(day date) date - Get the next business date from a given date, user defined

  • plvdate.bizdays_between(day1 date, day2 date) int - Get the number of business days between two dates

  • plvdate.prev_bizday(day date) date - Get the previous business date from a given date

  • plvdate_isbizday(date) bool - Call this function to determine if a date is a business day

  • plvdate.set_nonbizday(dow varchar) - Set day of week as non bussines day

  • plvdate.unset_nonbizday(dow varchar) - Unset day of week as non bussines day

  • plvdate.set_nonbizday(day date) - Set day as non bussines day

  • plvdate.unset_nonbizday(day date) - Unset day as non bussines day

  • plvdate.set_nonbizday(day date, repeat bool) - Set day as non bussines day, if 'repeat' is true, then day is nonbiz every year

  • plvdate.unset_nonbizday(day date, repeat bool) - Unset day as non bussines day, if 'repeat' is true, then day is nonbiz every year

  • plvdate.use_easter() - Easter Sunday and easter monday will be holiday

  • plvdate.unuse_easter();

  • plvdate.use_easter(useit boolean);

  • plvdate.using_easter() bool - If we use easter then returns true

  • plvdate.use_great_friday() - Easter Great Friday will be holiday

  • plvdate.unuse_easter();

  • plvdate.use_easter(useit boolean);

  • plvdate.using_easter() bool - If we use easter Great Friday as holiday then returns true

  • plvdate.include_start() - Include starting date in bizdays_between calculation

  • plvdate.noinclude_start();

  • plvdate.include_start(include boolean);

  • plvdate.including_start() bool;

  • plvdate.default_holidays(varchar) - load default configurations. You can use the following configurations: Czech, German, Austria, Poland, Slovakia, Russia, GB and USA at this moment.

  • configuration contains only common holidays for all regions. You can add your own regional holiday with plvdate.set_nonbizday(nonbizday, true)

Example:

postgres=# select plvdate.default_holidays('czech');
 default_holidays
 -----------------

(1 row)
postgres=# select to_char(current_date, 'day'),
           plvdate.next_bizday(current_date),
	   to_char(plvdate.next_bizday(current_date),'day');
  to_char  | next_bizday |  to_char
 ----------+-------------+-----------
 saturday  | 2006-03-13  | monday
(1 row)

Change for non-European environment:

select plvdate.unset_nonbizday('saturday');
select plvdate.unset_nonbizday('sunday');
select plvdate.set_nonbizday('friday');
select plvdate.set_nonbizday('2006-05-19', true);
select plvdate.unuse_easter();

F.29.15. Package PLVstr and PLVchr #

This package contains some useful string and character functions. Each function supports positive and negative offsets — i.e., offset from the end of the string. For example:

plvstr.left('abcdef',2) -> ab
plvstr.left('abcdef',-2) -> abcd
plvstr.substr('abcdef',1,1) -> a
plvstr.substr('abcdef',-1,1) -> f
plvstr.substr('abcde',-2,1) -> d

List of functions:

  • plvstr.normalize(str text) - Normalize string - Replace white chars by space, replace spaces by space

  • plvstr.is_prefix(str text, prefix text, cs bool) - Returns true, if prefix is prefix of str

  • plvstr.is_prefix(str text, prefix text) - Returns true, if prefix is prefix of str

  • plvstr.is_prefix(str int, prefix int) - Returns true, if prefix is prefix of str

  • plvstr.is_prefix(str bigint, prefix bigint) - Returns true, if prefix is prefix of str

  • plvstr.substr(str text, start int, len int) - Returns substring started on start_in to end

  • plvstr.substr(str text, start int) - Returns substring started on start_in to end

  • plvstr.instr(str text, patt text, start int, nth int) - Search pattern in string

  • plvstr.instr(str text, patt text, start int) - Search pattern in string

  • plvstr.instr(str text, patt text) - Search pattern in string

  • plvstr.lpart(str text, div text, start int, nth int, all_if_notfound bool) - Call this function to return the left part of a string

  • plvstr.lpart(str text, div text, start int, nth int) - Call this function to return the left part of a string

  • plvstr.lpart(str text, div text, start int) - Call this function to return the left part of a string

  • plvstr.lpart(str text, div text) - Call this function to return the left part of a string

  • plvstr.rpart(str text, div text, start int, nth int, all_if_notfound bool) - Call this function to return the right part of a string

  • plvstr.rpart(str text, div text, start int, nth int) - Call this function to return the right part of a string

  • plvstr.rpart(str text, div text, start int) - Call this function to return the right part of a string

  • plvstr.rpart(str text, div text) - Call this function to return the right part of a string

  • plvstr.lstrip(str text, substr text, num int) - Call this function to remove characters from the beginning

  • plvstr.lstrip(str text, substr text) - Call this function to remove characters from the beginning

  • plvstr.rstrip(str text, substr text, num int) - Call this function to remove characters from the end

  • plvstr.rstrip(str text, substr text) - Call this function to remove characters from the end

  • plvstr.rvrs(str text, start int, _end int) - Reverse string or part of string

  • plvstr.rvrs(str text, start int) - Reverse string or part of string

  • plvstr.rvrs(str text) - Reverse string or part of string

  • plvstr.left(str text, n int) - Returns firs num_in characters. You can use negative num_in

  • plvstr.right(str text, n int) - Returns last num_in characters. You can use negative num_ni

  • plvstr.swap(str text, replace text, start int, length int) - Replace a substring in a string with a specified string

  • plvstr.swap(str text, replace text) - Replace a substring in a string with a specified string

  • plvstr.betwn(str text, start int, _end int, inclusive bool) - Find the Substring Between Start and End Locations

  • plvstr.betwn(str text, start text, _end text, startnth int, endnth int, inclusive bool, gotoend bool) - Find the Substring Between Start and End Locations

  • plvstr.betwn(str text, start text, _end text) - Find the Substring Between Start and End Locations

  • plvstr.betwn(str text, start text, _end text, startnth int, endnth int) - Find the Substring Between Start and End Locations

  • plvchr.nth(str text, n int) - Call this function to return the Nth character in a string

  • plvchr.first(str text) - Call this function to return the first character in a string

  • plvchr.last(str text) - Call this function to return the last character in a string

  • plvchr.is_blank(c int) - Is blank

  • plvchr.is_blank(c text) - Is blank

  • plvchr.is_digit(c int) - Is digit

  • plvchr.is_digit(c text) - Is digit

  • plvchr.is_quote(c int) - Is quote

  • plvchr.is_quote(c text) - Is quote

  • plvchr.is_other(c int) - Is other

  • plvchr.is_other(c text) - Is other

  • plvchr.is_letter(c int) - Is letter

  • plvchr.is_letter(c text) - Is letter

  • plvchr.char_name(c text) - Returns the name of the character to ascii code as a VARCHAR.

  • plvchr.quoted1(str text) - Quoted text between '''

  • plvchr.quoted2(str text) - Quoted text between '"'

  • plvchr.stripped(str text, char_in text) - Strips a string of all instances of the specified characters

F.29.16. Package PLVsubst #

The PLVsubst package performs string substitutions based on a substitution keyword.

  • plvsubst.string(template_in text, vals_in text[]) - Scans a string for all instances of the substitution keyword and replace it with the next value in the substitution values list

  • plvsubst.string(template_in text, vals_in text[], subst_in text)

  • plvsubst.string(template_in text, vals_in text, delim_in text)

  • plvsubst.string(template_in text, vals_in text, delim_in text, subst_in text)

  • plvsubst.setsubst(str text) - Set substitution keyword to default '%s'

  • plvsubst.subst() - Retrieve substitution keyword

Examples:

select plvsubst.string('My name is %s %s.', ARRAY['Pavel','Stěhule']);
          string
 --------------------------
 My name is Pavel Stěhule.
(1 row)

select plvsubst.string('My name is %s %s.', 'Pavel,Stěhule');
          string
 --------------------------
 My name is Pavel Stěhule.
(1 row)

select plvsubst.string('My name is $$ $$.', 'Pavel|Stěhule','|','$$');
          string
 --------------------------
 My name is Pavel Stěhule.
(1 row)

F.29.17. Package DBMS_utility #

  • dms_utility.format_call_stack()  — return a formatted string with content of call stack

postgres=# select foo2();
               foo2
 ---------------------------------
 -----  Call Stack  -----
   line             object
 number  statement  name
      1  return     function foo
      1  return     function foo1
      1  return     function foo2
(1 row)

F.29.18. Package PLVlex #

This package isn’t compatible with original PLVlex.

postgres=# select * from
	plvlex.tokens('select * from a.b.c join d ON x=y', true, true);

 pos | token  | code |  class  | separator | mod
 ----+--------+------+---------+-----------+------
   0 | select |  527 | KEYWORD |           |
   7 | *      |   42 | OTHERS  |           | self
   9 | from   |  377 | KEYWORD |           |
  25 | a.b.c  |      | IDENT   |           |
  20 | join   |  418 | KEYWORD |           |
  25 | d      |      | IDENT   |           |
  27 | on     |  473 | KEYWORD |           |
  30 | x      |      | IDENT   |           |
  31 | =      |   61 | OTHERS  |           | self
  32 | y      |      | IDENT   |           |
(10 rows)

Warning: Keyword’s codes can be changed between Tantor SE versions! o plvlex.tokens(str text, skip_spaces bool, qualified_names bool) - Returns table of lexical elements in str.

F.29.19. Package DBMS_ASSERT #

This package protects user input against SQL injection.

  • dbms_assert.enquote_literal(varchar) varchar - Add leading and trailing quotes, verify that all single quotes are paired with adjacent single quotes.

  • dbms_assert.enquote_name(varchar [, boolean]) varchar - Enclose name in double quotes. Optional second parameter ensure loweralize of name. Attention - On Oracle is second parameter capitalize!

  • dbms_assert.noop(varchar) varchar - Returns value without any checking.

  • dbms_assert.qualified_sql_name(varchar) varchar - This function verifies that the input string is qualified SQL name.

  • dbms_assert.schema_name(varchar) varchar - Function verifies that input string is an existing schema name.

  • dbms_assert.simple_sql_name(varchar) varchar -This function verifies that the input string is simple SQL name.

  • dbms_assert.object_name(varchar) varchar - Verifies that input string is qualified SQL identifier of an existing SQL object.

F.29.20. Package PLUnit #

This unit contains some assert functions.

  • plunit.assert_true(bool [, varchar]) - Asserts that the condition is true.

  • plunit.assert_false(bool [, varchar]) - Asserts that the condition is false.

  • plunit.assert_null(anyelement [, varchar]) - Asserts that the actual is null.

  • plunit.assert_not_null(anyelement [, varchar]) - Asserts that the actual isn’t null.

  • plunit.assert_equals(anyelement, anyelement [, double precision] [, varchar]) - Asserts that expected and actual are equal.

  • plunit.assert_not_equals(anyelement, anyelement [, double precision] [, varchar]) - Asserts that expected and actual are equal.

  • plunit.fail([varchar]) - Fail can be used to cause a test procedure to fail immediately using the supplied message.

F.29.21. Package DBMS_random #

  • dbms_random.initialize(int) - Initialize package with a seed value.

  • dbms_random.normal() - Returns random numbers in a standard normal distribution.

  • dbms_random.random() - Returns random number from -2^31 .. 2^31.

  • dbms_random.seed(int)

  • dbms_random.seed(text) - Reset seed value.

  • dbms_random.string(opt text(1), len int) - Create random string

  • dbms_random.terminate() - Terminate package (do nothing in Pg)

  • dbms_random.value() - Returns a random number from [0.0 - 1.0)

  • dbms_random.value(low double precision, high double precision) - Returns a random number from [low - high)

F.29.22. Others functions #

This module contains implementation of functions: concat, nvl, nvl2, lnnvl, decode, greatest, least, bitand, nanvl, sinh, cosh, tanh, oracle.substr and oracle.mod.

  • oracle.substr(str text, start int, len int) - Oracle compatible substring

  • oracle.substr(str text, start int) - Oracle compatible substring

  • oracle.substr(str numeric, start numeric) - Oracle compatible substring

  • oracle.substr(str numeric, start numeric, len numeric) - Oracle compatible substring

  • oracle.substr(str varchar, start numeric) - Oracle compatible substring

  • oracle.substr(str varchar, start numeric,len numeric) - Oracle compatible substring

  • oracle.lpad(string, length [, fill]) - Oracle compatible lpad

  • oracle.rpad(string, length [, fill]) - Oracle compatible rpad

  • oracle.ltrim(string text [, characters text]) - Oracle compatible ltrim

  • oracle.rtrim(string text [, characters text]) - Oracle compatible rtrim

  • oracle.btrim(string text [, characters text]) - Oracle compatible btrim

  • oracle.length(string char) - Oracle compatible length

  • oracle.listagg(str text [, separator text]) - aggregate values to list

  • oracle.wm_concat(str text) - aggregate values to comma separatated list

  • oracle.median(float4) - calculate a median

  • oracle.median(float8) - calculate a median

  • oracle.to_number(text) - converts a string to a number

  • oracle.to_number(numeric) - converts a string to a number

  • oracle.to_number(numeric,numeric) - converts a string to a number

  • public.to_multi_byte(text) - Convert all single-byte characters to their corresponding multibyte characters

  • public.to_single_byte(text) - Convert all multi-byte characters to their corresponding single-byte characters

  • oracle.greatest(anyelement, anyelement[]) - Oracle compatibility greatest, return NULL on NULL input

  • oracle.least(anyelement, anyelement[]) - Oracle compatibility least, return NULL on NULL input

  • oracle.mod(int, int) - Oracle compatibility mod, If the second parameter is zero, it returns the first parameter

  • oracle.remainder(int, int) - returns remainder of number divided by another number

  • oracle.remainder(numeric, numeric) - returns remainder of number divided by another number

  • oracle.sys_guid() - returns bytea - 16 bytes of global uniq id

You might need to set search_path to 'oracle, pg_catalog, "$user", public' because oracle.substr, oracle.lpad, oracle.rpad, oracle.ltrim, oracle.rtrim, oracle.btrim, oracle.length are installed side-by-side with pg_catalog.substr, pg_catalog.lpad, pg_catalog.rpad, pg_catalog.ltrim, pg_catalog.rtrim, pg_catalog.btrim, pg_catalog.length respectively.

Functions oracle.decode, oracle.greatest and oracle.least must always be prefixed by the schema name even if the oracle is before pg_catalog in the search_path because these functions are implemented inside Tantor SE parser and analyzer. Without the schema name the internal functions will always be used.

Note that in case of lpad and rpad, parameters string and fill can be of types CHAR, VARCHAR, TEXT, VARCHAR2 or NVARCHAR2 (note that the last two are orafce-provided types). The default fill character is a half-width space. Similarly for ltrim, rtrim and btrim.

Note that oracle.length has a limitation that it works only in units of characters because Tantor SE CHAR type only supports character semantics.

The oracle.substr with three arguments can returns different result (null or empty string) in dependency to setting orafce.using_substring_zero_width_in_substr variable (oracle, warning_oracle, orafce, warning_orafce). This different result is returned only when third argument (substring_length) is zero. Default is warning_oracle, thats means raising warning and returning null.

F.29.23. oracle.sys_guid() function #

This functions returns global unique id. It calls specified functions from "uuid-ossp" extension, and then this function should be installed before function sys_guid is used. By default this function uses function uuid_generate_v1, but function uuid_generate_v1mc, uuid_generate_v4 can be used too (by setting orafce.sys_guid_source). oracle.sys_guid can use builin gen_random_uuid func too. In this case the extension "uuid-ossp" is not required.

F.29.24. VARCHAR2 and NVARCHAR2 Support #

orafce’s VARCHAR2 implements parts of Oracle database specification about VARCHAR2:

  • Unit of type modifier = 'bytes' (for character semantics, see NVARCHAR2)

  • Unlike Tantor SE varchar, implicit cast to VARCHAR2 does not truncate white spaces over declared maximum length

  • For these types is possible to use null safe || operator, when you enable orafce.varchar2_null_safe_concat TO true . The behaviour is very similar to Oracle.

    Attention: - when result is empty string, then result is NULL. This behaviour is
    disabled by default.
    Attention: - there is possible incompatibility between 3.7 and older Orafce
    releases. A operator function is now marked as stable (was immutable before).
    It's not possible to create functional indexes over stable or volatile expressions.
-- null safe concat (disabled by default)
SELECT NULL || 'hello'::varchar2 || NULL;

SET orafce.varchar2_null_safe_concat TO true;
SELECT NULL || 'hello'::varchar2 || NULL;

Please note that Tantor SE does not allow to dynamically specify how we interpret varchar strings. It always interprets them as 'character' strings as determined by database encoding. So, we cannot support both BYTE and CHARACTER semantics for a given varchar type in the same database. We chose to implement the BYTE semantics as that is default in Oracle. For CHARACTER semantics, please see NVARCHAR2 which by default always implements the CHARACTER semantics.

Please be careful when using the above type to store strings consisting of multibyte encoded characters wherein each character may be composed of an arbitrary number of bytes.

NVARCHAR2 implements the following:

  • Unit of type modifier = 'characters' (using the character set/encoding of the database)

Use this type if character semantics is preferred.

Please note that unlike Oracle, orafce’s VARCHAR2 and NVARCHAR2 do not impose the 4000 bytes limit on the 'declared' size. In fact it is same as that of Tantor SE varchar, which is about 10MB (although varchar can theoretically store values of size up to 1GB)

Some byte-based string functions to be used with VARCHAR2 strings

  • substrb(VARCHAR2, int [, int]) - extract a substring of specified length (in bytes) starting at a given byte position (counting from one); if the third argument isnot specified then length to the end of the string is considered

  • strposb(VARCHAR2, VARCHAR2) - returns the location of specified substring in a given string (counting from one)

  • lengthb(VARCHAR2) - returns the length (in bytes) of a given string

F.29.25. Triggers #

Oracle doesn’t make differences between NULL and empty string (when a value is used as text). For Postgres NULL and empty string are different values. For simplicity is good to ensure (in Postgres database) use only NULLs (and don’t use empty strings) or use only empty strings (and don’t use NULLs) for text type columns. Both variants has some advantages and disadvantages.

This can be enusured with trigger functions:

oracle.replace_empty_strings([raise_warnings boolean])
oracle.replace_null_strings([raise_warnings boolean])

Optional boolean argument is used as indicator so these functions should to raise warning when row was changed inside these functions.

CREATE TABLE test(id serial, name varchar, surname varchar);
CREATE TRIGGER test_trg
  BEFORE INSERT OR UPDATE
  ON test
  FOR EACH ROW
  EXECUTE PROCEDURE oracle.replace_empty_strings();

INSERT INTO test(name, surname) VALUES('', 'Stehule');

-- name will be replaced by NULL

F.29.26. Emulated views #

  • oracle.user_tab_columns

  • oracle.user_tables

  • oracle.user_cons_columns

  • oracle.user_constraints

  • oracle.product_componenent_version

  • oracle.user_objects

  • oracle.dba_segments

F.29.27. License #

This module is released under BSD licence.

F.29.28. Contributors #

The project was founded in 2008 by Pavel Stehule .

Other contributors:

  • Gabriele Bartolini (gbartolini)

  • Jeffrey Cohen (jcohen)

  • Giles Darold (darold)

  • Pavan Deolasee (pavanvd)

  • Peter Eisentraut (petere)

  • Beena Emerson (b-emerson)

  • Takahiro Itagaki (itagaki)

  • Zdenek Kotala (hlipa)

  • Amit Langote (amitlan)

  • Heikki Linnakangas (hlinnaka)

  • Fujii Masao

  • Marco Nenciarini (mnencia)

  • Vinayak Pokale

  • Gavin Sherry (swm)

  • Pavel Stehule (okbob)

  • Rahila Syed (rahila)

F.29.29. Orafce - Oracle’s compatibility functions and packages #

This documentation describes the environment settings and functionality offered for features that are compatible with Oracle databases.

F.29.30. Chapter 1 Overview #

Features compatible with Oracle databases are provided. These features enable you to easily migrate to Tantor SE and reduce the costs of reconfiguring applications.

The table below lists features compatible with Oracle databases.

F.29.30.1. Features compatible with Oracle databases #

Data type

Item Overview
VARCHAR2 Variable-length character data type
NVARCHAR2 Variable-length national character data type
DATE Data type that stores date and time

SQL Queries

Item Overview
DUAL table Table provided by the system

SQL Functions

  • Mathematical functions

Item Overview
BITAND Performs a bitwise AND operation
COSH Calculates the hyperbolic cosine of a number
SINH Calculates the hyperbolic sine of a number
TANH Calculates the hyperbolic tangent of a number
  • String functions

Item Overview
INSTR Returns the position of a substring in a string
LENGTH Returns the length of a string in number of characters
LENGTHB Returns the length of a string in number of bytes
LPAD Left-pads a string to a specified length with a sequence of characters
LTRIM Removes the specified characters from the beginning of a string
NLSSORT Returns a byte string used to sort strings in linguistic sort sequence based on locale
REGEXP_COUNT searches a string for a regular expression, and returns a count of the matches
REGEXP_INSTR returns the beginning or ending position within the string where the match for a pattern was located
REGEXP_LIKE condition in the WHERE clause of a query, causing the query to return rows that match the given pattern
REGEXP_SUBSTR returns the string that matches the pattern specified in the call to the function
REGEXP_REPLACE replace substring(s) matching a POSIX regular expression
RPAD Right-pads a string to a specified length with a sequence of characters
RTRIM Removes the specified characters from the end of a string
SUBSTR Extracts part of a string using characters to specify position and length
SUBSTRB Extracts part of a string using bytes to specify position and length
  • Date/time functions

Item Overview
ADD_MONTHS Adds months to a date
DBTIMEZONE Returns the value of the database time zone
LAST_DAY Returns the last day of the month in which the specified date falls
MONTHS_BETWEEN Returns the number of months between two dates
NEXT_DAY Returns the date of the first instance of a particular day of the week that follows the specified date
ROUND Rounds a date
SESSIONTIMEZONE Returns the time zone of the session
SYSDATE Returns the system date
TRUNC Truncates a date
  • Data type formatting functions

Item Overview
TO_CHAR Converts a value to a string
TO_DATE Converts a string to a date in accordance with the specified format
TO_MULTI_BYTE Converts a single-byte string to a multibyte string
TO_NUMBER Converts a value to a number in accordance with the specified format
TO_SINGLE_BYTE Converts a multibyte string to a single-byte string
  • Conditional expressions

Item Overview
DECODE Compares values, and if they match, returns a corresponding value
GREATEST Returns the greatest of the list of one or more expressions
LEAST Returns the least of the list of one or more expressions
LNNVL Evaluates if a value is false or unknown
NANVL Returns a substitute value when a value is not a number (NaN)
NVL Returns a substitute value when a value is NULL
NVL2 Returns a substitute value based on whether a value is NULL or not NULL
  • Aggregate functions

Item Overview
LISTAGG Returns a concatenated, delimited list of string values
MEDIAN Calculates the median of a set of values
  • Functions that return internal information

Item Overview
DUMP Returns internal information of a value

SQL Operators

Item Overview
Datetime operator Datetime operator for the DATE type

Packages

Item Overview
DBMS_ALERT Sends alerts to multiple sessions
DBMS_ASSERT Validates the properties of an input value
DBMS_OUTPUT Sends messages to clients
DBMS_PIPE Creates a pipe for inter-session communication
DBMS_RANDOM Generates random numbers
DBMS_UTILITY Provides various utilities
UTL_FILE Enables text file operations

F.29.31. Chapter 2 Notes on Using orafce #

Orafce is defined as user-defined functions in the “public” schema created by default when database clusters are created, so they can be available for all users without the need for special settings. For this reason, ensure that “public” (without the double quotation marks) is included in the list of schema search paths specified in the search_path parameter.

The following features provided by orafce are implemented in Tantor SE and orafce using different external specifications. In the default configuration of Tantor SE, the standard features of Tantor SE take precedence.

Features implemented in Tantor SE and orafce using different external specifications

  • Data type

Item Standard feature of Tantor SE Compatibility feature added by orafce
DATE Stores date only. Stores date and time.
  • Function

Item Standard feature of Tantor SE Compatibility feature added by orafce
LENGTH If the string is CHAR type, trailing spaces are not included in the length. If the string is CHAR type, trailing spaces are included in the length.
SUBSTR If 0 or a negative value is specified for the start position, simply subtracting 1 from the start position, the position will be shifted to the left, from where extraction will start. - If 0 is specified for the start position, extraction will start from the beginning of the string. - If a negative value is specified for the start position, extraction will start from the position counted from the end of the string.
LPAD RPAD - If the string is CHAR type, trailing spaces are removed and then the value is padded. - The result length is handled as a number of characters. - If the string is CHAR type, the value is padded without removing trailing spaces. - The result length is based on the width of the displayed string. Therefore, fullwidth characters are handled using a width of 2, and halfwidth characters are handled using a width of 1.
LTRIM RTRIM BTRIM (*1) If the string is CHAR type, trailing spaces are removed and then the value is removed. If the string is CHAR type, the value is removed without removing trailing spaces.
TO_DATE The data type of the return value is DATE. The data type of the return value is TIMESTAMP.

*1: BTRIM does not exist for Oracle databases, however, an external specification different to Tantor SE is implemented in orafce to align with the behavior of the TRIM functions.

Also, the following features cannot be used in the default configuration of Tantor SE.

Features that cannot be used in the default configuration of Tantor SE

  • Function

Feature
SYSDATE
DBTIMEZONE
SESSIONTIMEZONE
TO_CHAR (date/time value)
  • Operator

Feature
Datetime operator

To use these features, set “oracle” and “pg_catalog” in the “search_path” parameter of Tantor SE.conf. You must specify “oracle” before “pg_catalog” when doing this.

search_path = '"$user", public, oracle, pg_catalog'

Information

  • The search_path parameter specifies the order in which schemas are searched. Each feature compatible with Oracle databases is defined in the oracle schema.

  • It is recommended to set search_path in Tantor SE.conf. In this case, it will be effective for each instance.

  • The configuration of search_path can be done at the user level or at the database level. Setting examples are shown below.

  • If the standard features of Tantor SE take precedence, and features that cannot be used with the default configuration of Tantor SE are not required, it is not necessary to change the settings of search_path.

  • Example of setting at the user level

    • This can be set by executing an SQL command. In this example, user1 is used as the username.

ALTER USER user1 SET search_path = "$user",public,oracle,pg_catalog;
  • Example of setting at the database level

    • This can be set by executing an SQL command. In this example, db1 is used as the database name.
      You must specify “oracle” before “pg_catalog”.

ALTER DATABASE db1 SET search_path = "$user",public,oracle,pg_catalog;

See

  • Refer to “Server Administration” > “Client Connection Defaults” > “Statement Behavior” in the Tantor SE Documentation for information on search_path.

  • Refer to “Reference” > “SQL Commands” in the Tantor SE Documentation for information on ALTER USER and ALTER DATABASE.

F.29.32. Chapter 3 Data Types #

The following data types are supported:

  • VARCHAR2

  • NVARCHAR2

  • DATE

F.29.32.1. VARCHAR2 #

Syntax

Figure F.3. VARCHAR2

VARCHAR2

Specify the VARCHAR2 type as follows.

Data type syntax Explanation
VARCHAR2(len) String with a variable length up to len characters For len, specify an integer greater than 0. If len is omitted, the string can be any length.

General rules

  • VARCHAR2 is a character data type. Specify the number of bytes for the length.

  • Strings are of variable length. The specified value will be stored as is. The upper limit for this data type is approximately one gigabyte.

Note

The VARCHAR2 type does not support collating sequences. Therefore, the following error occurs when a collating sequence like that of an ORDER BY clause is required. At this time, the following HINT will prompt to use a COLLATE clause, however, because collating sequences are not supported, it is not possible to use this clause.

ERROR:   could not determine which collation to use for string comparison
HINT:   Use the COLLATE clause to set the collation explicitly.

If the error shown above is displayed, explicitly cast the column to VARCHAR or TEXT type.

F.29.32.2. NVARCHAR2 #

Syntax

Figure F.4. NVARCHAR2

NVARCHAR2

Specify the NVARCHAR2 type as follows.

Data type syntax Explanation
NVARCHAR2(len) National character string with a variable length up to len characters. For len, specify an integer greater than 0. If len is omitted, the string can be any length.

General rules

  • NVARCHAR2 is a national character data type. Specify the number of characters for the length.

  • Strings are of variable length. The specified value will be stored as is. The upper limit for this data type is approximately one gigabyte.

Note

The NVARCHAR2 type does not support collating sequences. Therefore, the following error occurs when a collating sequence like that of an ORDER BY clause is required. At this time, the following HINT will prompt to use a COLLATE clause, however, because collating sequences are not supported, it is not possible to use this clause.

ERROR:   could not determine which collation to use for string comparison
HINT:   Use the COLLATE clause to set the collation explicitly.

If the error shown above is displayed, explicitly cast the column to NCHAR VARYING or TEXT type.

F.29.32.3. DATE #

Syntax

Figure F.5. DATE

DATE

Specify the DATE type as follows.

Data type syntax Explanation
DATE Stores date and time

General rules

  • DATE is a date/time data type.

  • Date and time are stored in DATE. The time zone is not stored.

Note

If the DATE type of orafce is used in DDL statements such as table definitions, always set search_path before executing a DDL statement. Even if search_path is changed after definition, the data type will be the DATE type of Tantor SE.

Information

The DATE type of orafce is equivalent to the TIMESTAMP type of Tantor SE. Therefore, of the existing functions of Tantor SE, functions for which the data type of the argument is TIMESTAMP can be used.

F.29.33. Chapter 4 Queries #

The following queries are supported:

  • DUAL Table

F.29.33.1. DUAL Table #

DUAL table is a virtual table provided by the system. Use when executing SQL where access to a base table is not required, such as when performing tests to get result expressions such as functions and operators.

Example

In the following example, the current system date is returned.

SELECT  CURRENT_DATE  "date" FROM DUAL;
    date
------------
 2013-05-14
(1 row)

F.29.34. Chapter 5 SQL Function Reference #

F.29.34.1. Mathematical Functions #

The following mathematical functions are supported:

  • BITAND

  • COSH

  • SINH

  • TANH

F.29.34.1.1. BITAND #

Description

Performs a bitwise AND operation.

Syntax

Figure F.6. BITAND

BITAND

General rules

  • BITAND performs an AND operation on each bit of two integers, and returns the result.

  • Specify integer type values.

  • The data type of the return value is BIGINT.

Example

In the following example, the result of the AND operation on numeric literals 5 and 3 is returned.

SELECT BITAND(5,3) FROM DUAL;
 bitand
-------
      1
(1 row)
F.29.34.1.2. COSH #

Description

Calculates the hyperbolic cosine of a number.

Syntax

Figure F.7. COSH

COSH

General rules

  • COSH returns the hyperbolic cosine of the specified number.

  • The number must be a numeric data type.

  • The data type of the return value is DOUBLE PRECISION.

Example

In the following example, the hyperbolic cosine of the numeric literal 2.236 is returned.

SELECT COSH(2.236) FROM DUAL;
      cosh
-----------------
4.7313591000247
(1 row)
F.29.34.1.3. SINH #

Description

Calculates the hyperbolic sine of a number.

Syntax

Figure F.8. SINH

SINH

General rules

  • SINH returns the hyperbolic sine of the specified number.

  • The number must be a numeric data type.

  • The data type of the return value is DOUBLE PRECISION.

Example

In the following example, the hyperbolic sine of the numeric literal 1.414 is returned.

SELECT SINH(1.414) FROM DUAL;
      sinh
-----------------
1.93460168824956
(1 row)
F.29.34.1.4. TANH #

Description

Calculates the hyperbolic tangent of a number.

Syntax

Figure F.9. TANH

TANH

General rules

  • TANH returns the hyperbolic tangent of the specified number.

  • The number must be a numeric data type.

  • The data type of the return value is DOUBLE PRECISION.

Example

In the following example, the hyperbolic tangent of the numeric literal 3 is returned.

SELECT TANH(3) FROM DUAL;
      tanh
-----------------
0.995054753686731
(1 row)

F.29.34.2. String Functions #

The following string functions are supported:

  • BTRIM

  • INSTR

  • LENGTH

  • LENGTHB

  • LPAD

  • LTRIM

  • NLSSORT

  • REGEXP_COUNT

  • REGEXP_INSTR

  • REGEXP_LIKE

  • REGEXP_SUBSTR

  • RPAD

  • RTRIM

  • SUBSTR

  • SUBSTRB

F.29.34.2.1. BTRIM #

Description

Removes the specified characters from the beginning and end of a string.

Syntax

Figure F.10. BTRIM

BTRIM

General rules

  • BTRIM returns a string with trimChars removed from the beginning and end of string str.

  • If multiple trim characters are specified, all characters matching the trim characters are removed. If trimChars is omitted, all leading and trailing halfwidth spaces are removed.

  • The data type of the return value is TEXT.

Note

  • BTRIM does not exist for Oracle databases.

  • The CHAR type specification for BTRIM uses orafce for its behavior, which is different to that of BTRIM of Tantor SE. The search_path parameter must be modified for it to behave the same as the specification described above.

Information

The general rule for BTRIM of Tantor SE is as follows:

  • If the string is CHAR type, trailing spaces are removed and then the trim characters are removed.

See

  • Refer to “Notes on Using orafce” for information on how to edit search_path.

  • Refer to “The SQL Language” > “Functions and Operators” > “String Functions and Operators” in the Tantor SE Documentation for information on BTRIM.

Example

In the following example, a string that has had “a” removed from both ends of “aabcaba” is returned.

SELECT BTRIM('aabcaba','a') FROM DUAL;
 btrim
-------
 bcab
(1 row)
F.29.34.2.2. INSTR #

Description

Returns the position of a substring in a string.

Syntax

Figure F.11. INSTR

INSTR

General rules

  • INSTR searches for substring str2 in string str1 and returns the position (in characters) in str1 of the first character of the occurrence.

  • The search starts from the specified start position startPos in str1.

  • When startPos is 0 or negative, the start position will be the specified number of characters from the left of the end of str1, and INSTR will search backward from that point.

  • If the start position is not specified, the search will be performed from the beginning of str1.

  • If occurrences is specified, the position in str1 of the nth occurrence of str2 is returned. Only positive numbers can be specified.

  • If occurrences is not specified, the start position of the first occurrence that is found is returned.

  • If str2 is not found in str1, 0 is returned.

  • For startPos and occurrences, specify a SMALLINT or INTEGER type.

  • The data type of the return value is INTEGER.

Example

In the following example, characters “BC” are found in string “ABCACBCAAC”, and the position of those characters is returned.

SELECT INSTR('ABCACBCAAC','BC') FROM DUAL;
 instr
-------
     2
(1 row)

SELECT INSTR('ABCACBCAAC','BC',-1,2) FROM DUAL;
 instr
-------
     2
(1 row)
F.29.34.2.3. LENGTH #

Description

Returns the length of a string in number of characters.

Syntax

Figure F.12. LENGTH

LENGTH

General rules

  • LENGTH returns the number of characters in string str.

  • If the string is CHAR type, trailing spaces are included in the length.

  • The data type of the return value is INTEGER.

Note

The LENGTH specification above uses orafce for its behavior, which is different to that of LENGTH of Tantor SE. The search_path parameter must be modified for it to behave according to the orafce specification.

Information

The general rule for LENGTH of Tantor SE is as follows:

  • If the string is CHAR type, trailing spaces are not included in the length.

See

  • Refer to “Notes on Using orafce” for information on how to edit search_path.

  • Refer to “The SQL Language” > “Functions and Operators” > “String Functions and Operators” in the Tantor SE Documentation for information on LENGTH.

Example

In the following example, the number of characters in column col2 (defined using CHAR(10)) in table t1 is returned.

SELECT col2,LENGTH(col2) FROM t1 WHERE col1 = '1001';
    col2    | length
------------+--------
 AAAAA      |     10
(1 row)
F.29.34.2.4. LENGTHB #

Description

Returns the length of a string in number of bytes.

Syntax

Figure F.13. LENGTHB

LENGTHB

General rules

  • LENGTHB returns the number of bytes in string str.

  • If the string is CHAR type, trailing spaces are included in the length.

  • The data type of the return value is INTEGER.

Example

In the following example, the number of bytes in column col2 (defined using CHAR(10)) in table t1 is returned. Note that, in the second SELECT statement, each character in “*” has a length of 3 bytes, for a total of 9 bytes, and 7 bytes are added for the 7 trailing spaces. This gives a result of 16 bytes.

SELECT col2,LENGTHB(col2) FROM t1 WHERE col1 = '1001';
     col2      | lengthb
---------------+---------
 AAAAA         |      10
(1 row)

SELECT col2,LENGTHB(col2) FROM t1 WHERE col1 = '1004';
     col2      | lengthb
---------------+---------
 ***           |      16
(1 row)
F.29.34.2.5. LPAD #

Description

Left-pads a string to a specified length with a sequence of characters.

Syntax

Figure F.14. LPAD

LPAD

General rules

  • LPAD returns the result after repeatedly padding the beginning of string str with padding characters paddingStr until the string reaches length len.

  • If the string is CHAR type, the padding characters are added to the string without removing trailing spaces.

  • In the resultant string, fullwidth characters are recognized as having a length of 2, and halfwidth characters having a length of 1. If a fullwidth character cannot be included in the resultant string because there is only space available for one halfwidth character, the string is padded with a single-byte space.

  • The data type of the return value is TEXT.

Note

The LPAD specification above uses orafce for its behavior, which is different to that of LPAD of Tantor SE. The search_path parameter must be modified for it to behave according to the orafce specification.

Information

The general rules for LPAD of Tantor SE are as follows:

  • If the string is CHAR type, trailing spaces are removed and then the padding characters are added to the string.

  • The result length is the number of characters.

See

  • Refer to “Notes on Using orafce” for information on how to edit search_path.

  • Refer to “The SQL Language” > “Functions and Operators” > “String Functions and Operators” in the Tantor SE Documentation for information on LPAD.

Example

In the following example, a 10-character string that has been formed by left-padding the string “abc” with “a” is returned.

SELECT LPAD('abc',10,'a') FROM DUAL;
    lpad
------------
 aaaaaaaabc
(1 row)
F.29.34.2.6. LTRIM #

Description

Removes the specified characters from the beginning of a string.

Syntax

Figure F.15. LTRIM

LTRIM

General rules

  • LTRIM returns a string with trimChars removed from the beginning of string str.

  • If multiple trim characters are specified, all characters matching the trim characters are removed. If trimChars is omitted, all leading halfwidth spaces are removed.

  • The data type of the return value is TEXT.

Note

The LTRIM specification above uses orafce for its behavior, which is different to that of LTRIM of Tantor SE. The search_path parameter must be modified for it to behave according to the orafce specification.

Information

The general rule for LTRIM of Tantor SE is as follows:

  • If the string is CHAR type, trailing spaces are removed and then the trim characters are removed.

See

  • Refer to “Notes on Using orafce” for information on how to edit search_path.

  • Refer to “The SQL Language” > “Functions and Operators” > “String Functions and Operators” in the Tantor SE Documentation for information on LTRIM.

Example

In the following example, a string that has had “ab” removed from the beginning of “aabcab” is returned.

SELECT LTRIM('aabcab','ab') FROM DUAL;
 ltrim
-------
 cab
(1 row)
F.29.34.2.7. NLSSORT #

Description

Returns a byte string that denotes the lexical order of the locale (COLLATE).

Syntax

Figure F.16. NLSSORT

NLSSORT

General rules

  • NLSSORT is used for comparing and sorting in the collating sequence of a locale (COLLATE) that differs from the default locale.

  • Values that can be specified for the locale differ according to the operating system of the database server.

  • If the locale is omitted, it is necessary to use set_nls_sort to set the locale in advance. To set the locale using set_nls_sort, execute a SELECT statement.

Example of setting set_nls_sort using a SELECT statement

SELECT set_nls_sort('en_US.UTF8');
  • The data type of the return value is BYTEA.

Note

If specifying locale encoding, ensure it matches the database encoding.

See

Refer to “Server Administration” > “Localization” > “Locale Support” in the Tantor SE Documentation for information on the locales that can be specified.

Example

[Composition of table (t3)]

col1 col2
1001 aabcababc
2001 abcdef
3001 aacbaab

In the following example, the result of sorting column col2 in table t3 by “da_DK.UTF8” is returned.

SELECT col1,col2 FROM t3 ORDER BY NLSSORT(col2,'da_DK.UTF8');
 col1 |    col2
------+------------
 2001 | abcdef
 1001 | aabcababc
 3001 | aacbaab
(3 row)
F.29.34.2.8. REGEXP_COUNT #

Description

Searches a string for a regular expression, and returns a count of the matches.

General rules

  • REGEXP_COUNT returns the number of times pattern occurs in a source string. It returns an integer indicating the number of occurrences of pattern. If no match is found, then the function returns 0.

  • The search starts from the specified start position startPos in string, default starts from the beginning of string.

  • startPos is a positive integer, negative values to search from the end of string are not allowed.

  • flags is a character expression that lets you change the default matching behavior of the function. The value of flags can include one or more of the following characters:

    • ‘i’: case-insensitive matching.

    • ‘c’: case-sensitive and accent-sensitive matching.

    • ‘n’: the period (.) match the newline character. By default the period does not match the newline character.

    • ‘m’: treats the source string as multiple lines.

    • ‘x’: ignores whitespace characters. By default, whitespace characters match themselves. If you omit flags, then:

    • The default is case and accent sensitivity.

    • A period (.) does not match the newline character.

    • The source string is treated as a single line.

Example

SELECT REGEXP_COUNT('a'||CHR(10)||'d', 'a.d') FROM DUAL;
 regexp_count 
--------------
            0
(1 row)

SELECT REGEXP_COUNT('a'||CHR(10)||'d', 'a.d', 1, 'm') FROM DUAL;
 regexp_count 
--------------
            0
(1 row)

SELECT REGEXP_COUNT('a'||CHR(10)||'d', 'a.d', 1, 'n') FROM DUAL;
 regexp_count 
--------------
            1
(1 row)

SELECT REGEXP_COUNT('a'||CHR(10)||'d', '^d$', 1, 'm') FROM DUAL;
 regexp_count 
--------------
            1
(1 row)
F.29.34.2.9. REGEXP_INSTR #

Description

Returns the beginning or ending position within the string where the match for a pattern was located.

General rules

  • REGEXP_INSTR returns an integer indicating the beginning or ending position of the matched substring, depending on the value of the return_opt argument. If no match is found, then the function returns 0.

  • The search starts from the specified start position startPos in string, default starts from the beginning of string.

  • startPos is a positive integer, negative values to search from the end of string are not allowed.

  • occurrence is a positive integer indicating which occurrence of pattern in string should be search for. The default is 1, meaning the first occurrence of pattern in string.

  • return_opt lets you specify what should be returned in relation to the occurrence:

    • 0, the position of the first character of the occurrence is returned. This is the default.

    • 1, the position of the character following the occurrence is returned.

  • flags is a character expression that lets you change the default matching behavior of the function. See REGEXP_COUNT for detailed information.

  • For a pattern with capture group, group is a positive integer indicating which capture group in pattern shall be returned by the function. Capture groups can be nested, they are numbered in order in which their left parentheses appear in pattern. If group is zero, then the position of the entire substring that matches the pattern is returned. If group value exceed the number of capture groups in pattern, the function returns zero. A null group value returns NULL. The default value for group is zero.

Example

SELECT REGEXP_INSTR('1234567890', '(123)(4(56)(78))') FROM DUAL;
 regexp_instr 
--------------
            1
(1 row)

SELECT REGEXP_INSTR('1234567890', '(4(56)(78))', 3) FROM DUAL;
 regexp_instr 
--------------
            4
(1 row)

SELECT REGEXP_INSTR('123 123456 1234567, 1234567 1234567 12', '[^ ]+', 1, 6) FROM DUAL;
 regexp_instr 
--------------
           37

(1 row)

SELECT REGEXP_INSTR('199 Oretax Prayers, Riffles Stream, CA', '[S|R|P][[:alpha:]]{6}', 3, 2, 1) FROM DUAL;
 regexp_instr 
--------------
           28
(1 row)
F.29.34.2.10. REGEXP_LIKE #

Description

Condition in the WHERE clause of a query, causing the query to return rows that match the given pattern.

General rules

  • REGEXP_LIKE is similar to the LIKE condition, except it performs regular expression matching instead of the simple pattern matching performed by LIKE.

  • Returns a boolean, true when pattern match in string, false otherwise.

  • flags is a character expression that lets you change the default matching behavior of the function. See REGEXP_COUNT for detailed information.

Example

SELECT REGEXP_LIKE('a'||CHR(10)||'d', 'a.d', 'm') FROM DUAL;
 regexp_like 
-------------
 f
(1 row)

SELECT REGEXP_LIKE('a'||CHR(10)||'d', 'a.d', 'n') FROM DUAL;
 regexp_like 
-------------
 t
(1 row)
F.29.34.2.11. REGEXP_SUBSTR #

Description

Returns the string that matches the pattern specified in the call to the function.

General rules

  • REGEXP_SUBSTR returns the matched substring resulting from matching a POSIX regular expression pattern to a string. If no match is found, then the function returns NULL.

  • The search starts from the specified start position startPos in string, default starts from the beginning of string.

  • startPos is a positive integer, negative values to search from the end of string are not allowed.

  • occurrence is a positive integer indicating which occurrence of pattern in string should be search for. The default is 1, meaning the first occurrence of pattern in string.

  • flags is a character expression that lets you change the default matching behavior of the function. See REGEXP_COUNT for detailed information.

  • For a pattern with capture group, group is a positive integer indicating which capture group in pattern shall be returned by the function. Capture groups can be nested, they are numbered in order in which their left parentheses appear in pattern. If group is zero, then the position of the entire substring that matches the pattern is returned. If group value exceed the number of capture groups in pattern, the function returns NULL. A null group value returns NULL. The default value for group is zero.

Example

SELECT REGEXP_SUBSTR('number of your street, zipcode town, FR', ',[^,]+') FROM DUAL;
 regexp_substr  
----------------
 , zipcode town
(1 row)

SELECT regexp_substr('number of your street, zipcode town, FR', ',[^,]+', 24) FROM DUAL;
 regexp_substr 
---------------
 , FR
(1 row)

SELECT regexp_substr('number of your street, zipcode town, FR', ',[^,]+', 1, 2) FROM DUAL;
 regexp_substr 
---------------
 , FR
(1 row)

SELECT regexp_substr('1234567890 1234567890', '(123)(4(56)(78))', 1, 1, 'i', 0) FROM DUAL;
 regexp_substr 
---------------
 12345678
(1 row)
F.29.34.2.12. REGEXP_REPLACE #

Description

Returns the string that matches the pattern specified in the call to the function.

General rules

  • REGEXP_REPLACE returns a modified version of the source string where occurrences of a POSIX regular expression pattern found in the source string are replaced with the specified replacement string. If no match is found or the occurrence queried exceed the number of match, then the source string untouched is returned.

  • The search and replacement starts from the specified start position startPos in string, default starts from the beginning of string.

  • startPos is a positive integer, negative values to search from the end of string are not allowed.

  • occurrence is a positive integer indicating which occurrence of pattern in string should be search for and replaced. The default is 0, meaning all occurrences of pattern in string.

  • flags is a character expression that lets you change the default matching behavior of the function. See REGEXP_COUNT for detailed information.

Example

SELECT regexp_replace('512.123.4567 612.123.4567', '([[:digit:]]{3})\.([[:digit:]]{3})\.([[:digit:]]{4})', '(\1) \2-\3') FROM DUAL;
        regexp_replace
-------------------------------
 (512) 123-4567 (612) 123-4567
(1 row)

SELECT oracle.REGEXP_REPLACE('number   your     street,    zipcode  town, FR', '( ){2,}', ' ', 9);
             regexp_replace             
----------------------------------------
 number   your street, zipcode town, FR
(1 row)

SELECT oracle.REGEXP_REPLACE('number   your     street,    zipcode  town, FR', '( ){2,}', ' ', 9, 2);
               regexp_replace                
---------------------------------------------
 number   your     street, zipcode  town, FR
(1 row)
F.29.34.2.13. RPAD #

Description

Right-pads a string to a specified length with a sequence of characters.

Syntax

Figure F.17. RPAD

RPAD

General rules

  • RPAD returns the result after repeatedly padding the end of string str with padding characters paddingStr until the string reaches length len.

  • If the string is CHAR type, the padding characters are added to the string without removing trailing spaces.

  • In the resultant string, fullwidth characters are recognized as having a length of 2, and halfwidth characters having a length of 1. If a fullwidth character cannot be included in the resultant string because there is only space available for one halfwidth character, the string is padded with a single-byte space.

  • The data type of the return value is TEXT.

Note

The RPAD specification above uses orafce for its behavior, which is different to that of RPAD of Tantor SE. The search_path parameter must be modified for it to behave according to the orafce specification.

Information

The general rules for RPAD of Tantor SE are as follows:

  • If the string is CHAR type, trailing spaces are removed and then the padding characters are added to the string.

  • The result length is the number of characters.

See

  • Refer to “Notes on Using orafce” for information on how to edit search_path.

  • Refer to “The SQL Language” > “Functions and Operators” > “String Functions and Operators” in the Tantor SE Documentation for information on RPAD.

Example

In the following example, a 10-character string that has been formed by right-padding the string “abc” with “a” is returned.

SELECT RPAD('abc',10,'a') FROM DUAL;
    rpad
------------
 abcaaaaaaa
(1 row)
F.29.34.2.14. RTRIM #

Description

Removes the specified characters from the end of a string.

Syntax

Figure F.18. RTRIM

RTRIM

General rules

  • RTRIM returns a string with trimChars removed from the end of string str.

  • If multiple trim characters are specified, all characters matching the trim characters are removed. If trimChars is omitted, all trailing halfwidth spaces are removed.

  • The data type of the return value is TEXT.

Note

The RTRIM specification above uses orafce for its behavior, which is different to that of RTRIM of Tantor SE. The search_path parameter must be modified for it to behave the same as the orafce specification.

Information

The general rule for RTRIM of Tantor SE is as follows:

  • If the string is CHAR type, trailing spaces are removed and then the trim characters are removed.

See

  • Refer to “Notes on Using orafce” for information on how to edit search_path.

  • Refer to “The SQL Language” > “Functions and Operators” > “String Functions and Operators” in the Tantor SE Documentation for information on RTRIM.

Example

In the following example, a string that has had “ab” removed from the end of “aabcab” is returned.

SELECT RTRIM('aabcab','ab') FROM DUAL;
 rtrim
-------
 aabc
(1 row)
F.29.34.2.15. SUBSTR #

Description

Extracts part of a string using characters to specify position and length.

Syntax

Figure F.19. SUBSTR

SUBSTR

General rules

  • SUBSTR extracts and returns a substring of string str, beginning at position startPos, for number of characters len.

  • When startPos is positive, it will be the number of characters from the beginning of the string.

  • When startPos is 0, it will be treated as 1.

  • When startPos is negative, it will be the number of characters from the end of the string.

  • When len is not specified, all characters to the end of the string are returned. NULL is returned when len is less than 1.

  • For startPos and len, specify an integer or NUMERIC type. If numbers including decimal places are specified, they are truncated to integers.

  • The data type of the return value is TEXT.

Note

  • There are two types of SUBSTR. One that behaves as described above and one that behaves the same as SUBSTRING. The search_path parameter must be modified for it to behave the same as the specification described above.

  • If the change has not been implemented, SUBSTR is the same as SUBSTRING.

Information

The general rules for SUBSTRING are as follows:

  • The start position will be from the beginning of the string, whether the start position is positive, 0, or negative.

  • When len is not specified, all characters to the end of the string are returned.

  • An empty string is returned if no string is extracted or len is less than 1.

See

Refer to “The SQL Language” > “Functions and Operators” > “String Functions and Operators” in the Tantor SE Documentation for information on SUBSTRING.

Example

In the following example, part of the string “ABCDEFG” is extracted.

SELECT SUBSTR('ABCDEFG',3,4) "Substring" FROM DUAL;
 
 Substring
-----------
 CDEF
(1 row)

SELECT SUBSTR('ABCDEFG',-5,4) "Substring" FROM DUAL;

 Substring
-----------
 CDEF
(1 row)
F.29.34.2.16. SUBSTRB #

Description

Extracts part of a string using bytes to specify position and length.

Syntax

Figure F.20. SUBSTRB

SUBSTRB

General rules

  • SUBSTRB extracts and returns a substring of string str, beginning at byte position startPos, for number of bytes len.

  • When startPos is 0 or negative, extraction starts at the position found by subtracting 1 from the start position and shifting by that number of positions to the left.

  • When len is not specified, all bytes to the end of the string are returned.

  • An empty string is returned if no string is extracted or len is less than 1.

  • For startPos and len, specify a SMALLINT or INTEGER type.

  • The data type of the return value is VARCHAR2.

Note

The external specification of SUBSTRB is different to that of SUBSTR added by orafce, conforming with SUBSTRING of Tantor SE.

Example

In the following example, part of the string “aaabbbccc” is extracted.

SELECT SUBSTRB('aaabbbccc',4,3) FROM DUAL;
 substrb
-----------
 bbb
(1 row)

SELECT SUBSTRB('aaabbbccc',-2,6) FROM DUAL;
 substrb
-----------
 aaa
(1 row)

F.29.34.3. Date/time Functions #

The following date/time functions are supported:

  • ADD_MONTHS

  • DBTIMEZONE

  • LAST_DAY

  • MONTHS_BETWEEN

  • NEXT_DAY

  • ROUND

  • SESSIONTIMEZONE

  • SYSDATE

  • TRUNC

Note

If the DATE type only is shown in the date/time functions, these functions can be used in both orafce and Tantor SE.

F.29.34.3.1. ADD_MONTHS #

Description

Adds months to a date.

Syntax

Figure F.21. ADD_MONTHS

ADD_MONTHS

General rules

  • ADD_MONTHS returns date plus months.

  • For date, specify a DATE type.

  • For months, specify a SMALLINT or INTEGER type.

  • If a negative value is specified for months, the number of months is subtracted from the date.

  • The data type of the return value is DATE.

Note

If using the DATE type of orafce, it is necessary to specify “oracle” for search_path in advance.

See

Refer to “Notes on Using orafce” for information on how to edit search_path.

Example

The example below shows the result of adding 3 months to the date May 1, 2016.

SELECT ADD_MONTHS(DATE'2016/05/01',3) FROM DUAL;
     add_months
---------------------
 2016-08-01 00:00:00
(1 row)
F.29.34.3.2. DBTIMEZONE #

Description

Returns the value of the database time zone.

Syntax

Figure F.22. DBTIMEZONE

DBTIMEZONE

General rules

  • DBTIMEZONE returns the time zone value of the database.

  • The data type of the return value is TEXT.

Note

  • If using DBTIMEZONE, it is necessary to specify “oracle” for search_path in advance.

  • The time zone of the database is set to “GMT” by default. To change the time zone, change the “orafce.timezone” parameter. An example using the SET statement is shown below.

Setting example of orafce.timezone using a SET statement

SET orafce.timezone = 'Japan';
  • The orafce.timezone settings can be set using any of the methods for setting server parameters.

  • If the SQL statement is executed with orafce.timezone set, the following message may be displayed, however, the parameter settings are enabled, so you can ignore this.

WARNING:   unrecognized configuration parameter "orafce.timezone"
  • The time zones that can be set in “orafce.timezone” are the same as for the “TimeZone” server parameter.

See

  • Refer to “Notes on Using orafce” for information on how to edit search_path.

  • Refer to “The SQL Language” > “Data Types” > “Date/Time Types” in the Tantor SE Documentation for information on the time zone.

Example

In the following example, the DBTIMEZONE result is returned.

SELECT DBTIMEZONE() FROM DUAL;
 dbtimezone
------------
 GMT
(1 row)
F.29.34.3.3. LAST_DAY #

Description

Returns the last day of the month in which the specified date falls.

Syntax

Figure F.23. LAST_DAY

LAST_DAY

General rules

  • LAST_DAY returns the last day of the month in which the specified date falls.

  • For date, specify a DATE type.

  • The data type of the return value is DATE.

Note

If using the DATE type of orafce, it is necessary to specify “oracle” for search_path in advance.

See

Refer to “Notes on Using orafce” for information on how to edit search_path.

Example

In the example below, the last date of “February 01, 2016” is returned.

SELECT LAST_DAY(DATE'2016/02/01') FROM DUAL;
     last_day
---------------------
 2016-02-29 00:00:00
(1 row)
F.29.34.3.4. MONTHS_BETWEEN #

Description

Returns the number of months between two dates.

Syntax

Figure F.24. MONTHS_BETWEEN

MONTHS_BETWEEN

General rules

  • MONTHS_BETWEEN returns the difference in the number of months between date1 and date2.

  • For date1 and date2, specify a DATE type.

  • If date2 is earlier than date1, the return value will be negative.

  • If two dates fall on the same day, or each of the two dates are the last day of the month to which they belong, an integer is returned. If the days are different, one month is considered to be 31 days, and a value with the difference in the number of days divided by 31 added is returned.

  • The data type of the return value is NUMERIC.

Note

If using the DATE type of orafce, it is necessary to specify “oracle” for search_path in advance.

See

Refer to “Notes on Using orafce” for information on how to edit search_path.

Example

In the following example, the difference between the months of March 15, 2016 and November 15, 2015 is returned.

SELECT MONTHS_BETWEEN(DATE'2016/03/15', DATE'2015/11/15') FROM DUAL;
 months_between
----------------
               4
(1 row)
F.29.34.3.5. NEXT_DAY #

Description

Returns the date of the first instance of a particular day of the week that follows the specified date.

Syntax

Figure F.25. NEXT_DAY

NEXT_DAY

General rules

  • NEXT_DAY returns the date matching the first instance of dayOfWk that follows date.

  • For date, specify a DATE type.

  • Specify a numeric value or string indicating the day of the week.

Values that can be specified for the day

Setting example Overview
1 1 (Sunday) to 7 (Saturday) can be specified
‘Sun’, or ‘Sunday’ English display of the day
’*’ Japanese display of the day
  • The data type of the return value is DATE.

Note

  • If using the DATE type of orafce, it is necessary to specify “oracle” for search_path in advance.

  • The ability to use Japanese for entering days is provided by the orafce proprietary specification. Japanese cannot be used for entering days when using date/time functions other than NEXT_DAY (such as TO_DATE).

See

Refer to “Notes on Using orafce” for information on how to edit search_path.

Example

In the example below, the date of the first Friday on or after “May 1, 2016” is returned.

SELECT NEXT_DAY(DATE'2016/05/01', 'Friday') FROM DUAL;
      next_day
---------------------
 2016-05-06 00:00:00
(1 row)
F.29.34.3.6. ROUND #

Description

Rounds a date.

Syntax

Figure F.26. ROUND

ROUND

General rules

  • ROUND returns a date rounded to the unit specified by format model fmt.

  • For date, specify a DATE or TIMESTAMP type.

  • Specify the format model as a string.

Values that can be specified for the format model

Format model Rounding unit
Y,YY,YYY,YYYY, SYYYY,YEAR,SYEAR Year
I,IY,IYY,IYYY Year (values including calendar weeks, in compliance with the ISO standard)
Q Quarter
WW Week (first day of the year)
IW Week (Monday of that week)
W Week (first weekday on which the first day of the month falls)
DAY,DY,D Week (Sunday of that week)
MONTH,MON,MM,RM Month
CC,SCC Century
DDD,DD,J Day
HH,HH12,HH24 Hour
MI Minute
  • If decimal places are rounded: for year, the boundary for rounding is July 1; for month, the day is 16; and for week, the weekday is Thursday.

  • If fmt is omitted, the date is rounded by day.

  • If the DATE type of Tantor SE is specified for the date, that DATE type will be the data type of the return value. If the TIMESTAMP type is specified for the date, the data type will be TIMESTAMP WITH TIME ZONE, irrespective of whether a time zone is used.

Example

In the example below, the result of “June 20, 2016 18:00:00” rounded by Sunday of the week is returned.

SELECT ROUND(TIMESTAMP'2016/06/20 18:00:00','DAY') FROM DUAL;
         round
------------------------
 2016-06-19 00:00:00+09
(1 row)
F.29.34.3.7. SESSIONTIMEZONE #

Description

Returns the time zone of the session.

Syntax

Figure F.27. SESSIONTIMEZONE

SESSIONTIMEZONE

General rules

  • SESSIONTIMEZONE returns the time zone value between sessions.

  • The data type of the return value is TEXT.

Note

  • If using SESSIONTIMEZONE, it is necessary to specify “oracle” for search_path in advance.

  • The value returned by SESSIONTIMEZONE becomes the value set in the “TimeZone” server parameter.

See

Refer to “Notes on Using orafce” for information on how to edit search_path.

Example

In the following example, the time zone of the session is returned.

SELECT SESSIONTIMEZONE() FROM DUAL;
 sessiontimezone
-----------------
 Japan
(1 row)
F.29.34.3.8. SYSDATE #

Description

Returns the system date.

Syntax

Figure F.28. SYSDATE

SYSDATE

General rules

  • SYSDATE returns the system date.

  • The data type of the return value is the DATE type of orafce.

Note

  • If using SYSDATE, it is necessary to specify “oracle” for search_path in advance.

  • The date returned by SYSDATE depends on the time zone value of the orafce database.

See

  • Refer to “Notes on Using orafce” for information on how to edit search_path.

  • Refer to “DBTIMEZONE” for information on the time zone values of the database.

  • Refer to “The SQL Language” > “Data Types” > “Date/Time Types” in the Tantor SE Documentation for information on the time zone.

Example

In the following example, the system date is returned.

SELECT SYSDATE() FROM DUAL;
       sysdate
---------------------
 2016-06-22 08:06:51
(1 row)
F.29.34.3.9. TRUNC #

Description

Truncates a date.

Syntax

Figure F.29. TRUNC

TRUNC

General rules

  • TRUNC returns a date truncated to the unit specified by format model fmt.

  • For date, specify a DATE or TIMESTAMP type.

  • Specify the format model as a string. The values that can be specified are the same as for ROUND.

  • If fmt is omitted, the date is truncated by day.

  • If the DATE type of Tantor SE is specified for the date, that DATE type will be the data type of the return value. If the TIMESTAMP type is specified for the date, the data type will be TIMESTAMP WITH TIME ZONE, irrespective of whether a time zone is used.

See

Refer to “ROUND” for information on the values that can be specified for the format model.

Example

In the example below, the result of “August 10, 2016 15:30:00” truncated by the day is returned.

SELECT TRUNC(TIMESTAMP'2016/08/10 15:30:00','DDD') FROM DUAL;
         trunc
------------------------
 2016-08-10 00:00:00+09
(1 row)

F.29.34.4. Data Type Formatting Functions #

The following data type formatting functions are supported:

  • TO_CHAR

  • TO_DATE

  • TO_MULTI_BYTE

  • TO_NUMBER

  • TO_SINGLE_BYTE

F.29.34.4.1. TO_CHAR #

Description

Converts a value to a string.

Syntax

Figure F.30. TO_CHAR

TO_CHAR

General rules

  • TO_CHAR converts the specified number or date/time value to a string.

  • For num, specify a numeric data type.

  • For date, specify a DATE or TIMESTAMP type. Also, you must set a date/time format for the orafce.nls_date_format variable in advance. A setting example using the SET statement is shown below. Setting example of orafce.nls_date_format using a SET statement

SET orafce.nls_date_format = 'YYYY/MM/DD HH24:MI:SS';
  • The data type of the return value is TEXT.

Note

  • If using TO_CHAR for specifying date/time values, it is necessary to specify “oracle” for search_path in advance.

  • The orafce.nls_date_format settings can be set using any of the methods for setting server parameters.

  • If orafce.nls_date_format is set, the following message may be displayed when an SQL statement is executed, however, the parameter settings are enabled, so you can ignore this.

WARNING:  unrecognized configuration parameter "orafce.nls_date_format"

See

  • Refer to “Notes on Using orafce” for information on how to edit search_path.

  • Refer to “Server Administration” > “Server Configuration” > “Setting Parameters” in the Tantor SE Documentation for information on how to set the server parameters.

Example

In the following example, the numeric value “123.45” is returned as a string.

SELECT TO_CHAR(123.45) FROM DUAL;
 to_char
---------
 123.45
(1 row)
F.29.34.4.2. TO_DATE #

Description

Converts a string to a date in accordance with the specified format.

Syntax

Figure F.31. TO_DATE

TO_DATE

General rules

  • TO_DATE converts string str to a date in accordance with the specified format fmt.

  • Specify a string indicating the date/time.

  • Specify the required date/time format. If omitted, the format specified in the oracle.nls_date_format variable is used. If the oracle.nls_date_format variable has not been set, the existing date/time input interpretation is used. A setting example using the SET statement is shown below.

Setting example of orafce.nls_date_format using a SET statement

SET orafce.nls_date_format = 'YYYY/MM/DD HH24:MI:SS';
  • The data type of the return value is TIMESTAMP.

Note

  • The above TO_DATE specification uses orafce for its behavior, which is different to that of TO_DATE of Tantor SE. The search_path parameter must be modified for it to behave according to the orafce specification.

  • The orafce.nls_date_format settings can be set using any of the methods for setting server parameters.

  • If orafce.nls_date_format is set, the following message may be displayed when an SQL statement is executed, however, the parameter settings are enabled, so you can ignore this.

WARNING:   unrecognized configuration parameter "orafce.nls_date_format"

Information

The general rule for TO_DATE for specifying the data type format of Tantor SE is as follows:

  • The data type of the return value is the DATE type of Tantor SE.

See

  • Refer to “Notes on Using orafce” for information on how to edit search_path.

  • Refer to “The SQL Language” > “Functions and Operators” > “Data Type Formatting Functions” in the Tantor SE Documentation for information on TO_DATE of Tantor SE.

  • Refer to “Server Administration” > “Server Configuration” > “Setting Parameters” in the Tantor SE Documentation for information on how to set the server parameters.

  • Refer to “Date/Time Support” > “Date/Time Input Interpretation” in the Tantor SE Documentation for information on the interpretation of existing date/time input.

Example

In the following example, the string “2016/12/31” is converted to a date and returned.

SELECT TO_DATE('2016/12/31','YYYY/MM/DD') FROM DUAL;
       to_date
---------------------
 2016-12-31 00:00:00
(1 row)
F.29.34.4.3. TO_MULTI_BYTE #

Description

Converts a single-byte string to a multibyte string.

Syntax

Figure F.32. TO_MULTI_BYTE

TO_MULTI_BYTE

General rules

  • TO_MULTI_BYTE converts halfwidth characters in string str to fullwidth characters, and returns the converted string.

  • Only halfwidth alphanumeric characters, spaces and symbols can be converted.

  • The data type of the return value is TEXT.

Example

In the following example, “abc123” is converted to fullwidth characters and returned.

SELECT TO_MULTI_BYTE('abc123') FROM DUAL;
 to_multi_byte
---------------
   ******   
(1 row)

“******” is multibyte “abc123”.

F.29.34.4.4. TO_NUMBER #

Description

Converts a value to a number in accordance with the specified format.

Syntax

Figure F.33. TO_NUMBER

TO_NUMBER

General rules

  • TO_NUMBER converts the specified value to a numeric value in accordance with the specified format fmt.

  • For num, specify a numeric data type.

  • For str, specify a string indicating the numeric value. Numeric values must comprise only of convertible characters.

  • Specify the required numeric data format. The specified numeric value is handled as is as a data type expression.

  • The data type of the return value is NUMERIC.

See

Refer to “The SQL Language” > “Functions and Operators” > “Data Type Formatting Functions” in the Tantor SE Documentation for information on numeric value formats.

Example

In the following example, the numeric literal “-130.5” is converted to a numeric value and returned.

SELECT TO_NUMBER(-130.5) FROM DUAL;
 to_number
-----------
    -130.5
(1 row)
F.29.34.4.5. TO_SINGLE_BYTE #

Description

Converts a multibyte string to a single-byte string.

Syntax

Figure F.34. TO_SINGLE_BYTE

TO_SINGLE_BYTE

General rules

  • TO_SINGLE_BYTE converts fullwidth characters in string str to halfwidth characters, and returns the converted string.

  • Only fullwidth alphanumeric characters, spaces and symbols that can be displayed in halfwidth can be converted.

  • The data type of the return value is TEXT.

Example

In the following example, “******” is converted to halfwidth characters and returned. “******” is multibyte “xyz999”.

SELECT TO_SINGLE_BYTE('******') FROM DUAL;
 to_single_byte
----------------
 xyz999
(1 row)

F.29.34.5. Conditional Expressions #

The following functions for making comparisons are supported:

  • DECODE

  • GREATEST

  • LEAST

  • LNNVL

  • NANVL

  • NVL

  • NVL2

F.29.34.5.1. DECODE #

Description

Compares values and if they match, returns a corresponding value.

Syntax

Figure F.35. DECODE

DECODE

General rules

  • DECODE compares values of the value expression to be converted and the search values one by one. If the values match, a corresponding result value is returned. If no values match, the default value is returned if it has been specified. A NULL value is returned if a default value has not been specified.

  • If the same search value is specified more than once, then the result value returned is the one listed for the first occurrence of the search value.

  • The following data types can be used in result values and in the default value:

    • CHAR

    • VARCHAR

    • VARCHAR2

    • NCHAR

    • NCHAR VARYING

    • NVARCHAR2

    • TEXT

    • INTEGER

    • BIGINT

    • NUMERIC

    • DATE

    • TIME WITHOUT TIME ZONE

    • TIMESTAMP WITHOUT TIME ZONE

    • TIMESTAMP WITH TIME ZONE

  • The same data type must be specified for the values to be converted and the search values. However, note that different data types may also be specified if a literal is specified in the search value, and the value expression to be converted contains data types that can be converted.

  • If the result values and default value are all literals, the data types for these values will be as shown below:

    • If all values are string literals, all will become character types.

    • If there is one or more numeric literal, all will become numeric types.

    • If there is one or more literal cast to the datetime/time types, all will become datetime/time types.

  • If the result values and default value contain a mixture of literals and non-literals, the literals will be converted to the data types of the non-literals.

  • The same data type must be specified for all result values and for the default value. However, different data types can be specified if the data type of any of the result values or default value can be converted - these data types are listed below:

Data type combinations that can be converted by DECODE (summary)

  Other result values or default value
  Numeric typeCharacter typeDate/time type
Result value (any)Numeric typeYNN
Character typeNYN
Date/time typeNNS(*1)

Y: Can be converted

S: Some data types can be converted

N: Cannot be converted

*1: The data types that can be converted for date/time types are listed below:

Result value and default value date/time data types that can be converted by DECODE

  Other result values or default value
  DATE

TIME
WITHOUT TIME ZONE

TIMESTAMP
WITHOUT TIME ZONE

TIMESTAMP
WITH TIME ZONE

Result value (any)DATEYNYY

TIME
WITHOUT TIME ZONE

NYNN

TIMESTAMP
WITHOUT TIME ZONE

YNYY

TIMESTAMP
WITH TIME ZONE

YNYY

Y: Can be converted

N: Cannot be converted

  • The data type of the return value will be the data type within the result or default value that is longest and has the highest precision.

Example

In the following example, the value of col3 in table t1 is compared and converted to a different value. If the col3 value matches search value 1, the result value returned is “one”. If the col3 value does not match any of search values 1, 2, or 3, the default value “other number” is returned.

SELECT col1,
       DECODE(col3, 1, 'one',
                    2, 'two',
                    3, 'three',
                    'other number') "num-word"
       FROM t1;
col1  | num-word
------+----------
 1001 | one
 1002 | two
 1003 | three
(3 rows)
F.29.34.5.2. GREATEST and LEAST #

Description

The GREATEST and LEAST functions select the largest or smallest value from a list of any number of expressions. The expressions must all be convertible to a common data type, which will be the type of the result

Syntax

GREATEST(value [, ...])

LEAST(value [, ...])

General rules

  • These two function are the same behavior than the Tantor SE one except that instead of retunring NULL only when all parameters are NULL ,they return NULL when one of the parameters is NULL like in Oracle.

Example

In the following example, col1 and col3 of table t1 are returned when col3 has a value of 2000 or less, or null values.

SELECT GREATEST ('C', 'F', 'E')
 greatest
----------
 F 
(1 row)
\pset null ###
SELECT LEAST ('C', NULL, 'E')
 greatest
----------
 ###
(1 row)
F.29.34.5.3. LNNVL #

Description

Determines if a value is TRUE or FALSE for the specified condition.

Syntax

Figure F.36. LNNVL

LNNVL

General rules

  • LNNVL determines if a value is TRUE or FALSE for the specified condition. If the result of the condition is FALSE or NULL, TRUE is returned. If the result of the condition is TRUE, FALSE is returned.

  • The expression for returning TRUE or FALSE is specified in the condition.

  • The data type of the return value is BOOLEAN.

Example

In the following example, col1 and col3 of table t1 are returned when col3 has a value of 2000 or less, or null values.

SELECT col1,col3 FROM t1 WHERE LNNVL( col3 > 2000 );
 col1 | col3
------+------
 1001 | 1000
 1002 | 2000
 2002 |
(3 row)
F.29.34.5.4. NANVL #

Description

Returns a substitute value when a value is not a number (NaN).

Syntax

Figure F.37. NANVL

NANVL

General rules

  • NANVL returns a substitute value when the specified value is not a number (NaN). The substitute value can be either a number or a string that can be converted to a number.

  • For expr and substituteNum, specify a numeric data type. If expr and substituteNum have different data types, they will be converted to the data type with greater length or precision, and that is the data type that will be returned.

  • For substituteNum, you can also specify a string indicating the numeric value.

  • The data type used for the return value if a string is specified for the substitute value will be the same as the data type of expr.

Example

In the following example, “0” is returned if the value of col1 in table t1 is a NaN value.

SELECT col1, NANVL(col3,0) FROM t1;
 col1 | nanvl
------+-------
 2001 |     0
(1 row)
F.29.34.5.5. NVL #

Description

Returns a substitute value when a value is NULL.

Syntax

Figure F.38. NVL

NVL

General rules

  • NVL returns a substitute value when the specified value is NULL. When expr1 is NULL, expr2 is returned. When expr1 is not NULL, expr1 is returned.

  • Specify the same data types for expr1 and expr2. However, if a constant is specified in expr2, and the data type can also be converted by expr1, different data types can be specified. When this happens, the conversion by expr2 is done to suit the data type in expr1, so the value of expr2 returned when expr1 is a NULL value will be the value converted in the data type of expr1. This is not necessary for types (numeric, int) and (bigint, int).

Example

In the following example, “IS NULL” is returned if the value of col1 in table t1 is a NULL value.

SELECT col2, NVL(col1,'IS NULL') "nvl" FROM t1;
 col2 |   nvl
------+---------
 aaa  | IS NULL
(1 row)
F.29.34.5.6. NVL2 #

Description

Returns a substitute value based on whether a value is NULL or not NULL.

Syntax

Figure F.39. NVL2

NVL2

General rules

  • NVL2 returns a substitute value based on whether the specified value is NULL or not NULL. When expr is NULL, substitute2 is returned. When it is not NULL, substitute1 is returned.

  • Specify the same data types for expr, substitute1, and substitute2. However, if a literal is specified in substitute1 or substitute2, and the data type can also be converted by expr, different data types can be specified. When this happens, substitute1 or substitute2 is converted to suit the data type in expr, so the value of substitute2 returned when expr is a NULL value will be the value converted to the data type of expr.

Example

In the following example, if a value in column col1 in table t1 is NULL, “IS NULL” is returned, and if not NULL, “IS NOT NULL” is returned.

SELECT col2, NVL2(col1,'IS NOT NULL','IS NULL') FROM t1;
 col2 |   nvl2
------+---------
 aaa  | IS NULL
 bbb  | IS NOT NULL
(2 row)

F.29.34.6. Aggregate Functions #

The following aggregation functions are supported:

  • LISTAGG

  • MEDIAN

F.29.34.6.1. LISTAGG #

Description

Returns a concatenated, delimited list of string values.

Syntax

Figure F.40. LISTAGG

LISTAGG

General rules

  • LISTAGG concatenates and delimits a set of string values and returns the result.

  • For delimiter, specify a string. If the delimiter is omitted, a list of strings without a delimiter is returned.

  • The data type of the return value is TEXT.

Example

In the following example, the result with values of column col2 in table t1 delimited by ‘:’ is returned.

SELECT LISTAGG(col2,':') FROM t1;
      listagg
-------------------
 AAAAA:BBBBB:CCCCC
(1 row)
F.29.34.6.2. MEDIAN #

Description

Calculates the median of a set of numbers.

Syntax

Figure F.41. MEDIAN

MEDIAN

General rules

  • MEDIAN returns the median of a set of numbers.

  • The numbers must be numeric data type.

  • The data type of the return value will be REAL if the numbers are REAL type, or DOUBLE PRECISION if any other type is specified.

Example

In the following example, the median of column col3 in table t1 is returned.

SELECT MEDIAN(col3) FROM t1;
 median
--------
   2000
(1 row)

F.29.34.7. Functions That Return Internal Information #

The following functions that return internal information are supported:

  • DUMP

F.29.34.7.1. DUMP #

Description

Returns internal information of a value.

Syntax

Figure F.42. DUMP

DUMP

General rules

  • DUMP returns the internal information of the values specified in expressions in a display format that is in accordance with the output format.

  • The internal code (Typ) of the data type, the data length (Len) and the internal expression of the data are output as internal information.

  • Any data type can be specified for the expressions.

  • The display format (base n ) of the internal expression of the data is specified for the output format. The base numbers that can be specified are 8, 10, and 16. If omitted, 10 is used as the default.

  • The data type of the return value is VARCHAR.

Note

The information output by DUMP will be the complete internal information. Therefore, the values may change due to product updates, and so on.

Example

In the following example, the internal information of column col1 in table t1 is returned.

SELECT col1, DUMP(col1) FROM t1;
 col1 |                dump
------+------------------------------------
 1001 | Typ=25 Len=8: 32,0,0,0,49,48,48,49
 1002 | Typ=25 Len=8: 32,0,0,0,49,48,48,50
 1003 | Typ=25 Len=8: 32,0,0,0,49,48,48,51
(3 row)
F.29.34.7.2. Datetime Operator #

The following datetime operators are supported for the DATE type of orafce.

Datetime operator

Operation Example Result
+ DATE’2016/01/01’ + 10 2016-01-11 00:00:00
- DATE’2016/03/20’ - 35 2016-02-14 00:00:00
- DATE’2016/09/01’ - DATE’2015/12/31’ 245

Note

If using datetime operators for the DATE type of orafce, it is necessary to specify “oracle” for search_path in advance.

See

Refer to “Notes on Using orafce” for information on how to edit search_path.

F.29.35. Chapter 6 Package Reference #

A “package” is a group of features, brought together by schemas, that have a single functionality, and are used by calling from PL/pgSQL.

The following packages are supported:

  • DBMS_ALERT

  • DBMS_ASSERT

  • DBMS_OUTPUT

  • DBMS_PIPE

  • DBMS_RANDOM

  • DBMS_UTILITY

  • UTL_FILE

To call the different functionalities from PL/pgSQL, use the PERFORM statement or SELECT statement, using the package name to qualify the name of the functionality. Refer to the explanations for each of the package functionalities for information on the format for calling.

F.29.35.1. DBMS_ALERT #

Overview

The DBMS_ALERT package sends alerts from a PL/pgSQL session to multiple other PL/pgSQL sessions.

This package can be used when processing 1:N, such as when notifying alerts from a given PL/pgSQL session to another PL/pgSQL session at the same time.

Features

Feature Description
REGISTER Registers the specified alert.
REMOVE Removes the specified alert.
REMOVEALL Removes all alerts from a session.
SIGNAL Notifies alerts.
WAITANY Waits for notification of any alerts for which a session is registered.
WAITONE Waits for notification of a specific alert for which a session is registered.

Syntax

Figure F.43. DBMS_ALERT

DBMS_ALERT

F.29.35.1.1. Description of Features #

This section explains each feature of DBMS_ALERT.

REGISTER

  • REGISTER registers the specified alert to a session. By registering alerts to a session, SIGNAL notifications can be received.

  • Specify the name of the alert.

  • Alerts are case-sensitive.

  • Multiple alerts can be registered within a single session. If registering multiple alerts, call REGISTER for each alert.

Example

PERFORM DBMS_ALERT.REGISTER('sample_alert');

REMOVE

  • REMOVE removes the specified alert from a session.

  • Specify the name of the alert.

  • Alerts are case-sensitive.

  • The message left by the alert will be removed.

Example

PERFORM DBMS_ALERT.REMOVE('sample_alert');

REMOVEALL

  • REMOVEALL removes all alerts registered within a session.

  • All messages left by the alerts will be removed.

Example

PERFORM DBMS_ALERT.REMOVEALL();

SIGNAL

  • SIGNAL sends a message notification for the specified alert.

  • Specify the name of the alert for which message notifications are sent.

  • Alerts are case-sensitive.

  • In the message, specify the alert message for notifications.

  • Message notifications are not complete at the stage when SIGNAL is executed. Message notifications are sent upon committing the transaction. Message notifications are discarded if a rollback is performed after SIGNAL is executed.

  • If message notifications are sent for the same alert from multiple sessions, the messages will be accumulated without being removed.

Example

PERFORM DBMS_ALERT.SIGNAL('ALERT001','message001');

Note

If SIGNAL is issued continuously and the accumulated messages exceed a certain amount, an insufficient memory error may be output. If the memory becomes insufficient, call AITANY or WAITONE to receive an alert, and reduce the accumulated messages.

WAITANY

  • WAITANY waits for notification of any alerts registered for a session.

  • Specify the maximum wait time timeout in seconds to wait for an alert.

  • Use a SELECT statement to obtain the notified information, which is stored in the name, message and status columns.

  • The name column stores the alert names. The data type of name is TEXT.

  • The message column stores the messages of notified alerts. The data type of message is TEXT.

  • The status column stores the status code returned by the operation: 0-an alert occurred; 1-a timeout occurred. The data type of status is INTEGER.

Example

DECLARE
    alert_name         TEXT := 'sample_alert';
    alert_message      TEXT;
    alert_status       INTEGER;
BEGIN
    SELECT name,message,status INTO alert_name,alert_message,alert_status FROM DBMS_ALERT.WAITANY(60);

WAITONE

  • WAITONE waits for notification of the specified alert.

  • Specify the name of the alert to wait for.

  • Alerts are case-sensitive.

  • Specify the maximum wait time timeout in seconds to wait for the alert.

  • Use a SELECT statement to obtain the notified information, which is stored in the message and status columns.

  • The message column stores the messages of notified alerts. The data type of message is TEXT.

  • The status column stores the status code returned by the operation: 0-an alert occurred; 1-a timeout occurred. The data type of status is INTEGER.

Example

DECLARE
    alert_message   TEXT;
    alert_status    INTEGER;
BEGIN
    SELECT message,status INTO alert_message,alert_status FROM DBMS_ALERT.WAITONE('sample_alert', 60);
F.29.35.1.2. Usage Example #

Below is a usage example of the processing flow of DBMS_ALERT.

DBMS_ALERT flow

Figure F.44. DBMS_ALERT_flow

DBMS_ALERT_flow

Note

  • The target of message notifications by SIGNAL is sessions for which REGISTER is executed at the time of executing SIGNAL.

  • On the receiving side, always ensure that REMOVE or REMOVEALL is used to remove alerts as soon as the alerts are no longer needed. If a session is closed without removing the alerts, it may no longer be possible to receive a SIGNAL for alerts of the same name in another session.

  • DBMS_ALERT and DBMS_PIPE use the same memory environment. Therefore, when insufficient memory is detected for DBMS_PIPE, it is possible that insufficient memory will also be detected for DBMS_ALERT.

Usage example

  • Sending side

CREATE FUNCTION send_dbms_alert_exe() RETURNS VOID AS $$
BEGIN
    PERFORM DBMS_ALERT.SIGNAL('sample_alert','SIGNAL ALERT');
END;
$$ LANGUAGE plpgsql;
SELECT send_dbms_alert_exe();
DROP FUNCTION send_dbms_alert_exe();
  • Receiving side

CREATE FUNCTION receive_dbms_alert_exe() RETURNS VOID AS $$
DECLARE
    alert_name    TEXT := 'sample_alert';
    alert_message TEXT;
    alert_status  INTEGER;
BEGIN
    PERFORM DBMS_ALERT.REGISTER(alert_name);
    SELECT message,status INTO alert_message,alert_status FROM DBMS_ALERT.WAITONE(alert_name,300);
    RAISE NOTICE 'Message : %', alert_message;
    RAISE NOTICE 'Status  : %', alert_status;
    PERFORM DBMS_ALERT.REMOVE(alert_name);
END;
$$ LANGUAGE plpgsql;
SELECT receive_dbms_alert_exe();
DROP FUNCTION receive_dbms_alert_exe();

F.29.35.2. DBMS_ASSERT #

Overview

Performs verification of the properties of input values in PL/pgSQL.

Features

Feature Description
ENQUOTE_LITERAL Returns the specified string enclosed in single quotation marks.
ENQUOTE_NAME Returns the specified string enclosed in double quotation marks.
NOOP Returns the specified string as is.
OBJECT_NAME Verifies if the specified string is a defined identifier.
QUALIFIED_SQL_NAME Verifies if the specified string is in the appropriate format as an identifier.
SCHEMA_NAME Verifies if the specified string is a defined schema.
SIMPLE_SQL_NAME Verifies if the specified string is in the appropriate format as a single identifier.

Syntax

Figure F.45. DBMS_ASSERT

DBMS_ASSERT

F.29.35.2.1. Description of Features #

This section explains each feature of DBMS_ASSERT.

ENQUOTE_LITERAL

  • ENQUOTE_LITERAL returns the specified string enclosed in single quotation marks.

  • Specify a string enclosed in single quotation marks.

  • The data type of the return value is VARCHAR.

Example

DECLARE
    q_literal    VARCHAR(256);
BEGIN
    q_literal := DBMS_ASSERT.ENQUOTE_LITERAL('literal_word');

ENQUOTE_NAME

  • ENQUOTE_NAME returns the specified string enclosed in double quotation marks.

  • Specify a string enclosed in double quotation marks.

  • For lowercase conversion, specify TRUE or FALSE. Specify TRUE to convert uppercase characters in the string to lowercase. If FALSE is specified, conversion to lowercase will not take place. The default is TRUE.

  • If all the characters in the string are lowercase, they will not be enclosed in double quotation marks.

  • The data type of the return value is VARCHAR.

See

Refer to “The SQL Language” > “Data Types” > “Boolean Type” in the Tantor SE Documentation for information on boolean type (TRUE/FALSE) values.

Example

DECLARE
    dq_literal    VARCHAR(256);
BEGIN
    dq_literal := DBMS_ASSERT.ENQUOTE_NAME('TBL001');

NOOP

  • NOOP returns the specified string as is.

  • Specify a string.

  • The data type of the return value is VARCHAR.

Example

DECLARE
    literal    VARCHAR(256);
BEGIN
    literal := DBMS_ASSERT.NOOP('NOOP_WORD');

OBJECT_NAME

  • OBJECT_NAME verifies if the specified string is a defined identifier.

  • Specify the identifier for verification. If the identifier has been defined, the specified identifier will be returned. Otherwise, the following error will occur.

ERROR:  invalid object name
  • The data type of the return value is VARCHAR.

Example

DECLARE
    object_name    VARCHAR(256);
BEGIN
    object_name := DBMS_ASSERT.OBJECT_NAME('SCM001.TBL001');

QUALIFIED_SQL_NAME

  • QUALIFIED_SQL_NAME verifies if the specified string is in the appropriate format as an identifier.

  • Specify the identifier for verification. If the string can be used as an identifier, the specified identifier will be returned. Otherwise, the following error will occur.

ERROR:  string is not qualified SQL name
  • The data type of the return value is VARCHAR.

See

Refer to “The SQL Language” > “Lexical Structure” > “Identifiers and Key Words” in the Tantor SE Documentation for information on the formats that can be used as identifiers.

Example

DECLARE
    object_name    VARCHAR(256);
BEGIN
    object_name := DBMS_ASSERT.QUALIFIED_SQL_NAME('SCM002.TBL001');

SCHEMA_NAME

  • SCHEMA_NAME verifies if the specified string is a defined schema.

  • Specify a schema name for verification. If the schema has been defined, the specified schema name will be returned. Otherwise, the following error will occur.

ERROR:  invalid schema name
  • The data type of the return value is VARCHAR.

Example

DECLARE
    schema_name    VARCHAR(256);
BEGIN
    schema_name := DBMS_ASSERT.SCHEMA_NAME('SCM001');

SIMPLE_SQL_NAME

  • SIMPLE_SQL_NAME verifies if the specified string is in the appropriate format as a single identifier.

  • Specify an identifier for verification. If the specified string can be used as an identifier, the specified identifier will be returned. Otherwise, the following error will occur.

ERROR:  string is not qualified SQL name
  • The data type of the return value is VARCHAR.

See

Refer to “The SQL Language” > “Lexical Structure” > “Identifiers and Key Words” in the Tantor SE Documentation for information on the formats that can be used as identifiers. Note that an error will occur if an identifier using fullwidth characters is specified. If fullwidth characters are included, specify a quoted identifier.

Example

DECLARE
    simple_name    VARCHAR(256);
BEGIN
    simple_name := DBMS_ASSERT.SIMPLE_SQL_NAME('COL01');
F.29.35.2.2. Usage Example #

A usage example of DBMS_ASSERT is shown below. ~~~ CREATE FUNCTION dbms_assert_exe() RETURNS VOID AS
DECLAREwschemaVARCHAR(20) := ′public′; wtableVARCHAR(20) := ′T1′; wobjectVARCHAR(40); BEGINPERFORMDBMSASSERT.NOOP(wschema); PERFORMDBMSASSERT.SIMPLESQLNAME(wtable); PERFORMDBMSASSERT.SCHEMANAME(wschema); wobject := wschema||′.′||wtable; PERFORMDBMSASSERT.QUALIFIEDSQLNAME(wobject); PERFORMDBMSASSERT.OBJECTNAME(wobject); RAISENOTICEOBJECT : RAISENOTICETABLENAME : END;
LANGUAGE plpgsql; SELECT dbms_assert_exe(); DROP FUNCTION dbms_assert_exe(); ~~~

F.29.35.3. DBMS_OUTPUT #

Overview

Sends messages to clients such as psql from PL/pgSQL.

Features

Feature Description
ENABLE Enables features of this package.
DISABLE Disables features of this package.
SERVEROUTPUT Controls whether messages are sent.
PUT Sends messages.
PUT_LINE Sends messages with a newline character appended.
NEW_LINE Sends a newline character.
GET_LINE Retrieves a line from the message buffer.
GET_LINES Retrieves multiple lines from the message buffer.

Syntax

Figure F.46. DBMS_OUTPUT

DBMS_OUTPUT

F.29.35.3.1. Description #

This section explains each feature of DBMS_OUTPUT.

ENABLE

  • ENABLE enables the use of PUT, PUT_LINE, NEW_LINE, GET_LINE, and GET_LINES.

  • With multiple executions of ENABLE, the value specified last is the buffer size (in bytes). Specify a buffer size from 2000 to 1000000.

  • The default value of the buffer size is 20000. If NULL is specified as the buffer size, 1000000 will be used.

  • If ENABLE has not been executed, PUT, PUT_LINE, NEW_LINE, GET_LINE, and GET_LINES are ignored even if they are executed.

Example

PERFORM DBMS_OUTPUT.ENABLE(20000);

DISABLE

  • DISABLE disables the use of PUT, PUT_LINE, NEW_LINE, GET_LINE, and GET_LINES.

  • Remaining buffer information is discarded.

Example

PERFORM DBMS_OUTPUT.DISABLE();

SERVEROUTPUT

  • SERVEROUTPUT controls whether messages are sent.

  • Specify TRUE or FALSE for sendMsgs.

  • If TRUE is specified, when PUT, PUT_LINE, or NEW_LINE is executed, the message is sent to a client such as psql and not stored in the buffer.

  • If FALSE is specified, when PUT, PUT_LINE, or NEW_LINE is executed, the message is stored in the buffer and not sent to a client such as psql.

See

Refer to “The SQL Language” > “Data Types” > “Boolean Type” in the Tantor SE Documentation for information on boolean type (TRUE/FALSE) values.

Example

PERFORM DBMS_OUTPUT.SERVEROUTPUT(TRUE);

PUT

  • PUT sets the message to be sent.

  • The string is the message to be sent.

  • When TRUE is specified for SERVEROUTPUT, the messages are sent to clients such as psql.

  • When FALSE is specified for SERVEROUTPUT, the messages are retained in the buffer.

  • PUT does not append a newline character. To append a newline character, execute NEW_LINE.

  • If a string longer than the buffer size specified in ENABLE is sent, an error occurs.

Example

PERFORM DBMS_OUTPUT.PUT('abc');

PUT_LINE

  • PUT_LINE sets the message to be sent appended with a newline character.

  • The string is the message to be sent.

  • When TRUE is specified for SERVEROUTPUT, the messages are sent to clients such as psql.

  • When FALSE is specified for SERVEROUTPUT, the messages are retained in the buffer.

  • If a string longer than the buffer size specified in ENABLE is sent, an error occurs.

Example

PERFORM DBMS_OUTPUT.PUT_LINE('abc');

NEW_LINE

  • NEW_LINE appends a newline character to the message created with PUT.

  • When TRUE is specified for SERVEROUTPUT, the messages are sent to clients such as psql.

  • When FALSE is specified for SERVEROUTPUT, the messages are retained in the buffer.

Example

PERFORM DBMS_OUTPUT.NEW_LINE();

GET_LINE

  • GET_LINE retrieves a line from the message buffer.

  • Use a SELECT statement to obtain the retrieved line and status code returned by the operation, which are stored in the line and status columns.

  • The line column stores the line retrieved from the buffer. The data type of line is TEXT.

  • The status column stores the status code returned by the operation: 0-completed successfully; 1-failed because there are no more lines in the buffer. The data type of status is INTEGER.

  • If GET_LINE or GET_LINES is executed and then PUT, PUT_LINE or PUT_LINES is executed while messages that have not been retrieved from the buffer still exist, the messages not retrieved from the buffer will be discarded.

Example

DECLARE
    buff1   VARCHAR(20);
    stts1   INTEGER;
BEGIN
    SELECT line,status INTO buff1,stts1 FROM DBMS_OUTPUT.GET_LINE();

GET_LINES

  • GET_LINES retrieves multiple lines from the message buffer.

  • Specify the number of lines to retrieve from the buffer.

  • Use a SELECT statement to obtain the retrieved lines and the number of lines retrieved, which are stored in the lines and numlines columns.

  • The lines column stores the lines retrieved from the buffer. The data type of lines is TEXT.

  • The numlines column stores the number of lines retrieved from the buffer. If this number is less than the number of lines requested, then there are no more lines in the buffer. The data type of numlines is INTEGER.

  • If GET_LINE or GET_LINES is executed and then PUT, PUT_LINE, or NEW_LINE is executed while messages that have not been retrieved from the buffer still exist, the messages not retrieved from the buffer will be discarded.

Example

DECLARE
    buff    VARCHAR(20)[10];
    stts    INTEGER := 10;
BEGIN
    SELECT lines, numlines INTO buff,stts FROM DBMS_OUTPUT.GET_LINES(stts);
F.29.35.3.2. Usage Example #

A usage example of DBMS_OUTPUT is shown below.

CREATE FUNCTION dbms_output_exe() RETURNS VOID AS $$
DECLARE
    buff1 VARCHAR(20);
    buff2 VARCHAR(20);
    stts1 INTEGER;
    stts2 INTEGER;
BEGIN
    PERFORM DBMS_OUTPUT.DISABLE();
    PERFORM DBMS_OUTPUT.ENABLE();
    PERFORM DBMS_OUTPUT.SERVEROUTPUT(FALSE);
    PERFORM DBMS_OUTPUT.PUT('DBMS_OUTPUT TEST 1');
    PERFORM DBMS_OUTPUT.NEW_LINE();
    PERFORM DBMS_OUTPUT.PUT_LINE('DBMS_OUTPUT TEST 2');
    SELECT line,status INTO buff1,stts1 FROM DBMS_OUTPUT.GET_LINE();
    SELECT line,status INTO buff2,stts2 FROM DBMS_OUTPUT.GET_LINE();
    PERFORM DBMS_OUTPUT.SERVEROUTPUT(TRUE);
    PERFORM DBMS_OUTPUT.PUT_LINE(buff1);
    PERFORM DBMS_OUTPUT.PUT_LINE(buff2);
END;
$$ LANGUAGE plpgsql;
SELECT dbms_output_exe();
DROP FUNCTION dbms_output_exe();

F.29.35.4. DBMS_PIPE #

Overview

Performs communication between sessions that execute PL/pgSQL.

This package can be used for 1:1 communication, such as when data is being exchanged between sessions executing PL/pgSQL.

For pipes, there are explicit pipes and implicit pipes, and furthermore, for explicit pipes, you can select public pipes and private pipes. The characteristics of each type are as follows:

Types of pipes

Type Characteristics
Explicit pipe - CREATE_PIPE is used to create a pipe explicitly. - While creating a pipe, you can select between a public pipe and private pipe. - It is necessary to use REMOVE_PIPE to explicitly remove a pipe.
Implicit pipe - Created automatically when SEND_MESSAGE and RECEIVE_MESSAGE are used. - The pipe that is created becomes a public pipe. - When messages are received using RECEIVE_MESSAGE, if there are no additional messages remaining in the pipe, the pipe will be removed automatically.
Public pipe - Can be created as an explicit pipe or implicit pipe. - Can also be used by users other than the creator.
Private pipe - Can only be created as an explicit pipe. - Can only be used by its creator.

Note

  • Up to 50 pipes can be used concurrently by a single instance.

  • In cases where pipes are frequently created and removed repetitively, use public pipes. If you create a private pipe, internal information (the creator of the private pipe) will remain even after the pipe is removed. Thus, repeatedly creating and removing pipes may ultimately cause memory to run out.

  • If a timeout occurs without receiving a message when an implicit pipe is created by RECEIVE_MESSAGE, the pipe will not be removed.

Features

Feature Description
CREATE_PIPE Creates a public or private pipe.
NEXT_ITEM_TYPE Determines the data type of the next item in the local buffer, and returns that type.
PACK_MESSAGE Sets a message in the local buffer.
PURGE Empties the contents of the specified pipe.
RECEIVE_MESSAGE Sets a received message in the local buffer.
REMOVE_PIPE Removes the specified pipe.
RESET_BUFFER Resets the set position of the local buffer.
SEND_MESSAGE Sends the contents of the local buffer.
UNIQUE_SESSION_NAME Returns a unique session name.
UNPACK_MESSAGE_BYTEA Receives a message in the local buffer in BYTEA type.
UNPACK_MESSAGE_DATE Receives a message in the local buffer in DATE type.
UNPACK_MESSAGE_NUMBER Receives a message in the local buffer in NUMERIC type.
UNPACK_MESSAGE_RECORD Receives a message in the local buffer in RECORD type.
UNPACK_MESSAGE_TEXT Receives a message in the local buffer in TEXT type.
UNPACK_MESSAGE_TIMESTAMP Receives a message in the local buffer in TIMESTAMP type.

Syntax

Figure F.47. DBMS_PIPE

DBMS_PIPE

F.29.35.4.1. Description of Features #

This section explains each feature of DBMS_PIPE.

CREATE_PIPE

  • CREATE_PIPE explicitly creates a pipe environment for data communication.

  • Specify the name of the pipe to be created.

  • Pipe names are case-sensitive.

  • Specify the maximum number of messages that can be sent or received. If omitted, 0 (cannot send messages) will be used. Specify from 1 to 32767.

  • Specify TRUE or FALSE for private. If TRUE is specified, a private pipe will be created. If FALSE is specified, a public pipe will be created. The default is FALSE.

  • An error will occur if a pipe of the same name has already been created.

See

Refer to “The SQL Language” > “Data Types” > “Boolean Type” in the Tantor SE Documentation for information on boolean type (TRUE/FALSE) values.

Example

PERFORM DBMS_PIPE.CREATE_PIPE('P01', 100, FALSE);

NEXT_ITEM_TYPE

  • NEXT_ITEM_TYPE returns the next data type in the local buffer.

  • The data type of the return value is INTEGER. One of the following values is returned:

Values returned by NEXT_ITEM_TYPE

Return value Data type
9 NUMERIC type
11 TEXT type
12 DATE type
13 TIMESTAMP type
23 BYTEA type
24 RECORD type
0 No data in the buffer

Example

DECLARE
    i_iType    INTEGER;
BEGIN
    i_iType := DBMS_PIPE.NEXT_ITEM_TYPE();

PACK_MESSAGE

  • PACK_MESSAGE sets the specified message in the local buffer.

  • Specify the data to be set in the local buffer. The following data types can be used:

    • Character type (*1)

    • Integer type (*2)

    • NUMERIC type

    • DATE type

    • TIMESTAMP type (*3)

    • BYTEA type

    • RECORD type

*1: The character type is converted internally to TEXT type.

*2: The integer type is converted internally to NUMERIC type.

*3: The TIMESTAMP type is converted internally to TIMESTAMP WITH TIME ZONE type.

  • Each time PACK_MESSAGE is called, a new message is added to the local buffer.

  • The size of the local buffer is approximately 8 KB. However, each message has overhead, so the total size that can be stored is actually less than 8 KB. To clear the local buffer, send a message (SEND_MESSAGE), or reset the buffer (RESET_BUFFER) to its initial state.

Example

PERFORM DBMS_PIPE.PACK_MESSAGE('Message Test001');

PURGE

  • PURGE removes the messages in the pipe.

  • Specify the name of the pipe for which the messages are to be removed.

  • Pipe names are case-sensitive.

Example

PERFORM DBMS_PIPE.PURGE('P01');

Note

When PURGE is executed, the local buffer is used to remove the messages in the pipe. Therefore, if there are any messages remaining in the pipe, the local buffer will be overwritten by PURGE.

RECEIVE_MESSAGE

  • RECEIVE_MESSAGE receives messages that exist in the specified pipe, and sets those messages in the local buffer.

  • Messages are received in the units in which they are sent to the pipe by SEND_MESSAGE. Received messages are removed from the pipe after being set in the local buffer.

  • Specify the name of the pipe for which the messages are to be received.

  • Pipe names are case-sensitive.

  • Specify the maximum wait time timeout in seconds to wait for a message. If omitted, the default is 31536000 seconds (1 year).

  • The data type of the return value is INTEGER. If a message is received successfully, 0 is returned. If a timeout occurs, 1 is returned.

Example

DECLARE
    i_Ret    INTEGER;
BEGIN
    i_Ret := DBMS_PIPE.RECEIVE_MESSAGE('P01', 60);

REMOVE_PIPE

  • REMOVE_PIPE removes the specified pipe.

  • Specify the name of the pipe to be removed.

  • Pipe names are case-sensitive.

Example

PERFORM DBMS_PIPE.REMOVE_PIPE('P01');

RESET_BUFFER

  • RESET_BUFFER resets the set position of the local buffer. Any unnecessary data remaining in the local buffer can be discarded using this operation.

Example

PERFORM DBMS_PIPE.RESET_BUFFER();

SEND_MESSAGE

  • SEND_MESSAGE sends data stored in the local buffer to the specified pipe.

  • Specify the name of the pipe that the data is to be sent to.

  • Pipe names are case-sensitive.

  • Specify the maximum wait time timeout in seconds for sending data stored in the local buffer. If omitted, the default is 31536000 seconds (1 year).

  • Specify the maximum number of messages that can be sent or received. If omitted, the maximum number of messages set in CREATE_PIPE is used. If omitted in the implicit pipe, the number of messages will be unlimited. Specify from 1 to 32767.

  • If the maximum number of messages is specified in both SEND_MESSAGE and CREATE_PIPE, the larger of the values will be used.

  • The data type of the return value is INTEGER. If a message is received successfully, 0 is returned. If a timeout occurs, 1 is returned.

Example

DECLARE
    i_Ret    INTEGER;
BEGIN
    i_Ret := DBMS_PIPE.SEND_MESSAGE('P01', 10, 20);

Note

A timeout will occur during sending if the maximum number of messages is reached, or if the message being sent is too large. If a timeout occurs, use RECEIVE_MESSAGE to receive any messages that are in the pipe.

UNIQUE_SESSION_NAME

  • UNIQUE_SESSION_NAME returns a name that is unique among all the sessions. This name can be used as the pipe name.

  • Multiple calls from the same session always return the same name.

  • The data type of the return value is VARCHAR. Returns a string of up to 30 characters.

Example

DECLARE
    p_Name   VARCHAR(30);
BEGIN
    p_Name := DBMS_PIPE.UNIQUE_SESSION_NAME();

UNPACK_MESSAGE_BYTEA

  • NPACK_MESSAGE_BYTEA receives BTYEA type messages in the local buffer.

  • Messages are received in the unit set in the local buffer by PACK_MESSAGE. Received messages are removed from the local buffer.

  • The data type of the return value is BYTEA.

  • If no messages exist in the local buffer, a NULL value is returned.

  • For the data type, it is necessary to align with the data type set by PACK_MESSAGE. If the data type is different, the following error will occur.

ERROR:  datatype mismatch
DETAIL:  unpack unexpected type: xx

Example

DECLARE
    g_Bytea   BYTEA;
BEGIN
    g_Bytea := DBMS_PIPE.UNPACK_MESSAGE_BYTEA();

UNPACK_MESSAGE_DATE

  • UNPACK_MESSAGE_DATE receives DATE type messages in the local buffer.

  • Messages are received in the unit set in the local buffer by PACK_MESSAGE. Received messages are removed from the local buffer.

  • The data type of the return value is DATE.

  • If no messages exist in the local buffer, a NULL value is returned.

  • For the data type, it is necessary to align with the data type set by PACK_MESSAGE. If the data type is different, the following error will occur.

ERROR:  datatype mismatch
DETAIL:  unpack unexpected type: xx

Example

DECLARE
    g_Date   DATE;
BEGIN
    g_Date := DBMS_PIPE.UNPACK_MESSAGE_DATE();

Note

If the “oracle” schema is set in search_path, the DATE type of orafce will be used, so for receiving data, use UNPACK_MESSAGE_TIMESTAMP. UNPACK_MESSAGE_DATE is the interface for the DATE type of Tantor SE.

UNPACK_MESSAGE_NUMBER

  • UNPACK_MESSAGE_NUMBER receives NUMERIC type messages in the local buffer.

  • Messages are received in the unit set in the local buffer by PACK_MESSAGE. Received messages are removed from the local buffer.

  • The data type of the return value is NUMERIC.

  • If no messages exist in the local buffer, a NULL value is returned.

  • For the data type, it is necessary to align with the data type set by PACK_MESSAGE. If the data type is different, the following error will occur.

ERROR:  datatype mismatch
DETAIL:  unpack unexpected type: xx

Example

DECLARE
    g_Number   NUMERIC;
BEGIN
    g_Number := DBMS_PIPE.UNPACK_MESSAGE_NUMBER();

UNPACK_MESSAGE_RECORD

  • UNPACK_MESSAGE_RECORD receives RECORD type messages in the local buffer.

  • Messages are received in the unit set in the local buffer by PACK_MESSAGE. Received messages are removed from the local buffer.

  • The data type of the return value is RECORD.

  • If no messages exist in the local buffer, a NULL value is returned.

  • For the data type, it is necessary to align with the data type set by PACK_MESSAGE. If the data type is different, the following error will occur.

ERROR:  datatype mismatch
DETAIL:  unpack unexpected type: xx

Example

DECLARE
    msg1     TEXT;
    status   NUMERIC;
BEGIN
    SELECT col1, col2 INTO msg1, status FROM DBMS_PIPE.UNPACK_MESSAGE_RECORD();

UNPACK_MESSAGE_TEXT

  • UNPACK_MESSAGE_TEXT receives TEXT type messages in the local buffer.

  • Messages are received in the unit set in the local buffer by PACK_MESSAGE. Received messages are removed from the local buffer.

  • The data type of the return value is TEXT.

  • If no messages exist in the local buffer, a NULL value is returned.

  • For the data type, it is necessary to align with the data type set by PACK_MESSAGE. If the data type is different, the following error will occur.

ERROR:  datatype mismatch
DETAIL:  unpack unexpected type: xx

Example

DECLARE
    g_Text   TEXT;
BEGIN
    g_Text := DBMS_PIPE.UNPACK_MESSAGE_TEXT();

UNPACK_MESSAGE_TIMESTAMP

  • UNPACK_MESSAGE_TIMESTAMP receives TIMESTAMP WITH TIME ZONE type messages in the local buffer.

  • Messages are received in the unit set in the local buffer by PACK_MESSAGE. Received messages are removed from the local buffer.

  • The data type of the return value is TIMESTAMP WITH TIME ZONE.

  • If no messages exist in the local buffer, a NULL value is returned.

  • For the data type, it is necessary to align with the data type set by PACK_MESSAGE. If the data type is different, the following error will occur.

ERROR:  datatype mismatch
DETAIL:  unpack unexpected type: xx

Example

DECLARE
    g_Timestamptz   TIMESTAMP WITH TIME ZONE;
BEGIN
    g_Timestamptz := DBMS_PIPE.UNPACK_MESSAGE_TIMESTAMP();
F.29.35.4.2. Usage Example #

Below is a usage example of the processing flow of DBMS_PIPE.

Flow of DBMS_PIPE

Figure F.48. DBMS_PIPE_flow

DBMS_PIPE_flow

Note

  • When CREATE_PIPE is used to explicitly create a pipe, ensure to use REMOVE_PIPE to remove the pipe. If a pipe is not removed explicitly, once created, it will remain until the instance is stopped.

  • In the flow diagram, CREATE_PIPE and REMOVE_PIPE are described on the receiving side, however, these can be executed on the sending side. In order to maintain consistency, it is recommended to create and remove pipes on one side.

  • An error will occur for CREATE_PIPE if a pipe of the same name already exists. Implicitly created pipes are also the target of SEND_MESSAGE and RECEIVE_MESSAGE, so when executing CREATE_PIPE, ensure that SEND_MESSAGE and RECEIVE_MESSAGE are not called beforehand.

  • DBMS_ALERT and DBMS_PIPE use the same memory environment. Therefore, when insufficient memory is detected for DBMS_ALERT, it is possible that insufficient memory will also be detected for DBMS_PIPE.

Information

The information of pipes that are in use can be viewed in the DBMS_PIPE.DB_PIPES view.

SELECT * from dbms_pipe.db_pipes;
 name | items | size | limit | private | owner
------+-------+------+-------+---------+-------
 P01  |     1 |   18 |   100 | f       |
(1 row)

Usage example

  • Sending side

CREATE FUNCTION send_dbms_pipe_exe(IN pipe_mess text) RETURNS void AS $$
DECLARE
    pipe_name text := 'sample_pipe';
    pipe_time timestamp := current_timestamp;
    pipe_stat int;
BEGIN
    PERFORM DBMS_PIPE.RESET_BUFFER();
    PERFORM DBMS_PIPE.PACK_MESSAGE(pipe_mess);
    PERFORM DBMS_PIPE.PACK_MESSAGE(pipe_time);
    pipe_stat := DBMS_PIPE.SEND_MESSAGE(pipe_name); 
    RAISE NOTICE 'PIPE_NAME: % SEND Return Value =%', pipe_name, pipe_stat;
END;
$$ LANGUAGE plpgsql;

SELECT send_dbms_pipe_exe('Sample Message.');
DROP FUNCTION send_dbms_pipe_exe(text);
  • Receiving side

CREATE FUNCTION receive_dbms_pipe_exe() RETURNS void AS $$
DECLARE
    pipe_name text := 'sample_pipe';
    pipe_text text;
    pipe_nume numeric;
    pipe_date date;
    pipe_time timestamp with time zone;
    pipe_byte bytea;
    pipe_reco record;
    pipe_item int;
    pipe_stat int;
BEGIN
    pipe_stat := DBMS_PIPE.RECEIVE_MESSAGE(pipe_name,300);
    RAISE NOTICE 'Return Value = %', pipe_stat;
    LOOP
        pipe_item := DBMS_PIPE.NEXT_ITEM_TYPE();
        RAISE NOTICE 'Next Item : %', pipe_item;
        IF (pipe_item = 9) THEN
            pipe_nume := DBMS_PIPE.UNPACK_MESSAGE_NUMBER();
            RAISE NOTICE 'Get Message : %' ,pipe_nume;
        ELSIF (pipe_item =11) THEN
            pipe_text := DBMS_PIPE.UNPACK_MESSAGE_TEXT();
            RAISE NOTICE 'Get Message : %' ,pipe_text;
        ELSIF (pipe_item = 12) THEN
            pipe_date := DBMS_PIPE.UNPACK_MESSAGE_DATE();
            RAISE NOTICE 'Get Message : %' ,pipe_date;
        ELSIF (pipe_item = 13) THEN
            pipe_time := DBMS_PIPE.UNPACK_MESSAGE_TIMESTAMP();
            RAISE NOTICE 'Get Message : %' ,pipe_time;
        ELSIF (pipe_item = 23) THEN
            pipe_byte := DBMS_PIPE.UNPACK_MESSAGE_BYTEA();
            RAISE NOTICE 'Get Message : %' ,pipe_byte;
        ELSIF (pipe_item = 24) THEN
            pipe_reco := DBMS_PIPE.UNPACK_MESSAGE_RECORD();
            RAISE NOTICE 'Get Message : %' ,pipe_reco;
        ELSE
            EXIT;
        END IF;
    END LOOP;
    PERFORM DBMS_PIPE.REMOVE_PIPE(pipe_name);
END;
$$ LANGUAGE plpgsql;

SELECT receive_dbms_pipe_exe();
DROP FUNCTION receive_dbms_pipe_exe();

F.29.35.5. DBMS_RANDOM #

Overview

Generates random numbers in PL/pgSQL.

Features

Feature Description
INITIALIZE Initializes the generation of random numbers.
NORMAL Returns a normally distributed random number.
RANDOM Generates a random number.
SEED Resets the seed value.
STRING Generates a random string.
TERMINATE Terminates generation of random numbers.
VALUE Generates a random decimal number between 0 and 1, or between specified values.

Syntax

Figure F.49. DBMS_RANDOM

DBMS_RANDOM

F.29.35.5.1. Description of Features #

This section explains each feature of DBMS_RANDOM.

INITIALIZE

  • INITIALIZE initializes the generation of random numbers using the specified seed value.

  • For seedVal, specify a SMALLINT or INTEGER type.

Example

PERFORM DBMS_RANDOM.INITIALIZE(999);

NORMAL

  • NORMAL generates and returns a normally distributed random number.

  • The return value type is DOUBLE PRECISION.

Example

DECLARE
    d_RunNum   DOUBLE PRECISION;
BEGIN
    d_RunNum := DBMS_RANDOM.NORMAL();

RANDOM

  • RANDOM generates and returns a random number.

  • The data type of the return value is INTEGER.

Example

DECLARE
    d_RunInt   INTEGER;
BEGIN
    d_RunInt := DBMS_RANDOM.RANDOM();

SEED

  • SEED initializes the generation of a random number using the specified seed value or seed string.

  • For seedVal, specify a SMALLINT or INTEGER type.

  • Any string can be specified for the seed string.

Example

PERFORM DBMS_RANDOM.SEED('123');

STRING

  • STRING generates and returns a random string in accordance with the specified display format and string length.

  • For the display format fmt, specify any of the following values. An error will occur if any other value is specified.

Values that can be specified for the display format

Setting value Generated string
‘u’, ‘U’ Uppercase letters only
‘l’, ‘L’ Lowercase letters only
‘a’, ‘A’ Mixture of uppercase and lowercase letters
‘x’, ‘X’ Uppercase letters and numbers
‘p’, ‘P’ Any displayable character
  • Specify the length of the string to be generated. Specify a SMALLINT or INTEGER type.

  • The data type of the return value is TEXT.

Example

DECLARE
    d_RunStr   TEXT;
BEGIN
    d_RunStr := DBMS_RANDOM.STRING('a', 20);

TERMINATE

  • Call TERMINATE to terminate generation of random numbers.

Information

TERMINATE does not do anything, but has been included for compatibility with Oracle databases.

Example

PERFORM DBMS_RANDOM.TERMINATE();

VALUE

  • VALUE generates and returns a random number within the specified range.

  • For min and max, specify a numeric data type. A random number between and inclusive of the minimum value and maximum value is generated.

  • If the minimum value and maximum value are omitted, a random decimal number between 0 and 1 will be generated.

  • The data type of the return value is DOUBLE PRECISION.

Example

DECLARE
    d_RunDbl   DOUBLE PRECISION;
BEGIN
    d_RunDbl := DBMS_RANDOM.VALUE();
F.29.35.5.2. Usage Example #

A usage example of DBMS_RANDOM is shown below.

CREATE FUNCTION dbms_random_exe() RETURNS VOID AS $$
DECLARE
    w_rkey VARCHAR(10) := 'rnd111';
    i_rkey INTEGER := 97310;
BEGIN
    PERFORM DBMS_RANDOM.INITIALIZE(i_rkey);
    RAISE NOTICE 'RANDOM -> NORMAL : %', DBMS_RANDOM.NORMAL();
    RAISE NOTICE 'RANDOM -> RANDOM : %', DBMS_RANDOM.RANDOM();
    RAISE NOTICE 'RANDOM -> STRING : %', DBMS_RANDOM.STRING('a',10);
    RAISE NOTICE 'RANDOM -> VALUE  : %', DBMS_RANDOM.VALUE();
    PERFORM DBMS_RANDOM.SEED(w_rkey);
    RAISE NOTICE 'RANDOM -> NORMAL : %', DBMS_RANDOM.NORMAL();
    RAISE NOTICE 'RANDOM -> RANDOM : %', DBMS_RANDOM.RANDOM();
    RAISE NOTICE 'RANDOM -> STRING : %', DBMS_RANDOM.STRING('p',10);
    RAISE NOTICE 'RANDOM -> VALUE  : %', DBMS_RANDOM.VALUE(1,100);
    PERFORM DBMS_RANDOM.TERMINATE();
END;
$$ LANGUAGE plpgsql;
SELECT dbms_random_exe();
DROP FUNCTION dbms_random_exe();

F.29.35.6. DBMS_UTILITY #

Overview

Provides utilities of PL/pgSQL.

Features

Feature Description
FORMAT_CALL_STACK Returns the current call stack.
GET_TIME Returns the number of hundredths of seconds that have elapsed since a point in time in the past.

Syntax

Figure F.50. DBMS_UTILITY

DBMS_UTILITY

F.29.35.6.1. Description of Features #

This section explains each feature of DBMS_UTILITY.

FORMAT_CALL_STACK

  • FORMAT_CALL_STACK returns the current call stack of PL/pgSQL.

  • For the display format fmt, specify any of the following values. An error will occur if any other value is specified.

Values that can be specified for the display format

Setting value Displayed content
‘o’ Standard-format call stack display (with header)
‘s’ Standard-format call stack display (without header)
‘p’ Comma-delimited call stack display (without header)
  • If the display format is omitted, display format ‘o’ will be used.

  • The data type of the return value is TEXT.

Example

DECLARE
    s_StackTrace   TEXT
BEGIN
    s_StackTrace := DBMS_UTILITY.FORMAT_CALL_STACK();

Note

If a locale other than English is specified for the message locale, the call stack result may not be retrieved correctly. To correctly retrieve the call stack result, specify English as the message locale.

F.29.35.6.2. Usage Example #

A usage example of DBMS_UTILITY is shown below.

CREATE FUNCTION dbms_utility1_exe() RETURNS VOID AS $$
DECLARE
    s_StackTrace TEXT;
BEGIN
    s_StackTrace := DBMS_UTILITY.FORMAT_CALL_STACK();
    RAISE NOTICE '%', s_StackTrace;
END;
$$ LANGUAGE plpgsql;

CREATE FUNCTION dbms_utility2_exe() RETURNS VOID AS $$
BEGIN
    PERFORM dbms_utility1_exe();
END;
$$ LANGUAGE plpgsql;

SELECT dbms_utility2_exe();
DROP FUNCTION dbms_utility2_exe();
DROP FUNCTION dbms_utility1_exe();

GET_TIME

  • GET_TIME returns the current time in 100th’s of a second from a point in time in the past. This function is used for determining elapsed time.

Example

DO $$
DECLARE
    start_time integer;
    end_time integer;
BEGIN
    start_time := DBMS_UTILITY.GET_TIME;
    PERFORM pg_sleep(10);
    end_time := DBMS_UTILITY.GET_TIME;
    RAISE NOTICE 'Execution time: % seconds', (end_time - start_time)/100;
END
$$;

Note

The function is called twice, the first time at the beginning of some procedural code and the second time at end. Then the first (earlier) number is subtracted from the second (later) number to determine the time elapsed. Must be divided by 100 to report the number of seconds elapsed.

F.29.35.7. UTL_FILE #

Overview

Text files can be written and read using PL/pgSQL.

To perform these file operations, the directory for the operation target must be registered in the UTL_FILE.UTL_FILE_DIR table beforehand. Use the INSERT statement as the database administrator or a user who has INSERT privileges to register the directory. Also, if the directory is no longer necessary, delete it from the same table. Refer to “Registering and Deleting Directories” for information on the how to register and delete the directory.

Declare the file handler explained hereafter as follows in PL/pgSQL:

DECLARE
f UTL_FILE.FILE_TYPE;

Features

Feature Description
FCLOSE Closes a file.
FCLOSE_ALL Closes all files open in a session.
FCOPY Copies a whole file or a contiguous portion thereof.
FFLUSH Flushes the buffer.
FGETATTR Retrieves the attributes of a file.
FOPEN Opens a file.
FREMOVE Deletes a file.
FRENAME Renames a file.
GET_LINE Reads a line from a text file.
IS_OPEN Checks if a file is open.
NEW_LINE Writes newline characters.
PUT Writes a string.
PUT_LINE Appends a newline character to a string and writes the string.
PUTF Writes a formatted string.

Syntax

Figure F.51. UTL_FILE

UTL_FILE

F.29.35.7.1. Registering and Deleting Directories #

Registering the directory

1 . Check if the directory is already registered (if it is, then step 2 is not necessary).

SELECT * FROM UTL_FILE.UTL_FILE_DIR WHERE dir='/home/pgsql';

2 . Register the directory.

INSERT INTO UTL_FILE.UTL_FILE_DIR VALUES('/home/pgsql');

Deleting the directory

DELETE FROM UTL_FILE.UTL_FILE_DIR WHERE dir='/home/pgsql';
F.29.35.7.2. Description #

This section explains each feature of UTL_FILE.

FCLOSE

  • FCLOSE closes a file that is open.

  • Specify an open file handle.

  • The value returned is a NULL value.

Example

f := UTL_FILE.FCLOSE(f);

FCLOSE_ALL

  • FCLOSE_ALL closes all files open in a session.

  • Files closed with FCLOSE_ALL can no longer be read or written.

Example

PERFORM UTL_FILE.FCLOSE_ALL();

FCOPY

  • FCOPY copies a whole file or a contiguous portion thereof. The whole file is copied if startLine and endLine are not specified.

  • Specify the directory location of the source file.

  • Specify the source file.

  • Specify the directory where the destination file will be created.

  • Specify the name of the destination file.

  • Specify the line number at which to begin copying. Specify a value greater than 0. If not specified, 1 is used.

  • Specify the line number at which to stop copying. If not specified, the last line number of the file is used.

Example

PERFORM UTL_FILE.FCOPY('/home/pgsql', 'regress_pgsql.txt', '/home/pgsql', 'regress_pgsql2.txt');

FFLUSH

  • FFLUSH forcibly writes the buffer data to a file.

  • Specify an open file handle.

Example

PERFORM UTL_FILE.FFLUSH(f);

FGETATTR

  • FGETATTR retrieves file attributes: file existence, file size, and information about the block size of the file.

  • Specify the directory where the file exists.

  • Specify the relevant file name.

  • Use a SELECT statement to obtain the file attributes, which are stored in the fexists, file_length, and blocksize columns.

  • The fexists column stores a boolean (TRUE/FALSE) value. If the file exists, fexists is set to TRUE. If the file does not exist, fexists is set to FALSE. The data type of fexists is BOOLEAN.

  • The file_length column stores the length of the file in bytes. If the file does not exist, file_length is NULL. The data type of file_length is INTEGER.

  • The blocksize column stores the block size of the file in bytes. If the file does not exist, blocksize is NULL. The data type of blocksize is INTEGER.

Example

SELECT fexists, file_length, blocksize INTO file_flag, file_len, size
FROM UTL_FILE.FGETATTR('/home/pgsql', 'regress_pgsql.txt');

FOPEN

  • FOPEN opens a file.

  • Specify the directory where the file exists.

  • Specify the file name.

  • Specify the mode for opening the file:

r: Read

w: Write

a: Add

  • Specify the maximum string length (in bytes) that can be processed with one operation. If omitted, the default is 1024. Specify a value from 1 to 32767.

  • Up to 50 files per session can be open at the same time.

Example

f := UTL_FILE.FOPEN('/home/pgsql','regress_pgsql.txt','r',1024);

FREMOVE

  • FREMOVE deletes a file.

  • Specify the directory where the file exists.

  • Specify the file name.

Example

PERFORM UTL_FILE.FREMOVE('/home/pgsql', 'regress_pgsql.txt');

FRENAME

  • FRENAME renames a file.

  • Specify the directory location of the source file.

  • Specify the source file to be renamed.

  • Specify the directory where the renamed file will be created.

  • Specify the new name of the file.

  • Specify whether to overwrite a file if one exists with the same name and in the same location as the renamed file. If TRUE is specified, the existing file will be overwritten. If FALSE is specified, an error occurs. If omitted, FALSE is set.

See

Refer to “The SQL Language” > “Data Types” > “Boolean Type” in the Tantor SE Documentation for information on boolean type (TRUE/FALSE) values.

Example

PERFORM UTL_FILE.FRENAME('/home/pgsql', 'regress_pgsql.txt', '/home/pgsql',
 'regress_pgsql2.txt', TRUE);

GET_LINE

  • GET_LINE reads a line from a file.

  • Specify the file handle returned by FOPEN using r (read) mode.

  • Specify the number of bytes to read from the file. If not specified, the maximum string length specified at FOPEN will be used.

  • The return value is the buffer that receives the line read from the file.

  • Newline characters are not loaded to the buffer.

  • An empty string is returned if a blank line is loaded.

  • Specify the maximum length (in bytes) of the data to be read. Specify a value from 1 to 32767. If not specified, the maximum string length specified at FOPEN is set. If no maximum string length is specified at FOPEN, 1024 is set.

  • If the line length is greater than the specified number of bytes to read, the remainder of the line is read on the next call.

  • A NO_DATA_FOUND exception will occur when trying to read past the last line.

Example

buff := UTL_FILE.GET_LINE(f);

IS_OPEN

  • IS_OPEN checks if a file is open.

  • Specify the file handle.

  • The return value is a BOOLEAN type. TRUE represents an open state and FALSE represents a closed state.

See

Refer to “The SQL Language” > “Data Types” > “Boolean Type” in the Tantor SE Documentation for information on boolean type (TRUE/FALSE) values.

Example

IF UTL_FILE.IS_OPEN(f) THEN
   PERFORM UTL_FILE.FCLOSE(f);
END IF;

NEW_LINE

  • NEW_LINE writes one or more newline characters.

  • Specify an open file handle.

  • Specify the number of newline characters to be written to the file. If omitted, “1” is used.

Example

PERFORM UTL_FILE.NEW_LINE(f, 2);

PUT

  • PUT writes a string to a file.

  • Specify the file handle that was opened with FOPEN using w (write) or a (append).

  • Specify the string to be written to the file.

  • The maximum length (in bytes) of the string to be written is the maximum string length specified at FOPEN.

  • PUT does not append a newline character. To append a newline character, execute NEW_LINE.

Example

PERFORM UTL_FILE.PUT(f, 'ABC');

PUT_LINE

  • PUT_LINE appends a newline character to a string and writes the string.

  • Specify the file handle that was opened with FOPEN w (write) or a (append).

  • Specify whether to forcibly write to the file. If TRUE is specified, file writing is forced. If FALSE is specified, file writing is asynchronous. If omitted, FALSE will be set.

  • The maximum length of the string (in bytes) is the maximum string length specified at FOPEN.

Example

PERFORM UTL_FILE.PUT_LINE(f, 'ABC', TRUE);

PUTF

  • PUTF writes a formatted string.

  • Specify the file handle that was opened with FOPEN w (write) or a (append).

  • Specify the format, which is a string that includes the formatting characters and %s.

  • The in the format is code for a newline character.

  • Specify the same number of input values as there are %s in the format. Up to a maximum of five input values can be specified. The %s in the format are replaced with the corresponding input characters. If an input value corresponding to %s is not specified, it is replaced with an empty string.

Example

PERFORM UTL_FILE.PUTF(f, '[1=%s, 2=%s, 3=%s, 4=%s, 5=%s]\n', '1', '2', '3', '4', '5');
F.29.35.7.3. Usage Example #

The procedure when using UTL_FILE, and a usage example, are shown below.

1 . Preparation

Before starting a new job that uses UTL_FILE, register the directory in the UTL_FILE.UTL_FILE_DIR table.

Refer to “Registering and Deleting Directories” for information on how to register the directory.

2 . Performing a job

Perform a job that uses UTL_FILE. The example is shown below.

CREATE OR REPLACE FUNCTION gen_file(mydir TEXT, infile TEXT, outfile TEXT, copyfile TEXT) RETURNS void AS $$
DECLARE
  v1 VARCHAR(32767);
  inf UTL_FILE.FILE_TYPE;
  otf UTL_FILE.FILE_TYPE;
BEGIN
  inf := UTL_FILE.FOPEN(mydir, infile,'r',256);
  otf := UTL_FILE.FOPEN(mydir, outfile,'w');
  v1 := UTL_FILE.GET_LINE(inf,256);
  PERFORM UTL_FILE.PUT_LINE(otf,v1,TRUE);
  v1 := UTL_FILE.GET_LINE(inf,256);
  PERFORM UTL_FILE.PUTF(otf,'%s\n',v1);
  v1 := UTL_FILE.GET_LINE(inf, 256);
  PERFORM UTL_FILE.PUT(otf,v1);
  PERFORM UTL_FILE.NEW_LINE(otf);
  PERFORM UTL_FILE.FFLUSH(otf);

  inf := UTL_FILE.FCLOSE(inf);
  otf := UTL_FILE.FCLOSE(otf);

  PERFORM UTL_FILE.FCOPY(mydir, outfile, mydir, copyfile, 2, 3);
  PERFORM UTL_FILE.FRENAME(mydir, outfile, mydir, 'rename.txt');

END;
$$ LANGUAGE plpgsql;

SELECT gen_file('/home/pgsql', 'input.txt', 'output.txt', 'copyfile.txt');

3 . Post-processing

If you remove a job that uses UTL_FILE, delete the directory information from the UTL_FILE.UTL_FILE_DIR table. Ensure that the directory information is not being used by another job before deleting it.

Refer to “Registering and Deleting Directories” for information on how to delete the directory.

F.29.36. Chapter 7 Transaction behavior #

Most of the transaction behavior are exactly same, however the below stuff is not.

F.29.36.1. Handled Statement Failure. #

create table t (a int primary key, b int);
begin;
insert into t values(1,1);
insert into t values(1, 1);
commit; 

Oracle : commit can succeed. t has 1 row after that.

Tantor SE: commit failed due to the 2nd insert failed. so t has 0 row.

F.29.36.2. DML with Subquery #

Case 1:

create table dml(a int, b int);
insert into dml values(1, 1), (2,2);

-- session 1: 
begin; 
delete from dml where a in (select min(a) from dml); 

--session 2:  
delete from dml where a in (select min(a) from dml); 

-- session 1:  
commit;

In Oracle: 1 row deleted in sess 2. so 0 rows in the dml at last.

In PG : 0 rows are deleted in sess 2, so 1 rows in the dml at last.

Oracle probably detects the min(a) is changed and rollback/rerun the statement.

The same reason can cause the below difference as well.

create table su (a int, b int);
insert into su values(1, 1);

- session 1:
begin;
update su set b = 2 where b = 1;

- sess 2:
select * from su where a in (select a from su where b = 1) for update;

- sess 1:
commit;

In oracle, 0 row is selected. In Tantor SE, 1 row (1, 2) is selected.

A best practice would be never use subquery in DML and SLEECT … FOR UPDATE. Even in Oracle, the behavior is inconsistent as well. Oracle between 11.2.0.1 and 11.2.0.3 probably behavior same as Postgres, but other versions not.

Purpose of This Document

This document explains the actions required for migrating an Oracle database to Tantor SE and provides notes on migration.

Intended Readers

This guide is intended for persons engaged in migrating an Oracle database to Tantor SE. The reader is assumed to have general knowledge of the following:

  • Tantor SE

  • Oracle database

  • SQL

  • Linux

F.29.37. Migration: Chapter 1 Pre-Migration Configuration #

This chapter explains the environment settings that must be configured before migration of an Oracle database.

Note

  • In this migration guide, the migration source Oracle database and the migration target Tantor SE are targeted to be the versions listed below.

    • Oracle Database 12c

    • PostgreSQL 9.5

  • After migration, verify operation and confirm that the data was migrated successfully by checking if the intended result is obtained.

F.29.37.1. Setting the Server Parameter #

This section explains the server parameter required for matching the behavior of Tantor SE with the behavior of the Oracle database. Set the parameter in Tantor SE.conf so that the database always operates in the same way from all clients.

The following table shows the server parameter explained here.

Server parameter Description
search_path Specifies the sequence in which schemas are searched.

Note

  • The server parameter setting does not need to be changed. Change it only as required.

  • The explanations in Chapter 2 and following assume that the server parameter has been set.

F.29.37.1.1. search_path #

Functions added by orafce, which provides features for Oracle database compatibility, are defined as user-defined functions in the “public” schema that is created by default when a database cluster is created. This enables all users to be able to use these functions without having to configure any particular settings. Therefore, when using the search_path parameter to specify a schema search path, you must include “public”.

Some data types and functions added by orafce are implemented with different external specifications in Tantor SE and orafce. By default, the Tantor SE external specifications have priority.

To implement these data types and functions in line with the orafce external specifications, specify “oracle” and “pg_catalog” in the search_path parameter of Tantor SE.conf. You must place “oracle” before “pg_catalog”.

  • Before (default)

search_path = '"$user", public'
  • After

search_path = '"$user", public, oracle, pg_catalog'

See

Refer to Orafce Docmentation for information on features implemented with different external specifications in Tantor SE and orafce.

F.29.37.2. Example Databases #

This section uses the examples of an inventory management database for a particular retail store, and a staff management database for a particular company. The explanations of data operation provided in this manual are based on these example databases.

F.29.37.2.1. Inventory Management Database #
F.29.37.2.1.1. Contents of Database Definitions #

This database manages inventory in a retail store. It consists of the following three tables:

  • inventory_table

    • This table contains information on the products being handled and their inventory quantities.

  • ordering_table

    • This table contains information on the products supplied by each supplier, their ordering quantities, and their purchase prices.

  • company_table

    • This table contains the company name, telephone number, and address of each supply company.

inventory_table

The inventory table consists of the following four columns:

  • i_number (product number)

    • Code assigned to the product

  • i_name (category)

    • Category of the product

  • i_quantity (inventory quantity)

    • Inventory quantity of the product

  • i_warehouse (warehouse number)

    • Code of the warehouse where the product is stored

The contents of the inventory table are shown in “inventory_table”.

  • ordering_table (ordering table)

    • The ordering table consists of the following five columns:

  • o_code (supplier)

    • Company code of the supplier

  • o_number (supplied product)

    • Code assigned to the product

  • o_price (purchase price)

    • Purchase price of the product

  • o_quantity (ordering quantity)

    • Number of products ordered

  • o_order_date (order date)

    • Product order date

The contents of the ordering table are shown in “ordering_table”.

  • company_table (company table)

    • The company table consists of the following four columns:

  • c_code (company code)

    • Code assigned to the company

  • c_name (company name)

    • Name of the company

  • c_telephone (telephone number)

    • Telephone number of the company

  • c_address (address)

    • Address of the company

The contents of the company table are shown in “company_table”.

Where the table names and column names described above are used in this guide, such as in example SQL statements, unless otherwise stated, the tables and columns listed in “Contents of the inventory management database” are specified. Note that the data shown in this table is fictitious.

Contents of the inventory management database

  1. inventory_table

i_number (product number) i_name (category) i_quantity (inventory quantity) i_warehouse (warehouse number)
SMALLINT PRIMARY KEY VARCHAR(20) NOT NULL INTEGER SMALLINT
110 television 85 2
111 television 90 2
123 refrigerator 60 1
124 refrigerator 75 1
140 cd player 120 2
212 television 0 2
215 video 5 2
226 refrigerator 8 1
227 refrigerator 15 1
240 cd player 25 2
243 cd player 14 2
351 cd 2500 2
  1. ordering_table

o_code (supplier) o_number (supplied product) o_price (purchase price) o_quantity (ordering quantity) o_order_date (order date)
SMALLINT NOT NULL SMALLINT NOT NULL INTEGER SMALLINT DATE
61 123 48000 60 42557
61 124 64000 40 42557
61 140 8000 80 42557
61 215 240000 10 42557
61 240 80000 20 42557
62 110 37500 120 42557
62 226 112500 20 42557
62 351 375 800 42557
63 111 57400 80 42557
63 212 205000 30 42557
63 215 246000 10 42557
71 140 7800 50 42557
71 351 390 600 42557
72 140 7000 70 42557
72 215 210000 10 42557
72 226 105000 20 42557
72 243 84000 10 42557
72 351 350 1000 42557
74 110 39000 120 42557
74 111 54000 120 42557
74 226 117000 20 42557
74 227 140400 10 42557
74 351 390 700 42557
  1. company_table

c_code (company code) c_name (company name) c_telephone (telephone number) c_address (address)
SMALLINT NOT NULL VARCHAR(20) NOT NULL VARCHAR(12) VARCHAR(50)
61 Adam Electric 111-777-4444 7-8-9, Shin-Kamata, Oda Ward, Tokyo
62 Idea Corporation 222-888-5555 1-2-3, Asahi Ward, Obama City, Kanagawa
63 Fullmoon Industry 333-999-6666 1-1-1, Osaki, Urawa Town, Saitama
71 Stream Electric 444-111-7777 4-5-6, Akasakadai, Sakaida City, Osaka
72 Tornado Industry 555-222-8888 2-3-7, Higashi-Yodogawa, Nada Town, Osaka
74 First Corporation 666-333-9999 4-16-16, Naka City, Kyoto
F.29.37.2.1.2. Relationship Between the Tables #

“Relationship between the tables” shows how the tables are related with one another. The inventory table and the ordering table are related by means of the product number and the supplied product. The ordering table and the company table are related by means of the supplier and the company code. For example, the product identified by the product number “123” in the inventory table has the category “refrigerator” and the inventory quantity “60”, and is stored in the warehouse identified by the code “1”. Then, the row containing the supplied product “123” in the ordering table shows that the purchase price of the product is “48000” and the ordering quantity is "“60”. Furthermore, the company code of the supplier can be confirmed as “61”, and the row containing the company code “61” in the company table shows the name, telephone number, and address of the company that supplies the product.

Relationship between the tables

Figure F.52. REL1

REL1

F.29.37.2.1.3. Example Database Definitions #

The following example shows table definitions for the inventory management database.

CREATE TABLE inventory_table (
i_number        SMALLINT PRIMARY KEY,
i_name          VARCHAR(20) NOT NULL,
i_quantity      INTEGER,
i_warehouse     SMALLINT
);

CREATE TABLE ordering_table (
o_code          SMALLINT NOT NULL,
o_number        SMALLINT NOT NULL,
o_price         INTEGER,
o_quantity      SMALLINT,
o_order_date    DATE
);

CREATE TABLE company_table (
c_code          SMALLINT NOT NULL,
c_name          VARCHAR(20) NOT NULL,
c_telephone     VARCHAR(12),
c_address       VARCHAR(50)
);

INSERT INTO inventory_table VALUES (110, 'television', 85, 2);
INSERT INTO inventory_table VALUES (111, 'television', 90, 2);
INSERT INTO inventory_table VALUES (123, 'refrigerator', 60, 1);
INSERT INTO inventory_table VALUES (124, 'refrigerator', 75, 1);
INSERT INTO inventory_table VALUES (140, 'cd player', 120, 2);
INSERT INTO inventory_table VALUES (212, 'television', 0, 2);
INSERT INTO inventory_table VALUES (215, 'video', 5, 2);
INSERT INTO inventory_table VALUES (226, 'refrigerator', 8, 1);
INSERT INTO inventory_table VALUES (227, 'refrigerator', 15, 1);
INSERT INTO inventory_table VALUES (240, 'cd player', 25, 2);
INSERT INTO inventory_table VALUES (243, 'cd player', 14, 2);
INSERT INTO inventory_table VALUES (351, 'cd', 2500, 2);

INSERT INTO ordering_table VALUES (61, 123, 48000, 60, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (61, 124, 64000, 40, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (61, 140, 8000, 80, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (61, 215, 240000, 10, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (61, 240, 80000, 20, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (62, 110, 37500, 120, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (62, 226, 112500, 20, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (62, 351, 375, 800, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (63, 111, 57400, 80, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (63, 212, 205000, 30, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (63, 215, 246000, 10, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (71, 140, 7800, 50, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (71, 351, 390, 600, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (72, 140, 7000, 70, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (72, 215, 210000, 10, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (72, 226, 105000, 20, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (72, 243, 84000, 10, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (72, 351, 350, 1000, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (74, 110, 39000, 120, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (74, 111, 54000, 120, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (74, 226, 117000, 20, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (74, 227, 140400, 10, DATE'2016-07-06');
INSERT INTO ordering_table VALUES (74, 351, 390, 700, DATE'2016-07-06');

INSERT INTO company_table
VALUES (61, 'Adam Electric', '111-777-4444', '7-8-9, Shin-Kamata, Oda Ward, Tokyo');
INSERT INTO company_table
VALUES (62, 'Idea Corporation', '222-888-5555', '1-2-3, Asahi Ward, Obama City, Kanagawa');
INSERT INTO company_table
VALUES (63, 'Fullmoon Industry', '333-999-6666', '1-1-1, Osaki, Urawa Town, Saitama');
INSERT INTO company_table
VALUES (71, 'Stream Electric', '444-111-7777', '4-5-6, Akasakadai, Sakaida City, Osaka');
INSERT INTO company_table
VALUES (72, 'Tornado Industry', '555-222-8888', '2-3-7, Higashi-Yodogawa, Nada Town, Osaka');
INSERT INTO company_table
VALUES (74, 'First Corporation', '666-333-9999', '4-16-16, Naka City, Kyoto');
F.29.37.2.2. Staff Management Database #
F.29.37.2.2.1. Contents of Database Definitions #

This database manages the staff of the company. It consists of the following two tables:

  • staff_table (staff table)

    • This table contains the name, position, age, and manager of each staff member.

  • attendance_table (attendance management table)

    • This table contains the attendance time of each staff member.

staff_table

The staff table consists of the following five columns:

  • staff_id (staff identification number)

    • Code assigned to the staff member

  • name (name of the staff member)

    • Name of the staff member

  • job (position)

    • Position title of the staff member

  • age (age)

    • Age of the staff member

  • manager_id (staff identification number of manager)

    • Code assigned to the manager of the staff member

The contents of the staff table are shown in “staff_table”.

attendance_table

The attendance management table consists of the following three columns:

  • staff_id (staff identification number)

    • Code assigned to the staff member

  • work_flag (attendance flag)

    • Flag indicating whether the staff member is present or absent

  • attendance_time (attendance time)

    • Work starting and ending times of the staff member

The contents of the attendance management table are shown in “attendance_table”.

Where the table names and column names described above are used in this guide, such as in example SQL statements, unless otherwise stated, the tables and columns listed in “Contents of the staff management database” are specified. Note that the data shown in this table is fictitious.

Contents of the staff management database

  1. staff_table

staff_id (staff ID number) name (name of the staff member) job (position) age (age) manager_id (staff ID number of manager)
CHAR(4) VARCHAR(20) VARCHAR(30) INTEGER CHAR(4)
1001 tokyo taro president 68 <NULL>
2001 oosaka jiro sales manager 48 1001
3001 hyogo akihiko sales member 28 2001
3002 mie megumi sales member 31 2001
3003 hirosima taro sales member 36 2001
3004 nagano motoko sales member 40 2001
3005 akita taro sales member 25 2001
2002 hukuoka saburo accounting manager 52 1001
4001 nagasaki rokuro accounting member 39 2002
2003 kyoto hanako general affairs manager 43 1001
5001 okayama reiko general affairs member 33 2003
5002 kagawa shiro general affairs member 27 2003
5003 okinawa takao general affairs member 30 2003
5004 miyagi kenta <NULL> 23 2003
5005 aichi yui ’’(null) 23 2003
  1. attendance_table

staff_id (staff ID number) work_flag (attendance flag) attendance_time (attendance time)
CHAR(4) CHAR(1) TIMESTAMP WITH TIME ZONE
1001 i 2016-07-06 08:00:00+09
3001 i 2016-07-06 08:30:00+09
1001 o 2016-07-06 17:30:00+09
3001 o 2016-07-06 18:00:00+09
F.29.37.2.2.2. Relationship Between the Tables #

“Relationship between the tables” shows how the tables are related with one another. The staff table and the attendance management table are related by means of the staff identification number.

Relationship between the tables

Figure F.53. REL2

REL2

F.29.37.2.2.3. Example Database Definitions #

The following example shows table definitions for the staff management database.

CREATE TABLE staff_table (
staff_id        CHAR(4),
name            VARCHAR(20),
job             VARCHAR(30),
age             INTEGER,
manager_id      CHAR(4)
);

CREATE TABLE attendance_table (
staff_id        CHAR(4),
work_flag       CHAR(1),
attendance_time TIMESTAMP WITH TIME ZONE
);

INSERT INTO staff_table VALUES ('1001', 'tokyo taro', 'president', 68, NULL);
INSERT INTO staff_table VALUES ('2001', 'oosaka jiro', 'sales manager', 48, '1001');
INSERT INTO staff_table VALUES ('3001', 'hyogo akihiko', 'sales member', 28, '2001');
INSERT INTO staff_table VALUES ('3002', 'mie megumi', 'sales member', 31, '2001');
INSERT INTO staff_table VALUES ('3003', 'hirosima taro', 'sales member', 36, '2001');
INSERT INTO staff_table VALUES ('3004', 'nagano motoko', 'sales member', 40, '2001');
INSERT INTO staff_table VALUES ('3005', 'akita taro', 'sales member', 25, '2001');
INSERT INTO staff_table VALUES ('2002', 'hukuoka saburo', 'accounting manager', 52, '1001');
INSERT INTO staff_table VALUES ('4001', 'nagasaki rokuro', 'accounting member', 39, '2002');
INSERT INTO staff_table VALUES ('2003', 'kyoto hanako', 'general affairs manager', 43, '1001');
INSERT INTO staff_table VALUES ('5001', 'okayama reiko', 'general affairs member', 33, '2003');
INSERT INTO staff_table VALUES ('5002', 'kagawa shiro', 'general affairs member', 27, '2003');
INSERT INTO staff_table VALUES ('5003', 'okinawa takao', 'general affairs member', 30, '2003');
INSERT INTO staff_table VALUES ('5004', 'miyagi kenta', NULL, 23, '2003');
INSERT INTO staff_table VALUES ('5005', 'aichi yui', '', 23, '2003');

INSERT INTO attendance_table VALUES ('1001', 'i', TIMESTAMP WITH TIME ZONE'2016-07-06 08:00:00+09:00');
INSERT INTO attendance_table VALUES ('3001', 'i', TIMESTAMP WITH TIME ZONE'2016-07-06 08:30:00+09:00');
INSERT INTO attendance_table VALUES ('1001', 'o', TIMESTAMP WITH TIME ZONE'2016-07-06 17:30:00+09:00');
INSERT INTO attendance_table VALUES ('3001', 'o', TIMESTAMP WITH TIME ZONE'2016-07-06 18:00:00+09:00');

F.29.38. Migration: Chapter 2 Migrating Syntax Elements #

This chapter explains how to migrate SQL syntax elements.

F.29.38.1. Basic Elements #

This section explains the basic elements of SQL syntax.

F.29.38.1.1. TIMESTAMP Literal #

Description

A literal with the TIMESTAMP prefix is treated as TIMESTAMP type data.

Functional differences

  • Oracle database

    • The TIMESTAMP prefix can signify a time zone literal.

  • Tantor SE

    • The TIMESTAMP WITH TIME ZONE prefix signifies a time zone literal. If the prefix is TIMESTAMP only, the time zone value is discarded. No warning, error, or other notification is output.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword TIMESTAMP and identify where it is used as a literal prefix.

  2. If a time zone has been specified for the literal, change the prefix to TIMESTAMP WITH TIME ZONE.

Migration example

The example below shows how to migrate a TIMESTAMP literal with time zone.

Oracle database Tantor SE
INSERT INTO attendance_table 
 VALUES( '1001', 
 'i', 
 TIMESTAMP'2016-05-20 12:30:00 +09:00' );
INSERT INTO attendance_table 
 VALUES( '1001',
         'i',
 TIMESTAMP WITH TIME ZONE'2016-05-20 12:30:00 +09:00' );
F.29.38.1.2. Alternate Quotation Literal #

Description

Using alternate quotation enables a delimiter to be used for a text string.

Functional differences

  • Oracle database

    • The alternate quotation marks q’x and x’ are used. The letter x represents the alternate character.

  • Tantor SE

    • The alternate quotation marks q and q are used.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword q’ or Q’ and identify where alternate quotation marks are used.

  2. Delete alternate characters and single quotation marks where alternate quotation has been used, and enclose strings with q. The character between the two $ symbols can be omitted or any string can be specified.

Migration example

The example below shows how to migrate alternate quotation.

Oracle database Tantor SE
SELECT q'[Adam Electric company's address]' 
 FROM DUAL;
SELECT $q$Adam Electric company's address$q$ 
 FROM DUAL;

See

Refer to “The SQL Language” > “Lexical Structure” > “Dollar-quoted String Constants” in the Tantor SE Documentation for information on alternate quotation marks.

F.29.38.2. Data Types #

This section explains data types.

F.29.38.2.1. Migrating Data Types #

The table below lists the Tantor SE data types that correspond to Oracle database data types.

Data type correspondence

  • Character

Oracle database Data type Remarks Migratability Tantor SE Data type Remarks


CHAR
CHARACTER

Specifies the number of bytes or number of characters. YR


char
character

Only the number of characters can be specified.


CLOB
CHAR LARGE OBJECT
CHARACTER LARGE OBJECT

MR


text
Large object


Up to 1 GB(text)
Up to 4 TB(Large object)


CHAR VARYING
CHARACTER VARYING
VARCHAR

Specifies the number of bytes or number of characters. YR


char varying
character varying
varchar

Only the number of characters can be specified.
LONG MR text Up to 1 GB
M Large object


NCHAR
NATIONAL CHAR
NATIONAL CHARACTER

YR


nchar
national char
national character

This data type is internally used as a character type.


NCHAR VARYING
NATIONAL CHAR VARYING
NATIONAL CHARACTER VARYING

YR


nchar varying
national char varying
national character varying

This data type is internally used as a character varying type


NCLOB
NCHAR LARGE OBJECT
NATIONAL CHARACTER LARGE OBJECT

MR


text
Large object


Up to 1 GB(text)
Up to 4 TB(Large object)

NVARCHAR2 YR nvarchar2


Collating sequence is not supported.
This data type is added using orafce.

MR


nchar varying
national char varying
national character varying

This data type is internally used as a character varying type.
VARCHAR2 Specifies the number of bytes or number of characters. YR varchar2


Only the number of bytes can be specified.
Collating sequence is not supported.
This data type is added using orafce.

MR varchar Only the number of characters can be specified.
  • Numeric

Oracle database Data type Remarks Migratability Tantor SE Data type Remarks
BINARY_DOUBLE M double precision
BINARY_FLOAT M real
DOUBLE PRECISION Y double precision
FLOAT Y float
INT INTEGER Y int integer
NUMBER DEC DECIMAL NUMERIC Specifies numbers rounded according to the scale definition. MR smallint integer bigint numeric Integers from -32,768 to +32,767 (smallint) Integers from -2,147,483,648 to +2,147,483,647 (integer) Integers from -9,223,372,036,854,775,808 to +9,223,372,036,854,775,807(bigint)
REAL Y real
SMALLINT Y smallint
  • Date and time

Oracle database Data type Remarks Migratability Tantor SE Data type Remarks
INTERVAL DAY TO SECOND Y interval day to second
INTERVAL YEAR TO MONTH Y interval year to month
TIMESTAMP Y timestamp
TIMESTAMP WITH LOCAL TIME ZONE M timestamp with time zone
TIMESTAMP WITH TIME ZONE Y timestamp with time zone
DATE Y date (orafce) The time can be stored in addition to the date. The search_path parameter must be specified.
YR date (PostgreSQL) Only the date is stored.
M timestamp
  • Binary

Oracle database Data type Remarks Migratability Tantor SE Data type Remarks
BFILE MR bytea Large object Up to 1 GB (bytea) Up to 4 TB(Large object)
BLOB BINARY LARGE OBJECT MR bytea Large object Up to 1 GB (bytea) Up to 4 TB(Large object)
LONG RAW MR bytea Large object Up to 1 GB (bytea) Up to 4 TB(Large object)
RAW M bytea
ROWID M oid
UROWID N
  • Other

Oracle database Data type Remarks Migratability Tantor SE Data type Remarks
ANYDATA N
ANYDATASET N
ANYTYPE N
DBUriType N
HTTPUriType N
MLSLABEL N
ORDAudio N
ORDDicom N
ORDDoc N
ORDImage N
ORDVideo N
REF data type N
SDO_GEOMETRY N
SDO_GEORASTER N
SDO_TOPO_GEOMETRY N
SI_AverageColor N
SI_Color N
SI_ColorHistogram N
SI_FeatureList N
SI_PositionalColor N
SI_StillImage N
SI_Texture N
URIFactory package N
URIType N
VARRAY M Array type
XDBUriType N
XMLType M XML type
Object type N
Nested table N

Y: Data type can be migrated as is

M: Modified data type can be migrated

N: Cannot be migrated

YR: Data type can be migrated as is with restrictions

MR: Modified data type can be migrated with restrictions

F.29.38.2.2. Examples of Migrating Data Types #
F.29.38.2.2.1. Examples of Migrating General Data Types #

Description of migration

Refer to “Data type correspondence” and change Oracle database data types to Tantor SE data types.

Migration example

Oracle database Tantor SE
CREATE TABLE t1( col1 SMALLINT, 
                 col2 VARCHAR2(10), 
                 col3 NVARCHAR2(10), 
                 col4 DATE, 
                 col5 NUMBER(10), 
                 col6 RAW(2000), 
                 col7 BLOB ); 
CREATE TABLE t1( col1 SMALLINT, 
                 col2 VARCHAR(10), 
                 col3 NCHAR VARYING(10), 
                 col4 TIMESTAMP, 
                 col5 INTEGER, 
                 col6 BYTEA, 
                 col7 BYTEA );
F.29.38.2.2.2. NUMBER Type #

Functional differences

  • Oracle database

    • A negative value can be specified in a NUMBER type scale.
      Any value that is specified in a scale beyond the number of significant digits is rounded off.

  • Tantor SE

    • A negative value cannot be specified in a NUMERIC type scale.
      Any value that is specified in a scale beyond the number of significant digits is discarded.

Migration procedure

Use the following procedure to perform migration:

  1. Change DECIMAL scales to 0, and add the number of changed digits to the precision.

  2. Create a function that uses the ROUND function to round off the column that was changed in Step (1) above.

  3. Create a trigger that executes the function created in Step (2) above when the INSERT statement and UPDATE statement are executed.

Migration example

The example below shows how to migrate the NUMBER type.

Oracle database Tantor SE
CREATE TABLE t1( col1 SMALLINT, 
                 col2 NUMBER(10,-2) ); 






















 INSERT INTO t1 VALUES( 11, 1234567890 ); 
 SELECT * FROM t1;
 CREATE TABLE t1( col1 SMALLINT, 
                  col2 NUMERIC(12,0) ); 


 CREATE FUNCTION f1() RETURNS TRIGGER AS $$ 
 BEGIN 
  NEW.col2 := ROUND(NEW.col2,-2); 
  RETURN NEW; 
 END; 
 $$ LANGUAGE plpgsql; 
 CREATE TRIGGER g1 BEFORE INSERT OR UPDATE ON t1 
 FOR EACH ROW 
 EXECUTE PROCEDURE f1(); 


 INSERT INTO t1 VALUES( 11, 1234567890 ); 
 SELECT * FROM t1;

F.29.38.3. Pseudocolumns #

This section explains pseudocolumns.

F.29.38.3.1. CURRVAL #

Description

CURRVAL returns the value nearest to that obtained by NEXTVAL from the sequence in the current session.

Functional differences

  • Oracle database

    • The sequence name is specified as sequenceName.CURRVAL.

  • Tantor SE

    • The sequence name is specified as CURRVAL(‘sequenceName’).

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword CURRVAL and identify where it is used.

  2. Change the sequence name specification by placing it after CURRVAL and enclosing it in parentheses and single quotation marks.

Migration example

The example below shows how to migrate CURRVAL.

Oracle database Tantor SE
SELECT seq1.CURRVAL FROM DUAL;
SELECT CURRVAL('seq1') FROM DUAL;
F.29.38.3.2. NEXTVAL #

Description

NEXTVAL returns the next number in the sequence.

Functional differences

  • Oracle database

    • The sequence name is specified as sequenceName.NEXTVAL.

  • Tantor SE

    • The sequence name is specified as NEXTVAL(‘sequenceName’).

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword NEXTVAL and identify where it is used.

  2. Change the sequence name specification by placing it after NEXTVAL and enclosing it in parentheses and single quotation marks.

Migration example

The example below shows how to migrate NEXTVAL.

Oracle database Tantor SE
SELECT seq1.NEXTVAL FROM DUAL;
SELECT NEXTVAL('seq1') FROM DUAL;
F.29.38.3.3. ROWID #

Description

ROWID obtains information for uniquely identifying data.

Functional differences

  • Oracle database

    • ROWID is created automatically when a table is created.

  • Tantor SE

    • ROWID cannot be used. Use OID instead. However, WITH OIDS must be specified when a table is created.

Migration procedure

Use the following procedure to perform migration:

  1. Specify WITH OIDS at the end of the CREATE TABLE statement.

  2. Change the ROWID extraction item in the SELECT statement to OID.

Migration example

Oracle database Tantor SE
 CREATE TABLE t1( col1 INTEGER ); 


 INSERT INTO t1 VALUES( 11 ); 
 SELECT ROWID, col1 FROM t1;
 CREATE TABLE t1( col1 INTEGER ) WITH OIDS; 


 INSERT INTO t1 VALUES( 11 ); 
 SELECT OID, col1 FROM t1;
F.29.38.3.4. ROWNUM #

Description

ROWNUM obtains the number of the current row.

F.29.38.3.4.1. Obtaining the Row Number #

Functional differences

  • Oracle database

    • ROWNUM obtains the number of the current row.

  • Tantor SE

    • ROWNUM cannot be used. Use ROW_NUMBER() OVER() instead.

Migration procedure

Using the ROW_NUMBER() function instead of ROWNUM, perform migration so that the current number is obtained. Use the following procedure to perform migration:

  1. Search for the keyword ROWNUM and identify where it is used.

  2. Change ROWNUM to ROW_NUMBER() OVER().

Migration example

The example below shows migration when a line number is obtained.

Oracle database Tantor SE
SELECT ROWNUM, i_number, i_name 
 FROM inventory_table;
SELECT ROW_NUMBER() OVER(), i_number, i_name 
 FROM inventory_table; 

Note

This migration example cannot be used with the UPDATE statement.

F.29.38.3.4.2. Sorting Records and Obtaining the First N Records #

Functional differences

  • Oracle database

    • If a subquery that contains an ORDER BY clause is specified in the FROM clause and a ROWNUM condition is defined in the WHERE clause, the records are sorted and then the first N records are obtained.

  • Tantor SE

    • ROWNUM cannot be used. Using the LIMIT clause instead, sort the records and obtain the first N records.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword ROWNUM and identify where it is used.

  2. If an ORDER BY clause is specified in a subquery of the FROM clause and the results are filtered according to the ROWNUM condition in the WHERE clause, regard this portion as an SQL statement that sorts the records and then obtains the first N records.

  3. Move the table name and ORDER BY clause from the FROM clause subquery to a higher SELECT statement and delete the subquery.

  4. In the LIMIT clause, set the same number as the ROWNUM condition of the WHERE clause, and delete the ROWNUM condition from the WHERE clause.

Migration example

The example below shows migration when records are sorted and then the first N records are obtained.

Oracle database Tantor SE
SELECT i_number, i_name 
 FROM ( SELECT * FROM inventory_table 
 ORDER BY i_number DESC ) 
 WHERE ROWNUM < 5;
SELECT i_number, i_name  
 FROM inventory_table 
 ORDER BY i_number DESC LIMIT 4; 

F.29.38.4. Treatment of NULL and Zero-Length Strings #

This section explains how NULL and zero-length strings are treated.

Oracle databases treat zero-length strings as NULL. In contrast, Tantor SE treats zero-length strings and NULL as two different values.

The table below lists the advantages and disadvantages of using zero-length strings and NULL when performing migration.

Advantages and disadvantages of retaining or migrating Oracle database zero-length strings

Oracle database zero-length strings Advantages Disadvantages
Treated as zero-length strings without being migrated to NULL String concatenation (||) can be used as is. The target data has fewer hits than with IS NULL. Conditional expressions must be changed.
Migrated to NULL IS NULL can be used as is. The result of string concatenation (||) is NULL. String concatenation must be changed.

The following sections explain how to make changes if zero-length strings and NULL values are used together.

F.29.38.4.1. Search Conditions (IS NULL Predicate) #

Functional differences

  • Oracle database

    • Even zero-length strings hit the IS NULL condition.

  • Tantor SE

    • Zero-length strings do not hit the IS NULL condition.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword IS NULL and identify where a NULL search is used.

  2. Change the portions found by the IS NULL search to IS NULL OR strName = ’’.

Migration example

The example below shows migration when a search for zero-length strings and NULL values is performed.

Oracle database Tantor SE
SELECT * FROM staff_table 
 WHERE job IS NULL;
SELECT * FROM staff_table 
 WHERE job IS NULL OR job = '';

The example below shows migration when a search for values other than zero-length strings and NULL values is performed.

Oracle database Tantor SE
SELECT * FROM staff_table 
 WHERE job IS NOT NULL;
SELECT * FROM staff_table 
 WHERE job IS NOT NULL AND job != '';
F.29.38.4.2. Search Conditions (Comparison Predicate) #

Functional differences

  • Oracle database

    • Zero-length strings are treated as NULL, so they do not match search conditions.

  • Tantor SE

    • Zero-length strings are not treated as NULL, so they can match search conditions.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the name of the column where the zero-length string is stored, and identify where a string comparison is used.

  2. Add AND columnName != ’’ to the search condition.

Migration example

The example below shows migration when a zero-length string comparison is specified as the search condition.

Oracle database Tantor SE
SELECT * FROM staff_table 
 WHERE job < 'A00';
SELECT * FROM staff_table 
 WHERE job < 'A00' AND job != '';
F.29.38.4.3. String Concatenation (||) #

Functional differences

  • Oracle database

    • Concatenation with NULL returns strings other than NULL.

  • Tantor SE

    • Concatenation with NULL returns NULL.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword || and identify where string concatenation is used.

  2. If the values to be concatenated are likely to become NULL, use the NVL function to return a zero-length string instead of NULL.

Migration example

The example below shows migration when NULL is returned by string concatenation (||) in Oracle databases.

Oracle database Tantor SE
SELECT 'NAME:' || name 
 FROM staff_table;
 SELECT 'NAME:' || NVL( name, '' ) 
  FROM staff_table;

F.29.39. Migration: Chapter 3 Migrating Functions #

This chapter explains how to migrate SQL functions.

F.29.39.1. CONVERT #

Description

CONVERT converts a string from one character set to another.

Functional differences

  • Oracle database

    • The string is converted from the character set identified in the third argument to the character set identified in the second argument.

  • Tantor SE

    • The string is converted from the character set identified in the second argument to the character set identified in the third argument.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword CONVERT and identify where it is used.

  2. Switch the second and third arguments.

  3. Change the character sets in the second and third arguments to names that are valid under the Tantor SE encoding system.

Migration example

The example below shows migration when strings are changed to the character set of the target database.

Oracle database Tantor SE
SELECT CONVERT( 'abc', 
 'JA16EUC', 
 'AL32UTF8' ) 
 FROM DUAL;
SELECT CONVERT( CAST( 'abc' AS BYTEA ), 
  'UTF8', 
 'EUC_JP' ) 
 FROM DUAL;

F.29.39.2. EMPTY_BLOB #

Description

EMPTY_BLOB initializes BLOB type areas and creates empty data.

Functional differences

  • Oracle database

    • BLOB type areas are initialized and empty data is created.

  • Tantor SE

    • EMPTY_BLOB cannot be used. Instead, use a zero-length string for initialization.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword EMPTY_BLOB() and identify where it is used.

  2. Change EMPTY_BLOB() to the zero-length string ’’.

Migration example

The example below shows migration when empty data is inserted into the BLOB column.

Oracle database Tantor SE
CREATE TABLE t1( col1 INTEGER, 
 col2 BLOB ); 


 INSERT INTO t1 VALUES( 11, EMPTY_BLOB() );
CREATE TABLE t1( col1 INTEGER, 
 col2 BYTEA ); 


 INSERT INTO t1 VALUES( 11, '' );

The example below shows migration when BLOB column data is updated to empty.

Oracle database Tantor SE
UPDATE t1 SET col2 = EMPTY_BLOB() WHERE col1 = 11;
UPDATE t1 SET col2 = '' WHERE col1 = 11;

F.29.39.3. LEAD #

Description

LEAD obtains the value of the column specified in the arguments from the record that is the specified number of lines below.

Functional differences

  • Oracle database

    • A NULL value in the column specified in the arguments can be excluded from the calculation.

  • Tantor SE

    • A NULL value in the column specified in the arguments cannot be excluded from the calculation.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword LEAD and identify where it is used.

  2. If the IGNORE NULLS clause is specified, check the following values to create a subquery that excludes NULL values:

    • Arguments of LEAD (before IGNORE NULLS)

    • Tables targeted by IGNORE NULLS

    • Columns targeted by IGNORE NULLS

    • Columns to be sorted

  3. Change the table in the FROM clause to a subquery to match the format shown below.

  4. Replace LEAD in the select list with MAX. Specify LEAD_IGNLS in the arguments of MAX, and PARTITION BY CNT in the OVER clause.

FROM ( SELECT columnBeingUsed,
              CASE
               WHEN ignoreNullsTargetColumn IS NOT NULL THEN
                LEAD( leadFunctionArguments )
                 OVER( PARTITION BY NVL2( ignoreNullsTargetColumn, '0', '1' )
                        ORDER BY sortTargetColumn )
              END AS LEAD_IGNLS,
              COUNT( ignoreNullsTargetColumn )
               OVER( ORDER BY sortTargetColumn
                      ROWS BETWEEN 1 FOLLOWING AND UNBOUNDED FOLLOWING )
               AS CNT
        FROM ignoreNullsTargetTable ) AS T1;

Migration example

The example below shows migration when NULL values are not included in the calculation of column values.

Oracle database Tantor SE
SELECT staff_id, 
       name, 
       job, 
 LEAD( job, 1 ) IGNORE NULLS 
 OVER( ORDER BY staff_id DESC) 
 AS "LEAD_IGNORE_NULLS" 
 FROM staff_table 
 ORDER BY staff_id DESC;

































SELECT staff_id, 
       name, 
       job, 
 MAX( LEAD_IGNLS ) 
 OVER( PARTITION BY CNT ) 
 AS "LEAD_IGNORE_NULLS" 
 FROM ( SELECT staff_id, 
       name, 
       job, 
 CASE 
 WHEN job IS NOT NULL THEN 
 LEAD( job, 1 ) 
 OVER( PARTITION BY NVL2( 
       job, 
       '0', 
       '1' ) 
 ORDER BY staff_id DESC) 
 END AS LEAD_IGNLS, 
 COUNT( job ) 
 OVER( ORDER BY staff_id DESC 
  ROWS BETWEEN 1 FOLLOWING 
  AND UNBOUNDED FOLLOWING ) 
 AS CNT 
 FROM staff_table ) AS T1 
 ORDER BY staff_id DESC;

Information

If the IGNORE NULLS clause is not specified or if the RESPECT NULLS clause is specified, NULL is included in the calculation, so operation is the same as the LEAD function of Tantor SE. Therefore, if the IGNORE NULLS clause is not specified, no changes need to be made. If the RESPECT NULLS clause is specified, delete the RESPECT NULLS clause.

The example below shows migration when RESPECT NULLS is specified in the Oracle database.

LEAD migration example (when RESPECT NULLS is specified)

Oracle database Tantor SE
SELECT staff_id, 
       name, 
       job, 
 LEAD( job, 1 ) 
 RESPECT NULLS 
 OVER( ORDER BY staff_id DESC ) 
 AS "LEAD_RESPECT_NULLS" 
 FROM staff_table 
 ORDER BY staff_id DESC;
SELECT staff_id, 
       name, 
       job, 
 LEAD( job, 1 ) 
 OVER( ORDER BY staff_id DESC ) 
 AS "LEAD_RESPECT_NULLS" 
 FROM staff_table 
 ORDER BY staff_id DESC; 
 

F.29.39.4. RAWTOHEX #

Description

RAWTOHEX converts RAW type data to a hexadecimal string value.

Functional differences

  • Oracle database

    • RAW type data is converted to a hexadecimal string value.

  • Tantor SE

    • RAWTOHEX cannot be used. Instead, use ENCODE to convert binary data types corresponding to the RAW type.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword RAWTOHEX and identify where it is used.

  2. Change RAWTOHEX to ENCODE and specify HEX in the second argument.

Migration example

The example below shows migration when RAW data types are converted to hexadecimal string values.

Oracle database Tantor SE
SELECT RAWTOHEX ( 'ABC' ) FROM DUAL;
SELECT ENCODE ( 'ABC', 'HEX' ) FROM DUAL;

Information

A RAWTOHEX function that is used in PL/SQL to take a string as an argument must first be converted to a binary data type using DECODE, and then ENCODE must be used to convert the value to a string.

The example below shows migration of RAWTOHEX when it is used in PL/SQL to take a string as an argument.

ROWTOHEX migration example (when taking a string as an argument in PL/SQL)

Oracle database Tantor SE
SET SERVEROUTPUT ON; 


 DECLARE 
 HEX_TEXT VARCHAR2( 100 ); 
 BEGIN 
 HEX_TEXT := RAWTOHEX( '414243' ); 




 DBMS_OUTPUT.PUT_LINE( HEX_TEXT ); 
 END; 
 / 
 
 
 DO $$ 
 DECLARE 
 HEX_TEXT TEXT; 
 BEGIN 
 HEX_TEXT := 
 ENCODE( DECODE( '414243', 'HEX' ), 'HEX' ); 
 PERFORM DBMS_OUTPUT.SERVEROUTPUT( TRUE ); 
 PERFORM DBMS_OUTPUT.PUT_LINE( HEX_TEXT ); 
 END; 
 $$ LANGUAGE plpgsql;

F.29.39.5. REGEXP_REPLACE #

Description

REGEXP_REPLACE uses a regular expression pattern to replace a string.

Functional differences

  • Oracle database

    • All strings that match the regular expression pattern are replaced.

  • Tantor SE

    • The first string that matches the regular expression pattern is replaced.

Migration procedure

The REGEXP_REPLACE function of Tantor SE can return the same result if the option string is specified in the fourth argument. Use the following procedure to perform migration:

  1. Search for the keyword REGEXP_REPLACE and identify where it is used.

  2. Specify the argument ‘g’ in the fourth argument of REGEXP_REPLACE.

Migration example

The example below shows migration when a regular expression pattern is used to convert a string.

Oracle database Tantor SE
SELECT REGEXP_REPLACE( '2016', 
       '[0-2]', 
       '*' ) AS "REGEXP_REPLACE" 
 FROM DUAL; 
 
SELECT REGEXP_REPLACE( '2016', 
       '[0-2]', 
       '*', 
       'g' ) AS "REGEXP_REPLACE" 
 FROM DUAL;

F.29.39.6. TO_TIMESTAMP #

Description

TO_TIMESTAMP converts a string value to the TIMESTAMP data type.

Functional differences

  • Oracle database

    • The language to be used for returning the month and day of the week can be specified.

  • Tantor SE

    • The language to be used for returning the month and day of the week cannot be specified.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword TO_TIMESTAMP and identify where it is used.

  2. If the third argument of TO_TIMESTAMP is specified, delete it.

  3. If the a string in the first argument contains a national character string, it is replaced with a datetime keyword supported by Tantor SE.

Migration example

The example below shows migration when a string value is converted to the TIMESTAMP data type. One string specifies the month in Japanese as a national character, so it is replaced with the date keyword ‘JULY’.

Oracle database Tantor SE
SELECT TO_TIMESTAMP('2016/**/21 14:15:30', 
        'YYYY/MONTH/DD HH24:MI:SS', 
        'NLS_DATE_LANGUAGE = Japanese') 
 FROM DUAL;
SELECT TO_TIMESTAMP('2016/JULY/21 14:15:30', 
        'YYYY/MONTH/DD HH24:MI:SS') 


 FROM DUAL;

**: The July in Japanese

F.29.40. Migration: Chapter 4 Migrating SQL Statements #

This chapter explains how to migrate SQL statements.

F.29.40.1. Partitions #

This section provides examples of migrating partitions.

F.29.40.1.1. Partition Tables #

Description

Partitions split tables and indexes into smaller units for management.

The following example shows conversion of an Oracle database partition to child tables in Tantor SE. All migration examples provided here are based on this table.

Example of tables created by partitioning inventory_table

i_number (product code) i_name (category) i_quantity (inventory quantity) i_warehouse (warehouse code)
SMALLINT PRIMARY KEY VARCHAR(20) NOT NULL INTEGER SMALLINT
123 refrigerator 60 1
124 refrigerator 75 1
226 refrigerator 8 1
227 refrigerator 15 1
110 television 85 2
111 television 90 2
140 cd player 120 2
212 television 0 2
215 Video 5 2
240 cd player 25 2
243 cd player 14 2
351 Cd 2500 2

Functional differences

  • Oracle database

    • Partition tables can be created.

  • Tantor SE

    • Partition tables cannot be created.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword PARTITION and identify where CREATE TABLE is used to create a partition.

  2. Delete the PARTITION clause and following lines from the CREATE TABLE statement and create a table.

  3. Create a child table that inherits the table defined in step 1, and add table constraints to the split table for defining partition constraints.

  4. Define a trigger or rule so that data inserted to the table is assigned to the appropriate child table.

Migration example

The example below shows migration when partitions are created in inventory_table.

Oracle database Tantor SE
CREATE TABLE inventory_table( 
 i_number SMALLINT PRIMARY KEY, 
 i_name VARCHAR2(20) NOT NULL, 
 i_quantity INTEGER, 
 i_warehouse SMALLINT ) 
 PARTITION BY LIST ( i_warehouse ) 
 ( PARTITION inventory_table_1 VALUES (1), 
 PARTITION inventory_table_2 VALUES (2) ); 















































CREATE TABLE inventory_table( 
 i_number SMALLINT PRIMARY KEY, 
 i_name VARCHAR(20) NOT NULL, 
 i_quantity INTEGER, 
 i_warehouse SMALLINT ); 
 CREATE TABLE inventory_table_1 
 (CHECK ( i_warehouse = 1 )) 
 INHERITS( inventory_table ); 
 CREATE TABLE inventory_table_2 
 (CHECK ( i_warehouse = 2 )) 
 INHERITS( inventory_table ); 
 ------------------------------------------------- 
 CREATE FUNCTION TABLE_INSERT_TRIGGER() 
 RETURNS TRIGGER AS $$ 
 BEGIN 
   IF ( NEW.i_warehouse = 1 ) THEN 
     INSERT INTO inventory_table_1 
 VALUES( NEW.*); 
   ELSIF ( NEW.i_warehouse = 2 ) THEN 
     INSERT INTO inventory_table_2 
 VALUES( NEW.*); 
 ELSE 
   RAISE EXCEPTION 'Data out of range.  Fix the TABLE_INSERT_TRIGGER() function!'; 
   END IF; 
   RETURN NULL; 
 END; 
 $$ LANGUAGE plpgsql; 
 ------------------------------------------------- 
 CREATE TRIGGER TABLE_INSERT_TRIGGER 
 BEFORE INSERT ON inventory_table 
 FOR EACH ROW 
 EXECUTE PROCEDURE TABLE_INSERT_TRIGGER();
F.29.40.1.2. PARTITION Clause in a SELECT Statement #

Before a PARTITION clause in a SELECT statement can be migrated, the Oracle database partition must have been converted to child tables for Tantor SE.

Description

A PARTITION clause treats only some partitions of the table (partition table) specified in the FROM clause as the targets of a query.

F.29.40.1.3. Queries Where a PARTITION Clause is Specified #

Functional differences

  • Oracle database

    • A PARTITION clause can be specified.

  • Tantor SE

    • A PARTITION clause cannot be specified.

Migration procedure

A PARTITION clause cannot be specified, so change the search target to a child table so that the same result is returned. Use the procedure below to perform migration. The migration sequence depends on whether a FOR clause is specified.

  1. Search for the keyword PARTITION and identify where it is specified in a SELECT statement.

  2. Change the table name specified in the FROM clause to the name of the child table corresponding to the partition specified in the PARTITION clause.

  3. Delete the PARTITION clause.

Migration example

The example below shows migration of a query that uses PARTITION.

Oracle database Tantor SE
SELECT * 
 FROM inventory_table PARTITION( 
 inventory_table_1);
SELECT * 
 FROM inventory_table_1; 
 
F.29.40.1.4. 4.1.2. Queries when FOR is Specified in a PARTITION Clause #

Functional differences

  • Oracle database

    • FOR can be specified in a PARTITION clause.

  • Tantor SE

    • A PARTITION clause cannot be specified.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword PARTITION and identify where it is specified in a SELECT statement.

  2. Move the value specified in the PARTITION clause to a WHERE clause, and replace it with a conditional expression that compares the value with the column name written in the partition definition.

  3. Delete the PARTITION clause.

Migration example

The example below shows migration when a PARTITION FOR clause is used to execute a query.

Oracle database Tantor SE
SELECT * 
 FROM inventory_table PARTITION FOR (2);
SELECT * 
 FROM inventory_table WHERE i_warehouse = 2;

F.29.40.2. SELECT Statements #

This section explains SELECT statements.

F.29.40.2.1. UNIQUE #

Description

UNIQUE deletes duplicate rows from the selected list and displays the result.

Functional differences

  • Oracle database

    • UNIQUE can be specified in a select list.

  • Tantor SE

    • UNIQUE cannot be specified in a select list. Specify DISTINCT instead.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword UNIQUE and identify where it is specified in the select list of the SELECT statement.

  2. Change UNIQUE in the SELECT statement to DISTINCT.

Migration example

The example below shows migration when UNIQUE is specified in a select list.

Oracle database Tantor SE
SELECT UNIQUE i_name 
FROM inventory_table;
SELECT DISTINCT i_name 
FROM inventory_table;
F.29.40.2.2. Subqueries #

Description

A subquery specifies a sub SELECT statement in the main SQL statement.

Functional differences

  • Oracle database

    • A subquery specified in a FROM clause can be executed even without an alias being specified for it.

  • Tantor SE

    • A subquery specified in a FROM clause cannot be executed unless an alias is specified for it.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword SELECT and identify where a subquery is used.

  2. If the subquery is specified in a FROM clause and no alias is specified for it, specify an alias.

Migration example

The example below shows migration when a SELECT statement that uses a subquery is executed.

Oracle database Tantor SE
SELECT * 
 FROM ( SELECT * FROM inventory_table 
 WHERE i_name = 'television' ) 
 WHERE i_quantity > 0; 
SELECT * 
 FROM ( SELECT * FROM inventory_table 
 WHERE i_name = 'television' ) AS foo 
 WHERE i_quantity > 0;
F.29.40.2.3. Hierarchical Queries #

Description

If a table contains data that can associate its own records, a hierarchical query displays the result of associating those records.

F.29.40.2.3.1. Executing Hierarchical Queries #

Functional differences

  • Oracle database

    • Hierarchical queries can be used.

  • Tantor SE

    • Hierarchical queries cannot be used.

Migration procedure

Hierarchical queries cannot be used, so specify a recursive query that uses a WITH clause so that the same result is returned. Use the following procedure to perform migration:

  1. Search for the keyword CONNECT and identify where a hierarchical query is used.

  2. Check the following:

    • Target table of the hierarchical query

    • Column being used

    • Conditional expressions specified in the CONNECT BY clause

  3. Replace the hierarchical query with WITH clause syntax to match the format shown below.

  4. Change the table name specified in the FROM clause to the name of the query in the WITH clause, and delete the CONNECT BY clause.

WITH RECURSIVE queryName(
     columnUsed ) AS
( SELECT columnUsed
      FROM  targetTableOfHierarchicalQuery
    UNION ALL
    SELECT columnUsed(qualified by n)
      FROM  targetTableOfHierarchicalQuery  n,
            queryName  w
      WHERE conditionalExprOfConnectByClause(use w to qualify part qualified by PRIOR) )

Migration example

The example below shows migration when a hierarchical query is executed.

Oracle database Tantor SE
SELECT staff_id, name, manager_id 
 FROM staff_table 
 CONNECT BY PRIOR staff_id = manager_id; 














 
WITH RECURSIVE staff_table_w( staff_id, 
 name, 
 manager_id ) AS 
 ( SELECT staff_id, name, manager_id 
       FROM staff_table 
     UNION ALL 
     SELECT n.staff_id, n.name, n.manager_id 
       FROM staff_table n, staff_table_w w 
       WHERE w.staff_id = n.manager_id ) 
 SELECT staff_id, name, manager_id 
 FROM staff_table_w;
F.29.40.2.3.2. Hierarchical Query with Start Row #

Functional differences

  • Oracle database

    • A START WITH clause can be specified in a hierarchical query to set start row conditions.

  • Tantor SE

    • A START WITH clause cannot be specified.

Migration procedure

In a recursive query that uses a WITH clause, set a condition that is self-referencing so that the same result is returned. Use the following procedure to perform migration:

  1. Replace the hierarchical query with syntax that uses a recursive query (WITH clause).

  2. If a START WITH clause is specified, move the specified conditional expression to the WHERE clause of the first subquery specified in the WITH clause.

  3. Delete the START WITH clause.

Migration example

The example below shows migration when the start row is specified using a hierarchical query.

Oracle database Tantor SE
SELECT staff_id, name, manager_id 
 FROM staff_table 
 START WITH staff_id = '1001' 
 CONNECT BY PRIOR staff_id = manager_id;













WITH RECURSIVE staff_table_w( staff_id, 
 name, 
 manager_id ) AS 
 ( SELECT staff_id, name, manager_id 
       FROM staff_table 
       WHERE staff_id = '1001' 
     UNION ALL 
     SELECT n.staff_id, n.name, n.manager_id 
       FROM staff_table n, staff_table_w w 
       WHERE w.staff_id = n.manager_id ) 
 SELECT staff_id, name, manager_id 
 FROM staff_table_w;
F.29.40.2.3.3. Hierarchical Query Displaying the Hierarchical Position of Each Row #

Functional differences

  • Oracle database

    • Specifying a LEVEL pseudocolumn in the select list of a hierarchical query displays the hierarchical position of each row.

  • Tantor SE

    • A LEVEL pseudocolumn cannot be specified.

Migration procedure

In a recursive query that uses a WITH clause, create a result column equivalent to the LEVEL pseudocolumn as the query result of the WITH clause so that the same result is returned. Use the following procedure to perform migration:

  1. Replace the hierarchical query with syntax that uses a recursive query (WITH clause).

  2. Add LEVEL to the column list of the query result of the WITH clause.

  3. Specify the following values as the select list of the subquery in the position corresponding to the LEVEL column:

    • Specify 1 in the first query.

    • Specify LEVEL + 1 in the next query. (LEVEL is a column of the recursive table.)

  4. Using a query, replace the portion where the LEVEL pseudocolumn is used with LEVEL (quoted identifier).

The following shows the conversion format containing the LEVEL pseudocolumn.

WITH RECURSIVE queryName(
     columnUsed, "LEVEL"
) AS
( SELECT columnUsed, 1
      FROM  targetTableOfHierarchicalQuery
    UNION ALL
    SELECT columnUsed(qualified by n), w."LEVEL" + 1
      FROM  targetTableOfHierarchicalQuery  n,
            queryName  w
      WHERE conditionalExprOfConnectByClause(use w to qualify part qualified by PRIOR) )

Migration example

The example below shows migration when a hierarchical query is used for displaying the hierarchical position of each row.

Oracle database Tantor SE
SELECT staff_id, name, manager_id, LEVEL 
 FROM staff_table 
 START WITH staff_id = '1001' 
 CONNECT BY PRIOR staff_id = manager_id; 






















  
WITH RECURSIVE staff_table_w( staff_id, 
                name, 
                manager_id, 
                "LEVEL"  ) AS 
   ( SELECT staff_id, name, manager_id, 1 
       FROM staff_table 
       WHERE staff_id = '1001' 
     UNION ALL 
     SELECT n.staff_id, 
            n.name, 
            n.manager_id, 
            w."LEVEL" + 1 
       FROM staff_table n, staff_table_w w 
       WHERE w.staff_id = n.manager_id ) 
 SELECT staff_id, name, manager_id, "LEVEL"  
 FROM staff_table_w;
F.29.40.2.3.4. Hierarchical Query Displaying the Hierarchical Structure #

Functional differences

  • Oracle database

    • Specifying SYS_CONNECT_BY_PATH in the select list of a hierarchical query displays the hierarchical structure.

  • Tantor SE

    • SYS_CONNECT_BY_PATH cannot be specified.

Migration procedure

In a recursive query that uses a WITH clause, create an arithmetic expression that also uses the recursive query of the WITH clause so that the same result is returned. Use the following procedure to perform migration:

  1. Replace the hierarchical query with syntax that uses a recursive query (WITH clause).

  2. Add PATH to the column list of the query result of the WITH clause.

  3. Specify the following values for the select list of the subquery corresponding to the PATH column. The example here explains migration when a slash (/) is specified as the delimiter.

  • In the first query, specify the path to the values of the columns from the root to the node.

  • Specify m.PATH || ‘/’ || n.columnName in the next query. (PATH is a recursive table column.)

  1. Using a query, replace the part where PATH is used, with PATH.

The following shows the conversion format containing PATH.

WITH RECURSIVE queryName(
     columnUsed, PATH
) AS
( SELECT columnUsed, '/' || columnName
      FROM  targetTableOfHierarchicalQuery
    UNION ALL
    SELECT columnUsed(qualified by n), w.PATH || '/' || n.columnName
      FROM  targetTableOfHierarchicalQuery  n,
            queryName  w
      WHERE conditionalExprOfConnectByClause )

For conditionalExprOfConnectByClause, use w to qualify the part qualified by PRIOR.

Migration example

The example below shows migration when the hierarchical structure is displayed.

Oracle database Tantor SE
SELECT staff_id,name,manager_id, 
 SYS_CONNECT_BY_PATH(name,'/') AS PATH  
 FROM staff_table 
 START WITH staff_id = '1001' 
 CONNECT BY PRIOR staff_id = manager_id; 




















 
 WITH RECURSIVE staff_table_w( staff_id, 
                name, 
                manager_id, 
                 PATH) AS 
 ( SELECT staff_id,name,manager_id, '/' || name 
    FROM staff_table 
    WHERE staff_id = '1001' 
    UNION ALL 
    SELECT n.staff_id, 
               n.name, 
               n.manager_id, 
               w.PATH || '/' || n.name 
    FROM staff_table n,staff_table_w w 
    WHERE w.staff_id = n.manager_id ) 
 SELECT staff_id,name,manager_id, PATH 
 FROM staff_table_w;
F.29.40.2.3.5. Hierarchical Queries That Sort Each Hierarchy Level #

Functional differences

  • Oracle database

    • Specifying an ORDER SIBLINGS BY clause in a hierarchical query enables sorting of each hierarchical level.

  • Tantor SE

    • An ORDER SIBLINGS BY clause cannot be specified.

Migration procedure

Use the following procedure to perform migration:

  1. Replace the hierarchical query with syntax that uses a recursive query (WITH clause).

  2. In the syntax that uses a recursive query (WITH clause), add poskey to the column list of the query result of the WITH clause.

  3. Specify ROW_NUMBER() in the position corresponding to the poskey column. In the OVER clause, specify an ORDER BY clause that specifies the column of the ORDER SIBLINGS BY clause.

  4. Add siblings_pos to the column list of the query result of the WITH clause.

  5. Specify the following values as the select list of the subquery in the position corresponding to the siblings_pos column:

    • Specify ARRAY[poskey] in the first query.

    • Specify a concatenation of siblings_pos and poskey in the next query.

  6. Using a query, specify siblings_pos in the ORDER BY clause to perform a sort.

The following shows the conversion format containing sorting of each hierarchy level.

WITH RECURSIVE queryNameForPoskey(
     columnUsed, poskey
) AS
( SELECT columnUsed, 
ROW_NUMBER() OVER( ORDER BY columnNameSpecifiedInOrderSiblingsByClause )
      FROM  targetTableOfHierarchicalQuery ),
WITH RECURSIVE queryName(
     columnUsed, siblings_pos
) AS
( SELECT columnUsed, ARRAY[poskey]
      FROM  queryNameForPoskey
    UNION ALL
    SELECT columnUsed(qualified by n), w.siblings_pos || n.poskey
      FROM  queryNameForPoskey  n,
            queryName  w
      WHERE conditionalExprOfConnectByClause(use w to qualify part qualified by PRIOR ) )

Migration example

The example below shows migration when a hierarchical query is used to perform a sort in each hierarchy level.

Oracle database Tantor SE
SELECT staff_id, name, manager_id 
  FROM staff_table 
  START WITH staff_id = '1001' 
  CONNECT BY PRIOR staff_id = manager_id 
  ORDER SIBLINGS BY name; 














































 
 WITH RECURSIVE staff_table_pos ( staff_id, 
                name, 
                manager_id, 
                poskey ) AS 
 ( SELECT staff_id, 
          name, 
          manager_id, 
 ROW_NUMBER() OVER( ORDER BY name ) 
 FROM staff_table ), 
 staff_table_w ( staff_id, 
                 name, 
                 manager_id, 
 siblings_pos ) AS 
 ( SELECT staff_id, 
          name, 
          manager_id, 
          ARRAY[poskey] 
         FROM staff_table_pos 
         WHERE staff_id = '1001' 
       UNION ALL 
       SELECT n.staff_id, 
              n.name, 
              n.manager_id, 
              w.siblings_pos || n.poskey 
         FROM staff_table_pos n, staff_table_w w 
         WHERE w.staff_id = n.manager_id ) 
 SELECT staff_id, name, manager_id 
 FROM staff_table_w 
 ORDER BY siblings_pos;
F.29.40.2.3.6. Hierarchical Query Displaying data from the root #

Functional differences

  • Oracle database

    • Specifying CONNECT_BY_ROOT in the select list of a hierarchical query displays data from the root.

  • PostgreSQL

    • CONNECT_BY_ROOT cannot be specified.

Migration procedure

In a recursive query that uses a WITH clause, add a root column that also uses the recursive query of the WITH clause so that the same result is returned. Use the following procedure to perform migration:

  1. Replace the hierarchical query with syntax that uses a recursive query (WITH clause).

  2. Add root column to the column list of the query result of the WITH clause.

  • In the first query, specify the root columnName to the values of the columns from the root to the node.

  • Specify m.rootName in the next query. (rootName is a root column.)

The following shows the conversion format containing rootName.

WITH RECURSIVE queryName(
     columnUsed, rootName
) AS
( SELECT columnUsed, columnName
      FROM  targetTableOfHierarchicalQuery
    UNION ALL
    SELECT columnUsed(qualified by n), w.rootName
      FROM  targetTableOfHierarchicalQuery  n,
            queryName  w
      WHERE conditionalExprOfConnectByClause )

For conditionalExprOfConnectByClause, use w to qualify the part qualified by PRIOR.

Migration example

The example below shows migration when the root data is displayed.

Oracle database PostgreSQL
SELECT staff_id, name, CONNECT_BY_ROOT name as "Manager" 
  FROM staff_table 
  START WITH staff_id = '1001' 
  CONNECT BY PRIOR staff_id = manager_id;














 
WITH RECURSIVE staff_table_w( staff_id, 
 name, 
 Manager ) AS 
 (   SELECT staff_id, name, name 
       FROM staff_table 
     UNION ALL 
     SELECT n.staff_id, n.name, w.Manager 
       FROM staff_table n, staff_table_w w 
       WHERE w.staff_id = n.manager_id
 )
 SELECT staff_id, name, Manager 
 FROM staff_table_w;
F.29.40.2.3.7. Hierarchical Query identifys the leaves #

Functional differences

  • Oracle database

    • Specifying CONNECT_BY_ISLEAF in the select list of a hierarchical query can identify the leaf rows. This returns 1 if the current row is a leaf. Otherwise it returns 0.

  • PostgreSQL

    • CONNECT_BY_ISLEAF cannot be specified.

Migration procedure

In a recursive query that uses a WITH clause, the leaf can be checked using a sub-query so that the same result is returned. Use the following procedure to perform migration:

  1. Replace the hierarchical query with syntax that uses a recursive query (WITH clause).

  2. Add a sub-query to the column list of the query result of the WITH clause.

The following shows the conversion format containing rootName.

 WITH RECURSIVE queryName(
     columnUsed1, columnUsed2
) AS
(   SELECT columnUsed, columnUsed2
      FROM  targetTableOfHierarchicalQuery
    UNION ALL
    SELECT columnUsed(qualified by n), columnUsed2(qualified by n)
      FROM  targetTableOfHierarchicalQuery n,
            queryName w
      WHERE conditionalExprOfConnectByClause 
)
SELECT *,
       CASE WHEN EXISTS(select * from queryName p where p.columnUsed1 = e.columnUsed2)
            THEN 0 ELSE 1 END 
        as is_leaf
 FROM queryName e;

For conditionalExprOfConnectByClause, use w to qualify the part qualified by PRIOR.

Migration example

The example below shows migration when the leaf data is displayed.

Oracle database PostgreSQL
SELECT staff_id, name, CONNECT_BY_ISLEAF 
  FROM staff_table 
  START WITH staff_id = '1001' 
  CONNECT BY PRIOR staff_id = manager_id;
















 
WITH RECURSIVE staff_table_w( staff_id, 
                            name ) AS 
 (   SELECT staff_id, name
       FROM staff_table 
     UNION ALL 
     SELECT n.staff_id, n.name
       FROM staff_table n, staff_table_w w 
       WHERE w.staff_id = n.manager_id
 )
 SELECT staff_id, name,
       CASE WHEN EXISTS(select 1 from staff_table_w p where p.manager_id = e.staff_id)
            THEN 0 ELSE 1 END 
        as is_leaf 
 FROM staff_table_w e;
F.29.40.2.3.8. Returns all possible hierarchy permutations #

Functional differences

  • Oracle database

    • When CONNECT BY LEVEL is used without START WITH clause and PRIOR operator.

  • PostgreSQL

    • CONNECT BY LEVEL cannot be specified.

Migration procedure

In a recursive query that uses a WITH clause, returns all possible hierarchy permutations can use the descartes product. Use the following procedure to perform migration:

  1. Replace the hierarchical query with syntax that uses a recursive query (WITH clause).

  2. The left query of Union ALL does not specify a filter condition. The right query is the Descartes product of two tables, and the filter condition is the number of recursions.

The following shows the conversion format containing rootName.

 WITH RECURSIVE queryName(
     columnUsed1, level
) AS
(   SELECT columnUsed, 1
      FROM  targetTableOfHierarchicalQuery
    UNION ALL
    SELECT columnUsed(qualified by n), w.level+1
      FROM  targetTableOfHierarchicalQuery n,
            queryName w
      WHERE  w.level+1 < levelNum
);

Migration example

The example below shows migration when returns all possible hierarchy permutations of two levels.

Oracle database PostgreSQL
select staff_id, name, level 
    from staff_table 
    connect by level < 3;












 
WITH RECURSIVE staff_table_w( staff_id, 
                     name 
                     level ) AS 
 (   SELECT staff_id, name, 1 
       FROM staff_table 
     UNION ALL 
     SELECT n.staff_id, n.name, w.level + 1 
       FROM staff_table n, staff_table_w w
        WHERE w.level + 1 < 3 
 )
 SELECT staff_id, name, level 
 FROM staff_table_w;
F.29.40.2.4. MINUS #

Description

MINUS finds the difference between two query results, that is, it returns rows that are in the first result set that are not in the second result set.

Functional differences

  • Oracle database

    • MINUS is specified to find the difference between two query results.

  • Tantor SE

    • MINUS cannot be specified to find the difference between two query results. Specify EXCEPT instead.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword MINUS and identify where it is used.

  2. Change MINUS to EXCEPT.

Migration example

The example below shows migration when the set difference of query results is to be found.

Oracle database Tantor SE
SELECT i_number, i_name FROM inventory_table 
  WHERE i_warehouse = 2 
 MINUS 
 SELECT i_number, i_name FROM inventory_table 
  WHERE i_name = 'cd';
SELECT i_number, i_name FROM inventory_table 
  WHERE i_warehouse = 2 
 EXCEPT 
 SELECT i_number, i_name FROM inventory_table 
  WHERE i_name = 'cd';

F.29.40.3. DELETE Statements #

This section explains DELETE statements.

F.29.40.3.1. Omitting the FROM Keyword #

Functional differences

  • Oracle database

    • The FROM keyword can be omitted from a DELETE statement.

  • Tantor SE

    • The FROM keyword cannot be omitted from a DELETE statement.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword DELETE and identify where it is used.

  2. If the FROM keyword has been omitted from the DELETE statement, add it.

Migration example

The example below shows migration when the FROM keyword is omitted from a DELETE statement.

Oracle database Tantor SE
DELETE inventory_table 
  WHERE i_name = 'cd player';
DELETE FROM inventory_table 
  WHERE i_name = 'cd player';

F.29.40.4. MERGE Statements #

This section explains MERGE statements.

F.29.40.4.1. Executing MERGE Statements #

Functional differences

  • Oracle database

    • MERGE statements can be used.

  • Tantor SE

    • MERGE statements cannot be used.

Migration procedure

Use the following procedure to perform migration:

  1. Use an INSERT statement to specify the INSERT keyword that follows WHEN NOT MATCHED THEN in the MERGE statement.

  2. Use a SELECT statement after the lines added in step 1 to specify the SELECT statement that follows the USING clause of the MERGE statement.

  3. Use DO UPDATE in an ON CONFLICT clause of the INSERT statement specified in step 1 to specify the UPDATE keyword that follows WHEN MATCHED THEN in the MERGE statement.

Migration example

The example below shows how to migrate the MERGE statement.

Oracle database Tantor SE
MERGE INTO new_inventory_table N 
 USING ( SELECT i_number, 
 i_name, 
 i_quantity, 
 i_warehouse 
 FROM inventory_table ) I 
 ON ( N.i_number = I.i_number ) 
 WHEN MATCHED THEN 
     UPDATE SET N.i_quantity = I.i_quantity 
 WHEN NOT MATCHED THEN 
     INSERT ( N.i_number, 
 N.i_name, 
 N.i_quantity, 
 N.i_warehouse ) 
     VALUES ( I.i_number, 
 I.i_name, 
 I.i_quantity, 
 I.i_warehouse );
INSERT INTO new_inventory_table AS N ( 
             i_number, 
             i_name, 
             i_quantity, 
             i_warehouse 
            ) 
 SELECT i_number, 
        i_name, 
        i_quantity, 
        i_warehouse 
 FROM inventory_table 
 ON CONFLICT (i_number) DO UPDATE 
 SET i_quantity = excluded.i_quantity; 








 

Note

In the migration example shown above, a primary key or unique key definition must have been specified in the column specified in the ON clause of the MERGE statement. If using a table for which a primary key or unique key definition is not specified in the column of the conditional expression, refer to the migration example provided in “Information” below.

Information

The example below shows migration when a primary key or unique key definition is not specified in the column specified in the ON clause of the MERGE statement.

Migration procedure

Use the following procedure to perform migration:

  1. Use a SELECT statement in a WITH query to specify the SELECT statement that follows the USING clause of the MERGE statement.

  2. Use an UPDATE statement in the WITH query to specify the UPDATE keyword that follows WHEN MATCHED THEN in the MERGE statement.

  3. Specify the INSERT keyword that follows the WHEN NOT MATCHED THEN clause of the MERGE statement as an INSERT statement following the WITH query.

  4. Specify NOT IN within the INSERT statement added in step 3 as an equivalent condition to the WHEN MATCHED THEN clause of the MERGE statement.

Migration example

The example below shows migration of a MERGE statement in which no primary key or unique key definition is specified.

Oracle database Tantor SE
MERGE INTO new_inventory_table N 
 USING ( SELECT i_number, 
                i_name, 
                i_quantity, 
                i_warehouse 
 FROM inventory_table ) I 
 ON ( N.i_number = I.i_number ) 
 WHEN MATCHED THEN 
     UPDATE SET N.i_quantity = I.i_quantity 
 WHEN NOT MATCHED THEN 
     INSERT ( N.i_number, 
              N.i_name, 
              N.i_quantity, 
              N.i_warehouse ) 
     VALUES ( I.i_number, 
              I.i_name, 
              I.i_quantity, 
              I.i_warehouse );
WITH I AS ( 
 SELECT i_number, 
        i_name, 
        i_quantity, 
        i_warehouse 
 FROM inventory_table ), 
 U AS ( 
 UPDATE new_inventory_table AS N  
 SET i_quantity = I.i_quantity  
 FROM inventory_table I 
 WHERE N.i_number = I.i_number 
 RETURNING N.i_number ) 
 INSERT INTO new_inventory_table ( 
 SELECT * FROM I WHERE i_number NOT IN ( 
 SELECT i_number FROM U ) ); 




 

F.29.40.5. ALTER INDEX Statements #

Description

An ALTER INDEX statement changes an index definition.

F.29.40.5.1. Restructuring an Index #

Functional differences

  • Oracle database

    • A REBUILD clause can be specified in the ALTER INDEX statement to restructure an index.

  • Tantor SE

    • A REBUILD clause cannot be specified in the ALTER INDEX statement. Use a REINDEX statement instead.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keywords ALTER and INDEX, and identify where they are used.

  2. If a REBUILD clause is specified, replace the ALTER INDEX statement with a REINDEX statement.

Migration example

The example below shows migration when an index is restructured.

Oracle database Tantor SE
ALTER INDEX idx REBUILD;
REINDEX INDEX idx;
F.29.40.5.2. Restructuring an Index Where a Tablespace is Specified #

Functional differences

  • Oracle database

    • A tablespace can be specified in a REBUILD clause.

  • Tantor SE

    • A REBUILD clause cannot be used.

Migration procedure

The REBUILD statement for an index restructure is replaced with a REINDEX statement, but a tablespace cannot be specified in this statement. Therefore, move the tablespace before performing the index restructure. Use the following procedure to perform migration:

  1. Search for the keywords ALTER and INDEX, and identify where they are used.

  2. If both a REBUILD clause and a TABLESPACE clause are specified, replace the REBUILD clause of the ALTER INDEX statement with a SET clause.

  3. Add a REINDEX statement after the ALTER INDEX statement.

Migration example

The example below shows migration when a tablespace is specified for restructuring an index.

Oracle database Tantor SE
ALTER INDEX idx REBUILD TABLESPACE tablespace1;
ALTER INDEX idx SET TABLESPACE tablespace1; 
 REINDEX INDEX idx;
F.29.40.5.3. Restructuring an Index Where a Free Space Percentage is Specified #

Functional differences

  • Oracle database

    • PCTFREE can be specified in a REBUILD clause to specify a free space percentage for an index.

  • Tantor SE

    • A REBUILD clause cannot be used.

Migration procedure

The REBUILD statement for an index restructure is replaced with a REINDEX statement, but a free space percentage cannot be specified in this statement. Therefore, change the index utilization rate so that an equivalent result is returned. Then restructure the index. Use the following procedure to perform migration:

  1. Search for the keywords ALTER and INDEX, and identify where they are used.

  2. If both a REBUILD clause and the PCTFREE keyword are specified, replace the REBUILD clause with a SET clause and change PCTFREE to FILLFACTOR. Use 100 - valueSpecifiedInPctfree as the set value.

  3. Add a REINDEX statement after the ALTER INDEX statement.

Migration example

The example below shows migration when a fill factor is specified for restructuring an index.

Oracle database Tantor SE
ALTER INDEX idx REBUILD PCTFREE 10;
ALTER INDEX idx SET (FILLFACTOR=90); 
 REINDEX INDEX idx;

F.29.40.6. ALTER SESSION Statements #

Description

An ALTER SESSION statement specifies and changes parameters per session.

F.29.40.6.2. Changing the Initialization Parameters #

Functional differences

  • Oracle database

    • An ALTER SESSION statement is used to change the initialization parameters.

  • Tantor SE

    • ALTER SESSION statements cannot be used. Use a SET statement instead to change the server parameters.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keywords ALTER and SESSION, and identify where they are used.

  2. Replace the ALTER SESSION statement with a SET statement. The table below lists the corresponding initialization parameters and server parameters.

Corresponding initialization parameters and server parameters

Initialization parameter Runtime configuration parameters of Tantor SE
ENABLE_DDL_LOGGING log_statement
NLS_CURRENCY lc_monetary
NLS_DATE_FORMAT DateStyle
NLS_DATE_LANGUAGE lc_time
NLS_TIMESTAMP_FORMAT lc_time
NLS_TIMESTAMP_TZ_FORMAT lc_time
OPTIMIZER_INDEX_COST_ADJ cpu_index_tuple_cost seq_page_cost

Migration example

The example below shows migration when the initialization parameters are changed.

Oracle database Tantor SE
ALTER SESSION SET ENABLE_DDL_LOGGING = TRUE;
SET log_statement = 'DDL';

Note

The values that can be specified for server parameters may differ from those that can be specified for the initialization parameters. Refer to the manual provided by the vendor for the values that can be specified.

See

Refer to “Server Configuration” in “Server Administration” in the Tantor SE Documentation for information on server parameters.

F.29.40.6.3. Setting Transaction Characteristics #

Functional differences

  • Oracle database

    • An ALTER SESSION statement is used to set transaction characteristics.

  • Tantor SE

    • ALTER SESSION statements cannot be used. Use a SET TRANSACTION statement instead.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keywords ALTER and SESSION, and identify where they are used.

  2. If SET ISOLATION_LEVEL is specified, replace the ALTER SESSION statement with a SET TRANSACTION statement.

Migration example

The example below shows migration when transaction characteristics are set.

Oracle database Tantor SE
ALTER SESSION SET
 ISOLATION_LEVEL = SERIALIZABLE;
SET TRANSACTION 
 ISOLATION LEVEL SERIALIZABLE;
F.29.40.6.4. Migrating the Time Zone Setting #

Functional differences

  • Oracle database

    • An ALTER SESSION statement is used to set the time zone.

  • Tantor SE

    • ALTER SESSION statements cannot be used. Use a SET statement instead.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keywords ALTER and SESSION, and identify where they are used.

  2. If SET TIME_ZONE is specified, replace the ALTER SESSION statement with a SET statement.

Migration example

The example below shows migration when the time zone is set.

Oracle database Tantor SE
ALTER SESSION SET TIME_ZONE = '+09:00';
SET TimeZone='Japan';

Note

Be sure to use the full time zone name when specifying the time zone in the TimeZone parameter of Tantor SE.

F.29.40.7. GRANT Statements #

Description

A GRANT statement defines access privileges.

F.29.40.7.1. Migratability of GRANT Statement Features #

The following table indicates the migratability of the GRANT statement features provided by Oracle databases to Tantor SE.

System privileges

GRANT statement features of Oracle databases Migratability Remarks
Granting of system privileges MR PUBLIC cannot be specified for a grantee. There are restrictions on the privileges that can be migrated.
Granting of role (role) YR PUBLIC cannot be specified for a grantee.
Granting of all system privileges (ALL PRIVILEGES) Y
WITH ADMIN OPTION clause MR Only privileges that can be migrated with the GRANT statement.
WITH DELEGATE OPTION clause N

Object privileges

GRANT statement features of Oracle databases Migratability Remarks
Granting of object privileges YR Columns can be specified. There are restrictions on the privileges that can be migrated.
Granting of all object privileges (ALL [PRIVILEGES]) Y Columns can be specified.
Grantee Schema object Y
Grantee User N
Grantee Directory N
Grantee Edition N
Grantee Mining model N
Grantee Java source N
Grantee SQL translation profile N
WITH HIERARCHY OPTION clause N
WITH GRANT OPTION clause Y

Program unit privileges

GRANT statement features of Oracle databases Migratability Remarks
Granting of program unit privileges N

Y: Syntax can be migrated as is YR: Syntax can be migrated as is with restrictions MR: Modified syntax can be migrated with restrictions N: Cannot be migrated

F.29.40.7.2. Granting System Privileges #
F.29.40.7.2.1. Granting Privileges for Operating Users and Roles #

Functional differences

  • Oracle database

    • A GRANT statement is used to grant privileges for creating and changing users and roles.

  • Tantor SE

    • A GRANT statement cannot be used to grant privileges for creating and changing users and roles. Use an ALTER ROLE statement instead.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword GRANT and identify where it is used.

  2. If privileges for creating and changing users and roles are granted, replace the GRANT statement with the ALTER ROLE statement. The table below lists the migratable user and role operation privileges.

Migratable user and role operation privileges

  • ROLES

GRANT statement in Oracle database Corresponding ALTER ROLE statement in Tantor SE
GRANT CREATE ROLE TO roleName GRANT ALTER ANY ROLE TO roleName GRANT DROP ANY ROLE TO roleName GRANT ANY ROLE TO roleName ALTER ROLE roleName CREATEROLE;
  • USERS

GRANT statement in Oracle database Corresponding ALTER ROLE statement in Tantor SE
GRANT CREATE USER TO userName GRANT ALTER USER TO userName GRANT DROP USER TO userName ALTER ROLE userName CREATEUSER

Migration example

The example below shows migration when role creation privileges are granted.

Oracle database Tantor SE
GRANT CREATE ROLE TO role1;
ALTER ROLE role1 CREATEROLE;
F.29.40.7.3. Granting Privileges for Creating Objects #

Functional differences

  • Oracle database

    • A GRANT statement is used to grant creation privileges per object.

  • Tantor SE

    • A GRANT statement is used to grant object creation privileges per schema or database.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword GRANT and identify where it is used.

  2. If creation privileges are granted per object, replace the GRANT statement with a GRANT statement that grants creation privileges per schema or database. The table below lists the migratable object creation privileges.

Migratable object creation privileges

Object GRANT statement in Oracle database Corresponding ALTER ROLE statement in Tantor SE
MATERIALIZED VIEWS GRANT CREATE MATERIALIZED VIEW TO userName GRANT CREATE ON SCHEMA schemaName TO userName
OPERATORS GRANT CREATE OPERATOR TO userName GRANT CREATE ON SCHEMA schemaName TO userName
PROCEDURES GRANT CREATE PROCEDURE TO userName GRANT CREATE ON SCHEMA schemaName TO userName
SEQUENCES GRANT CREATE SEQUENCE TO userName GRANT CREATE ON SCHEMA schemaName TO userName
SESSIONS GRANT CREATE SESSION TO userName GRANT CONNECT ON DATABASE databaseName TO userName
TABLES GRANT CREATE TABLE TO userName GRANT CREATE ON SCHEMA schemaName TO userName
TRIGGERS GRANT CREATE TRIGGER TO userName GRANT CREATE ON SCHEMA schemaName TO userName
TYPES GRANT CREATE TYPE TO userName GRANT CREATE ON SCHEMA schemaName TO userName
VIEWS GRANT CREATE VIEW TO userName GRANT CREATE ON SCHEMA schemaName TO userName

Migration example

The example below shows migration when table creation privileges are granted.

Oracle database Tantor SE
GRANT CREATE TABLE TO user1;
GRANT CREATE ON SCHEMA scm1 TO user1;
F.29.40.7.3.1. Granting Roles (with Password Setting) #

Functional differences

  • Oracle database

    • When a GRANT statement is used to assign a user to a role, a password can be set at the same time.

  • Tantor SE

    • When a GRANT statement is used to assign a user to a role, a password cannot be set at the same time.

Migration procedure

To set a password, you must specify a separate CREATE USER or ALTER USER statement and set the password in that statement. Use the following procedure to perform migration:

  1. Search for the keyword GRANT and identify where it is used.

  2. If an IDENTIFIED BY clause is specified, check if the target user exists.

  3. If the user exists, use an ALTER USER statement to change the password. If the user does not exist, use a CREATE USER statement to create a new user and set a password.

  4. Delete the clause for granting a password from the GRANT statement.

Migration example

The example below shows migration when role1 is granted to user1.

Oracle database Tantor SE
GRANT role1 TO user1 IDENTIFIED BY PASSWORD;
 CREATE USER user1 PASSWORD 'PASSWORD'; 
 GRANT role1 TO user1;
F.29.40.7.4. Granting Object Privileges #

There is no difference in the syntax of GRANT statements with regard to object privileges that are migratable from an Oracle database. However, some object privileges cannot be used in Tantor SE, so they must be changed to supported object privileges.

The table below lists the object privileges that can be migrated from an Oracle database to Tantor SE.

Migratable object privileges

  • Materialized view privileges

Name of object privilege Change required Remarks
READ Yes Change to SELECT.
SELECT No If a FOR UPDATE clause is used in the SELECT statement, UPDATE privileges are also required.
  • Operator privileges

Name of object privilege Change required Remarks
EXECUTE Yes In Tantor SE, EXECUTE privileges must be granted to a function that implements operators.
  • Procedure, function, and package privileges

Name of object privilege Change required Remarks
EXECUTE Yes The FUNCTION keyword must be added before the function name.
  • Sequence privileges

Name of object privilege Change required Remarks
SELECT Yes Change to USAGE. The SEQUENCE keyword must be added before the sequence name.
  • Table privileges

Name of object privilege Change required Remarks
DELETE No
INSERT No
READ Yes Change to SELECT.
REFERENCES No
SELECT No If a FOR UPDATE clause is used in the SELECT statement, UPDATE privileges are also required.
UPDATE No
  • View privileges

Name of object privilege Change required Remarks
DELETE No
INSERT No
READ Yes Change to SELECT.
REFERENCES No
SELECT No If a FOR UPDATE clause is used in the SELECT statement, UPDATE privileges are also required.
UPDATE No

F.29.41. Migration: Chapter 5 Migrating PL/SQL #

This chapter explains how to migrate Oracle database PL/SQL. Note that in this document, PL/SQL refers to the language to be migrated to Tantor SE PL/pgSQL.

F.29.41.1. Notes on Migrating from PL/SQL to PL/pgSQL #

This section provides notes on migration from PL/SQL to PL/pgSQL.

F.29.41.1.1. Transaction Control #

PL/pgSQL does not allow transaction control within a process. Terminate a procedure whenever a transaction is terminated in the Oracle database and execute a transaction control statement from the application.

F.29.41.2. Basic Elements #

This section explains how to migrate the basic elements of PL/SQL.

F.29.41.2.1. Migrating Data Types #

The table below lists the Tantor SE data types that correspond to data types unique to PL/SQL.

Data type correspondence with PL/SQL

  • Character

Oracle database Data type Remarks Migratability Tantor SE Data type Remarks
STRING The number of bytes or number of characters can be specified. MR varchar Only the number of characters can be specified.
  • Numeric

Oracle database Data type Remarks Migratability Tantor SE Data type Remarks
BINARY_INTEGER M integer
NATURAL M integer
NATURALN Type with NOT NULL constraints MR integer Set “not null” constraints for variable declarations.
PLS_INTEGER M integer
POSITIVE M integer
POSITIVEN Type with NOT NULL constraints MR integer Set “not null” constraints for variable declarations.
SIGNTYPE M smallint
SIMPLE_DOUBLE Type with NOT NULL constraints MR double precision Set “not null” constraints for variable declarations.
SIMPLE_FLOAT Type with NOT NULL constraints MR real Set “not null” constraints for variable declarations.
SIMPLE_INTEGER Type with NOT NULL constraints MR integer Set “not null” constraints for variable declarations.
  • Date and time

Oracle database Data type Remarks Migratability Tantor SE Data type Remarks
DSINTERVAL_UNCONSTRAINED N
TIME_TZ_UNCONSTRAINED N
TIME_UNCONSTRAINED N
TIMESTAMP_LTZ_UNCONSTRAINED N
TIMESTAMP_TZ_UNCONSTRAINED N
TIMESTAMP_UNCONSTRAINED N
YMINTERVAL_UNCONSTRAINED N
  • Other

Oracle database Data type Remarks Migratability Tantor SE Data type Remarks
BOOLEAN Y boolean
RECORD M Complex type
REF CURSOR (cursor variable) M refcursor type
Subtype with constraints N
Subtype that uses the base type within the same data type family N
Unconstrained subtype N

Y: Data type can be migrated as is

M: Modified data type can be migrated

N: Cannot be migrated

MR: Modified data type can be migrated with restrictions

See

Refer to “Data Types” for information on migrating data types other than those unique to PL/SQL.

F.29.41.3. Migrating Functions #

This section explains how to migrate PL/SQL functions.

Description

A stored function is a user-defined function that returns a value.

F.29.41.3.1. Defining Functions #

Functional differences

  • Oracle database

    • A RETURN clause within a function prototype is specified as RETURN.
      DECLARE does not need to be specified as the definition portion of a variable used within a function.

  • Tantor SE

    • Use RETURNS to specify a RETURN clause within a function prototype.
      DECLARE must be specified as the definition portion of a variable to be used within a function.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keywords CREATE and FUNCTION, and identify where user-defined functions are created.

  2. If an IN or OUT qualifier is specified in an argument, move it to the beginning of the parameters.

  3. Change RETURN within the function prototype to RETURNS.

  4. Change the AS clause to AS $$. (If the keyword is IS, change it to AS.)

  5. If a variable is defined, add the DECLARE keyword after $$.

  6. Delete the final slash (/) and specify $$ and a LANGUAGE clause.

Migration example

The example below shows migration when CREATE FUNCTION is used to define a function.

Oracle database Tantor SE
CREATE FUNCTION PROFIT_FUNC( 
  selling IN INTEGER, 
  sales_num IN INTEGER, 
  cost IN INTEGER 
 ) RETURN INTEGER AS 


     profit INTEGER; 
   BEGIN 
     profit := ( ( selling * sales_num ) - cost ); 
     RETURN profit; 
   END; 
 /
CREATE FUNCTION PROFIT_FUNC( 
  IN selling INTEGER, 
  IN sales_num INTEGER, 
  IN cost INTEGER 
 ) RETURNS INTEGER AS $$ 
 DECLARE 
     profit INTEGER; 
 BEGIN 
     profit := ( ( selling * sales_num ) - cost ); 
     RETURN profit; 
 END; 
 $$ LANGUAGE plpgsql;

F.29.41.4. Migrating Procedures #

This section explains how to migrate PL/SQL procedures.

Description

A stored procedure is a single procedure into which multiple processes have been grouped.

F.29.41.4.1. Defining Procedures #

Functional differences

  • Oracle database

    • Procedures can be created.

  • Tantor SE

    • Procedures cannot be created.

Migration procedure

Procedures cannot be created in Tantor SE. Therefore, replace them with functions. Use the following procedure to perform migration:

  1. Search for the keywords CREATE and PROCEDURE, and identify where a procedure is defined.

  2. Replace the CREATE PROCEDURE statement with the CREATE FUNCTION statement.

  3. Change the AS clause to RETURNS VOID AS $$. (If the keyword is IS, change it to AS.)

  4. If a variable is defined, add the DECLARE keyword after $$.

  5. Delete the final slash (/) and specify $$ and a LANGUAGE clause.

Note

If the OUT or INOUT keywords are specified in the arguments, a different migration method must be used. Refer to “Defining Procedures That Return a Value”.

Migration example

The example below shows migration when a procedure is defined.

Oracle database Tantor SE
CREATE PROCEDURE UPD_QUANTITY ( 
  upd_number SMALLINT, 
  upd_quantity INTEGER 
 ) AS 
   BEGIN 
     UPDATE inventory_table 
 SET i_quantity = upd_quantity 
       WHERE i_number = upd_number; 
   END; 
 / 
 ------------------------------------------------- 


 DECLARE 
   v_i_number SMALLINT := 110; 
   v_i_quantity INTEGER := 100; 
 BEGIN 
   upd_quantity( v_i_number, v_i_quantity ); 
 END; 
 / 
 
CREATE FUNCTION UPD_QUANTITY ( 
  upd_number SMALLINT, 
  upd_quantity INTEGER 
 ) RETURNS VOID AS $$ 
 BEGIN 
     UPDATE inventory_table 
 SET i_quantity = upd_quantity 
       WHERE i_number = upd_number; 
 END; 
 $$ LANGUAGE plpgsql; 
 ------------------------------------------------- 
 DO $$ 
 DECLARE 
   v_i_number SMALLINT := 110; 
   v_i_quantity INTEGER := 100; 
 BEGIN 
   PERFORM upd_quantity( v_i_number, v_i_quantity ); 
 END; 
 $$ 
 ;
F.29.41.4.2. Calling Procedures #

Functional differences

  • Oracle database

    • A procedure can be called as a statement.

  • Tantor SE

    • Procedures cannot be used. Instead, call the procedure as a function that does not return a value.

Migration procedure

Use the following procedure to perform migration:

  1. Identify where each procedure is called.

  2. Specify PERFORM in front of the procedure call.

Migration example

The example below shows migration when a procedure is called.

Oracle database Tantor SE
SET SERVEROUTPUT ON; 
 BEGIN 


   DBMS_OUTPUT.PUT_LINE( 'Hello World.' ); 
 END; 
 / 
 
DO $$ 
 BEGIN 
   PERFORM DBMS_OUTPUT.SERVEROUTPUT( TRUE ); 
   PERFORM DBMS_OUTPUT.PUT_LINE( 'Hello World.' ); 
 END; 
 $$ 
 ;
F.29.41.4.3. Defining Procedures That Return a Value #

Functional differences

  • Oracle database

    • Procedures that return a value can be created.

  • Tantor SE

    • Procedures that return a value cannot be created.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the CREATE and PROCEDURE keywords, and identify where a procedure is defined.

  2. Confirm that the OUT or INOUT keyword is specified in the arguments.

  3. Replace the CREATE PROCEDURE statement with the CREATE FUNCTION statement.

  4. If the IN, OUT, or INOUT keyword is specified in the arguments, move it to the beginning of the arguments.

  5. Change the AS clause to AS $$. (If the keyword is IS, change it to AS.)

  6. If a variable is defined, add the DECLARE keyword after $$.

  7. Delete the final slash (/) and specify $$ and a LANGUAGE clause.

  8. If calling a function, call it without specifying arguments in the OUT parameter and store the return value in the variable. If there are multiple OUT parameters, use a SELECT INTO statement.

Migration example

The example below shows migration when the OUT parameter of CREATE PROCEDURE is used to define a procedure that returns a value.

Oracle database Tantor SE
 CREATE PROCEDURE remove_row ( 
  del_name VARCHAR2, 
  del_row OUT INTEGER 
 ) AS 
  BEGIN 
   DELETE FROM inventory_table 
    WHERE i_name = del_name; 
   del_row := SQL%ROWCOUNT; 
  END; 
 / 
 ------------------------------------------------- 
 SET SERVEROUTPUT ON; 
 DECLARE 
  rtn_row INTEGER; 
  v_i_name VARCHAR2(20) := 'television'; 
 BEGIN 


  remove_row( v_i_name, rtn_row ); 
  DBMS_OUTPUT.PUT_LINE( 
   TO_CHAR( rtn_row ) || 'rows deleted!' ); 
 END; 
 / 
 
CREATE FUNCTION remove_row ( 
  del_name VARCHAR, 
  OUT del_row INTEGER 
 ) AS $$ 
  BEGIN 
   DELETE FROM inventory_table 
    WHERE i_name = del_name; 
   GET DIAGNOSTICS del_row := ROW_COUNT; 
  END; 
 $$ LANGUAGE plpgsql; 
 ------------------------------------------------- 
 DO $$ 
 DECLARE 
  rtn_row INTEGER; 
  v_i_name VARCHAR(20) := 'television'; 
 BEGIN 
  PERFORM DBMS_OUTPUT.SERVEROUTPUT( TRUE ); 
  rtn_row := remove_row( v_i_name ); 
  PERFORM DBMS_OUTPUT.PUT_LINE( 
   TO_CHAR( rtn_row ) || 'rows deleted!' ); 
 END; 
 $$ 
 ;

See

Refer to “Defining Nested Procedures” for examples of migrating a call portion that uses a SELECT INTO statement.

F.29.41.4.4. Defining Nested Procedures #

Functional differences

  • Oracle database

    • Nested procedures can be defined.

  • Tantor SE

    • Nested procedures cannot be defined.

Migration procedure

Procedures must be replaced with functions, but functions cannot be nested in Tantor SE. Therefore, define and call the functions separately. Use the following procedure to perform migration:

  1. Search for the CREATE and PROCEDURE keywords, and identify where a procedure is defined.

  2. If a PROCEDURE statement is defined in a DECLARE clause, regard it as a nested procedure.

  3. Check for variables that are used by both the procedure and the nested procedure.

  4. Replace a nested procedure (from PROCEDURE procedureName to END procedureName;) with a CREATE FUNCTION statement. Specify the variables you found in step 3 in the INOUT argument of CREATE FUNCTION.

  5. Replace the portion that calls the nested procedure with a SELECT INTO statement. Specify the common variables you found in step 3 in both the variables used for calling the function and the variables used for accepting the INTO clause.

Migration example

The example below shows migration when nested procedures are used and a variable is shared by a procedure and its call portion.

Oracle database Tantor SE
SET SERVEROUTPUT ON; 
 DECLARE 
  sales_num INTEGER; 
  stock_num INTEGER; 
  v_i_quantity INTEGER; 
  PROCEDURE quantity_check ( 
   sales INTEGER, 
   stock INTEGER 
  ) IS 
   quantity_err EXCEPTION; 
  BEGIN 


   v_i_quantity := ( stock - sales ); 
   IF ( v_i_quantity < 0 ) THEN 
    RAISE quantity_err; 
   END IF; 
  EXCEPTION 
   WHEN quantity_err THEN 
    DBMS_OUTPUT.PUT_LINE( 
     'ERR: i_quantity is negative value.' ); 
  END quantity_check; 








 BEGIN 


  sales_num := 80; 
  stock_num := 100; 
  quantity_check( sales_num, stock_num ); 


  DBMS_OUTPUT.PUT_LINE( 
   'i_quantity: ' || v_i_quantity ); 


  sales_num := 100; 
  stock_num := 80; 
  quantity_check( sales_num, stock_num ); 


  DBMS_OUTPUT.PUT_LINE( 
   'i_quantity: ' || v_i_quantity ); 
 END; 
 / 








 
 
 CREATE FUNCTION quantity_check( 
  sales INTEGER, 
  stock INTEGER, 
  INOUT quantity INTEGER 
 ) AS $$ 


  BEGIN 
   PERFORM DBMS_OUTPUT.SERVEROUTPUT( TRUE ); 
   quantity := ( stock - sales ); 
   IF ( quantity < 0 ) THEN 
    RAISE USING ERRCODE = '20001'; 
   END IF; 
  EXCEPTION 
   WHEN SQLSTATE '20001' THEN 
    PERFORM DBMS_OUTPUT.PUT_LINE( 
     'ERR: i_quantity is negative value.' ); 
  END; 
 $$ LANGUAGE plpgsql; 
 ------------------------------------------------- 
 DO $$ 
 DECLARE 
  sales_num INTEGER; 
  stock_num INTEGER; 
  v_i_quantity INTEGER; 
 BEGIN 
  PERFORM DBMS_OUTPUT.SERVEROUTPUT( TRUE ); 
  sales_num := 80; 
  stock_num := 100; 
  SELECT quantity INTO v_i_quantity 
   FROM quantity_check( sales_num, 
                        stock_num, 
                        v_i_quantity ); 
  PERFORM DBMS_OUTPUT.PUT_LINE( 
   'i_quantity: ' || v_i_quantity ); 


  sales_num := 100; 
  stock_num := 80; 
  SELECT quantity INTO v_i_quantity 
   FROM quantity_check( sales_num, 
                        stock_num, 
                        v_i_quantity ); 
  PERFORM DBMS_OUTPUT.PUT_LINE( 
  'i_quantity: ' || v_i_quantity ); 
 END; 
 $$ 
 ;
F.29.41.4.5. Defining Anonymous Code Blocks #

Description

An anonymous code block generates and executes a temporary function within a procedural language.

Functional differences

  • Oracle database

    • Anonymous code blocks that are enclosed with (DECLARE) BEGIN to END can be executed.

  • Tantor SE

    • PL/pgSQL blocks ((DECLARE) BEGIN to END) that are enclosed with DO
      to
      can be executed.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keywords DECLARE and BEGIN, and identify where an anonymous code block is defined.

  2. Specify DO $$ at the beginning of the anonymous code block.

  3. Delete the final slash (/) and specify $$.

Migration example

The example below shows migration when an anonymous code block is defined.

Oracle database Tantor SE
SET SERVEROUTPUT ON; 
 BEGIN 


     DBMS_OUTPUT.PUT_LINE( 'Hello World.' ); 
 END; 
 / 
 
DO $$ 
 BEGIN 
     PERFORM DBMS_OUTPUT.SERVEROUTPUT( TRUE ); 
     PERFORM DBMS_OUTPUT.PUT_LINE( 'Hello World.' ); 
 END; 
 $$ 
 ;

F.29.41.5. Migrating Packages #

This section explains how to migrate PL/SQL packages.

Description

A package defines and contains procedures and functions as a single relationship group in the database.

Functional differences

  • Oracle database

    • Packages can be created.

  • Tantor SE

    • Packages cannot be created.

Packages cannot be created in Tantor SE, so define a schema with the same name as the package and define functions that have a relationship in the schema so that they are treated as a single group. In the following sections, the migration procedure is explained for each feature to be defined in a package.

F.29.41.5.1. Defining Functions Within a Package #

Functional differences

  • Oracle database

    • Functions can be created within a package.

  • Tantor SE

    • The package itself cannot be created.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keywords CREATE and PACKAGE, and identify where they are defined.

  2. Define a schema with the same name as the package.

  3. If a FUNCTION statement is specified within a CREATE PACKAGE BODY statement, define, within the schema created in step 2, the functions that were defined within the package.

Migration example

The example below shows migration when a package is defined and functions are created within that package.

Oracle database Tantor SE
CREATE PACKAGE smpl_pkg AS 
   FUNCTION remove_row( rm_i_name VARCHAR2 ) 
     RETURN INTEGER; 
 END smpl_pkg; 
 / 
 CREATE PACKAGE BODY smpl_pkg AS 
   FUNCTION remove_row( rm_i_name VARCHAR2 ) 
     RETURN INTEGER IS 


       rtn_row INTEGER; 
     BEGIN 
       DELETE FROM inventory_table 
 WHERE i_name = rm_i_name; 


       RETURN(SQL%ROWCOUNT); 
     END; 
 END smpl_pkg; 
 /
CREATE SCHEMA smpl_scm; 








 CREATE FUNCTION smpl_scm.remove_row( 
  rm_i_name VARCHAR 
 ) RETURNS INTEGER AS $$ 
 DECLARE 
   rtn_row INTEGER; 
 BEGIN 
   DELETE FROM inventory_table 
     WHERE i_name = rm_i_name; 
   GET DIAGNOSTICS rtn_row := ROW_COUNT; 
   RETURN rtn_row; 
 END; 
 $$ LANGUAGE plpgsql; 
 

See

Refer to “Defining Functions” for information on migrating FUNCTION statements within a package.

F.29.41.5.2. Defining Procedures Within a Package #

Functional differences

  • Oracle database

    • Procedures can be created within a package.

  • Tantor SE

    • The package itself cannot be created.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keywords CREATE and PACKAGE, and identify where they are defined.

  2. Define a schema with the same name as the package.

  3. If a PROCEDURE statement is specified within a CREATE PACKAGE BODY statement, migrate the procedures that were defined within the package to functions and define them within the schema created in step 2.

Migration example

The example below shows migration when a package is defined and procedures are created within that package.

Oracle database Tantor SE
CREATE PACKAGE smpl_pkg AS 
  PROCEDURE increase_row( 
   add_i_num SMALLINT, 
   add_i_name VARCHAR2, 
   add_i_quantity INTEGER, 
   add_i_warehouse SMALLINT 
  ); 
  END smpl_pkg; 
 / 
 CREATE PACKAGE BODY smpl_pkg AS 
  PROCEDURE increase_row( 
   add_i_num SMALLINT, 
   add_i_name VARCHAR2, 
   add_i_quantity INTEGER, 
   add_i_warehouse SMALLINT 
  ) IS 
   BEGIN 
    INSERT INTO inventory_table 
     VALUES ( add_i_num, 
              add_i_name, 
              add_i_quantity, 
              add_i_warehouse ); 
     END; 
 END smpl_pkg; 
 /
CREATE SCHEMA smpl_scm; 


















 CREATE FUNCTION smpl_scm.increase_row( 
  add_i_num SMALLINT, 
  add_i_name VARCHAR, 
  add_i_quantity INTEGER, 
  add_i_warehouse SMALLINT 
 ) RETURNS VOID AS $$ 
 BEGIN 
  INSERT INTO inventory_table 
   VALUES ( add_i_num, 
            add_i_name, 
            add_i_quantity, 
            add_i_warehouse ); 
 END; 
 $$ LANGUAGE plpgsql; 
 

See

Refer to “Defining Procedures” for information on migrating PROCEDURE statements within a package.

F.29.41.5.3. Sharing Variables Within a Package #

Functional differences

  • Oracle database

    • Variables can be shared within a package.

  • Tantor SE

    • A package cannot be created, so variables cannot be shared.

Migration procedure

Use a temporary table instead of variables within a package. Use the following procedure to perform migration:

  1. Search for the keywords CREATE and PACKAGE, and identify where they are defined.

  2. Check for variables defined directly in a package.

  3. Create a temporary table that defines the variables checked in step 2 in a column.

  4. Insert one record to the temporary table created in step 3. (The set value is the initial value specified within the package.)

  5. Replace the respective portions that reference a variable and set a variable with SQL statements.

    • To reference a variable, use a SELECT INTO statement to store a value in the variable and then reference it. (A variable for referencing a variable must be defined separately.)

    • To update a variable, use an UPDATE statement and update the target column.

Migration example

The example below shows migration when a package is defined and variables within the package are shared.

Oracle database Tantor SE
SET SERVEROUTPUT ON; 
 CREATE PACKAGE row_pkg AS 
   PROCEDURE set_item( item INTEGER ); 
   i_item INTEGER; 
 END row_pkg; 
 / 
 CREATE PACKAGE BODY row_pkg AS 


 PROCEDURE set_item( 
 item INTEGER 
 ) IS 
     BEGIN 
       i_item := item; 
     END; 
 END row_pkg; 
 / 
 ------------------------------------------------- 
 SET SERVEROUTPUT ON; 












 BEGIN 


   row_pkg.set_item( 1000 ); 




   DBMS_OUTPUT.PUT_LINE( 
          'ITEM :' || row_pkg.i_item ); 
   row_pkg.set_item(2000); 




   DBMS_OUTPUT.PUT_LINE( 
          'ITEM :' || row_pkg.i_item ); 
 END; 
 / 
 
CREATE SCHEMA row_pkg; 














 CREATE FUNCTION row_pkg.set_item( 
 item INTEGER 
 ) RETURNS VOID AS $$ 
   BEGIN 
     UPDATE row_pkg_variables SET i_item = item; 
   END; 
 $$ LANGUAGE plpgsql; 


 ------------------------------------------------- 
 CREATE TEMP TABLE row_pkg_variables ( i_item INTEGER ); 
 INSERT INTO row_pkg_variables VALUES (0); 


 DO $$ 
 DECLARE 
   g_item INTEGER; 
 BEGIN 
   PERFORM DBMS_OUTPUT.SERVEROUTPUT( TRUE ); 
   PERFORM row_pkg.set_item( 1000 ); 
   SELECT i_item INTO g_item 
     FROM row_pkg_variables; 
   PERFORM DBMS_OUTPUT.PUT_LINE( 
                  'ITEM :' || g_item ); 
   PERFORM row_pkg.set_item(2000); 
   SELECT i_item INTO g_item 
     FROM row_pkg_variables; 
   PERFORM DBMS_OUTPUT.PUT_LINE( 
                  'ITEM :' || g_item ); 
 END; 
 $$ 
 ; 

F.29.42. Migration: Chapter 6 Notes on Using orafce #

This chapter provides notes on using Oracle database compatibility features added by orafce.

F.29.42.1. Data Types #

This section explains how to migrate data types added by orafce.

F.29.42.1.1. Notes on VARCHAR2 #

This section provides notes on VARCHAR2.

F.29.42.1.1.1. Specifying the Maximum Number of Bytes and Maximum Number of Characters #

Functional differences

  • Oracle database

    • Specifying the keyword BYTE or CHAR after a size enables the size to be indicated in terms of the maximum number of bytes or the maximum number of characters.

  • Tantor SE

    • The keyword BYTE or CHAR cannot be set after the size.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword VARCHAR2 and check if the keyword BYTE or CHAR is specified after the size.

  2. If the BYTE keyword is specified, delete it.

  3. If the CHAR keyword is specified, delete it and convert the data type to VARCHAR.

Migration example

The example below shows migration when the maximum number of bytes or the maximum number of characters for the VARCHAR2 type is specified.

Oracle database Tantor SE
CREATE TABLE t1( 
  col1 VARCHAR2(5 BYTE), 
  col2 VARCHAR2(5 CHAR) 
 );
CREATE TABLE t1( 
  col1 VARCHAR2(5), 
  col2 VARCHAR(5) 
 );

Note

The VARCHAR2 type does not support collating sequences. Therefore, the following error occurs when a collating sequence like that of an ORDER BY clause is required. At this time, the following HINT will prompt to use a COLLATE clause, however, because collating sequences are not supported, it is not possible to use this clause.

ERROR:  could not determine which collation to use for string comparison
HINT:  Use the COLLATE clause to set the collation explicitly.

If the error shown above is displayed, explicitly cast the column to VARCHAR or TEXT type.

F.29.42.2. Functions #

This section explains how to migrate functions added by orafce.

F.29.42.2.1. INSTRB #

Description

INSTRB searches for a substring in a string and returns the start position (in bytes) of the first occurrence of the substring. ##### 6.2.1.1 Obtaining the Start Position of a Substring (in Bytes) Functional differences

  • Oracle database

    • INSTRB searches for a substring in a string and returns the start position (in bytes) of the substring.

  • Tantor SE

    • There is no INSTRB function. Use STRPOSB instead. STRPOSB is unique to orafce.

Migration procedure

Use the following procedure to migrate to STRPOSB:

  1. Search for the keyword INSTRB and identify where it is used.

  2. Confirm that arguments up to the second argument are specified.

  3. Change INSTRB to STRPOSB.

Migration example

The example below shows migration when searching for a particular substring in a string, and returning the start position of the substring in bytes.

Oracle database Tantor SE
SELECT c_code, INSTRB( c_address, ',' ) 
  FROM company_table;
SELECT c_code, STRPOSB( c_address, ',' ) 
  FROM company_table;

Note

If the third argument is specified in INSTRB, refer to the conversion example shown below. If the fourth argument is specified, migration is not possible.

Information

The general rules for STRPOSB are as follows:

Description

INSTRB returns the start position (in bytes) of a substring within a string.

Specification format

Figure F.54. STRPOSB

STRPOSB

General rules

  • STRPOSB searches for string str2 in str1 and returns the start position it finds in bytes.

  • If str2 is not found, 0 is returned.

  • The data type of the return value is INTEGER.

F.29.42.2.1.1. Obtaining the Start Position of a Substring from a Specified Search Start Position (in Bytes) #

Functional differences

  • Oracle database

    • The search start position is specified in the third argument of INSTRB.

  • Tantor SE

    • A search start position cannot be specified with STRPOSB.

Migration procedure

A search start position cannot be specified, so truncate the search target string to the start position so that the same result is returned. Use the following procedure to perform migration:

  1. Search for the keyword INSTRB and identify where it is used.

  2. Confirm that arguments up to the third argument are specified and that a positive number is specified.

  3. Enclose the string specified in the first argument with SUBSTRB, and specify the value specified in the third argument of INSTRB as the second argument of SUBSTRB.

  4. Change INSTRB to STRPOSB and delete the value specified in the third argument.

  5. Enclose the function in a simple CASE expression to evaluate the result of the function changed in step 4.
    Define the selector so that 0 is returned when the result is 0.
    If the result is not 0, specify the same function as in step 4, and add the value obtained by subtracting 1 from the value specified in the second argument of SUBSTRB.

Migration example

The example below shows migration when a search start position is specified and then the start position of a string is found in bytes.

Oracle database Tantor SE
SELECT c_code, INSTRB( c_address, '-', 10 ) 
 FROM company_table; 








 
SELECT c_code, 
 CASE STRPOSB( SUBSTRB( c_address, 10 ),'-') 
 WHEN 0 THEN 0 
 ELSE STRPOSB( SUBSTRB( c_address, 10 ), '-' ) + 9 
 END 
 FROM company_table;
F.29.42.2.2. INSTRC, INSTR2, and INSTR4 #

Description

INSTRC, INSTR2, and INSTR4 return the start position of a substring in a string using the relevant encoding.

Functional differences

  • Oracle database

    • INSTRC, INSTR2, and INSTR4 use the relevant encoding to search for a substring in a string from a specified position and then return the start position of the substring.

  • Tantor SE

    • There are no INSTRC, INSTR2, and INSTR4 functions. Only Unicode encoding is used in Tantor SE.

Migration procedure

Use the following procedure to migrate to INSTR:

  1. Search for the keywords INSTRC, INSTR2, and INSTR4, and identify where they are used.

  2. Change those keywords to INSTR.

Migration example

The example below shows migration from INSTRC, INSTR2, and INSTR4.

Oracle database Tantor SE
 SELECT c_name, INSTRC( c_name, 'Corp', 2, 1 ) 
  FROM company_table; 


 SELECT c_name, INSTR2( c_name, 'Corp', 2, 1 ) 
  FROM company_table; 


 SELECT c_name, INSTR4( c_name, 'Corp', 2, 1 ) 
  FROM company_table;
SELECT c_name, INSTR( c_name, 'Corp', 2, 1 ) 
  FROM company_table; 












 
F.29.42.2.3. LENGTHC, LENGTH2, and LENGTH4 #

Description

LENGTHC, LENGTH2, and LENGTH4 use the relevant encoding to return the length of the specified string.

Functional differences

  • Oracle database

    • LENGTHC, LENGTH2, and LENGTH4 use the relevant encoding to return the length of the specified string.

  • Tantor SE

    • There are no LENGTHC, LENGTH2, and LENGTH4 functions. Only Unicode encoding is used in Tantor SE.

Migration procedure

Use the following procedure to migrate to LENGTH:

  1. Search for the keywords LENGTHC, LENGTH2, and LENGTH4, and identify where they are used.

  2. Change those keywords to LENGTH.

Migration example

The example below shows migration from LENGTHC, LENGTH2, and LENGTH4.

Oracle database Tantor SE
 SELECT name, LENGTHC( name ) 
  FROM staff_table 
  WHERE job = 'sales member'; 


 SELECT name, LENGTH2( name ) 
  FROM staff_table 
  WHERE job = 'sales member'; 


 SELECT name, LENGTH4( name ) 
  FROM staff_table 
  WHERE job = 'sales member';
 SELECT name, LENGTH( name ) 
  FROM staff_table 
  WHERE job = 'sales member'; 
















 
F.29.42.2.4. LISTAGG #

Description

LISTAGG returns a concatenated, delimited list of string values.

F.29.42.2.4.1. Specifying the Join Sequence for a List #

Functional differences

  • Oracle database

    • The join sequence for a list is specified using WITHIN GROUP(ORDER BY).

  • Tantor SE

    • WITHIN GROUP(ORDER BY) cannot be used. Instead, a join sequence can be specified using ORDER BY immediately after the value.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword LISTAGG and confirm where it is used.

  2. Move the ORDER BY clause of WITHIN GROUP(ORDER BY) immediately after the value of LISTAGG and then delete WITHIN GROUP().

Migration example

The example below shows migration of the join sequence of specified values.

Oracle database Tantor SE
 SELECT manager_id, 
        LISTAGG( name, ', ' ) 
         WITHIN GROUP( ORDER BY staff_id ) 
  FROM staff_table 
  GROUP BY manager_id;
 SELECT manager_id, 
        LISTAGG( name, ', ' ORDER BY staff_id ) 


  FROM staff_table 
  GROUP BY manager_id;
F.29.42.2.4.2. Specifying the Join Sequence for a List per Group (Window Functions) #

Functional differences

  • Oracle database

    • The join sequence for a list per group is specified using WITHIN GROUP(ORDER BY) OVER(PARTITION BY).

  • Tantor SE

    • The join sequence for a list per group cannot be specified.

Migration procedure

The join sequence for a list per group cannot be specified, so sort the data into the sequence in which it is to be joined and then join it. Use the following procedure to perform migration:

  1. Search for the keywords LISTAGG and OVER, and identify where the OVER clause of LISTAGG is used.

  2. Convert the table in the FROM clause to a subquery, and move the ORDER BY clause of WITHIN GROUP(ORDER BY) to the subquery.

  3. Delete WITHIN GROUP(ORDER BY).

Migration example

The example below shows migration when a join sequence for a list per group is specified.

Oracle database Tantor SE
 SELECT name, 
        manager_id, 
        LISTAGG( name, ', ' ) 
         WITHIN GROUP( ORDER BY staff_id ) 
         OVER( PARTITION BY manager_id )  
  FROM staff_table; 


 
 SELECT name, 
        manager_id, 
        LISTAGG( name, ', ' ) 


         OVER( PARTITION BY manager_id ) 
  FROM ( SELECT * FROM staff_table 
          ORDER BY staff_id ) st_tbl; 
 
F.29.42.2.5. NLSSORT #

Description

NLSSORT returns a binary value that denotes the lexical order of the locale (COLLATE).

F.29.42.2.5.1. Sorting by the Specified Locale #

Functional differences

  • Oracle database

    • The locale is specified by NLS_SORT=locale.
      The specifiable locales are provided by the Oracle database.

  • Tantor SE

    • The locale is specified by locale.
      The specifiable locales depend on the operating system.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword NLSSORT and identify where it is used.

  2. Delete NLS_SORT= and change the locale to the locale used by the operating system corresponding to the specified collating sequence.

Migration example

The example below shows migration when the specified locale is used for sorting. Note that the example locale in Tantor SE would be the value specified for Linux.

Oracle database Tantor SE
 SELECT c_code, c_name 
  FROM company_table 
  ORDER BY NLSSORT( c_name, 
                    'NLS_SORT = xDanish' ); 


 SELECT c_code, c_name 
  FROM company_table 
  ORDER BY NLSSORT( c_name, 
                    'NLS_SORT = JAPANESE_M' );
 SELECT c_code, c_name 
  FROM company_table 
  ORDER BY NLSSORT( c_name, 'danish' ); 




 SELECT c_code, c_name 
  FROM company_table 
  ORDER BY NLSSORT( c_name, 'ja_JP.UTF8' ); 
 
F.29.42.2.5.2. Sorting by Character Set #

Functional differences

  • Oracle database

    • NLS_SORT=BINARY is specified in the locale specification for sorting by character set.

  • Tantor SE

    • C is specified in the locale specification for sorting by character set.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword NLSSORT and identify where it is used.

  2. If NLS_SORT=BINARY is specified for the locale, change it to C.

Migration example

The example below shows migration when the character set is used for sorting.

Oracle database Tantor SE
 SELECT c_code, c_name 
  FROM company_table 
  ORDER BY NLSSORT( c_name, 'NLS_SORT = BINARY' );
 SELECT c_code, c_name 
  FROM company_table 
  ORDER BY NLSSORT( c_name, 'C' );
F.29.42.2.5.3. Case-Insensitive Sorting #

Functional differences

  • Oracle database

    • Specifying _CI at the end of the locale sets case-insensitive sorting.

  • Tantor SE

    • _CI cannot be specified at the end of the locale.

Migration procedure

There are no features that perform case-insensitive sorting, so make all characters either uppercase or lowercase before starting sorting so that the same result is returned. Use the following procedure to perform migration:

  1. Search for the keyword NLSSORT and identify where it is used.

  2. If _CI is specified at the end of the specified locale, put the sort column inside the parentheses of LOWER (or UPPER).

Migration example

The example below shows migration when case-insensitive sorting is used.

Oracle database Tantor SE
 SELECT c_code, c_name 
  FROM company_table 
 ORDER BY NLSSORT( c_name, 
                   'NLS_SORT = JAPANESE_M_CI' );
 SELECT c_code, c_name 
  FROM company_table 
  ORDER BY NLSSORT( LOWER( c_name ), 
                    'ja_JP.UTF8' ); 
 
F.29.42.2.6. SUBSTRC, SUBSTR2, and SUBSTR4 #

Description

SUBSTRC, SUBSTR2, and SUBSTR4 extract part of a string in the character unit of the relevant encoding.

Functional differences

  • Oracle database

    • SUBSTRC, SUBSTR2, and SUBSTR4 extract part of a string in the character unit of the relevant encoding.

  • Tantor SE

    • There are no SUBSTRC, SUBSTR2, and SUBSTR4 functions. Only Unicode encoding is used in Tantor SE.

Migration procedure

Use the following procedure to migrate to SUBSTR:

  1. Search for the keywords SUBSTRC, SUBSTR2, and SUBSTR4, and identify where they are used.

  2. Change those keywords to SUBSTR.

Migration example

The example below shows migration when part of a string is extracted in the character unit of the relevant encoding.

Oracle database Tantor SE
 SELECT SUBSTRC( c_telephone, 5, 8 ) 
  FROM company_table; 


 SELECT SUBSTR2( c_telephone, 5, 8 ) 
 FROM company_table; 


 SELECT SUBSTR4( c_telephone, 5, 8 ) 
  FROM company_table;
 SELECT SUBSTR( c_telephone, 5, 8 ) 
  FROM company_table; 












 
F.29.42.2.7. SUBSTRB #

Description

SUBSTRB extracts part of a string in bytes.

F.29.42.2.7.1. Specifying Zero as the Start Position #

Functional differences

  • Oracle database

    • If 0 is specified as the start position, the part of the string is extracted from the first byte.

  • Tantor SE

    • If 0 is specified as the start position, extraction starts at the position found by subtracting 1 from the start position and shifting by that number of positions to the left.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword SUBSTRB and identify where it is used.

  2. If 0 is specified as the start position, change it to 1.

Migration example

The example below shows migration when 0 is specified as the start position for SUBSTRB.

Oracle database Tantor SE
 SELECT SUBSTRB( c_telephone, 0, 7 ) || '-xxxx' 
  FROM company_table;
 SELECT SUBSTRB( c_telephone, 1, 7 ) || '-xxxx' 
  FROM company_table;
F.29.42.2.7.2. Specifying a Negative Value as the Start Position #

Functional differences

  • Oracle database

    • If a negative value is specified as the start position, extraction starts at the position found by counting by that number of bytes after the end of the string.

  • Tantor SE

    • If a negative value is specified as the start position, extraction starts at the position found by subtracting 1 from the start position and shifting by that number of positions to the left.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword SUBSTRB and identify where it is used.

  2. If a negative value is specified as the start position, add (OCTET_LENGTH(firstArgumentOfSubstrb)+1) before the negative value of the start position parameter.

Migration example

The example below shows migration when a negative value is specified as the start position for SUBSTRB.

Oracle database Tantor SE
 SELECT 'xxx-' || 
        SUBSTRB( c_telephone, -8, 3 ) || 
        '-xxxx' 
 FROM company_table; 






 
SELECT 'xxx-' || 
        SUBSTRB( c_telephone, 
                 ( OCTET_LENGTH( c_telephone )  
                    +1 ) -8, 
                   3 ) || 
        '-xxxx' 
  FROM company_table;
F.29.42.2.7.3. Specifying a Value Less Than One as the String Length #

Functional differences

  • Oracle database

    • If a value less than 1 is specified as the string length, NULL is returned.

  • Tantor SE

    • If the string length is 0, a null character is returned. A negative value cannot be specified as a string length.

Migration procedure

Use the following procedure to perform migration. Note that the final step depends on whether NULL or a null character is expected as the return value.

  • When expecting NULL as the return value

    1. Search for the keyword SUBSTRB and identify where it is used.

    2. Confirm that a value less than 1 is specified in the string length parameter.

    3. Change the string length to NULL.

  • When expecting a null character as the return value

    1. Search for the keyword SUBSTRB and identify where it is used.

    2. Confirm that a value less than 1 is specified in the string length parameter.

    3. If a value less than 0 is specified as the string length, change it to 0.

Migration example

The example below shows migration when a value less than 1 is specified as the string length in SUBSTRB. In this example, NULL is expected as the return value.

Oracle database Tantor SE
 SELECT SUBSTRB( c_telephone, 1, -1 ) 
  FROM company_table;
 SELECT SUBSTRB( c_telephone, 1, NULL ) 
  FROM company_table;
F.29.42.2.8. TO_CHAR and TO_DATE #

Description

TO_CHAR and TO_DATE convert the specified value in accordance with the format.

F.29.42.2.8.1. When Only Part of the TO_DATE Datetime Format is Specified #

Functional differences

  • Oracle database

    • If only part of the TO_DATE datetime format is specified, the omitted portion is set automatically, with the year set to the current year, the month set to the current month, the day set to 1, and the hour, minute, and second set to 0.

  • Tantor SE

    • If only part of the TO_DATE datetime format is specified, the omitted portion is set automatically, with the year, month, and day set to 1, and the hour, minute, and second set to 0.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword TO_DATE and confirm that the year or month is not specified in the datetime format.

  2. Use DATE_TRANC to find the year. If the year is omitted, specify SYSDATE to obtain the current year.

  3. Multiply the result of DATE_PART by one month indicated in the INTERVAL type to find the month. If the month is omitted, specify SYSDATE to obtain the current month.

  4. Add the results found in steps 2 and 3.

Migration example

The example below shows migration when only part of the TO_DATE datetime format is specified.

Oracle database Tantor SE
 SELECT TO_DATE( '04', 'MM' ) 
  FROM DUAL;






 SELECT TO_DATE( '2000', 'YYYY' )  
  FROM DUAL; 




  
 SELECT DATE_TRUNC( 'YEAR', SYSDATE() ) 
 + ( DATE_PART( 'MONTH', TO_DATE( '04', 'MM' ) ) - 1 ) 
 * INTERVAL '1 MONTH' 
 FROM DUAL; 


 SELECT DATE_TRUNC( 'YEAR', TO_DATE( '2000', 'YYYY' ) ) 
 + ( DATE_PART( 'MONTH', SYSDATE() ) - 1 ) 
 * INTERVAL '1 MONTH' 
 FROM DUAL;
F.29.42.2.8.2. Omitting the Data Type Format #

Functional differences

  • Oracle database

    • If the data type format (datetime format) is omitted from TO_DATE or TO_CHAR, the values are converted in accordance with NLS_DATE_FORMAT.
      Statements such as ALTER SESSION can be used to change NLS_DATE_FORMAT.

  • Tantor SE

    • If the data type format (datetime format) is omitted from TO_DATE or TO_CHAR, the values are converted in accordance with oracle.nls_date_format.
      Statements such as SET can be used to change oracle.nls_date_format.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keywords TO_DATE and TO_CHAR, and check where the data type format (datetime format) is omitted.

  2. Check the settings of the NLS_DATE_FORMAT parameter.

  3. In oracle.nls_date_format, specify the datetime format specified in the NLS_DATE_FORMAT parameter.

Migration example

The example below shows migration when the date format is specified in the ALTER SESSION statement.

Oracle database Tantor SE
 ALTER SESSION 
  SET NLS_DATE_FORMAT = "yyyy/mm/dd hh24:mi:ss"; 
 SELECT o_code, TO_CHAR( SYSDATE ) 
  FROM ordering_table; 
  
 SET orafce.nls_date_format =  
     'yyyy/mm/dd hh24:mi:ss'; 
 SELECT o_code, 
        TO_CHAR( SYSDATE() ) 
  FROM ordering_table; 
 

See

The scope of supported datetime formats differs between Oracle databases and Tantor SE. Refer to “Formats” for information on the differences in the supported datetime formats.

F.29.42.2.8.3. Setting a Data Type Format Locale (Setting the Third Argument) #

Functional differences

  • Oracle database

    • The third argument (data type format locale setting) can be specified.

  • Tantor SE

    • The third argument (data type format locale setting) cannot be specified.

Migration procedure

The locale cannot be specified in the data type format, so change the server parameters so that the same result is returned. Use the following procedure to perform migration:

  1. Search for the keywords TO_CHAR and TO_DATE, and identify where they are used.

  2. If the third argument is specified, use a SET statement to specify the corresponding server parameter to match the string format locale to be converted. The table below shows the correspondence between the parameters for setting a data type format locale and the server parameters.

  3. Delete the third argument specified in TO_CHAR and TO_DATE.

Correspondence between the parameters for setting a data type format locale and the server parameters

Data type format Parameter for setting data type format locale (Oracle database) Server parameter (Tantor SE)
Number format NLS_NUMERIC_CHARACTERS LC_NUMERIC (*1)
Number format NLS_CURRENCY LC_MONETARY (*1)
Number format NLS_ISO_CURRENCY - (Cannot be migrated because there is no corresponding parameter)
Datetime format NLS_DATE_LANGUAGE LC_TIME (*2)(*3)(*4)

*1: In Oracle databases, the corresponding string is specified directly, but in Tantor SE, the locale is specified. The string that is set is the value predetermined for each locale.

*2: When a string that is dependent on the specified locale is to be found, the prefix TM must be added at the beginning of the date format. If the TM prefix is not specified, an English-language string will be returned.

*3: When a string that is dependent on a Japanese-language or other character set is to be found, the string including the encoding must be specified. (Example: SET LC_TIME=‘ja_JP.UTF-8’)

*4: Migration is possible only if TO_CHAR is used to find a string from a date. If TO_DATE is used, a locale-dependent string cannot be used as input.

Migration example

The example below shows migration when the data type format locale is set (in the third argument).

Oracle database Tantor SE
 SELECT o_code, 
        TO_CHAR( o_price * o_quantity / 1.2, 
                 'l999g999g999d00', 
                 'NLS_NUMERIC_CHARACTERS = '',.'' 
                 NLS_CURRENCY = ''EUR'' ' ) "MONEY" 
   FROM ordering_table;
 SET LC_MONETARY='de_DE'; 
 SET LC_NUMERIC='de_DE'; 
 SELECT o_code, 
        TO_CHAR( o_price * o_quantity / 1.2, 
                 'l999g999g999d00' ) "MONEY" 
  FROM ordering_table;

Information

If the data type format matches the client locale, simply delete the third argument of TO_CHAR.

See

The values that can be specified in the server parameters depend on the locale of the operating system on the client. Refer to the Tantor SE Documentation for details.

F.29.42.2.9. Functions Requiring Parentheses #

Some functions added by orafce do not have arguments. Parentheses must be added to these functions when they are called. The functions to which parentheses must be added are listed below. Functions requiring parentheses:

  • SYSDATE

  • SESSIONTIMEZONE

  • DBTIMEZONE

Migration example

The example below shows migration when a function that has no arguments is called.

Oracle database Tantor SE
 SELECT SYSDATE FROM DUAL;
 SELECT SYSDATE() FROM DUAL;

F.29.42.3. Standard Packages #

This section explains how to migrate the standard packages added by orafce.

F.29.42.3.1. DBMS_ALERT #

Description

The DBMS_ALERT package sends alerts from a PL/pgSQL execution session to multiple other PL/pgSQL execution sessions.

F.29.42.3.1.1. Set Value of DBMS_ALERT.REGISTER #

Functional differences

  • Oracle database

    • The second argument of DBMS_ALERT.REGISTER can be specified. The second argument specifies whether to perform a cleanup of the pipe to be used.
      The default is TRUE, which causes a cleanup to be performed.

  • Tantor SE

    • The second argument cannot be specified.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword DBMS_ALERT.REGISTER and identify where it is used.

  2. If the second argument is specified, delete it.

Migration example

The example below shows migration when the second argument is specified in DBMS_ALERT.REGISTER.

Oracle database Tantor SE
 DBMS_ALERT.REGISTER( 'SAMPLEALERT', TRUE );
 PERFORM DBMS_ALERT.REGISTER( 'SAMPLEALERT' );
F.29.42.3.1.2. Case Sensitivity of Alert Names #

Functional differences

  • Oracle database

    • Alert names are case-insensitive.

  • Tantor SE

    • Alert names are case-sensitive.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keywords DBMS_ALERT.REGISTER, DBMS_ALERT.SIGNAL, DBMS_ALERT.WAITONE, and DBMS_ALERT.REMOVE, and identify where they are used.

  2. If there are alert names in different cases (uppercase and lowercase characters), change them to the same case.

Migration example

The example below shows migration when there is an alert name in uppercase characters and an alert name in lowercase characters. In this example, the alert names are aligned in uppercase.

Oracle database Tantor SE
 DBMS_ALERT.REGISTER( 'SAMPLEALERT', TRUE ); 
 ~ 
 DBMS_ALERT.SIGNAL( 'samplealert', 
                    'TEST MESSAGE 1' );
 PERFORM DBMS_ALERT.REGISTER( 'SAMPLEALERT' ); 
 ~ 
 PERFORM DBMS_ALERT.SIGNAL( 'SAMPLEALERT', 
                            'TEST MESSAGE 1' );
F.29.42.3.1.3. Other Notes on Using DBMS_ALERT #

This section explains the functional differences to be noted when DBMS_ALERT is used. Note that PL/pgSQL features cannot migrate these functional differences. Consider, for example, changing the application logic.

Executing DBMS_ALERT.SIGNAL from Multiple PL/pgSQL Sessions #

Functional differences

  • Oracle database

    • DBMS_ALERT.SIGNAL is serialized according to the execution sequence.
      Therefore, when DBMS_ALERT.SIGNAL is sent from multiple PL/SQL execution sessions to the same alert,
      each DBMS_ALERT.SIGNAL remains in wait state until the preceding DBMS_ALERT.SIGNAL is committed.

  • Tantor SE

    • DBMS_ALERT.SIGNAL is not serialized according to the execution sequence.
      Therefore, even if the preceding DBMS_ALERT.SIGNAL is not yet committed,
      the following DBMS_ALERT.SIGNAL does not enter wait state and the alert that is committed first is reported.

Message Received when Alert is Reported Multiple Times #

Functional differences

  • Oracle database

    • If multiple DBMS_ALERT.SIGNAL procedures are executed between the time that DBMS_ALERT.REGISTER is executed and DBMS_ALERT.WAITANY/WAITONE is executed, the message from the DBMS_ALERT.SIGNAL executed last is received. All earlier alert messages are discarded.

  • Tantor SE

    • If multiple DBMS_ALERT.SIGNAL procedures are executed between the time that DBMS_ALERT.REGISTER is executed and DBMS_ALERT.WAITANY/WAITONE is executed, the message from the DBMS_ALERT.SIGNAL executed first is received. Subsequent alert messages are not discarded but retained.

Note

If alerts with the same name are used in multiple sessions, ensure that all alert messages are received or delete alerts from the PL/pgSQL sessions by using DBMS_ALERT.REMOVE/REMOVEALL at the point where alerts no longer need to be received. If alerts remain when the session is closed, other sessions may no longer be able to receive alerts properly.

F.29.42.3.1.4. Example of Migrating DBMS_ALERT #

The example below shows migration to PL/pgSQL when DBMS_ALERT is used.

Oracle database Tantor SE
(Receiving side) 
 BEGIN 
  DBMS_ALERT.REGISTER( 'SAMPLEALERT', TRUE ); 
 END; 
 / 




 ------------------------------------------------- 
 (Sending side) 


 BEGIN 
   DBMS_ALERT.SIGNAL( 'samplealert', 
                      'TEST MESSAGE 1' ); 
   COMMIT; 
   DBMS_ALERT.SIGNAL( 'samplealert', 
                      'TEST MESSAGE 2' ); 
   COMMIT; 
 END; 
 / 
 ------------------------------------------------- 
 (Receiving side) 
 SET SERVEROUTPUT ON 
 DECLARE 
  alname VARCHAR2(100) := 'SAMPLEALERT'; 
  almess VARCHAR2(1000); 
  alst   NUMBER; 
 BEGIN 
  DBMS_ALERT.WAITONE( alname, almess, alst, 60 ); 
  DBMS_OUTPUT.PUT_LINE( alname ); 
  DBMS_OUTPUT.PUT_LINE( almess ); 
  DBMS_OUTPUT.PUT_LINE( 'alst =' || alst ); 
  DBMS_ALERT.REMOVE( alname ); 
 END; 
 / 




  
 (Receiving side) 
 DO $$ 
 BEGIN 
  PERFORM DBMS_ALERT.REGISTER( 'SAMPLEALERT' ); 
 END; 
 $$ 
 ; 
 ------------------------------------------------- 
 (Sending side) 
 DO $$ 
 BEGIN 
  PERFORM DBMS_ALERT.SIGNAL( 'SAMPLEALERT', 
                             'TEST MESSAGE 1' ); 
  PERFORM DBMS_ALERT.SIGNAL( 'SAMPLEALERT', 
                             'TEST MESSAGE 2' ); 
 END; 
 $$ 
 ; 


 ------------------------------------------------- 
 (Receiving side) 
 DO $$ 
 DECLARE 
  alname VARCHAR2(100) := 'SAMPLEALERT'; 
  almess VARCHAR2(1000); 
  alst   int; 
 BEGIN 
  PERFORM DBMS_OUTPUT.SERVEROUTPUT( TRUE ); 
  SELECT message, status INTO almess, alst 
   FROM DBMS_ALERT.WAITONE( alname, 60 ); 
  PERFORM DBMS_OUTPUT.PUT_LINE( alname ); 
  PERFORM DBMS_OUTPUT.PUT_LINE( almess ); 
  PERFORM DBMS_OUTPUT.PUT_LINE( 'alst =' || alst ); 
  PERFORM DBMS_ALERT.REMOVE( alname ); 
 END; 
 $$ 
 ; 
 
F.29.42.3.2. DBMS_ASSERT #

Description

The DBMS_ASSERT package checks and normalizes SQL syntax elements.

F.29.42.3.2.1. DBMS_ASSERT.ENQUOTE_LITERAL #

Functional differences

  • Oracle database

    • If a string in an argument is already enclosed in single quotation marks, it is not again enclosed in single quotation marks.

  • Tantor SE

    • Even if a string in an argument is already enclosed in single quotation marks, it is again enclosed in single quotation marks.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword DBMS_ASSERT.ENQUOTE_LITERAL and identify where it is used.

  2. In the conditions of an IF statement, use LEFT and RIGHT to check the leading and trailing characters.

  3. If each result does not match a single quotation mark (E’’), use ENQUOTE_LITERAL to replace it.

Migration example

The example below shows migration when a string is enclosed in single quotation marks.

Oracle database Tantor SE
 DBMS_OUTPUT.PUT_LINE( 
  DBMS_ASSERT.ENQUOTE_LITERAL( en_lit ) ); 








 
 IF ( LEFT( en_lit, 1 ) = E'\x27' AND 
      RIGHT( en_lit, 1 ) = E'\x27' ) THEN 
   PERFORM DBMS_OUTPUT.PUT_LINE( en_lit ); 
 ELSE 
  PERFORM DBMS_OUTPUT.PUT_LINE( 
   DBMS_ASSERT.ENQUOTE_LITERAL( en_lit ) ); 
 END IF;

Note

Tantor SE does not verify single quotation marks.

F.29.42.3.2.2. DBMS_ASSERT.ENQUOTE_NAME #

Functional differences

  • Oracle database

    • If the string in the first argument is already enclosed in double quotation marks, it is not again enclosed in double quotation marks.
      In addition, regardless of whether there is a second argument, a string enclosed in double quotation marks is not converted from lowercase to uppercase.

  • Tantor SE

    • Even if the string in the first argument is already enclosed in double quotation marks, it is again enclosed in double quotation marks.
      However, a first argument string that is all in lowercase is not enclosed in double quotation marks.
      In addition, if the second argument is set to TRUE or the default, it is converted from uppercase to lowercase even if it is enclosed in double quotation marks.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword DBMS_ASSERT.ENQUOTE_NAME and identify where it is used.

  2. In the conditions of an IF statement, use LEFT and RIGHT to check the leading and trailing characters.

  3. If each result does not match a double quotation mark (E’’), use ENQUOTE_NAME to replace it.

Migration example

The example below shows migration when a string is enclosed in double quotation marks.

Oracle database Tantor SE
 DBMS_OUTPUT.PUT_LINE( 
  DBMS_ASSERT.ENQUOTE_NAME( en_nam ) ); 








  
 IF ( LEFT( en_nam, 1 ) = E'\x22' AND 
      RIGHT( en_nam, 1 ) = E'\x22' ) THEN 
   PERFORM DBMS_OUTPUT.PUT_LINE( en_nam ); 
 ELSE 
  PERFORM DBMS_OUTPUT.PUT_LINE( 
   DBMS_ASSERT.ENQUOTE_NAME( en_nam ) ); 
 END IF;
F.29.42.3.2.3. DBMS_ASSERT.SIMPLE_SQL_NAME #

Functional differences

  • Oracle database

    • If the leading or trailing position of a string in an argument contains a space, the space is deleted before the string is evaluated.

  • Tantor SE

    • If the leading or trailing position of a string in an argument contains a space, the string is evaluated as is, causing an error.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword DBMS_ASSERT.SIMPLE_SQL_NAME and identify where it is used.

  2. If the leading or trailing position of a string in an argument contains a space, use TRIM to delete the space immediately preceding or following the argument string.

Migration example

The example below shows migration when the leading or trailing position of a string in an argument contains a space.

Oracle database Tantor SE
DBMS_OUTPUT.PUT_LINE( 
  DBMS_ASSERT.SIMPLE_SQL_NAME( si_nam ) ); 
  
 PERFORM DBMS_OUTPUT.PUT_LINE( 
  DBMS_ASSERT.SIMPLE_SQL_NAME( 
   TRIM( both from si_nam ) ) );

See

The strings checked by DBMS_ASSERT.SIMPLE_SQL_NAME correspond to identifiers among the SQL elements. Refer to “The SQL Language” > “Lexical Structure” > “Identifiers and Key Words” in the Tantor SE Documentation for information on the values that can be used as identifiers in Tantor SE.

F.29.42.3.2.4. DBMS_ASSERT.SQL_OBJECT_NAME #

Functional differences

  • Oracle database

    • DBMS_ASSERT.SQL_OBJECT_NAME exists.

  • Tantor SE

    • DBMS_ASSERT.SQL_OBJECT_NAME does not exist. Use DBMS_ASSERT.OBJECT_NAME instead.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword DBMS_ASSERT.SQL_OBJECT_NAME and identify where it is used.

  2. Change DBMS_ASSERT.SQL_OBJECT_NAME to DBMS_ASSERT.OBJECT_NAME.

Migration example

The example below shows migration when an input value is verified as a qualified SQL identifier of an existing SQL object.

Oracle database Tantor SE
 SELECT 
   DBMS_ASSERT.SQL_OBJECT_NAME( 'inventory_table' ) 
  INTO table_name 
  FROM DUAL;
 SELECT 
   DBMS_ASSERT.OBJECT_NAME( 'inventory_table' ) 
  INTO table_name 
  FROM DUAL;
F.29.42.3.2.5. Example of Migrating DBMS_ASSERT #

The example below shows migration to PL/pgSQL when DBMS_ASSERT is used.

Oracle database Tantor SE
 SET SERVEROUTPUT ON 
 DECLARE 
  en_lit VARCHAR2(50) := '''ENQUOTE_LITERAL'''; 
  en_nam VARCHAR2(50) := '"enquote_name"'; 
  si_nam VARCHAR2(50) := ' SIMPLE_SQL_NAME   '; 
  table_name VARCHAR2(20); 
 BEGIN 


  DBMS_OUTPUT.PUT_LINE( 
   DBMS_ASSERT.ENQUOTE_LITERAL( en_lit )); 












  DBMS_OUTPUT.PUT_LINE( 
   DBMS_ASSERT.ENQUOTE_NAME( en_nam )); 












  DBMS_OUTPUT.PUT_LINE( 
   DBMS_ASSERT.SIMPLE_SQL_NAME( si_nam )); 




  SELECT DBMS_ASSERT.SQL_OBJECT_NAME( 
                     'inventory_table' ) 
  INTO table_name 
  FROM DUAL; 
  DBMS_OUTPUT.PUT_LINE( 
              'Object is : ' || table_name ); 
 END; 
 / 
 
 DO $$ 
 DECLARE 
  en_lit VARCHAR2(50) := '''ENQUOTE_LITERAL''';  
  en_nam VARCHAR2(50) := '"enquote_name"';  
  si_nam VARCHAR2(50) := ' SIMPLE_SQL_NAME   ';  
  table_name VARCHAR2(20);  
 BEGIN 
  PERFORM DBMS_OUTPUT.SERVEROUTPUT(TRUE);  
  IF ( LEFT( en_lit, 1 ) = E'\x27' AND 
       RIGHT( en_lit, 1 ) = E'\x27' ) THEN 
   PERFORM DBMS_OUTPUT.PUT_LINE( en_lit );  
  ELSE 
   PERFORM DBMS_OUTPUT.PUT_LINE( 
    DBMS_ASSERT.ENQUOTE_LITERAL( en_lit )); 
  END IF; 


  IF ( LEFT( en_nam, 1 ) = E'\x22' AND 
       RIGHT( en_nam, 1 ) = E'\x22' ) THEN 
   PERFORM DBMS_OUTPUT.PUT_LINE( en_nam ); 
  ELSE 
   PERFORM DBMS_OUTPUT.PUT_LINE( 
    DBMS_ASSERT.ENQUOTE_NAME( en_nam ) ); 
  END IF;  


  PERFORM DBMS_OUTPUT.PUT_LINE( 
   DBMS_ASSERT.SIMPLE_SQL_NAME( 
                       TRIM( both from si_nam ) ) ); 


  SELECT DBMS_ASSERT.OBJECT_NAME( 
                     'inventory_table' ) 
   INTO table_name 
   FROM DUAL; 
  PERFORM DBMS_OUTPUT.PUT_LINE( 
                      'Object is : ' || table_name ); 
 END; 
 $$ 
 ;  
F.29.42.3.3. DBMS_OUTPUT #

Description

The DBMS_OUTPUT package sends messages from PL/pgSQL to clients such as psql.

F.29.42.3.3.1. Differences in the Timing of Output Immediately After DBMS_OUTPUT.SERVEROUTPUT Changes from OFF to ON #

Functional differences

  • Oracle database

    • Messages stored in the buffer while SERVEROUTPUT is OFF are displayed after the execution of the first SQL statement or anonymous PL/SQL after SERVEROUTPUT changes to ON.

  • Tantor SE

    • Messages stored in the buffer while SERVEROUTPUT is FALSE are not displayed even after the execution of the first SQL statement or anonymous block after SERVEROUTPUT changes to TRUE. DBMS_OUT.NEW_LINE must be executed.

Migration procedure

Use the following procedure to perform migration: 1. Search for the keyword SERVEROUTPUT and identify where it changes from OFF to ON. 2. Change the code so that DBMS_OUT.NEW_LINE is executed immediately after the SQL statement or anonymous block that is executed after the SERVEROUTPUT statement is changed to ON.

Migration example

The example below shows migration when the status of SERVEROUTPUT changes.

Oracle database Tantor SE
 SET SERVEROUTPUT OFF; 










 ... 


 SET SERVEROUTPUT ON; 
 SELECT * FROM dual; 










 
 DO $$ 
 BEGIN 
 PERFORM DBMS_OUTPUT.SERVEROUTPUT( FALSE ); 
 END; 
 $$ 
 ; 
 ... 


 SELECT * FROM dual; 
 DO $$ 
 BEGIN 
  PERFORM DBMS_OUTPUT.SERVEROUTPUT( TRUE );  
  PERFORM DBMS_OUTPUT.NEW_LINE(); 
 END; 
 $$ 
 ; 
 
F.29.42.3.3.2. Other Notes on Using DBMS_OUTPUT #

This section explains the functional differences to be noted when DBMS_OUTPUT is used. Note that PL/pgSQL features cannot migrate these functional differences. Consider, for example, changing the application logic.

Differences in the Output Timing of DBMS_OUTPUT.PUT_LINE and DBMS_OUTPUT.NEW_LINE #

Functional differences

  • Oracle database

    • When SERVEROUTPUT is ON, the outputs of DBMS_OUTPUT.PUT_LINE and DBMS_OUTPUT.NEW_LINE are displayed together after the procedure finishes.
      These outputs are stored in the buffer of the server while the procedure is running.

  • Tantor SE

    • When SERVEROUTPUT is TRUE, the outputs from executing DBMS_OUTPUT.PUT_LINE and DBMS_OUTPUT.NEW_LINE are sent to the client and displayed immediately.
      They are not stored in the buffer of the server.

F.29.42.3.3.3. Example of Migrating DBMS_OUTPUT #

The example below shows migration to PL/pgSQL when DBMS_OUTPUT is used.

Oracle database Tantor SE
 SET SERVEROUTPUT OFF; 
 BEGIN 


  DBMS_OUTPUT.ENABLE( NULL ); 
  DBMS_OUTPUT.PUT_LINE( '1:Hello World' ); 
 END; 
 / 


 SET SERVEROUTPUT ON 
 SELECT * FROM dual; 












 
 DO $$ 
 BEGIN 
  PERFORM DBMS_OUTPUT.SERVEROUTPUT( FALSE ); 
  PERFORM DBMS_OUTPUT.ENABLE( NULL ); 
  PERFORM DBMS_OUTPUT.PUT_LINE( '1:Hello World' ); 
 END; 
 $$ 
 ; 
 SELECT * FROM dual; 
 DO $$ 
  BEGIN 
   PERFORM DBMS_OUTPUT.SERVEROUTPUT( TRUE ); 
   PERFORM DBMS_OUTPUT.NEW_LINE(); 
 END; 
 $$ 
 ; 
F.29.42.3.4. DBMS_PIPE #

Description

The DBMS_PIPE package performs one-to-one communication between PL/pgSQL sessions.

F.29.42.3.4.1. Differences from the DBMS_PIPE.CREATE_PIPE Definition #

Functional differences

  • Oracle database

    • The second argument specifies the maximum size of the pipe in bytes. The default is 8192 bytes.
      The third argument specifies the pipe type. The default is TRUE (private pipe).

  • Tantor SE

    • The second argument specifies the maximum number of messages that the pipe can hold. The default is 0. The specifiable range of numeric values is 1 to 32767.
      The third argument specifies the pipe type. The default is FALSE (public pipe).

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword DBMS_PIPE.CREATE_PIPE and identify where it is used.

  2. Change the code so that the maximum number of messages is specified in the second argument.

  3. If the third argument is omitted and a private pipe is to be created, specify TRUE in the third argument.

Note

Preferably, create a public pipe (the default) as the pipe type. If you create a private pipe, internal information (the creator of the private pipe) will remain even after the pipe is removed. Thus repeatedly creating and removing pipes may ultimately cause memory to run out.

Migration example

The example below shows migration of DBMS_PIPE.CREATE_PIPE.

Oracle database Tantor SE
 DBMS_PIPE.CREATE_PIPE( 
           'pipename', 
           2000,  
           TRUE );
 DBMS_PIPE.CREATE_PIPE( 
           'pipename', 
           50, 
           TRUE );
F.29.42.3.4.2. Return Values of DBMS_PIPE.CREATE_PIPE and DBMS_PIPE.REMOVE_PIPE #

Functional differences

  • Oracle database

    • DBMS_PIPE.CREATE_PIPE and DBMS_PIPE.REMOVE_PIPE both return values.

  • Tantor SE

    • DBMS_PIPE.CREATE_PIPE and DBMS_PIPE.REMOVE_PIPE both do not return values.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keywords DBMS_PIPE.CREATE_PIPE and DBMS_PIPE.REMOVE_PIPE, and identify where they are used.

  2. Change the code so that the call processing identified in step 1 is called by the PERFORM keyword.

  3. If return values are used, replace the target processing with 0.

Migration example

The example below shows migration of DBMS_PIPE.CREATE_PIPE.

Oracle database Tantor SE
 st := DBMS_PIPE.CREATE_PIPE( pipename, 2000 ); 
 DBMS_OUTPUT.PUT_LINE( 'Return Value =' || st ); 


 
 PERFORM DBMS_PIPE.CREATE_PIPE( pipename, 50 ); 
 st := 0; 
 PERFORM DBMS_OUTPUT.PUT_LINE( 
                  'Return Value =' || st );
F.29.42.3.4.3. Creating the Same Pipe Name with DBMS_PIPE.CREATE_PIPE #

Functional differences

  • Oracle database

    • If a pipe with the same name already exists and can be used, DBMS_PIPE.CREATE_PIPE returns normally.

  • Tantor SE

    • If a pipe with the same name already exists, DBMS_PIPE.CREATE_PIPE returns with an error.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword CREATE_PIPE and identify where it is used.

  2. If there may be a pipe with the same name, use the PERFORM statement shown below to check if the same pipe exists.

  3. If NOT FOUND returns TRUE, there is no pipe with the same name, so execute CREATE_PIPE.

PERFORM 1
  FROM DBMS_PIPE.DB_PIPES
  WHERE NAME = nameOfPipeToBeCreated

Migration example

The example below shows migration of CREATE_PIPE when there may be a pipe with the same name.

Oracle database Tantor SE
  
 DECLARE 
  pipename VARCHAR2(1000) := 'TESTPIPE01'; 
 BEGIN 
  DBMS_OUTPUT.PUT_LINE( 
   'Return = '|| DBMS_PIPE.CREATE_PIPE( 
                           pipename, 
                           2000, 
                           TRUE ) ); 






 END; 
 / 
 
 DO $$ 
 DECLARE 
 pipename VARCHAR2(1000) := 'TESTPIPE01'; 
 BEGIN 
  PERFORM 1 
   FROM DBMS_PIPE.DB_PIPES 
   WHERE NAME = pipename;  
  IF ( NOT FOUND ) THEN 
   PERFORM DBMS_PIPE.CREATE_PIPE( pipename, 
                                  50, 
                                  TRUE ); 
 END IF; 
 END; 
 $$ 
 ;
F.29.42.3.4.4. Return Values of DBMS_PIPE.NEXT_ITEM_TYPE #

Functional differences

  • Oracle database

    • DBMS_PIPE.NEXT_ITEM_TYPE has the following return values:
      0: There is no next item.
      6: NUMBER type
      9: VARCHAR2 type
      11: ROWID type
      12: DATE type
      23: RAW type

  • Tantor SE

    • DBMS_PIPE.NEXT_ITEM_TYPE has the following return values:
      0: There is no next item.
      9: NUMERIC type
      11: TEXT type
      12: DATE type
      13: TIMESTAMP type
      23: BYTEA type
      24: RECORD type

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword NEXT_ITEM_TYPE and identify the variable storing the return value of NEXT_ITEM_TYPE.

  2. If the return value of NEXT_ITEM_TYPE is determined, change it to the value in Tantor SE according to the table below.

Correspondence of return values of DBMS_PIPE.NEXT_ITEM_TYPE

Oracle database Tantor SE
NUMBER type NUMERIC type
VARCHAR2 type TEXT type
ROWID type
DATE type
DATE type TIMESTAMP type
RAW type BYTEA type
RECORD type

Migration example

The example below shows migration when processing is branched according to the return value of DBMS_PIPE.NEXT_ITEM_TYPE.

Oracle database Tantor SE
 item := DBMS_PIPE.NEXT_ITEM_TYPE; 
 IF ( item = 6 ) THEN  -- NUMBER type 
 ~ 
 ELSIF ( item = 9 ) THEN -- VARCHAR2 type 
 ~ 
 ELSIF ( item = 12 ) THEN  -- DATE type 
 ~
 item := DBMS_PIPE.NEXT_ITEM_TYPE(); 
 IF ( item = 9 ) THEN  -- NUMERIC type 
 ~ 
 ELSIF ( item =11 ) THEN -- TEXT type 
 ~ 
 ELSIF ( item = 13 ) THEN -- TIMESTAMP type 
 ~
F.29.42.3.4.5. Data Types That Can be Used in DBMS_PIPE.PACK_MESSAGE and UNPACK_MESSAGE #

Functional differences

  • Oracle database

    • The data types that can be used are VARCHAR2, NCHAR, NUMBER, DATE, RAW, and ROWID.
      When RAW or ROWID is used, the data type must be specified after UNPACK_MESSAGE.

  • Tantor SE

    • The data types that can be used are TEXT, NUMERIC, INTEGER (Note), BIGINT (Note), DATE, TIMESTAMP, BYTEA, and RECORD.
      All data types require the data type and empty parentheses to be specified after UNPACK_MESSAGE.

Note

  • The INTEGER and BIGINT data types can be used with PACK_MESSAGE only.

  • The INTEGER and BIGINT types are converted internally to the NUMERIC type. Therefore, use UNPACK_MESSAGE_NUMBER to receive a message.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword UNPACK_MESSAGE and identify where UNPACK_MESSAGE is used.

  2. Change the variable specified in the argument to an assignment expression specified on the left-hand side, separately specify each data type after UNPACK_MESSAGE, and delete the variable from the parentheses.

Migration example

The example below shows migration when a message is sent and received.

Oracle database Tantor SE
DBMS_PIPE.UNPACK_MESSAGE( testnum );
 testnum := 
     DBMS_PIPE.UNPACK_MESSAGE_NUMBER();
F.29.42.3.4.6. Case Sensitivity of DBMS_PIPE.RECEIVE_MESSAGE and SEND_MESSAGE #

Functional differences

  • Oracle database

    • Pipe names are case-insensitive.

  • Tantor SE

    • Pipe names are case-sensitive.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keywords RECEIVE_MESSAGE and SEND_MESSAGE, and check the pipe names.

  2. If there are pipe names in different cases (uppercase and lowercase characters), change them to the same case.

Migration example

The example below shows migration when uppercase and lowercase characters are used for the pipe names.

Oracle database Tantor SE
 (Sending side) 
 st := DBMS_PIPE.SEND_MESSAGE( 'TESTPIPE01', 
                               10, 
                               8192 ); 
 (Receiving side) 
 st := DBMS_PIPE.RECEIVE_MESSAGE( 'testpipe01' );
 (Sending side) 
 st := DBMS_PIPE.SEND_MESSAGE( 'TESTPIPE01', 
                               10, 
                               100 );  
 (Receiving side) 
 st := DBMS_PIPE.RECEIVE_MESSAGE( 'TESTPIPE01' );

Note

The return values of DBMS_PIPE.RECEIVE_MESSAGE and DBMS_PIPE.SEND_MESSAGE differ as shown below.

  • Oracle database

    • There are five return values, as follows:
      0: Completed successfully.
      1: A timeout occurred.
      2: A record in the pipe is too big for the buffer.
      3: An interrupt occurred.
      ORA-23322: The user does not have privileges for reading the pipe.

  • Tantor SE

    • There are two return values, as follows:
      0: Completed successfully.
      1: A timeout occurred.

F.29.42.3.4.7. Differences in the DBMS_PIPE.SEND_MESSAGE Feature #

Functional differences

  • Oracle database

    • The third argument specifies the maximum size of the pipe in bytes. The default is 8192 bytes.

  • Tantor SE

    • The third argument specifies the maximum number of messages that the pipe can hold.
      The specifiable range of numeric values is 1 to 32767.
      Note that if the maximum number of messages is omitted for an implicit pipe, the number is unlimited.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keyword SEND_MESSAGE and identify where the maximum number of bytes is specified.

  2. Replace the maximum number of bytes with the maximum number of messages.

Migration example

The example below shows migration when the maximum pipe size is specified.

Oracle database Tantor SE
 DBMS_PIPE.SEND_MESSAGE( 'testPIPE', 10, 200 );
 DBMS_PIPE.SEND_MESSAGE( 'testPIPE', 10, 10 );

F.29.42.4. Example of Migrating DBMS_PIPE #

The example below shows migration when one-to-one communication is performed between PL/pgSQL sessions.

Oracle database Tantor SE
 (Sending side) 
 SET SERVEROUTPUT ON; 
 DECLARE 
  testnum NUMBER := 111; 
  testvchar2 VARCHAR2(100) := 'Test Message'; 
  testdate DATE := SYSDATE; 
  testraw RAW(100) := '0101010101'; 
  st INT; 
  pipename VARCHAR2(1000) := 'TESTPIPE01'; 
 BEGIN 


  st := DBMS_PIPE.CREATE_PIPE( pipename, 2000 ); 










  DBMS_OUTPUT.PUT_LINE( 'Return Value =' || st ); 




  DBMS_PIPE.PACK_MESSAGE( testnum ); 
  DBMS_PIPE.PACK_MESSAGE( testvchar2 ); 
  DBMS_PIPE.PACK_MESSAGE( testdate ); 
  DBMS_PIPE.PACK_MESSAGE_RAW( testraw ); 
  st := DBMS_PIPE.SEND_MESSAGE( 'TESTPIPE01', 
                                10, 
                                200 ); 
   DBMS_OUTPUT.PUT_LINE( 'Return Value =' || st ); 


 END; 
 / 


 ------------------------------------------------- 
 (Receiving side) 
 SET SERVEROUTPUT ON; 
 DECLARE 
   testnum NUMBER; 
   testvchar2 VARCHAR2(100); 
   testdate DATE; 
   testraw RAW(100); 
   item NUMBER; 
   st INT; 
 BEGIN 


  st := DBMS_PIPE.RECEIVE_MESSAGE( 'testpipe01' ); 
  DBMS_OUTPUT.PUT_LINE( 'Return Value =' || st ); 


  LOOP 
   item := DBMS_PIPE.NEXT_ITEM_TYPE; 
   DBMS_OUTPUT.PUT_LINE( 'Next Item : ' || item ); 


   IF ( item = 6 ) THEN 
    DBMS_PIPE.UNPACK_MESSAGE( testnum ); 


   DBMS_OUTPUT.PUT_LINE( 
    'Get Message : ' || testnum ); 
   ELSIF ( item = 9 ) THEN 
    DBMS_PIPE.UNPACK_MESSAGE( testvchar2 ); 


    DBMS_OUTPUT.PUT_LINE( 
                'Get Message : ' || testvchar2 ); 
   ELSIF ( item = 12 ) THEN 
    DBMS_PIPE.UNPACK_MESSAGE( testdate ); 


    DBMS_OUTPUT.PUT_LINE( 
                'Get Message : ' || testdate ); 
   ELSIF ( item = 23 ) THEN 
    DBMS_PIPE.UNPACK_MESSAGE_RAW( testraw ); 






    DBMS_OUTPUT.PUT_LINE( 
                'Get Message : ' || testraw ); 
   ELSE 
    EXIT; 
   END IF; 
  END LOOP; 
  st := DBMS_PIPE.REMOVE_PIPE( 'testpipe01' ); 


  DBMS_OUTPUT.PUT_LINE( 'Return Value =' || st ); 


 END; 
 / 
 
 (Sending side) 
 DO $$ 
 DECLARE 
  testnum NUMERIC := 111; 
  testtext VARCHAR2(100) := 'Test Message'; 
  testtime TIMESTAMP := current_timestamp; 
  testbytea BYTEA := '0101010101'; 
  st INT; 
  pipename VARCHAR2(1000) := 'TESTPIPE01'; 
 BEGIN 
  PERFORM DBMS_OUTPUT.SERVEROUTPUT( TRUE ); 
  PERFORM 1 
   FROM DBMS_PIPE.DB_PIPES 
    WHERE NAME = pipename;  
  IF ( NOT FOUND ) THEN 
   PERFORM DBMS_PIPE.CREATE_PIPE( pipename,50 ); 
   st := 0; 
   PERFORM DBMS_OUTPUT.PUT_LINE( 
                    'Return Value =' || st ); 
  END IF; 
  PERFORM DBMS_PIPE.PACK_MESSAGE( testnum ); 
  PERFORM DBMS_PIPE.PACK_MESSAGE( testtext ); 
  PERFORM DBMS_PIPE.PACK_MESSAGE( testtime ); 
  PERFORM DBMS_PIPE.PACK_MESSAGE( testbytea ); 
  st := DBMS_PIPE.SEND_MESSAGE( 'TESTPIPE01', 
                                10, 
                                10 );  
  PERFORM DBMS_OUTPUT.PUT_LINE( 
  'Return Value =' || st ); 
 END; 
 $$ 
 ; 
 ------------------------------------------------- 
 (Receiving side) 
 DO $$ 
 DECLARE 
  testnum NUMERIC; 
  testtext VARCHAR2(100); 
  testtime TIMESTAMP; 
  testbytea BYTEA; 
  item INT; 
  st INT; 
 BEGIN 
  PERFORM DBMS_OUTPUT.SERVEROUTPUT( TRUE ); 
  st := DBMS_PIPE.RECEIVE_MESSAGE( 'TESTPIPE01' ); 
  PERFORM DBMS_OUTPUT.PUT_LINE( 
                      'Return Value ='|| st ); 
  LOOP 
   item := DBMS_PIPE.NEXT_ITEM_TYPE(); 
   PERFORM DBMS_OUTPUT.PUT_LINE( 
                       'Next Item : ' || item ); 
   IF ( item = 9 ) THEN 
    testnum := 
     DBMS_PIPE.UNPACK_MESSAGE_NUMBER(); 
    PERFORM DBMS_OUTPUT.PUT_LINE( 
                        'Get Message : ' || testnum ); 
   ELSIF ( item =11 ) THEN 
    testtext := 
     DBMS_PIPE.UNPACK_MESSAGE_TEXT(); 
    PERFORM DBMS_OUTPUT.PUT_LINE( 
                        'Get Message : ' || testtext ); 
   ELSIF ( item = 13 ) THEN 
    testtime := 
     DBMS_PIPE.UNPACK_MESSAGE_TIMESTAMP(); 
    PERFORM DBMS_OUTPUT.PUT_LINE( 
                        'Get Message : ' || testtime ); 
   ELSIF ( item = 23 ) THEN 
    testbytea := 
     DBMS_PIPE.UNPACK_MESSAGE_BYTEA(); 
    testtext := CAST( testbytea 
     AS varchar2(100) ); 
        PERFORM DBMS_OUTPUT.PUT_LINE( 
                            'Get Message : ' || testtext ); 
   ELSE 
    EXIT; 
   END IF; 
  END LOOP; 
  PERFORM DBMS_PIPE.REMOVE_PIPE( 'TESTPIPE01' ); 
  st := 0; 
  PERFORM DBMS_OUTPUT.PUT_LINE( 
                      'Return Value ='|| st ); 
 END; 
 $$ 
 ; 
 
F.29.42.4.1. UTL_FILE #

Description

The UTL_FILE package enables PL/pgSQL to read and write text files.

F.29.42.4.1.1. Appending a Newline at File Closure #

Functional differences

  • Oracle database

    • If data in which no newline is specified remains in the buffer, a newline is appended after the data is output and then the file is closed.

  • Tantor SE

    • If data in which no newline is specified remains in the buffer, the data is output and then the file is closed. A newline is not appended.

Migration procedure

Use the following procedure to perform migration:

  1. Search for the keywords UTL_FILE.FCLOSE and UTL_FILE.FCLOSE_ALL, and identify where they are used.

  2. If UTL_FILE.PUT is executed and no newline is specified during write processing before the file is closed, change the code so that UTL_FILE.NEW_LINE is executed before the file is closed.

Migration example

The example below shows migration when a file that does not end with a newline is closed.

Oracle database Tantor SE
 UTL_FILE.PUT(v_handle, buff); 
 UTL_FILE.FCLOSE(v_handle); 
 
 PERFORM UTL_FILE.PUT(v_handle, buff); 
 PERFORM UTL_FILE.NEW_LINE(v_handle, 1); 
 s_handle := UTL_FILE.FCLOSE(v_handle);
F.29.42.4.1.2. Processing UTL_FILE Exceptions #

Functional differences

  • Oracle database

    • There are exception definitions for the UTL_FILE package. They can be used for determining exceptions in the EXCEPTION clause.

  • Tantor SE

    • There are no exception definitions for the UTL_FILE package.

Migration procedure

There are no exception definitions for the UTL_FILE package, so if they are used for determining exceptions in the EXCEPTION clause, replace them with Tantor SE error codes. Use the following procedure to perform migration:

  1. Search for the keyword UTL_FILE and check if an EXCEPTION clause is specified in the target PL/SQL.

  2. If a UTL_FILE exception is used, replace it with a Tantor SE error code in accordance with the table below.

Correspondence of UTL_FILE exceptions

UTL_FILE exception definition (Oracle database) Migratability Corresponding Tantor SE error code
INVALID_PATH Y RAISE_EXCEPTION
INVALID_MODE Y RAISE_EXCEPTION
INVALID_FILEHANDLE Y RAISE_EXCEPTION
INVALID_OPERATION Y RAISE_EXCEPTION
READ_ERROR N Not generated
WRITE_ERROR Y RAISE_EXCEPTION
INTERNAL_ERROR Y INTERNAL_ERROR
CHARSETMISMATCH N Not generated
FILE_OPEN N Not generated
INVALID_MAXLINESIZE Y RAISE_EXCEPTION
INVALID_FILENAME Y INVALID PARAMETER NULL VALUE NOT ALLOWED (file name is NULL)
ACCESS_DENIED Y RAISE_EXCEPTION
INVALID_OFFSET N Not generated
DELETE_FAILED N Not generated
RENAME_FAILED Y RAISE_EXCEPTION

Y: Can be migrated

N: Cannot be migrated

Migration example

The example below shows migration when an error message is displayed during UTL_FILE exception processing.

Oracle database Tantor SE
 EXCEPTION 
  WHEN UTL_FILE.INVALID_FILEHANDLE THEN 
   v_errmsg := SQLERRM; 
   DBMS_OUTPUT.PUT_LINE(v_errmsg); 
 END;
 EXCEPTION 
  WHEN RAISE_EXCEPTION THEN 
   v_errmsg := SQLERRM;  
   PERFORM DBMS_OUTPUT.PUT_LINE(v_errmsg); 
 END;
F.29.42.4.1.3. Other Notes on Using UTL_FILE #

This section explains the functional differences to be noted when UTL_FILE is used. Note that PL/pgSQL features cannot migrate these functional differences. Consider, for example, changing the application logic.

Differences in the Open Mode of UTL_FILE.FOPEN #

Functional differences

  • Oracle database

    • The rb (read byte), wb (write byte), or ab (append byte) open mode can be specified.

  • Tantor SE

    • The rb (read byte), wb (write byte), and ab (append byte) open modes cannot be specified for OPEN_MODE.

Differences in UTL_FILE.IS_OPEN #

Functional differences

  • Oracle database

    • Executing UTL_FILE.IS_OPEN after UTL_FILE.FCLOSE_ALL returns TRUE.

  • Tantor SE

    • Executing UTL_FILE.IS_OPEN after UTL_FILE.FCLOSE_ALL returns FALSE.

Timing of Write by UTL_FILE.FFLUSH #

Functional differences

  • Oracle database

    • Buffered data up to the newline character is written.

  • Tantor SE

    • All buffered data is written.

F.29.42.4.1.4. Example of Migrating UTL_FILE #

The example below shows migration to PL/pgSQL when UTL_FILE is used.

Oracle database Tantor SE
 SET SERVEROUTPUT ON 
 DECLARE 
  v_handle   UTL_FILE.FILE_TYPE; 
  v_dirname  VARCHAR2(250); 
  v_filename VARCHAR2(250); 
  v_output   VARCHAR2(250); 
  v_getmsg   VARCHAR2(250); 
  v_errmsg   VARCHAR2(1000); 
  v_opcheck  BOOLEAN; 
 BEGIN 
  v_dirname := '/home/oracle'; 
  v_filename := 'sample.txt'; 
  v_output := 'HELLO WORLD!'; 
  v_handle := UTL_FILE.FOPEN(v_dirname, 
                             v_filename, 
                             'w', 
                             256); 




  UTL_FILE.PUT_LINE(v_handle, v_output); 
  UTL_FILE.FFLUSH(v_handle); 
  UTL_FILE.PUT(v_handle, v_output); 


  UTL_FILE.FCLOSE(v_handle); 
  v_handle := UTL_FILE.FOPEN(v_dirname, 
                             v_filename, 
                             'r', 
                             256); 
  UTL_FILE.GET_LINE(v_handle, v_getmsg); 
  DBMS_OUTPUT.PUT_LINE( 
   'GET_MESSAGE : ' || v_getmsg); 
  UTL_FILE.FCLOSE_ALL; 
  v_opcheck := UTL_FILE.IS_OPEN(v_handle); 
  DBMS_OUTPUT.PUT_LINE(CASE 
   WHEN v_opcheck IS NULL THEN 'UNKNOWN' 
   WHEN v_opcheck THEN 'TRUE' 
   WHEN NOT v_opcheck THEN 'FALSE' 
   END); 


  BEGIN 
   UTL_FILE.PUT_LINE(v_handle, v_output); 
  EXCEPTION 
   WHEN UTL_FILE.INVALID_FILEHANDLE THEN 
    v_errmsg := SQLERRM; 
    DBMS_OUTPUT.PUT_LINE(v_errmsg); 
 END; 


 EXCEPTION WHEN OTHERS THEN 
  UTL_FILE.FCLOSE_ALL; 
  v_errmsg := SQLERRM; 
  DBMS_OUTPUT.PUT_LINE(v_errmsg); 
 END; 
 / 
 
 DO $$ 
 DECLARE 
  v_handle   UTL_FILE.FILE_TYPE; 
  v_dirname  VARCHAR2(250); 
  v_filename VARCHAR2(250); 
  v_output   VARCHAR2(250); 
  v_getmsg   VARCHAR2(250); 
  v_errmsg   VARCHAR2(1000); 
  v_opcheck  BOOLEAN; 
 BEGIN 
  PERFORM DBMS_OUTPUT.SERVEROUTPUT(TRUE); 
  PERFORM DBMS_OUTPUT.ENABLE(NULL); 
  v_dirname := '/home/pgsql'; 
  v_filename := 'sample.txt'; 
  v_output := 'HELLO WORLD!'; 
  v_handle := UTL_FILE.FOPEN(v_dirname, 
                             v_filename, 
                             'w', 
                             256); 
  PERFORM UTL_FILE.PUT_LINE(v_handle, v_output); 
  PERFORM UTL_FILE.PUT(v_handle, v_output); 
  PERFORM UTL_FILE.FFLUSH(v_handle); 
  PERFORM UTL_FILE.NEW_LINE(v_handle, 1); 
  v_handle := UTL_FILE.FCLOSE(v_handle); 
  v_handle := UTL_FILE.FOPEN(v_dirname, 
                             v_filename, 
                             'r', 
                             256); 
  v_getmsg := UTL_FILE.GET_LINE(v_handle); 
  PERFORM DBMS_OUTPUT.PUT_LINE( 
   'GET_MESSAGE : ' || v_getmsg); 
  PERFORM UTL_FILE.FCLOSE_ALL(); 
  v_opcheck := UTL_FILE.IS_OPEN(v_handle); 
  PERFORM DBMS_OUTPUT.PUT_LINE(CASE 
   WHEN v_opcheck IS NULL THEN 'UNKNOWN' 
   WHEN v_opcheck THEN 'TRUE' 
   WHEN NOT v_opcheck THEN 'FALSE' 
   END); 


  BEGIN 
   PERFORM UTL_FILE.PUT_LINE(v_handle, v_output); 
  EXCEPTION 
   WHEN RAISE_EXCEPTION THEN 
    v_errmsg := SQLERRM; 
    PERFORM DBMS_OUTPUT.PUT_LINE(v_errmsg); 
   END; 


 EXCEPTION WHEN OTHERS THEN 
  PERFORM UTL_FILE.FCLOSE_ALL(); 
  v_errmsg := SQLERRM; 
  PERFORM DBMS_OUTPUT.PUT_LINE(v_errmsg); 
 END; 
 $$ 
 ;

F.29.43. Appendix A Correspondence with Oracle Databases #

This appendix explains the correspondence between Tantor SE and Oracle databases.

F.29.43.1. A.1 Hint Clauses #

Description

An execution plan specified for a query can be controlled per SQL statement by hints without any change in the settings for the entire server.

F.29.43.1.1. A.1.1 Hint Clause Correspondence #

The table below lists the pg_hint_plan hints that correspond to Oracle database hints.

Correspondence between Oracle database hints and pg_hint_plan

Hint (Oracle database) Hint (Tantor SE)
FIRST_ROWS hint Rows
FULL hint Seqscan
INDEX hint IndexScan
LEADING hint Leading
NO_INDEX hint NoIndexScan
NO_USE_HASH hint NoHashJoin
NO_USE_MERGE hint NoMergeJoin
NO_USE_NL hint NoNestLoop
ORDERED hint Leading
USE_HASH hint HashJoin
USE_MERGE hint MergeJoin
USE_NL hint NestLoop

Note

The optimizer operates differently for each database. Therefore, hint statements that are migrated as is may not have the same effect after migration. Be sure to verify operation at migration.

Migration example

The example below shows migration of a hint clause (INDEX hint).

Oracle database Tantor SE
SELECT /*+INDEX(inventory_table idx1)*/ *
 FROM inventory_table WHERE i_number = 110;
SELECT /*+IndexScan(inventory_table idx1)*/ *
 FROM inventory_table WHERE i_number = 110; 

Note: The string idx1 is the index name defined for the i_number row of inventory_table.

Note

The pg_hint_plan hint, which is an extended feature of Tantor SE, cannot be used to specify a column name or set a query block before the table name specification.

F.29.43.2. A.2 Dynamic Performance Views #

Description

Dynamic performance views are views that can reference information mainly relating to database performance.

F.29.43.2.1. A.2.1 Alternatives for Dynamic Performance Views #

Tantor SE does not contain any dynamic performance views. Consider using the Tantor SE system catalogs or statistics views instead.

The table below lists the alternative system catalogs and statistics views that correspond to the dynamic performance views.

Alternatives for dynamic performance views

Dynamic performance view (Oracle database) System catalog or statistics view (Tantor SE)
VACCESS|pglocks||VACTIVE_SERVICES pg_stat_activity
VARCHIVEDLOG|pgstatarchiver||VCLIENT_STATS pg_stat_activity
VCONTEXT|pgsettings||VDATABASE pg_database
VEMXUSAGESTATS|pgstatuserfunctions||VENABLEDPRIVS pg_authid
VENQUEUELOCK|pglocks||VFILESTAT pg_statio_all_tables
VFIXEDTABLE|pgviews||VFIXED_VIEW_DEFINITION pg_views
VGESBLOCKINGENQUEUE|pglocks||VGLOBAL_BLOCKED_LOCKS pg_locks
VGLOBALTRANSACTION|pglocks||VLOCK pg_locks
VLOCKEDOBJECT|pglocks||VMVREFRESH pg_matviews
VMYSTAT|pgstatalltablesorotherview||VNLS_PARAMETERS pg_settings
VNLSVALIDVALUES|pgproc < br > pgtsconfig < br > pgcollation < br > pgtype||VOBJECT_PRIVILEGE pg_default_acl
VOBJECTUSAGE|pgstatallindexes||VOPEN_CURSOR pg_cursors
VOPTION|pgsettings||VPARAMETER pg_settings
VPARAMETER2|pgsettings||VPROCESS pg_stat_activity
VPWFILEUSERS|pgusers||VREPLPROP pg_replication_origin pg_replication_origin_status
VSESSION|pgstatactivity||VSESSTAT pg_stat_all_tables or other view
VSQLFNMETADATA|pgproc, pgaggrgate||VSYSTEM_PARAMETER pg_settings
VSYSTEMPARAMETER2|pgsettings||VTABLESPACE pg_tablespace
VTEMPSTAT|pgstatdatabase||VTIMEZONE_NAMES pg_timezone_names
VTRANSACTION|pglocks||VTRANSACTION_ENQUEUE pg_locks

Note

Not all dynamic performance view information can be obtained from the system catalogs and statistics views. Each user should determine whether the obtained information can be used.

F.29.43.3. A.3 Formats #

Description

Specifying formats in data type formatting functions makes it possible to convert numeric and date and time data types to formatted strings and to convert formatted strings to specific data types.

F.29.43.3.1. A.3.1 Number Format Correspondence #

The table below indicates which Oracle database number formats are available in Tantor SE.

Number format correspondence

Number format TO_CHAR TO_NUMBER Remarks
, (comma) Y Y
. (period) Y Y
$ YR YR If a dollar sign ($) is specified in any position other than the first character of a number format, move it to the front of the number format.
0 Y Y
9 Y Y
B Y Y
C N N
D Y Y
EEEE Y Y
G Y Y
L Y Y
MI Y Y
PR Y Y
RN Y -
Rn Y -
S Y Y
TM N -
U N N
V Y -
X N N
X N N

Y: Available

YR: Available with restrictions

N: Cannot be migrated

-: Does not need to be migrated (because it is not available in Oracle databases)

F.29.43.3.2. A.3.2 Datetime Format Correspondence #

The table below indicates which Oracle database datetime formats are available in Tantor SE.

Datetime format correspondence

Datetime format TO_CHAR TO_DATE TO_TIMESTAMP Remarks
- / , . ; : “text” Y Y Y
AD Y Y Y
A.D. Y Y Y
AM Y Y Y
A.M. Y Y Y
BC Y Y Y
B.C. Y Y Y
CC Y - -
SCC Y - -
D Y Y Y
DAY Y Y Y
DD Y Y Y
DDD Y YR YR The year must also be specified. (This format is used together with other formats such as YYYY.)
DL N N N
DS N N N
DY Y Y Y
E N N N
EE N N N
FF1 to FF9 MR - MR Change to MS. However, the number of digits is fixed at three.
FM YR YR YR Applies only to the format specified immediately after FM.
FX Y Y Y
HH Y Y Y
HH12 Y Y Y
HH24 Y Y Y
IW Y - -
IYYY Y - -
IYY Y - -
IY Y - -
I Y - -
J Y Y Y
MI Y Y Y
MM Y Y Y
MON Y Y Y
MONTH Y Y Y
PM Y Y Y
P.M. Y Y Y
Q Y - -
RM Y Y Y
RR Y Y Y
RRRR Y Y Y
SS Y Y Y
SSSSS M M M Change to SSSS.
TS N N N
TZD M - - Change to TZ.
TZH N - -
TZM N - -
TZR M - - Change to TZ.
WW Y Y Y
W Y Y Y
X Y - Y
Y,YYY Y Y Y
YEAR N - -
SYEAR N - -
YYYY Y Y Y
SYYYY N N N
YYY Y Y Y
YY Y Y Y
Y Y Y Y

Y: Available

M: Can be migrated

N: Cannot be migrated

YR: Available with restrictions

MR: Can be migrated with restrictions

-: Does not need to be migrated (because it is not available in Oracle databases)