作者:马顺华
从事运维管理工作多年,目前就职于某科技有限公司,熟悉运维自动化、OceanBase部署运维、MySQL 运维以及各种云平台技术和产品。并已获得OceanBase认证OBCA、OBCP证书。
第7天 | openGauss中一个数据库中可以创建多个模式
学习目标
学习openGauss数据库、用户和模式的关系和访问方式,理解模式是在数据库层面,用户是在实例层面
课程学习
一个用户连接到数据库后,可以在这个数据库中创建多个模式。要访问这些模式,可以使用DatabaseName.SchemaName.TableName或者SchemaName.TableName,来访问某个模式下的一个表。
默认情况下访问public模式下的表,可以不用添加模式名前缀。
1.测试环境准备:
su - omm
gsql -r
连接数据库
#第一次进入等待15秒
#数据库启动中…
进入数据库omm
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=#

2.创建模式、查看模式
1)–进入数据库omm,创建表空间、测试数据库
drop DATABASE IF EXISTS musicdb;
drop DATABASE IF EXISTS musicdb1;
drop DATABASE IF EXISTS musicdb2;
drop DATABASE IF EXISTS musicdb3;
drop tablespace IF EXISTS music_tbs;
CREATE TABLESPACE music_tbs RELATIVE LOCATION ‘tablespace/test_ts1’;
CREATE DATABASE musicdb WITH TABLESPACE = music_tbs;
omm=# drop DATABASE IF EXISTS musicdb;
NOTICE: database "musicdb" does not exist, skipping
DROP DATABASE
omm=# drop DATABASE IF EXISTS musicdb1;
NOTICE: database "musicdb1" does not exist, skipping
DROP DATABASE
omm=# drop DATABASE IF EXISTS musicdb2;
NOTICE: database "musicdb2" does not exist, skipping
DROP DATABASE
omm=# drop DATABASE IF EXISTS musicdb3;
NOTICE: database "musicdb3" does not exist, skipping
DROP DATABASE
omm=# drop tablespace IF EXISTS music_tbs;
NOTICE: Tablespace "music_tbs" does not exist, skipping.
DROP TABLESPACE
omm=# CREATE TABLESPACE music_tbs RELATIVE LOCATION 'tablespace/test_ts1';
CREATE TABLESPACE
omm=# CREATE DATABASE musicdb WITH TABLESPACE = music_tbs;
CREATE DATABASE
omm=#

2)–执行下面的SQL语句,创建用户user1:
CREATE USER user1 IDENTIFIED BY ‘kunpeng@1234’;
omm=# CREATE USER user1 IDENTIFIED BY 'kunpeng@1234';
NOTICE: The encrypted password contains MD5 ciphertext, which is not secure.
CREATE ROLE

3)–授予user1数据库系统的SYSADMIN权限:
ALTER USER user1 SYSADMIN;
omm=# ALTER USER user1 SYSADMIN;
ALTER ROLE

4)–使用用户user1连接到数据库musicdb,首先查看当前数据库下有哪些模式;
\q
gsql -d musicdb -U user1 -p 5432 -W kunpeng@1234 -r
omm=# \q
omm@modb:~$ gsql -d musicdb -U user1 -p 5432 -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.
musicdb=>

\dn
musicdb=> \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)
musicdb=>
3.然后为数据库musicdb创建4个模式: schm1、 schm2、 schm3、 schm4
1)–用户user1在数据库musicdb中,创建了4个模式:
create schema schm1 AUTHORIZATION user1;
create schema schm2 AUTHORIZATION user1;
create schema schm3 AUTHORIZATION user1;
create schema schm4 AUTHORIZATION user1;
musicdb=> create schema schm1 AUTHORIZATION user1;
CREATE SCHEMA
musicdb=> create schema schm2 AUTHORIZATION user1;
CREATE SCHEMA
musicdb=> create schema schm3 AUTHORIZATION user1;
CREATE SCHEMA
musicdb=> create schema schm4 AUTHORIZATION user1;
CREATE SCHEMA
musicdb=>

2)–查看musicdb数据库下有哪些模式:
\dn
musicdb=> \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 | user1
schm3 | user1
schm4 | user1
snapshot | omm
sqladvisor | omm
(14 rows)
musicdb=>

3)–除了可以用gsql的元命令\dn来查看数据库有哪些模式,还可以执行下面的SQL语句,查看某个数据库下有哪些模式:
SELECT catalog_name, schema_name, schema_owner FROM information_schema.schemata;
musicdb=> SELECT catalog_name, schema_name, schema_owner FROM information_schema.schemata;
catalog_name | schema_name | schema_owner
--------------+--------------------+--------------
musicdb | pg_toast | omm
musicdb | cstore | omm
musicdb | pkg_service | omm
musicdb | dbe_perf | omm
musicdb | snapshot | omm
musicdb | blockchain | omm
musicdb | schm4 | user1
(17 rows)
musicdb | pg_catalog | omm
musicdb | public | omm
musicdb | sqladvisor | omm
musicdb | dbe_pldebugger | omm
musicdb | dbe_pldeveloper | omm
musicdb | information_schema | omm
musicdb | db4ai | omm
musicdb | schm1 | user1
musicdb | schm2 | user1
musicdb | schm3 | user1
musicdb=>

