-
Notifications
You must be signed in to change notification settings - Fork 0
/
020_update_permissions_v1-14.sql
244 lines (221 loc) · 10 KB
/
020_update_permissions_v1-14.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
/*
GROUP HEADERS GENERATED BY: https://patorjk.com/software/taag/#p=display&h=0&v=1&c=c&f=ANSI%20Shadow&t=STAGE%20FUNCS
SUB GROUP HEADERS GENERATED BY: https://patorjk.com/software/taag/#p=display&h=1&v=1&c=c&f=Banner3&t=permissions
*/
set search_path = public, const, ext, stage, helpers, internal, unsecure;
select *
from check_version('1.13', _component := 'keen_auth_permissions', _throw_err := true);
select *
from start_version_update('1.14',
'Fix assigning permission and Fixes related to situation when user identity has to be created, for example, for per resource authorization, but provider_uid is unknown at that point',
_component := 'keen_auth_permissions');
create or replace function unsecure.recalculate_user_groups(
_created_by text
, _target_user_id bigint
, _provider_code text)
returns TABLE
(
__tenant_id integer,
__user_group_id integer,
__user_group_code text
)
language plpgsql
as
$$
declare
__not_really_used int;
__provider_groups text[];
__provider_roles text[];
begin
select provider_groups
, provider_roles
from auth.user_identity
where provider_code = _provider_code
and user_id = _target_user_id
into __provider_groups, __provider_roles;
insert into auth.user_group_member (created_by, group_id, user_id, member_type_code)
select _created_by, ug.user_group_id, _target_user_id, 'adhoc'
from auth.user_group ug
where is_default
on conflict (group_id, user_id) do nothing;
-- cleanup membership of groups user is no longer part of
with affected_deleted_group_tenants as (
delete
from auth.user_group_member
where user_id = _target_user_id
and mapping_id is not null
and group_id not in (
select distinct ugm.group_id
from unnest(__provider_groups) g
inner join auth.user_group_mapping ugm
on ugm.provider_code = _provider_code and ugm.mapped_object_id = lower(g)
inner join auth.user_group u
on u.user_group_id = ugm.group_id
union
select distinct ugm.group_id
from unnest(__provider_roles) r
inner join auth.user_group_mapping ugm
on ugm.provider_code = _provider_code and ugm.mapped_role = lower(r)
inner join auth.user_group u
on u.user_group_id = ugm.group_id)
returning group_id)
, affected_group_tenants as (
insert
into auth.user_group_member (created_by, user_id, group_id, mapping_id, member_type_code)
select distinct _created_by
, _target_user_id
, ugm.group_id
, ugm.ug_mapping_id
, 'adhoc'
from unnest(__provider_groups) g
inner join auth.user_group_mapping ugm
on ugm.provider_code = _provider_code and ugm.mapped_object_id = lower(g)
where ugm.group_id not in (
select group_id
from auth.user_group_member
where user_id = _target_user_id)
returning group_id)
, affected_role_tenants as (
insert
into auth.user_group_member (created_by, user_id, group_id, mapping_id, member_type_code)
select distinct _created_by
, _target_user_id
, ugm.group_id
, ugm.ug_mapping_id
, 'adhoc'
from unnest(__provider_roles) r
inner join auth.user_group_mapping ugm
on ugm.provider_code = _provider_code and ugm.mapped_role = lower(r)
where ugm.group_id not in (
select group_id
from auth.user_group_member
where user_id = _target_user_id)
returning group_id)
, all_group_ids as (
select group_id
from affected_deleted_group_tenants
union
select group_id
from affected_group_tenants
union
select group_id
from affected_role_tenants)
, all_tenants as (
select tenant_id
from all_group_ids ids
inner join auth.user_group ug
on ids.group_id = ug.user_group_id
group by tenant_id)
-- variable not really used, it's there just to avoid 'query has no destination for result data'
select at.tenant_id
from all_tenants at
, lateral unsecure.clear_permission_cache(_created_by, _target_user_id, at.tenant_id) r
into __not_really_used;
return query
select distinct ug.tenant_id
, ug.user_group_id
, ug.code
from auth.user_group_member ugm
inner join auth.user_group ug on ug.user_group_id = ugm.group_id
where ugm.user_id = _target_user_id;
end;
$$;
create or replace function unsecure.assign_permission(_created_by text, _user_id bigint,
_user_group_id int default null,
_target_user_id bigint default null,
_perm_set_code text default null, _perm_code text default null,
_tenant_id int default 1)
returns setof auth.permission_assignment
language plpgsql
as
$$
declare
__last_id bigint;
__perm_set_id int;
__perm_set_assignable bool;
__permission_id int;
__permission_assignable bool;
begin
if _user_group_id is null and _target_user_id is null then
perform error.raise_52272();
end if;
if
_perm_set_code is null and _perm_code is null then
perform error.raise_52273();
end if;
if _user_group_id is not null and not exists(select
from auth.user_group ug
where ug.user_group_id = _user_group_id) then
perform error.raise_52171(_user_group_id);
end if;
if _target_user_id is not null and not exists(select
from auth.user_info ui
where ui.user_id = _target_user_id) then
perform error.raise_52103(_target_user_id);
end if;
if _perm_set_code is not null then
select ps.perm_set_id, ps.is_assignable
from auth.perm_set ps
where ps.tenant_id = _tenant_id
and ps.code = _perm_set_code
into __perm_set_id, __perm_set_assignable;
if __perm_set_id is null then
perform error.raise_52282(_perm_set_code);
else
if not __perm_set_assignable then
perform error.raise_52283(_perm_code);
end if;
end if;
end if;
if _perm_code is not null then
select p.permission_id, p.is_assignable
from auth.permission p
where p.full_code = _perm_code::ext.ltree
into __permission_id, __permission_assignable;
if __permission_id is null then
perform error.raise_52180(_perm_code);
else
if not __permission_assignable then
perform error.raise_52181(_perm_code);
end if;
end if;
end if;
insert into auth.permission_assignment (created_by, tenant_id, group_id, user_id, perm_set_id, permission_id)
values (_created_by, _tenant_id, _user_group_id, _target_user_id, __perm_set_id, __permission_id)
returning assignment_id
into __last_id;
return query
select *
from auth.permission_assignment
where assignment_id = __last_id;
if
_user_group_id is not null then
perform public.add_journal_msg(_created_by, _user_id
, format('User: %s assigned new permission: %s to group: %s in tenant: %s'
, _created_by, coalesce(_perm_set_code, _perm_code), _user_group_id, _tenant_id)
, 'group', _user_group_id
, array ['assignment_id', __last_id::text, 'perm_set_code', _perm_set_code, 'permission_code', _perm_code]
, 50304
, _tenant_id := _tenant_id);
else
perform public.add_journal_msg(_created_by, _user_id
, format('User: %s assigned new permission: %s to user: %s in tenant: %s'
, _created_by, coalesce(_perm_set_code, _perm_code), _target_user_id, _tenant_id)
, 'user', _target_user_id
, array ['assignment_id', __last_id::text, 'perm_set_code', _perm_set_code, 'permission_code', _perm_code]
, 50304
, _tenant_id := _tenant_id);
end if;
end;
$$;
/***
* ██████╗ ██████╗ ███████╗████████╗ ██████╗██████╗ ███████╗ █████╗ ████████╗███████╗
* ██╔══██╗██╔═══██╗██╔════╝╚══██╔══╝ ██╔════╝██╔══██╗██╔════╝██╔══██╗╚══██╔══╝██╔════╝
* ██████╔╝██║ ██║███████╗ ██║ ██║ ██████╔╝█████╗ ███████║ ██║ █████╗
* ██╔═══╝ ██║ ██║╚════██║ ██║ ██║ ██╔══██╗██╔══╝ ██╔══██║ ██║ ██╔══╝
* ██║ ╚██████╔╝███████║ ██║ ╚██████╗██║ ██║███████╗██║ ██║ ██║ ███████╗
* ╚═╝ ╚═════╝ ╚══════╝ ╚═╝ ╚═════╝╚═╝ ╚═╝╚══════╝╚═╝ ╚═╝ ╚═╝ ╚══════╝
*
*/
select *
from stop_version_update('1.14', _component := 'keen_auth_permissions');