Skip to content

Commit

Permalink
fix: migrate old session launchers (#513)
Browse files Browse the repository at this point in the history
  • Loading branch information
olevski authored Nov 7, 2024
1 parent afce678 commit 71b9da7
Show file tree
Hide file tree
Showing 6 changed files with 283 additions and 38 deletions.
5 changes: 4 additions & 1 deletion .devcontainer/docker-compose.yml
Original file line number Diff line number Diff line change
Expand Up @@ -36,9 +36,12 @@ services:
restart: unless-stopped
volumes:
- postgres-data:/var/lib/postgresql/data
- type: bind
source: ./generate_ulid_func.sql
target: /docker-entrypoint-initdb.d/generate_ulid_func.sql
environment:
POSTGRES_USER: renku
POSTGRES_DB: renku
POSTGRES_DB: postgres
POSTGRES_PASSWORD: renku
ports:
- "8000:8000"
Expand Down
89 changes: 89 additions & 0 deletions .devcontainer/generate_ulid_func.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,89 @@
CREATE DATABASE renku_template;
ALTER DATABASE renku_template WITH is_template TRUE;
\c renku_template;

-- From https://github.com/geckoboard/pgulid/blob/master/pgulid.sql
-- Taken at commit sha b265253
-- pgulid is based on OK Log's Go implementation of the ULID spec
--
-- https://github.com/oklog/ulid
-- https://github.com/ulid/spec
--
-- Copyright 2016 The Oklog Authors
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.

CREATE EXTENSION IF NOT EXISTS pgcrypto;

-- NOTE: REPLACE will error if you change the name, args or return type of the function
-- There is no CREATE IF EXISTS, this is the closest thing that gives similar functionality
CREATE OR REPLACE FUNCTION generate_ulid()
RETURNS TEXT
AS $$
DECLARE
-- Crockford's Base32
encoding BYTEA = '0123456789ABCDEFGHJKMNPQRSTVWXYZ';
timestamp BYTEA = E'\\000\\000\\000\\000\\000\\000';
output TEXT = '';

unix_time BIGINT;
ulid BYTEA;
BEGIN
-- 6 timestamp bytes
unix_time = (EXTRACT(EPOCH FROM CLOCK_TIMESTAMP()) * 1000)::BIGINT;
timestamp = SET_BYTE(timestamp, 0, (unix_time >> 40)::BIT(8)::INTEGER);
timestamp = SET_BYTE(timestamp, 1, (unix_time >> 32)::BIT(8)::INTEGER);
timestamp = SET_BYTE(timestamp, 2, (unix_time >> 24)::BIT(8)::INTEGER);
timestamp = SET_BYTE(timestamp, 3, (unix_time >> 16)::BIT(8)::INTEGER);
timestamp = SET_BYTE(timestamp, 4, (unix_time >> 8)::BIT(8)::INTEGER);
timestamp = SET_BYTE(timestamp, 5, unix_time::BIT(8)::INTEGER);

-- 10 entropy bytes
ulid = timestamp || gen_random_bytes(10);

-- Encode the timestamp
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 0) & 224) >> 5));
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 0) & 31)));
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 1) & 248) >> 3));
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 1) & 7) << 2) | ((GET_BYTE(ulid, 2) & 192) >> 6)));
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 2) & 62) >> 1));
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 2) & 1) << 4) | ((GET_BYTE(ulid, 3) & 240) >> 4)));
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 3) & 15) << 1) | ((GET_BYTE(ulid, 4) & 128) >> 7)));
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 4) & 124) >> 2));
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 4) & 3) << 3) | ((GET_BYTE(ulid, 5) & 224) >> 5)));
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 5) & 31)));

