Updated on 2024-06-03 GMT+08:00

DBE_UTILITY

Interface Description

Table 1 provides all interfaces supported by the DBE_UTILITY package.

Table 1 DBE_UTILITY

Interface

Description

DBE_UTILITY.FORMAT_ERROR_BACKTRACE

Outputs the call stack of an abnormal stored procedure.

DBE_UTILITY.FORMAT_ERROR_STACK

Outputs detailed information about a stored procedure exception.

DBE_UTILITY.FORMAT_CALL_STACK

Outputs the call stack of a stored procedure.

DBE_UTILITY.GET_TIME

Outputs the current time, which is used to obtain the execution duration.

DBE_UTILITY.CANONICALIZE

Canonicalizes the character string of a table name.

DBE_UTILITY.COMMA_TO_TABLE

Converts a comma-delimited string of names into a PL/SQL table of names.

DBE_UTILITY.DB_VERSION

Returns the version number and compatibility version number of the database.

DBE_UTILITY.EXEC_DDL_STATEMENT

Executes DDL statements entered by users.

DBE_UTILITY.EXPAND_SQL_TEXT_PROC

Expands the view of the SQL query.

DBE_UTILITY.GET_CPU_TIME

Returns the measured value of the current CPU processing time.

DBE_UTILITY.GET_ENDIANNESS

Obtains the big-endian and little-endian information of the byte order on the platform where the database is located.

DBE_UTILITY.GET_HASH_VALUE

Returns the hash value of a given string.

DBE_UTILITY.GET_SQL_HASH

Outputs the hash value of a given string. This stored procedure is used when proc_outparam_override is not enabled.

DBE_UTILITY.IS_BIT_SET

Checks whether parameter n exists in r.

DBE_UTILITY.IS_CLUSTER_DATABASE

Determines whether the current database is running in database cluster mode.

DBE_UTILITY.NAME_RESOLVE

Parses the given object name, including synonym translation and necessary authorization checks.

DBE_UTILITY.NAME_TOKENIZE

Parses the name in the a [. b [. c ]][@ dblink ] format.

DBE_UTILITY.OLD_CURRENT_SCHEMA

Returns the name of the database schema in the current user environment.

DBE_UTILITY.OLD_CURRENT_USER

Returns the name of the current user.

DBE_UTILITY.TABLE_TO_COMMA

Converts a PL/SQL table of names into a comma-delimited string of names.

DBE_UTILITY.GET_SQL_HASH_FUNC

Equivalent to DBE_UTILITY.GET_SQL_HASH. This function is used when proc_outparam_override is enabled.

DBE_UTILITY.EXPAND_SQL_TEXT

This is an internal function and is not recommended.

DBE_UTILITY.CANONICALIZE_RET

This is an internal function and is not recommended.

DBE_UTILITY.COMMA_TO_TABLE_FUN

This is an internal function and is not recommended.

DBE_UTILITY.COMPILE_SCHEMA

This is an internal function and is deprecated. You are advised not to use this function.

DBE_UTILITY.NAME_SEPARATE

This is an internal function and is not recommended.

DBE_UTILITY.NAME_TOKENIZE_FUNC

This is an internal function and is not recommended.

DBE_UTILITY.NAME_TOKENIZE_LOWER

This is an internal function and is not recommended.

DBE_UTILITY.NAME_TOKENIZE_LOWER_FUNC

This is an internal function and is not recommended.

DBE_UTILITY.PRIVILEGE_CHECK

This is an internal function and is not recommended.

DBE_UTILITY.SEARCH_CLASS_WITH_NSPOID_ONAME_TYPE

This is an internal function and is not recommended.

DBE_UTILITY.SEARCH_OBJECTS

This is an internal function and is not recommended.

DBE_UTILITY.SEARCH_OBJECTS_SYNONYM_FILL_SECHEMA

This is an internal function and is not recommended.

DBE_UTILITY.SEARCH_PROCEDURE_WITH_NSPOID_ONAME

This is an internal function and is not recommended.

DBE_UTILITY.SEARCH_SYNONM_WITH_NSPOID_ONAME

