CREATE DATABASE statement

Description

Creates a database. The database consists of several operating system files.

Syntax

CREATE DATABASE db-name
... [ [ TRANSACTION ] { LOG ON [ log-file-name ]
      [ MIRROR mirror-file-name] } ]
... [ CASE { RESPECT | IGNORE } ]
... [ PAGE SIZE page-size ]
... [ COLLATION collation-label ] [ ENCRYPTED 
ON | OFF | key-spec} ] {... [ BLANK PADDING ON ]
 ]
... [ JAVA { ON | OFF } ]
... [ JCONNECT { ON | OFF } ]
... [ PASSWORD CASE { RESPECT | IGNORE } ]
... [ IQ PATH iq-file-name ]
... [ IQ SIZE iq-file-size ]
... [ IQ PAGE SIZE iq-page-size ]
... [ BLOCK SIZE block-size ]
... [ IQ RESERVE sizeMB ]
... [ TEMPORARY RESERVE sizeMB ]
... [ MESSAGE PATH message-file-name ]
... [ TEMPORARY PATH temp-file-name ]
.... [ TEMPORARY SIZE temp-db-size ]

Parameters

db-name | log-file-name | mirror-file-name | iq-file-name | message-file-name | temp-file-name:

'file-name'

page-size:

{ 4096 | 8192 | 16384 | 32768 }

iq-page-size:

{ 65536 | 131072 | 262144 | 524288 }

block-size:

{ 4096 | 8192 | 16384 | 32768 }

collation-label:

string

key-spec: [ ON ] KEY key [ ALGORITHM ’AES’ ]

Examples

Example 1

CREATE DATABASE 'C:\\s1\\data\\mydb'
BLANK PADDING ON
IQ PATH 'C:\\s1\\data'
IQ SIZE 2000
IQ PAGE SIZE 65536
CREATE DATABASE '/s1/data/bigdb'
IQ PATH '/dev/md/rdsk/bigdb'
MESSAGE PATH '/s1/data'
TEMPORARY PATH '/dev/md/rdsk/bigtmp'
CREATE DATABASE 'marvin.db'
JAVA OFF
BLANK PADDING ON
CASE RESPECT
COLLATION 'ISO_BINENG'
IQ PATH '/filesystem/marvin.main1'
IQ SIZE 6400
IQ PAGE SIZE 262144
TEMPORARY PATH '/filesystem/marvin.temp1'
TEMPORARY SIZE 3200
MESSAGE PATH '/filesystem/marvin.mess1'
ENCRYPTED ON KEY 'is!seCret' ALGORITHM 'AES'

Usage

Creates an IQ database with the supplied name and attributes. The IQ PATH clause is required for creating the IQ database. Otherwise, you will create a standard Adaptive Server Anywhere database. If you omit the IQ PATH option, specifying any of the following options will generate an error: IQ SIZE, IQ PAGE SIZE, BLOCK SIZE, MESSAGE PATH, TEMPORARY PATH, and TEMPORARY SIZE.

When Sybase IQ creates an IQ database, it automatically generates four database files to store different types of data that constitute an IQ database. Each file corresponds to a dbspace, the logical name by which Sybase IQ identifies database files. The files are:

In addition to these files, an IQ database has a transaction log file (db-name.log) and may have a transaction log mirror file.


File names

The file names ( db-name, log-file-name, mirror-file-name, iq-file-name, message-file-name, temp-file-name) are strings containing operating system file names. As literal strings, they must be enclosed in single quotes.

Relative pathnames are recommended.

WARNING! The database file, temporary dbspace, and transaction log file must be located on the same physical machine as the database server. Do not place database files and transaction log files on a network drive. The transaction log should be on a separate device from its mirror, however.

On UNIX systems you can create symbolic links, which are indirect pointers that contain the pathname of the file to which they point. You can use symbolic links as relative pathnames. There are several advantages to creating a symbolic link for the database filename:

To create a symbolic link, use the ln -s command. For example:

ln -s /disk1/company/iqdata/company.iq company_iq_store

Once you create this link, you can specify the symbolic link in commands like CREATE DATABASE or RESTORE instead of the fully qualified pathname.

When you create a database or a dbspace, the path for every dbspace file must be unique. If your CREATE DATABASE command specifies the identical path and filename for these two stores, you receive an error.

NoteMultiplex databases have a shared IQ Store, where they share all dbspaces, and a local IQ Store. The local IQ Store consists of dbspaces that are managed by only one query server and are not visible to any other query server. To create multiplex databases, use the Create Database and Create Query Server wizards in Sybase Central. See Chapter 5, “Working with Database Objects” in the Sybase IQ System Administration Guide for more information.

You can cause a unique path in any of these ways:

WARNING! On UNIX platforms, to maintain database consistency you must be careful to specify filenames that are links to different files. IQ cannot detect the target where linked files point. Even if the filenames in the command differ, it is your responsibility to make sure they do not point to the same file.


Clauses and options of CREATE DATABASE:

TRANSACTION LOG clause The transaction log is a file where the database server logs all changes made to the database. The transaction log plays a key role in system recovery. If you do not specify any TRANSACTION LOG clause, or if you omit a path for the filename, it is placed in the same directory as the .db file. However, you should place it on a different physical device from the .db and .iq. It cannot be created on a raw partition.

