Configuring Wireless

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

Monday, January 9, 2012

Noetix: Removing Item Information Caching @ Release 12

Posted on 5:29 AM by Unknown
We use Oracle E-Business Suite to manage our (pharmaceutical) production facility. Because of the nature of the work we do we create items, batches, and lots every single day of the week. Normally this isn't a problem but in Noetix views item information is cached in the N_KFF_SYS_Item table and is only refreshable by using a supplied concurrent processes.

Clearly as we're creating multiple items every day it's just not practical for us to add a "Now run the concurrent process" step across our business to make sure that the reporting information is up to date for those running reports. It also creates an issue of "trust" - if users are looking at cached data is it up to date or not?

Looking at the source code for the Noetix views which access the cached information rather than going directly to the cached table they instead go via a view; XXK_Sys_Item which just does a direct select from the table  (I'm making a point here of not just copy/pasting blocks of Noetix source code so you'll find a lot of this is instructions on how to find the code rather than the code itself). The benefit of this approach is that if we want to stop using caching we just replace the view with a new view that goes directly to the table. You may be thinking that it might actually be easier to replace the references to the view in the Noetix configuration tables but unfortunately this isn't actually possible. If you look in the table N_View_Table_Templates (or just N_View_Tables) for the view_label INV_Items you will notice that the only NOETIX table in use is N_MFG_LOOKUPS_VL - no mention of the XXK_Sys_Item view. This must be added "elsewhere".

Doing a search of the source code (.sql) files in the Noetix install directory for the table name reveals that the regenerate process builds a package called N_KFF_SYS_Item_Pkg to handle the management of the cached table.

So in summary here is the structure (with INVG0_Items being the public view we're going to use for testing);


Looking in more detail at the N_Kff_SYS_Item_Pkg package we can see that the routine called Init_Upld (which is the basis for the concurrent request) does the initial upload of rows into the table - it's the SQL to do this that we need to build into a view to replace the XXK_Sys_Item view.

In the source code (in the N_KFF_Sys_Item_pkg.sql file) I'm looking at line 145 which does the insert (it reads "INSERT  /*+ APPEND */ INTO N_KFF_Sys_Item" if you want to search for it in your Source code. The format for the insert is a simple SELECT ... which makes life a lot easier when you're looking at creating a view!

Looking at the columns inserted not all of them are making it through to the view (last_update_date for instance) so this column isn't needed in our replacement view. Clearly some clever logic has gone into building this view which would pick up multiple segments and structures but in our system it seems a lot of this is wasted as the data (probably explaining why we feel caching is unnecessary) seems to default to a single value. Looking at this code seems to indicate that the SQL we need to build the replacement view is;

CREATE OR REPLACE VIEW XXK_SYS_ITEM AS
SELECT
       msib.SEGMENT1 CV$System_Item_KFF,
       msib.INVENTORY_ITEM_ID,
       msib.ORGANIZATION_ID,
       msib.SEGMENT1 SV$ITEM,
       'Item' SEGMENT_NAME_LIST,
       101 STRUCTURE_ID,
       'System Items' STRUCTURE_NAME,
       null Z$XXK_SYS_ITEM
  FROM INV.MTL_SYSTEM_ITEMS_B msib;

Clearly this is quite a substantial change so what we need to do is provide us with a way to back it out quickly after it's gone live in the event of substantial problems being found (low level-testing has been done but this will never cover 350+ reports) so the script to make the update will rename the existing view rather than just overwriting it so we can do a quick rollback*. Here is the script;

@utlspon xu6_replace_xxk_sys_item_view

BEGIN
  for v_Data in (SELECT 'x'
                   FROM ALL_VIEWS av
                  WHERE av.owner = USER
                    and av.view_name = 'XXK_SYS_ITEM_BK') loop
    execute immediate 'drop view XXK_SYS_ITEM_BK'; -- Remove an existing backup view if it exists
  end loop;
END;
/

RENAME XXK_SYS_ITEM TO XXK_SYS_ITEM_BK
/

CREATE OR REPLACE VIEW XXK_SYS_ITEM AS
SELECT
       msib.SEGMENT1 CV$System_Item_KFF,
       msib.INVENTORY_ITEM_ID,
       msib.ORGANIZATION_ID,
       msib.SEGMENT1 SV$ITEM,
       'Item' SEGMENT_NAME_LIST,
       101 STRUCTURE_ID,
       'System Items' STRUCTURE_NAME,
       null Z$XXK_SYS_ITEM
  FROM INV.MTL_SYSTEM_ITEMS_B msib
/



begin
  dbms_output.put_line('Recompiling invalid Views under NOETIX_SYS Schema');
  dbms_output.put_line('-------------------------------------------------');
  dbms_output.put_line('Remove Invalid Noetix Views (that are not set to be ommitted)');
  for v_SQL in (select 'ALTER VIEW NOETIX_SYS.' || do.object_name || ' COMPILE' text
                  from dba_objects do
                 where do.status = 'INVALID'
                   and do.OWNER = 'NOETIX_SYS'
                   and do.OBJECT_TYPE = 'VIEW'
                   and do.OBJECT_NAME not in
                       (select view_name
                          from n_views
                         where nvl(omit_flag, 'N') = 'N')) loop
    dbms_output.put_line('  ' || v_SQL.Text);
    execute immediate v_SQL.Text;
  end loop;
  dbms_output.put_line('END');
end;
/
 

COMMIT;

@utlspoff


This is available as a file here (via Google Docs).

You then need to add a call in XU6 to call the new file.

*- Just drop the new view and reverse the "RENAME ..."

UPDATE (11-JAN-2012): I've added in a section to the script to do a COMPILE of the views that are invalidated by this change. Normally it wouldn't be required as the first query will automatically recompile the view - however we have a check in XU6 for invalid views so they need to be valid by that stage otherwise our regenerate fails.


Email ThisBlogThis!Share to XShare to FacebookShare to Pinterest
Posted in MTL_System_Items_B, N_KFF_Sys_Item, N_KFF_Sys_Item_Pkg, noetix, noetix views | 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)
      • Noetix: Reporting AP Credit Card Transactions
      • Submitting an e-Petition to Cambridgeshire County ...
      • SSRS: Removing Blank Pages In Your Reports
      • SSRS: Creating a Simple Report With An Embedded Da...
      • SSRS: Adding Calculated Fields To Data Sets
      • Google Knol: Final Farewell ...
      • Oracle EBS: Creating New Menu Items in Oracle e-Bu...
      • Enabling Auto-Login Under Windows 7
      • Oracle EBS: Cloning Script To Clear Email Addresses
      • Noetix: XU2/XU5 Scripts run but generate no logfiles!
      • Noetix: Removing Item Information Caching @ Releas...
      • Noetix: Checking Incremental Refresh
      • Noetix: INV_Period_Close_Details and Process Manuf...
  • ►  2011 (65)
    • ►  December (8)
    • ►  November (8)
    • ►  October (7)
    • ►  September (9)
    • ►  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