作者:马顺华
从事运维管理工作多年,目前就职于某科技有限公司,熟悉运维自动化、OceanBase部署运维、MySQL 运维以及各种云平台技术和产品。并已获得OceanBase认证OBCA、OBCP证书。
第12天 | openGauss逻辑结构:模式管理
学习目标
模式管理包括为数据库创建模式、删除模式、查看和设置模式的搜索路径、查看模式中的信息。
课程学习
openGauss的模式是对数据库做一个逻辑分割。所有的数据库对象都建立在模式下面。openGauss的模式和用户是弱绑定的,所谓的弱绑定是指虽然创建用户的同时会自动创建一个同名模式,但用户也可以单独创建模式,并且为用户指定其他的模式。
在一个数据库中,可以有多个模式。模式可以把一组对象组织在一起。这样组织机构有多少个应用,我们可以将数据库对象组织成几个模式;组织机构有几个部门,也可以为该部门创建单独的模式。默认情况下,用户将访问数据库的public模式。
1.实验准备:
#第一次进入等待15秒
#数据库启动中…
–连接数据库
su - omm
gsql -r
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=#

–执行如下的命令和SQL语句,创建表空间enmtbs和数据库enmdb:
CREATE TABLESPACE enmtbs RELATIVE LOCATION ‘tablespace/enmtbs1’;
CREATE DATABASE enmdb WITH TABLESPACE = enmtbs;
omm=# CREATE TABLESPACE enmtbs RELATIVE LOCATION 'tablespace/enmtbs1';
CREATE TABLESPACE
omm=# CREATE DATABASE enmdb WITH TABLESPACE = enmtbs;
CREATE DATABASE
omm=#

–执行下面的gsql元命令\l,查看openGauss数据库集群上有哪些数据库:
\l
omm=# \l
List of databases
Name | Owner | Encoding | Collate | Ctype | Access privileges
-----------+-------+----------+---------+-------+-------------------
enmdb | omm | UTF8 | C | C |
(5 rows)
omm=# 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
omm=#

–执行下面的gsql元命令\db,查看openGauss数据库集群上有哪些表空间:
\db
omm=# \db
List of tablespaces
Name | Owner | Location
------------+-------+--------------------
enmtbs | omm | tablespace/enmtbs1
pg_default | omm |
pg_global | omm |
(3 rows)
omm=#

2.执行下面的gsql元命令,查看openGauss数据库上有哪些用户和模式
–执行下面的gsql元命令\du,查看openGauss数据库上有哪些用户:
\du
–执行下面的gsql元命令\dn,查看openGauss数据库上有哪些模式
\dn
3.执行下面的SQL语句,创建一个数据库用户user1,其密码为kunpeng@1234,并授予数据库用户user1 SYSADMIN权限:
–创建数据库用户user1的同时,会在系统的omm数据库中创建一个与这个用户名同名的模式user1。
CREATE USER user1 IDENTIFIED BY ‘kunpeng@1234’;
ALTER USER user1 SYSADMIN;
omm=# CREATE USER user1 IDENTIFIED BY 'kunpeng@1234';
NOTICE: The encrypted password contains MD5 ciphertext, which is not secure.
CREATE ROLE
omm=# ALTER USER user1 SYSADMIN;
ALTER ROLE
omm=#

–再次执行下面的gsql元命令\du,查看openGauss数据库上有哪些用户:
\du
omm=# \du
omm | Sysadmin, Create role, Create DB, Replication, Administer audit, Monitoradmin, Operatoradmin, Policyadmin, UseFT | {}
user1 | Sysadmin | {}
omm=# List of roles
Role name | Attributes | Member of
-----------+------------------------------------------------------------------------------------------------------------------+-----------
gaussdb | Sysadmin | {}
omm=#

–再次执行下面的gsql元命令\dn,查看openGauss数据库上有哪些模式
\dn+
omm=# \dn+
List of schemas
Name | Owner | Access privileges | Description | WithBlockChain
-----------------+-------+-------------------+----------------------------------+----------------
blockchain | omm | | blockchain schema | f
cstore | omm | | reserved schema for DELTA tables | 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 | |
pkg_service | omm | | pkg_service schema | f
public | omm | omm=UC/omm +| standard public schema | f
db4ai | omm | omm=UC/omm +| db4ai schema | f
| | =U/omm | |
dbe_perf | omm | | dbe_perf schema | f
sqladvisor | omm | omm=UC/omm +| sqladvisor schema | f
| | =U/omm | |
user1 | user1 | | | f
(11 rows)
| | =U/omm | |
snapshot | omm | | snapshot schema | f
omm=#

