INTELLIGENT WORK FORUMS
FOR COMPUTER PROFESSIONALS

Log In

Come Join Us!

Are you a
Computer / IT professional?
Join Tek-Tips Forums!
  • Talk With Other Members
  • Be Notified Of Responses
    To Your Posts
  • Keyword Search
  • One-Click Access To Your
    Favorite Forums
  • Automated Signatures
    On Your Posts
  • Best Of All, It's Free!

*Tek-Tips's functionality depends on members receiving e-mail. By joining you are opting in to receive e-mail.

Posting Guidelines

Promoting, selling, recruiting, coursework and thesis posting is forbidden.

Jobs

Normalize Column Data

Normalize Column Data

(OP)
I have an old ugly system table that I need to normalize. It contains a pipe delimited part numbers list in one field and a corresponding node in another column.

Here is an example:

CODE

CREATE TABLE lookup(
part_number VARCHAR2(100),
node NUMBER
);

INSERT
INTO lookup(part_number, node)
VALUES ('aaabbb|aaaccc|aaaddd|aaaeee', 100);

INSERT
INTO lookup(part_number, node)
VALUES ('aaafff', 200);

INSERT
INTO lookup(part_number, node)
VALUES ('aaaggg|aaahhh|aaaiii', 300);

SELECT *
FROM lookup;

Output:
part_number node
aaabbb|aaaccc|aaaddd|aaaeee 100
aaafff 200
aaaggg|aaahhh|aaaiii 300

My desired output from a single query would be:

CODE

part_number node
aaabbb 100
aaaccc 100
aaaddd 100
aaaeee 100
aaafff 200
aaaggg 300
aaahhh 300
aaaiii 300

I can parse a single row like I want if I use regexp_substr and connect by like this:

CODE

SELECT regexp_substr(part_number, regex, 1, LEVEL), node
FROM (SELECT part_number, node, '[^|]+' regex
FROM lookup
WHERE node = 100)
CONNECT BY LEVEL <= LENGTH(REGEXP_REPLACE(part_number, regex)) + 1;

Output:
aaabbb 100
aaaccc 100
aaaddd 100
aaaeee 100

But, if I remove the node = 100 condition, then the results are wrong. I know I could parse through this easily using PL/SQL, but I'd like to see if it's possible with pure SQL first. In case it's not obvious, I'm on Oracle 11g. Thanks for the replies!

RE: Normalize Column Data

This is a bit clunky and there are probably better ways but at least its a start.

SQL> column part_number format a40
SQL> select * from lookup;

PART_NUMBER NODE
---------------------------------------- ----------
aaabbb|aaaccc|aaaddd|aaaeee 100
aaafff 200
aaaggg|aaahhh|aaaiii 300

1 WITH T AS
2 (SELECT node,part_number c
3 FROM lookup),
4 t2 AS
5 (SELECT node,'|'||c||'|' c FROM T)
6 SELECT distinct node,SUBSTR(c, INSTR(c,'|',1,LEVEL)+1,
7 INSTR(c, '|', 1, LEVEL+1)- INSTR (c, '|', 1, LEVEL)- 1) "String"
8 FROM t2
9 CONNECT BY LEVEL < LENGTH(c) - LENGTH(REPLACE(c,'|'))
10* order by node
SQL> /

NODE String
---------- --------------------
100 aaabbb
100 aaaccc
100 aaaddd
100 aaaeee
200 aaafff
300 aaaggg
300 aaahhh
300 aaaiii

8 rows selected.


In order to understand recursion, you must first understand recursion.

RE: Normalize Column Data

(OP)
Thanks for the reply. This is essentially what my regexp does, except you added a DISTINCT to get rid of the duplicates. I appreciate seeing another way to do this, but performance wise, it's just as bad as the regexp version. I guess what I need is a query that won't create duplicates to begin with, and therefore won't require a costly DISTINCT clause to clean it up. Any ideas on that? Thanks again.

RE: Normalize Column Data

2
See if this performs better

SQL> l
1 with t as
2 (
3 select node, part_number str from lookup
4 )
5 select trim(x.column_value.extract('e/text()')) cols ,node
6 from t t, table (xmlsequence(xmltype('<e><e>' ||
7* replace(t.str,'|','</e><e>')|| '</e></e>').extract('e/e'))) x
SQL> /

COLS NODE
-------------------- ----------
aaabbb 100
aaaccc 100
aaaddd 100
aaaeee 100
aaafff 200
aaaggg 300
aaahhh 300
aaaiii 300


In order to understand recursion, you must first understand recursion.

RE: Normalize Column Data

(OP)
Wow! Blazing fast! This is night and day compared the what I had, and I would give you 5 stars if I could! Thanks so much for your help!

RE: Normalize Column Data

Glad to be of help, have a star yourself for the simple fact of giving us table creation and insert statements in your OP. This makes investigating and answering questions soooooooooooo much easier. Others take note 2thumbsup


In order to understand recursion, you must first understand recursion.

Red Flag This Post

Please let us know here why this post is inappropriate. Reasons such as off-topic, duplicates, flames, illegal, vulgar, or students posting their homework.

Red Flag Submitted

Thank you for helping keep Tek-Tips Forums free from inappropriate posts.
The Tek-Tips staff will check this out and take appropriate action.

Reply To This Thread

Posting in the Tek-Tips forums is a member-only feature.

Click Here to join Tek-Tips and talk with other members!

Resources

Close Box

Join Tek-Tips® Today!

Join your peers on the Internet's largest technical computer professional community.
It's easy to join and it's free.

Here's Why Members Love Tek-Tips Forums:

Register now while it's still free!

Already a member? Close this window and log in.

Join Us             Close