You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
Source Postgres : use more simple and comprehensive query to get selectable tables (#14251)
* use more simple and comprehensive query to get selectable tables
* cover case when schema is not specified
* add test to check discover with different ways of grants
* format
* incr ver
* incr ver
* auto-bump connector version
Co-authored-by: Octavia Squidington III <[email protected]>
Copy file name to clipboardExpand all lines: airbyte-integrations/connectors/source-postgres/src/main/java/io/airbyte/integrations/source/postgres/PostgresSource.java
+9-57
Original file line number
Diff line number
Diff line change
@@ -301,65 +301,17 @@ public Set<JdbcPrivilegeDto> getPrivilegesTableForCurrentUser(final JdbcDatabase
JOIN information_schema.applicable_roles r ON p.grantee = r.role_name
344
-
WHERE r.grantee in
345
-
(WITH RECURSIVE membership_tree(grpid, userid) AS (
346
-
SELECT pg_roles.oid, pg_roles.oid
347
-
FROM pg_roles WHERE oid = (select oid from pg_roles where rolname=?)
348
-
UNION ALL
349
-
SELECT m_1.roleid, t_1.userid
350
-
FROM pg_auth_members m_1, membership_tree t_1
351
-
WHERE m_1.member = t_1.grpid
352
-
)
353
-
SELECT DISTINCT m.rolname AS grpname
354
-
FROM membership_tree t, pg_roles r, pg_roles m
355
-
WHERE t.grpid = m.oid AND t.userid = r.oid)
356
-
AND privilege_type = 'SELECT';
307
+
JOIN pg_namespace n on c.relnamespace = n.oid
308
+
WHERE has_table_privilege(c.oid, 'SELECT')
309
+
-- r = ordinary table, i = index, S = sequence, t = TOAST table, v = view, m = materialized view, c = composite type, f = foreign table, p = partitioned table, I = partitioned index
Copy file name to clipboardExpand all lines: airbyte-integrations/connectors/source-postgres/src/test/java/io/airbyte/integrations/source/postgres/PostgresSourceTest.java
ctx.fetch("create materialized view not_granted_mv_name_1 as SELECT not_granted_table_name_1.column_1 FROM not_granted_table_name_1;");
357
+
ctx.fetch("create materialized view not_granted_mv_name_2 as SELECT not_granted_table_name_2.column_1 FROM not_granted_table_name_2;");
358
+
ctx.fetch("create materialized view not_granted_mv_name_3 as SELECT not_granted_table_name_3.column_1 FROM not_granted_table_name_3;");
359
+
ctx.fetch("create materialized view mv_granted_by_role as SELECT table_granted_by_role.column_1 FROM table_granted_by_role;");
360
+
ctx.fetch(
361
+
"create materialized view test_mv_granted_directly as SELECT test_table_granted_directly.column_1 FROM test_table_granted_directly;");
362
+
ctx.fetch(
363
+
"create materialized view mv_granted_by_role_with_options as SELECT table_granted_by_role_with_options.column_1 FROM table_granted_by_role_with_options;");
364
+
ctx.fetch(
365
+
"create materialized view test_mv_granted_directly_with_options as SELECT test_table_granted_directly_with_options.column_1 FROM test_table_granted_directly_with_options;");
366
+
367
+
ctx.fetch("create view not_granted_view_name_1(column_1) as SELECT not_granted_table_name_1.column_1 FROM not_granted_table_name_1;");
368
+
ctx.fetch("create view not_granted_view_name_2(column_1) as SELECT not_granted_table_name_2.column_1 FROM not_granted_table_name_2;");
369
+
ctx.fetch("create view not_granted_view_name_3(column_1) as SELECT not_granted_table_name_3.column_1 FROM not_granted_table_name_3;");
370
+
ctx.fetch("create view view_granted_by_role(column_1) as SELECT table_granted_by_role.column_1 FROM table_granted_by_role;");
371
+
ctx.fetch(
372
+
"create view test_view_granted_directly(column_1) as SELECT test_table_granted_directly.column_1 FROM test_table_granted_directly;");
373
+
ctx.fetch(
374
+
"create view view_granted_by_role_with_options(column_1) as SELECT table_granted_by_role_with_options.column_1 FROM table_granted_by_role_with_options;");
375
+
ctx.fetch(
376
+
"create view test_view_granted_directly_with_options(column_1) as SELECT test_table_granted_directly_with_options.column_1 FROM test_table_granted_directly_with_options;");
377
+
378
+
ctx.fetch("create role test_role;");
379
+
380
+
ctx.fetch("grant delete on not_granted_table_name_2 to test_role;");
381
+
ctx.fetch("grant delete on not_granted_mv_name_2 to test_role;");
382
+
ctx.fetch("grant delete on not_granted_view_name_2 to test_role;");
383
+
384
+
ctx.fetch("grant select on table_granted_by_role to test_role;");
385
+
ctx.fetch("grant select on mv_granted_by_role to test_role;");
386
+
ctx.fetch("grant select on view_granted_by_role to test_role;");
387
+
388
+
ctx.fetch("grant select on table_granted_by_role_with_options to test_role with grant option;");
389
+
ctx.fetch("grant select on mv_granted_by_role_with_options to test_role with grant option;");
390
+
ctx.fetch("grant select on view_granted_by_role_with_options to test_role with grant option;");
391
+
392
+
ctx.fetch("create user new_test_user;");
393
+
ctx.fetch("ALTER USER new_test_user WITH PASSWORD 'new_pass';");
394
+
ctx.fetch("GRANT CONNECT ON DATABASE test TO new_test_user;");
395
+
396
+
ctx.fetch("grant test_role to new_test_user;");
397
+
398
+
ctx.fetch("grant delete on not_granted_table_name_3 to new_test_user;");
399
+
ctx.fetch("grant delete on not_granted_mv_name_3 to new_test_user;");
400
+
ctx.fetch("grant delete on not_granted_view_name_3 to new_test_user;");
401
+
402
+
ctx.fetch("grant select on test_table_granted_directly to new_test_user;");
403
+
ctx.fetch("grant select on test_mv_granted_directly to new_test_user;");
404
+
ctx.fetch("grant select on test_view_granted_directly to new_test_user;");
405
+
406
+
ctx.fetch("grant select on test_table_granted_directly_with_options to test_role with grant option;");
407
+
ctx.fetch("grant select on test_mv_granted_directly_with_options to test_role with grant option;");
408
+
ctx.fetch("grant select on test_view_granted_directly_with_options to test_role with grant option;");
0 commit comments