bcp

Description

Copies a database table to or from an operating system file in a user-specified format. bcp is located in $SYBASE/$SYBASE_OCS/bin.

(Windows) The utility is bcp.exe, and is located in %SYBASE%\%SYBASE_OCS%\bin.

Syntax

bcp [[database_name.]owner.]table_name [: [ partition_id | slice_number ] |
	partition partition_name] {in | out} datafile
	[-f formatfile]
	[-e errfile] 
	[-d discardfileprefix]
	[-F firstrow]
	[-L lastrow]
	[-b batchsize]
	[-m maxerrors]
	[-n]
	[-c]
	[-t field_terminator]
	[-r row_terminator]
	[-U username]
	[-P password]
	[-I interfaces_file]
	[-S server]
	[-a display_charset]
	[-z language]
	[-A packet_size]
	[-J client_charset]
	[-T text_or_image_size]
	[-E]
	[-g id_start_value]
	[-N]
	[-W]
	[-X]
	[-M LabelName LabelValue] 
	[-labeled]
	[-K keytab_file]
	[-R remote_server_principal]
	[-C]
	[-V [security_options]]
	[-Z security_mechanism]
	[-Q]
	[-Y]
	[-y sybase directory]
	[-x trusted.txt_file]
	[--maxconn maximum_connections
	[--show-fi]
	[--hide-vcc]
	[--colpasswd [[[database_name.[owner].table_name.]column_name
		[password]]]
	[--keypasswd [[database_name.[owner].]key_name [password]]]
	[--initstring ‘Transact-SQL_command’]

Or

bcp -v

Parameters

maxconn maximum_connections

is the maximum number of parallel connections permitted for each bulk copy operation. The default is 10.

database_name

is optional if the table being copied is in your default database or in master. Otherwise, you must specify a database name.

owner

is optional if you or the Database Owner owns the table being copied. If you do not specify an owner, bcp looks first for a table of that name that you own, and then looks for one owned by the Database Owner. If another user owns the table, you must specify the owner name or the command fails.

table_name

is the name of the database table to copy. The table name cannot be a Transact-SQL reserved word.

partition_id

specifies the partition number into which data is to be copied. It is supported only for bcp in. It is the equivalent of slice_number in Adaptive Server 12.5.x.

slice_number

specifies the partition slice into which data is to be copied. It is supported only for bcp in and only for round-robin partitioned tables in Adaptive Server 15.0 and later.

partition partition_name

specifies a set of one or more partitions, separated by commas.

in | out

is the direction of the copy. in indicates a copy from a file into the database table; out indicates a copy to a file from the database table or view.

datafile

specifies a set of one or more unique data files, separated by commas. It is supported for both bcp in and bcp out. The path name can be from 1 to 255 characters in length.

-f formatfile

is the full path name of a file with stored responses from a previous use of bcp on the same table. After you answer bcp’s format questions, it prompts you to save your answers in a format file. Creation of the format file is optional. The default file name is bcp.fmt. The bcp program can refer to a format file when you are copying data so that you do not have to duplicate your previous format responses interactively. Use the -f parameter only if you previously created a format file that you want to use now for a copy in or copy out. If you do not specify this parameter, bcp interactively queries you for format information.

-e errfile

is the full path name of an error file where bcp stores any rows that it was unable to transfer from the file to the database. Error messages from bcp appear on your terminal. bcp creates an error file only when you specify this parameter.

-d discardfileprefix

Logs the rejected rows into a dedicated discard file. The discard file has the same format as the host file and is created by appending the input file name to the discard file prefix supplied. You can correct the rows in this file and use the file to reload the corrected rows.

Sybase recommends that you use the -d discardfileprefix option in conjunction with -e errorfile to help identify and diagnose the problem rows logged in the discard file.

-F firstrow

is the number of the first row to copy from an input file (default is the first row).

Avoid using the -F option when performing heavy-duty, multi-process copying, as it causes bcp to generally spend more effort to run, and does not provide you with a faster process. Instead, use -F for single-process, ad-hoc copying.

-L lastrow

is the number of the last row to copy from an input file (default is the last row). if multiple files are used, this option applies to each file.

-b batchsize

is the number of rows per batch of data copied. By default, bcp in copies n rows in one batch, where n is equal to the batch size. Batching applies only when you are bulk copying in; it has no effect on bulk copying out. The smallest number bcp accepts for batchsize is 1. The largest number bcp accepts for batchsize is 2147483647L.

NoteSetting the batch size to 1 causes Adaptive Server to allocate one data page to one row copied in. This option only applies to fast bcp, and is only useful in locating corrupt rows of data. Use -b1 with care—doing so causes a new page to be allocated for each row, and is a poor use of space.

-m maxerrors

is the maximum number of nonfatal errors permitted before bcp aborts the copy. bcp discards each row that it cannot insert (due to a data conversion error, or an attempt to insert a null value into a column that does not allow them), counting each rejected row as one error. If you do not include this parameter, bcp uses a default value of 10.

-n

performs the copy operation using native (operating system) formats. Specifying the -n parameter means bcp will not prompt for each field. Files in native data format are not human-readable.

WARNING! Do not use:

  • bcp in native format for data recovery or salvage or to resolve an emergency situation.

  • bcp in native format to transport data between different hardware platforms, different operating systems, or different major releases of Adaptive Server.

  • field terminators (-t) or row terminators (-r) with bcp in native format.

Results are unpredictable and data may become corrupted.

Using bcp in native format can create flat files that cannot be reloaded into Adaptive Server and it may be impossible to recover the data. If you cannot rerun bcp in character format (for example, a table was truncated or dropped, hardware damage occurred, a database was dropped, and so on) the data is unrecoverable.

-c

performs the copy operation with char datatype as the default storage type of all columns in the data file. Use this format if you are sharing data between platforms. This parameter does not prompt for each field; it uses char as the default storage type, no prefixes, \t (tab) as the default field terminator, and \n (new line) as the default row terminator.

-t field_terminator

specifies the default field terminator.

-r row_terminator

specifies the row terminator.

WARNING! Do not use -t or -r parameters with bcp in native format. Results are unpredictable and data may become corrupted.

When specifying terminators from the command line with the -t or -r parameter, you must escape characters that have special significance to the UNIX operating system (or the command prompt shell for Windows). See the examples for bcp for more information. Either place a backslash in front of the special character or enclose it in quotes. This is not necessary when bcp prompts you (interactive mode).

-U username

specifies an Adaptive Server login name.

-P password

specifies an Adaptive Server password. If you do not specify -Ppassword, bcp prompts for a password. You can leave out the -P flag if your password is NULL.

-I interfaces_file

specifies the name and location of the interfaces file to search when connecting to Adaptive Server. If you do not specify -I, bcp looks for an interfaces file (sql.ini in Windows) located in the directory specified by the SYBASE environment variable (ini directory in Windows).

-S server

specifies the name of the Adaptive Server to which to connect. If you specify -S with no argument, bcp uses the server specified by the DSQUERY environment variable.

-a display_charset

allows you to run bcp from a terminal where the character set differs from that of the machine on which bcp is running. Use -a in conjunction with -J to specify the character set translation file (.xlt file) required for the conversion. Use -a without -J only if the client character set is the same as the default character set.

The following error message appears if the character translation file(s) named with the -a parameter is missing, or you mistype the name(s):

Error in attempting to determine the size of a pair of
translation tables.:'stat' utility failed.
-z language

is the official name of an alternate language the server uses to display bcp prompts and messages. Without the -z flag, bcp uses the server’s default language.

You can add languages to an Adaptive Server during installation or afterwards, using either the langinstall utility (or langinst in Windows) or the sp_addlanguage stored procedure.

The following error message appears if an incorrect or unrecognized language is named with the -z parameter:

Unrecognized localization object. Using default value 
'us_english'.
Starting copy...
=> warning.
-v

displays the version number of bcp and a copyright message and returns to the operating system.

-A packet_size

specifies the network packet size to use for this bcp session. For example, the following sets the packet size to 4096 bytes for this bcp session:

bcp pubs2..titles out table_out -A 4096

packet_size must be between the values of the default network packet size and maximum network packet size configuration variables, and it must be a multiple of 512.

Use network packet sizes larger than the default to improve the performance of large bulk-copy operations.

-J client_charset

specifies the character set to use on the client. bcp uses a filter to convert input between client_charset and the Adaptive Server character set.

-J client_charset requests that Adaptive Server convert to and from client_charset, the character set used on the client.

-J with no argument sets character set conversion to NULL. No conversion takes place. Use this if the client and server use the same character set.

Omitting -J sets the character set to a default for the platform, which may not necessarily be the character set that the client is using.

This error message appears if an incorrect or unrecognized character set is named with the -J parameter:

Unrecognized localization object. Using default value 
'iso_1'.
Starting copy...
=> warning.

For more information about character sets and associated flags, see the System Administration Guide.

-T text_or_image_size

allows you to specify, in bytes, the maximum length of text or image data that Adaptive Server sends. The default is 32K. If a text or an image field is larger than the value of -T or the default, bcp does not send the overflow.

-E

explicitly specifies the value of a table’s IDENTITY column.

By default, when you bulk copy data into a table with an IDENTITY column, bcp assigns each row a temporary IDENTITY column value of 0. This is effective only when copying data into a table. bcp reads the value of the ID column from the data file, but does not send it to the server. Instead, as bcp inserts each row into the table, the server assigns the row a unique, sequential, IDENTITY column value, beginning with the value 1. If you specify the -E flag when copying data into a table, bcp reads the value from the data file and sends it to the server which inserts the value into the table. If the number of rows inserted exceeds the maximum possible IDENTITY column value, Adaptive Server returns an error.

The -E parameter has no effect when you are bulk copying data out. Adaptive Server copies the ID column to the data file, unless you use the -N parameter.

You cannot use the -E and -g flags together.

-g id_start_value

specifies the value of the IDENTITY column to use as a starting point for copying data in.

You cannot use the -g and -E flags together.

-N

skips the IDENTITY column. Use this parameter when copying data in if your host data file does not include a placeholder for the IDENTITY column values, or when copying data out, if you do not want to include the IDENTITY column information in the host file.

You cannot use both -N and -E parameters when copying data in.

-W

specifies that if the server to which bcp is attempting to connect supports neither normal password encryption nor extended password encryption, plain text password retires are disabled. If this option is used, the CS_SEC_NON_ENCRYPTION_RETRY connection property will be set to CS_FALSE, and plain text (unencrypted) passwords will not be used in retrying the connection.

-X

specifies that, in this connection to the server, the application initiates the login with client-side password encryption. bcp (the client) specifies to the server that password encryption is desired. The server sends back an encryption key, which bcp uses to encrypt your password, and the server uses the key to authenticate your password when it arrives.

If bcp crashes, the system creates a core file that contains your password. If you did not use the encryption option, the password appears in plain text in the file. If you used the encryption option, your password is not readable.

-M LabelName LabelValue

(secure Adaptive Server only) enables multilevel users to set the session labels for the bulk copy. Value values for LabelName are:

  • curread (current reading level) – is the initial level of data that you can read during this session, curread must dominate curwrite.

  • curwrite (current write level) – is the initial sensitivity level that will be applied to any data that you write during this session.

  • maxread (maximum read level) – is the maximum level at which you can read data. This is the upper bound to which you as a multilevel user can set your curread during the session. maxread must dominate maxwrite.

  • maxwrite (maximum write level) – is the maximum level at which you can write data. This is the upper bound to which you as a multilevel user can set your curwrite during a session. maxwrite must dominate minwrite and curwrite.

  • minwrite (minimum write level) – is the minimum level at which you can write data. This is the lower bound to which you as a multilevel user can set curwrite during a session. minwrite must be dominated by maxwrite and curwrite.

LabelValue is the actual value of the label, expressed in the human-readable format used on your system (for example, “Company Confidential Personnel”).

-labeled

(secure Adaptive Server only) indicates that the data you are importing already has labels in the first field of every record.

For exporting data, this option indicates that you want the sensitivity label of every row to be copied out as the first field.

-K keytab_file

specifies the path to the keytab file used for authentication in DCE.

-R remote_server_principal

specifies the principal name for the server as defined to the security mechanism. By default, a server’s principal name matches the server’s network name (which is specified with the -S parameter or the DSQUERY environment variable). Use the -R parameter when the server’s principal name and network name are not the same.

-C

supports bulk copy of encrypted columns if Adaptive Server supports encrypted columns. -C enables the ciphertext option before initiating the bulk copy operation.

-V security_options

specifies network-based user authentication. With this option, the user must log in to the network’s security system before running the utility. In this case, users must supply their network user name with the -U option; any password supplied with the -P option is ignored.

You can follow -V with a security_options string of key-letter options to enable additional security services. These key letters are:

  • c – enables data confidentiality service

  • i – enables data integrity service

  • m – enables mutual authentication for connection establishment

  • o – enables data origin stamping service

  • r – enables data replay detection

  • q – enables out-of-sequence detection

-i input_file

specifies the name of the input file. The Standard Input is used as the default.

-o output_file

specifies the name of the output file. The Standard Output is used as the default.

-Z security_mechanism

specifies the name of a security mechanism to use on the connection.

Security mechanism names are defined in the $SYBASE/install/libtcl.cfg configuration file. If no security_mechanism name is supplied, the default mechanism is used. For more information on security mechanism names, see the description of the libtcl.cfg file in the Open Client and Open Server Configuration Guide.

-Q

provides backward compatibility with bcp version 10.0.4 for copying operations involving nullable columns.

-Y

specifies that character-set conversion is disabled in the server, and is instead performed by bcp on the client side when using bcp in.

NoteA client-side Unicode conversion is supported only for Adaptive Server 15.0 and later.

All character-set conversion is done in the server during bcp out.

-y sybase_directory

sets an alternate Sybase home directory.

-x trusted.txt_file

specifies an alternate trusted.txt file.

--maxconn maximum_connections

is the maximum number of parallel connections that the bcp client can open to the server. If --maxconn is not specified, bcp determines the number of connections to use.

--show-fi

instructs bcp to copy functional indexes, while using either bcp in or bcp out.

Using this option sends the data from a functional index to or from the server.

--hide-vcc

instructs bcp not to copy virtual computed columns either to or from a datafile. When you use this option in bcp OUT, the data file contains no data for virtual computed columns. When you use it in bcp IN, the data file may contain no data for a virtual computed column.

If you use this option, Adaptive Server does not calculate or send virtual computed column data.

--colpasswd [[database_name [owner].]table_name.]column_name [password]]]

