Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

[yugabyte] SQL Migrations #1138

Merged
merged 10 commits into from
Dec 13, 2024
Merged
Show file tree
Hide file tree
Changes from 3 commits
Commits
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
28 changes: 28 additions & 0 deletions .github/workflows/ci.yml
Original file line number Diff line number Diff line change
Expand Up @@ -67,3 +67,31 @@ jobs:
run: make qualify-locally
- name: Bring down local DSS instance
run: make down-locally

dss-tests-with-yugabyte:
name: DSS tests with Yugabyte
runs-on: ubuntu-latest
env:
COMPOSE_PROFILES: with-yugabyte
steps:
- name: Job information
run: |
echo "Job information"
echo "Trigger: ${{ github.event_name }}"
echo "Host: ${{ runner.os }}"
echo "Repository: ${{ github.repository }}"
echo "Branch: ${{ github.ref }}"
docker images
go env
- name: Checkout
uses: actions/checkout@v2
with:
submodules: true
- name: Build dss image
run: make build-dss
- name: Tear down any pre-existing local DSS instance
run: make down-locally
- name: Start local DSS instance
run: make start-locally
- name: Bring down local DSS instance
run: make down-locally
Original file line number Diff line number Diff line change
@@ -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;
Original file line number Diff line number Diff line change
@@ -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;
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
UPDATE schema_versions set schema_version = 'v2.0.0' WHERE onerow_enforcer = TRUE;
Original file line number Diff line number Diff line change
@@ -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;
Original file line number Diff line number Diff line change
@@ -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;
Original file line number Diff line number Diff line change
@@ -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;
Original file line number Diff line number Diff line change
@@ -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');
48 changes: 48 additions & 0 deletions build/db_schemas/yugabyte/rid/upto-v2.0.0-add_inverted_indices.sql
Original file line number Diff line number Diff line change
@@ -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;
1 change: 1 addition & 0 deletions build/db_schemas/yugabyte/rid/upto-v3.0.0-no_change.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
UPDATE schema_versions set schema_version = 'v3.0.0' WHERE onerow_enforcer = TRUE;
Original file line number Diff line number Diff line change
@@ -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;
Original file line number Diff line number Diff line change
@@ -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;
Original file line number Diff line number Diff line change
@@ -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;
Original file line number Diff line number Diff line change
@@ -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;
Original file line number Diff line number Diff line change
@@ -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;
Original file line number Diff line number Diff line change
@@ -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;
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
DROP TABLE IF EXISTS scd_uss_availability;

UPDATE schema_versions set schema_version = 'v3.0.0' WHERE onerow_enforcer = TRUE;
Original file line number Diff line number Diff line change
@@ -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;
Original file line number Diff line number Diff line change
@@ -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');
Loading
Loading