第 12 天打卡,本科学习内容是模式的管理,包括数据库创建模式、删除模式、查看和设置模式的搜索路径、查看模式中的信息等内容。
关于 openGauss 的模式,课件中描述如下:
openGauss 的模式是对数据库做一个逻辑分割。所有的数据库对象都建立在模式下面。openGauss 的模式和用户是弱绑定的,所谓的弱绑定是指虽然创建用户的同时会自动创建一个同名模式,但用户也可以单独创建模式,并且为用户指定其他的模式。
在一个数据库中,可以有多个模式。模式可以把一组对象组织在一起。这样组织机构有多少个应用,我们可以将数据库对象组织成几个模式;组织机构有几个部门,也可以为该部门创建单独的模式。默认情况下,用户将访问数据库的 public 模式。
作业
- 准备工作
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 enmtbs RELATIVE LOCATION 'tablespace/enmtbs1';
CREATE TABLESPACE
omm=# CREATE DATABASE enmdb WITH TABLESPACE = enmtbs;
CREATE DATABASE
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=# \db
List of tablespaces
Name | Owner | Location
------------+-------+--------------------
enmtbs | omm | tablespace/enmtbs1
pg_default | omm |
pg_global | omm |
(3 rows)
omm=#
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 | {}
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
snapshot | omm
sqladvisor | omm
(10 rows)
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=# \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 | Sysadmin | {}
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 | |
snapshot | omm | | snapshot schema | f
sqladvisor | omm | omm=UC/omm +| sqladvisor schema | f
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
| | =U/omm | |
| | =U/omm | |
user1 | user1 | | | f
(11 rows)
- 创建名为 testsm、testsm1 的模式
omm=# create schema testsm;
CREATE SCHEMA
omm=# create schema testsm1;
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
snapshot | omm
sqladvisor | omm
testsm | omm
testsm1 | omm
user1 | user1
(13 rows)
omm=#
- 创建一个用户 john, 并将 testsm 的 owner 修改为 john,且修改 owner 前后分别使用 \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
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 | |
sqladvisor | omm | omm=UC/omm +| sqladvisor schema | f
| | =U/omm | |
pkg_service | omm | | pkg_service schema | f
public | omm | omm=UC/omm +| standard public schema | f
testsm | omm | | | f
testsm1 | omm | | | f
user1 | user1 | | | f
(13 rows)
| | =U/omm | |
snapshot | omm | | snapshot schema | f
omm=#
omm=# CREATE USER john IDENTIFIED BY 'kunpeng@1234';
NOTICE: The encrypted password contains MD5 ciphertext, which is not secure.
CREATE ROLE
omm=# ALTER USER john SYSADMIN;
ALTER ROLE
omm=#
omm=# ALTER SCHEMA testsm OWNER TO john;
ALTER SCHEMA
omm=# \dn+
List of schemas
Name | Owner | Access privileges | Description | WithBlockChain
-----------------+-------+-------------------+----------------------------------+----------------
blockchain | omm | | blockchain schema | f
cstore | omm | | reserved schema for DELTA tables | f
| | =U/omm | |
dbe_pldeveloper | omm | omm=UC/omm +| dbe_pldeveloper schema | 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
pkg_service | omm | | pkg_service schema | f
public | omm | omm=UC/omm +| standard public schema | f
| | =U/omm | |
john | john | | | f
sqladvisor | omm | omm=UC/omm +| sqladvisor schema | f
| | =U/omm | |
testsm | john | | | f
| | =U/omm | |
snapshot | omm | | snapshot schema | f
testsm1 | omm | | | f
user1 | user1 | | | f
(14 rows)
- 重命名 testsm 为 testsm2
omm=# ALTER SCHEMA testsm RENAME TO testsm2;
ALTER SCHEMA
omm=# \dn
List of schemas
Name | Owner
-----------------+-------
blockchain | omm
cstore | omm
db4ai | omm
dbe_perf | omm
dbe_pldebugger | omm
dbe_pldeveloper | omm
john | john
pkg_service | omm
public | omm
snapshot | omm
sqladvisor | omm
testsm1 | omm
testsm2 | john
user1 | user1
(14 rows)
omm=#
- 在模式 testsm1 中建表 t1、插入记录和查询记录
omm=# create table testsm1.t1(id int,name char(20));
CREATE TABLE
omm=# insert into testsm1.t1 values(1,'Tank');
INSERT 0 1
omm=# select * from testsm1.t1 ;
id | name
----+----------------------
1 | Tank
(1 row)
omm=#
- 在会话级设置模式搜索顺序
omm=# show SEARCH_PATH;
search_path
----------------
"$user",public
(1 row)
omm=# set SEARCH_PATH TO testsm1;
SET
omm=# show SEARCH_PATH; search_path
-------------
testsm1
(1 row)
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-#
- 在数据库级设置模式搜索顺序
omm=# show SEARCH_PATH;
search_path
----------------
"$user",public
(1 row)
omm=# ALTER DATABASE enmdb SET SEARCH_PATH TO testsm1;
ALTER DATABASE
omm=# \c enmdb john
Password for user john:
Non-SSL connection (SSL connection is recommended when requiring high-security)
You are now connected to database "enmdb" as user "john".
enmdb=> show SEARCH_PATH;
search_path
-------------
testsm1
(1 row)
enmdb=>
- 在用户级设置模式搜索顺序
enmdb=> ALTER USER john SET SEARCH_PATH TO testsm2;
ALTER ROLE
enmdb=> \q
omm@modb:~$ gsql -d enmdb -U john -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;
search_path
-------------
testsm2
(1 row)
命令总结
- 设置模式的搜索路径
-- session
SET SEARCH_PATH TO schm1;
-- database
ALTER DATABASE enmdb SET SEARCH_PATH TO schm1;
-- user
ALTER USER user1 SET SEARCH_PATH TO schm2;
- 查看当前搜索路径
SHOW SEARCH_PATH;
- 修改模式的所有者
ALTER SCHEMA test1 OWNER TO user2;
- 修改模式名称
ALTER SCHEMA test RENAME TO test1;
- 查看模式有哪些表
-- 查看当前连接的数据库中,public 模式下有哪些表:
gsql -r
select table_catalog,table_schema,table_name,table_type
from information_schema.tables
where table_schema = 'public';
-- 查看指定数据库中,public 模式下有哪些表:
select table_catalog,table_schema,table_name,table_type
from information_schema.tables
where table_catalog='omm' and table_schema = 'public';
总结
第 12 天打卡完毕,在理解 Oracle schema 基础之上,理解 openGauss 的 schema 更为容易一些。后半程加油!
历史打卡记录:
openGauss 每日一练第 1 天|openGauss 数据库状态查看
openGauss 每日一练第 2 天|学习 openGauss 客户端工具 gsql 的使用
openGauss 每日一练第 3 天|openGauss 中一个数据库集簇对应多个数据库
openGauss 每日一练第 4 天|openGauss 中一个数据库可以被多个用户访问
openGauss 每日一练第 5 天|openGauss 中一个用户可以访问多个数据库
openGauss 每日一练第 6 天|openGauss 中用户一次只能连接到一个数据库
openGauss 每日一练第 7 天|openGauss 中一个数据库中可以创建多个模式
openGauss 每日一练第 8 天|openGauss 中一个数据库可以存储在多个表空间中
openGauss 每日一练第 9 天|openGauss 中一个表空间可以存储多个数据库




