MySQL :: MySQL 8.4 Reference Manual :: 11.2.2 Identifier Qualifiers (original) (raw)

11.2.2 Identifier Qualifiers

Object names may be unqualified or qualified. An unqualified name is permitted in contexts where interpretation of the name is unambiguous. A qualified name includes at least one qualifier to clarify the interpretive context by overriding a default context or providing missing context.

For example, this statement creates a table using the unqualified name t1:

CREATE TABLE t1 (i INT);

Because t1 includes no qualifier to specify a database, the statement creates the table in the default database. If there is no default database, an error occurs.

This statement creates a table using the qualified namedb1.t1:

CREATE TABLE db1.t1 (i INT);

Because db1.t1 includes a database qualifierdb1, the statement createst1 in the database nameddb1, regardless of the default database. The qualifier must be specified if there is no default database. The qualifier may be specified if there is a default database, to specify a database different from the default, or to make the database explicit if the default is the same as the one specified.

Qualifiers have these characteristics:

The permitted qualifiers for object names depend on the object type:

CREATE DATABASE db1;  
CREATE TABLE mytable ...;  
CREATE VIEW myview ...;  
CREATE PROCEDURE myproc ...;  
CREATE FUNCTION myfunc ...;  
CREATE EVENT myevent ...;  
CREATE TABLE mydb.mytable ...;  
CREATE VIEW mydb.myview ...;  
CREATE PROCEDURE mydb.myproc ...;  
CREATE FUNCTION mydb.myfunc ...;  
CREATE EVENT mydb.myevent ...;  
CREATE TRIGGER mytrigger ... ON mytable ...;  
CREATE TRIGGER mytrigger ... ON mydb.mytable ...;  
SELECT c1 FROM mytable  
WHERE c2 > 100;  
SELECT mytable.c1 FROM mytable  
WHERE mytable.c2 > 100;  
SELECT mydb.mytable.c1 FROM mydb.mytable  
WHERE mydb.mytable.c2 > 100;  

You need not specify a qualifier for an object reference in a statement unless the unqualified reference is ambiguous. Suppose that column c1 occurs only in tablet1, c2 only int2, and c in botht1 and t2. Any unqualified reference to c is ambiguous in a statement that refers to both tables and must be qualified ast1.c or t2.c to indicate which table you mean:

SELECT c1, c2, t1.c FROM t1 INNER JOIN t2
WHERE t2.c > 100;

Similarly, to retrieve from a table t in database db1 and from a tablet in database db2 in the same statement, you must qualify the table references: For references to columns in those tables, qualifiers are required only for column names that appear in both tables. Suppose that column c1 occurs only in tabledb1.t, c2 only indb2.t, and c in bothdb1.t and db2.t. In this case, c is ambiguous and must be qualified but c1 and c2 need not be:

SELECT c1, c2, db1.t.c FROM db1.t INNER JOIN db2.t
WHERE db2.t.c > 100;

Table aliases enable qualified column references to be written more simply:

SELECT c1, c2, t1.c FROM db1.t AS t1 INNER JOIN db2.t AS t2
WHERE t2.c > 100;