MIRROR clause A transaction log mirror is an identical copy of a transaction log, usually maintained on a separate device, for greater protection of your data. By default, Sybase IQ does not use a mirrored transaction log. If you do wish to use a transaction log mirror, you must provide a filename. If you use a relative path, the transaction log mirror is created relative to the directory of the Catalog Store (db-name.db). Sybase recommends that you always create a mirror copy of the transaction log.

CASE clause For databases created with CASE RESPECT, all affected values are case sensitive in comparisons and string operations. Database object names such as columns, procedures, or user IDs, are unaffected. Dbspace names are case sensitive for databases created with CASE RESPECT. Password case sensitivity follows data sensitivity unless you specify the PASSWORD CASE clause of CREATE DATABASE.

NoteWhen a database is created with CASE IGNORE, queries may return data in either upper or lower case, depending on the type of index the optimizer chose to use. You can return all upper case data in such a situation by using this command:

SET TEMPORARY OPTION AGGREGATION_PREFERENCE=-2

Alternatively, you can use the LOWER or UPPER functions on columns to display the column values in lower or upper case.

This option is provided for compatibility with the ISO/ANSI SQL standard. The default (RESPECT) is that all comparisons are case sensitive. CASE RESPECT provides better performance than CASE IGNORE.

NoteAll databases are created with at least one user ID:

DBA

and password:

SQL

If you create a database requiring case-sensitive comparisons, the password must be entered in uppercase, unless you specify PASSWORD CASE IGNORE. The user ID is unaffected by the CASE RESPECT setting.

PAGE SIZE clause The page size for the Anywhere segment of the database (containing the catalog tables) can be 4096, 8192, 16384, or 32768 bytes, with 4096 being the default. Other values for the size will be changed to the next larger size. Normally you should use the default, 4096 (4KB). Large databases may see performance benefits from a page size larger than this default. Smaller values may limit the number of columns your database can support. If you specify a page size smaller than 4096, IQ uses a page size of 4096.

When you start a database, its page size cannot be larger than the page size of the current server. The server page size is taken from the first set of databases started or is set on the server command line using the -gp command-line option.

Command line length for any statement is limited to the Catalog page size. The 4KB default is large enough in most cases; however, in a few cases a larger PAGE SIZE value is needed to accommodate very long commands, such as RESTORE commands that reference numerous dbspaces.

COLLATION clause The collation sequence used for all string comparisons in the database.The default collation sequence is ISO_BINENG, which provides the best performance. In ISO_BINENG, the collation order is the same as the order of characters in the ASCII character set. All uppercase letters precede all lowercase letters (for example, both 'A' and 'B' precede 'a').

For a list of available collation sequences, see “The CP874toUTF8 utility” in Chapter 3, “Database Administration Utilities” of the Sybase IQ Utility Guide.

Before creating a database with a non-default collation, or a custom collating sequence, be sure to see Chapter 11, “International Languages and Character Sets” in the Sybase IQ System Administration Guide.

ENCRYPTED clause Encryption makes the data stored in your physical database file unreadable. There are two levels of encryption:

Encryption can only be specified during database creation. (To introduce encryption to an existing database requires a complete unload, database recreation, and reloading of all data.) To create a strongly encrypted database, specify the ENCRYPTED clause with the KEY clause. As with most passwords, it is best to choose a KEY value that cannot be easily guessed. We recommend that you choose a value for your KEY that is at least 16 characters long, contains a mix of upper and lower case, and includes numbers, letters and special characters.

You will require this key each time you start the database.

Using the ALGORITHM clause in conjunction with the ENCRYPTED and KEY clauses lets you specify the encryption algorithm. Currently, the only supported algorithm is AES. If the ENCRYPTED clause is used but no algorithm is specified, the default is AES. Encryption is OFF by default.

WARNING! Protect your KEY! Be sure to store a copy of your key in a safe location. A lost KEY will result in a completely inaccessible database, from which there is no recovery.

BLANK PADDING clause By default, trailing blanks are ignored for comparison purposes (BLANK PADDING ON), and Embedded SQL programs pad strings fetched into character arrays. This option is provided for compatibility with the ISO/ANSI SQL standard.

For example, the two strings

'Smith'
'Smith   '

would be treated as equal in a database created with BLANK PADDING ON.

NoteCREATE DATABASE no longer supports BLANK PADDING OFF for new databases. This change has no effect on existing databases. You can test the state of existing databases using the BlankPadding database property:

select db_property ( ‘BlankPadding’ )

Sybase recommends that you change any existing columns affected by BLANK PADDING OFF, to ensure correct join results. Recreate join columns as CHAR data type, rather than VARCHAR. CHAR columns are always blank padded.

JAVA clause If you wish to use Java in your database, you must install entries for the Sybase runtime Java classes into the catalog system tables. By default, these entries are installed. You can specify JAVA OFF if you are sure you will not be using Java to avoid installing these entries. Platforms that support JAVA ON will have the file “libdbjava7”, with a platform-specific suffix, in the /lib directory.

