In MySQL, databases correspond to directories within the data
        directory. Each table within a database corresponds to at least
        one file within the database directory (and possibly more,
        depending on the storage engine). Triggers also correspond to
        files. Consequently, the case sensitivity of the underlying
        operating system plays a part in the case sensitivity of
        database, table, and trigger names. This means such names are
        not case-sensitive in Windows, but are case-sensitive in most
        varieties of Unix. One notable exception is macOS, which is
        Unix-based but uses a default file system type (HFS+) that is
        not case-sensitive. However, macOS also supports UFS volumes,
        which are case-sensitive just as on any Unix. See
        Section 1.6.1, “MySQL Extensions to Standard SQL”. The
        lower_case_table_names system
        variable also affects how the server handles identifier case
        sensitivity, as described later in this section.
          Although database, table, and trigger names are not
          case-sensitive on some platforms, you should not refer to one
          of these using different cases within the same statement. The
          following statement would not work because it refers to a
          table both as my_table and as
          MY_TABLE:
        
mysql> SELECT * FROM my_table WHERE MY_TABLE.col=1;Partition, subpartition, column, index, stored routine, event, and resource group names are not case-sensitive on any platform, nor are column aliases.
However, names of logfile groups are case-sensitive. This differs from standard SQL.
        By default, table aliases are case-sensitive on Unix, but not so
        on Windows or macOS. The following statement would not work on
        Unix, because it refers to the alias both as
        a and as A:
      
mysql> SELECT col_name FROM tbl_name AS a
       WHERE a.col_name = 1 OR A.col_name = 2;However, this same statement is permitted on Windows. To avoid problems caused by such differences, it is best to adopt a consistent convention, such as always creating and referring to databases and tables using lowercase names. This convention is recommended for maximum portability and ease of use.
        How table and database names are stored on disk and used in
        MySQL is affected by the
        lower_case_table_names system
        variable.
        lower_case_table_names can take
        the values shown in the following table. This variable does
        not affect case sensitivity of trigger
        identifiers. On Unix, the default value of
        lower_case_table_names is 0. On
        Windows, the default value is 1. On macOS, the default value is
        2.
      
        lower_case_table_names can only
        be configured when initializing the server. Changing the
        lower_case_table_names setting
        after the server is initialized is prohibited.
| Value | Meaning | 
|---|---|
| 0 | Table and database names are stored on disk using the lettercase
              specified in the CREATE
              TABLEorCREATE
              DATABASEstatement. Name comparisons are
              case-sensitive. You should not set
              this variable to 0 if you are running MySQL on a system
              that has case-insensitive file names (such as Windows or
              macOS). If you force this variable to 0 with--lower-case-table-names=0on a case-insensitive file system and accessMyISAMtablenames using different
              lettercases, index corruption may result. | 
| 1 | Table names are stored in lowercase on disk and name comparisons are not case-sensitive. MySQL converts all table names to lowercase on storage and lookup. This behavior also applies to database names and table aliases. | 
| 2 | Table and database names are stored on disk using the lettercase
              specified in the CREATE
              TABLEorCREATE
              DATABASEstatement, but MySQL converts them to
              lowercase on lookup. Name comparisons are not
              case-sensitive. This works only on
              file systems that are not case-sensitive!InnoDBtable names and view names are
              stored in lowercase, as forlower_case_table_names=1. | 
        If you are using MySQL on only one platform, you do not normally
        have to use a
        lower_case_table_names setting
        other than the default. However, you may encounter difficulties
        if you want to transfer tables between platforms that differ in
        file system case sensitivity. For example, on Unix, you can have
        two different tables named my_table and
        MY_TABLE, but on Windows these two names are
        considered identical. To avoid data transfer problems arising
        from lettercase of database or table names, you have two
        options:
- Use - lower_case_table_names=1on all systems. The main disadvantage with this is that when you use- SHOW TABLESor- SHOW DATABASES, you do not see the names in their original lettercase.
- Use - lower_case_table_names=0on Unix and- lower_case_table_names=2on Windows. This preserves the lettercase of database and table names. The disadvantage of this is that you must ensure that your statements always refer to your database and table names with the correct lettercase on Windows. If you transfer your statements to Unix, where lettercase is significant, they do not work if the lettercase is incorrect.- Exception: If you are using - InnoDBtables and you are trying to avoid these data transfer problems, you should use- lower_case_table_names=1on all platforms to force names to be converted to lowercase.
        Object names may be considered duplicates if their uppercase
        forms are equal according to a binary collation. That is true
        for names of cursors, conditions, procedures, functions,
        savepoints, stored routine parameters, stored program local
        variables, and plugins. It is not true for names of columns,
        constraints, databases, partitions, statements prepared with
        PREPARE, tables, triggers, users,
        and user-defined variables.
      
        File system case sensitivity can affect searches in string
        columns of INFORMATION_SCHEMA tables. For
        more information, see
        Section 12.8.7, “Using Collation in INFORMATION_SCHEMA Searches”.