学习目标
表空间是数据的容器。掌握表空间的管理,包括创建表空间、删除表空间、重命名表空间、查看表空间的情况。
课程学习
通过使用表空间,管理员可以控制一个数据库安装的磁盘布局。
表空间对应于一个文件系统目录,假定数据库节点数据目录/pg_location/mount1/path1是用户拥有读写权限的空目录。
openGauss自带了两个表空间:pg_default和pg_global。
默认表空间pg_default:用来存储非共享系统表、用户表、用户表index、临时表、临时表index、内部临时表的默认表空间。对应存储目录为实例数据目录下的base目录。
共享表空间pg_global:用来存放共享系统表的表空间。对应存储目录为实例数据目录下的global目录。
连接数据库 #第一次进入等待15秒 #数据库启动中... su - omm gsql -r1.执行如下命令创建用户jack
CREATE USER jack IDENTIFIED BY 'kunpeng@1234';2.创建表空间、表
--执行下面的SQL语句,创建表空间t_tbspace: CREATE TABLESPACE t_tbspace RELATIVE LOCATION 'tablespace/t_tbspace1'; --查看系统有哪些表空间 select oid,* from pg_tablespace ; 或 \db --数据库系统管理员执行如下命令将“t_tbspace”表空间的访问权限赋予数据用户jack。 GRANT CREATE ON TABLESPACE t_tbspace TO jack; --执行如下命令,使用jack用户在指定表空间t_tbspace创建表。 \c omm jack CREATE TABLE foo(i int) TABLESPACE t_tbspace; \q3.查看表空间t_tbspace的大小
gsql -r SELECT PG_TABLESPACE_SIZE('t_tbspace');4.查看数据库在默认表空间下有哪些对象
with objectInDefaultTS as ( 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' ) select * from objectInDefaultTS where relname not like 'pg_%' and relname not like 'gs_%' and relname not like 'sql_%' order by relpages desc;5.查看数据库在非默认表空间下有哪些对象
--执行下面的SQL语句,查询数据库studentdb的非默认表空间t_tbspace下有哪些对象: 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='t_tbspace' order by a.relpages desc;6.重命名表空间
--命名表空间t_tbspace为app_tbs ALTER TABLESPACE t_tbspace RENAME TO app_tbs; --执行下面的gsql命令,查看数据库当前的表空间信息: \db复制
7.删除表空间
--用户必须是表空间的owner或者系统管理员才能删除表空间。需要先删除表空间的对象,再删除表空间app_ts: drop table jack.foo ; DROP TABLESPACE app_tbs;学习目标
1、创建表空间t_tbspace、用户test,并使用test,在这个表空间上创建表t1
```sql
omm=# create user test identified by 'kunpeng@1234'; NOTICE: The encrypted password contains MD5 ciphertext, which is not secure. CREATE ROLE omm=# create tablespace t_tbspace RELATIVE LOCATION 'tablespace/tb_1'; CREATE TABLESPACE
omm=# select oid, * from pg_tablespace; oid | spcname | spcowner | spcacl | spcoptions | spcmaxsize | relative -------+------------+----------+--------+------------+------------+---------- 1663 | pg_default | 10 | | | | f 1664 | pg_global | 10 | | | | f 16393 | t_tbspace | 10 | | | | t (3 rows) omm=# \db List of tablespaces Name | Owner | Location ------------+-------+----------------- pg_default | omm | pg_global | omm | t_tbspace | omm | tablespace/tb_1 (3 rows)
omm=# grant create on tablespace t_tbspace to test; GRANT
omm=# \c omm test Password for user test: Non-SSL connection (SSL connection is recommended when requiring high-security) You are now connected to database "omm" as user "test". omm=> create table t1(id integer) tablespace t_tbspace; CREATE TABLE
```
2、查看表空间t_tbspace的oid和大小
```sql
omm=# SELECT PG_TABLESPACE_SIZE('t_tbspace'); pg_tablespace_size -------------------- 8192 (1 row) omm=# select oid ,* from pg_tablespace; oid | spcname | spcowner | spcacl | spcoptions | spcmaxsize | relative -------+------------+----------+------------------------+------------+------------+---------- 1663 | pg_default | 10 | | | | f 1664 | pg_global | 10 | | | | f 16393 | t_tbspace | 10 | {omm=C/omm,test=C/omm} | | | t (3 rows)
```
3、查看数据库在默认表空间下有哪些对象
```sql
omm=# with objectInDefaultTS as omm-# ( select relname, relkind, relpages,pg_size_pretty(pg_relation_size(a.oid)), omm(# reltablespace,relowner omm(# from pg_class a omm(# where a.relkind in ('r', 'i') and reltablespace='0' omm(# ) omm-# select * omm-# from objectInDefaultTS omm-# where relname not like 'pg_%' and relname not like 'gs_%' and relname not like 'sql_%' omm-# order by relpages desc; relname | relkind | relpages | pg_size_pretty | reltablespace | relowner ------------------------------------------+---------+----------+----------------+---------------+---------- streaming_gather_agg_index | i | 2 | 16 kB | 0 | 10 snapshot_id_key | i | 1 | 8192 bytes | 0 | 10 streaming_cont_query_lookupidxid_index | i | 1 | 8192 bytes | 0 | 10 streaming_cont_query_schema_change_index | i | 1 | 8192 bytes | 0 | 10 streaming_reaper_status_id_index | i | 1 | 8192 bytes | 0 | 10 streaming_reaper_status_oid_index | i | 1 | 8192 bytes | 0 | 10 snapshot_pkey | i | 1 | 8192 bytes | 0 | 10 statement_history_time_idx | i | 1 | 8192 bytes | 0 | 10 streaming_stream_oid_index | i | 1 | 8192 bytes | 0 | 10 streaming_stream_relid_index | i | 1 | 8192 bytes | 0 | 10 streaming_cont_query_relid_index | i | 1 | 8192 bytes | 0 | 10 streaming_cont_query_defrelid_index | i plan_table_data | r | 0 | 0 bytes | 0 | 10 statement_history | r | 0 | 0 bytes | 0 | 10 streaming_stream | r | 0 | 0 bytes | 0 | 10 snapshot | r | 0 | 0 bytes | 0 | 10 streaming_reaper_status | r | 0 | 0 bytes | 0 | 10 | 1 | 8192 bytes | 0 | 10 streaming_cont_query_id_index | i | 1 | 8192 bytes | 0 | 10 streaming_cont_query_oid_index | i | 1 | 8192 bytes | 0 | 10 streaming_cont_query_matrelid_index | i | 1 | 8192 bytes | 0 | 10 streaming_cont_query | r | 0 | 0 bytes | 0 | 10 (21 rows)
```
4、查看数据库在非默认表空间下有哪些对象
```sql
omm=# --执行下面的SQL语句,查询数据库studentdb的非默认表空间t_tbspace下有哪些对象: omm=# select relname,relkind,relpages,pg_size_pretty(pg_relation_size(a.oid)), omm-# reltablespace,relowner omm-# from pg_class a, pg_tablespace tb omm-# where a.relkind in ('r', 'i') and a.reltablespace=tb.oid omm-# omm-# omm-# and tb.spcname='t_tbspace' order by a.relpages desc; relname | relkind | relpages | pg_size_pretty | reltablespace | relowner ---------+---------+----------+----------------+---------------+---------- t1 | r | 0 | 0 bytes | 16393 | 16389 (1 row)
```
5、重命名表空间
```sql
omm=# --命名表空间t_tbspace为app_tbs omm=# ALTER TABLESPACE t_tbspace RENAME TO app_tbs; ALTER TABLESPACE omm=# --执行下面的gsql命令,查看数据库当前的表空间信息: omm=# \db List of tablespaces Name | Owner | Location ------------+-------+----------------- app_tbs | omm | tablespace/tb_1 pg_default | omm | pg_global | omm | (3 rows)
```
6、删除表空间
```sql
omm=# drop table test.t1; DROP TABLE omm=# drop tablespace app_tbs; omm=# DROP TABLESPACE
```




