HomeMogDBMogDB StackUqbar
v2.1

Documentation:v2.1

Supported Versions:

CREATE DATABASE

Function

CREATE DATABASE is used to create a database. By default, the new database will be created only by cloning the standard system database template0.

Precautions

  • A user that has the CREATEDB permission or a system administrator can create a database.
  • CREATE DATABASE cannot be executed inside a transaction block.
  • During the database creation, an error message indicating that permission denied is displayed, possibly because the permission on the data directory in the file system is insufficient. If an error message, indicating no space left on device is displayed, the possible cause is that the disk space is used up.

Syntax

CreateDatabase ::= CREATE DATABASE database_name
    [ [ WITH ] { [ OWNER [=] user_name ] |
               [ TEMPLATE [=] template ] |
               [ ENCODING [=] encoding ] |
               [ LC_COLLATE [=] lc_collate ] |
               [ LC_CTYPE [=] lc_ctype ] |
               [ DBCOMPATIBILITY [=] compatibilty_type ] |
               [ TABLESPACE [=] tablespace_name ] |
               [ CONNECTION LIMIT [=] connlimit ]}[...] ];

Parameter Description

  • database_name

    Specifies the database name.

    Value range: a string. It must comply with the naming convention.

  • OWNER [ = ] user_name

    Specifies the owner of the new database. If omitted, the default owner is the current user.

    Value range: an existing username

  • TEMPLATE [ = ] template

    Specifies a template name. That is, the template from which the database is created. MogDB creates a database by copying data from a template database. MogDB has two default template databases template0 and template1 and a default user database postgres.

    Value range: template0

  • ENCODING [ = ] encoding

    Specifies the character encoding used by the database. The value can be a string (for example, SQL_ASCII) or an integer.

    If this parameter is not specified, the encoding of the template database is used by default. By default, the codes of the template databases template0 and template1 are related to the operating system environment. The character encoding of template1 cannot be changed. To change the encoding, use template0 to create a database.

    The common values are GBK, UTF8, and Latin1.

    Table 1 MogDB character set

    Name Description Language Server Or Not ICU Or Not Byte/Character Alias
    BIG5 Big Five Traditional Chinese No No 1-2 WIN950, Windows950
    EUC_CN Extended UNIX Code-CN Simplified Chinese Yes Yes 1-3 -
    EUC_JP Extended UNIX Code-JP Japanese Yes Yes 1-3 -
    EUC_JIS_2004 Extended UNIX Code-JP, JIS X 0213 Japanese Yes No 1-3 -
    EUC_KR Extended UNIX Code-KR Korean Yes Yes 1-3 -
    EUC_TW Extended UNIX Code-TW Traditional Chinese, Taiwan, China Yes Yes 1-3 -
    GB18030 National Standard Chinese Yes No 1-4 -
    GBK Extended National Standard Simplified Chinese Yes No 1-2 WIN936, Windows936
    ISO_8859_5 ISO 8859-5, ECMA 113 Latin/Cyrillic Yes Yes 1 -
    ISO_8859_6 ISO 8859-6, ECMA 114 Latin/Arabic Yes Yes 1 -
    ISO_8859_7 ISO 8859-7, ECMA 118 Latin/Greek Yes Yes 1 -
    ISO_8859_8 ISO 8859-8, ECMA 121 Latin/Hebrew Yes Yes 1 -
    JOHAB JOHAB Korean No No 1-3 -
    KOI8R KOI8-R Cyrillic (Russian) Yes Yes 1 KOI8
    KOI8U KOI8-U Cyrillic (Ukrainian) Yes Yes 1 -
    LATIN1 ISO 8859-1, ECMA 94 Western European Yes Yes 1 ISO88591
    LATIN2 ISO 8859-2, ECMA 94 Central European Yes Yes 1 ISO88592
    LATIN3 ISO 8859-3, ECMA 94 South European Yes Yes 1 ISO88593
    LATIN4 ISO 8859-4, ECMA 94 North European Yes Yes 1 ISO88594
    LATIN5 ISO 8859-9, ECMA 128 Turkish Yes Yes 1 ISO88599
    LATIN6 ISO 8859-10, ECMA 144 Nordic Yes Yes 1 ISO885910
    LATIN7 ISO 8859-13 Baltic Yes Yes 1 ISO885913
    LATIN8 ISO 8859-14 Celtic Yes Yes 1 ISO885914
    LATIN9 ISO 8859-15 LATIN1 with Euro and accents Yes Yes 1 ISO885915
    LATIN10 ISO 8859-16, ASRO SR 14111 Romanian Yes No 1 ISO885916
    MULE_INTERNAL Mule internal code Multilingual Emacs Yes No 1-4 -
    SJIS Shift JIS Japanese No No 1-2 Mskanji, ShiftJIS, WIN932, Windows932
    SHIFT_JIS_2004 Shift JIS, JIS X 0213 Japanese No No 1-2 -
    SQL_ASCII Unspecified (see the text) Any Yes No 1 -
    UHC Unified Hangul Code Korean No No 1-2 WIN949, Windows949
    UTF8 Unicode, 8-bit All Yes Yes 1-4 Unicode
    WIN866 Windows CP866 Cyrillic Yes Yes 1 ALT
    WIN874 Windows CP874 Thai Yes No 1 -
    WIN1250 Windows CP1250 Central European Yes Yes 1 -
    WIN1251 Windows CP1251 Cyrillic Yes Yes 1 WIN
    WIN1252 Windows CP1252 Western European Yes Yes 1 -
    WIN1253 Windows CP1253 Greek Yes Yes 1 -
    WIN1254 Windows CP1254 Turkish Yes Yes 1 -
    WIN1255 Windows CP1255 Hebrew Yes Yes 1 -
    WIN1256 Windows CP1256 Arabic Yes Yes 1 -
    WIN1257 Windows CP1257 Baltic Yes Yes 1 -
    WIN1258 Windows CP1258 Vietnamese Yes Yes 1 ABC, TCVN, TCVN5712, VSCII

    img CAUTION: Note that not all client APIs support the preceding character sets. The SQL_ASCII setting performs quite differently from other settings. If the character set of the server is SQL_ASCII, the server interprets the byte values 0 to 127 according to the ASCII standard. The byte values 128 to 255 are regarded as the characters that cannot be parsed. If this parameter is set to SQL_ASCII, no code conversion occurs. Therefore, this setting is not basically used to declare the specified encoding used, because this declaration ignores the encoding. In most cases, if you use any non-ASCII data, it is unwise to use the SQL_ASCII setting because MogDB will not be able to help you convert or validate non-ASCII characters.

    img NOTICE:

    • The character set encoding of the new database must be compatible with the local settings (LC_COLLATE and LC_CTYPE).
    • When the specified character encoding set is GBK, some uncommon Chinese characters cannot be directly used as object names. This is because the byte encoding overlaps with the ASCII characters @A-Z[^_`a-z{|} when the second byte of the GBK ranges from 0x40 to 0x7E. @[]^_'{|} is an operator in the database. If it is directly used as an object name, a syntax error will be reported. For example, the GBK hexadecimal code is 0x8240, and the second byte is 0x40, which is the same as the ASCII character @. Therefore, the character cannot be used as an object name. If you do need to use this function, you can add double quotation marks ("") to avoid this problem when creating and accessing objects.
    • If the client-side encoding is A and the server-side encoding is B, the conversion between encoding format A and B in the database needs to be met. For example: if the server-side encoding is gb18030, since the current database does not support the conversion between gb18030 and gbk, When the client encoding format is set to gbk, the error "Conversion between GB18030 and GBK is not supported." will be reported. For all the encoding format conversions that the database can support, see the system table pg_conversion for details.
  • LC_COLLATE [ = ] lc_collate

    Specifies the character set used by the new database. For example, set this parameter by using lc_collate = 'zh_CN.gbk'.

    The use of this parameter affects the sort order of strings (for example, the order of using ORDER BY for execution and the order of using indexes on text columns). By default, the sorting order of the template database is used.

    Value range: a valid sorting type

  • LC_CTYPE [ = ] lc_ctype

    Specifies the character class used by the new database. For example, set this parameter by using lc_ctype = 'zh_CN.gbk'. The use of this parameter affects the classification of characters, such as uppercase letters, lowercase letters, and digits. By default, the character classification of the template database is used.

    Value range: a valid character type

  • DBCOMPATIBILITY [ = ] compatibility_type

    Specifies the compatible database type. The default compatible database is Oracle.

    Value range: A, B and PG, indicating Oracle, MySQL and Postgres databases, respectively.

    img NOTE:

    • For A compatibility, the database treats empty strings as NULL and replaces DATE with TIMESTAMP(0) WITHOUT TIME ZONE.
    • When a character string is converted to an integer, if the input is invalid, the input will be converted to 0 due to B compatibility, and an error will be reported due to other compatibility issues.
    • For PG compatibility, CHAR and VARCHAR are counted by character. For other compatibility types, they are counted by byte. For example, for the UTF-8 character set, CHAR(3) can store three Chinese characters in PG compatibility scenarios, but can store only one Chinese character in other compatibility scenarios.
  • TABLESPACE [ = ] tablespace_name

    Specifies the tablespace of the database.

    Value range: an existing tablespace name

  • CONNECTION LIMIT [ = ] connlimit

    Specifies the maximum number of concurrent connections that can be made to the new database.

    img NOTICE:

    • The system administrator is not restricted by this parameter.
    • connlimit is calculated separately for each primary database node. Number of connections of MogDB = connlimit x Number of normal CN primary database nodes.

    Value range: an integer greater than or equal to -1 The default value is -1, indicating that there is no limit.

The restrictions on character encoding are as follows:

  • If the locale is set to C (or POSIX), all encoding types are allowed. For other locale settings, the character encoding must be the same as that of the locale.
  • If the character encoding mode is SQL_ASCII and the modifier is an administrator, the character encoding mode can be different from the locale setting.
  • The encoding and region settings must match the template database, except that template0 is used as a template. This is because other databases may contain data that does not match the specified encoding, or may contain indexes whose sorting order is affected by LC_COLLATE and LC_CTYPE. Copying this data will invalidate the indexes in the new database. template0 does not contain any data or indexes that may be affected.

Examples

-- Create users jim and tom.
mogdb=# CREATE USER jim PASSWORD 'xxxxxxxxx';
mogdb=# CREATE USER tom PASSWORD 'xxxxxxxxx';

-- Create database music using GBK (the local encoding type is also GBK).
mogdb=# CREATE DATABASE music ENCODING 'GBK' template = template0;

-- Create database music2 and specify user jim as its owner.
mogdb=# CREATE DATABASE music2 OWNER jim;

-- Create database music3 using template template0 and specify user jim as its owner.
mogdb=# CREATE DATABASE music3 OWNER jim TEMPLATE template0;

-- Set the maximum number of connections to database music to 10.
mogdb=# ALTER DATABASE music CONNECTION LIMIT= 10;

-- Rename database music to music4.
mogdb=# ALTER DATABASE music RENAME TO music4;

-- Change the owner of database music2 to user tom.
mogdb=# ALTER DATABASE music2 OWNER TO tom;

-- Set the tablespace of database music3 to PG_DEFAULT.
mogdb=# ALTER DATABASE music3 SET TABLESPACE PG_DEFAULT;

-- Disable the default index scan on database music3.
mogdb=# ALTER DATABASE music3 SET enable_indexscan TO off;

-- Reset the enable_indexscan parameter.
mogdb=# ALTER DATABASE music3 RESET enable_indexscan;

-- Delete the database.
mogdb=# DROP DATABASE music2;
mogdb=# DROP DATABASE music3;
mogdb=# DROP DATABASE music4;

-- Delete the jim and tom users.
mogdb=# DROP USER jim;
mogdb=# DROP USER tom;

-- Create a database compatible with the TD format.
mogdb=# CREATE DATABASE td_compatible_db DBCOMPATIBILITY 'C';

-- Create a database compatible with the A format.
mogdb=# CREATE DATABASE ora_compatible_db DBCOMPATIBILITY 'A';

-- Delete the databases that are compatible with the TD and A formats.
mogdb=# DROP DATABASE td_compatible_db;
mogdb=# DROP DATABASE ora_compatible_db;

ALTER DATABASE and DROP DATABASE

Suggestions

  • create database

    Database cannot be created in a transaction.

  • ENCODING LC_COLLATE LC_CTYPE

    If the new database Encoding, LC-Collate, or LC_Ctype does not match the template database (SQL_ASCII) ('GBK', 'UTF8', or 'LATIN1'), template [=] template0 must be specified.

Copyright © 2011-2024 www.enmotech.com All rights reserved.