学习目标
掌握openGauss视图的管理:创建视图、删除视图、查询视图的信息、修改视图的信息。
课程学习
1.创建视图
--创建模式、表和插入数据
su - omm
sql -r
Create schema tpcds;
CREATE TABLE tpcds.customer
( c_customer_sk integer,
c_customer_id char(5),
c_first_name char(6),
c_last_name char(8)
) ;
INSERT INTO tpcds.customer VALUES
(6885, 1, 'Joes', 'Hunter'),
(4321, 2, 'Lily','Carter'),
(9527, 3, 'James', 'Cook'),
(9500, 4, 'Lucy', 'Baker');
--创建视图
CREATE VIEW tpcds.customer_details_view_v1 AS
SELECT * FROM tpcds.customer
WHERE c_customer_sk > 5400;
--查看视图内容
select * from tpcds.customer_details_view_v1;
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=# CREATE VIEW tpcds.customer_details_view_v1 AS
omm-# SELECT * FROM tpcds.customer
omm-# WHERE c_customer_sk > 5400;
CREATE VIEW
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
(3 rows)
omm=#
2.基于视图建立新的视图
create VIEW tpcds.part_view as SELECT * FROM tpcds.customer_details_view_v1 where c_customer_sk =9527;
--查看新的视图
select * from tpcds.part_view;
omm=# create VIEW tpcds.part_view as SELECT * FROM tpcds.customer_details_view_v1 where c_customer_sk =9527;
CREATE VIEW
omm=# select * from tpcds.part_view;
c_customer_sk | c_customer_id | c_first_name | c_last_name
---------------+---------------+--------------+-------------
9527 | 3 | James | Cook
(1 row)
omm=# 3.创建物化视图
普通视图在查询中是实时进行计算的。如果建立视图的基表数据很多,使用视图的时候,进行实时计算视图表示的结果集,将消耗很大的计算机资源,并且费时很长。
物化视图提前计算出视图的结果集,并将该结果集保存在数据库里。
如果更新了基表,物化视图将过期。也就是说,基表更新后,物化视图不能反映最新的数据情况。因此在基表发生变化的时候,需要对物化视图进行更新。
--创建基表
drop materialized view if exists mv_test;
drop table if exists test;
create table test(id serial primary key,testnum serial);
insert into test(testnum) values(generate_series(1,100000));
--创建物化视图:
create materialized view mv_test as
select * from test where testnum%2=0;
--查看物化视图目前有多少行记录:
select count(*) from mv_test;
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;
NOTICE: table "test" does not exist, skipping
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=# create materialized view mv_test as select * from test where testnum%2=0;
CREATE MATERIALIZED VIEW
omm=# select count(*) from mv_test;
count
-------
50000
(1 row)
omm=#4.普通视图相关的系统表pg_views
--系统视图pg_views
select * from pg_views where schemaname = 'tpcds' or schemaname = 'public';
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系统表提供了关于数据库中每一个物化视图的信息。select * from GS_MATVIEW;
omm=# select * from GS_MATVIEW;
matviewid | mapid | ivm | needrefresh | refreshtime
-----------+-------+-----+-------------+-------------
16412 | 0 | f | |
(1 row)
omm=#6.手动更新物化视图
--向基表test插入数据,查看物化视图有多少行记录:
insert into test(testnum) values(generate_series(1,100000));
select count(*) from mv_test;
--手动更新物化视图,并查看更新物化视图后,物化视图有多少行记录:
refresh materialized view mv_test;
select count(*) from mv_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=# refresh materialized view mv_test;
REFRESH MATERIALIZED VIEW
omm=# select count(*) from mv_test;
count
--------
100000
(1 row)
omm=#7.删除视图
--删除普通视图
DROP view tpcds.part_view;
DROP view TPCDS.customer_details_view_v1;
--删除物化视图
DROP MATERIALIZED VIEW mv_test;
omm=# DROP view tpcds.part_view;
DROP VIEW
omm=# DROP view TPCDS.customer_details_view_v1;
DROP VIEW
omm=# DROP MATERIALIZED VIEW mv_test;
DROP MATERIALIZED VIEW
omm=#
课程作业
1.创建表,创建普通视图
create table txiaocx(id int,name varchar(20));insert into txiaocx(name) values('user1');
insert into txiaocx(name) values('user2');
insert into txiaocx(name) values('user3');
insert into txiaocx(name) values('user4');
insert into txiaocx(name) values('user5');
insert into txiaocx(name) values('user6');
insert into txiaocx(name) values('xiaocx1');
insert into txiaocx(name) values('xiaocx2');
insert into txiaocx(name) values('xiaocx3');
omm=# create table txiaocx(id int,name varchar(20));
CREATE TABLE
omm=# insert into txiaocx(name) values('user1');
INSERT 0 1
omm=# insert into txiaocx(name) values('user2');
INSERT 0 1
omm=# insert into txiaocx(name) values('user3');
INSERT 0 1
omm=# insert into txiaocx(name) values('user4');
INSERT 0 1
omm=# insert into txiaocx(name) values('user5');
INSERT 0 1
omm=# insert into txiaocx(name) values('user6');
INSERT 0 1
omm=# insert into txiaocx(name) values('xiaocx1');
INSERT 0 1
omm=# insert into txiaocx(name) values('xiaocx2');
INSERT 0 1
omm=# insert into txiaocx(name) values('xiaocx3');
INSERT 0 1
omm=# 2.使用视图创建新的视图
CREATE VIEW v_xiaocx AS SELECT * FROM txiaocx WHERE name like 'xiaocx%';select * from v_xiaocx;
\dv
CREATE VIEW v_xiaocx_01 AS SELECT * from v_xiaocx;
select * from v_xiaocx;
\dv
omm=# CREATE VIEW v_xiaocx AS SELECT * FROM txiaocx WHERE name like 'xiaocx%';
CREATE VIEW
omm=#
omm=# select * from v_xiaocx;
id | name
----+---------
| xiaocx1
| xiaocx2
| xiaocx3
(3 rows)
omm=#omm=# \dv
List of relations
Schema | Name | Type | Owner | Storage
--------+----------+------+-------+---------
public | v_xiaocx | view | omm |
(1 row)
omm=#
omm=# CREATE VIEW v_xiaocx_01 AS SELECT * from v_xiaocx;
CREATE VIEW
omm=#
omm=# select * from v_xiaocx_01;
id | name
----+---------
| xiaocx1
| xiaocx2
| xiaocx3
(3 rows)
omm=# \dv
List of relations
Schema | Name | Type | Owner | Storage
--------+-------------+------+-------+---------
public | v_xiaocx | view | omm |
public | v_xiaocx_01 | view | omm |
(2 rows)
omm=#
3.创建物化视图
insert into txiaocx(name) values(generate_series(1,100000));create materialized view mv_xiaocx as select * from txiaocx where name>'5000';
select count(*) from mv_xiaocx;
\dm
omm=# insert into txiaocx(name) values(generate_series(1,100000));
INSERT 0 100000
omm=#
omm=# create materialized view mv_xiaocx as select * from txiaocx where name>'5000';
CREATE MATERIALIZED VIEW
omm=# select count(*) from mv_xiaocx;
count
-------
55560
(1 row)
omm=# \mv
Invalid command \mv. Try \? for help.
omm=# \dmv
List of relations
Schema | Name | Type | Owner | Storage
--------+-------------+-------------------+-------+----------------------------------
public | mv_xiaocx | materialized view | omm | {orientation=row,compression=no}
public | v_xiaocx | view | omm |
public | v_xiaocx_01 | view | omm |
(3 rows)
omm=# \dm
List of relations
Schema | Name | Type | Owner | Storage
--------+-----------+-------------------+-------+----------------------------------
public | mv_xiaocx | materialized view | omm | {orientation=row,compression=no}
(1 row)
omm=#
4.手动更新物化视图
insert into txiaocx(name) values(generate_series(1,100000));select count(*) from mv_xiaocx;
refresh materialized view mv_xiaocx;
select count(*) from mv_xiaocx;
omm=# insert into txiaocx(name) values(generate_series(1,100000));
INSERT 0 100000
omm=# select count(*) from mv_xiaocx;
count
-------
55560
(1 row)
omm=# refresh materialized view mv_xiaocx;
REFRESH MATERIALIZED VIEW
omm=# select count(*) from mv_xiaocx;
count
--------
111111
(1 row)
omm=#5.删除创建的视图
\dmvDROP VIEW v_xiaocx_01;
DROP VIEW v_xiaocx;
DROP MATERIALIZED VIEW mv_xiaocx;
\dmv
注意这里在删除视图(v_xiaocx),需要先删除依赖该视图的对象(v_xiaocx_01),或者使用关键字CASCADE。
DROP VIEW v_xiaocx CASCADE;
\dv
omm=# \dmv
List of relations
Schema | Name | Type | Owner | Storage
--------+-------------+-------------------+-------+----------------------------------
public | mv_xiaocx | materialized view | omm | {orientation=row,compression=no}
public | v_xiaocx | view | omm |
public | v_xiaocx_01 | view | omm |
(3 rows)
omm=#
omm=# DROP view v_xiaocx;
ERROR: cannot drop view v_xiaocx because other objects depend on it
DETAIL: view v_xiaocx_01 depends on view v_xiaocx
HINT: Use DROP ... CASCADE to drop the dependent objects too.omm=# DROP view v_xiaocx_01;
DROP VIEWomm=# DROP view v_xiaocx;
DROP VIEW
omm=# DROP MATERIALIZED VIEW mv_xiaocx;
DROP MATERIALIZED VIEW
omm=#
omm=# DROP VIEW v_xiaocx CASCADE;
NOTICE: drop cascades to view v_xiaocx_01
DROP VIEW
omm=# \DV
Invalid command \DV. Try \? for help.
omm=# \dv
No relations found.
omm=#
omm=# \dmv
No relations found.
omm=#
最后修改时间:2022-12-11 10:46:58
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