-- Encode the entropy
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 6) & 248) >> 3));
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 6) & 7) << 2) | ((GET_BYTE(ulid, 7) & 192) >> 6)));
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 7) & 62) >> 1));
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 7) & 1) << 4) | ((GET_BYTE(ulid, 8) & 240) >> 4)));
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 8) & 15) << 1) | ((GET_BYTE(ulid, 9) & 128) >> 7)));
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 9) & 124) >> 2));
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 9) & 3) << 3) | ((GET_BYTE(ulid, 10) & 224) >> 5)));
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 10) & 31)));
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 11) & 248) >> 3));
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 11) & 7) << 2) | ((GET_BYTE(ulid, 12) & 192) >> 6)));
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 12) & 62) >> 1));
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 12) & 1) << 4) | ((GET_BYTE(ulid, 13) & 240) >> 4)));
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 13) & 15) << 1) | ((GET_BYTE(ulid, 14) & 128) >> 7)));
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 14) & 124) >> 2));
output = output || CHR(GET_BYTE(encoding, ((GET_BYTE(ulid, 14) & 3) << 3) | ((GET_BYTE(ulid, 15) & 224) >> 5)));
output = output || CHR(GET_BYTE(encoding, (GET_BYTE(ulid, 15) & 31)));

RETURN output;
END
$$
LANGUAGE plpgsql
VOLATILE;

CREATE DATABASE renku TEMPLATE renku_template;
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,13 @@
branch_labels = None
depends_on = None

default_command = ["sh", "-c"]
default_args = [
"jupyter server --ServerApp.ip=0.0.0.0 --ServerApp.port=8888 --ServerApp.base_url=$RENKU_BASE_URL_PATH "
'--ServerApp.token="" --ServerApp.password="" --ServerApp.allow_remote_access=true '
"--ContentsManager.allow_hidden=true --ServerApp.allow_origin=*",
]


def upgrade() -> None:
# ### commands auto generated by Alembic - please adjust! ###
Expand All @@ -31,6 +38,12 @@ def upgrade() -> None:
),
schema="sessions",
)
op.execute(
sa.text("UPDATE sessions.environments SET command=:command, args=:args").bindparams(
sa.bindparam("command", value=default_command, type_=sa.JSON),
sa.bindparam("args", value=default_args, type_=sa.JSON),
)
)
# ### end Alembic commands ###


Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -26,22 +26,48 @@