This is an internal function and is not recommended.

DBE_UTILITY.TABLE_TO_COMMA_FUNC

This is an internal function and is not recommended.

DBE_UTILITY.USER_NAME

This is an internal function and is not recommended.

  • DBE_UTILITY.FORMAT_ERROR_BACKTRACE

    Returns the call stack where an error occurs during execution. The prototype of the DBE_UTILITY.FORMAT_ERROR_BACKTRACE function is as follows:

    1
    2
    DBE_UTILITY.FORMAT_ERROR_BACKTRACE()
    RETURN TEXT;
    
  • DBE_UTILITY.FORMAT_ERROR_STACK
    Returns the detailed information about the error location when an error occurs during the execution. The prototype of the DBE_UTILITY.FORMAT_ERROR_STACK function is as follows:
    1
    2
    DBE_UTILITY.FORMAT_ERROR_STACK()
    RETURN TEXT;
    
  • DBE_UTILITY.FORMAT_CALL_STACK

    Sets the call stack of the output function. The prototype of the DBE_UTILITY.FORMAT_CALL_STACK function is as follows:

    1
    2
    DBE_UTILITY.FORMAT_CALL_STACK()
    RETURN TEXT;
    
  • DBE_UTILITY.GET_TIME

    Sets the output time, which is usually used for difference. A separate return value is meaningless. The prototype of the DBE_UTILITY.GET_TIME function is as follows:

    1
    2
    DBE_UTILITY.GET_TIME()
    RETURN BIGINT;
    
  • DBE_UTILITY.CANONICALIZE

    Canonicalizes the character string of a table name. The procedure handles a single reserved word or keyword, and removes white spaces for a single identifier so that "table" becomes TABLE. The prototype of the DBE_UTILITY.CANONICALIZE function is as follows:

    1
    2
    3
    4
    5
    DBE_UTILITY.CANONICALIZE(
        name       IN   VARCHAR2,
        canon_name OUT  VARCHAR2,
        canon_len  IN   BINARY_INTEGER DEFAULT 1024
    );
    
    Table 2 DBE_UTILITY.CANONICALIZE parameters

    Parameter

    Type

    Input/Output Parameter

    Can Be Empty

    Description

    name

    VARCHAR2

    IN

    No

    Character string to be canonicalized.

    canon_name

    VARCHAR2

    OUT

    Yes

    Canonicalized character string.

    canon_len

    BINARY_INTEGER

    IN

    Yes

    Length of the string to be canonicalized. The default value is 1024 (in bytes). If the value of this parameter is less than the actual length (in bytes) of the character string to be standardized, the character string is truncated by byte.

  • DBE_UTILITY.COMMA_TO_TABLE

    Converts a comma-delimited string of names into a PL/SQL table of names. The prototype of the DBE_UTILITY.COMMA_TO_TABLE function is as follows:

    1
    2
    3
    4
    5
    DBE_UTILITY.COMMA_TO_TABLE ( 
        list   IN  VARCHAR2,
        tablen OUT BINARY_INTEGER,
        tab    OUT VARCHAR2[]
    ); 
    
    Table 3 DBE_UTILITY.COMMA_TO_TABLE parameters

    Parameter

    Type

    Input/Output Parameter

    Can Be Empty

    Description

    list

    VARCHAR2

    IN

    No

    A comma-delimited string of names.

    tablen

    BINARY_INTEGER

    OUT

    Yes

    Number of names in the table.

    tab

    VARCHAR2

    OUT

    Yes

    Table which contains the string of names.

  • DBE_UTILITY.DB_VERSION

    Returns the version number and compatibility version number of the database. The prototype of the DBE_UTILITY.DB_VERSION function is as follows:

    1
    2
    3
    DBE_UTILITY.DB_VERSION (
        version OUT VARCHAR2
    );
    
    Table 4 DBE_UTILITY.DB_VERSION parameters

    Parameter

    Type

    Input/Output Parameter

    Can Be Empty

    Description

    version

    VARCHAR2

    OUT

    No

    Output parameter, which indicates the internal database software version. The value is a character string.

  • DBE_UTILITY.EXEC_DDL_STATEMENT

    Executes DDL statements entered by users. The prototype of the DBE_UTILITY.EXEC_DDL_STATEMENT function is as follows:

    1
    2
    3
    DBE_UTILITY.EXEC_DDL_STATEMENT (
        parse_string IN TEXT
    );
    
    Table 5 DBE_UTILITY.EXEC_DDL_STATEMENT parameters

    Parameter

    Type

    Input/Output Parameter

    Can Be Empty

    Description

    parse_string

    TEXT

    IN

    Yes

    DDL statements to be executed.

  • DBE_UTILITY.EXPAND_SQL_TEXT_PROC

    Expands the view of the SQL query. It recursively expands the view objects in the view until a table is displayed. The function prototype of DBE_UTILITY.EXPAND_SQL_TEXT_PROC is as follows:

    1
    2
    3
    4
    DBE_UTILITY.EXPAND_SQL_TEXT_PROC (
        input_sql_text  IN  CLOB,
        output_sql_text OUT CLOB
    );
    
    Table 6 DBE_UTILITY.EXPAND_SQL_TEXT_PROC parameters

    Parameter

    Type

    Input/Output Parameter

    Can Be Empty

    Description

    input_sql_text

    CLOB

    IN

    No

    Input SQL text.

    output_sql_text

    CLOB

    OUT

    No

    Output SQL text of the expanded view.

    In the input_sql_text parameter entered by a user, a schema prefix must be added to the object in the SQL statement. Otherwise, the function reports an error indicating that no object is found. If behavior_compat_options is set to bind_procedure_searchpath, you do not need to forcibly specify the schema prefix.

  • DBE_UTILITY.GET_CPU_TIME

    Returns the measured value of the current CPU processing time, in hundredths of a second. The prototype of the DBE_UTILITY.GET_CPU_TIME function is as follows:

    1
    2
    DBE_UTILITY.GET_CPU_TIME()
    RETURN BIGINT;
    
  • DBE_UTILITY.GET_ENDIANNESS

    Obtains the big-endian and little-endian information of the byte order on the platform where the database is located. DBE_UTILITY. The prototype of the GET_ENDIANNESS function is as follows:

    1
    2
    DBE_UTILITY.GET_ENDIANNESS
    RETURN INTEGER;
    
  • DBE_UTILITY.GET_HASH_VALUE

    Returns the hash value of a given string. The prototype of the DBE_UTILITY.GET_HASH_VALUE function is as follows:

    1
    2
    3
    4
    5
    DBE_UTILITY.GET_HASH_VALUE(
        name      IN VARCHAR2(n),
        base      IN INTEGER,
        hash_size IN INTEGER)
    RETURN INTEGER;
    
    Table 7 DBE_UTILITY.GET_HASH_VALUE parameters

    Parameter

    Type

    Input/Output Parameter

    Can Be Empty

    Description

    name

    VARCHAR2

    IN

    No

    Character string to be hashed.

    base

    INTEGER

    IN

    No

    Start value of the returned hash value.

    hash_size

    INTEGER

    IN

    No

    Size of the hash table to which the hash is mapped.

  • DBE_UTILITY.GET_SQL_HASH

    Outputs the hash value of a given character string using the MD5 algorithm. The prototype of the DBE_UTILITY.GET_SQL_HASH function is as follows:

    1
    2
    3
    4
    5
    DBE_UTILITY.GET_SQL_HASH(
        name       IN  VARCHAR2,
        hash       OUT RAW,
        last4bytes OUT BIGINT
    )RETURN BIGINT;
    
    Table 8 DBE_UTILITY.GET_SQL_HASH parameters

    Parameter

    Type

    Input/Output Parameter

    Can Be Empty

    Description

    name

    VARCHAR2

    IN

    No

    Character string to be hashed.

    hash

    RAW

    OUT

    No

    Complete hexadecimal MD5 hash value.

    last4bytes

    BIGINT

    OUT

    No

    Last four bytes of the MD5 hash value, which is displayed as an unsigned integer.

    After setting behavior_compat_options to a value other than proc_outparam_override, call the DBE_UTILITY.GET_SQL_HASH function. If DBE_UTILITY.GET_SQL_HASH_FUNC is called, the value assignment fails. (Contact the administrator for parameter setting.)

  • DBE_UTILITY.IS_BIT_SET

    Checks whether parameter n exists in r. DBE_UTILITY. The prototype of the IS_BIT_SET function is as follows:

    1
    2
    3
    4
    DBE_UTILITY.IS_BIT_SET (
        r IN RAW, 
        n IN INTEGER)
    RETURN INTEGER;
    
    Table 9 DBE_UTILITY.IS_BIT_SET parameters

    Parameter

    Type

    Input/Output Parameter

    Can Be Empty

    Description

    r

    RAW

    IN

    No

    4 bytes plus the actual hexadecimal string.

    n

    INTEGER

    IN

    No

    Determines whether the value exists in the binary system.

  • DBE_UTILITY.IS_CLUSTER_DATABASE

    Determines whether the current database is running in database cluster mode. The prototype of the DBE_UTILITY.IS_CLUSTER_DATABASE function is as follows:

    1
    2
    DBE_UTILITY.IS_CLUSTER_DATABASE
    RETURN BOOLEAN;
    
  • DBE_UTILITY.NAME_RESOLVE

    Parses the given object name, including synonym translation and necessary authorization checks. The prototype of the DBE_UTILITY.NAME_RESOLVE function is as follows:

     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    DBE_UTILITY.NAME_RESOLVE (
        name          IN   VARCHAR2,
        context       IN   INTEGER,
        schema        OUT VARCHAR2,
        part1         OUT VARCHAR2,
        part2         OUT VARCHAR2,
        dblink        OUT VARCHAR2,
        part1_type    OUT INTEGER,
        object_number OUT OID
    );
    
    Table 10 DBE_UTILITY.NAME_RESOLVE parameters

    Parameter

    Type

    Input/Output Parameter

    Can Be Empty

    Description

    name

    VARCHAR2

    IN

    No

    Name of the object to be parsed. The structure is [[a.]b.]c[@d].

    context

    INTEGER

    IN

    No

    Start value of the returned hash value.

    schema

    VARCHAR2

    OUT

    No

    Schema of an object.

    part1

    VARCHAR2

    OUT

    No

    First part of the name. The type of this column is specified by part1_type.

    part2

    VARCHAR2

    OUT

    Yes

    If this column is not empty, the value is the subprogram name.

    dblink

    VARCHAR2

    OUT

    Yes

    Database link.

    part1_type

    INTEGER

    OUT

    No

    Part 1 types:

    • 5: synonym
    • 7: procedure (top level)
    • 8: function (top level)

    object_number

    OID

    OUT

    No

    Object ID. In database ORA, object_number is of the numeric type, indicating the object ID. In GaussDB, object_number is of the OID type and does not support implicit conversion from a number to an OID.

  • DBE_UTILITY.NAME_TOKENIZE

    Parses names in the a [. b [. c ]][@ dblink ] format. If a name contains double quotation marks, the double quotation marks are deleted. Otherwise, the name becomes uppercase letters. The prototype of the DBE_UTILITY.NAME_TOKENIZE function is as follows:

    1
    2
    3
    4
    5
    6
    7
    8
    DBE_UTILITY.NAME_TOKENIZE ( 
    name    IN  VARCHAR2,
    a       OUT VARCHAR2,
    b       OUT VARCHAR2,
    c       OUT VARCHAR2,
    dblink  OUT VARCHAR2, 
    nextpos OUT INTEGER
    );
    
    Table 11 DBE_UTILITY.NAME_TOKENIZE parameters

    Parameter

    Type

    Input/Output Parameter

    Can Be Empty

    Description

    name

    VARCHAR2

    IN

    No

    Name, consisting of SQL identifiers (for example, scott.foo@dblink).

    a

    VARCHAR2

    OUT

    No

    First token of the name.

    b

    VARCHAR2

    OUT

    Yes

    Second token of the name.

    c

    VARCHAR2

    OUT

    Yes

    Third token of the name.

    dblink

    VARCHAR2

    OUT

    Yes

    Database link.

    nextpos

    INTEGER

    OUT

    No

    Next position of a parsed character string.

  • DBE_UTILITY.OLD_CURRENT_SCHEMA
    Returns the name of the database schema in the current user environment. The prototype of the DBE_UTILITY.OLD_CURRENT_SCHEMA function is as follows:
    1
    2
    DBE_UTILITY.OLD_CURRENT_SCHEMA()
    RETURN VARCHAR;
    
  • DBE_UTILITY.OLD_CURRENT_USER

    Returns the name of the current user. The prototype of the DBE_UTILITY.OLD_CURRENT_USER function is as follows:

    1
    2
    DBE_UTILITY.OLD_CURRENT_USER()
    RETURN TEXT;
    
  • DBE_UTILITY.TABLE_TO_COMMA

    Converts a PL/SQL table of names into a comma-delimited string of names. The prototype of the DBE_UTILITY.TABLE_TO_COMMA function is as follows:

    1
    2
    3
    4
    5
    DBE_UTILITY.TABLE_TO_COMMA ( 
        tab    IN  VARCHAR2[], 
        tablen OUT BINARY_INTEGER,
        list   OUT VARCHAR2
    );
    
    Table 12 DBE_UTILITY.TABLE_TO_COMMA parameters

    Parameter

    Type

    Input/Output Parameter

    Can Be Empty

    Description

    tab

    VARCHAR2[]

    IN

    No

    PL/SQL table which contains the string of names.

    tablen

    BINARY_INTEGER

    OUT

    No

    Number of names in the PL/SQL table.

    list

    VARCHAR2

    OUT

    No

    A comma-delimited string of names.

  • DBE_UTILITY.GET_SQL_HASH_FUNC
    Uses the MD5 algorithm to output the hash value of a given character string. The prototype of the DBE_UTILITY.GET_SQL_HASH_FUNC function is:
    1
    2
    3
    4
    5
    DBE_UTILITY.GET_SQL_HASH_FUNC(
        name       IN  VARCHAR2,
        hash       OUT RAW,
        last4bytes OUT BIGINT
    );
    
    Table 13 DBE_UTILITY.GET_SQL_HASH_FUNC parameters

    Parameter

    Type

    Input/Output Parameter

    Can Be Empty

    Description

    name

    VARCHAR2

    IN

    No

    Character string to be hashed.

    hash

    RAW

    OUT

    No

    Complete hexadecimal MD5 hash value.

    last4bytes

    BIGINT

    OUT

    No

    Last four bytes of the MD5 hash value, which is displayed as an unsigned integer.

    After setting set behavior_compat_options to 'proc_outparam_override', invoke the DBE_UTILITY.GET_SQL_HASH_FUNC function. If you invoke the DBE_UTILITY.GET_SQL_HASH function, a parameter mismatch error is reported.

