暂无图片
暂无图片
暂无图片
暂无图片
暂无图片

openGauss 每日一练第 8 天 | openGauss 中一个数据库可以存储在多个表空间中

1151

学习目标

学习表空间与数据库对象的关系。

在 musicdb 数据库中创建的所有的表,没有指定表空间的名字,因此都创建在数据库默认的表空间 music_tbs 中,当我们在 musicdb 数据库中创建表 warehouse_t1 的时候,明确指定在表空间 ds_location1 中创建时,这个表会存储在这个指定的表空间。即一个数据库中的对象,可以位于不同的表空间.

前面每日一练链接

openGauss 每日一练第 1 天 | openGauss 数据库状态查看
openGauss 每日一练第 2 天 | 学习 gsql 命令行的使用
openGauss 每日一练第 3 天 | openGauss 数据库状态查看
openGauss 每日一练第 4 天 | openGauss 中一个数据库可以被多个用户访问
openGauss 每日一练第 5 天 | openGauss 中一个用户可以访问多个数据库
openGauss 每日一练第 6 天 | openGauss 中用户一次只能连接到一个数据库
openGauss 每日一练第 7 天 | openGauss 中一个数据库中可以创建多个模式

课程学习

1.连接数据库,准备测试环境

#第一次进入等待15秒
#数据库启动中...
su - omm
gsql -r

--进入数据库 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;

--执行下面的SQL语句,创建用户user1:

 CREATE USER user1 IDENTIFIED BY 'JiekeXu_1234';
 
--授予user1数据库系统的SYSADMIN权限:

ALTER USER user1 SYSADMIN;

图片.png

2.创建表空间、查看表空间

--执行下面的命令,查看当前表空间:
\db
 
--创建一个新的名为 ds_location1 的表空间:
 
 CREATE TABLESPACE ds_location1 RELATIVE LOCATION 'tablespace/tablespace_1';
 
--执行下面的命令,查看实例当前有哪些表空间:
\db

图片.png

3.使用 user1 用户,访问 musicdb 数据库 ,在表空间 ds_location1 上创建表 warehouse_t1:

\c musicdb user1

create table warehouse_t1 (col1 char(10)) tablespace ds_location1;
omm=# \c musicdb user1
Password for user user1: 
Non-SSL connection (SSL connection is recommended when requiring high-security)
You are now connected to database "musicdb" as user "user1".
musicdb=> 
musicdb=> create table warehouse_t1 (col1 char(10)) tablespace ds_location1;
CREATE TABLE
musicdb=> \dt
                            List of relations
 Schema |     Name     | Type  | Owner |             Storage              
--------+--------------+-------+-------+----------------------------------
 public | warehouse_t1 | table | user1 | {orientation=row,compression=no}
(1 row)
musicdb=> \d warehouse_t1
    Table "public.warehouse_t1"
 Column |     Type      | Modifiers 
--------+---------------+-----------
 col1   | character(10) | 
Tablespace: "ds_location1"

4.查看 musicdb 数据库目前有哪些表:

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=> 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');
 table_catalog |  table_schema   |  table_name  | table_type 
---------------+-----------------+--------------+------------
 musicdb       | db4ai           | snapshot     | BASE TABLE
 musicdb       | dbe_pldeveloper | gs_errors    | BASE TABLE
 musicdb       | dbe_pldeveloper | gs_source    | BASE TABLE
 musicdb       | public          | warehouse_t1 | BASE TABLE
(4 rows)

5.查询表在那个表空间

系统表在默认表空间,非系统表在指定的表空间中(否则在默认表空间)

--建表 warehouse_t1 指定表空间 ds_location1,查看表 warehouse_t1 所在的表空间:
musicdb=> select * from pg_tables where tablename = 'warehouse_t1';
 schemaname |  tablename   | tableowner |  tablespace  | hasindexes | hasru
les | hastriggers | tablecreator |           created            |        la
st_ddl_time         
------------+--------------+------------+--------------+------------+------
----+-------------+--------------+------------------------------+----------
--------------------
 public     | warehouse_t1 | user1      | ds_location1 | f          | f    
    | f           | user1        | 2022-12-01 23:12:03.81201+08 | 2022-12-0
1 23:12:03.81201+08
(1 row)

--创建表 warehouse_t12 未指定表空间,则在默认表空间(不显示默认表空间名)
create table warehouse_t12 (col1 char(10));
select * from pg_tables where tablename = 'warehouse_t12';

musicdb=> select * from pg_tables where tablename = 'warehouse_t12';
   | f           | user1        | 2022-12-01 23:19:13.319277+08 | 2022-12-0
1 23:19:13.319277+08
(1 row)

 schemaname |   tablename   | tableowner | tablespace | hasindexes | hasrul