def upgrade() -> None:
# ### commands auto generated by Alembic - please adjust! ###
op.execute("DELETE FROM sessions.launchers")
op.drop_column("launchers", "default_url", schema="sessions")
op.drop_column("launchers", "environment_kind", schema="sessions")
op.drop_column("launchers", "container_image", schema="sessions")
# Migrate session launchers
op.execute("DROP TYPE environmentkind CASCADE")
op.execute("CREATE TYPE environmentkind AS ENUM ('GLOBAL', 'CUSTOM')")
op.add_column("environments", sa.Column("port", sa.Integer(), nullable=True), schema="sessions")
op.add_column("environments", sa.Column("working_directory", sa.String(), nullable=True), schema="sessions")
op.add_column("environments", sa.Column("mount_directory", sa.String(), nullable=True), schema="sessions")
op.add_column("environments", sa.Column("uid", sa.Integer(), nullable=True), schema="sessions")
op.add_column("environments", sa.Column("gid", sa.Integer(), nullable=True), schema="sessions")
op.add_column(
"environments",
sa.Column("environment_kind", sa.Enum("GLOBAL", "CUSTOM", name="environmentkind"), nullable=True),
schema="sessions",
)
op.execute("UPDATE sessions.environments SET environment_kind = 'GLOBAL' WHERE environment_kind is NULL")
# NOTE: When the session launcher has environment_id set to null then it is a custom environment
# NOTE: We populate the name column in the new environment with the session launcher id
# This way we can join the newly add environments with their launchers and update the foreign key in the launchers
# with the newly created environments.
# NOTE: Since postgres cannot autogenerate ulids we use the session launcher ulid when creating the environment
op.execute(
"INSERT INTO sessions.environments(id, name, created_by_id, creation_date, container_image, default_url, environment_kind) "
"SELECT generate_ulid(), id, created_by_id, creation_date, container_image, default_url, 'CUSTOM' "
"FROM sessions.launchers "
"WHERE environment_id IS NULL"
)
op.execute(
"UPDATE sessions.launchers "
"SET environment_id = sessions.environments.id "
"FROM sessions.environments "
"WHERE sessions.environments.name = sessions.launchers.id"
)
# NOTE: Make the environment name human readable when the join and udpate is done
op.execute(
"UPDATE sessions.environments "
"SET name = CONCAT('Custom environment for session launcher ID ', name) "
"WHERE environment_kind = 'CUSTOM'"
)
# Drop unused fields from session launchers
op.drop_column("launchers", "default_url", schema="sessions")
# op.drop_column("launchers", "environment_kind", schema="sessions")
op.drop_column("launchers", "container_image", schema="sessions")
# Add new fields to environment
op.add_column("environments", sa.Column("port", sa.Integer(), nullable=True), schema="sessions")
op.add_column("environments", sa.Column("working_directory", sa.String(), nullable=True), schema="sessions")
op.add_column("environments", sa.Column("mount_directory", sa.String(), nullable=True), schema="sessions")
op.add_column("environments", sa.Column("uid", sa.Integer(), nullable=True), schema="sessions")
op.add_column("environments", sa.Column("gid", sa.Integer(), nullable=True), schema="sessions")
op.execute(sa.text("UPDATE sessions.environments SET port = :port WHERE port is NULL").bindparams(port=port))
op.execute(
sa.text(
Expand All @@ -55,12 +81,12 @@ def upgrade() -> None:
)
op.execute(sa.text("UPDATE sessions.environments SET uid = :uid WHERE uid is NULL").bindparams(uid=uid))
op.execute(sa.text("UPDATE sessions.environments SET gid = :gid WHERE gid is NULL").bindparams(gid=gid))
op.execute("UPDATE sessions.environments SET environment_kind = 'GLOBAL' WHERE environment_kind is NULL")
op.execute(
sa.text("UPDATE sessions.environments SET default_url = :default_url WHERE default_url is NULL").bindparams(
default_url=default_url
)
)
# Set proper nullable constraints
op.alter_column("environments", "port", nullable=False, schema="sessions")
op.alter_column("environments", "working_directory", nullable=False, schema="sessions")
op.alter_column("environments", "mount_directory", nullable=False, schema="sessions")
Expand All @@ -75,13 +101,7 @@ def upgrade() -> None:

def downgrade() -> None:
# ### commands auto generated by Alembic - please adjust! ###
op.drop_column("environments", "environment_kind", schema="sessions")
op.drop_column("environments", "gid", schema="sessions")
op.drop_column("environments", "uid", schema="sessions")
op.drop_column("environments", "mount_directory", schema="sessions")
op.drop_column("environments", "working_directory", schema="sessions")
op.drop_column("environments", "port", schema="sessions")
op.execute("DROP TYPE environmentkind")
op.execute("ALTER TYPE environmentkind RENAME TO environmentkind_old;")
op.execute("CREATE TYPE environmentkind AS ENUM ('global_environment', 'container_image')")
op.add_column(
"launchers",
Expand All @@ -94,7 +114,7 @@ def downgrade() -> None:
"environment_kind",
postgresql.ENUM("global_environment", "container_image", name="environmentkind"),
autoincrement=False,
nullable=False,
nullable=True,
),
schema="sessions",
)
Expand All @@ -103,7 +123,26 @@ def downgrade() -> None:
sa.Column("default_url", sa.VARCHAR(length=200), autoincrement=False, nullable=True),
schema="sessions",
)
# Move the custom environments spec back into the session launcher table
op.execute(
"UPDATE sessions.launchers "
"SET default_url = environments.default_url, "
"container_image = environments.container_image, "
"environment_kind = 'container_image' "
"FROM sessions.environments "
"WHERE launchers.environment_id = environments.id AND "
"environments.environment_kind = 'CUSTOM'"
)
op.execute("UPDATE sessions.launchers SET environment_kind = 'global_environment' WHERE environment_kind IS NULL")
op.alter_column("launchers", "environment_kind", nullable=False, schema="sessions")
op.alter_column(
"environments", "default_url", existing_type=sa.VARCHAR(length=200), nullable=True, schema="sessions"
)
op.drop_column("environments", "environment_kind", schema="sessions")
op.drop_column("environments", "gid", schema="sessions")
op.drop_column("environments", "uid", schema="sessions")
op.drop_column("environments", "mount_directory", schema="sessions")
op.drop_column("environments", "working_directory", schema="sessions")
op.drop_column("environments", "port", schema="sessions")
op.execute("DROP TYPE environmentkind_old CASCADE")
# ### end Alembic commands ###
Loading

0 comments on commit 71b9da7

Please sign in to comment.