CREATE DATABASE Statement

Creates a database consisting of several operating system files.

Quick Links:

Go to Parameters

Go to Examples

Go to Usage

Go to Standards

Go to Permissions

Syntax

CREATE DATABASE db-name
   … [ [ TRANSACTION ] { LOG ONlog-file-name ]
         [MIRROR mirror-file-name ] } ]
   … [ CASERESPECT | IGNORE } ]
   … [ PAGE SIZE catalog-page-size ]
   … [ COLLATION collation-label[( collation-tailoring-string ) ] ]
   … [ ENCRYPTED {algorithm-key-spec | OFF } ]
   … [ BLANK PADDING ON ]
   … [ JCONNECTON | OFF } ]
   … [ 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 ]
   … [ DBA USER userid ]
   … [ DBA PASSWORD password ]
   … [ SYSTEM PROCEDURE AS DEFINER {ON | OFF} ]

catalog-page-size (bytes) - (back to Syntax)4096 | 8192 | 16384 | 32768 }

collation-label - (back to Syntax)
   string

collation-tailoring-string - (back to Syntax)
   keyword=value

algorithm-key-spec - (back to Syntax)
   ON 
   | [ ON ] KEY key [ ALGORITHM AES-algorithm ] 
   | [ ON ] ALGORITHM AES-algorithm KEY key 
   | [ ON ] ALGORITHM ‘SIMPLEAES-algorithm - (back to algorithm-key-spec)AES’ | ‘AES256’ | ‘AES_FIPS’ | ‘AES256_FIPSkey: - (back to algorithm-key-spec)
   quoted string

iq-page-size (bytes) - (back to Syntax)65536 | 131072 | 262144 | 524288 }

block-size (bytes) - (back to Syntax)4096 | 8192 | 16384 | 32768 }

Parameters

(back to top)

Examples

(back to top)

Usage

(back to top)

Creates a database with the supplied name and attributes. The IQ PATH clause is required for creating the SAP Sybase IQ database; otherwise, you create a standard SQL Anywhere database.

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

  • db-name.db is the file that holds the catalog dbspace, SYSTEM. It contains the system tables and stored procedures describing the database and any standard SQL Anywhere database objects you add. If you do not include the .db extension, SAP Sybase IQ adds it. This initial dbspace contains the catalog store, and you can later add dbspaces to increase its size. It cannot be created on a raw partition.
  • db-name.iq is the default name of the file that holds the main data dbspace, IQ_SYSTEM_MAIN, which contains the IQ tables and indexes. You can specify a different file name with the IQ PATH clause. This initial dbspace contains the IQ store.
    Warning!   IQ_SYSTEM_MAIN is a special dbspace that contains all structures necessary for the database to open: the IQ db_identity blocks, the IQ checkpoint log, the IQ rollforward/rollback bitmaps of each committed transaction and each active checkpointed transaction, the incremental backup bitmaps, and the freelist root pages. IQ_SYSTEM_MAIN is always online when the database is open.

    The administrator can allow user tables to be created in IQ_SYSTEM_MAIN, especially if these tables are small, important tables. However, it is more common that immediately after creating the database, the administrator creates a second main dbspace, revokes create privilege in dbspace IQ_SYSTEM_MAIN from all users, grants create privilege on the new main dbspace to selected users, and sets PUBLIC.default_dbspace to the new main dbspace.

  • db-name.iqtmp is the default name of the file that holds the initial temporary dbspace, IQ_SYSTEM_TEMP. It contains the temporary tables generated by certain queries. The required size of this file can vary depending on the type of query and amount of data. You can specify a different name using the TEMPORARY PATH clause. This initial dbspace contains the temporary store.
  • db-name.iqmsg is the default name of the file that contains the messages trace dbspace, IQ_SYSTEM_MSG. You can specify a different file name using the MESSAGE PATH clause.

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

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.

In Windows, if you specify a path, any backslash characters (\) must be doubled if they are followed by an n or an x. This prevents them being interpreted as a newline character (\n) or as a hexadecimal number (\x), according to the rules for strings in SQL. It is safer to always double the backslash. For example:

