Sponsored Content
Top Forums Shell Programming and Scripting calling sqlplus, read table return etc Post 302308612 by colemar on Sunday 19th of April 2009 05:24:23 PM
Old 04-19-2009
To pass variable values to Oracle SQL you can embed ${} syntax in SQL code inlined as here document.
To retrieve data from a table you can select your values and put a separator in between (I often use a comma as separator); the rows are coming out from sqlplus standard output and you can capture and separate the values using the built in command read.
I can only say that this works with the korn shell; bash should be ok also.

Code:
#!/bin/ksh

# set here USER PASS DBNAME and MYVAR

$ORACLE_HOME/bin/sqlplus -s << SQLEND
set pagesize 0 feedback off tab off termout off
connect ${USER}/${PASS}@${DBNAME}

var myvar varchar2(99)
exec :myvar := '${MYVAR}';

select COL1||','||COL2||','||COL3
from TABLE
where COL1 = :myvar;

quit
SQLEND | IFS=',' while read col1 col2 col3; do
  # do whatever you want with $col1 $col2 $col3
done

Perhaps I forgot to set some sqlplus variable besides pagesize and the others. The point is to make sqlplus to output only the table rows and nothing more.

Passing credentials to sqlplus directly on the command line allows everyone to learn the password if they can execute the ps command, therefore I prefer to use an explicit connect command inside the sql block.

:myvar is a bind variable. Using a bind variable instead of embedding ${MYVAR} directly into the query has an advantage, namely the query text does not change between successive executions of the sql section even if the value of MYVAR does change; this allows the Oracle optimizer to recognize that the query to be parsed is one that it has already seen and so it does not (hard) parse it again.

Of course if the query is guaranteed to output only one row -- or the rows are ordered (by order by! There are no other means to ensure a particular order) and you are interested only in the first row -- you can do without the while loop:
Code:
SQLEND | IFS=',' read col1 col2 col3
# do whatever you want with $col1 $col2 $col3

Another way to capture sqlplus output is to redirect it into a file, perhaps because the query output is already in a form that can be sourced by the shell:
Code:
select 'export '||COL2||'='||COL3
from TABLE
where COL1 = :myvar;

quit
SQLEND > /tmp/env$$
source /tmp/env$$

Or you can capture the whole output in a shell variable and then eval it:
Code:
sqlout=$($ORACLE_HOME/bin/sqlplus -s << SQLEND
...
SQLEND)
eval $sqlout

I am not sure if this is the correct way to combine the here document construct with the $() syntax, but I remember they can be made to work together.

The bottom line is that you don't need to ask Oracle to open a file, because the data is already coming out from sqlplus standard output.

And, please, don't use a PL/SQL block to output query results via dbms_output, this is just plain silly because sqlplus already does that for you.

Last edited by colemar; 04-19-2009 at 07:29 PM.. Reason: 99
 

10 More Discussions You Might Find Interesting

1. Shell Programming and Scripting

calling sqlplus from shell

Hi All, I am executing the following code :- sqlplus -s ${DATABASE_USER} |& print -p -- 'set feed off pause off pages 0 head off veri off line 500' print -p -- 'set term off time off serveroutput on size 1000000' print -p -- "set sqlprompt ''" print -p -- "SELECT run_command from... (2 Replies)
Discussion started by: suds19
2 Replies

2. UNIX for Advanced & Expert Users

Problem while calling Oracle 10g SQLPLUS files

Hi all, Iam facing a lot of problem while calling Oracle 10g SQLPLUS files from shell. What is the standard procedures to be taken care. Any help would be useful for me. Thanks in advance, Ganapati. (2 Replies)
Discussion started by: ganapati
2 Replies

3. Shell Programming and Scripting

calling sqlplus from within a for loop

i'm not new to programming, but i AM new to unix scripting. here's my deal. this works: #!/bin/ksh echo "HELLO" /oracle_home/bin/sqlplus username/password@MYDB<<EOF SELECT COUNT(*) FROM EMPLOYEES; EOF exit echo "GOODBYE" this doesn't: #!/bin/ksh echo "HELLO" for x in 1 2... (4 Replies)
Discussion started by: akosz
4 Replies

4. UNIX and Linux Applications

How to access Oracle table using sqlplus

Hi, I want to use sqlplus from server1 sqlplus usr1/pass1@dns1 and I want to connect to an Oracle database from a server2. Unfortunately the database was created on the server1 and on server2. So when I use the command just like that...it connects to the database from the server2. ... (2 Replies)
Discussion started by: AngelMady
2 Replies

5. Shell Programming and Scripting

Error in calling store procedure using SQLPLUS in unix

Hi, I am facing the following error in calling the stored procedure from SQLPLUS in unix environment. SQL> set serveroutput on SQL> var store number; SQL> exec test_proc(:store, 200); BEGIN TEST_PROC(:store, 200); END; * ERROR at line 1: ORA-01858: a non-numeric character was found... (8 Replies)
Discussion started by: pradeep7986
8 Replies

6. UNIX for Dummies Questions & Answers

calling a unix shell script from sqlplus

I want to execute a shell script from sqlplus prompt and get its output back to sqlplus. Is this possible? if yes just give me an example for doing that. (2 Replies)
Discussion started by: boopathyvasagam
2 Replies

7. Shell Programming and Scripting

Calling sqlplus from Korn shell heredoc issue

Hi, I am facing an issue wherein some temporary files (here docs) are getting created in /tmp and are not getting deleted automatically. When i check the list of open files with below command i can see one file is getting appended continuously.(In this case /tmp/sfe7h.34p) The output is... (4 Replies)
Discussion started by: Navin_Ramdhami
4 Replies

8. Shell Programming and Scripting

Truncate table $TABLE -- SQLPLUS

I want to truncate a table using sqlplus where the table name is in shell variable: I am using : sqlplus -s / <<end truncate table $TABLE end (2 Replies)
Discussion started by: IB_88
2 Replies

9. Shell Programming and Scripting

Avoid $ symbol while calling sqlplus in shellscript.

Hi All, we have requirement, i am created a shell script , inside i am connecting sqlplus and execute the query. below my code for your reference. get_sqlid () { sqlid=$( sqlplus -s $PBDW_USERID/$PBDW_PW@$PBDW_SID <<EOF DEFINE TBLNAME=$1 set feedback off set serverout on size... (4 Replies)
Discussion started by: KK230689
4 Replies

10. UNIX for Beginners Questions & Answers

SQLPLUS calling Via Script

Hello All, Could you please help me if i am doing anything wrong in below script, especially the sqlplus part performance wise or anything else i could improvise in the script. Thank you. #!/bin/ksh ## Batch Obj Id MP_BCH_OBJ_ID=$1 PASS=$2 partition=$3 ## script dir... (6 Replies)
Discussion started by: Ariean
6 Replies
All times are GMT -4. The time now is 08:09 PM.
Unix & Linux Forums Content Copyright 1993-2022. All Rights Reserved.
Privacy Policy