学习目标
openGauss的模式是对数据库做一个逻辑分割。所有的数据库对象都建立在模式下面。openGauss的模式和用户是弱绑定的,所谓的弱绑定是指虽然创建用户的同时会自动创建一个同名模式,但用户也可以单独创建模式,并且为用户指定其他的模式。
在一个数据库中,可以有多个模式。模式可以把一组对象组织在一起。这样组织机构有多少个应用,我们可以将数据库对象组织成几个模式;组织机构有几个部门,也可以为该部门创建单独的模式。默认情况下,用户将访问数据库的public模式。
实验环境
omm=# \l
List of databases
Name | Owner | Encoding | Collate | Ctype | Access privileges
-----------+--------+----------+---------+-------+-------------------
mydb | myuser | UTF8 | C | C |
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
(5 rows)
omm=# \db
List of tablespaces
Name | Owner | Location
------------+-------+-------------------
app_ts | omm | tablespace/appts
enmtbs | omm | tablespace/enmtbs
pg_default | omm |
pg_global | omm |
(4 rows)
omm=# \dn
List of schemas
Name | Owner
-----------------+--------
blockchain | omm
cstore | omm
db4ai | omm
dbe_perf | omm
dbe_pldebugger | omm
dbe_pldeveloper | omm
jack | jack
myuser | myuser
pkg_service | omm
public | omm
snapshot | omm
sqladvisor | omm
test | test
(13 rows)
omm=#
omm=# \du
List of roles
Role name | Attributes | Member of
-----------+------------------------------------------------------------------------------------------------------------------+-----------
gaussdb | Sysadmin | {}
jack | | {}
myuser | Sysadmin | {}
omm | Sysadmin, Create role, Create DB, Replication, Administer audit, Monitoradmin, Operatoradmin, Policyadmin, UseFT | {}
test |
课后练习
1.创建一个名为testsm、testsm1的模式
omm=# create schema testsm AUTHORIZATION myuser;
CREATE SCHEMA
omm=# create schema testsm1 AUTHORIZATION myuser;
CREATE SCHEMA
2.创建一个用户john, 并将testsm的owner修改为john,且修改owner前后分别使用\dn+查看模式信息
-- 创建用户
omm=# create user john identified by 'kunpeng@1234';
NOTICE: The encrypted password contains MD5 ciphertext, which is not secure.
CREATE ROLE
-- 查看testsm为myuser
omm=# \dn+
List of schemas
Name | Owner | Access privileges | Description | WithBlockChain
-----------------+--------+-------------------+----------------------------------+----------------
blockchain | omm | | blockchain schema | f
cstore | omm | | reserved schema for DELTA tables | f
db4ai | omm | omm=UC/omm +| db4ai schema | f
| | =U/omm | |
dbe_perf | omm | | dbe_perf schema | f
dbe_pldebugger | omm | omm=UC/omm +| dbe_pldebugger schema | f
| | =U/omm | |
john | john | | | f
myuser | myuser | | | f
pkg_service | omm | | pkg_service schema | f
public | omm | omm=UC/omm +| standard public schema | f
| | =U/omm | |
dbe_pldeveloper | omm | omm=UC/omm +| dbe_pldeveloper schema | f
| | =U/omm | |
jack | jack | | | f
| | =U/omm | |
test | test | | | f
testsm | myuser | | | f
--More-- snapshot | omm | | snapshot schema | f
sqladvisor | omm | omm=UC/omm +| sqladvisor schema | f
testsm1 | myuser | | | f
(16 rows)
-- 修改schema的拥有者为john ^
omm=# alter user john SYSADMIN;
ALTER ROLE
omm=# alter schema testsm owner to john;
ALTER SCHEMA
--再次查看testsm为john
omm=# \dn+
List of schemas
Name | Owner | Access privileges | Description | WithBlockChain
-----------------+--------+-------------------+----------------------------------+----------------
blockchain | omm | | blockchain schema | f
cstore | omm | | reserved schema for DELTA tables | f
db4ai | omm | omm=UC/omm +| db4ai schema | f
pkg_service | omm | | pkg_service schema | f
public | omm | omm=UC/omm +| standard public schema | f
| | =U/omm | |
snapshot | omm | | snapshot schema | f
sqladvisor | omm | omm=UC/omm +| sqladvisor schema | f
| | =U/omm | |
test | test | | | f
testsm | john | | | f
--More-- | | =U/omm | |
dbe_perf | omm | | dbe_perf schema | f
dbe_pldebugger | omm | omm=UC/omm +| dbe_pldebugger schema | f
| | =U/omm | |
dbe_pldeveloper | omm | omm=UC/omm +| dbe_pldeveloper schema | f
| | =U/omm | |
jack | jack | | | f
john | john | | | f
myuser | myuser | | | f
testsm1 | myuser | | | f
(16 rows)
omm=#
3.重命名testsm为testsm2 (使用 rename to 就对了)
omm=# alter schema testsm rename to testsm2;
ALTER SCHEMA
4.在模式testsm1中建表t1、插入记录和查询记录
omm=# create table testsm1.t1(a int);
CREATE TABLE
omm=# insert into testsm1.t1 values (1);
INSERT 0 1
omm=# select * from testsm1.t1;
a
---
1
(1 row)
5.在会话级设置模式搜索顺序(只对当前会话生效)
omm=# set SEARCH_PATH TO testsm1;
SET
omm=# show SEARCH_PATH;
search_path
-------------
testsm1
(1 row)
omm=#
omm=# \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=# show SEARCH_PATH;
search_path
----------------
"$user",public
(1 row)
6.在数据库级设置模式搜索顺序
omm=# alter database mydb set SEARCH_PATH TO testsm1;
ALTER DATABASE
omm=# \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=# \c mydb myuser
Password for user myuser:
Non-SSL connection (SSL connection is recommended when requiring high-security)
You are now connected to database "mydb" as user "myuser".
mydb=>
mydb=> show SEARCH_PATH;
search_path
-------------
testsm1
(1 row)
mydb=>
7.在用户级设置模式搜索顺序
mydb=>
mydb=> ALTER USER myuser SET SEARCH_PATH TO TESTSM2;
ALTER ROLE
mydb=> \q
omm@modb:~$ gsql -d mydb -U myuser -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.
mydb=> show SEARCH_PATH;
search_path
-------------
testsm2
(1 row)
mydb=>
21天打卡,坚持坚持再坚持,加油!!!
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