sets the passwords for encrypted columns by sending set encryption passwd password for column column_name to Adaptive Server. This does not automatically apply passwords to other encrypted columns, even if the second column is encrypted with the same key. The password must be supplied a second time to access the second column.

--keypasswd [[database_name.[owner].]key_name [password]]]

sets passwords for all columns accessed by a key by sending set encryption passwd password for key key_name to Adaptive Server.

--initstring ["Transact-SQL_command"]

sets any Transact-SQL command as an initialization string for the current isql session only. Result sets issued by the initialization string are silently ignored, unless an error occurs.

Examples

Example 1

Copies data from the publishers table to a file named pub_out with char datatype as the default storage type of all columns in the data file, specifying the default field terminator and row terminator.

In UNIX, the first backslash before the final “r” escapes the second so that only one backslash is printed:

bcp pubs2..publishers out pub_out -c -t , -r \\r

In Windows:

bcp pubs2..publishers out pub_out -c -t , -r \r

Example 2

Copies data from the publishers table to a file named pub_out for later reloading into Adaptive Server. Press Return to accept the defaults specified by the prompts. The same prompts appear when you copy data into the publishers table:

bcp pubs2..publishers out pub_out
Password:
Enter the file storage type of field pub_id [char]:
Enter prefix length of field pub_id [0]:
Enter length of field pub_id [4]:
Enter field terminator [none]:
Enter the file storage type of field pub_name [char]:
Enter prefix length of field pub_name [1]:
Enter length of field pub_name [40]:
Enter field terminator [none]:
Enter the file storage type of field city [char]:
Enter prefix length of field city [1]:
Enter length of field city [20]:
Enter field terminator [none]:
Enter the file storage type of field state [char]:
Enter prefix length of field state [1]:
Enter length of field state [2]:
Enter field terminator [none]:

In UNIX, you are then asked:

Do you want to save this format information in a
    file? [Y-n] y
Host filename [bcp.fmt]: pub_form
Starting copy...
3 rows copied.
 Clock Time (ms.): total = 1 Avg = 0 (3000.00 rows per sec.)

Example 3

Copies data back into Adaptive Server using the saved format file, pub_form:

bcp pubs2..publishers in pub_out -f pub_form

Example 4

Enter the single letter exactly as it appears below:

To see examples of datatypes, enter "?" at the prompt:
Enter the file storage type of field 'pub_id'
    ['char']:?
Invalid column type. Valid types are:
 <cr>: same type as Adaptive Server column.
    c : char
    T : text
    i : int
    s : smallint
    t : tinyint
    f : float
    m : money
    b : bit
    d : datetime
    x : binary
    I : image
    D : smalldatetime
    r : real
    M : smallmoney
    n : numeric
    e : decimal

Example 5

Copies a data file created with a character set used on a VT200 terminal into the pubs2..publishers table. The -z flag displays bcp messages in French:

bcp pubs2..publishers in vt200_data -J iso_1 -z french

Example 6

(UNIX) Specifies that you are using a Macintosh, running bcp on a workstation that is using roman8:

bcp pubs2..publishers in -a mac -J roman8