–或
SELECT catalog_name, schema_name, schema_owner FROM information_schema.schemata;
omm=# SELECT catalog_name, schema_name, schema_owner FROM information_schema.schemata;
catalog_name | schema_name | schema_owner
--------------+--------------------+--------------
omm | pg_toast | omm
omm | cstore | omm
omm | pkg_service | omm
omm | dbe_perf | omm
omm | snapshot | omm
omm | blockchain | omm
omm | pg_catalog | omm
omm | public | omm
omm | sqladvisor | omm
omm | dbe_pldebugger | omm
omm | dbe_pldeveloper | omm
omm | information_schema | omm
omm | db4ai | omm
omm | user1 | user1
(14 rows)
omm=#

4.PUBLIC模式:
openGauss在创建一个新的数据库时,会自动创建一个public模式。当用户登录到该数据库时,如果没有特殊的指定,都是操作在public模式中的数据库对象。
默认情况下,用户新创建的表,位于public模式中
–执行下面的SQL语句,创建一个测试表test:
create table test(col1 char(10));
omm=# create table test(col1 char(10));
CREATE TABLE
omm=#

–执行下面的gsql元命令\dt,查看 test表的Schema:
\dt test
omm=# \dt test
omm=# List of relations
Schema | Name | Type | Owner | Storage
--------+------+-------+-------+----------------------------------
public | test | table | omm | {orientation=row,compression=no}
(1 row)
omm=#

5.为数据库创建模式
一个用户可以创建多个模式
–创建一个模式schm1,属主是用户user1,并再次查看当前连接的数据库下有哪些模式:
create schema schm1 AUTHORIZATION user1;
omm=#
omm=# create schema schm1 AUTHORIZATION user1;
CREATE SCHEMA
omm=#

–继续在数据库enmdb中,创建模式schm2,模式schm3,属主是用户omm:
create schema schm2;
create schema schm3;
\dn
omm=# create schema schm2;
CREATE SCHEMA
omm=# create schema schm3;
CREATE SCHEMA
omm=# \dn
List of schemas
Name | Owner
-----------------+-------
blockchain | omm
cstore | omm
db4ai | omm
dbe_perf | omm
dbe_pldebugger | omm
dbe_pldeveloper | omm
pkg_service | omm
public | omm
schm1 | user1
schm2 | omm
schm3 | omm
snapshot | omm
sqladvisor | omm
user1 | user1
(14 rows)
omm=#
6.查看和设置模式的搜索路径
–会话级设置模式搜索顺序
在gsql客户端会话中,执行命令SET SEARCH_PATH TO schm1可以修改模式搜索路径,但只在gsql客户端会话的持续过程中起作用,一旦退出gsql客户端会话,这个设置就丢失了。重新登录gsql会话将模式搜索路径恢复为默认值"$user",public。
SET SEARCH_PATH TO schm1;
show SEARCH_PATH;
\q
omm=# SET SEARCH_PATH TO schm1;
SET
omm=# show SEARCH_PATH;
search_path
-------------
schm1
(1 row)
omm=# \q
omm@modb:~$

gsql -r
show SEARCH_PATH;
omm@modb:~$
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)
omm=#

–数据库级设置模式搜索顺序
修改数据库级别的搜索顺序后,数据库用户user1再次登录到数据库enmdb,其模式搜索路径已经变更为数据库默认的模式搜索路径schm1。
ALTER DATABASE enmdb SET SEARCH_PATH TO schm1;
\q
omm=# ALTER DATABASE enmdb SET SEARCH_PATH TO schm1;
ALTER DATABASE
omm=# \q
omm@modb:~$

gsql -r
\c enmdb user1
show SEARCH_PATH;
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 enmdb user1
Password for user user1:
Non-SSL connection (SSL connection is recommended when requiring high-security)
You are now connected to database "enmdb" as user "user1".
enmdb=> show SEARCH_PATH;
search_path
-------------
schm1
(1 row)
enmdb=>

–用户级设置模式搜索顺序
–设置数据库的用户user1的模式搜索顺序为模式schm2:
ALTER USER user1 SET SEARCH_PATH TO schm2;
\q
enmdb=> ALTER USER user1 SET SEARCH_PATH TO schm2;
ALTER ROLE
enmdb=> \q
omm@modb:~$

gsql -d enmdb -U user1 -W kunpeng@1234 -r
show SEARCH_PATH;
omm@modb:~$ gsql -d enmdb -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.
enmdb=> show SEARCH_PATH;
enmdb=> search_path
-------------
schm2
(1 row)
enmdb=>

7.搜索顺序的优先级
–会话级模式搜索顺序的优先级最高,用户级模式搜索顺序的优先级第2,数据库级模式搜索顺序的优先级最低。
#在会话级修改模式搜索顺序为模式schm3:
SET SEARCH_PATH TO schm3;
show SEARCH_PATH;
enmdb=> SET SEARCH_PATH TO schm3;
SET
enmdb=> show SEARCH_PATH;
search_path
-------------
schm3
(1 row)
enmdb=>

