bcp Utility
The bcp utility copies data between Microsoft® SQL Server™ and a data file in a user-specified format.
Syntax
bcp {[[database_name.][owner].]{table_name | view_name} | "query"}
{in | out | queryout | format} data_file
[-m max_errors] [-f format_file] [-e err_file]
[-F first_row] [-L last_row] [-b batch_size]
[-n] [-c] [-w] [-N] [-6] [-q] [-C code_page]
[-t field_term] [-r row_term]
[-i input_file] [-o output_file] [-a packet_size]
[-S server_name] [-U login_id] [-P password]
[-T] [-v] [-R] [-k] [-E] [-h "hint [,...n]"]
Arguments
- database_name
- Is the name of the database in which the specified table or view resides. If not specified, this is the default database for the user.
- owner
- Is the name of the table or view owner. owner is optional if the user performing the bulk copy operation owns the specified table or view. If owner is not specified and the user performing the bulk copy operation does not own the specified table or view, Microsoft SQL Server returns an error message, and the bulk copy operation is canceled.
- table_name
- Is the name of the destination table when copying data into SQL Server (in), and the source table when copying data from SQL Server (out).
- view_name
- Is the name of the destination view when copying data into SQL Server (in), and the source view when copying data from SQL Server (out). Only views in which all columns refer to the same table can be used as destination views. For more information on the restrictions for copying data into views, see INSERT.
- query
- Is a Transact-SQL query that returns a result set. If the query returns multiple result sets, such as a SELECT statement that specifies a COMPUTE clause, only the first result set is copied to the data file; subsequent result sets are ignored. Use double quotation marks around the query and single quotation marks around anything embedded in the query. queryout must also be specified when bulk copying data from a query.
- in | out | queryout | format
- Specifies the direction of the bulk copy. in copies from a file into the database table or view. out copies from the database table or view to a file. queryout must be specified only when bulk copying data from a query. format creates a format file based on the option specified (-n, -c, -w, -6, or -N) and the table or view delimiters. If format is used, the -f option must be specified as well.
- data_file
- Is the full path of the data file used when bulk copying a table or view to or from a disk. When bulk copying data into SQL Server, the data file contains the data to be copied into the specified table or view. When bulk copying data from SQL Server, the data file contains the data copied from the table or view. The path can have from 1 through 255 characters.
- -m max_errors
- Specifies the maximum number of errors that can occur before the bulk copy operation is canceled. Each row that cannot be copied by bcp is ignored and counted as one error. If this option is not included, the default is 10.
- -f format_file
- Specifies the full path of the format file that contains stored responses from a previous use of bcp on the same table or view. Use this option when using a format file created with the format option to bulk copy data in or out. Creation of the format file is optional. After prompting you with format questions, bcp prompts whether to save the answers in a format file. The default file name is Bcp.fmt. bcp can refer to a format file when bulk copying data; therefore, reentering previous format responses interactively is not necessary. If this option is not used and -n, -c, -w, -6, or -N is not specified, bcp prompts for format information.
- -e err_file
- Specifies the full path of an error file used to store any rows bcp is unable to transfer from the file to the database. Error messages from bcp go to the user’s workstation. If this option is not used, an error file is not created.
- -F first_row
- Specifies the number of the first row to bulk copy. The default is 1, indicating the first row in the specified data file.
- -L last_row
- Specifies the number of the last row to bulk copy. The default is 0, indicating the last row in the specified data file.
- -b batch_size
- Specifies the number of rows per batch of data copied. Each batch is copied to the server as one transaction. SQL Server commits or rolls back, in the case of failure, the transaction for every batch. By default, all data in the specified data file is copied in one batch. Do not use in conjunction with the -h "ROWS_PER_BATCH = bb" option.
- -n
- Performs the bulk copy operation using the native (database) data types of the data. This option does not prompt for each field; it uses the native values.
- -c
- Performs the bulk copy operation using a character data type. This option does not prompt for each field; it uses char as the storage type, no prefixes, \t (tab character) as the field separator, and \n (newline character) as the row terminator.
- -w
- Performs the bulk copy operation using Unicode characters. This option does not prompt for each field; it uses nchar as the storage type, no prefixes, \t (tab character) as the field separator, and \n (newline character) as the row terminator. Cannot be used with SQL Server version 6.5 or earlier.
- -N
- Performs the bulk copy operation using the native (database) data types of the data for noncharacter data, and Unicode characters for character data. This option offers a higher performance alternative to the -w option, and is intended for transferring data from one SQL Server to another using a data file. It does not prompt for each field. Use this option when you are transferring data that contains ANSI extended characters and you want to take advantage of the performance of native mode. -N cannot be used with SQL Server 6.5 or earlier.
- -6
- Performs the bulk copy operation using SQL Server 6.0 or 6.5 data types. Use this option in conjunction with character (-c) or native (-n) format. This option does not prompt for each field; it uses the default values. Use this option when data files contain values using SQL Server 6.5 formats, such as data files generated by the bcp utility supplied with SQL Server 6.5 and earlier. For example, to bulk copy date formats supported by earlier versions of the bcp utility (but no longer supported by ODBC) into SQL Server, use the -6 parameter.
Important When bulk copying data from SQL Server into a data file, bcp does not generate SQL Server 6.0 or 6.5 date formats for any datetime or smalldatetime data, even if -6 is specified. Dates are always written in ODBC format. Additionally, null values in bit columns are written as the value 0 because SQL Server versions 6.5 and earlier do not support nullable bit data.
- -q
- Specifies that quoted identifiers are required, for example, when the table or view name contains characters that are not ANSI characters. Enclose the entire three-part table or view name (which may contain embedded special characters, such as spaces) in double quotation marks (“ “).
- -C code_page
- Specifies the code page of the data in the data file. code_page is relevant only if the data contains char, varchar, or text columns with character values greater than 127 or less than 32.
Code page value |
Description |
ACP |
ANSI/Microsoft Windows® (ISO 1252). |
OEM |
Default code page used by the client. This is the default code page used by bcp if -C is not specified. |
RAW |
No conversion from one code page to another occurs. This is the fastest option because no conversion occurs. |
<value> |
Specific code page number, for example, 850. |
- -t field_term
- Specifies the field terminator. The default is \t (tab character). Use this parameter to override the default field terminator.
- -r row_term
- Specifies the row terminator. The default is \n (newline character). Use this parameter to override the default row terminator.
- -i input_file
- Specifies the name of a response file, containing the responses to the command prompt questions for each field when performing a bulk copy using interactive mode (-n, -c, -w, -6, or -N not specified).
- -o output_file
- Specifies the name of a file that receives output from bcp redirected from the command prompt.
- -a packet_size
- Specifies the number of bytes, per network packet, sent to and from the server. A server configuration option can be set by using SQL Server Enterprise Manager (or the sp_configure system stored procedure). However, the server configuration option can be overridden on an individual basis by using this option. packet_size can be from 4096 to 65535 bytes; the default is 4096.
Increased packet size can enhance performance of bulk copy operations. If a larger packet is requested but cannot be granted, the default is used. The performance statistics generated by bcp show the packet size used.
- -S server_name
- Specifies the server running SQL Server to connect to. server_name is the name of the server on the network. The default is the local server running SQL Server (no server name). This option is required when executing bcp from a remote computer on the network.
- -U login_id
- Specifies the login ID used to connect to SQL Server.
- -P password
- Specifies the password for the login ID. If this option is not used, bcp prompts for a password. If this option is used at the end of the command prompt without a password, bcp uses the default password (NULL).
- -T
- Specifies that bcp connects to SQL Server with a trusted connection, using the security credentials of the network user. login_id and password are not required.
- -v
- Reports the bcp utility version number and copyright.
- -R
- Specifies that currency, date, and time data is bulk copied into SQL Server using the regional format defined for the locale setting of the client computer. By default, regional settings are ignored.
- -k
- Specifies that empty columns should retain a null value during the bulk copy operation, rather than have any default values for the columns inserted.
- -E
- Specifies that the values for an identity column are present in the file being imported. If -E is not given, the identity values for this column in the data file being imported are ignored, and SQL Server automatically assigns unique values based on the seed and increment values specified during table creation. If the data file does not contain values for the identity column in the table or view, use a format file to specify that the identity column in the table or view should be skipped when importing data; SQL Server automatically assigns unique values for the column. For more information, see DBCC CHECKIDENT.
- -h "hint [,...n]"
- Specifies the hint(s) to be used during a bulk copy of data into a table or view. This option cannot be used when bulk copying data into SQL Server 6.x or earlier.
Hint |
Description |
ORDER (column [ASC | DESC] [,...n]) |
Sort order of the data in the data file. Bulk copy performance is improved if the data being loaded is sorted according to the clustered index on the table. If the data file is sorted in a different order, or there is no clustered index on the table, the ORDER hint is ignored. The names of the columns supplied must be valid columns in the destination table. By default, bcp assumes the data file is unordered. |
ROWS_PER_BATCH = bb |
Number of rows of data per batch (as bb). Used when -b is not specified, resulting in the entire data file being sent to the server as a single transaction. The server optimizes the bulk load according to the value bb. By default, ROWS_PER_BATCH is unknown. |
KILOBYTES_PER_BATCH = cc |
Approximate number of kilobytes (KB) of data per batch (as cc). By default, KILOBYTES_PER_BATCH is unknown. |
TABLOCK |
A table-level lock is acquired for the duration of the bulk copy operation. This hint significantly improves performance because holding a lock only for the duration of the bulk copy operation reduces lock contention on the table. A table can be loaded by multiple clients concurrently if the table has no indexes and TABLOCK is specified. By default, locking behavior is determined by the table option table lock on bulk load. |
CHECK_CONSTRAINTS |
Any constraints on the destination table are checked during the bulk copy operation. By default, constraints are ignored. |
Remarks
Values in the data file being imported for computed or timestamp columns are ignored, and SQL Server automatically assigns values. If the data file does not contain values for the computed or timestamp columns in the table, use a format file to specify that the computed or timestamp columns in the table should be skipped when importing data; SQL Server automatically assigns values for the column.
Computed and timestamp columns are bulk copied from SQL Server to a data file as usual.
SQL Server identifiers, including database names, table or view names, logins, and passwords, can include characters such as embedded spaces and quotation marks. When specifying an identifier at the command prompt that includes a space or quotation mark, enclose the identifier in double quotation marks (“ “). Additionally, for table or view names that contain embedded spaces or quotation marks, specify the -q parameter. For example, to bulk copy the Authors.txt file into the my table table in the pubs copy database, using the my name login and my pass password, execute:
bcp "pubs copy..my table" in authors.txt -c -q -Sserver_name -U"my name" -P"my pass"
See Also
(c) 1988-98 Microsoft Corporation. All Rights Reserved.