CREATE DATABASE 'c:\\sybase\\mydb.db'
LOG ON 'e:\\logdrive\\mydb.log'
JCONNECT OFF
IQ PATH 'c:\\sybase\\mydb'
IQ SIZE 40
If you specify no path, or a relative path:
  • The catalog store file (db-name.db) is created relative to the working directory of the server.
  • The IQ store, temporary store, and message log files are created in the same directory as, or relative to, the catalog store.

Relative path names 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-like operating systems, you can create symbolic links, which are indirect pointers that contain the path name of the file to which they point. You can use symbolic links as relative path names. There are several advantages to creating a symbolic link for the database file name:
  • Symbolic links to raw devices can have meaningful names, while the actual device name syntax can be obscure.
  • A symbolic name might eliminate problems restoring a database file that was moved to a new directory since it was backed up.

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 DATABASE instead of the fully qualified path name.

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 file name for these two stores, you receive an error.

You can create a unique path in any of these ways:
  • Specify a different extension for each file (for example, mydb.iq and mydb.iqtmp)
  • Specify a different file name (for example, mydb.iq and mytmp.iq)
  • Specify a different path name (for example, /iqfiles/main/iq and /iqfiles/temp/iq) or different raw partitions
  • Omit TEMPORARY PATH when you create the database. In this case, the temporary store is created in the same path as the catalog store, with the default name and extension dbname.iqtmp, where dbname is the database name.
Warning!   To maintain database consistency on UNIX-like operating systems, you must specify file names that are links to different files. SAP Sybase IQ cannot detect the target where linked files point. Even if the file names in the command differ, make sure they do not point to the same operating system file.

Character strings inserted into tables are always stored in the case they are entered, regardless of whether the database is case-sensitive or not. If the string Value is inserted into a character data type column, the string is always stored in the database with an uppercase V and the remainder of the letters lowercase. SELECT statements return the string as Value. If the database is not case-sensitive, however, all comparisons make Value the same as value, VALUE, and so on. The SAP Sybase IQ server may return results in any combination of lowercase and uppercase, so you cannot expect case-sensitive results in a database that is case-insensitive (CASE IGNORE).

For example, given this table and data:

CREATE TABLE tb (id int NOT NULL,
                 string VARCHAR(30) NOT NULL);
INSERT INTO tb VALUES (1, ‘ONE’);
SELECT * FROM tb WHERE string = ‘oNe’;

The result of the SELECT can be “oNe” (as specified in the WHERE clause) and not necessarily “ONE” (as stored in the database).

Similarly, the result of:

SELECT * FROM tb WHERE string = ‘One’;

can be “One” and the result of:

SELECT * FROM tb WHERE string = ‘ONe’;

can be “ONe”.

All databases are created with at least one user ID:

DBA

and password:

sql

In new databases, all passwords are case-sensitive, regardless of the case-sensitivity of the database. The user ID is unaffected by the CASE RESPECT setting.

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 DATABASE commands that reference numerous dbspaces. A larger page size might also be needed to execute queries involving large numbers of tables or views.

Because the default catalog page size is 4KB, this is a problem only when the connection is to a database such as utility_db, which has a page size of 1024. This restriction may cause RESTORE DATABASE commands that reference numerous dbspaces to fail. To avoid the problem, make sure the length of SQL command lines is less than the catalog page size.

Alternatively, start the engine with -gp 32768 to increase catalog page size.

Side effects:
  • Automatic commit

Standards

(back to top)

  • SQL—Vendor extension to ISO/ANSI SQL grammar.
  • SAP Sybase Database product—Adaptive Server provides a CREATE DATABASE statement, but with different options.

Permissions

(back to top)

The permissions required to execute this statement are set using the -gu server command line option, as follows:
  • NONENo user can issue this statement.
  • DBARequires the SERVER OPERATOR system privilege.
  • UTILITY_DBOnly those users who can connect to the utility_db database can issue this statement.

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

Related reference
CREATE DBSPACE Statement
DROP DATABASE Statement