feat(api): search user trails by username
feat(db): index to search user trails by username
This commit is contained in:
parent
9fcba8703e
commit
18f0d2fbca
4 changed files with 26 additions and 14 deletions
|
|
@ -9,6 +9,7 @@ from pydantic import BaseModel, Field
|
|||
from starlette.background import BackgroundTask
|
||||
|
||||
import app as main_app
|
||||
import schemas
|
||||
import schemas_ee
|
||||
from chalicelib.utils import pg_client, helper
|
||||
from chalicelib.utils.TimeUTC import TimeUTC
|
||||
|
|
@ -154,29 +155,36 @@ async def process_traces_queue():
|
|||
|
||||
def get_all(tenant_id, data: schemas_ee.TrailSearchPayloadSchema):
|
||||
with pg_client.PostgresClient() as cur:
|
||||
conditions = ["tenant_id=%(tenant_id)s", "created_at>=%(startDate)s", "created_at<=%(endDate)s"]
|
||||
conditions = ["traces.tenant_id=%(tenant_id)s",
|
||||
"traces.created_at>=%(startDate)s",
|
||||
"traces.created_at<=%(endDate)s"]
|
||||
params = {"tenant_id": tenant_id,
|
||||
"startDate": data.startDate,
|
||||
"endDate": data.endDate,
|
||||
"p_start": (data.page - 1) * data.limit,
|
||||
"p_end": data.page * data.limit,
|
||||
**data.dict()}
|
||||
if data.user_id is not None:
|
||||
conditions.append("user_id=%(user_id)s")
|
||||
if data.action is not None:
|
||||
conditions.append("action=%(action)s")
|
||||
if data.query is not None and len(data.query) > 0:
|
||||
conditions.append("users.name ILIKE %(query)s")
|
||||
params["query"] = helper.values_for_operator(value=data.query,
|
||||
op=schemas.SearchEventOperator._contains)
|
||||
cur.execute(
|
||||
cur.mogrify(
|
||||
f"""SELECT COUNT(*) AS count,
|
||||
COALESCE(JSONB_AGG(full_traces)
|
||||
COALESCE(JSONB_AGG(full_traces ORDER BY rn)
|
||||
FILTER (WHERE rn > %(p_start)s AND rn <= %(p_end)s), '[]'::JSONB) AS sessions
|
||||
FROM (SELECT *, ROW_NUMBER() OVER (ORDER BY created_at) AS rn
|
||||
FROM traces
|
||||
FROM (SELECT traces.*,users.email,users.name AS username,
|
||||
ROW_NUMBER() OVER (ORDER BY traces.created_at {data.order}) AS rn
|
||||
FROM traces LEFT JOIN users USING (user_id)
|
||||
WHERE {" AND ".join(conditions)}
|
||||
ORDER BY created_at) AS full_traces;""",
|
||||
{"tenant_id": tenant_id,
|
||||
"startDate": data.startDate,
|
||||
"endDate": data.endDate,
|
||||
"p_start": (data.page - 1) * data.limit,
|
||||
"p_end": data.page * data.limit,
|
||||
**data.dict()})
|
||||
ORDER BY traces.created_at {data.order}) AS full_traces;""", params)
|
||||
)
|
||||
rows = cur.fetchall()
|
||||
return helper.list_to_camel_case(rows)
|
||||
rows = cur.fetchone()
|
||||
return helper.dict_to_camel_case(rows)
|
||||
|
||||
|
||||
def get_available_actions(tenant_id):
|
||||
|
|
|
|||
|
|
@ -1,4 +1,4 @@
|
|||
from typing import Optional, List
|
||||
from typing import Optional, List, Literal
|
||||
|
||||
from pydantic import BaseModel, Field
|
||||
|
||||
|
|
@ -29,7 +29,9 @@ class TrailSearchPayloadSchema(schemas._PaginatedSchema):
|
|||
startDate: int = Field(default=TimeUTC.now(-7))
|
||||
endDate: int = Field(default=TimeUTC.now(1))
|
||||
user_id: Optional[int] = Field(default=None)
|
||||
query: Optional[str] = Field(default=None)
|
||||
action: Optional[str] = Field(default=None)
|
||||
order: Literal["asc", "desc"] = Field(default="desc")
|
||||
|
||||
class Config:
|
||||
alias_generator = schemas.attribute_to_camel_case
|
||||
|
|
|
|||
|
|
@ -12,4 +12,5 @@ ALTER TABLE IF EXISTS dashboards
|
|||
|
||||
CREATE INDEX IF NOT EXISTS traces_created_at_idx ON traces (created_at);
|
||||
CREATE INDEX IF NOT EXISTS traces_action_idx ON traces (action);
|
||||
CREATE INDEX IF NOT EXISTS users_name_gin_idx ON users USING GIN (name gin_trgm_ops);
|
||||
COMMIT;
|
||||
|
|
@ -257,6 +257,7 @@ $$
|
|||
internal_id text NULL DEFAULT NULL
|
||||
);
|
||||
CREATE INDEX IF NOT EXISTS users_tenant_id_deleted_at_N_idx ON users (tenant_id) WHERE deleted_at ISNULL;
|
||||
CREATE INDEX IF NOT EXISTS users_name_gin_idx ON users USING GIN (name gin_trgm_ops);
|
||||
|
||||
|
||||
CREATE TABLE IF NOT EXISTS basic_authentication
|
||||
|
|
|
|||
Loading…
Add table
Reference in a new issue