add many-to-many relationship between groups and users
This commit is contained in:
parent
eccb753c3c
commit
7af24f59c3
3 changed files with 133 additions and 63 deletions
|
|
@ -78,13 +78,16 @@ def get_provider_resource_chunk(
|
||||||
"""
|
"""
|
||||||
SELECT
|
SELECT
|
||||||
groups.*,
|
groups.*,
|
||||||
users_data.array as users
|
COALESCE(
|
||||||
|
(
|
||||||
|
SELECT json_agg(users)
|
||||||
|
FROM public.user_group
|
||||||
|
JOIN public.users USING (user_id)
|
||||||
|
WHERE user_group.group_id = groups.group_id
|
||||||
|
),
|
||||||
|
'[]'
|
||||||
|
) AS users
|
||||||
FROM public.groups
|
FROM public.groups
|
||||||
LEFT JOIN LATERAL (
|
|
||||||
SELECT json_agg(users) AS array
|
|
||||||
FROM public.users
|
|
||||||
WHERE users.group_id = groups.group_id
|
|
||||||
) users_data ON true
|
|
||||||
WHERE groups.tenant_id = %(tenant_id)s
|
WHERE groups.tenant_id = %(tenant_id)s
|
||||||
LIMIT %(limit)s
|
LIMIT %(limit)s
|
||||||
OFFSET %(offset)s;
|
OFFSET %(offset)s;
|
||||||
|
|
@ -108,13 +111,16 @@ def get_provider_resource(
|
||||||
"""
|
"""
|
||||||
SELECT
|
SELECT
|
||||||
groups.*,
|
groups.*,
|
||||||
users_data.array as users
|
COALESCE(
|
||||||
|
(
|
||||||
|
SELECT json_agg(users)
|
||||||
|
FROM public.user_group
|
||||||
|
JOIN public.users USING (user_id)
|
||||||
|
WHERE user_group.group_id = groups.group_id
|
||||||
|
),
|
||||||
|
'[]'
|
||||||
|
) AS users
|
||||||
FROM public.groups
|
FROM public.groups
|
||||||
LEFT JOIN LATERAL (
|
|
||||||
SELECT json_agg(users) AS array
|
|
||||||
FROM public.users
|
|
||||||
WHERE users.group_id = groups.group_id
|
|
||||||
) users_data ON true
|
|
||||||
WHERE
|
WHERE
|
||||||
groups.tenant_id = %(tenant_id)s
|
groups.tenant_id = %(tenant_id)s
|
||||||
AND groups.group_id = %(group_id)s
|
AND groups.group_id = %(group_id)s
|
||||||
|
|
@ -188,26 +194,24 @@ def create_provider_resource(
|
||||||
VALUES ({value_clause})
|
VALUES ({value_clause})
|
||||||
RETURNING *
|
RETURNING *
|
||||||
),
|
),
|
||||||
linked_users AS (
|
ugs AS (
|
||||||
UPDATE public.users
|
INSERT INTO public.user_group (user_id, group_id)
|
||||||
SET
|
SELECT users.user_id, g.group_id
|
||||||
group_id = g.group_id,
|
|
||||||
updated_at = now()
|
|
||||||
FROM g
|
FROM g
|
||||||
WHERE
|
JOIN public.users ON users.user_id = ANY({user_id_clause})
|
||||||
users.user_id = ANY({user_id_clause})
|
|
||||||
AND users.deleted_at IS NULL
|
|
||||||
AND users.tenant_id = {tenant_id}
|
|
||||||
RETURNING *
|
RETURNING *
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
g.*,
|
g.*,
|
||||||
COALESCE(users_data.array, '[]') as users
|
COALESCE(
|
||||||
|
(
|
||||||
|
SELECT json_agg(users)
|
||||||
|
FROM ugs
|
||||||
|
JOIN public.users USING (user_id)
|
||||||
|
),
|
||||||
|
'[]'
|
||||||
|
) AS users
|
||||||
FROM g
|
FROM g
|
||||||
LEFT JOIN LATERAL (
|
|
||||||
SELECT json_agg(lu) AS array
|
|
||||||
FROM linked_users AS lu
|
|
||||||
) users_data ON true
|
|
||||||
LIMIT 1;
|
LIMIT 1;
|
||||||
"""
|
"""
|
||||||
)
|
)
|
||||||
|
|
@ -245,6 +249,12 @@ def _update_resource_sql(
|
||||||
cur.mogrify("%s", (user_id,)).decode("utf-8") for user_id in user_ids
|
cur.mogrify("%s", (user_id,)).decode("utf-8") for user_id in user_ids
|
||||||
]
|
]
|
||||||
user_id_clause = f"ARRAY[{', '.join(user_id_fragments)}]::int[]"
|
user_id_clause = f"ARRAY[{', '.join(user_id_fragments)}]::int[]"
|
||||||
|
cur.execute(
|
||||||
|
f"""
|
||||||
|
DELETE FROM public.user_group
|
||||||
|
WHERE user_group.group_id = {group_id}
|
||||||
|
"""
|
||||||
|
)
|
||||||
cur.execute(
|
cur.execute(
|
||||||
f"""
|
f"""
|
||||||
WITH
|
WITH
|
||||||
|
|
@ -256,36 +266,25 @@ def _update_resource_sql(
|
||||||
AND groups.tenant_id = {tenant_id}
|
AND groups.tenant_id = {tenant_id}
|
||||||
RETURNING *
|
RETURNING *
|
||||||
),
|
),
|
||||||
unlinked_users AS (
|
linked_user_group AS (
|
||||||
UPDATE public.users
|
INSERT INTO public.user_group (user_id, group_id)
|
||||||
SET
|
SELECT users.user_id, g.group_id
|
||||||
group_id = null,
|
FROM g
|
||||||
updated_at = now()
|
JOIN public.users ON users.user_id = ANY({user_id_clause})
|
||||||
WHERE
|
WHERE users.deleted_at IS NULL AND users.tenant_id = {tenant_id}
|
||||||
users.group_id = {group_id}
|
|
||||||
AND users.user_id <> ALL({user_id_clause})
|
|
||||||
AND users.deleted_at IS NULL
|
|
||||||
AND users.tenant_id = {tenant_id}
|
|
||||||
),
|
|
||||||
linked_users AS (
|
|
||||||
UPDATE public.users
|
|
||||||
SET
|
|
||||||
group_id = {group_id},
|
|
||||||
updated_at = now()
|
|
||||||
WHERE
|
|
||||||
users.user_id = ANY({user_id_clause})
|
|
||||||
AND users.deleted_at IS NULL
|
|
||||||
AND users.tenant_id = {tenant_id}
|
|
||||||
RETURNING *
|
RETURNING *
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
g.*,
|
g.*,
|
||||||
COALESCE(users_data.array, '[]') as users
|
COALESCE(
|
||||||
|
(
|
||||||
|
SELECT json_agg(users)
|
||||||
|
FROM linked_user_group
|
||||||
|
JOIN public.users USING (user_id)
|
||||||
|
),
|
||||||
|
'[]'
|
||||||
|
) AS users
|
||||||
FROM g
|
FROM g
|
||||||
LEFT JOIN LATERAL (
|
|
||||||
SELECT json_agg(lu) AS array
|
|
||||||
FROM linked_users AS lu
|
|
||||||
) users_data ON true
|
|
||||||
LIMIT 1;
|
LIMIT 1;
|
||||||
"""
|
"""
|
||||||
)
|
)
|
||||||
|
|
|
||||||
|
|
@ -156,6 +156,13 @@ def convert_provider_resource_to_client_resource(
|
||||||
"displayName": provider_resource["name"] or provider_resource["email"],
|
"displayName": provider_resource["name"] or provider_resource["email"],
|
||||||
"userType": provider_resource.get("role_name"),
|
"userType": provider_resource.get("role_name"),
|
||||||
"active": provider_resource["deleted_at"] is None,
|
"active": provider_resource["deleted_at"] is None,
|
||||||
|
"groups": [
|
||||||
|
{
|
||||||
|
"value": str(group["group_id"]),
|
||||||
|
"$ref": f"Groups/{group['group_id']}",
|
||||||
|
}
|
||||||
|
for group in provider_resource["groups"]
|
||||||
|
],
|
||||||
}
|
}
|
||||||
|
|
||||||
|
|
||||||
|
|
@ -185,7 +192,16 @@ def get_provider_resource_chunk(
|
||||||
"""
|
"""
|
||||||
SELECT
|
SELECT
|
||||||
users.*,
|
users.*,
|
||||||
roles.name AS role_name
|
roles.name AS role_name,
|
||||||
|
COALESCE(
|
||||||
|
(
|
||||||
|
SELECT json_agg(groups)
|
||||||
|
FROM public.user_group
|
||||||
|
JOIN public.groups USING (group_id)
|
||||||
|
WHERE user_group.user_id = users.user_id
|
||||||
|
),
|
||||||
|
'[]'
|
||||||
|
) AS groups
|
||||||
FROM public.users
|
FROM public.users
|
||||||
LEFT JOIN public.roles USING (role_id)
|
LEFT JOIN public.roles USING (role_id)
|
||||||
WHERE
|
WHERE
|
||||||
|
|
@ -209,7 +225,16 @@ def get_provider_resource(
|
||||||
"""
|
"""
|
||||||
SELECT
|
SELECT
|
||||||
users.*,
|
users.*,
|
||||||
roles.name AS role_name
|
roles.name AS role_name,
|
||||||
|
COALESCE(
|
||||||
|
(
|
||||||
|
SELECT json_agg(groups)
|
||||||
|
FROM public.user_group
|
||||||
|
JOIN public.groups USING (group_id)
|
||||||
|
WHERE user_group.user_id = users.user_id
|
||||||
|
),
|
||||||
|
'[]'
|
||||||
|
) AS groups
|
||||||
FROM public.users
|
FROM public.users
|
||||||
LEFT JOIN public.roles USING (role_id)
|
LEFT JOIN public.roles USING (role_id)
|
||||||
WHERE
|
WHERE
|
||||||
|
|
@ -257,8 +282,18 @@ def create_provider_resource(
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
u.*,
|
u.*,
|
||||||
roles.name as role_name
|
roles.name as role_name,
|
||||||
FROM u LEFT JOIN public.roles USING (role_id);
|
COALESCE(
|
||||||
|
(
|
||||||
|
SELECT json_agg(groups)
|
||||||
|
FROM public.user_group
|
||||||
|
JOIN public.groups USING (group_id)
|
||||||
|
WHERE user_group.user_id = u.user_id
|
||||||
|
),
|
||||||
|
'[]'
|
||||||
|
) AS groups
|
||||||
|
FROM u
|
||||||
|
LEFT JOIN public.roles USING (role_id)
|
||||||
""",
|
""",
|
||||||
{
|
{
|
||||||
"tenant_id": tenant_id,
|
"tenant_id": tenant_id,
|
||||||
|
|
@ -303,7 +338,16 @@ def restore_provider_resource(
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
u.*,
|
u.*,
|
||||||
roles.name as role_name
|
roles.name as role_name,
|
||||||
|
COALESCE(
|
||||||
|
(
|
||||||
|
SELECT json_agg(groups)
|
||||||
|
FROM public.user_group
|
||||||
|
JOIN public.groups USING (group_id)
|
||||||
|
WHERE user_group.user_id = u.user_id
|
||||||
|
),
|
||||||
|
'[]'
|
||||||
|
) AS groups
|
||||||
FROM u LEFT JOIN public.roles USING (role_id);
|
FROM u LEFT JOIN public.roles USING (role_id);
|
||||||
""",
|
""",
|
||||||
{
|
{
|
||||||
|
|
@ -346,7 +390,16 @@ def rewrite_provider_resource(
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
u.*,
|
u.*,
|
||||||
roles.name as role_name
|
roles.name as role_name,
|
||||||
|
COALESCE(
|
||||||
|
(
|
||||||
|
SELECT json_agg(groups)
|
||||||
|
FROM public.user_group
|
||||||
|
JOIN public.groups USING (group_id)
|
||||||
|
WHERE user_group.user_id = u.user_id
|
||||||
|
),
|
||||||
|
'[]'
|
||||||
|
) AS groups
|
||||||
FROM u LEFT JOIN public.roles USING (role_id);
|
FROM u LEFT JOIN public.roles USING (role_id);
|
||||||
""",
|
""",
|
||||||
{
|
{
|
||||||
|
|
@ -377,7 +430,8 @@ def update_provider_resource(
|
||||||
).decode("utf-8")
|
).decode("utf-8")
|
||||||
set_fragments.append(fragment)
|
set_fragments.append(fragment)
|
||||||
set_clause = ", ".join(set_fragments)
|
set_clause = ", ".join(set_fragments)
|
||||||
query = f"""
|
cur.execute(
|
||||||
|
f"""
|
||||||
WITH u AS (
|
WITH u AS (
|
||||||
UPDATE public.users
|
UPDATE public.users
|
||||||
SET {set_clause}
|
SET {set_clause}
|
||||||
|
|
@ -389,7 +443,17 @@ def update_provider_resource(
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
u.*,
|
u.*,
|
||||||
roles.name as role_name
|
roles.name as role_name,
|
||||||
FROM u LEFT JOIN public.roles USING (role_id);"""
|
COALESCE(
|
||||||
cur.execute(query)
|
(
|
||||||
|
SELECT json_agg(groups)
|
||||||
|
FROM public.user_group
|
||||||
|
JOIN public.groups USING (group_id)
|
||||||
|
WHERE user_group.user_id = u.user_id
|
||||||
|
),
|
||||||
|
'[]'
|
||||||
|
) AS groups
|
||||||
|
FROM u LEFT JOIN public.roles USING (role_id)
|
||||||
|
"""
|
||||||
|
)
|
||||||
return cur.fetchone()
|
return cur.fetchone()
|
||||||
|
|
|
||||||
|
|
@ -162,12 +162,19 @@ CREATE TABLE public.users
|
||||||
origin text NULL DEFAULT NULL,
|
origin text NULL DEFAULT NULL,
|
||||||
role_id integer REFERENCES public.roles (role_id) ON DELETE SET NULL,
|
role_id integer REFERENCES public.roles (role_id) ON DELETE SET NULL,
|
||||||
internal_id text NULL DEFAULT NULL,
|
internal_id text NULL DEFAULT NULL,
|
||||||
service_account bool NOT NULL DEFAULT FALSE,
|
service_account bool NOT NULL DEFAULT FALSE
|
||||||
group_id integer REFERENCES public.groups (group_id) ON DELETE SET NULL
|
|
||||||
);
|
);
|
||||||
CREATE INDEX users_tenant_id_deleted_at_N_idx ON public.users (tenant_id) WHERE deleted_at ISNULL;
|
CREATE INDEX users_tenant_id_deleted_at_N_idx ON public.users (tenant_id) WHERE deleted_at ISNULL;
|
||||||
CREATE INDEX users_name_gin_idx ON public.users USING GIN (name gin_trgm_ops);
|
CREATE INDEX users_name_gin_idx ON public.users USING GIN (name gin_trgm_ops);
|
||||||
|
|
||||||
|
CREATE TABLE public.user_group
|
||||||
|
(
|
||||||
|
user_group_id integer generated BY DEFAULT AS IDENTITY PRIMARY KEY,
|
||||||
|
user_id integer REFERENCES public.users (user_id) ON DELETE CASCADE,
|
||||||
|
group_id integer REFERENCES public.groups (group_id) ON DELETE CASCADE,
|
||||||
|
UNIQUE (user_id, group_id)
|
||||||
|
);
|
||||||
|
|
||||||
CREATE TABLE public.basic_authentication
|
CREATE TABLE public.basic_authentication
|
||||||
(
|
(
|
||||||
user_id integer NOT NULL REFERENCES public.users (user_id) ON DELETE CASCADE,
|
user_id integer NOT NULL REFERENCES public.users (user_id) ON DELETE CASCADE,
|
||||||
|
|
|
||||||
Loading…
Add table
Reference in a new issue