Mohamed Houri’s Oracle Notes

July 15, 2011

Extracting separate information from a character string

Filed under: PL/SQL — hourim @ 9:01 am

I have been recently asked to develop a pl/sql stored procedure in order to dequeue a payload message from an Oracle Advanced queue. It was a text message. Don’t ask me why they didn’t foresee an object type for that purpose, I did asked the same question and I have been told that this is the standard they have been successfully using since several years and they do not have the intention to change it.

The goal is to dequeue that text message and extract from it several fields that are separated by a given delimiter.  I decided to reproduce this development in a blog article so that I can found it easily and also redirect to it when similar request will be done in Oracle forums.

mhouri.world> create or replace package split_text
3  IS
4   TYPE t_msg_array IS TABLE OF VARCHAR2(4000) INDEX BY BINARY_INTEGER;
7    FUNCTION f_extract_message_info (piv_message IN VARCHAR2
8                                    ,piv_delim   IN VARCHAR2)
9       RETURN t_msg_array;
11  END split_text;
12  /

Package created.

 

mhouri.world> create or replace package body split_text
2  IS
3  FUNCTION f_extract_message_info (piv_message IN VARCHAR2
5                                   ,piv_delim   IN VARCHAR2)
6     RETURN t_msg_array
7  IS
8     l_t_msg_array   t_msg_array;
9     ln_pos          NUMBER          := 0;
10     li              INTEGER         := 0;
11     lv_str          VARCHAR2 (4000) := piv_message;
12
13  BEGIN
14     -- Get the position fo the first delimitor
15     ln_pos := instr(lv_str,piv_delim,1,1);
16
17     -- While there is still delimitors loop
18     WHILE ( ln_pos != 0)
19     LOOP
20
21       -- Remove the first delimitor from the message
22       lv_str := substr(lv_str,ln_pos + length(piv_delim),length(lv_str));
23
24       -- Determine now the new position of the first delimiter
25       ln_pos := instr(lv_str,piv_delim,1,1);
26
27       -- Fill each information of the message in an array
28       li := li + 1;
29       IF ln_pos != 0
30       THEN
31         l_t_msg_array(li) := substr(lv_str,1, ln_pos-1);
32       ELSE
33         l_t_msg_array(li) := lv_str;
34       END IF;
35
36     END LOOP;
37
38     -- return the array
39      RETURN l_t_msg_array;
41  END f_extract_message_info;
44  END split_text;
45  /

Package body created.

Few points should be taken into account

  1. piv_delim represents the fields delimiter
  2. the message text should starts by the delimiter
And here below is a simple test of  this function:
mhouri.world> set serveroutput on

mhouri.world> declare
2   piv_txt            varchar2(4000);
3   l_t_jus_msg_array  split_text.t_msg_array;
4
5  BEGIN
6
7   piv_txt := '#@test01#@test02#@test03';
8
9   l_t_jus_msg_array     := split_text.f_extract_message_info(piv_txt,'#@');
10
11   dbms_output.put_line(' item1 := '||l_t_jus_msg_array(1) );
12   dbms_output.put_line(' item2 := '||l_t_jus_msg_array(2));
13   dbms_output.put_line(' item3 := '||l_t_jus_msg_array(3));
14
15
16  END;
17  /

item1 := test01
item2 := test02
item3 := test03

PL/SQL procedure successfully completed.

				

Leave a Comment »

No comments yet.

RSS feed for comments on this post. TrackBack URI

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s

Create a free website or blog at WordPress.com.

Tony's Oracle Tips

Tony Hasler's light hearted approach to learning about Oracle

Richard Foote's Oracle Blog

Focusing Specifically On Oracle Indexes, Database Administration and Some Great Music

Hatem Mahmoud Oracle's blog

Just another Oracle blog : Database topics and techniques

Mohamed Houri’s Oracle Notes

Qui se conçoit bien s’énonce clairement

Oracle Diagnostician

Performance troubleshooting as exact science

Raheel's Blog

Things I have learnt as Oracle DBA

Coskan's Approach to Oracle

What I learned about Oracle

So Many Oracle Manuals, So Little Time

“Books to the ceiling, Books to the sky, My pile of books is a mile high. How I love them! How I need them! I'll have a long beard by the time I read them”—Lobel, Arnold. Whiskers and Rhymes. William Morrow & Co, 1988.

EU Careers info

Your career in the European Union

Carlos Sierra's Tools and Tips

Tools and Tips for Oracle Performance and SQL Tuning

Oracle Scratchpad

Just another Oracle weblog

OraStory

Dominic Brooks on Oracle Performance, Tuning, Data Quality & Sensible Design ... (Now with added Sets Appeal)

%d bloggers like this: