bcp

Description

Copies a database table to or from an operating system file in a user-specified format. This utility is available in the %SYBASE%\%SYBASE_OCS%\bin directory.

Syntax

bcp [[database_name.]owner.]table_name [:slice_number | partition
partition_name] {in | out} datafile 
    [-a display_charset]
    [-A packet_size]
    [-b batch_size]
    [-c]
    [-C]
    [-d discardfileprefix]
    [-e errfile] 
    [-E]
    [-f formatfile] 
    [-F firstrow]
    [-g id_start_value]
    [-i input_file]
    [-I interfaces_file]
    [-J client_character_set]
    [-K keytab_file]
    [-L lastrow]
    [-m maxerrors]
    [-n]
    [-N]
    [-o output file]
    [-P password]
    [-Q]
    [-r row_terminator] 
    [-R remote_server_principal]
    [-S server]
    [-t field_terminator]
    [-T text_or_image_size]
    [-U username] 
    [-v]
    [-V [security_options]]
    [-W]
    [-X]
    [-y alternate_home_directory] 
    [-Y ]
    [-z language] 
    [-Z security_mechanism]
    [--colpasswd [[[db_name.[owner].]table_name.]
                            column_name [password]]]
    [--hide-vcc]
    [--initstring “TSQL_command”]
    [--keypasswd [[db_name.[owner].]key_name [password]]]
    [--maxconn maximum_connections]
    [--show-fi]
    [--skiprows nSkipRows] 

Parameters

database_name

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

owner

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 owned by you. Then it 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

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

slice_number

The number of the slice of the database table to copy.

partition partition_name

The name of the partition in Adaptive Server. For multiple partitions, use a comma-separated list of partition names.

in | out

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.

datafile

The full path name of an operating system file. The path name can be from 1 to 255 characters in length. For multiple datafiles, use a comma-separated list of file names. For multiple datafiles and partitions, the number of datafiles and partitions must be the same.

-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.
-A packet_size

Specifies the network packet size to use for this bcp session. For example, the following example 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.

-b batchsize

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. Batch size applies only when bulk copying in; it has no effect on bulk copying out. The smallest number bcp accepts for batchsize is 1.

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

-c

Performs the copy operation with char datatype as the default storage type for 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 (newline) as the default row terminator.

-C

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

-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 the -e errorfile to help identify and diagnose the problem rows logged in the discard file.

-e errfile

The full path name of an error file where bcp stores all rows that bcp was unable to transfer from the file to the database. The error messages from the bcp program appear on your terminal and are also logged in the error file. bcp creates an error file only when you specify this parameter. If multiple sessions are used, the partition and filename information for the error is added to the error file.

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

-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 inserted rows exceeds the maximum possible IDENTITY column value, Adaptive Server returns an error.

By default, when you bulk copy data from a table with an IDENTITY column, bcp excludes all information about the column from the output file. If you specify the -E flag, bcp copies the existing IDENTITY column values into the output file.

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.

-f formatfile

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 copying data, so that you do not have to duplicate your previous format responses interactively. Use this parameter only if you previously created a format file that you want to use now for a copy in or out. If you do not specify this parameter, bcp interactively queries you for format information.

-F firstrow

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

Avoid using this parameter 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.

Note--F cannot co-exist with --skiprows.

-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.

-i input_file

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

-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 the interfaces file, sql.ini located in %SYBASE%\ini directory.

-J client_character_set

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_character_set requests that Adaptive Server convert to and from client_character_set, the character set used on the client.

-J with no argument disables character set conversion. 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. For more information about character sets and associated flags, see the Adaptive Server Enterprise System Administration Guide.

-K keytab_file

Specifies the path to the keytab file for authentication in DCE.

-L lastrow

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.

-m maxerrors

The maximum number of 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), each rejected row as one error. If you do not include this option, bcp uses a default value of 10.

When multiple partitions are used, this number will be used for every file.

-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, salvage, or to resolve an emergency situation. Do not use bcp in native format to transport data between different hardware platforms, different operating systems, or different major releases of Adaptive Server. Do not use field terminators (-t) or row terminators (-r) with bcp in native format. Results are unpredictable and data may get 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 are unable to rerun bcp in character format (for example, a table was truncated or dropped, hardware damage occurred, a database table was dropped, and so on), the data is unrecoverable.

-N

Skips the IDENTITY column. Use this parameter when copying data in if your host data file does not include a place holder 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 in data.

-o output_file

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

-P password

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

-Q

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

-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 get corrupted.

When specifying terminators from the command line with the -t or -r parameter, you must escape characters that have special significance to the command prompt shell. 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).

-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.

-S server

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

-t field_terminator

Specifies the default field terminator.

-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 image field is larger than the value of -T or the default, bcp does not send the overflow.

-U username

Specifies an Adaptive Server login name. If you do not specify username, bcp uses the current user’s operating system login name.

-v

Displays the current version of bcp and a copyright message and returns to the operating system.

-V security_options

Specifies network-based user authentication. With this parameter, 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 parameter; any password supplied with the -P parameter is ignored.

-V can be followed by a security_options string of key-letter options to enable additional security services. These key letters are:

  • c – Enable data confidentiality service

  • d – Enable credential delegation and forward the client credentials to the gateway application

  • i – Enable data integrity service

  • m – Enable mutual authentication for connection establishment

  • o – Enable data origin stamping service

  • q – Enable out-of-sequence detection

  • r – Enable data replay detection

-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 retries 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.

NoteThe -W option and the CS_SEC_NON_ENCRYPTION_RETRY property are ignored in this release.

-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.

This option can result in normal or extended password encryption, depending on connection property settings at the server. If CS_SEC_ENCRYPTION is set to CS_TRUE, normal password encryption is used. If CS_SEC_EXTENDED_ENCRYPTION is set to CS_TRUE, extended password encryption is used. If both CS_SEC_ENCRYPTION and CS_SEC_EXTENDED_ENCRYPTION are set to CS_TRUE, extended password encryption is used as the first preference.

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.

-y alternate_home_directory

Sets an alternate Sybase home directory.

-Y

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

NoteAll character-set conversion is done in the server during bcp OUT.

-z language

The official name of an alternate language that 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 langinst utility or the sp_addlanguage stored procedure.

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

Unrecognized localization object. Using default value ‘us_english’. 
Starting copy ... 
=> warning.
-Z security_mechanism

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

Security mechanism names are defined in the libtcl.cfg configuration file located in the %SYBASE%\%SYBASE_OCS%\ini directory. If no security_mechanism name is supplied, the default mechanism is used.

NoteThe CS_LIBTCL_CFG property specifies the name and path to an alternative libtcl.cfg file. For details about this property, see the Open Client and Open Server Client Libraries Reference Manual.

For more information on security mechanism names, see the description of the libtcl.cfg file in the Open Client and Open Server Configuration Guide for Microsoft Windows.

--colpasswd column_name password

Sets passwords for encrypted columns by sending “set encryption passwd password for column column_name” to ASE. 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.

--hide-vcc

Instructs bcp not to copy virtual computed columns (VCC) either to or from a datafile. When you use this parameter in bcp OUT, the datafile does not contain data for VCC; in bcp IN, the data file may not contain data for a VCC.

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

--initstring “TSQL_command“

Sends Transact-SQL commands to ASE before data is transferred.

Result sets issued by the initialization string are silently ignored, unless an error occurs. If ASE returns an error, bcp stops before data is transferred and displays an error message.

--keypasswd key_name password

Sets passwords for all columns accessed by a key by sending “set encryption passwd password for key key_name” to ASE.

--maxconn maximum_connections

The maximum number of parallel connections permitted for each bulk copy operation. For example, the following example sets the maximum number of parallel connections permitted for each operation to 2:

bcp --maxconn 2

If you do not include this parameter, bcp uses a default value of 10.

--show-fi

Instructs bcp to copy functional indexes, while using either bcp IN or bcp OUT. If this parameter is not specified, Adaptive Server generates the value for the functional index.

--skiprows nSkipRows

Instructs bcp to skip a specified number of rows before starting to copy from an input file. The valid range for --skiprows is between 0 and the actual number of rows in the input file. If you provide an invalid value, an error message displays.

Note--skiprows cannot co-exist with the -F option. Use of --skiprows with the -F option results in an error message.

Examples

Example 1

The -c parameter copies data out of the publishers table in character format (using char for all fields). The -t field_terminator parameter ends each field with a comma, and the -r row_terminator parameter ends each line with a Return. bcp prompts only for a password.

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

Example 2

The -C parameter copies data out of the publishers table (with encrypted columns) in cipher-text format, instead of plain text. Pressing Return accepts the defaults specified by the prompts. The same prompts appear when copying data into the publishers table.

bcp pubs2..publishers out pub_out -C 
Password: 
Enter the file storage type of field col1 [int]: 
Enter prefix length of field col1 [0]: 
Enter field terminator [none]: 
Enter the file storage type of field col2 [char]: 
Enter prefix length of field col2 [0]: 
Enter length of field col2 [10]: 
Enter field terminator [none]: 
Enter the file storage type of field col3 [char]: 
Enter prefix length of field col3 [1]: 
Enter field terminator [none]: 

Example 3

Copies data from the publishers table to a file named pub_out for later reloading into Adaptive Server. Pressing Return accepts the defaults that the prompts specify. The same prompts appear when copying 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]: 

Example 4

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

bcp t1 partition p1 out mypart.dat

Example 5

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

bcp pubs2..publishers in pub_out -f pub_form

Example 6

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 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

Copies the mypart.dat file from the current directory, into table t1 of partition p1.

bcp t1 partition p1 in mypart.dat

Example 9

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

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

Example 10

Copies files data.first, data.last and data.other into partitions p1, p2 and p3 respectively.

bcp t1 partition p1, p2, p3 in data.first, data.last,
data.other

Example 11

Disables replication when titles.txt data is transferred into the pubs2 titles table:

bcp pubs2..titles in titles.txt -- initstring “set replication off”

NoteBecause the set replication off command in this example is limited to the current session in Adaptive Server, there is no need to explicitly reset the configuration option after bcp is finished.

Example 12

Sets the password to pwd1 for encrypted column col1:

bcp mydb..mytable out myfile –U uuu –P ppp –-colpasswd db..tbl.col1 pwd1

Example 13

Sets a prompt to enter the password for encrypted column:

bcp mydb..mytable out myfile –U uuu –P ppp –-colpasswd db..tbl.col1
Enter column db..tbl.col1’s password: ***?

Example 14

Reads the password for encrypted column col1 from external OS file passwordfile:

bcp mydb..mytable out myfile –U uuu –P ppp –-colpasswd db..tbl.col1 < passwordfile

Example 15

Sets password pwd1 for encryption key key1:

bcp mydb..mytable in myfile –U uuu –p ppp –-keypasswd db..key1 pwd1

Example 16

Creates the discard file reject_titlesfile.txt:

bcp pubs2..titles in titlesfile.txt -d reject_

Example 17

For MIT Kerberos, requests credential delegation and forwards the client credentials to MY_GATEWAY:

bcp -Vd -SMY_GATEWAY

Example 18

bcp ignores the first two rows of the input file titles.txt, and starts to copy from the third row.

bcp pubs2..titles in titles.txt -U username -P password
--skiprows 2

Example 19

Sets an alternate Sybase home directory to C:\work\NewSybase:

bcp tempdb..T1 out T1.out -yC:\work\NewSybase -Uuser1 
-Psecret -SMYSERVER

Usage

NoteTo use a previous version of bcp, you must set the CS_BEHAVIOR property in the [bcp] section of the ocs.cfg file:

[bcp]
CS_BEHAVIOR = CS_BEHAVIOR_100

If CS_BEHAVIOR is not set to CS_BEHAVIOR_100, you can use functionality for bcp 11.1 and later.


Using the -d option

NoteIf the discard file option is specified, the batch size is automatically adjusted and the message Warning!!! Batch size adjusted to the value newbatchsize, for the optimization of the discard file feature. is displayed, when:


Copying tables with indexes or triggers

NoteThe performance penalty for copying data into a table that has indexes or triggers in place can be severe. If you are copying in a very large number of rows, it may be faster to drop all the indexes and triggers beforehand with drop index (or alter table for indexes created as a unique constraint) and drop trigger; set the database option; copy the data into the table; recreate the indexes and triggers; and then dump the database. However, you need to allocate disk space for the construction of indexes and triggers—about 2.2 times the amount of space needed for the data.


Responding to bcp prompts

When you copy data in or out using the -n (native format) or -c (character format) parameter, bcp prompts only for your password, unless you supplied it with the -P parameter. If you do not supply either the -n, -c or -f formatfile parameter, bcp prompts you for information for each field in the table.

Table A-3: Adaptive Server char data

Prefix length = 0

Prefix length 1, 2 or 4

No terminator

string--string--

Pstring--Pstring--

Terminator

string--Tstring--T

Pstring--TPstring--T

Table A-4: Other datatypes converted to char storage

Prefix length = 0

Prefix length 1, 2 or 4

No terminator

string--string--

PstringPstring

Terminator

stringTstringT

PstringTPstringT


Messages

Permissions

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