|
| 1 | +--- |
| 2 | +title: "Guide: Handle upstream schema changes with zero downtime" |
| 3 | +description: "How to add a column, or drop a column, from your source PostgreSQL database, without any downtime in Materialize" |
| 4 | + |
| 5 | +menu: |
| 6 | + main: |
| 7 | + parent: "postgresql" |
| 8 | + weight: 85 |
| 9 | + |
| 10 | +--- |
| 11 | + |
| 12 | +{{< private-preview />}} |
| 13 | +{{< note >}} |
| 14 | +Changing column types is currently unsupported. |
| 15 | +{{< /note >}} |
| 16 | + |
| 17 | +Starting in v26.0.0, Materialize allows you to handle certain types of upstream |
| 18 | +table schema changes seamlessly, specifically: |
| 19 | + |
| 20 | +- Adding a column in the upstream database. |
| 21 | +- Dropping a column in the upstream database. |
| 22 | + |
| 23 | +This guide walks you through how to handle these changes without any downtime in Materialize. |
| 24 | + |
| 25 | +## Prerequisites |
| 26 | + |
| 27 | +Some familiarity with Materialize. If you've never used Materialize before, |
| 28 | +start with our [guide to getting started](/get-started/quickstart/) to learn |
| 29 | +how to connect a database to Materialize. |
| 30 | + |
| 31 | +### Set up a PostgreSQL database |
| 32 | + |
| 33 | +For this guide, setup a PostgreSQL 11+ database. In your PostgreSQL, create a |
| 34 | +table `T` and populate: |
| 35 | + |
| 36 | +```sql |
| 37 | +CREATE TABLE T ( |
| 38 | + A INT |
| 39 | +); |
| 40 | + |
| 41 | +INSERT INTO T (A) VALUES |
| 42 | + (10); |
| 43 | +``` |
| 44 | + |
| 45 | +### Connect your source database to Materialize |
| 46 | + |
| 47 | +{{< include-md file="shared-content/postgres-source-prereq.md" >}} |
| 48 | + |
| 49 | +## Create a source using the new syntax |
| 50 | + |
| 51 | +In Materialize, create a source using the updated [`CREATE SOURCE` |
| 52 | +syntax](/sql/create-source/postgres-v2/). |
| 53 | + |
| 54 | +```sql |
| 55 | +CREATE SOURCE IF NOT EXISTS my_source |
| 56 | + FROM POSTGRES CONNECTION my_connection (PUBLICATION 'mz_source'); |
| 57 | +``` |
| 58 | + |
| 59 | +Unlike the [legacy syntax](/sql/create-source/postgres/), the new syntax does |
| 60 | +not include the `FOR [[ALL] TABLES|SCHEMAS]` clause; i.e., the new syntax does |
| 61 | +not create corresponding subsources in Materialize automatically. Instead, the |
| 62 | +new syntax requires a separate [`CREATE TABLE ... FROM |
| 63 | +SOURCE`](/sql/create-table/), which will create the corresponding tables and |
| 64 | +start the snapshotting process. See [Create a table from the |
| 65 | +source](#create-a-table-from-the-source). |
| 66 | + |
| 67 | +{{< note >}} |
| 68 | +The [legacy syntax](/sql/create-source/postgres/) is still supported. However, |
| 69 | +the legacy syntax doesn't support upstream schema changes. |
| 70 | +{{< /note >}} |
| 71 | + |
| 72 | +## Create a table from the source |
| 73 | +To start ingesting specific tables from your source database, you can create a |
| 74 | +table in Materialize. We'll add it into the v1 schema in Materialize. |
| 75 | + |
| 76 | +```sql |
| 77 | +CREATE SCHEMA v1; |
| 78 | + |
| 79 | +CREATE TABLE v1.T |
| 80 | + FROM SOURCE my_source(REFERENCE public.T); |
| 81 | +``` |
| 82 | + |
| 83 | +Once you've created a table from source, the [initial |
| 84 | +snapshot](/ingest-data/#snapshotting) of table `v1.T` will begin. |
| 85 | + |
| 86 | +{{< note >}} |
| 87 | + |
| 88 | +During the snapshotting, the data ingestion for the other tables associated with |
| 89 | +the source is temporarily blocked. As before, you can monitor progress for the |
| 90 | +snapshot operation on the overview page for the source in the Materialize |
| 91 | +console. |
| 92 | + |
| 93 | +{{< /note >}} |
| 94 | + |
| 95 | +## Create a view on top of the table. |
| 96 | + |
| 97 | +For this guide, add a materialized view `matview` (also in schema `v1`) that |
| 98 | +sums column `A` from table `T`. |
| 99 | + |
| 100 | +```sql |
| 101 | +CREATE MATERIALIZED VIEW v1.matview AS |
| 102 | + SELECT SUM(A) from v1.T; |
| 103 | +``` |
| 104 | + |
| 105 | +## Handle upstream column addition |
| 106 | + |
| 107 | +### A. Add a column in your upstream PostgreSQL database |
| 108 | + |
| 109 | +In your upstream PostgreSQL database, add a new column `B` to the table `T`: |
| 110 | + |
| 111 | +```sql |
| 112 | +ALTER TABLE T |
| 113 | + ADD COLUMN B BOOLEAN DEFAULT false; |
| 114 | + |
| 115 | +INSERT INTO T (A, B) VALUES |
| 116 | + (20, true); |
| 117 | +``` |
| 118 | + |
| 119 | +This operation will have no immediate effect in Materialize. In Materialize, |
| 120 | +`v1.T` will continue to ingest only column `A`. The materialized view |
| 121 | +`v1.matview` will continue to have access to column `A` as well. |
| 122 | + |
| 123 | +### B. Incorporate the new column in Materialize |
| 124 | + |
| 125 | +To incorporate the new column into Materialize, create a new `v2` schema and |
| 126 | +recreate the table in the new schema: |
| 127 | + |
| 128 | +```sql |
| 129 | +CREATE SCHEMA v2; |
| 130 | + |
| 131 | +CREATE TABLE v2.T |
| 132 | + FROM SOURCE my_source(REFERENCE public.T); |
| 133 | +``` |
| 134 | + |
| 135 | +The [snapshotting](/ingest-data/#snapshotting) of table `v2.T` will begin. |
| 136 | +`v2.T` will include columns `A` and `B`. |
| 137 | + |
| 138 | +{{< note >}} |
| 139 | + |
| 140 | +During the snapshotting, the data ingestion for the other tables associated with |
| 141 | +the source is temporarily blocked. As before, you can monitor progress for the |
| 142 | +snapshot operation on the overview page for the source in the Materialize |
| 143 | +console. |
| 144 | + |
| 145 | +{{< /note >}} |
| 146 | + |
| 147 | + |
| 148 | +When the new `v2.T` table has finished snapshotting, create a new materialized |
| 149 | +view `matview` in the new schema. Since the new `v2.matview` is referencing the |
| 150 | +new `v2.T`, it can reference column `B`: |
| 151 | + |
| 152 | +```sql {hl_lines="4"} |
| 153 | +CREATE MATERIALIZED VIEW v2.matview AS |
| 154 | + SELECT SUM(A) |
| 155 | + FROM v2.T |
| 156 | + WHERE B = true; |
| 157 | +``` |
| 158 | + |
| 159 | +## Handle upstream column drop |
| 160 | + |
| 161 | +### A. Exclude the column in Materialize |
| 162 | + |
| 163 | +To drop a column safely, in Materialize, first, create a new `v3` schema, and |
| 164 | +recreate table `T` in the new schema but exclude the column to drop. In this |
| 165 | +example, we'll drop the column B. |
| 166 | + |
| 167 | +```sql |
| 168 | +CREATE SCHEMA v3; |
| 169 | +CREATE TABLE v3.T |
| 170 | + FROM SOURCE my_source(REFERENCE public.T) WITH (EXCLUDE COLUMNS (B)); |
| 171 | +``` |
| 172 | + |
| 173 | +{{< note >}} |
| 174 | + |
| 175 | +During the snapshotting, the data ingestion for the other tables associated with |
| 176 | +the source is temporarily blocked. As before, you can monitor progress for the |
| 177 | +snapshot operation on the overview page for the source in the Materialize |
| 178 | +console. |
| 179 | + |
| 180 | +{{< /note >}} |
| 181 | + |
| 182 | +### B. Drop a column in your upstream PostgreSQL database |
| 183 | + |
| 184 | +In your upstream PostgreSQL database, drop the column `B` from the table `T`: |
| 185 | + |
| 186 | +```sql |
| 187 | +ALTER TABLE T DROP COLUMN B; |
| 188 | +``` |
| 189 | + |
| 190 | +Dropping the column B will have no effect on `v3.T`. |
| 191 | + |
| 192 | +## Optional: Swap schemas |
| 193 | + |
| 194 | +When you're ready to fully cut over to the new source version, you can optionally swap the schemas and drop the old objects. |
| 195 | + |
| 196 | +```sql |
| 197 | +ALTER SCHEMA v1 SWAP WITH v3; |
| 198 | + |
| 199 | +DROP SCHEMA v3 CASCADE; |
| 200 | +``` |
0 commit comments