CREATE DATABASE

CREATE DATABASE — create a new database

Synopsis

CREATE DATABASE name
    [ [ WITH ] [ OWNER [=] user_name ]
           [ TEMPLATE [=] template ]
           [ ENCODING [=] encoding ]
           [ LOCALE [=] locale ]
           [ LC_COLLATE [=] lc_collate ]
           [ LC_CTYPE [=] lc_ctype ]
           [ TABLESPACE [=] tablespace_name ]
           [ ALLOW_CONNECTIONS [=] allowconn ]
           [ CONNECTION LIMIT [=] connlimit ]
           [ IS_TEMPLATE [=] istemplate ] ]
           [ LIGHTDB_SYNTAX_COMPATIBLE_TYPE [=] compa_type ] ]
           [ LIGHTDB_MYSQL_LOWER_CASE_TABLE_NAMES [=] mysql_lower_case ] ]
           [ LIGHTDB_ASCII_ZERO_STORE_VALUE [=] ascii_zero_store_value ] ]

Description

CREATE DATABASE creates a new LightDB database.

To create a database, you must be a superuser or have the special CREATEDB privilege. See CREATE ROLE.

Before LightDB 23.4, by default, the new database will be created by cloning the standard system database template1. Starting from LightDB 23.4, the standard system database is not template1 anymore, it will be one of template_pg, template_oracle or template_mysql.

Table 315. Different syntax compatible mode LIGHTDB_SYNTAX_COMPATIBLE_TYPE support different template:

TemplateLIGHTDB_SYNTAX_COMPATIBLE_TYPE
offoraclemysql
template0supportsupportsupport
template1not supportnot supportnot support
template_pgsupportnot supportnot support
template_oraclenot supportsupportnot support
template_mysqlnot supportnot supportsupport

The syntax compatible mode of the database must be one of off, oracle or mysql when be created. If the syntax compatible mode and the template are incompatible, an error will be reported. If the GUC parameter lightdb_ignore_template_compatible_type_mismatch have be set as true, the template option will be ignored, and the syntax compatible mode off, oracle and mysql will use template_pg, template_oracle and template_mysql as default templates in turn.

A different template can be specified by writing TEMPLATE name. In particular, by writing TEMPLATE template0, you can create a pristine database (one where no user-defined objects exist and where the system objects have not been altered) containing only the standard objects predefined by your version of LightDB. This is useful if you wish to avoid copying any installation-local objects that might have been added to the standard system database.

Please be aware that if a user-created template is provided during the database creation process, the compatibility mode check is bypassed.

Parameters

name

The name of a database to create.

user_name

The role name of the user who will own the new database, or DEFAULT to use the default (namely, the user executing the command). To create a database owned by another role, you must be a direct or indirect member of that role, or be a superuser.

template

The name of the template from which to create the new database, or DEFAULT to use the default template (template1).

encoding

Character set encoding to use in the new database. Specify a string constant (e.g., 'SQL_ASCII'), or an integer encoding number, or DEFAULT to use the default encoding (namely, the encoding of the template database). The character sets supported by the LightDB server are described in Section 21.3.1. See below for additional restrictions.

locale

This is a shortcut for setting LC_COLLATE and LC_CTYPE at once. If you specify this, you cannot specify either of those parameters.

Tip

The other locale settings lc_messages, lc_monetary, lc_numeric, and lc_time are not fixed per database and are not set by this command. If you want to make them the default for a specific database, you can use ALTER DATABASE ... SET.

lc_collate

Collation order (LC_COLLATE) to use in the new database. This affects the sort order applied to strings, e.g., in queries with ORDER BY, as well as the order used in indexes on text columns. The default is to use the collation order of the template database. See below for additional restrictions.

lc_ctype

Character classification (LC_CTYPE) to use in the new database. This affects the categorization of characters, e.g., lower, upper and digit. The default is to use the character classification of the template database. See below for additional restrictions.

tablespace_name

The name of the tablespace that will be associated with the new database, or DEFAULT to use the template database's tablespace, since 22.3, default tablespace is users. This tablespace will be the default tablespace used for objects created in this database. See CREATE TABLESPACE for more information.

allowconn

