Configuring Wireless

  • Subscribe to our RSS feed.
  • Twitter
  • StumbleUpon
  • Reddit
  • Facebook
  • Digg

Tuesday, September 6, 2011

Oracle PL/SQL: Working with Materialized Views in a 24/7 Reporting Environment

Posted on 11:50 AM by Unknown

This blog post gives an outline for a process that will provide users with the Last Update, Next Update, and a "nice message" during a materialized view refresh.

The purpose of this blog post is to provide your report writers with a way of identifying whether or not the view is currently being refreshed so they can "try again later". Of course for business-critical up-to-the-second reporting you might not want to be using materialized views at all.


Setting Up The Demonstration System
In order to show this in action we need to setup the following items in a database;

create table MAT_VIEW_TEST
(
  ID          number not null,
  SHORTCODE   varchar2(30) not null,
  DESCRIPTION varchar2(255),
  STARTDATE   date not null,
  ENDDATE     date
)
;

alter table MAT_VIEW_TEST
  add constraint MAT_VIEW_TEST_PK primary key (ID);

insert into MAT_VIEW_TEST (ID, SHORTCODE, DESCRIPTION, STARTDATE, ENDDATE)
values (1, 'IT', 'IT Department', to_date('01-05-2010', 'dd-mm-yyyy'), null);
insert into MAT_VIEW_TEST (ID, SHORTCODE, DESCRIPTION, STARTDATE, ENDDATE)
values (2, 'IT', 'Business Systems Department', to_date('01-01-1980', 'dd-mm-yyyy'), to_date('30-04-2010', 'dd-mm-yyyy'));
insert into MAT_VIEW_TEST (ID, SHORTCODE, DESCRIPTION, STARTDATE, ENDDATE)
values (3, 'FIN', 'Finance', to_date('01-01-1980', 'dd-mm-yyyy'), null);
insert into MAT_VIEW_TEST (ID, SHORTCODE, DESCRIPTION, STARTDATE, ENDDATE)
values (4, 'PRC', 'Procurement', to_date('01-01-1980', 'dd-mm-yyyy'), null);
insert into MAT_VIEW_TEST (ID, SHORTCODE, DESCRIPTION, STARTDATE, ENDDATE)
values (5, 'LEG', 'Legal', to_date('01-01-1980', 'dd-mm-yyyy'), null);
commit;

 create materialized view mat_view_test_mv
  refresh complete 
   start with sysdate 
   next trunc(sysdate)+1 + 5/24 as
  select *
    from mat_view_test
 ;

The materialized view we're creating will refresh immediately and will then schedule itself to refresh at 5am each day going forward.

Aims and Expected Results
The whole point of this Knol is to manage the users expectations. If you provide them a report which is refreshed at 5am and they make a change to the data and then run the report you want them to know why they're not going to see their new record so they don't call your helpdesk and start saying the report is "broken".

The result we're expecting to see (from a simple SELECT * ...) would be;


(1) - This is the date the view was last refreshed and the date the view will next be refreshed.
(2) - As all the records are being returned from the main table the message always reads "OK".

We would expect to get this result at any time other than when the view was being refreshed. When the view is actively being refreshed then the result would normally be blank but what we'd like to see would be a single row returned with the message "REFRESHING".


Building Our View of the Materialized View
Now the values we need (the last and next refresh dates) are stored in SYS.ALL_MVIEWS and SYS.DBA_JOBS respectively. It's a fairly simple process to join these objects together and get the result;

select am.LAST_REFRESH_DATE,
       dj.next_date next_refresh_date,
       'OK' as message,
       mvtv.*
  from MAT_VIEW_TEST_MV mvtv
  left outer join sys.dba_jobs dj
    on dj.what =
       'dbms_refresh.refresh(''"' || USER || '"."MAT_VIEW_TEST_MV"'');'
  join sys.all_mviews am
    on am.owner = user
   and am.mview_name = 'MAT_VIEW_TEST_MV'

We can use a default for the message so that we can change it to something more meaningful in the reporting tool.

Now that we've got our main result we now need to handle the special case when MAT_VIEW_TEST_MV contains no records. The easiest way to do this is to use the DUAL system object to return a single row and do a check in MAT_VIEW_TEST_MV for records. For example;

select null, null, 'REFRESHING', mvtv.*
  from sys.dual
  left join MAT_VIEW_TEST_MV mvtv
    on 3 = 1
 where not exists (select 'x' from MAT_VIEW_TEST_MV)

