Use this statement to import data into a database table from an external file or from the keyboard, or import from a generic ODBC data source
INPUT INTO [ owner.]table-name input-options
input-options : [ ( column-name, ... ) ] [ BY { ORDER | NAME ] [ BYTE ORDER MARK { ON | OFF } [ COLUMN WIDTHS ( integer, ...) ] [ DELIMITED BY string ] [ ENCODING encoding ] [ ESCAPE CHARACTER character ] [ ESCAPES { ON | OFF } [ FORMAT input-format ] [ FROM filename | PROMPT ] [ NOSTRIP ]
input-format : TEXT | FIXED
encoding : identifier or string
INPUT USING connection-string FROM source-table-name INTO destination-table-name [ CREATE TABLE { ON | OFF } ]
connection-string : { DRIVER=odbc_driver_name | DSN=odbc_data_source } [ ; { connection_parameter = value } ]
BY clause The BY clause 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 list (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.
BYTE ORDER MARK clause Use this clause to specify whether to process a byte order mark (BOM) in the data.
The BYTE ORDER MARK clause is relevant only when reading from TEXT formatted files. Attempts to use the BYTE ORDER MARK clause with FORMAT clauses other than TEXT returns an error.
The BYTE ORDER MARK clause is used only when reading or writing files encoded with UTF-8 or UTF-16 (and their variants). Attempts to use the BYTE ORDER MARK clause with any other encoding returns an error.
If the ENCODING clause is specified:
If the ENCODING clause is not specified:
COLUMN WIDTHS clause COLUMN WIDTHS 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.
CREATE TABLE clause Use the CREATE TABLE clause to specify whether to create the destination table if it does not exist. The default is ON.
DELIMITED BY clause The DELIMITED BY clause allows you to specify a string to be used as the delimiter in TEXT input format. The default delimiter is a comma.
ENCODING clause The encoding argument allows you to specify the encoding that is used to read the file. The ENCODING clause can only be used with the TEXT format.
For more information about how to obtain the list of SQL Anywhere supported encodings, see Supported character sets.
For Interactive SQL, if encoding is not specified, the encoding that is used to read the file is determined in the following order:
If the input file was created using the OUTPUT statement and an encoding was specified, then the same ENCODING clause should be specified on the INPUT statement.
For more information about Interactive SQL and encodings, see default_isql_encoding option [Interactive SQL].
Specify the BYTE ORDER clause to include a byte order mark in the data.
ESCAPE CHARACTER clause The default escape character for hexadecimal codes and symbols is a backslash (\). For example, \x0A is the linefeed character.
The newline characters can be specified as \n. Other characters can be specified using 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 is interpreted as a backslash and the letter q.
The escape character can be changed, using the ESCAPE CHARACTER clause. For example, to use the exclamation mark as the escape character, specify:
... ESCAPE CHARACTER '!' |
ESCAPES clause With ESCAPES turned on (the default), characters following the escape character are interpreted as special characters by the database server. With ESCAPES turned off, the characters are read exactly as they appear in the source.
FORMAT clause The FORMAT clause allows you to specify the file format for the output.
If the FORMAT clause is not specified, then each set of values must be in the format set by the Interactive SQL SET OPTION input_format statement.
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:
TEXT Input lines are assumed to be characters, one row per line, with column values separated by delimiters. Alphabetic strings may be enclosed in apostrophes (single quotes) or quotation marks (double quotes). Strings containing delimiters 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. You can use the DELIMITED BY clause to specify a different delimiter string than the default, which is a comma.
Three other special sequences are also recognized. The two characters \n represent a newline character, \\ represents a single (\), and the sequence \xDD represents the character with hexadecimal code DD.
If the file has entries indicating that a value might be null, it is treated as NULL. If the value in that position cannot be NULL, a zero is inserted in numeric columns and an empty string in character columns.
FIXED Input lines are in fixed format. The width of the columns can be specified using the COLUMN WIDTHS clause. 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.
The FIXED format cannot be used with binary columns that contain embedded newline and End-of-File character sequences.
If you want to use other formats such as, DBASEII, DBASE III, FoxPro, Lotus 123, or Excel 97, you need to use INPUT USING.
FROM filename clause The filename can be quoted or unquoted. If the string is quoted, it is subject to the same formatting requirements as other SQL strings.
To indicate directory paths, the backslash character (\) must be represented by two backslashes. The statement to load data from the file c:\temp\input.dat into the Employees table is:
INPUT INTO Employees FROM 'c:\\temp\\input.dat'; |
The location of a relative filename is determined as follows:
INPUT INTO Employees FROM 'inputs\\inputfile.dat'; |
Interactive SQL looks for c:\work\inputs\inputfile.dat.
For example, suppose you had a file, c:\homework\inputs.sql, that contained the following statement:
INPUT INTO Employees FROM 'inputs\\inputfile.dat'; |
Interactive SQL would first look for inputfile.dat in c:\homework\inputs. If Interactive SQL does not find inputfile.dat in that location, Interactive SQL looks in the directory in which Interactive SQL is running.
FROM source-table-name clause The source-table-name parameter is a quoted string containing the name of the table in the source database. The name can be in the form database-name.owner.table-name, owner.table-name, or simply table-name. Use a period to separate the components, even if that is not the native separator in the source database. If the source
database requires a database name, but not an owner name, the format of source-table-name must be database..table (in this case the owner name is empty). Do not quote any of the names in the parameter (for example, do not use 'dba."my-table"'
; use 'dba.my-table'
instead.)
PROMPT clause The PROMPT clause allows the user to enter values for each column in a row. When running in windowed mode, a window is displayed, allowing the user to enter the values for the new row. If you are running Interactive SQL from the command line, Interactive SQL prompts you to type the value for each column on the command line.
NOSTRIP clause Normally, for TEXT 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.
USING clause The USING clause inputs data from an ODBC data source. You can either specify the ODBC data source name with the DSN option, or the ODBC driver name and connection parameters with the DRIVER option. Connection-parameter is an optional list of database-specific connection parameters.
odbc-data-source is the name of a user or ODBC data source name. For example, odbc-data-source for the SQL Anywhere demo database is SQL Anywhere 11 Demo.
Odbc-driver-name is the ODBC driver name. For a SQL Anywhere 11 database, the odbc-driver-name is SQL Anywhere 11; for an UltraLite database, odbc-driver-name is UltraLite 11.
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 FROM filename is specified). 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.
When the input is read directly from the SQL Statements pane, you must specify a semicolon before the values for the records to be inserted at the end of the INPUT statement. For example:
INPUT INTO Owner.TableName; value1, value2, value3 value1, value2, value3 value1, value2, value3 value1, value2, value3 END; |
The END statement terminates data for INPUT statements that do not name a file and do not include the PROMPT keyword.
If a column list is specified, 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 as 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.
For example, if you create a table with the following statement:
CREATE TABLE inventory ( Quantity INTEGER, item VARCHAR(60) ); |
and you want to import TEXT data from the input file stock.txt that contains the name value before the quantity value,
'Shirts', 100 'Shorts', 60 |
then you must list 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 TEXT (item, Quantity); |
By default, the INPUT statement 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 on the Messages tab 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.
Because the INPUT statement is an Interactive SQL command, it cannot be used in any compound statement (such as IF) or in a stored procedure.
See Statements allowed in procedures, triggers, events, and batches.
Must have INSERT permission on the table or view.
None.
SQL/2003 Vendor extension.
The following is an example of an INPUT statement from a TEXT file.
INPUT INTO Employees FROM new_emp.inp FORMAT TEXT; |
The following fictitious example copies the table, ulTest, into a table called saTest. ulTest is a table in an UltraLite database in the file C:\test\myULDatabase.udb, and saTest is a table created in demo.db:
INPUT USING 'driver=Ultralite 11;dbf=C:\\test\\myULDatabase.udb' FROM "ulTest" INTO "saTest"; |
Send feedback about this page via email or DocCommentXchange | Copyright © 2008, iAnywhere Solutions, Inc. - SQL Anywhere 11.0.0 |