DROP TABLE Z CASCADE CONSTRAINTS PURGE;
DROP TABLE YEARS CASCADE CONSTRAINTS PURGE;
DROP MATERIALIZED VIEW Z_MV;
CREATE TABLE Z(Z NUMBER(16) NOT NULL
, VALIDFROM NUMBER(4) NOT NULL
, VALIDTILL NUMBER(4) NOT NULL
, CONSTRAINT FRO2000 CHECK (2000 < VALIDFROM)
, CONSTRAINT TIL2050 CHECK (VALIDTILL <= 2050)
, CONSTRAINT FROTIL CHECK (VALIDFROM <= VALIDTILL)
);
CREATE TABLE YEARS AS
SELECT 2000+LEVEL TIM FROM DUAL CONNECT BY LEVEL < (2051-2000)
;
CREATE MATERIALIZED VIEW LOG ON Z WITH ROWID
;
CREATE MATERIALIZED VIEW LOG ON YEARS WITH ROWID
;
CREATE MATERIALIZED VIEW Z_MV REFRESH FAST ON COMMIT AS
SELECT Z.ROWID ZRID,T.ROWID TRID,Z.Z,T.TIM
FROM Z INNER JOIN YEARS T ON VALIDFROM < T.TIM AND T.TIM <= VALIDTILL
;
With Oracle 11.1.0.7 and 11.2.0.1 getting
ORA-12054: cannot set the ON COMMIT refresh attribute for the materialized view
No worries. It is about inner join syntax not so widely supported with MVs.
CREATE MATERIALIZED VIEW Z_MV REFRESH FAST ON COMMIT AS
SELECT Z.ROWID ZRID,T.ROWID TRID,Z.Z,T.TIM
FROM Z,YEARS T
WHERE VALIDFROM < T.TIM AND T.TIM <= VALIDTILL
;
ALTER TABLE Z_MV ADD CONSTRAINT Z_MV_U UNIQUE (Z,TIM);
CREATE INDEX Z_MV_ZRID_IDX ON Z_MV(ZRID);
ZRID indexed to give the optimizer at least a possibility to do small updates "fast". More about the issue may be read from Alberto Dell'Era's Oracle blog
INSERT INTO Z VALUES(1,2001,2011);
INSERT INTO Z VALUES(1,2011,2011);
COMMIT;
INSERT INTO Z VALUES(1,2010,2012);
COMMIT;
SQL ERROR: ORA-12008: ERROR IN MATERIALIZED VIEW REFRESH PATH
ORA-00001: UNIQUE CONSTRAINT (RAFU.Z_MV_U) VIOLATED
INSERT INTO Z VALUES(2,2049,2050);
COMMIT;
INSERT INTO Z VALUES(2,2049,2050);
COMMIT;
SQL ERROR: ORA-12008: ERROR IN MATERIALIZED VIEW REFRESH PATH
ORA-00001: UNIQUE CONSTRAINT (RAFU.Z_MV_U) VIOLATED
INSERT INTO Z VALUES(2,2010,2012);
COMMIT;
INSERT INTO Z VALUES(2,2001,2049);
COMMIT;
SQL ERROR: ORA-12008: ERROR IN MATERIALIZED VIEW REFRESH PATH
ORA-00001: UNIQUE CONSTRAINT (RAFU.Z_MV_U) VIOLATED
INSERT INTO Z VALUES(2,2014,2017);
COMMIT;
SELECT * FROM Z ORDER BY Z, VALIDFROM;
1 2001 2011
1 2011 2011
2 2010 2012
2 2014 2017
2 2049 2050
SELECT COUNT(*) FROM Z_MV;
16
No comments:
Post a Comment