SQL*PLUS - SET Statement

Set sqlplus system settings and defaults.

Syntax:

   SET option value

   SHO[W] option

Options: most of the options listed below have an abbreviated and a long form
           e.g. APPINFO or APPI will do the same thing

APPI[NFO] {ON|OFF|text}
   Application info for performance monitor (see DBMS_APPLICATION_INFO)

ARRAY[SIZE] {15|n}
   Fetch size (1 to 5000) the number of rows that will be retrieved in one go.

AUTO[COMMIT] {OFF|ON|IMM[EDIATE]|n} 
   Autocommit commits after each SQL command or PL/SQL block

AUTOP[RINT] {OFF|ON}
   Automatic PRINTing of bind variables.(see PRINT)

AUTORECOVERY [ON|OFF]
   Configure the RECOVER command to automatically apply 
   archived redo log files during recovery - without any user confirmation.

AUTOT[RACE] {OFF|ON|TRACE[ONLY]} [EXP[LAIN]] [STAT[ISTICS]] 
   Display a trace report for SELECT, INSERT, UPDATE or DELETE statements
   EXPLAIN shows the query execution path by performing an EXPLAIN PLAN.
   STATISTICS displays SQL statement statistics.
   Using ON or TRACEONLY with no explicit options defaults to EXPLAIN STATISTICS

BLO[CKTERMINATOR] {.|c|OFF|ON}
   Set the non-alphanumeric character used to end PL/SQL blocks to c

CMDS[EP] {;|c|OFF|ON}
   Change or enable command separator - default is a semicolon (;)

COLSEP { |text} 
   The text to be printed between SELECTed columns normally a space.

COM[PATIBILITY] {V5|V6|V7|V8|NATIVE}
   Version of oracle - see also init.ora COMPATIBILITY=
   You can set this back by up to 2 major versions e.g. Ora 9 supports 8 and 7

CON[CAT] {.|c|OFF|ON}
   termination character for substitution variable reference
   default is a period.

COPYC[OMMIT] {0|n}
   The COPY command will fetch n batches of data between commits.
   (n= 0 to 5000) the size of each fetch=ARRAYSIZE.
   If COPYCOMMIT = 0, COPY will commit just once - at the end.

COPYTYPECHECK {OFF|ON}
   Suppres the comparison of datatypes while inserting or appending to DB2

DEF[INE] {&|c|OFF|ON}
   c =  the char used to prefix substitution variables. 
   ON or OFF controls whether to replace substitution variables with their values.
   (this overrides SET SCAN) 

DESCRIBE [DEPTH {1|n|ALL}][LINENUM {ON|OFF}][INDENT {ON|OFF}]
   Sets the depth of the level to which you can recursively describe an object
   (1 to 50) see the DESCRIBE command 

ECHO {OFF|ON}
   Display commands as they are executed

EMB[EDDED] {OFF|ON}
   OFF = report printing will start at the top of a new page.
   ON = report printing can begin anywhere on a page.
 
ESC[APE] {\|c|OFF|ON} 
    Defines the escape character. OFF undefines. ON enables. 

FEED[BACK] {6|n|OFF|ON}
   Display the number of records returned (when rows >= n )
   OFF (or n=0) will turn the display off
   ON will set n=1

FLAGGER {OFF|ENTRY|INTERMED[IATE]|FULL}
   Checks to make sure that SQL statements conform to the ANSI/ISO SQL92 standard.
   non-standard constructs are flagged as errors and displayed 
   See also ALTER SESSION SET FLAGGER.

FLU[SH] {OFF|ON}
   Buffer display output (OS)
   (no longer used in Oracle 9)

HEA[DING] {OFF|ON}
   print column headings

HEADS[EP] {||c|OFF|ON}
   Define the heading separator character (used to divide a column heading onto > one line.)
   OFF will actually print the heading separator char
   see also: COLUMN command

INSTANCE [instance_path|LOCAL] 
   Change the default instance for your session, this command can only be issued when 
   not already connected and requires Net8

LIN[ESIZE] {150|n} 
   Width of a line (before wrapping to the next line)
   Earlier versions default to 80, Oracle 9 is 150

LOBOF[FSET] {n|1}
   Starting position from which CLOB and NCLOB data is retrieved and displayed

LOGSOURCE [pathname] 
   Change the location from which archive logs are retrieved during recovery
   normally taken from LOG_ARCHIVE_DEST 

LONG {80|n}
   Set the maximum width (in chars) for displaying and copying LONG values.

LONGC[HUNKSIZE] {80|n}
   Set the fetch size (in chars) for retrieving LONG values.

MARK[UP] HTML [ON|OFF]
  [HEAD text] [BODY text] [TABLE text] 
     [ENTMAP {ON|OFF}][SPOOL {ON|OFF}]
        [PRE[FORMAT] {ON|OFF}]
   Output HTML text, which is the output used by iSQL*Plus.

