calling sqlplus, read table return etc

I have korn shell scripts.

I want to pass a variable to a script which will execute a a sql script to read a table that contains env. variables. I want to read and then somehow export at unix level variables

example
for every row selected from the table build export command line

field1 := 'export SHELL = /app/pasf/sqr; ';

I some how need to get these back to unix korn script so I can create the variable at the unix level. It will be valid only while the session is open.

Not sure the best way to do this.

So far I created a the following(its just a start):

SET serveroutput ON
DECLARE
   recordtype   varchar2 (6)      :='DBASE1'; 
   SHELL        VARCHAR2 (36);
   SHELL1        VARCHAR2 (36);
   SHELL2        VARCHAR2 (36);
   PARMS        VARCHAR2 (36);
   SQR          VARCHAR2 (31);
   SQLq          VARCHAR2 (36);
   CTL          VARCHAR2 (36);
   TNS_ADMIN    VARCHAR2 (44);
   ORACLE_HOME1 VARCHAR2 (44);
   PATH1        VARCHAR2 (30);

CURSOR XXX_cursor IS
 SELECT  PROGRAM_ID,STRING_ID,LABEL_ID,STRING_TEXT,COL_WIDTH from PS_XXX_ENV_VARS
           WHERE PROGRAM_ID =  recordtype;
 XXX_VARS XXX_cursor%ROWTYPE;
BEGIN
    IF NOT XXX_cursor%isopen THEN
       OPEN XXX_cursor;
    END IF;
    
 
   LOOP
    fetch XXX_cursor into XXX_VARS;
    EXIT WHEN XXX_cursor%notfound; 
     SHELL2 := XXX_VARS.STRING_TEXT ;
     SHELL1 := XXX_VARS.STRING_ID;
    DBMS_OUTPUT.put_line (SHELL1);
        EXIT WHEN XXX_cursor%notfound; 
   END LOOP;
   CLOSE XXX_cursor ;
END;

output is

EXPORT PARMS= /unixsxxx/apps/psf/zzz/CCC/

EXPORT SHELL= /unixsxxx/apps/psf/zzz/CCC/

EXPORT SQL= /unixsxxx/apps/psf/zzz/CCCC/

EXPORT SQR= /unixsxx/apps/psf/zzz/

use UTL_FILE to open a file, write those script statements to the file, then close the file. For example call it /tmp/env.sh

# ........ sql code goes here in  a here document

sqlplus -s username/password@somedbname <<EOF
SET serveroutput ON
DECLARE
   recordtype   varchar2 (6)      :='DBASE1'; 
   SHELL        VARCHAR2 (36);
   SHELL1        VARCHAR2 (36);
   SHELL2        VARCHAR2 (36);
   PARMS        VARCHAR2 (36);
   SQR          VARCHAR2 (31);
   SQLq          VARCHAR2 (36);
   CTL          VARCHAR2 (36);
   TNS_ADMIN    VARCHAR2 (44);
   ORACLE_HOME1 VARCHAR2 (44);
   PATH1        VARCHAR2 (30);
   FP           UTL_FILE.FILE_TYPE;

CURSOR XXX_cursor IS
 SELECT  PROGRAM_ID,STRING_ID,LABEL_ID,STRING_TEXT,COL_WIDTH from PS_XXX_ENV_VARS
           WHERE PROGRAM_ID =  recordtype;
 XXX_VARS XXX_cursor%ROWTYPE;
BEGIN
    IF NOT XXX_cursor%isopen THEN
       OPEN XXX_cursor;
    END IF;
    
   FP:=UTL_FILE.FOPEN('/TMP','ENV.SH','W');
   LOOP
    	fetch XXX_cursor into XXX_VARS;
    	EXIT WHEN XXX_cursor%notfound; 
    	 SHELL2 := XXX_VARS.STRING_TEXT ;
    	 SHELL1 := XXX_VARS.STRING_ID;
    	UTL_FILE.put_line (FP, SHELL1||'='||SHELL2);        
   END LOOP;
   UTL_FILE.FCLOSE(FP);
   CLOSE XXX_cursor ;
END;
  exit
EOF

# set permissions on file:
chmod +x /tmp/env.sh
# source the shell script to bring env vars into this process
. /tmp/env.sh

meh .... you don't need a temp file.

Terminate the output with semi-colons, then eval:

output:

% your_sql_script.sh

EXPORT PARMS= /unixsxxx/apps/psf/zzz/CCC/;

EXPORT SHELL= /unixsxxx/apps/psf/zzz/CCC/;

EXPORT SQL= /unixsxxx/apps/psf/zzz/CCCC/;

EXPORT SQR= /unixsxx/apps/psf/zzz/;

% eval `your_sql_script.sh`

% echo $SQR

Hey all thanks, I did some research and I found infor on UTIL_FILE. Quesion with regrads to this, Do I not need to add the directory I want to the UTIL_FILE_DIR in order to work?

ORA-29280: invalid directory path
ORA-06512: at "SYS.UTL_FILE", line 33
ORA-06512: at "SYS.UTL_FILE", line 436
ORA-06512: at line 30

Your idea was good but I cannot use UTL_file. I did code using this package, got it to work but discovered that I am running on one server and the output is automatically going to another server which we cannot have access to.

Would anyone have a different approach to returning multiple rows to the calling shell script to set environment variables.

Thank you

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.

#!/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:

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:

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:

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.