Examples

  1
  2
  3
  4
  5
  6
  7
  8
  9
 10
 11
 12
 13
 14
 15
 16
 17
 18
 19
 20
 21
 22
 23
 24
 25
 26
 27
 28
 29
 30
 31
 32
 33
 34
 35
 36
 37
 38
 39
 40
 41
 42
 43
 44
 45
 46
 47
 48
 49
 50
 51
 52
 53
 54
 55
 56
 57
 58
 59
 60
 61
 62
 63
 64
 65
 66
 67
 68
 69
 70
 71
 72
 73
 74
 75
 76
 77
 78
 79
 80
 81
 82
 83
 84
 85
 86
 87
 88
 89
 90
 91
 92
 93
 94
 95
 96
 97
 98
 99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
-- Example 1
create or replace procedure print_err() as
DECLARE
    a bool;
BEGIN
    a := not_exist;
exception
    when others then
        dbe_output.print_line('err_stack: ' || DBE_UTILITY.FORMAT_ERROR_STACK());
END;
/
CREATE PROCEDURE

call print_err();
-- The expected result is as follows:
err_stack: 50360452: column "not_exist" does not exist
 print_err 
-----------

(1 row)

-- Clean the environment.
drop procedure print_err;
DROP PROCEDURE

-- Example 2
create or replace procedure print_err() as
DECLARE
    a bool;