JCONNECT clause If you wish to use the Sybase jConnect JDBC driver to access system catalog information, you need to install jConnect support. Use this option if you wish to exclude the jConnect system objects (the default is ON). You can still use JDBC, as long as you do not access system information.

PASSWORD CASE clause You can specify whether passwords are case sensitive in the database. The case sensitivity of passwords does not have to be the same as the database's case sensitivity setting for string comparisons. If you do not specify the case sensitivity of passwords, passwords follow the case sensitivity of the database, which defaults to CASE RESPECT. Extended characters used in passwords (that is, characters above the first 128 in the code page) are case sensitive, regardless of the password case sensitivity setting.

IQ PATH clause The pathname of the main segment file containing the IQ data. You can specify an operating system file or a raw partition of an I/O device. (The Sybase IQ Installation and Configuration Guide for your platform describes the format for specifying a raw partition.) IQ automatically detects which type based on the pathname you specify. If you use a relative path, the file is created relative to the directory of the Catalog Store (the .db file).

IQ SIZE clause The size in MB of either the raw partition or the operating system file you specify with the IQ PATH clause. For raw partitions, you should always take the default, which allows IQ to use the entire raw partition; if you specify a value for IQ SIZE it must match the size of the I/O device or IQ returns an error. For operating system files, you can specify a value based on the size of your data, from the minimum in the table below up to a maximum of 128GB. The default for operating system files depends on IQ PAGE SIZE:

Table 6-5: Default and minimum sizes of IQ and Temporary Store files

IQ PAGE SIZE

IQ SIZE default

TEMPORARY SIZE default

Minimum explicit IQ SIZE

Minimum explicit TEMPORARY SIZE

65536

4096000

2048000

4MB

2MB

131072

8192000

4096000

8MB

4MB

262144

16384000

8192000

16MB

8MB

524288

32768000

16384000

32MB

16MB

IQ PAGE SIZE clause The page size in bytes for the IQ segment of the database (containing the IQ tables and indexes). The value must be a power of 2, from 65536 to 524288 bytes. The default is 131072 (128KB). Other values for the size will be changed to the next larger size. The IQ page size determines the default I/O transfer block size and maximum data compression for your database.

For the best performance, Sybase recommends the following minimum IQ page sizes:

Very wide tables, such as tables with multiple columns of wide VARCHAR data (columns from 255 to 32,767 bytes) may need the next larger IQ PAGE SIZE.

BLOCK SIZE clause The I/O transfer block size in bytes for the IQ segment of the database. The value must be less than IQ PAGE SIZE, and must be a power of two between 4096 and 32768. Other values for the size will be changed to the next larger size. The default value depends on the value of the IQ PAGE SIZE clause. For most applications, this default value is optimum. Before specifying a different value, see Chapter 4, “Managing System Resources” in the Sybase IQ Performance and Tuning Guide.

IQ RESERVE clause Specifies the size in megabytes of free list space to reserve for the Main IQ Store (IQ_SYSTEM_MAIN dbspace), so that the dbspace can be increased in size in the future. The sizeMB parameter can be any number greater than 0. The reserve cannot be changed after the dbspace is created.

When IQ RESERVE is specified, the database uses more space for internal (free list) structures. If reserve size is too large, the space needed for the internal structures can be larger than the specified size, which results in an error.

TEMPORARY RESERVE clause Specifies the size in megabytes of free list space to reserve for the Temporary IQ Store (IQ_SYSTEM_TEMP dbspace), so that the dbspace can be increased in size in the future. The sizeMB parameter can be any number greater than 0. The reserve cannot be changed after the dbspace is created.

When TEMPORARY RESERVE is specified, the database uses more space for internal (free list) structures. If reserve size is too large, the space needed for the internal structures can be larger than the specified size, which results in an error.

NoteReserve and mode for temporary dbspaces are lost, if the database is restored from a backup.

MESSAGE PATH clause The pathname of the segment containing the IQ messages trace file. You must specify an operating system file; the message file cannot be on a raw partition. If you use a relative path or omit the path, the message file is created relative to the directory of the .db file.

TEMPORARY PATH clause The pathname of the temporary segment file containing the temporary tables generated by certain queries. You can specify an operating system file or a raw partition of an I/O device. (The Sybase IQ Installation and Configuration Guide for your platform describes the format for specifying a raw partition.) IQ automatically detects which type based on the pathname you specify. If you use a relative path or omit the path, the temporary file is created relative to the directory of the .db file.

TEMPORARY SIZE clause The size in MB of either the raw partition or the operating system file you specify with the TEMPORARY PATH clause. For raw partitions, you should always take the default, which allows IQ to use the entire raw partition. The default for operating system files is always one-half the value of IQ SIZE. If the IQ Store is on a raw partition and the Temporary Store is an operating system file, the default TEMPORARY SIZE is half the size of the IQ Store raw partition.


Side effects

Several operating system files are created.

Standards

Permissions

The permissions required to execute this statement are set on the server command line, using the -gu command-line option. The default setting is to require DBA authority.

The account under which the server is running must have write permissions on the directories where files are created.

See also