Now you're probably already spotted that the columns returned by both queries are identical which makes unioning them a lot easier giving you the final piece of SQL;

create view mat_view_test_v as
select am.LAST_REFRESH_DATE,
       dj.next_date next_refresh_date,
       'OK' as message,
       mvtv.*
  from MAT_VIEW_TEST_MV mvtv
  left outer join sys.dba_jobs dj
    on dj.what =
       'dbms_refresh.refresh(''"' || USER || '"."MAT_VIEW_TEST_MV"'');'
  join sys.all_mviews am
    on am.owner = user
   and am.mview_name = 'MAT_VIEW_TEST_MV'
union
select null, null, 'REFRESHING', mvtv.*
  from sys.dual
  left join MAT_VIEW_TEST_MV mvtv
    on 3 = 1
 where not exists (select 'x' from MAT_VIEW_TEST_MV)

You now have a view which will return the contents of the materialized view if it has any or a single record you can check for if it doesn't.

Email ThisBlogThis!Share to XShare to FacebookShare to Pinterest
Posted in materialized views, Oracle, pl/sql | No comments
Newer Post Older Post Home

0 comments:

Post a Comment

Subscribe to: Post Comments (Atom)

Popular Posts

  • Oracle PL/SQL: Working With Oracle Jobs (Showing/ Deleting/ Adding)
    Showing All Oracle Jobs To see a list of the currently configured Oracle Jobs use the SQL; SELECT job,        schema_user,        last_date,...
  • Oracle PL/SQL: Copying Column Comments From One View To Another
    This blog post gives a piece of simple SQL that will allow you to automatically copy the comments from one database view to another. In the ...
  • Oracle PL/SQL: Using DBMS_LDAP To Query Active Directory
    It's always useful to be able to retrieve details from Active Directory when working within an Oracle Database (I'll do a separate p...
  • PL/SQL: Using R12 Item Open Interface Tables
    I'm sure we won't be the only company to need to do a batch update of all the existing Items (in INV.MTL_SYSTEM_ITEMS_B) so I though...
  • SSRS: Deployment Problems With Large Data Models
    This blog post describes how to solve the "Maximum request length exceeded" error when deploying large data models; the "maxi...
  • SSRS: Creating a "Shared Reports" folder in Reporting Services
    This blog post covers step-by step instructions on how to create a folder that can be shared between multiple users without being publicly f...
  • Oracle EBS: Creating New Menu Items in Oracle e-Business Suite
    NOTE: Don't do this on a production environment. Did that need saying? Apparently one person who submitted a comment seemed to think so ...
  • Lot Genealogy, Part 3: Debugging Lots and Batches
    As you might have noticed I've just updated the LOT_GENEALOGY source code for this project to a new version following the discovery of a...
  • SSRS: Adding Calculated Fields To Data Sets
    This blog post covers an example of how to add a simple calculated field to a Dataset in SQL Server Reporting Services using Report Builder ...
  • Noetix: Adding a new Z$ Column Reference
    Sometimes you need to add an additional Z$ column to link between two view. This Google Knol tells you what you need to know to make a simpl...

