在實際的生產環境 ,我們經常會碰到這樣的情況:因為業務場景需要,本部門某些重要的業務數據表需要給予其他部門查看權限,因業務的擴展及調整,后期可能需要放開更多的表查詢權限。為解決此種業務需求,我們可以采用創建視圖的方式來解決,已可以通過創建影子用戶的方式來滿足需求,本文主要介紹影子用戶的創建及授權方法。
場景1:只授予usage on schema 權限
session 1:
--創建readonly用戶,并將test模式賦予readonly用戶。
postgres=# create user readonly with password 'postgres';
CREATE ROLE
postgres=# grant usage on schema test to readonly;
GRANT
postgres=# \dn
List of schemas
Name | Owner
-------+-------
test | postgres
session 2:
--登陸readonly用戶可以查詢test模式下現存的所有表。
postgres=# \c postgres readonly
You are now connected to database "postgres" as user "readonly".
postgres=> select * from test.emp ;
empno | ename | job | mgr | hiredate | sal | comm | deptno
-------+--------+-----------+------+------------+---------+---------+--------
7499 | ALLEN | SALESMAN | 7698 | 1981-02-20 | 1600.00 | 300.00 | 30
7521 | WARD | SALESMAN | 7698 | 1981-02-22 | 1250.00 | 500.00 | 30
7566 | JONES | MANAGER | 7839 | 1981-04-02 | 2975.00 | | 20
7654 | MARTIN | SALESMAN | 7698 | 1981-09-28 | 1250.00 | 1400.00 | 30
7698 | BLAKE | MANAGER | 7839 | 1981-05-01 | 2850.00 | | 30
7782 | CLARK | MANAGER | 7839 | 1981-06-09 | 2450.00 | | 10
7839 | KING | PRESIDENT | | 1981-11-17 | 5000.00 | | 10
7844 | TURNER | SALESMAN | 7698 | 1981-09-08 | 1500.00 | 0.00 | 30
7900 | JAMES | CLERK | 7698 | 1981-12-03 | 950.00 | | 30
7902 | FORD | ANALYST | 7566 | 1981-12-03 | 3000.00 | | 20
7934 | MILLER | CLERK | 7782 | 1982-01-23 | 1300.00 | | 10
7788 | test | ANALYST | 7566 | 1982-12-09 | 3000.00 | | 20
7876 | ADAMS | CLERK | 7788 | 1983-01-12 | 1100.00 | | 20
1111 | SMITH | CLERK | 7902 | 1980-12-17 | 800.00 | | 20
(14 rows)
換到session 1創建新表t1
postgres=# create table test.t1 as select * from test.emp;
CREATE TABLE
切換到session 2 readonly用戶下,t1表無法查詢
postgres=> select * from test.t1 ;
2021-03-02 15:25:33.290 CST [21059] ERROR: permission denied for table t1
2021-03-02 15:25:33.290 CST [21059] STATEMENT: select * from test.t1 ;
**ERROR: permission denied for table t1
結論:如果只授予 usage on schema 權限,readonly 只能查看 test 模式下已經存在的表和對象。在授予 usage on schema 權限之后創建的新表無法查看。
場景2:授予usage on schema 權限之后,再賦予 select on all tables in schema 權限
針對上個場景session 2 **ERROR: permission denied for table t1 錯誤的處理
postgres=> select * from test.t1 ;
**ERROR: permission denied for table t1
session 1: 使用postgres用戶授予readonly用戶 select on all tables 權限
postgres=# grant select on all tables in schema test TO readonly ;
session 2: readonly用戶查詢 t1 表
postgres=> select * from test.t1;
empno | ename | job | mgr | hiredate | sal | comm | deptno
-------+--------+-----------+------+------------+---------+---------+--------
7499 | ALLEN | SALESMAN | 7698 | 1981-02-20 | 1600.00 | 300.00 | 30
7521 | WARD | SALESMAN | 7698 | 1981-02-22 | 1250.00 | 500.00 | 30
7566 | JONES | MANAGER | 7839 | 1981-04-02 | 2975.00 | | 20
7654 | MARTIN | SALESMAN | 7698 | 1981-09-28 | 1250.00 | 1400.00 | 30
7698 | BLAKE | MANAGER | 7839 | 1981-05-01 | 2850.00 | | 30
7782 | CLARK | MANAGER | 7839 | 1981-06-09 | 2450.00 | | 10
7839 | KING | PRESIDENT | | 1981-11-17 | 5000.00 | | 10
7844 | TURNER | SALESMAN | 7698 | 1981-09-08 | 1500.00 | 0.00 | 30
7900 | JAMES | CLERK | 7698 | 1981-12-03 | 950.00 | | 30
7902 | FORD | ANALYST | 7566 | 1981-12-03 | 3000.00 | | 20
7934 | MILLER | CLERK | 7782 | 1982-01-23 | 1300.00 | | 10
7788 | test | ANALYST | 7566 | 1982-12-09 | 3000.00 | | 20
7876 | ADAMS | CLERK | 7788 | 1983-01-12 | 1100.00 | | 20
1111 | SMITH | CLERK | 7902 | 1980-12-17 | 800.00 | | 20
(14 rows)
session1 :postgres用戶的test模式下創建新表 t2
postgres=# create table test.t2 as select * from test.emp;
SELECT 14
session 2:readonly用戶查詢 t2 表權限不足
postgres=> select * from test.t2 ;
ERROR: permission denied for table t2
session 1:再次賦予 grant select on all tables
postgres=# grant select on all tables in schema test TO readonly ;
session 2:readonly用戶又可以查看 T2 表
postgres=> select * from test.t2 ;
empno | ename | job | mgr | hiredate | sal | comm | deptno
-------+--------+-----------+------+------------+---------+---------+--------
7499 | ALLEN | SALESMAN | 7698 | 1981-02-20 | 1600.00 | 300.00 | 30
7521 | WARD | SALESMAN | 7698 | 1981-02-22 | 1250.00 | 500.00 | 30
7566 | JONES | MANAGER | 7839 | 1981-04-02 | 2975.00 | | 20
7654 | MARTIN | SALESMAN | 7698 | 1981-09-28 | 1250.00 | 1400.00 | 30
7698 | BLAKE | MANAGER | 7839 | 1981-05-01 | 2850.00 | | 30
7782 | CLARK | MANAGER | 7839 | 1981-06-09 | 2450.00 | | 10
7839 | KING | PRESIDENT | | 1981-11-17 | 5000.00 | | 10
7844 | TURNER | SALESMAN | 7698 | 1981-09-08 | 1500.00 | 0.00 | 30
7900 | JAMES | CLERK | 7698 | 1981-12-03 | 950.00 | | 30
7902 | FORD | ANALYST | 7566 | 1981-12-03 | 3000.00 | | 20
7934 | MILLER | CLERK | 7782 | 1982-01-23 | 1300.00 | | 10
7788 | test | ANALYST | 7566 | 1982-12-09 | 3000.00 | | 20
7876 | ADAMS | CLERK | 7788 | 1983-01-12 | 1100.00 | | 20
1111 | SMITH | CLERK | 7902 | 1980-12-17 | 800.00 | | 20
(14 rows)
影子用戶創建
如果想讓readonly只讀用戶不在每次 postgres用戶在test模式中創建新表后都要手工賦予 grant select on all tables in schema test TO readonly 權限。則需要授予對test默認的訪問權限,對于test模式新創建的也生效。
session 1:未來訪問test模式下所有新建的表賦權,創建 t5 表。
postgres=# alter default privileges in schema test grant select on tables to readonly ;
ALTER DEFAULT PRIVILEGES
postgres=# create table test.t5 as select * from test.emp;
CREATE TABLE
session 2:查詢readonly用戶
postgres=> select * from test.t5;
empno | ename | job | mgr | hiredate | sal | comm | deptno
-------+--------+-----------+------+------------+---------+---------+--------
7499 | ALLEN | SALESMAN | 7698 | 1981-02-20 | 1600.00 | 300.00 | 30
7521 | WARD | SALESMAN | 7698 | 1981-02-22 | 1250.00 | 500.00 | 30
7566 | JONES | MANAGER | 7839 | 1981-04-02 | 2975.00 | | 20
7654 | MARTIN | SALESMAN | 7698 | 1981-09-28 | 1250.00 | 1400.00 | 30
7698 | BLAKE | MANAGER | 7839 | 1981-05-01 | 2850.00 | | 30
7782 | CLARK | MANAGER | 7839 | 1981-06-09 | 2450.00 | | 10
7839 | KING | PRESIDENT | | 1981-11-17 | 5000.00 | | 10
7844 | TURNER | SALESMAN | 7698 | 1981-09-08 | 1500.00 | 0.00 | 30
7900 | JAMES | CLERK | 7698 | 1981-12-03 | 950.00 | | 30
7902 | FORD | ANALYST | 7566 | 1981-12-03 | 3000.00 | | 20
7934 | MILLER | CLERK | 7782 | 1982-01-23 | 1300.00 | | 10
7788 | test | ANALYST | 7566 | 1982-12-09 | 3000.00 | | 20
7876 | ADAMS | CLERK | 7788 | 1983-01-12 | 1100.00 | | 20
1111 | SMITH | CLERK | 7902 | 1980-12-17 | 800.00 | | 20
(14 rows)
總結:影子用戶創建的步驟
--創建影子用戶
create user readonly with password 'postgres';
--將schema中usage權限賦予給readonly用戶,訪問所有已存在的表
grant usage on schema test to readonly;
grant select on all tables in schema test to readonly;
--未來訪問test模式下所有新建的表
alter default privileges in schema test grant select on tables to readonly ;
到此這篇關于postgresql影子用戶實踐的文章就介紹到這了,更多相關postgresql影子用戶內容請搜索腳本之家以前的文章或繼續瀏覽下面的相關文章希望大家以后多多支持腳本之家!
您可能感興趣的文章:- PostGreSql 判斷字符串中是否有中文的案例
- PostgreSQL的中文拼音排序案例
- 自定義函數實現單詞排序并運用于PostgreSQL(實現代碼)
- PostgreSQL將數據加載到buffer cache中操作方法
- 在PostgreSQL中使用ltree處理層次結構數據的方法
- postgresql 中的時間處理小技巧(推薦)
- Postgresql限制用戶登錄錯誤次數的實例代碼
- PostgreSQL用戶登錄失敗自動鎖定的處理方案
- 如何使用PostgreSQL進行中文全文檢索