Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
![]() |
![]() |
Home -> Community -> Mailing Lists -> Oracle-L -> Re: storing data horizontal vs vertical using pl/sql
Raj,
You could, and I'm making this up as I go along, do something like :
CREATE TABLE hospital(acct# NUMBER, medrec# NUMBER, dx1 NUMBER, dx2
NUMBER, dx3 NUMBER);
ALTER TABLE hospital ADD CONSTRAINT hospital_pk PRIMARY KEY
(acct#,medrec#);
CREATE TABLE diagnosis(acct# NUMBER, md# NUMBER, position NUMBER, dx
NUMBER);
ALTER TABLE diagnosis ADD CONSTRAINT diagnosis_pk PRIMARY KEY
(acct#,md#, position);
INSERT INTO hospital VALUES (1,1,100.1, 200.2, 300.3); INSERT INTO hospital VALUES (1,2,1000.1, 2000.2, 3000.3); COMMIT; SELECT * FROM hospital;
DECLARE
CURSOR GetData(p_x IN NUMBER) IS
SELECT acct#,
medrec#, CASE WHEN p_x = 1 THEN dx1 WHEN p_x = 2 THEN dx2 WHEN p_x = 3 THEN dx3 END AS dx_value
BEGIN
FOR x IN 1..3 LOOP
FOR y IN GetData(x) LOOP
EXECUTE IMMEDIATE 'insert into diagnosis values (:acct, :md,
:position, :dx)'
USING y.acct#, y.medrec#, x, y.dx_value;END LOOP;
The output uis as follows :
Table created. Table altered. Table created. Table altered. 1 row created. 1 row created.
ACCT# MEDREC# DX1 DX2 DX3 ---------- ---------- ---------- ---------- ----------
1 1 100.1 200.2 300.3 1 2 1000.1 2000.2 3000.3
2 rows selected.
PL/SQL procedure successfully completed.
Commit complete.
ACCT# MD# POSITION DX ---------- ---------- ---------- ----------
1 1 1 100.1 1 1 2 200.2 1 1 3 300.3 1 2 1 1000.1 1 2 2 2000.2 1 2 3 3000.3
6 rows selected.
It's a major bummer when you are left to sort out the 'errors' of a database designer - been there, had to do it, hated it !
Good luck.
Cheers,
Norman.
Norman Dunbar.
Contract Oracle DBA.
Rivers House, Leeds.
Internal : 7 28 2051
External : 0113 231 2051
>>> raja rao <raja4list_at_yahoo.com> 01/18/06 03:59pm >>>
Hi Team,
Can someone help me in moving the data from one table into multiple tables.
The situation is:
I have a table called hospital that contains the below columns:
acct#, medrec#, diagnosis(dx1), dx2,dx3,dx4.... dxN
Right now i have everythign in one table called hospital. But management requires this data to be split into 2 tbales.
1 is the header table which should contain only acct#,medrec# 2. the second table(line items) should be able to hold the diagnosis information.
the second table strucure is like this:
desc ICD9_DX
acct# number,
mr# number,
dx number
position number
the hospital table (main table) will hold data like this for
diagnosis:
101.1, 980.0, 7878.1, 7484.1, 5734.4 ..............
But this diagnosis should store like this in the ICD_9_DX table:
diagnosis position
101.1 1 980.0 2 7878.1 3 7484.1 4 5734.4 5
can someone give me some hint how this can be achieved with pl/sql.
Thakns in advance,
Raj
Information in this message may be confidential and may be legally privileged. If you have received this message by mistake, please notify the sender immediately, delete it and do not copy it to anyone else.
We have checked this email and its attachments for viruses. But you should still check any attachment before opening it.
We may have to make this message and any reply to it public if asked to under the Freedom of Information Act, Data Protection Act or for litigation. Email messages and attachments sent to or from any Environment Agency address may also be accessed by someone other than the sender or recipient, for business purposes.
If we have sent you information and you wish to use it please read our terms and conditions which you can get by calling us on 08708 506 506. Find out more about the Environment Agency at www.environment-agency.gov.uk
-- http://www.freelists.org/webpage/oracle-lReceived on Wed Jan 18 2006 - 10:57:29 CST
![]() |
![]() |