0.学习内容与环境进入
学习目标
掌握openGauss视图的管理:创建视图、删除视图、查询视图的信息、修改视图的信息。
普通视图在查询中是实时进行计算的。如果建立视图的基表数据很多,使用视图的时候,进行实时计算视图表示的结果集,将消耗很大的计算机资源,并且费时很长。
物化视图提前计算出视图的结果集,并将该结果集保存在数据库里。
如果更新了基表,物化视图将过期。也就是说,基表更新后,物化视图不能反映最新的数据情况。因此在基表发生变化的时候,需要对物化视图进行更新。
-
系统视图
pg_views -
物化视图系统表
GS_MATVIEW
GS_MATVIEWS
select relname from pg_class where oid=(select matviewid from GS_MATVIEW); -
产生连续数组
generate_series(1,100000) -
创造视图
CREATE VIEW <viewname> AS
SELECT * FROM <tablename>
WHERE <condition>;
- 创造物化视图
create materialized view <viewname> as
select <columnname> from <tablename> where <condition>;
- 进入环境
su - omm 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.
\l
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)
1.创建表,创建普通视图
create schema tds;
CREATE TABLE tds.customer
( c_customer_sk integer,
c_customer_id char(10),
c_first_name char(20),
c_last_name char(20)
) ;
INSERT INTO tds.customer VALUES
(6885, 1, 'Joes', 'Hunter'),
(4321, 2, 'Lily','Carter'),
(9527, 3, 'James', 'Cook'),
(9500, 4, 'Lucy', 'Baker');
CREATE SCHEMA
CREATE TABLE
INSERT 0 4
CREATE TABLE
INSERT 0 4
CREATE VIEW tds.customer_details_view AS
SELECT * FROM tds.customer
WHERE c_customer_sk > 5400;
select * from tds.customer_details_view;
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)
---------------+---------------+----------------------+----------------------
6885 | 1 | Joes | Hunter
9527 | 3 | James | Cook
9500 | 4 | Lucy | Baker
(3 rows)
2.使用视图创建新的视图
create VIEW tds.part_view as SELECT * FROM tds.customer_details_view where c_customer_sk > 9000;
select * from tds.part_view;
c_customer_sk | c_customer_id | c_first_name | c_last_name
---------------+---------------+----------------------+----------------------
9527 | 3 | James | Cook
9500 | 4 | Lucy | Baker
(2 rows)
---------------+---------------+----------------------+----------------------
9527 | 3 | James | Cook
9500 | 4 | Lucy | Baker
(2 rows)
3.创建物化视图
drop materialized view if exists m_view;
create materialized view m_view as select * from tds.customer where c_customer_sk%2=0;
select count(*) from m_view;
count
-------
1
(1 row)
-------
1
(1 row)
4.手动更新物化视图
INSERT INTO tds.customer VALUES
(10000, 5, 'Woe', 'keeper'),
(2500, 6, 'Iron', 'nightwatch');
refresh materialized view m_view;
select count(*) from m_view;
count
-------
3
(1 row)
-------
3
(1 row)
5.删除创建的视图
- 先查看有哪些视图
select * from pg_views where schemaname = 'tds';
-----------------------
customer_details_view
part_view
(2 rows)
- 删除视图
drop view tds.part_view;
drop view tds.customer_details_view;
DROP VIEW
DROP VIEW
DROP VIEW
- 查看物化视图状态有两个表
select oid,* from GS_MATVIEW;
oid | matviewid | mapid | ivm | needrefresh | refreshtime
-------+-----------+-------+-----+-------------+----------------------------
16405 | 16401 | 0 | f | | 2022-12-11 15:48:43.845743
(1 row)
-------+-----------+-------+-----+-------------+----------------------------
16405 | 16401 | 0 | f | | 2022-12-11 15:48:43.845743
(1 row)
- 查看并删除物化视图
select * from GS_MATVIEWS;
DROP MATERIALIZED VIEW m_view;
schemaname | matviewname | matviewowner | tablespace | hasindexes | definition
------------+-------------+--------------+------------+------------+----------------------------------------------------------
-------------
public | m_view | omm | | f | SELECT * FROM tds.customer WHERE ((customer.c_customer_s
k % 2) = 0);
(1 row)
DROP MATERIALIZED VIEW
------------+-------------+--------------+------------+------------+----------------------------------------------------------
-------------
public | m_view | omm | | f | SELECT * FROM tds.customer WHERE ((customer.c_customer_s
k % 2) = 0);
(1 row)
DROP MATERIALIZED VIEW
最后修改时间:2022-12-11 17:55:56
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