es | hastriggers | tablecreator |            created            |         l
ast_ddl_time         
------------+---------------+------------+------------+------------+-------
---+-------------+--------------+-------------------------------+----------
---------------------
 public     | warehouse_t12 | user1      |            | f          | f     
musicdb=> 

6.查看 openGuass 数据库的默认表空间

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   |         16389 | music_tbs
 template0 |          1663 | pg_default
 postgres  |          1663 | pg_default
(5 rows)

7.查询数据库的默认表空间上的对象

select relname, relkind, relpages,pg_size_pretty(pg_relation_size(a.oid)),reltablespace,relowner  
from pg_class a  
where a.relkind in ('r', 'i')  
and reltablespace='0'  
order by a.relpages desc;

8.查询表空间 ds_location1 上的对像

\c musicdb user1
select relname, relkind, relpages,pg_size_pretty(pg_relation_size(a.oid)),reltablespace,relowner  
from pg_class a, pg_tablespace tb  
where a.relkind in ('r', 'i')  
and a.reltablespace=tb.oid  
and tb.spcname='ds_location1'  
order by a.relpages desc;


musicdb=> \c musicdb user1
Password for user user1: 
Non-SSL connection (SSL connection is recommended when requiring high-security)
You are now connected to database "musicdb" as user "user1".
musicdb=> 
(a.oid)),reltablespace,relowner  , relpages,pg_size_pretty(pg_relation_size(
musicdb-> from pg_class a, pg_tablespace tb  
musicdb-> where a.relkind in ('r', 'i')  
musicdb-> and a.reltablespace=tb.oid  
musicdb-> and tb.spcname='ds_location1'  
musicdb-> order by a.relpages desc;
   relname    | relkind | relpages | pg_size_pretty | reltablespace | relow
ner 
--------------+---------+----------+----------------+---------------+------
----
 warehouse_t1 | r       |        0 | 0 bytes        |         16395 |    16
391
(1 row)

课后作业

1.创建表空间 newtbs1、 ds_location,查看表空间

\db
create tablespace newtbs1 relative location 'tablespace/newtbs1';
create tablespace ds_location relative location 'tablespace/ds_location';

musicdb=> \db
              List of tablespaces
     Name     | Owner |        Location         
--------------+-------+-------------------------
 ds_location  | user1 | tablespace/ds_location
 ds_location1 | omm   | tablespace/tablespace_1
 music_tbs    | omm   | tablespace/test_ts1
 newtbs1      | user1 | tablespace/newtbs1
 pg_default   | omm   | 
 pg_global    | omm   | 
(6 rows)

2.创建一个数据库 newdb1,默认表空间为 newtbs1

create database newdb1 with tablespace = newtbs1;

musicdb=> \l
                         List of databases
   Name    | Owner | Encoding | Collate | Ctype | Access privileges 
-----------+-------+----------+---------+-------+-------------------
 musicdb   | omm   | UTF8     | C       | C     | 
 newdb1    | user1 | 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
(6 rows)

3.创建用户 user5,并授予 SYSADMIN 权限,访问数据库 newdb1,在表空间 ds_location 上,创建一个表 newt1(表结构自定义)

create user user5 IDENTIFIED BY 'JiekeXu_1234';
alter user user5 sysadmin;

\c newdb1 user5
create table newt1 (col1 char(10)) tablespace ds_location;

4.查看表所在的表空间

select tablespace from pg_tables where tablename = 'newt1';

newdb1=> \d newt1
        Table "public.newt1"
 Column |     Type      | Modifiers 
--------+---------------+-----------
 col1   | character(10) | 
Tablespace: "ds_location"

newdb1=> select tablespace from pg_tables where tablename = 'newt1';
 tablespace  
-------------
 ds_location
(1 row)

5.查看表空间 newtbs1、 ds_location 上的对象

select relname, relkind, relpages,pg_size_pretty(pg_relation_size(a.oid)),reltablespace,relowner  
from pg_class a, pg_tablespace tb  
where a.relkind in ('r', 'i')  
and a.reltablespace=tb.oid  
and tb.spcname in ('newtbs1','ds_location')  
order by a.relpages desc;

relname | relkind | relpages | pg_size_pretty | reltablespace | relowner 
---------+---------+----------+----------------+---------------+----------
 newt1   | r       |        0 | 0 bytes        |         16403 |    16405
(1 row)

欢迎关注我的公众号【JiekeXu DBA之路】,第一时间一起学习新知识!
————————————————————————————
公众号:JiekeXu DBA之路
CSDN :https://blog.csdn.net/JiekeXu
墨天轮:https://www.modb.pro/u/4347
腾讯云:https://cloud.tencent.com/developer/user/5645107
————————————————————————————
图片.png

「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

评论