feat(api): EE role-projects

feat(api): EE project authorizer by user
feat(api): EE projects list by user
This commit is contained in:
Taha Yassine Kraiem 2022-01-11 18:32:51 +01:00
parent 98b5fad26e
commit 99c31f2090
10 changed files with 202 additions and 72 deletions

View file

@ -16,10 +16,12 @@ class ProjectAuthorizer:
return
current_user: schemas.CurrentContext = await OR_context(request)
project_identifier = request.path_params[self.project_identifier]
user_id = current_user.user_id if request.state.authorizer_identity == "jwt" else None
if (self.project_identifier == "projectId" \
and not projects.is_authorized(project_id=project_identifier, tenant_id=current_user.tenant_id)) \
and not projects.is_authorized(project_id=project_identifier, tenant_id=current_user.tenant_id,
user_id=user_id)) \
or (self.project_identifier.lower() == "projectKey" \
and not projects.is_authorized(project_id=projects.get_internal_project_id(project_identifier),
tenant_id=current_user.tenant_id)):
tenant_id=current_user.tenant_id, user_id=user_id)):
print("unauthorized project")
raise HTTPException(status_code=status.HTTP_401_UNAUTHORIZED, detail="unauthorized project.")

View file

@ -42,7 +42,7 @@ def __create(tenant_id, name):
def get_projects(tenant_id, recording_state=False, gdpr=None, recorded=False, stack_integrations=False, version=False,
last_tracker_version=None):
last_tracker_version=None, user_id=None):
with pg_client.PostgresClient() as cur:
tracker_query = ""
if last_tracker_version is not None and len(last_tracker_version) > 0:
@ -54,6 +54,15 @@ def get_projects(tenant_id, recording_state=False, gdpr=None, recorded=False, st
elif version:
tracker_query = ",(SELECT tracker_version FROM public.sessions WHERE sessions.project_id = s.project_id ORDER BY start_ts DESC LIMIT 1) AS tracker_version"
role_query = """INNER JOIN LATERAL (SELECT 1
FROM users
INNER JOIN roles USING (role_id)
LEFT JOIN roles_projects USING (role_id)
WHERE users.user_id = %(user_id)s
AND users.deleted_at ISNULL
AND users.tenant_id = %(tenant_id)s
AND (roles.all_projects OR roles_projects.project_id = s.project_id)
) AS role_project ON (TRUE)"""
cur.execute(
cur.mogrify(f"""\
SELECT
@ -64,10 +73,11 @@ def get_projects(tenant_id, recording_state=False, gdpr=None, recorded=False, st
{tracker_query}
FROM public.projects AS s
{'LEFT JOIN LATERAL (SELECT COUNT(*) AS count FROM public.integrations WHERE s.project_id = integrations.project_id LIMIT 1) AS stack_integrations ON TRUE' if stack_integrations else ''}
{role_query if user_id is not None else ""}
WHERE s.tenant_id =%(tenant_id)s
AND s.deleted_at IS NULL
ORDER BY s.project_id;""",
{"tenant_id": tenant_id})
{"tenant_id": tenant_id, "user_id": user_id})
)
rows = cur.fetchall()
if recording_state:
@ -124,10 +134,34 @@ def get_project(tenant_id, project_id, include_last_session=False, include_gdpr=
return helper.dict_to_camel_case(row)
def is_authorized(project_id, tenant_id):
def is_authorized(project_id, tenant_id, user_id=None):
if project_id is None or not str(project_id).isdigit():
return False
return get_project(tenant_id=tenant_id, project_id=project_id) is not None
with pg_client.PostgresClient() as cur:
role_query = """INNER JOIN LATERAL (SELECT 1
FROM users
INNER JOIN roles USING (role_id)
LEFT JOIN roles_projects USING (role_id)
WHERE users.user_id = %(user_id)s
AND users.deleted_at ISNULL
AND users.tenant_id = %(tenant_id)s
AND (roles.all_projects OR roles_projects.project_id = %(project_id)s)
) AS role_project ON (TRUE)"""
query = cur.mogrify(f"""\
SELECT project_id
FROM public.projects AS s
{role_query if user_id is not None else ""}
where s.tenant_id =%(tenant_id)s
AND s.project_id =%(project_id)s
AND s.deleted_at IS NULL
LIMIT 1;""",
{"tenant_id": tenant_id, "project_id": project_id, "user_id": user_id})
cur.execute(
query=query
)
row = cur.fetchone()
return row is not None
def create(tenant_id, user_id, data: schemas.CreateProjectSchema, skip_authorization=False):
@ -275,3 +309,22 @@ def get_project_by_key(tenant_id, project_key, include_last_session=False, inclu
)
row = cur.fetchone()
return helper.dict_to_camel_case(row)
def is_authorized_batch(project_ids, tenant_id):
if project_ids is None or not len(project_ids):
return False
with pg_client.PostgresClient() as cur:
query = cur.mogrify("""\
SELECT project_id
FROM public.projects
where tenant_id =%(tenant_id)s
AND project_id IN %(project_ids)s
AND deleted_at IS NULL;""",
{"tenant_id": tenant_id, "project_ids": tuple(project_ids)})
cur.execute(
query=query
)
rows = cur.fetchall()
return [r["project_id"] for r in rows]

View file

@ -1,64 +1,111 @@
from chalicelib.core import users
import schemas_ee
from chalicelib.core import users, projects
from chalicelib.utils import pg_client, helper
from chalicelib.utils.TimeUTC import TimeUTC
def update(tenant_id, user_id, role_id, changes):
def update(tenant_id, user_id, role_id, data: schemas_ee.RolePayloadSchema):
admin = users.get(user_id=user_id, tenant_id=tenant_id)
if not admin["admin"] and not admin["superAdmin"]:
return {"errors": ["unauthorized"]}
if len(changes.keys()) == 0:
return None
ALLOW_EDIT = ["name", "description", "permissions"]
sub_query = []
for key in changes.keys():
if key in ALLOW_EDIT:
sub_query.append(f"{helper.key_to_snake_case(key)} = %({key})s")
if not data.all_projects and (data.projects is None or len(data.projects) == 0):
return {"errors": ["must specify a project or all projects"]}
if data.projects is not None and len(data.projects) > 0 and not data.all_projects:
data.projects = projects.is_authorized_batch(project_ids=data.projects, tenant_id=tenant_id)
with pg_client.PostgresClient() as cur:
cur.execute(
cur.mogrify(f"""\
cur.mogrify("""SELECT 1
FROM public.roles
WHERE role_id = %(role_id)s
AND tenant_id = %(tenant_id)s
AND protected = TRUE
LIMIT 1;""",
{"tenant_id": tenant_id, "role_id": role_id})
)
if cur.fetchone() is not None:
return {"errors": ["this role is protected"]}
cur.execute(
cur.mogrify("""\
UPDATE public.roles
SET {" ,".join(sub_query)}
SET name= %(name)s,
description= %(description)s,
permissions= %(permissions)s,
all_projects= %(all_projects)s
WHERE role_id = %(role_id)s
AND tenant_id = %(tenant_id)s
AND deleted_at ISNULL
AND protected = FALSE
RETURNING *;""",
{"tenant_id": tenant_id, "role_id": role_id, **changes})
RETURNING *, COALESCE((SELECT ARRAY_AGG(project_id)
FROM roles_projects WHERE roles_projects.role_id=%(role_id)s),'{}') AS projects;""",
{"tenant_id": tenant_id, "role_id": role_id, **data.dict()})
)
row = cur.fetchone()
row["created_at"] = TimeUTC.datetime_to_timestamp(row["created_at"])
if not data.all_projects:
d_projects = [i for i in row["projects"] if i not in data.projects]
if len(d_projects) > 0:
cur.execute(
cur.mogrify(
"DELETE FROM roles_projects WHERE role_id=%(role_id)s AND project_id IN %(project_ids)s",
{"role_id": role_id, "project_ids": tuple(d_projects)})
)
n_projects = [i for i in data.projects if i not in row["projects"]]
if len(n_projects) > 0:
cur.execute(
cur.mogrify(
f"""INSERT INTO roles_projects(role_id, project_id)
VALUES {",".join([f"(%(role_id)s,%(project_id_{i})s)" for i in range(len(n_projects))])}""",
{"role_id": role_id, **{f"project_id_{i}": p for i, p in enumerate(n_projects)}})
)
row["projects"] = data.projects
return helper.dict_to_camel_case(row)
def create(tenant_id, user_id, name, description, permissions):
def create(tenant_id, user_id, data: schemas_ee.RolePayloadSchema):
admin = users.get(user_id=user_id, tenant_id=tenant_id)
if not admin["admin"] and not admin["superAdmin"]:
return {"errors": ["unauthorized"]}
if not data.all_projects and (data.projects is None or len(data.projects) == 0):
return {"errors": ["must specify a project or all projects"]}
if data.projects is not None and len(data.projects) > 0 and not data.all_projects:
data.projects = projects.is_authorized_batch(project_ids=data.projects, tenant_id=tenant_id)
with pg_client.PostgresClient() as cur:
cur.execute(
cur.mogrify("""INSERT INTO roles(tenant_id, name, description, permissions)
VALUES (%(tenant_id)s, %(name)s, %(description)s, %(permissions)s::text[])
cur.mogrify("""INSERT INTO roles(tenant_id, name, description, permissions, all_projects)
VALUES (%(tenant_id)s, %(name)s, %(description)s, %(permissions)s::text[], %(all_projects)s)
RETURNING *;""",
{"tenant_id": tenant_id, "name": name, "description": description, "permissions": permissions})
{"tenant_id": tenant_id, "name": data.name, "description": data.description,
"permissions": data.permissions, "all_projects": data.all_projects})
)
row = cur.fetchone()
row["created_at"] = TimeUTC.datetime_to_timestamp(row["created_at"])
if not data.all_projects:
role_id = row["role_id"]
cur.execute(
cur.mogrify(f"""INSERT INTO roles_projects(role_id, project_id)
VALUES {",".join(f"(%(role_id)s,%(project_id_{i})s)" for i in range(len(data.projects)))};""",
{"role_id": role_id, **{f"project_id_{i}": p for i, p in enumerate(data.projects)}})
)
return helper.dict_to_camel_case(row)
def get_roles(tenant_id):
with pg_client.PostgresClient() as cur:
cur.execute(
cur.mogrify("""SELECT *
FROM public.roles
where tenant_id =%(tenant_id)s
AND deleted_at IS NULL
ORDER BY role_id;""",
cur.mogrify("""SELECT *, COALESCE(projects, '{}') AS projects
FROM public.roles
LEFT JOIN LATERAL (SELECT array_agg(project_id) AS projects
FROM roles_projects
INNER JOIN projects USING (project_id)
WHERE roles_projects.role_id = roles.role_id
AND projects.deleted_at ISNULL ) AS role_projects ON (TRUE)
WHERE tenant_id =%(tenant_id)s
AND deleted_at IS NULL
ORDER BY role_id;""",
{"tenant_id": tenant_id})
)
rows = cur.fetchall()
@ -71,11 +118,10 @@ def get_role_by_name(tenant_id, name):
with pg_client.PostgresClient() as cur:
cur.execute(
cur.mogrify("""SELECT *
FROM public.roles
where tenant_id =%(tenant_id)s
AND deleted_at IS NULL
AND name ILIKE %(name)s
;""",
FROM public.roles
where tenant_id =%(tenant_id)s
AND deleted_at IS NULL
AND name ILIKE %(name)s;""",
{"tenant_id": tenant_id, "name": name})
)
row = cur.fetchone()
@ -92,11 +138,11 @@ def delete(tenant_id, user_id, role_id):
with pg_client.PostgresClient() as cur:
cur.execute(
cur.mogrify("""SELECT 1
FROM public.roles
WHERE role_id = %(role_id)s
AND tenant_id = %(tenant_id)s
AND protected = TRUE
LIMIT 1;""",
FROM public.roles
WHERE role_id = %(role_id)s
AND tenant_id = %(tenant_id)s
AND protected = TRUE
LIMIT 1;""",
{"tenant_id": tenant_id, "role_id": role_id})
)
if cur.fetchone() is not None:

View file

@ -482,7 +482,7 @@ def change_password(tenant_id, user_id, email, old_password, new_password):
c = tenants.get_by_tenant_id(tenant_id)
c.pop("createdAt")
c["projects"] = projects.get_projects(tenant_id=tenant_id, recording_state=True, recorded=True,
stack_integrations=True)
stack_integrations=True, user_id=user_id)
c["smtp"] = helper.has_smtp()
c["iceServers"] = assist.get_ice_servers()
return {
@ -510,7 +510,7 @@ def set_password_invitation(tenant_id, user_id, new_password):
c = tenants.get_by_tenant_id(tenant_id)
c.pop("createdAt")
c["projects"] = projects.get_projects(tenant_id=tenant_id, recording_state=True, recorded=True,
stack_integrations=True)
stack_integrations=True, user_id=user_id)
c["smtp"] = helper.has_smtp()
c["iceServers"] = assist.get_ice_servers()
return {

View file

@ -52,7 +52,7 @@ def login(data: schemas.UserLoginSchema = Body(...)):
c = tenants.get_by_tenant_id(tenant_id)
c.pop("createdAt")
c["projects"] = projects.get_projects(tenant_id=tenant_id, recording_state=True, recorded=True,
stack_integrations=True, version=True)
stack_integrations=True, version=True, user_id=r["id"])
c["smtp"] = helper.has_smtp()
c["iceServers"] = assist.get_ice_servers()
r["smtp"] = c["smtp"]
@ -195,7 +195,8 @@ def search_sessions_by_metadata(key: str, value: str, projectId: Optional[int] =
if key is None or value is None or len(value) == 0 and len(key) == 0:
return {"errors": ["please provide a key&value for search"]}
if projectId is not None and not projects.is_authorized(project_id=projectId, tenant_id=context.tenant_id):
if projectId is not None and not projects.is_authorized(project_id=projectId, tenant_id=context.tenant_id,
user_id=context.user_id):
return {"errors": ["unauthorized project"]}
if len(value) == 0:
return {"errors": ["please provide a value for search"]}

View file

@ -23,7 +23,7 @@ def get_roles(context: schemas.CurrentContext = Depends(OR_context)):
@app.post('/client/roles', tags=["client", "roles"])
@app.put('/client/roles', tags=["client", "roles"])
def add_role(data: schemas_ee.RolePayloadSchema = Body(...), context: schemas.CurrentContext = Depends(OR_context)):
data = roles.create(tenant_id=context.tenant_id, user_id=context.user_id, **data.dict())
data = roles.create(tenant_id=context.tenant_id, user_id=context.user_id, data=data)
if "errors" in data:
return data
@ -36,7 +36,7 @@ def add_role(data: schemas_ee.RolePayloadSchema = Body(...), context: schemas.Cu
@app.put('/client/roles/{roleId}', tags=["client", "roles"])
def edit_role(roleId: int, data: schemas_ee.RolePayloadSchema = Body(...),
context: schemas.CurrentContext = Depends(OR_context)):
data = roles.update(tenant_id=context.tenant_id, user_id=context.user_id, role_id=roleId, changes=data.dict())
data = roles.update(tenant_id=context.tenant_id, user_id=context.user_id, role_id=roleId, data=data)
if "errors" in data:
return data

View file

@ -9,6 +9,11 @@ class RolePayloadSchema(BaseModel):
name: str = Field(...)
description: Optional[str] = Field(None)
permissions: List[str] = Field(...)
all_projects: bool = Field(True)
projects: List[int] = Field([])
class Config:
alias_generator = schemas.attribute_to_camel_case
class CreateMemberSchema(schemas.CreateMemberSchema):

View file

@ -37,9 +37,9 @@ CREATE INDEX IF NOT EXISTS errors_session_id_timestamp_error_id_idx ON events.er
CREATE INDEX IF NOT EXISTS errors_error_id_timestamp_idx ON events.errors (error_id, timestamp);
CREATE INDEX IF NOT EXISTS errors_timestamp_error_id_session_id_idx ON events.errors (timestamp, error_id, session_id);
CREATE INDEX IF NOT EXISTS errors_error_id_timestamp_session_id_idx ON events.errors (error_id, timestamp, session_id);
CREATE INDEX ON events.resources (timestamp);
CREATE INDEX ON events.resources (success);
CREATE INDEX ON public.projects (project_key);
CREATE INDEX IF NOT EXISTS resources_timestamp_idx ON events.resources (timestamp);
CREATE INDEX IF NOT EXISTS resources_success_idx ON events.resources (success);
CREATE INDEX IF NOT EXISTS projects_project_key_idx ON public.projects (project_key);
CREATE INDEX IF NOT EXISTS resources_timestamp_type_durationgt0NN_idx ON events.resources (timestamp, type) WHERE duration > 0 AND duration IS NOT NULL;
CREATE INDEX IF NOT EXISTS resources_session_id_timestamp_idx ON events.resources (session_id, timestamp);
CREATE INDEX IF NOT EXISTS resources_session_id_timestamp_type_idx ON events.resources (session_id, timestamp, type);
@ -63,9 +63,9 @@ ALTER TABLE tenants
ALTER COLUMN name SET NOT NULL;
ALTER TABLE sessions
ADD COLUMN utm_source text NULL DEFAULT NULL,
ADD COLUMN utm_medium text NULL DEFAULT NULL,
ADD COLUMN utm_campaign text NULL DEFAULT NULL;
ADD COLUMN IF NOT EXISTS utm_source text NULL DEFAULT NULL,
ADD COLUMN IF NOT EXISTS utm_medium text NULL DEFAULT NULL,
ADD COLUMN IF NOT EXISTS utm_campaign text NULL DEFAULT NULL;
CREATE INDEX IF NOT EXISTS sessions_utm_source_gin_idx ON public.sessions USING GIN (utm_source gin_trgm_ops);
CREATE INDEX IF NOT EXISTS sessions_utm_medium_gin_idx ON public.sessions USING GIN (utm_medium gin_trgm_ops);
@ -85,7 +85,7 @@ CREATE INDEX IF NOT EXISTS performance_session_id_timestamp_idx ON events.perfor
CREATE INDEX IF NOT EXISTS performance_avg_cpu_gt0_idx ON events.performance (avg_cpu) WHERE avg_cpu > 0;
CREATE INDEX IF NOT EXISTS performance_avg_used_js_heap_size_gt0_idx ON events.performance (avg_used_js_heap_size) WHERE avg_used_js_heap_size > 0;
CREATE TABLE metrics
CREATE TABLE IF NOT EXISTS metrics
(
metric_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY,
project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE,
@ -96,7 +96,7 @@ CREATE TABLE metrics
deleted_at timestamp
);
CREATE INDEX IF NOT EXISTS metrics_user_id_is_public_idx ON public.metrics (user_id, is_public);
CREATE TABLE metric_series
CREATE TABLE IF NOT EXISTS metric_series
(
series_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY,
metric_id integer REFERENCES metrics (metric_id) ON DELETE CASCADE,
@ -110,7 +110,7 @@ CREATE INDEX IF NOT EXISTS metric_series_metric_id_idx ON public.metric_series (
CREATE INDEX IF NOT EXISTS funnels_project_id_idx ON public.funnels (project_id);
CREATE TABLE searches
CREATE TABLE IF NOT EXISTS searches
(
search_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY,
project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE,
@ -127,11 +127,24 @@ CREATE INDEX IF NOT EXISTS searches_project_id_idx ON public.searches (project_i
CREATE INDEX IF NOT EXISTS alerts_project_id_idx ON alerts (project_id);
ALTER TABLE alerts
ADD COLUMN series_id integer NULL REFERENCES metric_series (series_id) ON DELETE CASCADE;
ADD COLUMN IF NOT EXISTS series_id integer NULL REFERENCES metric_series (series_id) ON DELETE CASCADE;
CREATE INDEX IF NOT EXISTS alerts_series_id_idx ON alerts (series_id);
UPDATE alerts
SET options=jsonb_set(options, '{change}', '"change"')
WHERE detection_method = 'change'
AND options -> 'change' ISNULL;
ALTER TABLE roles
ADD COLUMN IF NOT EXISTS all_projects bool NOT NULL DEFAULT TRUE;
CREATE TABLE IF NOT EXISTS roles_projects
(
role_id integer NOT NULL REFERENCES roles (role_id) ON DELETE CASCADE,
project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE,
CONSTRAINT roles_projects_pkey PRIMARY KEY (role_id, project_id)
);
CREATE INDEX IF NOT EXISTS roles_projects_role_id_idx ON roles_projects (role_id);
CREATE INDEX IF NOT EXISTS roles_projects_project_id_idx ON roles_projects (project_id);
COMMIT;

View file

@ -137,14 +137,15 @@ $$
CREATE TABLE roles
(
role_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY,
tenant_id integer NOT NULL REFERENCES tenants (tenant_id) ON DELETE CASCADE,
name text NOT NULL,
description text DEFAULT NULL,
permissions text[] NOT NULL DEFAULT '{}',
protected bool NOT NULL DEFAULT FALSE,
created_at timestamp NOT NULL DEFAULT timezone('utc'::text, now()),
deleted_at timestamp NULL DEFAULT NULL
role_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY,
tenant_id integer NOT NULL REFERENCES tenants (tenant_id) ON DELETE CASCADE,
name text NOT NULL,
description text DEFAULT NULL,
permissions text[] NOT NULL DEFAULT '{}',
protected bool NOT NULL DEFAULT FALSE,
all_projects bool NOT NULL DEFAULT TRUE,
created_at timestamp NOT NULL DEFAULT timezone('utc'::text, now()),
deleted_at timestamp NULL DEFAULT NULL
);
CREATE TYPE user_role AS ENUM ('owner', 'admin', 'member');
@ -293,6 +294,15 @@ $$
FOR EACH ROW
EXECUTE PROCEDURE notify_project();
CREATE TABLE roles_projects
(
role_id integer NOT NULL REFERENCES roles (role_id) ON DELETE CASCADE,
project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE,
CONSTRAINT roles_projects_pkey PRIMARY KEY (role_id, project_id)
);
CREATE INDEX roles_projects_role_id_idx ON roles_projects (role_id);
CREATE INDEX roles_projects_project_id_idx ON roles_projects (project_id);
-- --- webhooks.sql ---
create type webhook_type as enum ('webhook', 'slack', 'email');

View file

@ -9,13 +9,13 @@ CREATE INDEX IF NOT EXISTS user_favorite_sessions_user_id_session_id_idx ON user
CREATE INDEX IF NOT EXISTS pages_session_id_timestamp_idx ON events.pages (session_id, timestamp);
CREATE INDEX ON events.errors (timestamp);
CREATE INDEX ON public.projects (project_key);
CREATE INDEX IF NOT EXISTS errors_timestamp_idx ON events.errors (timestamp);
CREATE INDEX IF NOT EXISTS projects_project_key_idx ON public.projects (project_key);
ALTER TABLE sessions
ADD COLUMN utm_source text NULL DEFAULT NULL,
ADD COLUMN utm_medium text NULL DEFAULT NULL,
ADD COLUMN utm_campaign text NULL DEFAULT NULL;
ADD COLUMN IF NOT EXISTS utm_source text NULL DEFAULT NULL,
ADD COLUMN IF NOT EXISTS utm_medium text NULL DEFAULT NULL,
ADD COLUMN IF NOT EXISTS utm_campaign text NULL DEFAULT NULL;
CREATE INDEX IF NOT EXISTS sessions_utm_source_gin_idx ON public.sessions USING GIN (utm_source gin_trgm_ops);
CREATE INDEX IF NOT EXISTS sessions_utm_medium_gin_idx ON public.sessions USING GIN (utm_medium gin_trgm_ops);
@ -36,7 +36,7 @@ CREATE INDEX IF NOT EXISTS performance_session_id_timestamp_idx ON events.perfor
CREATE INDEX IF NOT EXISTS performance_avg_cpu_gt0_idx ON events.performance (avg_cpu) WHERE avg_cpu > 0;
CREATE INDEX IF NOT EXISTS performance_avg_used_js_heap_size_gt0_idx ON events.performance (avg_used_js_heap_size) WHERE avg_used_js_heap_size > 0;
CREATE TABLE metrics
CREATE TABLE IF NOT EXISTS metrics
(
metric_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY,
project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE,
@ -47,7 +47,7 @@ CREATE TABLE metrics
deleted_at timestamp
);
CREATE INDEX IF NOT EXISTS metrics_user_id_is_public_idx ON public.metrics (user_id, is_public);
CREATE TABLE metric_series
CREATE TABLE IF NOT EXISTS metric_series
(
series_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY,
metric_id integer REFERENCES metrics (metric_id) ON DELETE CASCADE,
@ -62,7 +62,7 @@ CREATE INDEX IF NOT EXISTS metric_series_metric_id_idx ON public.metric_series (
CREATE INDEX IF NOT EXISTS funnels_project_id_idx ON public.funnels (project_id);
CREATE TABLE searches
CREATE TABLE IF NOT EXISTS searches
(
search_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY,
project_id integer NOT NULL REFERENCES projects (project_id) ON DELETE CASCADE,
@ -79,7 +79,7 @@ CREATE INDEX IF NOT EXISTS searches_project_id_idx ON public.searches (project_i
CREATE INDEX IF NOT EXISTS alerts_project_id_idx ON alerts (project_id);
ALTER TABLE alerts
ADD COLUMN series_id integer NULL REFERENCES metric_series (series_id) ON DELETE CASCADE;
ADD COLUMN IF NOT EXISTS series_id integer NULL REFERENCES metric_series (series_id) ON DELETE CASCADE;
CREATE INDEX IF NOT EXISTS alerts_series_id_idx ON alerts (series_id);
UPDATE alerts