SQL> SAVE file_name
SQL*Plus adds the extension SQL to the filename to identify it as a SQL query file. If you wish to save the command or block under a name with a different file extension, type a period at the end of the filename, followed by the extension you wish to use.
Note that within SQL*Plus, you separate the extension from the filename with a period. Your operating system may use a different character or a space to separate the filename and the extension.
Example 3-6 Saving the Current Command
First, LIST the buffer contents to see your current command:
SQL> LIST 1 SELECT DEPTNO, ENAME, SAL 2 FROM EMP 3 WHERE DEPTNO = 10 4* ORDER BY SAL DESC
If the query shown is not in your buffer, re-enter the query now. Next, enter the SAVE command followed by the filename DEPTINFO:
SQL> SAVE DEPTINFO Created file DEPTINFO
You can verify that the command file DEPTINFO exists by entering the SQL*Plus HOST command followed by your host operating system's file listing command:
SQL> HOST your_host's_file_listing_command
You can use the same method to save a PL/SQL block currently stored in the buffer.
You can also store a set of SQL*Plus commands you plan to use with many different queries by themselves in a command file.
Example 3-7 Saving Commands Using INPUT and SAVE
Suppose you have composed a query to display a list of salespeople and their commissions. You plan to run it once a month to keep track of how well each employee is doing. To compose and save the query using INPUT, you must first clear the buffer:
SQL> CLEAR BUFFER
Next, use INPUT to enter the command (be sure not to type a semicolon at the end of the command):
SQL> INPUT 1 COLUMN ENAME HEADING SALESMAN 2 COLUMN SAL HEADING SALARY FORMAT $99,999 3 COLUMN COMM HEADING COMMISSION FORMAT $99,990 4 SELECT EMPNO, ENAME, SAL, COMM 5 FROM EMP 6 WHERE JOB = 'SALESMAN' 7
The zero at the end of the format model for the column COMM tells SQL*Plus to display a zero instead of a blank when the value of COMM is zero for a given row. Format models and the COLUMN command are described in more detail.
Now use the SAVE command to store your query in a file called SALES with the extension SQL:
SQL> SAVE SALES Created file SALES
Note that you do not type a semicolon at the end of the query; if you did include a semicolon, SQL*Plus would attempt to run the buffer contents. The SQL*Plus commands in the buffer would produce an error because SQL*Plus expects to find only SQL commands in the buffer. You will learn how to run a command file later in this chapter.
To input more than one SQL command, leave out the semicolons on all the SQL commands. Then, use APPEND to add a semicolon to all but the last command. (SAVE appends a slash to the end of the file automatically; this slash tells SQL*Plus to run the last command when you run the command file.)
To input more than one PL/SQL block, enter the blocks one after another without including a period or a slash on a line between blocks. Then, for each block except the last, list the last line of the block to make it current and use INPUT in the following form to insert a slash on a line by itself:
INPUT /
SQL> EDIT SALES
Like the SAVE command, EDIT adds the filename extension SQL to the name unless you type a period and a different extension at the end of the filename. When you save the command file with the text editor, it is saved back into the same file.
You must include a semicolon at the end of each SQL command and a period on a line by itself after each PL/SQL block in the file. (You can include multiple SQL commands and PL/SQL blocks.)
When you create a command file using EDIT, you can also include SQL*Plus commands at the end of the file. You cannot do this when you create a command file using the SAVE command because SAVE appends a slash to the end of the file. This slash would cause SQL*Plus to run the command file twice, once upon reaching the semicolon at the end of the last SQL command (or the slash after the last PL/SQL block) and once upon reaching the slash at the end of the file.
Note: You cannot enter a comment on the same line on which you enter a semicolon.
REMARK Commissions report REMARK to be run monthly. COLUMN ENAME HEADING SALESMAN COLUMN SAL HEADING SALARY FORMAT $99,999 COLUMN COMM HEADING COMMISSION FORMAT $99,990 REMARK Includes only salesmen. SELECT EMPNO, ENAME, SAL, COMM FROM EMP WHERE JOB = 'SALESMAN'
/* Commissions report to be run monthly. */ COLUMN ENAME HEADING SALESMAN COLUMN SAL HEADING SALARY FORMAT $99,999 COLUMN COMM HEADING COMMISSION FORMAT $99,990 SELECT EMPNO, ENAME, SAL, COMM FROM EMP WHERE JOB = 'SALESMAN' /* Includes only salesmen. */
If you enter a SQL comment directly at the command prompt, SQL*Plus does not store the comment in the buffer.
-- Commissions report to be run monthly DECLARE --block for reporting monthly sales
For SQL*Plus commands, you can only include "--" style comments if they are on a line by themselves. For example, these comments are legal:
--set maximum width for LONG to 777 SET LONG 777 -- set the heading for ENAME to be SALESMAN COLUMN ENAME HEADING SALESMAN
These comments are illegal:
SET LONG 777 -- set maximum width for LONG to 777 SET -- set maximum width for LONG to 777 LONG 777
If you entered the following SQL*Plus command, it would be treated as a comment and would not be executed:
-- SET LONG 777
Just as you can save a query from the buffer to a file with the SAVE command, you can retrieve a query from a file to the buffer with the GET command:
SQL> GET file_name
When appropriate to the operating system, SQL*Plus adds a period and the extension SQL to the filename unless you type a period at the end of the filename followed by a different extension.
Example 3-8 Retrieving a Command File
Suppose you need to retrieve the SALES file in a later session. You can retrieve the file by entering the GET command. To retrieve the file SALES, enter
SQL> GET SALES 1 COLUMN ENAME HEADING SALESMAN 2 COLUMN SAL HEADING SALARY FORMAT $99,999 3 COLUMN COMM HEADING COMMISSION FORMAT $99,990 4 SELECT EMPNO, ENAME, SAL, COMM 5 FROM EMP 6* WHERE JOB = 'SALESMAN'
SQL*Plus retrieves the contents of the file SALES with the extension SQL into the SQL buffer and lists it on the screen. Then you can edit the command further. If the file did not contain SQL*Plus commands, you could also execute it with the RUN command.
START file_name
If the file has the extension SQL, you need not add the period and the extension SQL to the filename.
Example 3-9 Running a Command File
To retrieve and run the command stored in SALES.SQL, enter
SQL> START SALES
SQL*Plus runs the commands in the file SALES and displays the results of the commands on your screen, formatting the query results according to the SQL*Plus commands in the file:
EMPNO SALESMAN SALARY COMMISSION ---------- ---------- -------- ---------- 7499 ALLEN $1,600 $300 7521 WARD $1,250 $500 7654 MARTIN $1,250 $1,400 7844 TURNER $1,500 $0
To see the commands as SQL*Plus "enters" them, you can set the ECHO variable of the SET command to ON. The ECHO variable controls the listing of the commands in command files run with the START, @ and @@ commands. Setting the ECHO variable to OFF suppresses the listing.
You can also use the @ ("at" sign) command to run a command file:
SQL> @SALES
The @ command lists and runs the commands in the specified command file in the same manner as START. SET ECHO affects the @ command as it affects the START command.
START, @ and @@ leave the last SQL command or PL/SQL block in the command file in the buffer.
START Q1SALES START Q2SALES START Q3SALES START Q4SALES START YRENDSLS
Note: The @@ command may be useful in this example. See the @@ command for more information.
SQL> EDIT PROFIT
Remember that EDIT assumes the file extension SQL if you do not specify one.
To edit an existing file using GET, the SQL*Plus editing commands, and SAVE, first retrieve the file with GET, then edit the file with the SQL*Plus editing commands, and finally save the file with the SAVE command.
Note that if you want to replace the contents of an existing command file with the command or block in the buffer, you must use the SAVE command and follow the filename with the word REPLACE. For example:
SQL> GET MYREPORT 1* SELECT * FROM EMP SQL> C/*/ENAME, JOB 1* SELECT ENAME, JOB FROM EMP SQL> SAVE MYREPORT REPLACE Wrote file MYREPORT
If you want to append the contents of the buffer to the end of an existing command file, use the SAVE command and follow the filename with the word APPEND:
SQL> SAVE file_name APPEND
Similarly, the WHENEVER OSERROR command may be used to exit if an operating system error occurs. See WHENEVER OSERROR for more information.
You can add any SQL commands, PL/SQL blocks, or SQL*Plus commands to this file; when you start SQL*Plus, it automatically searches for your LOGIN file (first in your local directory and then on a system-dependent path) and runs the commands it finds there. (You may also have a Site Profile, for example, GLOGIN.SQL. See the SQLPLUS command for more information on the relationship of Site and User Profiles.)
To store the current setting of all system variables, enter
SQL> STORE SET file_name
By default, SQL*Plus adds the extension "SQL" to the file name. If you want to use a different file extension, type a period at the end of the file name, followed by the extension. Alternatively, you can use the SET SUFFIX command to change the default file extension.
SQL> START file_name
If the file has the default extension (as specified by the SET SUFFIX command), you do not need to add the period and extension to the file name.
You can also use the @ ("at" sign) or the @@ (double "at" sign) commands to run the command file.
Example 3-10 Storing and Restoring SQL*Plus System Variables
To store the current values of the SQL*Plus system variables in a new command file "plusenv.sql":
SQL> STORE SET plusenv Created file plusenv
Now the value of any system variable can be changed:
SQL> SHOW PAGESIZE pagesize 24 SQL> SET PAGESIZE 60 SQL> SHOW PAGESIZE pagesize 60
The original values of the system variables can then be restored from the command file:
SQL> START plusenv SQL> SHOW PAGESIZE pagesize 24