Documentation Home
MySQL 8.0 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 47.0Mb
PDF (A4) - 47.1Mb
PDF (RPM) - 42.4Mb
HTML Download (TGZ) - 10.8Mb
HTML Download (Zip) - 10.9Mb
HTML Download (RPM) - 9.4Mb
Man Pages (TGZ) - 227.0Kb
Man Pages (Zip) - 333.8Kb
Info (Gzip) - 4.2Mb
Info (Zip) - 4.2Mb
Excerpts from this Manual

MySQL 8.0 Reference Manual  /  ...  /  ALTER DATABASE Statement

13.1.2 ALTER DATABASE Statement

ALTER {DATABASE | SCHEMA} [db_name]
    alter_specification ...

alter_specification:
    [DEFAULT] CHARACTER SET [=] charset_name
  | [DEFAULT] COLLATE [=] collation_name
  | DEFAULT ENCRYPTION [=] {'Y' | 'N'}

ALTER DATABASE enables you to change the overall characteristics of a database. These characteristics are stored in the data dictionary. To use ALTER DATABASE, you need the ALTER privilege on the database. ALTER SCHEMA is a synonym for ALTER DATABASE.

The database name can be omitted from the first syntax, in which case the statement applies to the default database.

National Language Characteristics

The CHARACTER SET clause changes the default database character set. The COLLATE clause changes the default database collation. Chapter 10, Character Sets, Collations, Unicode, discusses character set and collation names.

You can see what character sets and collations are available using, respectively, the SHOW CHARACTER SET and SHOW COLLATION statements. See Section 13.7.7.3, “SHOW CHARACTER SET Statement”, and Section 13.7.7.4, “SHOW COLLATION Statement”, for more information.

If you change the default character set or collation for a database, stored routines that use the database defaults must be dropped and recreated so that they use the new defaults. (In a stored routine, variables with character data types use the database defaults if the character set or collation are not specified explicitly. See Section 13.1.17, “CREATE PROCEDURE and CREATE FUNCTION Statements”.)

Encryption

The DEFAULT ENCRYPTION clause, introduced in MySQL 8.0.16, defines the default database encryption, which is inherited by tables created in the database. Changing the default encryption of the database does not alter the encryption of existing tables associated with the schema. Only newly-created tables inherit the default database encryption. An ALTER DATABASE statement executed without a DEFAULT ENCRYPTION clause retains the existing default database encryption. If the table_encryption_privilege_check variable is enabled, the TABLE_ENCRYPTION_ADMIN privilege is required to specify a default encryption setting that differs from the default_table_encryption setting. For more information, see Defining an Encryption Default for Schemas and General Tablespaces.