Imports data into a database table from an external file or from the keyboard.
input into [ owner.]table_name [ from filename | prompt] [ format { ascii | dbase | dbasell | dbaselll | excel | fixed | foxpro | lotus }] [ escape character character] [ escapes { on | off } [ by order | by name ] [ delimited by string ] [ column widths (integer , . . . ) ] [ nostrip ] [ ( column_name, . . . ) ] [ encoding {identifier | string}]
is the file name that is passed to the server as a quoted string. The string is therefore subject to the same formatting requirements as other SQL strings. In particular:
To indicate directory paths, you must represent the backslash character (\) by two backslashes. To load data from the file c: emp\input.dat into the employee table:
input into employee from 'c: nn temp nn input.dat'
The path name is relative to the machine on which Interactive SQL is running.
allows the user to enter values for each column in a row. When running in windowed mode, a dialog appears where the user can enter the values for the new row. If the user is running Interactive SQL on the command line, Interactive SQL prompts the user to type the value for each column on the command line.
each set of values must be in the format specified by the format clause, or the set option input_format statement if the format clause is not specified. When input is entered by the user, a dialog is provided for the user to enter one row per line in the input format.
Certain file formats contain information about column names and types.
Using this information, the input statement creates the database table if it does not already exist. This is a very easy way to load data into the database. The formats that have enough information to create the table are: dbasell, dbaselll, foxpro, and lotus.
Input from a command file is terminated by a line containing end. Input from a file is terminated at the end of the file.
Allowable input formats are:
ascii – input lines are assumed to be ASCII characters, one row per line, with values separated by commas. Alphabetic strings may be enclosed in apostrophes (single quotes) or quotation marks (double quotes). Strings containing commas must be enclosed in either single or double quotes. If the string itself contains single or double quotes, double the quote character to use it within the string. Optionally, you can use the delimited by clause to specify a delimiter string other than the default, which is a comma.
Three other special sequences are also recognized. The two characters represent a new line character, “\”, represents a single (\), and the sequence \xDD represents the character with hexadecimal code DD.
dbase – the file is in DBASEll or DBASElll format. Interactive SQL will attempt to determine which format, based on information in the file. If the table does not exist, it is created.
dbasell – the file is in DBASEll format. If the table does not exist, it is created.
dbaselll – the file is in DBASElll format. If the table does not exist, it is created.
excel – input file is in the format of Microsoft Excel 2.1. If the table does not exist, it is created.
fixed – input lines are in fixed format. Use the column widths clause to specify column widths. If they are not specified, column widths in the file must be the same as the maximum number of characters required by any value of the corresponding database column’s type.
You cannot use the fixed format with binary columns that contain embedded new line and End of File character sequences.
foxpro – the file is in FoxPro format. If the table does not exist, it is created.
lotus – the file is a Lotus WKS format worksheet. input assumes that the first row in the Lotus WKS format worksheet is column names. If the table does not exist, it is created. In this case, the types and sizes of the columns created may not be correct because the information in the file pertains to a cell, not to a column.
is the default escape character for hexadecimal codes and symbols is a backslash (\), so \x0A is the linefeed character, for example.
You can change the escape character using the escape character clause. For example, to use the exclamation mark as the escape character, enter:
... escape character '|'
Only one single-byte character can be used as an escape character.
with escapes enabled (the default), characters following the backslash character are recognized and interpreted as special characters by the database server. New line characters can be included as the combination \n, other characters can be included in data as hexadecimal ASCII codes, such as \x09 for the tab character. A sequence of two backslash characters ( \) is interpreted as a single backslash. A backslash followed by any character other than n, x, X or \is interpreted as two separate characters. For example, \q inserts a backslash and the letter q.
allows the user to specify whether the columns from the input file should be matched up with the table columns based on their ordinal position in the lists (order, the default) or by their names (name). Not all input formats have column name information in the file. name is allowed only for those formats that do. They are the same formats that allow automatic table creation: dbasell, dbaselll, foxpro, and lotus.
allows you to specify a string to be used as the delimiter in ASCII input format.
can be specified for fixed format only; it specifies the widths of the columns in the input file. If column widths is not specified, the widths are determined by the database column types. Do not use this clause if you are inserting long varchar or binary data in fixed format.
normally, for ASCII input format, trailing blanks are stripped from unquoted strings before the value is inserted. nostrip can be used to suppress trailing blank stripping. Trailing blanks are not stripped from quoted strings, regardless of whether the option is used. Leading blanks are stripped from unquoted strings, regardless of the nostrip option setting.
If the ASCII file has entries such that a column appears to be null, it is treated as NULL. If the column in that position cannot be NULL, a zero is inserted in numeric columns, and an empty string in character columns.
allows you to specify the encoding that is used to read the file. encoding can be used only with the ASCII format.
If encoding is not specified, Interactive SQL determines the code page that is used to read the file as follows, where code page values occurring earlier in the list take precedence over those occurring later in the list:
The code page specified with the default_isql_encoding option (if this option is set)
The code page specified with the -codepage option when Interactive SQL was started
The default code page for the computer Interactive SQL is running on
Is an input statement from an ASCII text file:
input into employee from new_emp.inp format ASCII
The input statement allows efficient mass insertion into a named database table. Lines of input are read either from the user via an input window (if prompt is specified) or from a file (if you specify from file_name). If neither is specified, the input is read from the command file that contains the input statement. In Interactive SQL, this can even be directly from the SQL Statements pane. In this case, input is ended with a line containing only the string end.
If a column list is specified for any input format, the data is inserted into the specified columns of the named table. By default, the input statement assumes that column values in the input file appear in the same order in which they appear in the database table definition. If the input file’s column order is different, you must list the input file’s actual column order at the end of the input statement.
In this example, you create a table called inventory. To import ASCII data from the input file that contains the name value before the quantity value, you must list the input file’s actual column order at the end of the input statement for the data to be inserted correctly:
create table inventory ( quantity int, item varchar(60) )
The ASCII data from the input file stock.txt that contains the name value before the quantity value:
'Shirts', 100 'Shorts', 60
The input file’s actual column order at the end of the input statement for the data to be inserted correctly:
input into inventory from stock.txt FORMAT ASCII (item, quantity)
By default, input stops when it attempts to insert a row that causes an error. Errors can be treated in different ways by setting the on_error and conversion_error options (see “set option”). Interactive SQL prints a warning in the Messages pane if any string values are truncated on input. Missing values for NOT NULL columns are set to zero for numeric types and to the empty string for non-numeric types. If input attempts to insert a NULL row, the input file contains an empty row.
You must have insert permission on the table or view.