BEGIN
    a := not_exist;
exception
    when others then
        dbe_output.print_line('backtrace: ' || DBE_UTILITY.FORMAT_ERROR_BACKTRACE());
END;
/
CREATE PROCEDURE

call print_err();
-- The expected result is as follows:
backtrace: 50360452: PL/pgSQL function print_err() line 5 at assignment

 print_err 
-----------

(1 row)

-- Clean the environment.
drop procedure print_err;
DROP PROCEDURE

-- Example 3
create or replace procedure print_err() as
DECLARE
    a bool;
BEGIN
    a := not_exist;
exception
    when others then
        dbe_output.print_line('call_stack: ');
        dbe_output.print_line(DBE_UTILITY.FORMAT_CALL_STACK());
END;
/
CREATE PROCEDURE

call print_err();
-- The expected result is as follows:
call_stack: 
      3  dbe_utility.format_call_stack()
      9  print_err()

 print_err 
-----------

(1 row)

-- Clean the environment.
drop procedure print_err;
DROP PROCEDURE

-- Example 4
CREATE OR REPLACE PROCEDURE test_get_time1() 
AS
declare
    start_time  bigint;
    end_time  bigint;
BEGIN
    start_time:= dbe_utility.get_time ();
    pg_sleep(1);
    end_time:=dbe_utility.get_time ();
    dbe_output.print_line(end_time - start_time); 