4.在数据库musicdb的不同的模式下创建同名的表:
1)–在不同模式下,创建相同的表
create table schm1.ttt(col varchar(100));
create table schm2.ttt(col varchar(100));
create table schm3.ttt(col varchar(100));
create table schm4.ttt(col varchar(100));
musicdb=> create table schm1.ttt(col varchar(100));
CREATE TABLE
musicdb=> create table schm2.ttt(col varchar(100));
CREATE TABLE
musicdb=> create table schm3.ttt(col varchar(100));
CREATE TABLE
musicdb=> create table schm4.ttt(col varchar(100));
CREATE TABLE
musicdb=>

2)–执行下面的SQL语句,往4个模式中的表ttt分别插入一条数据:
–在同一个数据库下,可以直接使用SchemaName.TableName来指定一个表,可以省略数据库名。
insert into schm1.ttt values(‘Hello! from schema schm1 11111’);
insert into schm2.ttt values(‘Hello! from schema schm2 22222’);
insert into schm3.ttt values(‘Hello! from schema schm3 33333’);
insert into schm4.ttt values(‘Hello! from schema schm4 44444’);
musicdb=> insert into schm1.ttt values('Hello! from schema schm1 11111');
INSERT 0 1
musicdb=> insert into schm2.ttt values('Hello! from schema schm2 22222');
INSERT 0 1
musicdb=> insert into schm3.ttt values('Hello! from schema schm3 33333');
INSERT 0 1
musicdb=> insert into schm4.ttt values('Hello! from schema schm4 44444');
INSERT 0 1
musicdb=>

3)–执行下面的SQL语句,查看musicdb数据库目前有哪些表
–创建视图:
create or replace view my_tables as
select table_catalog, table_schema, table_name, table_type
from information_schema.tables
where table_schema not in (‘pg_catalog’, ‘information_schema’,‘dbe_perf’);
musicdb=> create or replace view my_tables as
musicdb-> select table_catalog, table_schema, table_name, table_type
musicdb-> from information_schema.tables
musicdb-> where table_schema not in ('pg_catalog', 'information_schema','dbe_perf');
CREATE VIEW
musicdb=>

4)----查看视图:
select * from my_tables;
musicdb=> select * from my_tables;
table_catalog | table_schema | table_name | table_type
---------------+-----------------+------------+------------
musicdb | db4ai | snapshot | BASE TABLE
musicdb | dbe_pldeveloper | gs_errors | BASE TABLE
musicdb=> musicdb | dbe_pldeveloper | gs_source | BASE TABLE
musicdb | public | my_tables | VIEW
musicdb | schm4 | ttt | BASE TABLE
musicdb | schm3 | ttt | BASE TABLE
musicdb | schm2 | ttt | BASE TABLE
musicdb | schm1 | ttt | BASE TABLE
(8 rows)
musicdb=>

5.查看用户在数据库中搜索模式的顺序:
1)–查看默认的搜索模式的顺序
show SEARCH_PATH;
musicdb=> show SEARCH_PATH;
search_path
----------------
"$user",public
(1 row)
musicdb=>

2)–访问musicdb数据库下其他模式的表,需要指定模式名前缀:
select * from schm1.ttt;
select * from schm2.ttt;
select * from schm3.ttt;
select * from schm4.ttt;
musicdb=> select * from schm1.ttt;
col
----------------------------------
Hello! from schema schm1 11111
(1 row)
musicdb=> select * from schm2.ttt;
col
----------------------------------
Hello! from schema schm2 22222
(1 row)
musicdb=> select * from schm3.ttt;
col
----------------------------------
Hello! from schema schm3 33333
(1 row)
musicdb=> select * from schm4.ttt;
col
----------------------------------
Hello! from schema schm4 44444
(1 row)
musicdb=>

6.模式是在数据库层面,用户是在实例层面
1)–登录musicdb数据库,查看用户和模式
gsql -d musicdb -U user1 -p 5432 -W kunpeng@1234 -r
musicdb-> \q
omm@modb:~$ gsql -d musicdb -U user1 -p 5432 -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.

\du
musicdb=> \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 |
{}
musicdb=>

\dn
\q
musicdb=> \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 | user1
schm3 | user1
schm4 | user1
snapshot | omm
sqladvisor | omm
(14 rows)
musicdb=> \q

2)–登录omm数据库,查看用户和模式
gsql -r
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=#

\du
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=#

\dn
\q
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
user1 | user1
(11 rows)
omm=# \q
omm@modb:~$

课程总结
1.查看当前数据库下有哪些模式
2.然后为数据库musicdb创建4个模式,名称自定义
3.在数据库musicdb的不同的模式下创建同名的表
4.访问musicdb数据库下不同模式的同名表
5.实验理解:模式是在数据库层面,用户是在实例层面




