学习目标
进一步学习表空间与数据库对象的关系,了解oid的含义。课程学习
1.创建表空间、多个数据库和用户
2.使用sql查看数据库所在的表空间
3.在文件系统中查看表空间中的多个数据库
实验:
1.连接数据库,检查数据库环境,准备测试环境
连接数据库并检查数据库环境过程
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=# \db
List of tablespaces
Name | Owner | Location
------------+-------+----------
pg_default | omm |
pg_global | omm |
(2 rows)
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=# \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
(4 rows)2.创建表空间、多个数据库和用户
进入数据库omm,创建表空间、测试数据库CREATE TABLESPACE music_tbs RELATIVE LOCATION 'tablespace/test_ts1';
CREATE DATABASE musicdb WITH TABLESPACE = music_tbs;
CREATE DATABASE musicdb1 WITH TABLESPACE = music_tbs;
CREATE DATABASE musicdb2 WITH TABLESPACE = music_tbs;
CREATE DATABASE musicdb3 WITH TABLESPACE = music_tbs;
执行下面的SQL语句,创建用户user1 :
CREATE USER user1 IDENTIFIED BY 'xiaocx_1234';
授予user1数据库系统的SYSADMIN权限:
ALTER USER user1 SYSADMIN;
omm=# CREATE TABLESPACE music_tbs RELATIVE LOCATION 'tablespace/test_ts1';
CREATE TABLESPACE
omm=# CREATE DATABASE musicdb WITH TABLESPACE = music_tbs;
CREATE DATABASE
omm=# CREATE DATABASE musicdb1 WITH TABLESPACE = music_tbs;
CREATE DATABASE
omm=# CREATE DATABASE musicdb2 WITH TABLESPACE = music_tbs;
CREATE DATABASE
omm=# CREATE DATABASE musicdb3 WITH TABLESPACE = music_tbs;
CREATE DATABASE
omm=# CREATE USER user1 IDENTIFIED BY 'xiaocx_1234';
NOTICE: The encrypted password contains MD5 ciphertext, which is not secure.
CREATE ROLE
omm=# ALTER USER user1 SYSADMIN;
ALTER ROLE
omm=#3.使用sql查看数据库所在的表空间
查看数据库所在的表空间,可以看到一个表空间可以有多个数据库select datname,dattablespace,spcname from pg_database d, pg_tablespace t where d.dattablespace=t.oid;
omm=# select datname,dattablespace,spcname from pg_database d, pg_tablespace t where d.dattablespace=t.oid;
datname | dattablespace | spcname
-----------+---------------+------------
template1 | 1663 | pg_default
omm | 1663 | pg_default
musicdb | 16393 | music_tbs
template0 | 1663 | pg_default
musicdb1 | 16393 | music_tbs
musicdb2 | 16393 | music_tbs
musicdb3 | 16393 | music_tbs
postgres | 1663 | pg_default
(8 rows)
3.在文件系统中查看表空间中的多个数据库
查看数据库、表空间的oid
select oid,datname from pg_database;
select oid,* from pg_tablespace ;
select datname,dattablespace,spcname from pg_database d, pg_tablespace t where d.dattablespace=t.oid;
omm=# select oid,datname from pg_database;
oid | datname
-------+-----------
1 | template1
16384 | omm
16394 | musicdb
14555 | template0
16395 | musicdb1
16396 | musicdb2
16397 | musicdb3
14560 | postgres
(8 rows)
omm=# select oid,* from pg_tablespace ;
oid | spcname | spcowner | spcacl | spcoptions | spcmaxsize | relative
-------+------------+----------+--------+------------+------------+----------
1663 | pg_default | 10 | | | | f
1664 | pg_global | 10 | | | | f
16393 | music_tbs | 10 | | | | t
(3 rows)
omm=# select datname,dattablespace,spcname from pg_database d, pg_tablespace t where d.dattablespace=t.oid;
datname | dattablespace | spcname
-----------+---------------+------------
template1 | 1663 | pg_default
omm | 1663 | pg_default
musicdb | 16393 | music_tbs
template0 | 1663 | pg_default
musicdb1 | 16393 | music_tbs
musicdb2 | 16393 | music_tbs
musicdb3 | 16393 | music_tbs
postgres | 1663 | pg_default
(8 rows) 从文件系统,查看music_tbs表空间oid,可以看到一个表空间可以有多个数据库
omm@modb:~$ cd /var/lib/opengauss/data/pg_tblspc/16393/PG_9.2_201611171_gaussdb/
omm@modb:/var/lib/opengauss/data/pg_tblspc/16393/PG_9.2_201611171_gaussdb$ ls
16394 16395 16396 16397 pgsql_tmp
omm@modb:/var/lib/opengauss/data/pg_tblspc/16393/PG_9.2_201611171_gaussdb$ ls -lsa
total 76
4 drwx------ 7 omm omm 4096 Dec 2 10:04 .
4 drwx------ 3 omm omm 4096 Dec 2 10:04 ..
16 drwx------ 2 omm omm 16384 Dec 2 10:04 16394
16 drwx------ 2 omm omm 16384 Dec 2 10:04 16395
16 drwx------ 2 omm omm 16384 Dec 2 10:04 16396
16 drwx------ 2 omm omm 16384 Dec 2 10:04 16397
4 drwx------ 2 omm omm 4096 Dec 2 10:04 pgsql_tmp#说明:xxxxx是表空间 music_tbs的oid
课后作业
1.创建表空间 newtbs1
CREATE TABLESPACE newtbs1 RELATIVE LOCATION 'tablespace/newtbs1';
omm=# CREATE TABLESPACE newtbs1 RELATIVE LOCATION 'tablespace/newtbs1';
CREATE TABLESPACE2.创建3个数据库 newdb1、newdb2、newdb3,默认表空间为newtbs1
CREATE DATABASE newdb1 WITH TABLESPACE = newtbs1;
CREATE DATABASE newdb2 WITH TABLESPACE = newtbs1;
CREATE DATABASE newdb3 WITH TABLESPACE = newtbs1;
omm=# CREATE DATABASE newdb1 WITH TABLESPACE = newtbs1;
CREATE DATABASE
omm=# CREATE DATABASE newdb2 WITH TABLESPACE = newtbs1;
CREATE DATABASE
omm=# CREATE DATABASE newdb3 WITH TABLESPACE = newtbs1;
CREATE DATABASE
omm=# 3.使用sql查看表空间newtbs1上有几个数据库
select datname,dattablespace,spcname from pg_database d, pg_tablespace t where d.dattablespace=t.oid and spcname='newtbs1';
omm=# select datname,dattablespace,spcname from pg_database d, pg_tablespace t where d.dattablespace=t.oid and spcname='newtbs1';
datname | dattablespace | spcname
---------+---------------+---------
newdb1 | 16402 | newtbs1
newdb2 | 16402 | newtbs1
newdb3 | 16402 | newtbs1
(3 rows)
omm=#4.在文件系统中查看表空间newtbs1中的多个数据库
cd /var/lib/opengauss/data/pg_tblspc/16393/PG_9.2_201611171_gaussdb/
omm@modb:~$ cd /var/lib/opengauss/data/pg_tblspc
omm@modb:/var/lib/opengauss/data/pg_tblspc$ ls
16393 16402
omm@modb:/var/lib/opengauss/data/pg_tblspc$ cd 16402
omm@modb:/var/lib/opengauss/data/pg_tblspc/16402$ ls
PG_9.2_201611171_gaussdb
omm@modb:/var/lib/opengauss/data/pg_tblspc/16402$ cd PG_9.2_201611171_gaussdb/
omm@modb:/var/lib/opengauss/data/pg_tblspc/16402/PG_9.2_201611171_gaussdb$ ls
16403 16404 16405 pgsql_tmp
omm@modb:/var/lib/opengauss/data/pg_tblspc/16402/PG_9.2_201611171_gaussdb$ 