NEWP[AGE] {1|n}
   The number of blank lines between the top of each page and the top title.
   0 = a formfeed between pages.

NULL text
   Replace a null value with 'text'
   The NULL clause of the COLUMN command will override this for a given column.

NUMF[ORMAT] format
   The default number format.
   see COLUMN FORMAT. 

NUM[WIDTH] {10|n}
   The default width for displaying numbers.

PAGES[IZE] {14|n}
   The height of the page - number of lines.
   0 will suppress all headings, page breaks, titles

PAU[SE] {OFF|ON|text}
   press [Return] after each page
   enclose 'text' in single quotes

RECSEP {WR[APPED]|EA[CH]|OFF}
   Print a single line of the RECSEPCHAR between each record.
   WRAPPED = print only for wrapped lines
   EACH=print for every row

RECSEPCHAR {_|c}
   Define the RECSEPCHAR character, default= ' '

SCAN {OFF|ON}
   OFF = disable substitution variables and parameters

SERVEROUT[PUT] {OFF|ON} [SIZE n] [FOR[MAT] {WRA[PPED]|WOR[D_WRAPPED]|TRU[NCATED]}] 
   whether to display the output of stored procedures (or PL/SQL blocks)
   i.e., DBMS_OUTPUT.PUT_LINE

   SIZE = buffer size (2000-1,000,000) bytes

SHOW[MODE] {OFF|ON}
   Display old and new settings of a system variable

SPA[CE] {1|n}
   The number of spaces between columns in output (1-10)

SQLBL[ANKLINES] {ON|OFF} 
   Allow blank lines within an SQL command. reverts to OFF after the curent command/block.

SQLC[ASE] {MIX[ED]|LO[WER]|UP[PER]} 
   Convert the case of SQL commands and PL/SQL blocks
   (but not the SQL buffer itself)

SQLPLUSCOMPAT[IBILITY] {x.y[.z]}
  Set the behavior or output format of VARIABLE to that of the
  release or version specified by x.y[.z]. 

SQLCO[NTINUE] {> |text}
   Continuation prompt (used when a command is continued on an additional line using a hyphen -)

SQLN[UMBER] {OFF|ON}
   Set the prompt for the second and subsequent lines of a command or PL/SQL block.
   ON = set the SQL prompt = the line number.
   OFF = set the SQL prompt = SQLPROMPT.

SQLPRE[FIX] {#|c}
   set a non-alphanumeric prefix char for immediately executing one line of SQL (#)

SQLP[ROMPT] {SQL>|text}
   Set the command prompt.

SQLT[ERMINATOR] {;|c|OFF|ON}| 
   Set the char used to end and execute SQL commands to c. 
   OFF disables the command terminator - use an empty line instead.
   ON resets the terminator to the default semicolon (;).
 
SUF[FIX] {SQL|text} 
   Default file extension for SQL scripts

TAB {OFF|ON}
   Format white space in terminal output.  
   OFF = use spaces to format white space.
   ON = use the TAB char.
   Note this does not apply to spooled output files.
   The default is system-dependent. Enter SHOW TAB to see the default value. 

TERM[OUT] {OFF|ON}
   OFF suppresses the display of output from a command file
   ON displays the output.
   TERMOUT OFF does not affect the output from commands entered interactively. 

TI[ME] {OFF|ON}
   Display the time at the command prompt.

TIMI[NG] {OFF|ON}
   ON = display timing statistics for each SQL command or PL/SQL block run.
   OFF = suppress timing statistics

TRIM[OUT] {OFF|ON}
   Display trailing blanks at the end of each line.
   ON = remove blanks, improving performance
   OFF = display blanks. 
   This does not affect spooled output.
   SQL*Plus ignores TRIMOUT ON unless you set TAB ON.

TRIMS[POOL] {ON|OFF}
   Allows trailing blanks at the end of each spooled line.
   This does not affect terminal output.

UND[ERLINE] {-|c|ON|OFF}
   Set the char used to underline column headings to c.

VER[IFY] {OFF|ON}
   ON = list the text of a command before and after replacing substitution variables with values.
   OFF = dont display the command.

WRA[P] {OFF|ON}
   Controls whether to truncate or wrap the display of long lines. 
   OFF = truncate 
   ON = wrap to the next line
   The COLUMN command (WRAPPED and TRUNCATED clause) can override this for specific columns. 

The items in Gray on this page are deprecated from Oracle 9 onwards - also note that several of the options above have 'gone missing' from the official documentation set - HELP SET is a more accurate reference.

Get a list of these SET options in sql*plus with the command:
SQLPLUS> HELP SET

Example

A demo SQL script with the most common SET options

Related Oracle Commands:
SQL*Plus commands


 
Copyright © 1999-2024 SS64.com
Some rights reserved