feat(chalice): optimized /projects
feat(DB): changed projects structure
This commit is contained in:
parent
a6c77ed091
commit
698861f48d
6 changed files with 150 additions and 76 deletions
|
|
@ -43,17 +43,53 @@ def __create(tenant_id, name):
|
|||
|
||||
def get_projects(tenant_id, recording_state=False, gdpr=None, recorded=False, stack_integrations=False):
|
||||
with pg_client.PostgresClient() as cur:
|
||||
cur.execute(f"""\
|
||||
SELECT
|
||||
s.project_id, s.name, s.project_key, s.save_request_payloads
|
||||
{',s.gdpr' if gdpr else ''}
|
||||
{',COALESCE((SELECT TRUE FROM public.sessions WHERE sessions.project_id = s.project_id LIMIT 1), FALSE) AS recorded' if recorded else ''}
|
||||
{',stack_integrations.count>0 AS stack_integrations' if stack_integrations else ''}
|
||||
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 ''}
|
||||
WHERE s.deleted_at IS NULL
|
||||
ORDER BY s.project_id;""")
|
||||
extra_projection = ""
|
||||
extra_join = ""
|
||||
if gdpr:
|
||||
extra_projection += ',s.gdpr'
|
||||
if recorded:
|
||||
extra_projection += """, COALESCE(nullif(EXTRACT(EPOCH FROM s.first_recorded_session_at) * 1000, NULL)::BIGINT,
|
||||
(SELECT MIN(sessions.start_ts)
|
||||
FROM public.sessions
|
||||
WHERE sessions.project_id = s.project_id
|
||||
AND sessions.start_ts >= (EXTRACT(EPOCH FROM
|
||||
COALESCE(s.sessions_last_check_at, s.created_at)) * 1000-24*60*60*1000)
|
||||
AND sessions.start_ts <= %(now)s
|
||||
LIMIT 1), NULL) AS first_recorded"""
|
||||
if stack_integrations:
|
||||
extra_projection += ',stack_integrations.count>0 AS stack_integrations'
|
||||
|
||||
if stack_integrations:
|
||||
extra_join = """LEFT JOIN LATERAL (SELECT COUNT(*) AS count
|
||||
FROM public.integrations
|
||||
WHERE s.project_id = integrations.project_id
|
||||
LIMIT 1) AS stack_integrations ON TRUE"""
|
||||
|
||||
query = cur.mogrify(f"""{"SELECT *, first_recorded IS NOT NULL AS recorded FROM (" if recorded else ""}
|
||||
SELECT s.project_id, s.name, s.project_key, s.save_request_payloads, s.first_recorded_session_at
|
||||
{extra_projection}
|
||||
FROM public.projects AS s
|
||||
{extra_join}
|
||||
WHERE s.deleted_at IS NULL
|
||||
ORDER BY s.project_id {") AS raw" if recorded else ""};""", {"now": TimeUTC.now()})
|
||||
cur.execute(query)
|
||||
rows = cur.fetchall()
|
||||
# if recorded is requested, check if it was saved or computed
|
||||
if recorded:
|
||||
for r in rows:
|
||||
if r["first_recorded_session_at"] is None:
|
||||
extra_update = ""
|
||||
if r["recorded"]:
|
||||
extra_update = ", first_recorded_session_at=to_timestamp(%(first_recorded)s/1000)"
|
||||
query = cur.mogrify(f"""UPDATE public.projects
|
||||
SET sessions_last_check_at=(now() at time zone 'utc')
|
||||
{extra_update}
|
||||
WHERE project_id=%(project_id)s""",
|
||||
{"project_id": r["project_id"], "first_recorded": r["first_recorded"]})
|
||||
cur.execute(query)
|
||||
r.pop("first_recorded_session_at")
|
||||
r.pop("first_recorded")
|
||||
|
||||
if recording_state:
|
||||
project_ids = [f'({r["project_id"]})' for r in rows]
|
||||
query = cur.mogrify(f"""SELECT projects.project_id, COALESCE(MAX(start_ts), 0) AS last
|
||||
|
|
|
|||
|
|
@ -52,31 +52,57 @@ def get_projects(tenant_id, recording_state=False, gdpr=None, recorded=False, st
|
|||
AND users.tenant_id = %(tenant_id)s
|
||||
AND (roles.all_projects OR roles_projects.project_id = s.project_id)
|
||||
) AS role_project ON (TRUE)"""
|
||||
pre_select = ""
|
||||
extra_projection = ""
|
||||
extra_join = ""
|
||||
if gdpr:
|
||||
extra_projection += ',s.gdpr'
|
||||
if recorded:
|
||||
pre_select = """WITH recorded_p AS (SELECT DISTINCT projects.project_id
|
||||
FROM projects INNER JOIN sessions USING (project_id)
|
||||
WHERE tenant_id =%(tenant_id)s
|
||||
AND deleted_at IS NULL
|
||||
AND duration > 0)"""
|
||||
cur.execute(
|
||||
cur.mogrify(f"""\
|
||||
{pre_select}
|
||||
SELECT
|
||||
s.project_id, s.name, s.project_key, s.save_request_payloads
|
||||
{',s.gdpr' if gdpr else ''}
|
||||
{',EXISTS(SELECT 1 FROM recorded_p WHERE recorded_p.project_id = s.project_id) AS recorded' if recorded else ''}
|
||||
{',stack_integrations.count>0 AS stack_integrations' if stack_integrations else ''}
|
||||
FROM public.projects AS s
|
||||
{'LEFT JOIN recorded_p USING (project_id)' if recorded else ''}
|
||||
{'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, "user_id": user_id})
|
||||
)
|
||||
extra_projection += """,COALESCE(nullif(EXTRACT(EPOCH FROM s.first_recorded_session_at) * 1000, NULL)::BIGINT ,
|
||||
(SELECT MIN(sessions.start_ts)
|
||||
FROM public.sessions
|
||||
WHERE sessions.project_id = s.project_id
|
||||
AND sessions.start_ts >= (EXTRACT(EPOCH FROM
|
||||
COALESCE(s.sessions_last_check_at, s.created_at)) * 1000-24*60*60*1000)
|
||||
AND sessions.start_ts <= %(now)s
|
||||
LIMIT 1), NULL) AS first_recorded"""
|
||||
if stack_integrations:
|
||||
extra_projection += ',stack_integrations.count>0 AS stack_integrations'
|
||||
|
||||
if stack_integrations:
|
||||
extra_join = """LEFT JOIN LATERAL (SELECT COUNT(*) AS count
|
||||
FROM public.integrations
|
||||
WHERE s.project_id = integrations.project_id
|
||||
LIMIT 1) AS stack_integrations ON TRUE"""
|
||||
|
||||
query = cur.mogrify(f"""{"SELECT *, first_recorded IS NOT NULL AS recorded FROM (" if recorded else ""}
|
||||
SELECT s.project_id, s.name, s.project_key, s.save_request_payloads, s.first_recorded_session_at
|
||||
{extra_projection}
|
||||
FROM public.projects AS s
|
||||
{extra_join}
|
||||
{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 {") AS raw" if recorded else ""};""",
|
||||
{"tenant_id": tenant_id, "user_id": user_id, "now": TimeUTC.now()})
|
||||
cur.execute(query)
|
||||
rows = cur.fetchall()
|
||||
|
||||
# if recorded is requested, check if it was saved or computed
|
||||
if recorded:
|
||||
for r in rows:
|
||||
if r["first_recorded_session_at"] is None:
|
||||
extra_update = ""
|
||||
if r["recorded"]:
|
||||
extra_update = ", first_recorded_session_at=to_timestamp(%(first_recorded)s/1000)"
|
||||
query = cur.mogrify(f"""UPDATE public.projects
|
||||
SET sessions_last_check_at=(now() at time zone 'utc')
|
||||
{extra_update}
|
||||
WHERE project_id=%(project_id)s""",
|
||||
{"project_id": r["project_id"], "first_recorded": r["first_recorded"]})
|
||||
cur.execute(query)
|
||||
r.pop("first_recorded_session_at")
|
||||
r.pop("first_recorded")
|
||||
|
||||
if recording_state:
|
||||
project_ids = [f'({r["project_id"]})' for r in rows]
|
||||
query = cur.mogrify(f"""SELECT projects.project_id, COALESCE(MAX(start_ts), 0) AS last
|
||||
|
|
|
|||
|
|
@ -5,6 +5,10 @@ $$
|
|||
SELECT 'v1.8.0-ee'
|
||||
$$ LANGUAGE sql IMMUTABLE;
|
||||
|
||||
ALTER TABLE IF EXISTS projects
|
||||
ADD COLUMN IF NOT EXISTS first_recorded_session_at timestamp without time zone NULL DEFAULT NULL,
|
||||
ADD COLUMN IF NOT EXISTS sessions_last_check_at timestamp without time zone NULL DEFAULT NULL;
|
||||
|
||||
COMMIT;
|
||||
|
||||
CREATE UNIQUE INDEX CONCURRENTLY IF NOT EXISTS autocomplete_unique_project_id_md5value_type_idx ON autocomplete (project_id, md5(value), type);
|
||||
|
|
|
|||
|
|
@ -228,32 +228,34 @@ $$
|
|||
|
||||
CREATE TABLE IF NOT EXISTS projects
|
||||
(
|
||||
project_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY,
|
||||
project_key varchar(20) NOT NULL UNIQUE DEFAULT generate_api_key(20),
|
||||
tenant_id integer NOT NULL REFERENCES tenants (tenant_id) ON DELETE CASCADE,
|
||||
name text NOT NULL,
|
||||
active boolean NOT NULL,
|
||||
sample_rate smallint NOT NULL DEFAULT 100 CHECK (sample_rate >= 0 AND sample_rate <= 100),
|
||||
created_at timestamp without time zone NOT NULL DEFAULT (now() at time zone 'utc'),
|
||||
deleted_at timestamp without time zone NULL DEFAULT NULL,
|
||||
max_session_duration integer NOT NULL DEFAULT 7200000,
|
||||
metadata_1 text DEFAULT NULL,
|
||||
metadata_2 text DEFAULT NULL,
|
||||
metadata_3 text DEFAULT NULL,
|
||||
metadata_4 text DEFAULT NULL,
|
||||
metadata_5 text DEFAULT NULL,
|
||||
metadata_6 text DEFAULT NULL,
|
||||
metadata_7 text DEFAULT NULL,
|
||||
metadata_8 text DEFAULT NULL,
|
||||
metadata_9 text DEFAULT NULL,
|
||||
metadata_10 text DEFAULT NULL,
|
||||
save_request_payloads boolean NOT NULL DEFAULT FALSE,
|
||||
gdpr jsonb NOT NULL DEFAULT'{
|
||||
project_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY,
|
||||
project_key varchar(20) NOT NULL UNIQUE DEFAULT generate_api_key(20),
|
||||
tenant_id integer NOT NULL REFERENCES tenants (tenant_id) ON DELETE CASCADE,
|
||||
name text NOT NULL,
|
||||
active boolean NOT NULL,
|
||||
sample_rate smallint NOT NULL DEFAULT 100 CHECK (sample_rate >= 0 AND sample_rate <= 100),
|
||||
created_at timestamp without time zone NOT NULL DEFAULT (now() at time zone 'utc'),
|
||||
deleted_at timestamp without time zone NULL DEFAULT NULL,
|
||||
max_session_duration integer NOT NULL DEFAULT 7200000,
|
||||
metadata_1 text DEFAULT NULL,
|
||||
metadata_2 text DEFAULT NULL,
|
||||
metadata_3 text DEFAULT NULL,
|
||||
metadata_4 text DEFAULT NULL,
|
||||
metadata_5 text DEFAULT NULL,
|
||||
metadata_6 text DEFAULT NULL,
|
||||
metadata_7 text DEFAULT NULL,
|
||||
metadata_8 text DEFAULT NULL,
|
||||
metadata_9 text DEFAULT NULL,
|
||||
metadata_10 text DEFAULT NULL,
|
||||
save_request_payloads boolean NOT NULL DEFAULT FALSE,
|
||||
gdpr jsonb NOT NULL DEFAULT'{
|
||||
"maskEmails": true,
|
||||
"sampleRate": 33,
|
||||
"maskNumbers": false,
|
||||
"defaultInputMode": "plain"
|
||||
}'::jsonb
|
||||
}'::jsonb,
|
||||
first_recorded_session_at timestamp without time zone NULL DEFAULT NULL,
|
||||
sessions_last_check_at timestamp without time zone NULL DEFAULT NULL
|
||||
);
|
||||
|
||||
|
||||
|
|
|
|||
|
|
@ -5,6 +5,10 @@ $$
|
|||
SELECT 'v1.8.0'
|
||||
$$ LANGUAGE sql IMMUTABLE;
|
||||
|
||||
ALTER TABLE IF EXISTS projects
|
||||
ADD COLUMN IF NOT EXISTS first_recorded_session_at timestamp without time zone NULL DEFAULT NULL,
|
||||
ADD COLUMN IF NOT EXISTS sessions_last_check_at timestamp without time zone NULL DEFAULT NULL;
|
||||
|
||||
COMMIT;
|
||||
|
||||
CREATE UNIQUE INDEX CONCURRENTLY IF NOT EXISTS autocomplete_unique_project_id_md5value_type_idx ON autocomplete (project_id, md5(value), type);
|
||||
|
|
|
|||
|
|
@ -173,31 +173,33 @@ $$
|
|||
|
||||
CREATE TABLE projects
|
||||
(
|
||||
project_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY,
|
||||
project_key varchar(20) NOT NULL UNIQUE DEFAULT generate_api_key(20),
|
||||
name text NOT NULL,
|
||||
active boolean NOT NULL,
|
||||
sample_rate smallint NOT NULL DEFAULT 100 CHECK (sample_rate >= 0 AND sample_rate <= 100),
|
||||
created_at timestamp without time zone NOT NULL DEFAULT (now() at time zone 'utc'),
|
||||
deleted_at timestamp without time zone NULL DEFAULT NULL,
|
||||
max_session_duration integer NOT NULL DEFAULT 7200000,
|
||||
metadata_1 text DEFAULT NULL,
|
||||
metadata_2 text DEFAULT NULL,
|
||||
metadata_3 text DEFAULT NULL,
|
||||
metadata_4 text DEFAULT NULL,
|
||||
metadata_5 text DEFAULT NULL,
|
||||
metadata_6 text DEFAULT NULL,
|
||||
metadata_7 text DEFAULT NULL,
|
||||
metadata_8 text DEFAULT NULL,
|
||||
metadata_9 text DEFAULT NULL,
|
||||
metadata_10 text DEFAULT NULL,
|
||||
save_request_payloads boolean NOT NULL DEFAULT FALSE,
|
||||
gdpr jsonb NOT NULL DEFAULT '{
|
||||
project_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY,
|
||||
project_key varchar(20) NOT NULL UNIQUE DEFAULT generate_api_key(20),
|
||||
name text NOT NULL,
|
||||
active boolean NOT NULL,
|
||||
sample_rate smallint NOT NULL DEFAULT 100 CHECK (sample_rate >= 0 AND sample_rate <= 100),
|
||||
created_at timestamp without time zone NOT NULL DEFAULT (now() at time zone 'utc'),
|
||||
deleted_at timestamp without time zone NULL DEFAULT NULL,
|
||||
max_session_duration integer NOT NULL DEFAULT 7200000,
|
||||
metadata_1 text DEFAULT NULL,
|
||||
metadata_2 text DEFAULT NULL,
|
||||
metadata_3 text DEFAULT NULL,
|
||||
metadata_4 text DEFAULT NULL,
|
||||
metadata_5 text DEFAULT NULL,
|
||||
metadata_6 text DEFAULT NULL,
|
||||
metadata_7 text DEFAULT NULL,
|
||||
metadata_8 text DEFAULT NULL,
|
||||
metadata_9 text DEFAULT NULL,
|
||||
metadata_10 text DEFAULT NULL,
|
||||
save_request_payloads boolean NOT NULL DEFAULT FALSE,
|
||||
gdpr jsonb NOT NULL DEFAULT '{
|
||||
"maskEmails": true,
|
||||
"sampleRate": 33,
|
||||
"maskNumbers": false,
|
||||
"defaultInputMode": "plain"
|
||||
}'::jsonb -- ??????
|
||||
}'::jsonb,
|
||||
first_recorded_session_at timestamp without time zone NULL DEFAULT NULL,
|
||||
sessions_last_check_at timestamp without time zone NULL DEFAULT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX projects_project_key_idx ON public.projects (project_key);
|
||||
|
|
|
|||
Loading…
Add table
Reference in a new issue