暂无图片
暂无图片
暂无图片
暂无图片
暂无图片

openGauss每日一练第19天 | 用户和角色管理

原创 李先生 2022-12-12
347

openGauss每日一练第19天 | 用户和角色管理


openGauss用户和角色管理

学习目标

掌握openGauss的用户和角色管理。

课程学习

使用create user创建的用户与使用create role创建的用户的区别在于,前者可以直接连接登录数据库,而使用create role创建的用户不能直接登录到数据库。必须添加LOGIN权限后,才能登录到数据库管理系统。
删除用户,首先需要将用户拥有的数据库对象转移或者删除。

1.环境准备
创建一个名叫test_tbs的表空间和一个名叫testdb的数据库:

root@modb:~# su - omm omm@modb:~$ gsql -r gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr ) Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. omm=# CREATE TABLESPACE test_tbs RELATIVE LOCATION 'tablespace/test_tbs1'; CREATE TABLESPACE omm=# CREATE DATABASE testdb WITH TABLESPACE = test_tbs; CREATE DATABASE omm=#

2.使用create user创建用户
使用create user创建的用户,具有登录权限。

--创建一个名叫user1的数据库用户,其密码为kunpeng@1234,并将数据库testdb所有的权限都授予用户user1: omm=# CREATE USER user1 IDENTIFIED BY 'kunpeng@1234'; NOTICE: The encrypted password contains MD5 ciphertext, which is not secure. CREATE ROLE omm=# GRANT ALL ON DATABASE testdb TO user1; GRANT omm=# --执行下面的gsql元命令,查看系统目前有哪些数据库: omm=# \l List of databases Name | Owner | Encoding | Collate | Ctype | Access privileges -----------+-------+----------+---------+-------+------------------- omm | omm | UTF8 | C | C | postgres | omm | UTF8 | C | C | template0 | omm | UTF8 | C | C | =c/omm + | | | | | omm=CTc/omm template1 | omm | UTF8 | C | C | =c/omm + | | | | | omm=CTc/omm testdb | omm | UTF8 | C | C | =Tc/omm + | | | | | omm=CTc/omm + | | | | | user1=CTc/omm + | | | | | user1=APm/omm (5 rows) omm=# --执行下面的gsql元命令,查看系统目前有哪些用户: omm=# \du List of roles Role name | Attributes | Member of -----------+------------------------------------------------------------------------------------------------------------------+----------- gaussdb | Sysadmin | {} omm | Sysadmin, Create role, Create DB, Replication, Administer audit, Monitoradmin, Operatoradmin, Policyadmin, UseFT | {} user1 | | {} omm=# \q omm@modb:~$ --用刚刚创建的数据库用户user1登录到数据库testdb omm@modb:~$ gsql -d testdb -U user1 -W kunpeng@1234 -r gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr ) Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. testdb=> \q omm@modb:~$

3.使用create role创建用户
使用create role命令创建的用户user2,没有登录权限。

--创建一个新的名叫user2的角色,并将数据库testdb所有的权限都授予用户user2: 用户user2对数据库testdb具有的权限和用户user1一模一样。 omm@modb:~$ gsql -r gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr ) Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. omm=# CREATE ROLE user2 IDENTIFIED BY 'kunpeng@1234'; NOTICE: The encrypted password contains MD5 ciphertext, which is not secure. CREATE ROLE omm=# GRANT ALL ON DATABASE testdb TO user2; GRANT omm=# --查看当前openGauss数据库集群由哪些用户: omm=# \du List of roles Role name | Attributes | Member of -----------+------------------------------------------------------------------------------------------------------------------+----------- gaussdb | Sysadmin | {} omm | Sysadmin, Create role, Create DB, Replication, Administer audit, Monitoradmin, Operatoradmin, Policyadmin, UseFT | {} user1 | | {} user2 | Cannot login | {} omm=# \q omm@modb:~$ --使用用户user2尝试登录到数据库testdb: omm@modb:~$ gsql -d testdb -U user2 -W kunpeng@1234 -r gsql: FATAL: role "user2" is not permitted to login omm@modb:~$

原因:
由于数据库用户user2是使用create role语句创建的,目前还不被允许登录到openGauss数据库管理系统。

4.授予用户user2登录权限后:
授予用户user2登录权限后,可以登录数据库

omm@modb:~$ gsql -r gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr ) Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. omm=# alter user user2 LOGIN; ALTER ROLE omm=# \du List of roles Role name | Attributes | Member of -----------+------------------------------------------------------------------------------------------------------------------+----------- gaussdb | Sysadmin | {} omm | Sysadmin, Create role, Create DB, Replication, Administer audit, Monitoradmin, Operatoradmin, Policyadmin, UseFT | {} user1 | | {} user2 | | {} omm=# --现在我们已经授予了user2用户登录数据库的权限,可以正常登录数据库testdb: omm@modb:~$ gsql -d testdb -U user2 -W kunpeng@1234 -r gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr ) Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. testdb=> \q omm@modb:~$

