Home » Infrastructure » Unix » sqls in Shell scripting
sqls in Shell scripting [message #562936] |
Tue, 07 August 2012 01:06 |
|
dhivyaenjoy
Messages: 49 Registered: June 2011
|
Member |
|
|
Hi Team,
I want to extract data like below using shell scripting and spool into .csv file
Select e.*
d.data_id||','||
d.insert_date
from
employee e,
data d
where
...
...
...
Here when i fetch all columns from employee table giving concatenation symbol ||','|| gives me an error.
Giving just a comma , doesn't spool the data in proper alignment.
what should i give?
please advise
Regards
Dhivya
|
|
|
|
Re: sqls in Shell scripting [message #562939 is a reply to message #562938] |
Tue, 07 August 2012 01:14 |
|
Littlefoot
Messages: 21823 Registered: June 2005 Location: Croatia, Europe
|
Senior Member Account Moderator |
|
|
COLSEP in SQL*Plus, maybe?
SQL> set colsep ,
SQL> select * from dept;
DEPTNO,DNAME ,LOC
----------,--------------,-------------
10,ACCOUNTING ,NEW YORK
20,RESEARCH ,DALLAS
30,SALES ,CHICAGO
40,OPERATIONS ,BOSTON
SQL>
(By the way, you are missing a comma behind "e.*")
|
|
|
Re: sqls in Shell scripting [message #563013 is a reply to message #562939] |
Tue, 07 August 2012 18:07 |
|
alan.kendall@nfl.com
Messages: 163 Registered: June 2012 Location: Culver City, California
|
Senior Member |
|
|
I use the following format to export and insert small tables between Oracle systems.
Since sqlplus converts 2 single quotes to 1 single quote, I use many single quotes.
The replace converts O'Hara to O''Hara (see the fifth line) because the two single quotes will
be replaced by one quote by sqlplus when the insert statement is run.
ECSCDAP1P > @export_scott_emp_table.sql
insert into EMP values(7369,'SMITH','CLERK',7902,'17-DEC-80',800,null,20);
insert into EMP values(7499,'ALLEN','SALESMAN',7698,'20-FEB-81',1600,300,30);
insert into EMP values(7521,'WARD','SALESMAN',7698,'22-FEB-81',1250,500,30);
insert into EMP values(7566,'JONES','MANAGER',7839,'02-APR-81',2975,null,20);
insert into EMP values(7654,'O''Hara','SALESMAN',7698,'28-SEP-81',1250,1400,30);
insert into EMP values(7698,'BLAKE','MANAGER',7839,'01-MAY-81',2850,null,30);
insert into EMP values(7782,'CLARK','MANAGER',7839,'09-JUN-81',2450,null,10);
insert into EMP values(7788,'SCOTT','ANALYST',7566,'19-APR-87',3000,null,20);
insert into EMP values(7839,'KING','PRESIDENT',null,'17-NOV-81',5000,null,10);
insert into EMP values(7844,'TURNER','SALESMAN',7698,'08-SEP-81',1500,0,30);
insert into EMP values(7876,'ADAMS','CLERK',7788,'23-MAY-87',1100,null,20);
ECSCDAP1P > list
1 select 'insert into EMP values('
2 ||nvl(to_char(EMPNO),'null')
3 ||','||''''||replace(ENAME,'''','''''')||''''
4 ||','||''''||replace(JOB,'''','''''')||''''
5 ||','||nvl(to_char(MGR),'null')
6 ||','||''''||HIREDATE||''''
7 ||','||nvl(to_char(SAL),'null')
8 ||','||nvl(to_char(COMM),'null')
9 ||','||nvl(to_char(DEPTNO),'null')
10* ||');' from SCOTT.EMP
ECSCDAP1P > select * from scott.emp;
EMPNO ENAME JOB MGR HIREDATE SAL COMM DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
7369 SMITH CLERK 7902 17-DEC-80 800 20
7499 ALLEN SALESMAN 7698 20-FEB-81 1600 300 30
7521 WARD SALESMAN 7698 22-FEB-81 1250 500 30
7566 JONES MANAGER 7839 02-APR-81 2975 20
7654 O'Hara SALESMAN 7698 28-SEP-81 1250 1400 30
7698 BLAKE MANAGER 7839 01-MAY-81 2850 30
7782 CLARK MANAGER 7839 09-JUN-81 2450 10
7788 SCOTT ANALYST 7566 19-APR-87 3000 20
7839 KING PRESIDENT 17-NOV-81 5000 10
7844 TURNER SALESMAN 7698 08-SEP-81 1500 0 30
7876 ADAMS CLERK 7788 23-MAY-87 1100 20
7900 JAMES CLERK 7698 03-DEC-81 950 30
7902 FORD ANALYST 7566 03-DEC-81 3000 20
7934 MILLER CLERK 7782 23-JAN-82 1300 10
ECSCDAP1P > @export_scott_dept_table.sql
insert into DEPT values(10,'ACCOUNTING','NEW YORK');
insert into DEPT values(20,'RESEARCH','DALLAS');
insert into DEPT values(30,'SALES','CHICAGO');
insert into DEPT values(40,'OPERATIONS','BOSTON');
ECSCDAP1P > list
1 select 'insert into DEPT values('
2 ||nvl(to_char(DEPTNO),'null')
3 ||','||''''||replace(DNAME,'''','''''')||''''
4 ||','||''''||replace(LOC,'''','''''')||''''
5* ||');' from SCOTT.DEPT
[Updated on: Tue, 07 August 2012 18:08] Report message to a moderator
|
|
|
Goto Forum:
Current Time: Thu Nov 21 10:00:50 CST 2024
|