diff --git a/docs/concepts/deploy-requests.md b/docs/concepts/deploy-requests.md index e2d77106..2e43abb1 100644 --- a/docs/concepts/deploy-requests.md +++ b/docs/concepts/deploy-requests.md @@ -32,7 +32,7 @@ Once you create a deploy request, you or your team can review it and, optionally PlanetScale will check if the request is deployable. This process includes checking for issues like: -- [Missing unique keys](/docs/learn/change-single-unique-key) +- [Incompatible unique keys](/docs/learn/onlineddl-change-unique-keys) - Invalid charsets (PlanetScale supports `utf8`, `utf8mb4`, `utf8mb3`, `latin1`, and `ascii`) - Invalid foreign key constraint names or lengths - And other various checks to ensure successful schema changes diff --git a/docs/imports/database-imports.md b/docs/imports/database-imports.md index 2978c753..c3014ffd 100644 --- a/docs/imports/database-imports.md +++ b/docs/imports/database-imports.md @@ -186,7 +186,7 @@ Below are a few common errors you may encounter while importing or connecting to #### No unique key -PlanetScale requires that all tables have a unique, not-null key that remains unchanged during the migration. If you run into this error, read through our [Change single unique key documentation](/docs/learn/change-single-unique-key#how-to-change-a-tables-single-unique-key) for more information. +PlanetScale requires that all tables have a unique, not-null key. When you modify a table, both the old and the new schema must have a unique key as described, and the columns covered by those keys must exist in both the old and the new schema. If you run into this error, read through our [Changing unique keys documentation](/docs/learn/onlineddl-change-unique-keys) for more information. It may also help to check out the official [MySQL documentation about Primary Keys](https://dev.mysql.com/doc/refman/8.0/en/partitioning-limitations-partitioning-keys-unique-keys.html). diff --git a/docs/learn/change-single-unique-key.md b/docs/learn/change-single-unique-key.md deleted file mode 100644 index 4f5685e8..00000000 --- a/docs/learn/change-single-unique-key.md +++ /dev/null @@ -1,59 +0,0 @@ ---- -title: 'Change single unique key' -subtitle: "Three step process for changing a table's single unique or primary key" -date: '2022-08-01' ---- - -## Overview - -To migrate data safely and [without downtime](/docs/concepts/nonblocking-schema-changes), PlanetScale requires that all tables have a unique, not-null key that remains unchanged during the migration. This requirement can cause difficulty if, for example, you attempt to ALTER the primary key of a table with no other unique keys. - -If you attempt to deploy such a schema change, the deploy request will fail with the error `All tables must have at least one unique, not-null key that remains unchanged during the migration`. - -{% callout %} -This example adds a temporary unique key but you could also use a unique index -or create the temporary key by adding a unique constraint. -{% /callout %} - -## How to change a table's single unique key - -Altering a single unique key can be accomplished in 3 steps. Each step is a [separate deploy request](/docs/concepts/branching#how-to-deploy-a-branch). - -1. Add a temporary unique key. To change a lone unique key you will first need to add another unique key that PlanetScale can use during the migration. In a new branch, add a new key on a unique column or combination of columns. The target columns should not contain null values. - - ```sql - ALTER TABLE table_name ADD UNIQUE KEY temp_unique_key (`column`,`column2`); - ``` - - Deploy this change via a deploy request. - -2. Alter the original key. Now that you have a second unique key, you can alter the original key. In a new branch, apply your intended schema change. - - Our example drops the existing primary key and replaces it with a compound primary key. - - ```sql - ALTER TABLE table_name DROP PRIMARY KEY, ADD PRIMARY KEY(`column`,`column2`); - ``` - - Deploy this change via a deploy request. - -3. Drop the temporary unique key. After the primary key has been updated, you can remove the temporary unique key that you added in Step 1. - - In a new branch, drop the temporary key. - - ```sql - ALTER TABLE table_name DROP KEY temp_unique_key; - ``` - - Once this deploy request has been deployed, you will have changed your table's unique primary key and removed the temporary unique key created in step 1. - -## Why? - -PlanetScale non-blocking schema changes works by first creating a ghost table, in the likeness of your original table. The ghost table is then altered to match your changed schema. -We copy over the data from the original table, as well as stream any changes as they happen to the ghost table. Once this ghost table is in sync with the original, we swap the tables in place. This safely completes the migration. - -To do this, we need to have a consistent primary or unique key across both of the tables to reliably replicate the data over. This is why we require a consistent key when migrating your data. - -## Summary - -This tutorial provides a three step process for updating a table's single unique key and can be repeated as often as needed. diff --git a/docs/learn/onlineddl-change-unique-keys.md b/docs/learn/onlineddl-change-unique-keys.md new file mode 100644 index 00000000..3e3b27f0 --- /dev/null +++ b/docs/learn/onlineddl-change-unique-keys.md @@ -0,0 +1,134 @@ +--- +title: 'Online DDL change unique keys' +subtitle: 'Supported scenarios for modifying primary and unique keys and solutions for cases where the change is too big.' +date: '2023-04-16' +--- + +## Overview + +It is possible to modify or replace a table's `PRIMARY KEY`, or any other `UNIQUE KEY`s according to the limitation described below, followed by examples. + +To migrate data safely and [without downtime](/docs/concepts/nonblocking-schema-changes), PlanetScale requires that all tables have a unique, not-null key. Note that a `PRIMARY KEY` satisfies this condition, and it is generally recommended to always have a `PRIMARY KEY` on all tables. + +When you modify a table, both the old and the new schema must have a unique key as described, and the columns covered by those keys must exist in both the old and the new schema. + +Essentially this makes it possible for PlanetScale to unambiguously identify and correlate a row between the two schemas. + +If you attempt to deploy a schema change which does not comply with the above restriction, the deploy request will fail with the error `Table ... has no shared columns covered by non-null unique keys between both branches.`. + +## Examples: allowed changes + +In our examples, we assume the base schema to be: + +```sql +CREATE TABLE `users` ( + `id` int, + `other_info` int, + `username` varchar(128), + `email` varchar(128), + PRIMARY KEY (`id`) +); +``` + +The following are all valid changes to the schema: + +### Expanding the PRIMARY KEY + +```sql +CREATE TABLE `users` ( + `id` int, + `other_info` int, + `username` varchar(128), + `email` varchar(128), + PRIMARY KEY (`id`, `other_info`) +); +``` + +In the above we modified the `PRIMARY KEY` to include `other_info`. This is allowed since both `id` and `other_info` columns exist in both the old and the new schema. + +### Moving PRIMARY KEY to a different column + +```sql +CREATE TABLE `users` ( + `id` int, + `other_info` int, + `username` varchar(128), + `email` varchar(128), + PRIMARY KEY (`email`) +); +``` + +Since both `id` and `email` columns exist in both old and new schema, the deploy request will be allowed. The success of the operation depends on whether `email` actually contains unique values. If there's duplication in `email` values, the deployment will fail with error. + +### Moving PRIMARY KEY to different columns + +Likewise, there is no problem if the new `PRIMARY KEY` covers multiple columns. Again, the success of the operation depends on the actual uniqueness of the combination of columns. + +```sql +CREATE TABLE `users` ( + `id` int, + `other_info` int, + `username` varchar(128), + `email` varchar(128), + PRIMARY KEY (`username`, `other_info`) +); +``` + +### Changing PRIMARY KEY and adding/removing other UNIQUE KEYs + +```sql +CREATE TABLE `users` ( + `id` int, + `other_info` int, + `username` varchar(128), + `email` varchar(128), + PRIMARY KEY (`username`, `other_info`), + UNIQUE KEY `email` (`email`) +); +``` + +## Examples: invalid changes + +Consider the next scenarios and the ways to work around them: + +### Changing a PRIMARY KEY to include a new column + +```sql +CREATE TABLE `users` ( + `id` int, + `other_info` int, + `username` varchar(128), + `email` varchar(128), + `new_info` int, + PRIMARY KEY (`username`, `new_info`) +); +``` + +This is an invalid change because in the new schema, the `PRIMARY KEY` covers the `new_info` column. But this column does not exist in the old schema. + +Consider splitting into two distinct schema changes and deploy requests: + +1. First, introduce the `new_info` column. +2. Next, change the `PRIMARY KEY`. + +### Changing a PRIMARY KEY and also dropping the old covered column + +```sql +CREATE TABLE `users` ( + `other_info` int, + `username` varchar(128), + `email` varchar(128), + PRIMARY KEY (`email`) +); +``` + +The above is invalid because `id` column, covered by the `PRIMARY KEY` in the old schema, does not exist in the new schema. + +Again, consider splitting into two distinct changes: + +1. First, change the `PRIMARY KEY`. +2. Next, drop the `id` column. + +## Summary + +We've seen how, in many scenarios, it's straightforward to modify your table's `PRIMARY KEY` or other keys. For some scenarios, it might take two or more steps to achieve the new schema. diff --git a/docs/navigation/standard.md b/docs/navigation/standard.md index 20fabf11..570d7586 100644 --- a/docs/navigation/standard.md +++ b/docs/navigation/standard.md @@ -158,8 +158,8 @@ slug: '/docs/learn/how-to-make-different-types-of-schema-changes' - label: 'Handling table and column renames' slug: '/docs/learn/handling-table-and-column-renames' - - label: 'Change single unique key' - slug: '/docs/learn/change-single-unique-key' + - label: 'Changing primary and unique keys' + slug: '/docs/learn/onlineddl-change-unique-keys' - label: 'Foreign key constraints' items: - label: 'Foreign key constraints support' diff --git a/docs/reference/mysql-compatibility.md b/docs/reference/mysql-compatibility.md index 49d1d43c..a8a180f6 100644 --- a/docs/reference/mysql-compatibility.md +++ b/docs/reference/mysql-compatibility.md @@ -51,7 +51,7 @@ If you're attempting to import a database using our Import tool, there are some | ----------------------------- | ------- | ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- | | **Empty schemas** | ❌ | Databases with empty schemas are invalid. You cannot deploy a schema change to production if no tables exist. | | **Non-InnoDB Storage engine** | ❌ | We only support [InnoDB](https://dev.mysql.com/doc/refman/8.0/en/innodb-storage-engine.html) storage engine. | -| **No unique key** | ❌ | We require all tables have a [unique, non-null key](/docs/learn/change-single-unique-key) that remains unchanged during migrations. | +| **No applicable unique key** | ❌ | We require all tables have a [unique, non-null key](/docs/learn/onlineddl-change-unique-keys) and that respective covered columns are shared between old and new schema. | | **Direct DDL** | ❌ | We do [not allow Direct DDL](/docs/learn/how-online-schema-change-tools-work) on [production branches](/docs/concepts/branching). This includes `TRUNCATE` statements. | | **Disabled binary logs** | ❗ | You must have binary logs enabled if importing a database using our [database importer tool](/docs/imports/database-imports). See our [Import doc](/docs/imports/database-imports#server-configuration-issues) for more required configuration. | | **Large JSON documents** | ❗ | MySQL supports JSON documents up to 1 GB in size. However, we do not recommend to store more than a few MB in a JSON document for performance reasons. |