feat: create sql migrations by replicating typeorm ones in an idempotent manner
This commit is contained in:
parent
4609078894
commit
5f1ad108c6
5 changed files with 144 additions and 0 deletions
|
@ -0,0 +1,6 @@
|
|||
CREATE TABLE IF NOT EXISTS migrations (
|
||||
id integer PRIMARY KEY,
|
||||
name varchar(100) UNIQUE NOT NULL,
|
||||
hash varchar(40) NOT NULL, -- sha1 hex encoded hash of the file name and contents, to ensure it hasn't been altered since applying the migration
|
||||
executed_at timestamp DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
69
packages/dashboard/migrations/00001-initial.sql
Normal file
69
packages/dashboard/migrations/00001-initial.sql
Normal file
|
@ -0,0 +1,69 @@
|
|||
DO $$
|
||||
BEGIN
|
||||
-- check if enum update_status_enum exists
|
||||
IF NOT EXISTS (
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
pg_type
|
||||
WHERE
|
||||
typname = 'update_status_enum') THEN
|
||||
-- create enum
|
||||
CREATE TYPE "public"."update_status_enum" AS ENUM (
|
||||
'FAILED',
|
||||
'SUCCESS'
|
||||
);
|
||||
END IF;
|
||||
-- check if enum app_status_enum exists
|
||||
IF NOT EXISTS (
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
pg_type
|
||||
WHERE
|
||||
typname = 'app_status_enum') THEN
|
||||
-- create enum
|
||||
CREATE TYPE "public"."app_status_enum" AS ENUM (
|
||||
'running',
|
||||
'stopped',
|
||||
'installing',
|
||||
'uninstalling',
|
||||
'stopping',
|
||||
'starting',
|
||||
'missing'
|
||||
);
|
||||
END IF;
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS "update" (
|
||||
"id" serial NOT NULL,
|
||||
"name" character varying NOT NULL,
|
||||
"status" "public"."update_status_enum" NOT NULL,
|
||||
"createdAt" timestamp NOT NULL DEFAULT now(),
|
||||
"updatedAt" timestamp NOT NULL DEFAULT now(),
|
||||
CONSTRAINT "UQ_6e7d7ecccdc972caa0ad33cb014" UNIQUE ("name"),
|
||||
CONSTRAINT "PK_575f77a0576d6293bc1cb752847" PRIMARY KEY ("id")
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS "user" (
|
||||
"id" serial NOT NULL,
|
||||
"username" character varying NOT NULL,
|
||||
"password" character varying NOT NULL,
|
||||
"createdAt" timestamp NOT NULL DEFAULT now(),
|
||||
"updatedAt" timestamp NOT NULL DEFAULT now(),
|
||||
CONSTRAINT "UQ_78a916df40e02a9deb1c4b75edb" UNIQUE ("username"),
|
||||
CONSTRAINT "PK_cace4a159ff9f2512dd42373760" PRIMARY KEY ("id")
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS "app" (
|
||||
"id" character varying NOT NULL,
|
||||
"status" "public"."app_status_enum" NOT NULL DEFAULT 'stopped',
|
||||
"lastOpened" timestamp with time zone DEFAULT now(),
|
||||
"numOpened" integer NOT NULL DEFAULT '0',
|
||||
"config" jsonb NOT NULL,
|
||||
"createdAt" timestamp NOT NULL DEFAULT now(),
|
||||
"updatedAt" timestamp NOT NULL DEFAULT now(),
|
||||
CONSTRAINT "UQ_9478629fc093d229df09e560aea" UNIQUE ("id"),
|
||||
CONSTRAINT "PK_9478629fc093d229df09e560aea" PRIMARY KEY ("id")
|
||||
);
|
31
packages/dashboard/migrations/00002-add-app-version.sql
Normal file
31
packages/dashboard/migrations/00002-add-app-version.sql
Normal file
|
@ -0,0 +1,31 @@
|
|||
-- Create version field if it doesn't exist
|
||||
ALTER TABLE "app"
|
||||
ADD COLUMN IF NOT EXISTS "version" integer DEFAULT '0';
|
||||
|
||||
-- Set version field to 1 for all apps that have no version
|
||||
UPDATE
|
||||
"app"
|
||||
SET
|
||||
"version" = '1'
|
||||
WHERE
|
||||
"version" IS NULL;
|
||||
|
||||
-- Set version field to not null
|
||||
ALTER TABLE "app"
|
||||
ALTER COLUMN "version" SET NOT NULL;
|
||||
|
||||
DO $$
|
||||
BEGIN
|
||||
IF NOT EXISTS (
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
information_schema.table_constraints
|
||||
WHERE
|
||||
constraint_name = 'UQ_9478629fc093d229df09e560aea'
|
||||
AND table_name = 'app') THEN
|
||||
ALTER TABLE "app"
|
||||
ADD CONSTRAINT "UQ_9478629fc093d229df09e560aea" UNIQUE ("id");
|
||||
END IF;
|
||||
END
|
||||
$$;
|
15
packages/dashboard/migrations/00003-add-status-updating.sql
Normal file
15
packages/dashboard/migrations/00003-add-status-updating.sql
Normal file
|
@ -0,0 +1,15 @@
|
|||
DO $$
|
||||
BEGIN
|
||||
IF NOT EXISTS (
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
pg_enum
|
||||
WHERE
|
||||
enumlabel = 'updating'::text
|
||||
AND enumtypid = 'public.app_status_enum'::regtype) THEN
|
||||
ALTER TYPE "public"."app_status_enum"
|
||||
ADD VALUE 'updating';
|
||||
END IF;
|
||||
END
|
||||
$$;
|
|
@ -0,0 +1,23 @@
|
|||
-- Create exposed field if it doesn't exist
|
||||
ALTER TABLE "app"
|
||||
ADD COLUMN IF NOT EXISTS "exposed" boolean DEFAULT FALSE;
|
||||
|
||||
-- Select all apps that have not the exposed field and put it to false
|
||||
UPDATE
|
||||
"app"
|
||||
SET
|
||||
"exposed" = FALSE
|
||||
WHERE
|
||||
"exposed" IS NULL;
|
||||
|
||||
-- Set exposed column to not null constraint
|
||||
ALTER TABLE "app"
|
||||
ALTER COLUMN "exposed" SET NOT NULL;
|
||||
|
||||
-- Create domain column if it doesn't exist
|
||||
ALTER TABLE "app"
|
||||
ADD COLUMN IF NOT EXISTS "domain" character varying;
|
||||
|
||||
-- Set default version to 1
|
||||
ALTER TABLE "app"
|
||||
ALTER COLUMN "version" SET DEFAULT '1';
|
Loading…
Add table
Reference in a new issue