Categories

  • .net framework
  • #Error
  • 1080p
  • 1248ub
  • 2007
  • 2008R2
  • 32-bit
  • 4.1.1
  • 64-bit
  • 720p
  • accellion
  • active directory
  • ad
  • airplay
  • All_Col_Comments
  • All_MViews
  • All_Objects
  • All_Source
  • All_Tab_Columns
  • All_Tables
  • All_Views
  • ALR_Action_Outputs_Pkg
  • ALR_Action_Sets
  • ALR_Actions_Pkg
  • ALR_Alert_Installations_Pkg
  • ALR_Alert_Outputs_Pkg
  • ALR_Alerts_Pkg
  • ALR_DBTrigger
  • amazon wishlist
  • aod
  • AP
  • AP_Credit_Card_Trxns_All
  • AP_Invoices_All
  • AP_Payables
  • AP_Vendor_Sites_Pkg
  • AP_Vendors_Pkg
  • app-v
  • apple
  • apple mac
  • apple maps
  • apple tv
  • application virtualisation
  • AR_Receivables
  • arbury carnival
  • arbury community centre
  • arbury court
  • arbury court library
  • army of darkness
  • army of darkness defense
  • asp.net
  • audiobooks
  • bar hill cambridgeshire uk
  • bar hill library
  • bbc micro
  • bids
  • biztalk 2009
  • british telecom
  • business intelligence development studio
  • business objects
  • c sharp
  • cambridge central library
  • cambridge regional college
  • cambridge station
  • cambridgeshire county council
  • cambridgeshire library service
  • Cast()
  • ccc
  • CDate()
  • citi 1
  • city councillor
  • classic pc
  • cmdb
  • commodore 64
  • Concurren Requests
  • configuration items
  • configuration management database
  • conservative
  • Count()
  • county councillor
  • crc
  • D600
  • data model
  • data source
  • database link
  • dataset
  • DateAdd()
  • DateSerial()
  • dba_jobs
  • DBA_Objects
  • DBA_Tab_Columns
  • dbms_job
  • DBMS_LDAP
  • dbms_refresh
  • dbo.AllUserData
  • dbo.Catalog
  • dbo.ExecutionLogStorage
  • Dell
  • district councillor
  • doodle.com
  • dos box
  • driver
  • e-Business Suite
  • easypush
  • EBS
  • email
  • epetitions
  • excel
  • ExecutionLog2
  • fa
  • FA_Fixed_Assets
  • fixed assets
  • FND_Form_Functions
  • FND_Form_Functions_Pkg
  • FND_Global
  • FND_Menu_Entries
  • FND_Menu_Entries_Pkg
  • FND_Menus
  • FND_Profile_Option_Values
  • FND_Profile_Options
  • FND_Program
  • FND_Request
  • FND_Users
  • FOI
  • Format()
  • freedom of information
  • Functional Administrator
  • GL_Daily_Rates_V
  • GL_Item_Cst
  • GL_Je_Lines
  • GL_Ledger
  • Gmail
  • GMD_Product_Development
  • GME_Process_Execution
  • GMF_OPM_Financials
  • GMF_Period_Balances
  • GMF_SLA_Cost_Subledger
  • gmfg0_item_costs
  • GMI_Onhand_Inv_By_Lot
  • GMI_Process_Planning
  • google
  • google dns
  • google knol
  • google maps
  • green
  • gremlin
  • group policy
  • guided bus
  • high definition
  • home hub 3.0
  • home sharing
  • hr.net
  • i-Expenses
  • ibm
  • iccid
  • iExpenses
  • IIF
  • IIF()
  • iis
  • iis 6
  • imei
  • information
  • installation
  • InStr
  • InStrRev
  • Internet Expenses
  • INV_Forecasts
  • INV_Inventory
  • INV_Item_Onhand_By_lot
  • inv_lot_transactions
  • INV_Onhand_Quantities
  • INV_Period_Close_Details
  • INV_Quantity_Tree_Pub
  • inv_reservations
  • iOS
  • iOS 6
  • ip address
  • iPad
  • ipconfig
  • iPhone
  • iPod
  • iresign
  • itunes
  • java
  • Join()
  • june
  • key flex field
  • Key Flex Fields
  • kff
  • labour
  • Latitude
  • Left()
  • level 50
  • Liberal Democrat
  • libraries
  • Lookup()
  • lot genealogy
  • materialized views
  • maximo
  • microsoft
  • microsoft app-v
  • microsoft exchange
  • microsoft paint
  • migration
  • MobileIron
  • Month()
  • MRP_Forecast_Dates
  • MRP_Forecast_Designators
  • msi
  • Mtl_Material_Status_History
  • MTL_System_Items_B
  • mtl_system_items_interface
  • mustek
  • N_Buffer
  • N_F_KFF_Flex_Sources
  • N_GSeg_Pkg
  • N_Gseg_Utility_Pkg
  • N_KFF_Ctlg_Grp
  • N_KFF_GL_Acct
  • N_KFF_Item_Loc
  • N_KFF_Mtl_Cat
  • N_KFF_Sys_Item
  • N_KFF_Sys_Item_Pkg
  • N_Role_View_Templates
  • N_View_Column_Property_Templates
  • N_View_Column_Templates
  • N_View_Columns
  • N_View_Query_Templates
  • N_View_Table_Templates
  • N_View_Templates
  • N_View_Where_Templates
  • N_Views
  • native-mode
  • ncm
  • NLS_Language
  • NLS_Territory
  • noetix
  • noetix customization maintenance
  • noetix views
  • Now()
  • OE_Order_Entry
  • OIE
  • open interface
  • open source software
  • opensource-it.com
  • opm
  • ORA-01795
  • Oracle
  • Oracle Alerts
  • oracle client
  • Oracle General Ledger
  • Oracle Internet Expenses
  • Oracle Payables
  • Oracle Process Manufacturing
  • oracle sql developer
  • orchard park
  • os x
  • os x lion
  • Outlook
  • parish councillor
  • Payables
  • pc line
  • pcl-3000
  • pl/sql
  • PO_Distributions_All
  • PO_Purchasing
  • PO_Vendor_Sites
  • PO_Vendors
  • port forwarding
  • quick guide
  • Recyclebin
  • Release 11
  • Release 12
  • remote server administration tools
  • Replace()
  • report builder 3
  • router
  • run as a different user
  • sap
  • scom
  • services
  • sharepoint
  • sharepoint 2007
  • sharepoint 2010
  • sharepoint content types
  • sharepoint document library
  • sharepoint integrated-mode
  • sharepoint native-mode
  • sla
  • smtp
  • sql server
  • sql server 2012
  • sql server analysis services
  • sql server integration services
  • sql server reporting services
  • ssas
  • ssis
  • ssrs
  • subledger accounting
  • subsidence
  • super hub
  • sysdate
  • system centre operations manager
  • telnet
  • test
  • textfile-search-and-replace
  • tnsnames.ora
  • town councillor
  • udid
  • ukip
  • umbraco
  • user accounts
  • User_Triggers
  • virgin media
  • vizual
  • vmware fusion
  • windows
  • windows 2003
  • windows 2008r2
  • windows 7
  • windows 8
  • windows 8 consumer preview
  • windows 8 server
  • windows update
  • windows vista
  • Wireless Drivers
  • wireless networking
  • wItem Installer
  • wnoetxu2.sql
  • wnoetxu5.sql
  • wnoetxu6.sql
  • work order
  • workflow builder
  • world of spectrum
  • xcode
  • XLA_Distribution_Links
  • xxk_mtl_cat
  • XXNAO
  • Year()
  • zool
  • zx spectrum

