For appeals, questions and feedback about Oracle Forums, please email oracle-forums-moderators_us@oracle.com. Technical questions should be asked in the appropriate category. Thank you!
Interested in getting your voice heard by members of the Developer Marketing team at Oracle? Check out this post for AppDev or this post for AI focus group information.
SPOOL d:\mydir\filenmae.txt select a.empcode employee a -- Did you mean "FROM employee a"? , address b where a.empcode != b.emp.code ; SPOOL OFF
CREATE OR REPLACE DIRECTORY TEST_DIR AS '\tmp\myfiles' / GRANT READ, WRITE ON DIRECTORY TEST_DIR TO myuser /
CREATE OR REPLACE PROCEDURE run_query(p_sql IN VARCHAR2 ,p_dir IN VARCHAR2 ,p_header_file IN VARCHAR2 ,p_data_file IN VARCHAR2 := NULL) IS v_finaltxt VARCHAR2(4000); v_v_val VARCHAR2(4000); v_n_val NUMBER; v_d_val DATE; v_ret NUMBER; c NUMBER; d NUMBER; col_cnt INTEGER; f BOOLEAN; rec_tab DBMS_SQL.DESC_TAB; col_num NUMBER; v_fh UTL_FILE.FILE_TYPE; v_samefile BOOLEAN := (NVL(p_data_file,p_header_file) = p_header_file); BEGIN c := DBMS_SQL.OPEN_CURSOR; DBMS_SQL.PARSE(c, p_sql, DBMS_SQL.NATIVE); d := DBMS_SQL.EXECUTE(c); DBMS_SQL.DESCRIBE_COLUMNS(c, col_cnt, rec_tab); FOR j in 1..col_cnt LOOP CASE rec_tab(j).col_type WHEN 1 THEN DBMS_SQL.DEFINE_COLUMN(c,j,v_v_val,2000); WHEN 2 THEN DBMS_SQL.DEFINE_COLUMN(c,j,v_n_val); WHEN 12 THEN DBMS_SQL.DEFINE_COLUMN(c,j,v_d_val); ELSE DBMS_SQL.DEFINE_COLUMN(c,j,v_v_val,2000); END CASE; END LOOP; -- This part outputs the HEADER v_fh := UTL_FILE.FOPEN(upper(p_dir),p_header_file,'w',32767); FOR j in 1..col_cnt LOOP v_finaltxt := ltrim(v_finaltxt||','||lower(rec_tab(j).col_name),','); END LOOP; -- DBMS_OUTPUT.PUT_LINE(v_finaltxt); UTL_FILE.PUT_LINE(v_fh, v_finaltxt); IF NOT v_samefile THEN UTL_FILE.FCLOSE(v_fh); END IF; -- -- This part outputs the DATA IF NOT v_samefile THEN v_fh := UTL_FILE.FOPEN(upper(p_dir),p_data_file,'w',32767); END IF; LOOP v_ret := DBMS_SQL.FETCH_ROWS(c); EXIT WHEN v_ret = 0; v_finaltxt := NULL; FOR j in 1..col_cnt LOOP CASE rec_tab(j).col_type WHEN 1 THEN DBMS_SQL.COLUMN_VALUE(c,j,v_v_val); v_finaltxt := ltrim(v_finaltxt||',"'||v_v_val||'"',','); WHEN 2 THEN DBMS_SQL.COLUMN_VALUE(c,j,v_n_val); v_finaltxt := ltrim(v_finaltxt||','||v_n_val,','); WHEN 12 THEN DBMS_SQL.COLUMN_VALUE(c,j,v_d_val); v_finaltxt := ltrim(v_finaltxt||','||to_char(v_d_val,'DD/MM/YYYY HH24:MI:SS'),','); ELSE v_finaltxt := ltrim(v_finaltxt||',"'||v_v_val||'"',','); END CASE; END LOOP; -- DBMS_OUTPUT.PUT_LINE(v_finaltxt); UTL_FILE.PUT_LINE(v_fh, v_finaltxt); END LOOP; UTL_FILE.FCLOSE(v_fh); DBMS_SQL.CLOSE_CURSOR(c); END;
SQL> exec run_query('select * from emp','TEST_DIR','output.txt'); PL/SQL procedure successfully completed.
empno,ename,job,mgr,hiredate,sal,comm,deptno 7369,"SMITH","CLERK",7902,17/12/1980 00:00:00,800,,20 7499,"ALLEN","SALESMAN",7698,20/02/1981 00:00:00,1600,300,30 7521,"WARD","SALESMAN",7698,22/02/1981 00:00:00,1250,500,30 7566,"JONES","MANAGER",7839,02/04/1981 00:00:00,2975,,20 7654,"MARTIN","SALESMAN",7698,28/09/1981 00:00:00,1250,1400,30 7698,"BLAKE","MANAGER",7839,01/05/1981 00:00:00,2850,,30 7782,"CLARK","MANAGER",7839,09/06/1981 00:00:00,2450,,10 7788,"SCOTT","ANALYST",7566,19/04/1987 00:00:00,3000,,20 7839,"KING","PRESIDENT",,17/11/1981 00:00:00,5000,,10 7844,"TURNER","SALESMAN",7698,08/09/1981 00:00:00,1500,0,30 7876,"ADAMS","CLERK",7788,23/05/1987 00:00:00,1100,,20 7900,"JAMES","CLERK",7698,03/12/1981 00:00:00,950,,30 7902,"FORD","ANALYST",7566,03/12/1981 00:00:00,3000,,20 7934,"MILLER","CLERK",7782,23/01/1982 00:00:00,1300,,10