Example 7

Specifies that Adaptive Server send 40K of text or image data using a packet size of 4096 bytes:

bcp pubs2..publishers out -T 40960 -A 4096

Example 8

Sets 2 as the maximum number of parallel connections permitted for each operation.

bcp_r --maxconn 2

Example 9

Copies the mypart.dat file of the current directory to partition p1 of table t1.

bcp t1 partition p1 in mypart.dat

Example 10

Copies partition p1, p2, and p3 to files a, b, and c respectively, into the \work2\data directory.

bcp t1 partition p1, p2, p3 out \work2\data\1,
\work2\data\b, \work2\data\c

Example 11

Limits this to the current session, disabling replication for the bcp connection during the transfer of data from titles.txt data into pubs2..titles.

bcp pubs2..titles in titles.txt --initstring 'set replication off'

You need not explicitly reset the configuration option after bcp is finished. If Adaptive Server returns an error, bcp stops the data transfer and displays an error message.

Example 12

Copies out database db_1, which includes table t1 with materialized computed column c1:

bcp db_1..t1 out db_1.dat -Usa -P -S big_db -I./interfaces -f ./bcp.fmt

Example 13

Copies in the data file (db_1.dat) created in Example 12, containing table t1 with materialized computed column c1:

bcp db_1..t1 in db_1.dat -Usa -P -S big_db -I./interfaces -f ./bcp.fmt

Usage


Using bcp with compressed data

Pages in a compressed table may have a combination of row-, page- or uncompressed rows. Tables and partitions listed as not compressed may contain a mixture of rows in different states of compression because you created them at times when the table’s compression level was different.

Using bcp to copy data out and then bcp it back in to a table configured for compression results in compressed data, even if the data was originally uncompressed.

Permissions

You must have an Adaptive Server account and the appropriate permissions on the database tables or views, as well as the operating system files to use in the transfer to use bcp.

Auditing

Values in event and extrainfo columns are:

Event

Audit option

Command or access audited

Information in extrainfo

4

bcp

bcp in

  • Roles – Current active roles

  • Keywords or options – NULL

  • Previous value – NULL

  • Current value – NULL

  • Other information – NULL

  • Proxy information – Original login name, if set proxy in effect

Tables used

sysaudits_01 – sysaudits_08

See also

Commands insert

Documentation Chapter 4, “Transfer Data to and from Adaptive Server with bcp” for an in-depth discussion of bcp, and the Performance and Tuning Guide for more information on how changing certain parameters can affect bcp for large batches.

Sytem procedures sp_audit, sp_dboption, sp_displayaudit