Blog Archive

  • ►  2013 (43)
    • ►  August (2)
    • ►  June (1)
    • ►  May (2)
    • ►  April (8)
    • ►  March (3)
    • ►  February (14)
    • ►  January (13)
  • ►  2012 (63)
    • ►  December (2)
    • ►  October (1)
    • ►  September (4)
    • ►  August (4)
    • ►  July (5)
    • ►  June (6)
    • ►  May (3)
    • ►  April (4)
    • ►  March (10)
    • ►  February (11)
    • ►  January (13)
  • ▼  2011 (65)
    • ►  December (8)
    • ►  November (8)
    • ►  October (7)
    • ▼  September (9)
      • SSRS: Creating a "Shared Reports" folder in Report...
      • Oracle EBS: Linking GL Lines to AP Invoice Distrib...
      • SSRS: Sharing Report Builder 3 Reports Between Users
      • Noetix: Adding a Flexfield to a View
      • Oracle PL/SQL: Working with Materialized Views in ...
      • Oracle PL/SQL: When are Materialized Views refresh...
      • Oracle PL/SQL: Removing an Existing Materialized View
      • SSRS: Problems Linking To SharePoint Lists When Ru...
      • SSRS: Using &ReportName In SharePoint Mode vs Nati...
    • ►  August (9)
    • ►  July (9)
    • ►  June (6)
    • ►  May (2)
    • ►  March (1)
    • ►  February (5)
    • ►  January (1)
  • ►  2010 (9)
    • ►  December (1)
    • ►  November (3)
    • ►  September (1)
    • ►  July (1)
    • ►  June (1)
    • ►  February (2)
  • ►  2009 (9)
    • ►  December (1)
    • ►  November (1)
    • ►  August (1)
    • ►  July (1)
    • ►  May (3)
    • ►  March (1)
    • ►  February (1)
  • ►  2008 (11)
    • ►  November (2)
    • ►  October (1)
    • ►  July (1)
    • ►  May (1)
    • ►  April (2)
    • ►  February (1)
    • ►  January (3)
  • ►  2007 (4)
    • ►  December (4)
  • ►  2004 (1)
    • ►  December (1)
Powered by Blogger.

About Me

Unknown
View my complete profile