END;
/
CREATE PROCEDURE

call test_get_time1();
-- The expected result is as follows:
101
 test_get_time1 
----------------

(1 row)

-- Clean the environment.
drop PROCEDURE test_get_time1;
DROP PROCEDURE

-- Example 5
-- Canonicalize the character string of a table name.
declare
    cname varchar2(50);
begin
    dbe_utility.canonicalize('seg1', cname, 50);
    dbe_output.put_line(cname);
end;
/
-- The expected result is as follows:
SEG1
ANONYMOUS BLOCK EXECUTE

-- Example 6
-- Convert the input character string into an array of table names.
DECLARE
 tab_list VARCHAR2(100) := 't1,t2';
 len BINARY_INTEGER;
 tab varchar2[];
BEGIN
 dbe_output.put_line('table list is: ' || tab_list);
 dbe_utility.comma_to_table(tab_list, len, tab);
END;
/
-- The expected result is as follows:
table list is: t1,t2
ANONYMOUS BLOCK EXECUTE

-- Example 7
-- Check the version number and compatibility version number of the database.
declare
    v_version varchar2;
begin
    dbe_utility.db_version(v_version);
    v_version:=left(v_version, 8);
    dbe_output.print_line('version:' || v_version); 
end;
/
-- The expected result is as follows:
version:gaussdb 
ANONYMOUS BLOCK EXECUTE