If false then no one can connect to this database. The default is true, allowing connections (except as restricted by other mechanisms, such as GRANT/REVOKE CONNECT).

connlimit

How many concurrent connections can be made to this database. -1 (the default) means no limit.

istemplate

If true, then this database can be cloned by any user with CREATEDB privileges; if false (the default), then only superusers or the owner of the database can clone it.

compa_type

If the values is oracle, then this database can use some oracle's features. If the values is mysql, then this database can use some mysql's features. If the values is off, then this database can not use above features. The default value is specified by lightdb_syntax_compatible_type

For more information about oracle's features and mysql's features, See lightdb_dblevel_syntax_compatible_type

mysql_lower_case

In MySQL compatibility mode, whether to enable the all-lowercase feature of table names. The mysql_lower_case value is one of (1, true, on, 0, false, off), the default value is 1. (1,true,on): enable (0,false,off): disable

ascii_zero_store_value

Lightdb 23.3 introduced a new database level GUC parameter lightdb_ascii_zero_store_value, the value must be within the valid range of 0 to 32, inclusive of both 0 and 32, it is a database level GUC parameter, it could not be changed once the database be created.

For more information about GUC lightdb_ascii_zero_store_value, See lightdb_ascii_zero_store_value

Optional parameters can be written in any order, not only the order illustrated above.

Notes

CREATE DATABASE cannot be executed inside a transaction block.

Errors along the line of could not initialize database directory are most likely related to insufficient permissions on the data directory, a full disk, or other file system problems.

Use DROP DATABASE to remove a database.

The program createdb is a wrapper program around this command, provided for convenience.

Database-level configuration parameters (set via ALTER DATABASE) and database-level permissions (set via GRANT) are not copied from the template database.

Although it is possible to copy a database other than the standard system database by specifying its name as the template, this is not (yet) intended as a general-purpose COPY DATABASE facility. The principal limitation is that no other sessions can be connected to the template database while it is being copied. CREATE DATABASE will fail if any other connection exists when it starts; otherwise, new connections to the template database are locked out until CREATE DATABASE completes. See Section 20.3 for more information.

The character set encoding specified for the new database must be compatible with the chosen locale settings (LC_COLLATE and LC_CTYPE). If the locale is C (or equivalently POSIX), then all encodings are allowed, but for other locale settings there is only one encoding that will work properly. CREATE DATABASE will allow superusers to specify SQL_ASCII encoding regardless of the locale settings, but this choice is deprecated and may result in misbehavior of character-string functions if data that is not encoding-compatible with the locale is stored in the database.

The encoding and locale settings must match those of the template database, except when template0 is used as template. This is because other databases might contain data that does not match the specified encoding, or might contain indexes whose sort ordering is affected by LC_COLLATE and LC_CTYPE. Copying such data would result in a database that is corrupt according to the new settings. template0, however, is known to not contain any data or indexes that would be affected.

The CONNECTION LIMIT option is only enforced approximately; if two new sessions start at about the same time when just one connection slot remains for the database, it is possible that both will fail. Also, the limit is not enforced against superusers or background worker processes.

Since version 23.1, LightDB supports the creation of users with the same name when the CREATE DATABASE command is executed. This feature takes effect only in oracle compatibility mode and does not support distribution. The automatically created user with the same name has the CREATE、CONNECT、TEMPORARY and LOGIN permission for the created database.

Examples

To create a new database:

CREATE DATABASE lusiadas;

To create a database sales owned by user salesapp with a default tablespace of salesspace:

CREATE DATABASE sales OWNER salesapp TABLESPACE salesspace;

To create a database music with a different locale:

CREATE DATABASE music
    LOCALE 'sv_SE.utf8'
    TEMPLATE template0;

In this example, the TEMPLATE template0 clause is required if the specified locale is different from the one in template1. (If it is not, then specifying the locale explicitly is redundant.)

To create a database music2 with a different locale and a different character set encoding:

CREATE DATABASE music2
    LOCALE 'sv_SE.iso885915'
    ENCODING LATIN9
    TEMPLATE template0;

The specified locale and encoding settings must match, or an error will be reported.

Note that locale names are specific to the operating system, so that the above commands might not work in the same way everywhere.

Query the list of databases and the list of users before creating database testdb:

lightdb@postgres=# \l
                                List of databases
   Name          |  Owner  | Encoding |   Collate   |    Ctype    |  Access privileges
-----------------+---------+----------+-------------+-------------+---------------------
 lt_test         | lightdb | UTF8     | zh_CN.UTF-8 | zh_CN.UTF-8 |
 postgres        | lightdb | UTF8     | zh_CN.UTF-8 | zh_CN.UTF-8 |
 template0       | lightdb | UTF8     | zh_CN.UTF-8 | zh_CN.UTF-8 | =c/lightdb         +
                 |         |          |             |             | lightdb=CTc/lightdb
 template1       | lightdb | UTF8     | zh_CN.UTF-8 | zh_CN.UTF-8 | =c/lightdb         +
                 |         |          |             |             | lightdb=CTc/lightdb
 template_pg     | lightdb | UTF8     | zh_CN.UTF-8 | zh_CN.UTF-8 | =c/lightdb         +
                 |         |          |             |             | lightdb=CTc/lightdb
 template_mysql  | lightdb | UTF8     | zh_CN.UTF-8 | zh_CN.UTF-8 | =c/lightdb         +
                 |         |          |             |             | lightdb=CTc/lightdb
 template_oracle | lightdb | UTF8     | zh_CN.UTF-8 | zh_CN.UTF-8 | =c/lightdb         +
                 |         |          |             |             | lightdb=CTc/lightdb
(7 rows)

lightdb@postgres=# 
lightdb@postgres=# \du
                                   List of roles
 Role name |                         Attributes                         | Member of 
-----------+------------------------------------------------------------+-----------
 lightdb   | Superuser, Create role, Create DB, Replication, Bypass RLS | {}

lightdb@postgres=# 

To create a database in oracle compatibility mode:

lightdb@postgres=# create database testdb with lightdb_syntax_compatible_type oracle;
NOTICE:  auto create user "testdb" success
CREATE DATABASE
lightdb@postgres=# 

Query the database list and user list again:

lightdb@postgres=# \l
                                List of databases
   Name          |  Owner  | Encoding |   Collate   |    Ctype    |  Access privileges
-----------------+---------+----------+-------------+-------------+---------------------
 lt_test         | lightdb | UTF8     | zh_CN.UTF-8 | zh_CN.UTF-8 |
 postgres        | lightdb | UTF8     | zh_CN.UTF-8 | zh_CN.UTF-8 |
 template0       | lightdb | UTF8     | zh_CN.UTF-8 | zh_CN.UTF-8 | =c/lightdb         +
                 |         |          |             |             | lightdb=CTc/lightdb
 template1       | lightdb | UTF8     | zh_CN.UTF-8 | zh_CN.UTF-8 | =c/lightdb         +
                 |         |          |             |             | lightdb=CTc/lightdb
 template_pg     | lightdb | UTF8     | zh_CN.UTF-8 | zh_CN.UTF-8 | =c/lightdb         +
                 |         |          |             |             | lightdb=CTc/lightdb
 template_mysql  | lightdb | UTF8     | zh_CN.UTF-8 | zh_CN.UTF-8 | =c/lightdb         +
                 |         |          |             |             | lightdb=CTc/lightdb
 template_oracle | lightdb | UTF8     | zh_CN.UTF-8 | zh_CN.UTF-8 | =c/lightdb         +
                 |         |          |             |             | lightdb=CTc/lightdb
 testdb          | lightdb | UTF8     | zh_CN.UTF-8 | zh_CN.UTF-8 | =Tc/lightdb        +
                 |         |          |             |             | lightdb=CTc/lightdb+
                 |         |          |             |             | testdb=CTc/lightdb
(8 rows)

lightdb@postgres=# 
lightdb@postgres=# \du
                                   List of roles
 Role name |                         Attributes                         | Member of 
-----------+------------------------------------------------------------+-----------
 lightdb   | Superuser, Create role, Create DB, Replication, Bypass RLS | {}
 testdb    |                                                            | {}

lightdb@postgres=# 

Compatibility

There is no CREATE DATABASE statement in the SQL standard. Databases are equivalent to catalogs, whose creation is implementation-defined.

See Also

ALTER DATABASE, DROP DATABASE