From 0c4950d9456b9956556c5e0624cf2f7dc2639b9b Mon Sep 17 00:00:00 2001
From: Michael Barroco <michael@orbitalize.com>
Date: Mon, 2 Dec 2024 11:29:10 +0100
Subject: [PATCH] [yugabyte] SQL Migrations

---
 ...downfrom-v1.0.0-remove_isa_subs_tables.sql |  5 ++
 ...ownfrom-v2.0.0-remove_inverted_indices.sql | 43 ++++++++++
 .../rid/downfrom-v3.0.0-no_change.sql         |  1 +
 .../downfrom-v3.1.0-remove_writer_column.sql  |  3 +
 ...1.1-remove_index_by_time_subscriptions.sql |  2 +
 .../downfrom-v4.0.0-move_rid_to_defaultdb.sql |  7 ++
 .../upto-v1.0.0-create_isa_subs_tables.sql    | 53 ++++++++++++
 .../rid/upto-v2.0.0-add_inverted_indices.sql  | 48 +++++++++++
 .../yugabyte/rid/upto-v3.0.0-no_change.sql    |  1 +
 .../rid/upto-v3.1.0-add_writer_column.sql     |  3 +
 ...v3.1.1-add_index_by_time_subscriptions.sql |  2 +
 .../upto-v4.0.0-rename_defaultdb_to_rid.sql   |  7 ++
 ...downfrom-v1.0.0-remove_initial_version.sql |  6 ++
 ...wnfrom-v2.0.0-remove_api_1_0_0_support.sql |  5 ++
 ...ownfrom-v3.0.0-remove_inverted_indices.sql | 66 +++++++++++++++
 ...ownfrom-v3.1.0-remove_uss_availability.sql |  3 +
 .../downfrom-v3.2.0-remove_ovn_columns.sql    |  5 ++
 .../upto-v1.0.0-create_initial_version.sql    | 82 +++++++++++++++++++
 .../scd/upto-v2.0.0-support_api_1_0_0.sql     | 12 +++
 .../scd/upto-v3.0.0-add_inverted_indices.sql  | 40 +++++++++
 .../upto-v3.1.0-create_uss_availability.sql   |  8 ++
 .../scd/upto-v3.2.0-add_ovn_columns.sql       | 12 +++
 22 files changed, 414 insertions(+)
 create mode 100644 build/db_schemas/yugabyte/rid/downfrom-v1.0.0-remove_isa_subs_tables.sql
 create mode 100644 build/db_schemas/yugabyte/rid/downfrom-v2.0.0-remove_inverted_indices.sql
 create mode 100644 build/db_schemas/yugabyte/rid/downfrom-v3.0.0-no_change.sql
 create mode 100644 build/db_schemas/yugabyte/rid/downfrom-v3.1.0-remove_writer_column.sql
 create mode 100644 build/db_schemas/yugabyte/rid/downfrom-v3.1.1-remove_index_by_time_subscriptions.sql
 create mode 100644 build/db_schemas/yugabyte/rid/downfrom-v4.0.0-move_rid_to_defaultdb.sql
 create mode 100644 build/db_schemas/yugabyte/rid/upto-v1.0.0-create_isa_subs_tables.sql
 create mode 100644 build/db_schemas/yugabyte/rid/upto-v2.0.0-add_inverted_indices.sql
 create mode 100644 build/db_schemas/yugabyte/rid/upto-v3.0.0-no_change.sql
 create mode 100644 build/db_schemas/yugabyte/rid/upto-v3.1.0-add_writer_column.sql
 create mode 100644 build/db_schemas/yugabyte/rid/upto-v3.1.1-add_index_by_time_subscriptions.sql
 create mode 100644 build/db_schemas/yugabyte/rid/upto-v4.0.0-rename_defaultdb_to_rid.sql
 create mode 100644 build/db_schemas/yugabyte/scd/downfrom-v1.0.0-remove_initial_version.sql
 create mode 100644 build/db_schemas/yugabyte/scd/downfrom-v2.0.0-remove_api_1_0_0_support.sql
 create mode 100644 build/db_schemas/yugabyte/scd/downfrom-v3.0.0-remove_inverted_indices.sql
 create mode 100644 build/db_schemas/yugabyte/scd/downfrom-v3.1.0-remove_uss_availability.sql
 create mode 100644 build/db_schemas/yugabyte/scd/downfrom-v3.2.0-remove_ovn_columns.sql
 create mode 100644 build/db_schemas/yugabyte/scd/upto-v1.0.0-create_initial_version.sql
 create mode 100644 build/db_schemas/yugabyte/scd/upto-v2.0.0-support_api_1_0_0.sql
 create mode 100644 build/db_schemas/yugabyte/scd/upto-v3.0.0-add_inverted_indices.sql
 create mode 100644 build/db_schemas/yugabyte/scd/upto-v3.1.0-create_uss_availability.sql
 create mode 100644 build/db_schemas/yugabyte/scd/upto-v3.2.0-add_ovn_columns.sql