-- Example 8
-- Check the measured value of the current CPU processing time.
DECLARE
    cputime NUMBER;
BEGIN
    cputime := dbe_utility.get_cpu_time();
    dbe_output.put_line('cpu time:' || cputime);
END;
/
-- The expected result is as follows (the value is not fixed):
cpu time: 70179
ANONYMOUS BLOCK EXECUTE

-- Example 9
-- Obtain the big-endian and little-endian information of the byte order on the platform where the database is located.
BEGIN
    dbe_output.PUT_LINE(dbe_utility.GET_ENDIANNESS());
END;
/
-- The expected result is as follows:
2
ANONYMOUS BLOCK EXECUTE

-- Example 10
-- Obtain the hash value of a given string.
DECLARE
    result NUMBER(28);
BEGIN
    result := dbe_utility.get_hash_value('hello',10,10);
    dbe_output.put_line(result);
END;
/
-- The expected result is as follows:
11
ANONYMOUS BLOCK EXECUTE

-- Example 11
-- Check whether the current database is in cluster mode.
DECLARE
    is_cluster BOOLEAN;
BEGIN
    is_cluster := dbe_utility.IS_CLUSTER_DATABASE();
    dbe_output.put_line('CLUSTER DATABASE: ' || CASE WHEN is_cluster THEN 'TRUE' ELSE 'FALSE' END);