5.删除用户和角色
删除用户,首先需要将用户拥有的数据库对象转移或者删除,回收权限。

-- 授予用户user2数据库超级用户的权限: omm@modb:~$ gsql -r gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr ) Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. omm=# ALTER USER user2 SYSADMIN; ALTER ROLE omm=# --使用用户user2登录到数据库testdb,创建表空间test_tbs1、数据库testdb、表test1和表test2: omm=# \c testdb user2 Password for user user2: Non-SSL connection (SSL connection is recommended when requiring high-security) You are now connected to database "testdb" as user "user2". testdb=> CREATE TABLESPACE test_tbs1 RELATIVE LOCATION 'tablespace/test_tbs11'; CREATE TABLESPACE testdb=> CREATE DATABASE testdb WITH TABLESPACE = test_tbs1; ERROR: database "testdb" already exists testdb=> CREATE TABLE test1(col int); CREATE TABLE testdb=> CREATE TABLE test2(col int); CREATE TABLE testdb=> \q omm@modb:~$ --执行如下的命令,删除用户user2: omm@modb:~$ gsql -r gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr ) Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. omm=# drop user user2; ERROR: role "user2" cannot be dropped because some objects depend on it DETAIL: owner of tablespace test_tbs1 privileges for database testdb 2 objects in database testdb omm=#

###可以看出不能删除用户user2的原因是:
1)用户user2拥有数据库testdb。
2)用户user2拥有表空间对象test_tbs1。
3)用户user2对数据库testdb具有权限。
4)用户user2在数据库testdb中有两个对象。

--要删除用户user2,必须先表空间对象和数据库对象的属主修改为其他的用户(如user1用户),或者干脆将其删除: omm=# alter database testdb owner to user1; ALTER DATABASE omm=# alter tablespace test_tbs1 owner to user1; ALTER TABLESPACE omm=# --回收用户user2对testdb数据库的权限: omm=# REVOKE ALL ON DATABASE testdb FROM user2; REVOKE omm=# --在testdb中属于用户user2的数据库对象的处理方法可以是:假如该对象还有用,可以将该对象转移给其他用户;假如该对象没有用,可以直接删除掉该对象 --假设表test1已经没有用了,我们可以删除表test1: omm=# \c testdb user2 Password for user user2: Non-SSL connection (SSL connection is recommended when requiring high-security) You are now connected to database "testdb" as user "user2". testdb=> drop table test1; DROP TABLE testdb=> --假设表test2还有用将表test2转移给用户user1: testdb=> REASSIGN OWNED BY user2 to user1; REASSIGN OWNED testdb=> \dt List of relations Schema | Name | Type | Owner | Storage --------+-------+-------+-------+---------------------------------- public | test2 | table | user1 | {orientation=row,compression=no} (1 row) testdb=> \q --执行删除用户的操作,可以删除user2用户 omm@modb:~$ gsql -r gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr ) Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. omm=# drop user user2; DROP ROLE omm=# \du List of roles Role name | Attributes | Member of -----------+------------------------------------------------------------------------------------------------------------------+----------- gaussdb | Sysadmin | {} omm | Sysadmin, Create role, Create DB, Replication, Administer audit, Monitoradmin, Operatoradmin, Policyadmin, UseFT | {} user1 | | {} omm=#

课程作业

1、创建test10_tbs的表空间,在这个表空间中创建数据库testdb10

omm@modb:~$ gsql -r gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr ) Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. omm=# create tablespace test10_tbs relative location 'tablespace/test10_tbs1'; CREATE TABLESPACE omm=# create database testdb10 with tablespace = test10_tbs; CREATE DATABASE omm=# \l List of databases Name | Owner | Encoding | Collate | Ctype | Access privileges -----------+-------+----------+---------+-------+------------------- omm | omm | UTF8 | C | C | postgres | omm | UTF8 | C | C | template0 | omm | UTF8 | C | C | =c/omm + | | | | | omm=CTc/omm template1 | omm | UTF8 | C | C | =c/omm + | | | | | omm=CTc/omm testdb | user1 | UTF8 | C | C | =Tc/user1 + | | | | | user1=CTc/user1 + | | | | | user1=APm/user1 testdb10 | omm | UTF8 | C | C | (6 rows) omm=#

2、使用create user创建用户user10,登录数据库testdb10,创建测试表t1和t2

