openGauss每日一练第18天 |逻辑结构:视图管理
openGauss逻辑结构:视图管理
学习目标
掌握openGauss视图的管理:创建视图、删除视图、查询视图的信息、修改视图的信息。
课程学习
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=# create schema tpcds;
CREATE SCHEMA
omm=# CREATE TABLE tpcds.customer
omm-# ( c_customer_sk integer,
omm(# c_customer_id char(5),
omm(# c_first_name char(6),
omm(# c_last_name char(8)
omm(# ) ;
CREATE TABLE
omm=# INSERT INTO tpcds.customer VALUES
omm-# (6885, 1, 'Joes', 'Hunter'),
omm-# (4321, 2, 'Lily','Carter'),
omm-# (9527, 3, 'James', 'Cook'),
omm-# (9500, 4, 'Lucy', 'Baker');
INSERT 0 4
omm=#
--创建视图
omm=# CREATE VIEW tpcds.customer_details_view_v1 AS
omm-# SELECT * FROM tpcds.customer
omm-# WHERE c_customer_sk > 5400;
CREATE VIEW
omm=#
--查看视图内容
omm=# select * from tpcds.customer_details_view_v1;
c_customer_sk | c_customer_id | c_first_name | c_last_name
---------------+---------------+--------------+-------------
6885 | 1 | Joes | Hunter
9527 | 3 | James | Cook
9500 | 4 | Lucy | Baker
6885 | 1 | Joes | Hunter
9527 | 3 | James | Cook
9500 | 4 | Lucy | Baker
(6 rows)
omm=#
2.基于视图建立新的视图
omm=# create VIEW tpcds.part_view as SELECT * FROM tpcds.customer_details_view_v1 where c_customer_sk =9527;
CREATE VIEW
omm=#
--查看新的视图
omm=# select * from tpcds.part_view;
c_customer_sk | c_customer_id | c_first_name | c_last_name
---------------+---------------+--------------+-------------
9527 | 3 | James | Cook
9527 | 3 | James | Cook
(2 rows)
omm=#
3.创建物化视图
普通视图在查询中是实时进行计算的。如果建立视图的基表数据很多,使用视图的时候,进行实时计算视图表示的结果集,将消耗很大的计算机资源,并且费时很长。
物化视图提前计算出视图的结果集,并将该结果集保存在数据库里。
如果更新了基表,物化视图将过期。也就是说,基表更新后,物化视图不能反映最新的数据情况。因此在基表发生变化的时候,需要对物化视图进行更新。
--创建基表
omm=# drop materialized view if exists mv_test;
NOTICE: materialized view "mv_test" does not exist, skipping
DROP MATERIALIZED VIEW
omm=# drop table if exists test;
DROP TABLE
omm=# create table test(id serial primary key,testnum serial);
NOTICE: CREATE TABLE will create implicit sequence "test_id_seq" for serial column "test.id"
NOTICE: CREATE TABLE will create implicit sequence "test_testnum_seq" for serial column "test.testnum"
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "test_pkey" for table "test"
CREATE TABLE
omm=# insert into test(testnum) values(generate_series(1,100000));
INSERT 0 100000
omm=#
--创建物化视图:
omm=# create materialized view mv_test as
omm-# select * from test where testnum%2=0;
CREATE MATERIALIZED VIEW
omm=#
--查看物化视图目前有多少行记录:
omm=# select count(*) from mv_test;
count
-------
50000
(1 row)
omm=#
4.普通视图相关的系统表pg_views
--系统视图pg_views
omm=# select * from pg_views where schemaname = 'tpcds' or schemaname = 'public';
schemaname | viewname | viewowner | definition
------------+--------------------------+-----------+------------------------------------------------------------------------------------------------------
tpcds | customer_details_view_v1 | omm | SELECT * FROM tpcds.customer WHERE (customer.c_customer_sk > 5400);
tpcds | part_view | omm | SELECT * FROM tpcds.customer_details_view_v1 WHERE (customer_details_view_v1.c_customer_sk = 9527);
(2 rows)
omm=#
5.物化视图相关的系统表GS_MATVIEW
--GS_MATVIEW系统表提供了关于数据库中每一个物化视图的信息。
omm=# select * from GS_MATVIEW;
matviewid | mapid | ivm | needrefresh | refreshtime
-----------+-------+-----+-------------+-------------
16439 | 0 | f | |
(1 row)
omm=#
6.手动更新物化视图
--向基表test插入数据,查看物化视图有多少行记录:
omm=# insert into test(testnum) values(generate_series(1,100000));
INSERT 0 100000
omm=# select count(*) from mv_test;
count
-------
50000
(1 row)
omm=#
--手动更新物化视图,并查看更新物化视图后,物化视图有多少行记录:
omm=# refresh materialized view mv_test;
REFRESH MATERIALIZED VIEW
omm=# select count(*) from mv_test;
count
--------
100000
(1 row)
omm=#
7.删除视图
--删除普通视图
omm=# DROP view tpcds.part_view;
DROP VIEW
omm=# DROP view TPCDS.customer_details_view_v1;
DROP VIEW
omm=#
--删除物化视图
omm=# DROP MATERIALIZED VIEW mv_test;
DROP MATERIALIZED VIEW
omm=#
课程作业
1.创建表,创建普通视图
omm=# create schema myschema;
CREATE SCHEMA
omm=# create table myschema.lxs (
omm(# id int,
omm(# name varchar2(20) not null,
omm(# age int default 20,
omm(# primary key(id)
omm(# );
omm(# NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "lxs_pkey" for table "lxs"
CREATE TABLE
omm=# insert into myschema.lxs values
omm-# (1,'zhao',22),
omm-# (2,'qian',25),
omm-# (3,'sun',27),
omm-# (4,'li',28);
INSERT 0 4
omm=# select * from myschema.lxs;
id | name | age
----+------+-----
1 | zhao | 22
2 | qian | 25
3 | sun | 27
4 | li | 28
(4 rows)
omm=#
omm=# create view myschema.v_lxs as select * from myschema.lxs where age<26;
CREATE VIEW
omm=# select * from myschema.v_lxs;
id | name | age
----+------+-----
1 | zhao | 22
2 | qian | 25
(2 rows)
omm=#
2.使用视图创建新的视图
omm=# create view myschema.v_lxs_new as select * from myschema.v_lxs where age=22;
CREATE VIEW
omm=# select * from myschema.v_lxs_new;
id | name | age
----+------+-----
1 | zhao | 22
(1 row)
omm=#
3.创建物化视图
omm=# create table lxs1 (id serial ,lxsnum int );
NOTICE: CREATE TABLE will create implicit sequence "lxs1_id_seq" for serial column "lxs1.id"
CREATE TABLE
omm=# insert into lxs1(lxsnum) values(generate_series(1,50));
INSERT 0 50
omm=# create materialized view mv_lxs1 as select * from lxs1 where lxsnum%5=0;
CREATE MATERIALIZED VIEW
omm=# select * from mv_lxs1;
id | lxsnum
----+--------
5 | 5
10 | 10
15 | 15
20 | 20
25 | 25
30 | 30
35 | 35
40 | 40
45 | 45
50 | 50
(10 rows)
omm=#
4.手动更新物化视图
omm=# insert into lxs1(lxsnum) values(generate_series(50,100));
omm=# INSERT 0 51
select * from mv_lxs1;
id | lxsnum
----+--------
5 | 5
10 | 10
15 | 15
20 | 20
25 | 25
30 | 30
35 | 35
40 | 40
45 | 45
50 | 50
(10 rows)
omm=# refresh materialized view mv_lxs1;
REFRESH MATERIALIZED VIEW
omm=# select * from mv_lxs1;
id | lxsnum
-----+--------
5 | 5
10 | 10
15 | 15
20 | 20
25 | 25
30 | 30
35 | 35
40 | 40
45 | 45
50 | 50
104 | 50
109 | 55
114 | 60
119 | 65
124 | 70
129 | 75
134 | 80
139 | 85
144 | 90
149 | 95
154 | 100
(21 rows)
omm=#
5.删除创建的视图
omm=# drop view myschema.v_lxs;
ERROR: cannot drop view myschema.v_lxs because other objects depend on it
DETAIL: view myschema.v_lxs_new depends on view myschema.v_lxs
HINT: Use DROP ... CASCADE to drop the dependent objects too.
omm=# drop view myschema.v_lxs_new;
DROP VIEW
omm=#
omm=# drop view myschema.v_lxs;
DROP VIEW
omm=#
omm=# drop materialized view mv_lxs1;
DROP MATERIALIZED VIEW
omm=#
–学如逆水行舟,不进则退。
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