END;
/
-- The expected result is as follows:
CLUSTER DATABASE: TRUE
ANONYMOUS BLOCK EXECUTE

-- Example 12
-- Obtain the name of the database schema in the current user environment.
DECLARE
    schm varchar2(100);
BEGIN
    schm := dbe_utility.old_current_schema();
    dbe_output.put_line('current schema: ' || schm);
END;
/
-- The expected result is as follows (the result is the schema name of the current database, which is not fixed):
current schema: public
ANONYMOUS BLOCK EXECUTE

-- Example 13
-- Obtain the current username.
select dbe_utility.old_current_user() from sys_dummy;
-- The expected result is as follows (the result is the username of the current database, which is not fixed):
 old_current_user 
------------------
 test
(1 row)

-- Example 14
DECLARE
    ddl_str VARCHAR2(255);
BEGIN
    dbe_output.print_line('start to test exec_ddl_statement create table.');
    ddl_str := 'CREATE TABLE test_ddl (COL1 INT)';
    dbe_utility.exec_ddl_statement(ddl_str);
END;
/
-- The expected result is as follows:
start to test exec_ddl_statement create table.
NOTICE:  The 'DISTRIBUTE BY' clause is not specified. Using 'col1' as the distribution column by default.
HINT:  Please use 'DISTRIBUTE BY' clause to specify suitable data distribution column.
CONTEXT:  SQL statement "CREATE TABLE test_ddl (COL1 INT)"
SQL statement "CALL dbe_utility.exec_ddl_statement(ddl_str)"
PL/pgSQL function inline_code_block line 5 at PERFORM
ANONYMOUS BLOCK EXECUTE

select * from test_ddl;
-- The expected result is as follows:
 col1 
------
(0 rows)

-- Clean the environment.
drop table test_ddl;
DROP TABLE

-- Example 15
create table t1 (c1 int primary key, c2 int);
insert into t1 values(1,1),(2,1),(3,2),(4,2),(5,3),(6,3);
create view v1 as select * from t1 where c1 > 1;
create view v2 as select c1 from v1 where c2 > 1;
create view v3 as select * from v2 where c1 > 2;

declare
    in_sql clob := 'select * from public.v3';
    out_sql clob;
begin
    dbe_output.print_line('start to test expand_sql_text_proc v3 expend sql text.');
    dbe_utility.expand_sql_text_proc(in_sql, out_sql);
    dbe_output.print_line(out_sql);
end;
/
-- The expected result is as follows:
start to test expand_sql_text_proc v3 expend sql text.
SELECT c1 FROM (SELECT v2.c1 FROM (SELECT v1.c1 FROM (SELECT t1.c1, t1.c2 FROM public.t1 WHERE t1.c1 > 1) v1 WHERE v1.c2 > 1) v2 WHERE v2.c1 > 2) v3
ANONYMOUS BLOCK EXECUTE

-- Clean the environment.
drop table t1 cascade;
-- The expected result is as follows:
NOTICE:  drop cascades to 3 other objects
DETAIL:  drop cascades to view v1
drop cascades to view v2
drop cascades to view v3
DROP TABLE

-- Example 16
declare 
    name varchar2;
    hash raw;
    last4bytes bigint;
BEGIN
    name := '';
    -- return correctly (D41D8CD98F00B204E9800998ECF8427E, 2118318316)
    dbe_utility.get_sql_hash(name,hash,last4bytes);
    raise notice '%',hash;
    raise notice '%',last4bytes;
END;
/
-- The expected result is as follows:
NOTICE:  D41D8CD98F00B204E9800998ECF8427E
NOTICE:  2118318316
ANONYMOUS BLOCK EXECUTE

-- Example 17
declare
    bitchar raw(8);