8.查看模式有哪些表
–查看当前连接的数据库中,public模式下有哪些表:
gsql -r
select table_catalog,table_schema,table_name,table_type
from information_schema.tables
where table_schema = ‘public’;
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=# select table_catalog,table_schema,table_name,table_type
omm-# from information_schema.tables
omm-# where table_schema = 'public';
table_catalog | table_schema | table_name | table_type
---------------+--------------+------------+------------
omm | public | test | BASE TABLE
(1 row)
omm=#

–查看指定数据库中,public模式下有哪些表:
select table_catalog,table_schema,table_name,table_type
from information_schema.tables
where table_catalog=‘omm’ and table_schema = ‘public’;
omm=# select table_catalog,table_schema,table_name,table_type
omm-# from information_schema.tables
omm-# where table_catalog='omm' and table_schema = 'public';
table_catalog | table_schema | table_name | table_type
---------------+--------------+------------+------------
omm | public | test | BASE TABLE
(1 row)
omm=#

课程作业
1.创建一个名为testsm、testsm1的模式
2.创建一个用户john, 并将testsm的owner修改为
john,且修改owner前后分别使用\dn+查看模式信息
3.重命名testsm为testsm2
4.在模式testsm1中建表t1、插入记录和查询记录
5.在会话级设置模式搜索顺序
6.在数据库级设置模式搜索顺序
7.在用户级设置模式搜索顺序
1.创建一个名为testsm、testsm1的模式
root@modb:~#
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=#

omm=# create schema testsm ;
CREATE SCHEMA
omm=# create schema testsm1 ;
CREATE SCHEMA
omm=#

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
omm=#

omm=# alter user john sysadmin ;
ALTER ROLE

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 | |
dbe_pldeveloper | omm | omm=UC/omm +| dbe_pldeveloper schema | f
| | =U/omm | |
john | john | | | f
pkg_service | omm | | pkg_service schema | f
public | omm | omm=UC/omm +| standard public schema | f
schm2 | omm | | | f
schm3 | omm | | | f
snapshot | omm | | snapshot schema | f
sqladvisor | omm | omm=UC/omm +| sqladvisor schema | f
| | =U/omm | |
| | =U/omm | |
schm1 | user1 | | | f
testsm | omm | | | f
testsm1 | omm | | | f
user1 | user1 | | | f
(17 rows)
omm=#
omm=#
omm=# alter schema testsm owner to john ;
ALTER SCHEMA
omm=#

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
| | =U/omm | |
dbe_pldeveloper | omm | omm=UC/omm +| dbe_pldeveloper schema | f
| | =U/omm | |
schm1 | user1 | | | f
schm2 | omm | | | f
schm3 | omm | | | f
snapshot | omm | | snapshot schema | f
pkg_service | omm | | pkg_service schema | f
public | omm | omm=UC/omm +| standard public schema | f
sqladvisor | omm | omm=UC/omm +| sqladvisor schema | f
| | =U/omm | |
testsm | john | | | f
testsm1 | omm | | | f
user1 | user1 | | | f
(17 rows)
omm=#

3.重命名testsm为testsm2
omm=# alter schema testsm rename to testsm2;
ALTER SCHEMA
omm=#

4.在模式testsm1中建表t1、插入记录和查询记录
omm=#
omm=# create table testsm1.t1
omm-# ( c_customer_sk integer,
omm(# c_customer_id char(5),
omm(# c_first_name char(6),
omm(# c_last_name char(8)
omm(# );
CREATE TABLE
omm=# insert into testsm1.t1 values
omm-# (6885, 1, 'Joes', 'Hunter'),
omm-# (4321, 2, 'Lily','Carter'),
omm-# (9527, 3, 'James', 'Cook'),
omm-# (9500, 4, 'Lucy', 'Baker');
omm=# INSERT 0 4
omm=# select * from testsm1.t1 ;
c_customer_sk | c_customer_id | c_first_name | c_last_name
---------------+---------------+--------------+-------------
6885 | 1 | Joes | Hunter
4321 | 2 | Lily | Carter
9527 | 3 | James | Cook
9500 | 4 | Lucy | Baker
(4 rows)
omm=#

5.在会话级设置模式搜索顺序
omm=# set SEARCH_PATH to testsm;
SET
omm=# show SEARCH_PATH;
omm=# search_path
-------------
testsm
(1 row)
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)
omm=#

6.在数据库级设置模式搜索顺序
omm=#
omm=# alter database omm set SEARCH_PATH to testsm;
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=# show SEARCH_PATH;
omm=# search_path
-------------
testsm
(1 row)
omm=#

7.在用户级设置模式搜索顺序
omm=# \l
List of databases
Name | Owner | Encoding | Collate | Ctype | Access privileges
-----------+-------+----------+---------+-------+-------------------
enmdb | omm | 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=# alter user omm set SEARCH_PATH to testsm1;
ALTER ROLE
omm=# \q
omm@modb:~$ gsql -d postgres -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.
openGauss=# show SEARCH_PATH;
search_path
-------------
testsm1
(1 row)
openGauss=#