omm=# create user user10 identified by 'enmotech@123'; NOTICE: The encrypted password contains MD5 ciphertext, which is not secure. CREATE ROLE omm=# \du List of roles Role name | Attributes | Member of -----------+------------------------------------------------------------------------------------------------------------------+----------- gaussdb | Sysadmin | {} omm | Sysadmin, Create role, Create DB, Replication, Administer audit, Monitoradmin, Operatoradmin, Policyadmin, UseFT | {} user1 | | {} user10 | | {} omm=# \du List of roles Role name | Attributes | Member of -----------+------------------------------------------------------------------------------------------------------------------+----------- gaussdb | Sysadmin | {} omm | Sysadmin, Create role, Create DB, Replication, Administer audit, Monitoradmin, Operatoradmin, Policyadmin, UseFT | {} user1 | | {} user10 | Sysadmin | {} omm=# omm=#\q omm@modb:~$ gsql -d testdb10 -U user10 -W enmotech@123 -r gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr ) Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. testdb10=> \q omm@modb:~$ gsql -r gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr ) Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. omm=# grant all on database testdb10 to user10; GRANT omm=# alter user user10 sysadmin; ALTER ROLE omm=#\q omm@modb:~$ gsql -d testdb10 -U user10 -W enmotech@123 -r gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr ) Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. testdb10=> create table t1 ( testdb10(> id int, testdb10(> name varchar2(20), testdb10(> age int, testdb10(> constraint pk_t1_id primary key(id) testdb10(> ); NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "pk_t1_id" for table "t1" CREATE TABLE testdb10=> create table t2 ( testdb10(> id int, testdb10(> name varchar2(20), testdb10(> age int, testdb10(> constraint pk_t2_id primary key(id) testdb10(> ); NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "pk_t2_id" for table "t2" CREATE TABLE testdb10=> \d List of relations Schema | Name | Type | Owner | Storage --------+------+-------+--------+---------------------------------- public | t1 | table | user10 | {orientation=row,compression=no} public | t2 | table | user10 | {orientation=row,compression=no} (2 rows) testdb10=> \q omm@modb:~$

3、使用create role创建角色role10,登录数据库testdb10

omm@modb:~$ gsql -r gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr ) Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. omm=# create role role10 identified by 'enmotech@123'; NOTICE: The encrypted password contains MD5 ciphertext, which is not secure. CREATE ROLE omm=# \du List of roles Role name | Attributes | Member of -----------+------------------------------------------------------------------------------------------------------------------+----------- gaussdb | Sysadmin | {} omm | Sysadmin, Create role, Create DB, Replication, Administer audit, Monitoradmin, Operatoradmin, Policyadmin, UseFT | {} role10 | Cannot login | {} user1 | | {} user10 | Sysadmin | {} omm=# \q omm@modb:~$ gsql -d testdb10 -U role10 -W enmotech@123 -r gsql: FATAL: role "role10" is not permitted to login omm@modb:~$

4、将表t1直接删除,将前面创建的表空间和数据库、表t2转给role10,删除用户user10

omm@modb:~$ gsql -r gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr ) Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. omm=# \c testdb10 user10 Password for user user10: Non-SSL connection (SSL connection is recommended when requiring high-security) You are now connected to database "testdb10" as user "user10". testdb10=> \d List of relations Schema | Name | Type | Owner | Storage --------+------+-------+--------+---------------------------------- public | t1 | table | user10 | {orientation=row,compression=no} public | t2 | table | user10 | {orientation=row,compression=no} (2 rows) testdb10=> drop table t1; DROP TABLE testdb10=> alter database testdb10 owner to role10; ALTER DATABASE testdb10=> alter tablespace test10_tbs owner to role10 ; ALTER TABLESPACE testdb10=> revoke all on database testdb10 from user10; REVOKE testdb10=> reassign owned by user10 to role10 ; REASSIGN OWNED testdb10=> \d List of relations Schema | Name | Type | Owner | Storage --------+------+-------+--------+---------------------------------- public | t2 | table | role10 | {orientation=row,compression=no} (1 row) testdb10=> \q omm@modb:~$ gsql -r gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr ) Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. omm=# drop user user10; DROP ROLE omm=# \du List of roles Role name | Attributes | Member of -----------+------------------------------------------------------------------------------------------------------------------+----------- gaussdb | Sysadmin | {} omm | Sysadmin, Create role, Create DB, Replication, Administer audit, Monitoradmin, Operatoradmin, Policyadmin, UseFT | {} role10 | Cannot login | {} user1 | | {} omm=#

5、最后删除role10

omm@modb:~$ gsql -r gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr ) Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. omm=# \c testdb10 omm Non-SSL connection (SSL connection is recommended when requiring high-security) You are now connected to database "testdb10" as user "omm". testdb10=# reassign owned by role10 to omm ; REASSIGN OWNED testdb10=# alter database testdb10 owner to omm; ALTER DATABASE testdb10=# alter tablespace test10_tbs owner to omm; ALTER TABLESPACE testdb10=# alter tablespace test10_tbs owner to omm; ALTER TABLESPACE testdb10=# drop user role10; DROP ROLE testdb10=#

–学如逆水行舟,不进则退。

「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

评论