begin
    bitchar := '2111111f';
    dbe_output.print('test '|| bitchar ||' bit is_bit_set value from 1 to 32 bit: ');
    for i in reverse 32 .. 1 loop
        dbe_output.print(dbe_utility.is_bit_set(bitchar, i));
    end loop;
    dbe_output.print_line('.');
end;
/
-- The expected result is as follows:
test 2111111F bit is_bit_set value from 1 to 32 bit: 00100001000100010001000100011111.
ANONYMOUS BLOCK EXECUTE

-- Example 18
create or REPLACE PROCEDURE p_test_pk ( -- for print result
    name in varchar2,
    type in integer
) 
as
    schema varchar2;
    part1 varchar2;
    part2 varchar2;
    dblink varchar2;
    part1_type integer;
    object_number integer;
begin
    dbe_utility.name_resolve(name,type,schema,part1,part2,dblink,part1_type,object_number);
    raise notice 'schema: % -- part1: % -- part2: % -- dblink: % -- part1_type: %', schema,part1,part2,dblink,part1_type;
end;
/
CREATE PROCEDURE

declare begin p_test_pk('a.b.c@aa',3); end;
/
-- The expected result is as follows:
NOTICE:  schema: a -- part1: b -- part2: c -- dblink: aa -- part1_type: 0
CONTEXT:  SQL statement "CALL p_test_pk('a.b.c@aa',3)"
PL/pgSQL function inline_code_block line 1 at PERFORM
ANONYMOUS BLOCK EXECUTE

-- Example 19
DECLARE
    name varchar;
    a    varchar;
    b    varchar;
    c    varchar;
    dblink varchar;
    nextpos INTEGER;
BEGIN
    name := 'Me.w#sdfsdf.CD';
    DBE_UTILITY.NAME_TOKENIZE(name, a, b, c, dblink, nextpos);
    RAISE INFO E'dbe_utility.name_tokenize parse error: name:%\na:%\nb:%\nc:%\ndblink:%',
    name, a, b, c, dblink;
    IF nextpos <> OCTET_LENGTH(name) THEN
        RAISE INFO E'dbe_utility.name_tokenize length error: name:%\nlength of name:%\nnextpos:%',
        name, OCTET_LENGTH(name), nextpos;
    END IF;
END;
/
-- The expected result is as follows:
INFO:  dbe_utility.name_tokenize parse error: name:Me.w#sdfsdf.CD
a: Me
b:W#SDFSDF
c:CD
dblink:<NULL>
ANONYMOUS BLOCK EXECUTE

-- Example 20
DECLARE
list varchar2(50) := 'aabb,ccdd,eeff,gghh';
len_list integer;
tab varchar2[];
get_list varchar2(50);
len_tab integer;
BEGIN
dbe_output.print_line(''Parameter list:' || list);
dbe_utility.comma_to_table(list,len_list,tab);
dbe_output.print_line('Parameter length:' || len_list);
FOR i IN 1 .. len_list LOOP
    dbe_output.print_line('List name' || i || ' : ' || tab(i));
END LOOP;
dbe_output.print_line('Call table_to_comma:');
dbe_utility.table_to_comma(tab,len_tab,get_list );
dbe_output.print_line('Output:' || get_list );
dbe_output.print_line('Array length:' || len_tab);
END;
/
-- The expected result is as follows:
Parameter list: aabb,ccdd,eeff,gghh
Parameter length: 4
List name 1: aabb
List name 2: ccdd
List name 3: eeff
List name 4: gghh
Call table_to_comma:
Output: aabb,ccdd,eeff,gghh
Array length: 4
ANONYMOUS BLOCK EXECUTE

-- Example 21
declare 
    name varchar2;
    hash raw;
    last4bytes bigint;
BEGIN
    name := 'hello world';
    -- return correctly(5EB63BBBE01EEED093CB22BB8F5ACDC3, 3285015183)
    dbe_utility.get_sql_hash_func(name,hash,last4bytes);
    raise notice '%',hash;
    raise notice '%',last4bytes;
END;
/
-- The expected result is as follows:
NOTICE:  3285015183
NOTICE:  <NULL>
ANONYMOUS BLOCK EXECUTE