diff --git a/build/db_schemas/yugabyte/rid/downfrom-v1.0.0-remove_isa_subs_tables.sql b/build/db_schemas/yugabyte/rid/downfrom-v1.0.0-remove_isa_subs_tables.sql
new file mode 100644
index 000000000..b95bdc8e9
--- /dev/null
+++ b/build/db_schemas/yugabyte/rid/downfrom-v1.0.0-remove_isa_subs_tables.sql
@@ -0,0 +1,5 @@
+DROP TABLE IF EXISTS cells_identification_service_areas;
+DROP TABLE IF EXISTS cells_subscriptions;
+DROP TABLE IF EXISTS identification_service_areas;
+DROP TABLE IF EXISTS subscriptions;
+DROP TABLE IF EXISTS schema_versions;
diff --git a/build/db_schemas/yugabyte/rid/downfrom-v2.0.0-remove_inverted_indices.sql b/build/db_schemas/yugabyte/rid/downfrom-v2.0.0-remove_inverted_indices.sql
new file mode 100644
index 000000000..664308e7e
--- /dev/null
+++ b/build/db_schemas/yugabyte/rid/downfrom-v2.0.0-remove_inverted_indices.sql
@@ -0,0 +1,43 @@
+-- Restore cells table
+CREATE TABLE IF NOT EXISTS cells_identification_service_areas (
+    cell_id BIGINT NOT NULL, -- INT64 in CRDB.
+    cell_level INT CHECK (cell_level BETWEEN 0 and 30),
+    identification_service_area_id UUID NOT NULL,
+    CONSTRAINT fk_cisa_isa_id FOREIGN KEY (identification_service_area_id) REFERENCES identification_service_areas (id) ON DELETE CASCADE,
+    PRIMARY KEY (cell_id, identification_service_area_id)
+);
+CREATE INDEX cisa_cell_id_idx ON cells_identification_service_areas (cell_id);
+CREATE INDEX cisa_identification_service_area_id_idx ON cells_identification_service_areas (identification_service_area_id);
+
+CREATE TABLE IF NOT EXISTS cells_subscriptions (
+    cell_id BIGINT NOT NULL, -- INT64 in CRDB.
+    cell_level INT CHECK (cell_level BETWEEN 0 and 30),
+    subscription_id UUID NOT NULL REFERENCES subscriptions (id) ON DELETE CASCADE,
+    PRIMARY KEY (cell_id, subscription_id)
+);
+CREATE INDEX sc_cell_id_idx ON cells_subscriptions (cell_id);
+CREATE INDEX sc_subscription_id_idx ON cells_subscriptions (subscription_id);
+
+-- Migrate data from index
+INSERT INTO cells_identification_service_areas
+SELECT UNNEST(cells) as cell_id,
+       13 AS cell_level,
+       id AS identification_service_area_id
+FROM identification_service_areas
+ON CONFLICT (identification_service_area_id, cell_id)
+DO NOTHING;
+
+INSERT INTO cells_subscriptions
+SELECT UNNEST(cells) AS cell_id,
+       13 AS cell_level,
+       id AS subscription_id
+FROM subscriptions
+ON CONFLICT (subscription_id, cell_id)
+DO NOTHING;
+
+-- Remove inverted indices
+DROP INDEX IF EXISTS isa_cell_idx;
+DROP INDEX IF EXISTS s_cell_idx;
+ALTER TABLE identification_service_areas DROP IF EXISTS cells;
+ALTER TABLE subscriptions DROP IF EXISTS cells;
+UPDATE schema_versions set schema_version = 'v1.0.0' WHERE onerow_enforcer = TRUE;
diff --git a/build/db_schemas/yugabyte/rid/downfrom-v3.0.0-no_change.sql b/build/db_schemas/yugabyte/rid/downfrom-v3.0.0-no_change.sql
new file mode 100644
index 000000000..d7bac827f
--- /dev/null
+++ b/build/db_schemas/yugabyte/rid/downfrom-v3.0.0-no_change.sql
@@ -0,0 +1 @@
+UPDATE schema_versions set schema_version = 'v2.0.0' WHERE onerow_enforcer = TRUE;
diff --git a/build/db_schemas/yugabyte/rid/downfrom-v3.1.0-remove_writer_column.sql b/build/db_schemas/yugabyte/rid/downfrom-v3.1.0-remove_writer_column.sql
new file mode 100644
index 000000000..878870a6a
--- /dev/null
+++ b/build/db_schemas/yugabyte/rid/downfrom-v3.1.0-remove_writer_column.sql
@@ -0,0 +1,3 @@
+ALTER TABLE identification_service_areas DROP IF EXISTS writer;
+ALTER TABLE subscriptions DROP IF EXISTS writer;
+UPDATE schema_versions set schema_version = 'v3.0.0' WHERE onerow_enforcer = TRUE;
diff --git a/build/db_schemas/yugabyte/rid/downfrom-v3.1.1-remove_index_by_time_subscriptions.sql b/build/db_schemas/yugabyte/rid/downfrom-v3.1.1-remove_index_by_time_subscriptions.sql
new file mode 100644
index 000000000..f63664dd5
--- /dev/null
+++ b/build/db_schemas/yugabyte/rid/downfrom-v3.1.1-remove_index_by_time_subscriptions.sql
@@ -0,0 +1,2 @@
+DROP INDEX IF EXISTS s_subs_by_time_with_owner;
+UPDATE schema_versions set schema_version = 'v3.1.0' WHERE onerow_enforcer = TRUE;
diff --git a/build/db_schemas/yugabyte/rid/downfrom-v4.0.0-move_rid_to_defaultdb.sql b/build/db_schemas/yugabyte/rid/downfrom-v4.0.0-move_rid_to_defaultdb.sql
new file mode 100644
index 000000000..20063f761
--- /dev/null
+++ b/build/db_schemas/yugabyte/rid/downfrom-v4.0.0-move_rid_to_defaultdb.sql
@@ -0,0 +1,7 @@
+-- The following statements are expected to executed as code since database change requires
+-- a reconnection to Yugabyte
+-- 1. DROP DATABASE IF EXISTS defaultdb;
+-- 2. ALTER DATABASE defaultdb RENAME TO rid;
+-- 3. USE defaultdb;
+
+UPDATE schema_versions set schema_version = 'v3.1.1' WHERE onerow_enforcer = TRUE;
diff --git a/build/db_schemas/yugabyte/rid/upto-v1.0.0-create_isa_subs_tables.sql b/build/db_schemas/yugabyte/rid/upto-v1.0.0-create_isa_subs_tables.sql
new file mode 100644
index 000000000..59ff838c1
--- /dev/null
+++ b/build/db_schemas/yugabyte/rid/upto-v1.0.0-create_isa_subs_tables.sql
@@ -0,0 +1,53 @@
+CREATE TABLE subscriptions (
+    id UUID PRIMARY KEY,
+    owner TEXT NOT NULL,
+    url TEXT NOT NULL,
+    notification_index INT4 DEFAULT 0,
+    starts_at TIMESTAMPTZ,
+    ends_at TIMESTAMPTZ,
+    updated_at TIMESTAMPTZ NOT NULL,
+    CHECK (starts_at IS NULL OR ends_at IS NULL OR starts_at < ends_at)
+);
+CREATE INDEX s_owner_idx ON subscriptions (owner);
+CREATE INDEX s_starts_at_idx ON subscriptions (starts_at);
+CREATE INDEX s_ends_at_idx ON subscriptions (ends_at);
+
+CREATE TABLE cells_subscriptions (
+		cell_id BIGINT NOT NULL, -- INT64 in CRDB.
+		cell_level INT CHECK (cell_level BETWEEN 0 and 30),
+		subscription_id UUID NOT NULL REFERENCES subscriptions (id) ON DELETE CASCADE,
+		PRIMARY KEY (cell_id, subscription_id)
+);
+CREATE INDEX sc_cell_id_idx ON cells_subscriptions (cell_id);
+CREATE INDEX sc_subscription_id_idx ON cells_subscriptions (subscription_id);
+
+CREATE TABLE identification_service_areas (
+    id UUID PRIMARY KEY,
+    owner TEXT NOT NULL,
+    url TEXT NOT NULL,
+    starts_at TIMESTAMPTZ,
+    ends_at TIMESTAMPTZ,
+    updated_at TIMESTAMPTZ NOT NULL,
+    CHECK (starts_at IS NULL OR ends_at IS NULL OR starts_at < ends_at)
+);
+CREATE INDEX isa_owner_idx ON identification_service_areas (owner);
+CREATE INDEX isa_starts_at_idx ON identification_service_areas (starts_at);
+CREATE INDEX isa_ends_at_idx ON identification_service_areas (ends_at);
+CREATE INDEX isa_updated_at_idx ON identification_service_areas (updated_at);
+
+CREATE TABLE cells_identification_service_areas (
+    cell_id BIGINT NOT NULL, -- INT64 in CRDB.
+    cell_level INT CHECK (cell_level BETWEEN 0 and 30),
+    identification_service_area_id UUID NOT NULL,
+    CONSTRAINT fk_cisa_isa_id FOREIGN KEY (identification_service_area_id) REFERENCES identification_service_areas (id) ON DELETE CASCADE,
+    PRIMARY KEY (cell_id, identification_service_area_id)
+);
+CREATE INDEX cisa_cell_id_idx ON cells_identification_service_areas (cell_id);
+CREATE INDEX cisa_identification_service_area_id_idx ON cells_identification_service_areas (identification_service_area_id);
+
+CREATE TABLE schema_versions (
+	onerow_enforcer bool PRIMARY KEY DEFAULT TRUE CHECK(onerow_enforcer),
+	schema_version TEXT NOT NULL
+);
+
+INSERT INTO schema_versions (schema_version) VALUES ('v1.0.0');
diff --git a/build/db_schemas/yugabyte/rid/upto-v2.0.0-add_inverted_indices.sql b/build/db_schemas/yugabyte/rid/upto-v2.0.0-add_inverted_indices.sql
new file mode 100644
index 000000000..73c1dbeb8
--- /dev/null
+++ b/build/db_schemas/yugabyte/rid/upto-v2.0.0-add_inverted_indices.sql
@@ -0,0 +1,48 @@
+-- Add inverted indices
+ALTER TABLE identification_service_areas ADD COLUMN IF NOT EXISTS cells BIGINT[];
+CREATE INDEX isa_cell_idx ON identification_service_areas USING ybgin (cells);
+ALTER TABLE subscriptions ADD COLUMN IF NOT EXISTS cells BIGINT[];
+CREATE INDEX s_cell_idx ON subscriptions USING ybgin (cells);
+
+-- Migrate data to index
+BEGIN;
+
+WITH compact_isa_cells AS
+    ( SELECT identification_service_area_id,
+             array_agg(cell_id) AS cell_ids
+     FROM cells_identification_service_areas
+     GROUP BY identification_service_area_id)
+UPDATE identification_service_areas isa
+SET cells = compact_isa_cells.cell_ids
+FROM compact_isa_cells
+WHERE isa.id = compact_isa_cells.identification_service_area_id
+    AND cells IS NULL;
+
+COMMIT;
+
+BEGIN;
+
+WITH compact_sub_cells AS
+    ( SELECT subscription_id,
+             array_agg(cell_id) AS cell_ids
+     FROM cells_subscriptions
+     GROUP BY subscription_id)
+UPDATE subscriptions subs
+SET cells = compact_sub_cells.cell_ids
+FROM compact_sub_cells
+WHERE subs.id = compact_sub_cells.subscription_id
+    AND cells IS NULL;
+
+COMMIT;
+
+ALTER TABLE identification_service_areas ALTER COLUMN cells SET NOT NULL;
+ALTER TABLE subscriptions ALTER COLUMN cells SET NOT NULL;
+ALTER TABLE identification_service_areas ADD CONSTRAINT isa_cells_not_null CHECK (array_length(cells, 1) IS NOT NULL);
+ALTER TABLE subscriptions ADD CONSTRAINT subs_cells_not_null CHECK (array_length(cells, 1) IS NOT NULL);
+ALTER TABLE identification_service_areas DROP CONSTRAINT IF EXISTS cells_not_null;
+ALTER TABLE subscriptions DROP CONSTRAINT IF EXISTS cells_not_null;
+
+-- Drop cells table
+DROP TABLE IF EXISTS cells_identification_service_areas;
+DROP TABLE IF EXISTS cells_subscriptions;
+UPDATE schema_versions set schema_version = 'v2.0.0' WHERE onerow_enforcer = TRUE;
diff --git a/build/db_schemas/yugabyte/rid/upto-v3.0.0-no_change.sql b/build/db_schemas/yugabyte/rid/upto-v3.0.0-no_change.sql
new file mode 100644
index 000000000..510f76b7a
--- /dev/null
+++ b/build/db_schemas/yugabyte/rid/upto-v3.0.0-no_change.sql
@@ -0,0 +1 @@
+UPDATE schema_versions set schema_version = 'v3.0.0' WHERE onerow_enforcer = TRUE;
diff --git a/build/db_schemas/yugabyte/rid/upto-v3.1.0-add_writer_column.sql b/build/db_schemas/yugabyte/rid/upto-v3.1.0-add_writer_column.sql
new file mode 100644
index 000000000..d24646d4e
--- /dev/null
+++ b/build/db_schemas/yugabyte/rid/upto-v3.1.0-add_writer_column.sql
@@ -0,0 +1,3 @@
+ALTER TABLE identification_service_areas ADD COLUMN IF NOT EXISTS writer TEXT;
+ALTER TABLE subscriptions ADD COLUMN IF NOT EXISTS writer TEXT;
+UPDATE schema_versions set schema_version = 'v3.1.0' WHERE onerow_enforcer = TRUE;
diff --git a/build/db_schemas/yugabyte/rid/upto-v3.1.1-add_index_by_time_subscriptions.sql b/build/db_schemas/yugabyte/rid/upto-v3.1.1-add_index_by_time_subscriptions.sql
new file mode 100644
index 000000000..3f02759bd
--- /dev/null
+++ b/build/db_schemas/yugabyte/rid/upto-v3.1.1-add_index_by_time_subscriptions.sql
@@ -0,0 +1,2 @@
+CREATE INDEX subs_by_time_with_owner ON subscriptions (ends_at) INCLUDE (owner);
+UPDATE schema_versions set schema_version = 'v3.1.1' WHERE onerow_enforcer = TRUE;
diff --git a/build/db_schemas/yugabyte/rid/upto-v4.0.0-rename_defaultdb_to_rid.sql b/build/db_schemas/yugabyte/rid/upto-v4.0.0-rename_defaultdb_to_rid.sql
new file mode 100644
index 000000000..a363e6be4
--- /dev/null
+++ b/build/db_schemas/yugabyte/rid/upto-v4.0.0-rename_defaultdb_to_rid.sql
@@ -0,0 +1,7 @@
+-- The following statements are expected to executed as code since database change requires
+-- a reconnection to Yugabyte
+-- a reconnection to Yugabyte
+-- 1. ALTER DATABASE defaultdb RENAME TO rid;
+-- 2. USE rid;
+-- 3. Create defaultdb as scd db expects it to exist: CREATE DATABASE defaultdb;
+UPDATE schema_versions set schema_version = 'v4.0.0' WHERE onerow_enforcer = TRUE;
\ No newline at end of file
diff --git a/build/db_schemas/yugabyte/scd/downfrom-v1.0.0-remove_initial_version.sql b/build/db_schemas/yugabyte/scd/downfrom-v1.0.0-remove_initial_version.sql
new file mode 100644
index 000000000..dbd0cdace
--- /dev/null
+++ b/build/db_schemas/yugabyte/scd/downfrom-v1.0.0-remove_initial_version.sql
@@ -0,0 +1,6 @@
+DROP TABLE IF EXISTS schema_versions;
+DROP TABLE IF EXISTS scd_constraints;
+DROP TABLE IF EXISTS scd_cells_operations;
+DROP TABLE IF EXISTS scd_operations;
+DROP TABLE IF EXISTS scd_cells_subscriptions;
+DROP TABLE IF EXISTS scd_subscriptions;
diff --git a/build/db_schemas/yugabyte/scd/downfrom-v2.0.0-remove_api_1_0_0_support.sql b/build/db_schemas/yugabyte/scd/downfrom-v2.0.0-remove_api_1_0_0_support.sql
new file mode 100644
index 000000000..d73a23d7a
--- /dev/null
+++ b/build/db_schemas/yugabyte/scd/downfrom-v2.0.0-remove_api_1_0_0_support.sql
@@ -0,0 +1,5 @@
+ALTER TABLE IF EXISTS scd_operations DROP COLUMN state;
+DROP TYPE IF EXISTS operational_intent_state;
+ALTER TABLE scd_operations ALTER COLUMN subscription_id SET NOT NULL;
+
+UPDATE schema_versions set schema_version = 'v1.0.0' WHERE onerow_enforcer = TRUE;
diff --git a/build/db_schemas/yugabyte/scd/downfrom-v3.0.0-remove_inverted_indices.sql b/build/db_schemas/yugabyte/scd/downfrom-v3.0.0-remove_inverted_indices.sql
new file mode 100644
index 000000000..955c64c22
--- /dev/null
+++ b/build/db_schemas/yugabyte/scd/downfrom-v3.0.0-remove_inverted_indices.sql
@@ -0,0 +1,66 @@
+-- Restore Table scd_cells_operations
+CREATE TABLE IF NOT EXISTS scd_cells_operations (
+    cell_id BIGINT NOT NULL,
+    cell_level INT CHECK (cell_level BETWEEN 0 and 30),
+    operation_id UUID NOT NULL REFERENCES scd_operations (id) ON DELETE CASCADE,
+    PRIMARY KEY (cell_id, operation_id)
+);
+CREATE INDEX sco_cell_id_idx ON scd_cells_operations (cell_id);
+CREATE INDEX sco_operation_id_idx ON scd_cells_operations (operation_id);
+
+
+-- Restore cells data in scd_cells_operations
+BEGIN;
+
+INSERT INTO
+    scd_cells_operations (cell_id, operation_id)
+SELECT
+    DISTINCT unnest(cells) as cell_id,
+    id
+from
+    scd_operations;
+
+COMMIT;
+
+-- Restore Table scd_cells_subscriptions
+CREATE TABLE IF NOT EXISTS scd_cells_subscriptions (
+   cell_id BIGINT NOT NULL,
+   cell_level INT CHECK (cell_level BETWEEN 0 and 30),
+   subscription_id UUID NOT NULL REFERENCES scd_subscriptions (id) ON DELETE CASCADE,
+   PRIMARY KEY (cell_id, subscription_id)
+);
+CREATE INDEX scs_cell_id_idx ON scd_cells_subscriptions (cell_id);
+CREATE INDEX scs_subscription_id_idx ON scd_cells_subscriptions (subscription_id);
+
+
+-- Restore cells data in scd_cells_subscriptions
+BEGIN;
+
+INSERT INTO
+    scd_cells_subscriptions (cell_id, subscription_id)
+SELECT
+    DISTINCT unnest(cells) as cell_id,
+    id
+from
+    scd_subscriptions;
+
+COMMIT;
+
+-- Remove inverted index for scd_subscriptions
+DROP INDEX IF EXISTS ss_cell_idx;
+
+ALTER TABLE
+    scd_subscriptions DROP IF EXISTS cells;
+
+-- Remove inverted index for scd_operations
+DROP INDEX IF EXISTS so_cell_idx;
+
+ALTER TABLE
+    scd_operations DROP IF EXISTS cells;
+
+UPDATE
+    schema_versions
+set
+    schema_version = 'v2.0.0'
+WHERE
+    onerow_enforcer = TRUE;
diff --git a/build/db_schemas/yugabyte/scd/downfrom-v3.1.0-remove_uss_availability.sql b/build/db_schemas/yugabyte/scd/downfrom-v3.1.0-remove_uss_availability.sql
new file mode 100644
index 000000000..3b863ac00
--- /dev/null
+++ b/build/db_schemas/yugabyte/scd/downfrom-v3.1.0-remove_uss_availability.sql
@@ -0,0 +1,3 @@
+DROP TABLE IF EXISTS scd_uss_availability;
+
+UPDATE schema_versions set schema_version = 'v3.0.0' WHERE onerow_enforcer = TRUE;
diff --git a/build/db_schemas/yugabyte/scd/downfrom-v3.2.0-remove_ovn_columns.sql b/build/db_schemas/yugabyte/scd/downfrom-v3.2.0-remove_ovn_columns.sql
new file mode 100644
index 000000000..4366cf0b8
--- /dev/null
+++ b/build/db_schemas/yugabyte/scd/downfrom-v3.2.0-remove_ovn_columns.sql
@@ -0,0 +1,5 @@
+ALTER TABLE scd_operations
+    DROP IF EXISTS uss_requested_ovn,
+    DROP IF EXISTS past_ovns;
+
+UPDATE schema_versions SET schema_version = 'v3.1.0' WHERE onerow_enforcer = TRUE;
diff --git a/build/db_schemas/yugabyte/scd/upto-v1.0.0-create_initial_version.sql b/build/db_schemas/yugabyte/scd/upto-v1.0.0-create_initial_version.sql
new file mode 100644
index 000000000..605106619
--- /dev/null
+++ b/build/db_schemas/yugabyte/scd/upto-v1.0.0-create_initial_version.sql
@@ -0,0 +1,82 @@
+CREATE TABLE IF NOT EXISTS scd_subscriptions (
+  id UUID PRIMARY KEY,
+  owner TEXT NOT NULL,
+  version INT4 NOT NULL DEFAULT 0,
+  url TEXT NOT NULL,
+  notification_index INT4 DEFAULT 0,
+  notify_for_operations BOOL DEFAULT false,
+  notify_for_constraints BOOL DEFAULT false,
+  implicit BOOL DEFAULT false,
+  starts_at TIMESTAMPTZ,
+  ends_at TIMESTAMPTZ,
+  updated_at TIMESTAMPTZ NOT NULL,
+  CHECK (starts_at IS NULL OR ends_at IS NULL OR starts_at < ends_at),
+  CHECK (notify_for_operations OR notify_for_constraints)
+);
+CREATE INDEX ss_owner_idx ON scd_subscriptions (owner);
+CREATE INDEX ss_starts_at_idx ON scd_subscriptions (starts_at);
+CREATE INDEX ss_ends_at_idx ON scd_subscriptions (ends_at);
+
+CREATE TABLE IF NOT EXISTS scd_cells_subscriptions (
+  cell_id BIGINT NOT NULL,
+  cell_level INT CHECK (cell_level BETWEEN 0 and 30),
+  subscription_id UUID NOT NULL REFERENCES scd_subscriptions (id) ON DELETE CASCADE,
+  PRIMARY KEY (cell_id, subscription_id)
+);
+CREATE INDEX scs_cell_id_idx ON scd_cells_subscriptions (cell_id);
+CREATE INDEX scs_subscription_id_idx ON scd_cells_subscriptions (subscription_id);
+
+CREATE TABLE IF NOT EXISTS scd_operations (
+  id UUID PRIMARY KEY,
+  owner TEXT NOT NULL,
+  version INT4 NOT NULL DEFAULT 0,
+  url TEXT NOT NULL,
+  altitude_lower REAL,
+  altitude_upper REAL,
+  starts_at TIMESTAMPTZ,
+  ends_at TIMESTAMPTZ,
+  subscription_id UUID NOT NULL REFERENCES scd_subscriptions(id) ON DELETE CASCADE,
+  updated_at TIMESTAMPTZ NOT NULL,
+  CHECK (starts_at IS NULL OR ends_at IS NULL OR starts_at < ends_at)
+);
+CREATE INDEX so_owner_idx ON scd_operations (owner);
+CREATE INDEX so_altitude_lower_idx ON scd_operations (altitude_lower);
+CREATE INDEX so_altitude_upper_idx ON scd_operations (altitude_upper);
+CREATE INDEX so_starts_at_idx ON scd_operations (starts_at);
+CREATE INDEX so_ends_at_idx ON scd_operations (ends_at);
+CREATE INDEX so_updated_at_idx ON scd_operations (updated_at);
+CREATE INDEX so_subscription_id_idx ON scd_operations (subscription_id);
+
+CREATE TABLE IF NOT EXISTS scd_cells_operations (
+  cell_id BIGINT NOT NULL,
+  cell_level INT CHECK (cell_level BETWEEN 0 and 30),
+  operation_id UUID NOT NULL REFERENCES scd_operations (id) ON DELETE CASCADE,
+  PRIMARY KEY (cell_id, operation_id)
+);
+CREATE INDEX sco_cell_id_idx ON scd_cells_operations (cell_id);
+CREATE INDEX sco_operation_id_idx ON scd_cells_operations (operation_id);
+
+CREATE TABLE IF NOT EXISTS scd_constraints (
+  id UUID PRIMARY KEY,
+  owner TEXT NOT NULL,
+  version INT4 NOT NULL DEFAULT 0,
+  url TEXT NOT NULL,
+  altitude_lower REAL,
+  altitude_upper REAL,
+  starts_at TIMESTAMPTZ,
+  ends_at TIMESTAMPTZ,
+  updated_at TIMESTAMPTZ NOT NULL,
+  cells BIGINT[] NOT NULL CHECK (array_length(cells, 1) IS NOT NULL),
+  CHECK (starts_at IS NULL OR ends_at IS NULL OR starts_at < ends_at)
+);
+CREATE INDEX sc_owner_idx ON scd_constraints (owner);
+CREATE INDEX sc_starts_at_idx ON scd_constraints (starts_at);
+CREATE INDEX sc_ends_at_idx ON scd_constraints (ends_at);
+CREATE INDEX sc_cells_idx ON scd_constraints USING ybgin (cells);
+
+CREATE TABLE IF NOT EXISTS schema_versions (
+	onerow_enforcer bool PRIMARY KEY DEFAULT TRUE CHECK(onerow_enforcer),
+	schema_version TEXT NOT NULL
+);
+
+INSERT INTO schema_versions (schema_version) VALUES ('v1.0.0');
diff --git a/build/db_schemas/yugabyte/scd/upto-v2.0.0-support_api_1_0_0.sql b/build/db_schemas/yugabyte/scd/upto-v2.0.0-support_api_1_0_0.sql
new file mode 100644
index 000000000..9270579bb
--- /dev/null
+++ b/build/db_schemas/yugabyte/scd/upto-v2.0.0-support_api_1_0_0.sql
@@ -0,0 +1,12 @@
+/* Note: Subscription version column is now ignored; version, like OVN for
+   operational intent, is encoded in updated_at */
+
+/* Add tracking for operational intent state */
+CREATE TYPE operational_intent_state AS ENUM ('Unknown', 'Accepted', 'Activated', 'Nonconforming', 'Contingent');
+ALTER TABLE scd_operations ADD COLUMN state operational_intent_state NOT NULL DEFAULT 'Unknown';
+
+/* Make Subscription associated with operational intent optional */
+ALTER TABLE scd_operations ALTER COLUMN subscription_id DROP NOT NULL;
+
+/* Record new database version */
+UPDATE schema_versions set schema_version = 'v2.0.0' WHERE onerow_enforcer = TRUE;
diff --git a/build/db_schemas/yugabyte/scd/upto-v3.0.0-add_inverted_indices.sql b/build/db_schemas/yugabyte/scd/upto-v3.0.0-add_inverted_indices.sql
new file mode 100644
index 000000000..188f8c900
--- /dev/null
+++ b/build/db_schemas/yugabyte/scd/upto-v3.0.0-add_inverted_indices.sql
@@ -0,0 +1,40 @@
+-- /* Switch to inverted indices for all Entities' cells */
+ALTER TABLE scd_subscriptions ADD COLUMN IF NOT EXISTS cells BIGINT[];
+CREATE INDEX ss_cells_idx ON scd_subscriptions USING ybgin (cells);
+BEGIN;
+
+WITH compact_subscription_cells AS
+    ( SELECT subscription_id,
+             array_agg(cell_id) AS cell_ids
+     FROM scd_cells_subscriptions
+     GROUP BY subscription_id)
+UPDATE scd_subscriptions subscription
+SET cells = compact_subscription_cells.cell_ids
+FROM compact_subscription_cells
+WHERE subscription.id = compact_subscription_cells.subscription_id
+    AND cells IS NULL;
+
+COMMIT;
+
+ALTER TABLE scd_operations ADD COLUMN IF NOT EXISTS cells BIGINT[];
+CREATE INDEX so_cells_idx ON scd_operations USING ybgin (cells);
+BEGIN;
+
+WITH compact_operation_cells AS
+    ( SELECT operation_id,
+             array_agg(cell_id) AS cell_ids
+     FROM scd_cells_operations
+     GROUP BY operation_id)
+UPDATE scd_operations operation
+SET cells = compact_operation_cells.cell_ids
+FROM compact_operation_cells
+WHERE operation.id = compact_operation_cells.operation_id
+    AND cells IS NULL;
+
+COMMIT;
+
+DROP TABLE IF EXISTS scd_cells_operations;
+DROP TABLE IF EXISTS scd_cells_subscriptions;
+
+/* Record new database version */
+UPDATE schema_versions set schema_version = 'v3.0.0' WHERE onerow_enforcer = TRUE;
diff --git a/build/db_schemas/yugabyte/scd/upto-v3.1.0-create_uss_availability.sql b/build/db_schemas/yugabyte/scd/upto-v3.1.0-create_uss_availability.sql
new file mode 100644
index 000000000..59d4bc7c9
--- /dev/null
+++ b/build/db_schemas/yugabyte/scd/upto-v3.1.0-create_uss_availability.sql
@@ -0,0 +1,8 @@
+CREATE TABLE IF NOT EXISTS scd_uss_availability (
+  id TEXT PRIMARY KEY,
+  availability TEXT NOT NULL,
+  updated_at TIMESTAMPTZ NOT NULL
+);
+
+/* Update database version */
+UPDATE schema_versions set schema_version = 'v3.1.0' WHERE onerow_enforcer = TRUE;
diff --git a/build/db_schemas/yugabyte/scd/upto-v3.2.0-add_ovn_columns.sql b/build/db_schemas/yugabyte/scd/upto-v3.2.0-add_ovn_columns.sql
new file mode 100644
index 000000000..6ace85f54
--- /dev/null
+++ b/build/db_schemas/yugabyte/scd/upto-v3.2.0-add_ovn_columns.sql
@@ -0,0 +1,12 @@
+ALTER TABLE scd_operations
+    ADD COLUMN IF NOT EXISTS uss_requested_ovn TEXT
+        CHECK (uss_requested_ovn != ''), -- uss_requested_ovn must be NULL if unspecified, not an empty string
+    ADD COLUMN IF NOT EXISTS past_ovns         TEXT[] NOT NULL
+        DEFAULT ARRAY []::TEXT[]
+        CHECK (
+            array_position(past_ovns, NULL) IS NULL AND
+            array_position(past_ovns, '') IS NULL AND
+            array_position(past_ovns, uss_requested_ovn) IS NULL
+            ); -- past_ovns must not contain NULL elements, empty strings or current uss_requested_ovn
+
+UPDATE schema_versions SET schema_version = 'v3.2.0' WHERE onerow_enforcer = TRUE;