DZone
Thanks for visiting DZone today,
Edit Profile
  • Manage Email Subscriptions
  • How to Post to DZone
  • Article Submission Guidelines
Sign Out View Profile
  • Post an Article
  • Manage My Drafts
Over 2 million developers have joined DZone.
Log In / Join
Please enter at least three characters to search
Refcards Trend Reports
Events Video Library
Refcards
Trend Reports

Events

View Events Video Library

Zones

Culture and Methodologies Agile Career Development Methodologies Team Management
Data Engineering AI/ML Big Data Data Databases IoT
Software Design and Architecture Cloud Architecture Containers Integration Microservices Performance Security
Coding Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
Culture and Methodologies
Agile Career Development Methodologies Team Management
Data Engineering
AI/ML Big Data Data Databases IoT
Software Design and Architecture
Cloud Architecture Containers Integration Microservices Performance Security
Coding
Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance
Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks

Modernize your data layer. Learn how to design cloud-native database architectures to meet the evolving demands of AI and GenAI workkloads.

Secure your stack and shape the future! Help dev teams across the globe navigate their software supply chain security challenges.

Releasing software shouldn't be stressful or risky. Learn how to leverage progressive delivery techniques to ensure safer deployments.

Avoid machine learning mistakes and boost model performance! Discover key ML patterns, anti-patterns, data strategies, and more.

Related

  • How Trustworthy Is Big Data?
  • Fixing Common Oracle Database Problems
  • How to Restore a Transaction Log Backup in SQL Server
  • Why I Built the Ultimate Text Comparison Tool (And Why You Should Try It)

Trending

  • Emerging Data Architectures: The Future of Data Management
  • Understanding Java Signals
  • Doris: Unifying SQL Dialects for a Seamless Data Query Ecosystem
  • Failure Handling Mechanisms in Microservices and Their Importance
  1. DZone
  2. Data Engineering
  3. Databases
  4. Implementing Temporal Validity in Oracle

Implementing Temporal Validity in Oracle

With temporal validity, we can query our data however we want. We can even pull the data and join it with other tables.

By 
Emrah Mete user avatar
Emrah Mete
·
Apr. 11, 18 · Interview
Likes (5)
Comment
Save
Tweet
Share
6.5K Views

Join the DZone community and get the full member experience.

Join For Free

In this article, I will talk about temporal validity, which is a new feature that has come with Oracle 12c R1. 

Temporal validity offers us an infrastructure with which we can render the data we have that is valid for a particular time range and query our table depending on the time. It’s a mechanism that allows us to examine the status of the data in the table or to use it in any time interval.

Now, let’s get to the examples and try to understand the subject.

First, let’s talk about the scenario. Let there be an invoice table and a validity interval assigned by us for every entry in this table. Then, let’s change our session parameters according to the validity dates of the inserted entries and query our table in the time period we want.

CREATE TABLE hr.invoice
  (
    custid    NUMBER,
    inv_no    NUMBER,
    inv_total NUMBER,
    inv_date  DATE,
    t_date    TIMESTAMP
  ); 

INSERT INTO hr.invoice VALUES  (1,1,100,sysdate-30,sysdate);
INSERT INTO hr.invoice VALUES  (1,2,900,sysdate-60,sysdate);
INSERT INTO hr.invoice VALUES  (1,3,700,sysdate-90,sysdate);
INSERT INTO hr.invoice VALUES  (1,4,600,sysdate-120,sysdate);
INSERT INTO hr.invoice VALUES  (1,5,300,sysdate-150,sysdate);
INSERT INTO hr.invoice VALUES  (1,6,200,sysdate-180,sysdate);
COMMIT;

We’ve created our table and inserted data into it. Now, it’s time to run the feature that will grant our table a time dimension.

We provided a time dimension to our table by using the PERIOD FOR phrase. We could also do this while creating our table, as shown below.

CREATE TABLE hr.invoice
  (
    custid    NUMBER,
    inv_no    NUMBER,
    inv_total NUMBER,
    inv_date  DATE,
    t_date    TIMESTAMP,
    PERIOD FOR valid_time
  ); 

We have created an infrastructure where we can query our table according to time. Oracle has already created two invisible columns in the background using the valid_time name that we had given with the PERIOD FOR phrase. The names of these are:

  1. valid_time_start 

  2. valid_time_end 

If we query them in the dictionary, we will not be able to see their existence, as they are invisible.

SELECT owner,
  table_name,
  column_name,
  data_type
FROM all_tab_columns
WHERE owner    = 'HR'
AND table_name = 'INVOICE';

tmv1

Now, we have provided them with a time dimension with the PERIOD FOR phrase. Let's update the valid_time_start and valid_time_end columns, which are created as invisible and whose validity we can adjust for every entry according to time.

UPDATE hr.invoice
SET valid_time_start = SYSTIMESTAMP - INTERVAL '20' MINUTE,
    valid_time_end   = SYSTIMESTAMP - INTERVAL '10' MINUTE
WHERE inv_no         =1;


UPDATE hr.invoice
SET valid_time_start = SYSTIMESTAMP - INTERVAL '20' MINUTE,
    valid_time_end   = SYSTIMESTAMP - INTERVAL '10' MINUTE
WHERE inv_no         =2;

UPDATE hr.invoice
SET valid_time_start = SYSTIMESTAMP - INTERVAL '15' MINUTE,
    valid_time_end   = SYSTIMESTAMP - INTERVAL '5'  MINUTE
WHERE inv_no         =3;

UPDATE hr.invoice
SET valid_time_start = SYSTIMESTAMP - INTERVAL '19' MINUTE,
    valid_time_end   = SYSTIMESTAMP - INTERVAL '10' MINUTE
WHERE inv_no         =4;

UPDATE hr.invoice
SET valid_time_start = SYSTIMESTAMP - INTERVAL '14' MINUTE,
    valid_time_end   = SYSTIMESTAMP - INTERVAL '3'  MINUTE
WHERE inv_no         =5;

UPDATE hr.invoice
SET valid_time_start = SYSTIMESTAMP + INTERVAL '2' MINUTE,
    valid_time_end   = SYSTIMESTAMP + INTERVAL '5'  MINUTE
WHERE inv_no         =6;

COMMIT;

With the updates, we made every one of the entries valid at a particular time. Now, what kind of a result appears when I query my table without touching my session’s Flashback setting?

tmv2

I was able to view all the data in my table when I queried without touching the Flashback setting. Good. Now, how can I query the table for a particular period or date?

This question has many answers; let’s look at the methods in order.

Querying the Data According to Time

1. DBMS_FLASHBACK_ ARCHIVE

You can do the query using the DBMS_FLASHBACK_ARCHIVE package. However, in order to use it, the user we connect with should have an authorization on that package.

GRANT ALL ON SYS.dbms_flashback_archive TO HR;

After authorizing the user, now we can adjust the time as session-based and re-run our query.

EXECUTE SYS.DBMS_FLASHBACK_ARCHIVE.ENABLE_AT_VALID_TIME('ASOF', SYSTIMESTAMP - INTERVAL '7' MINUTE);

With the line above, we enabled 7 minutes ago in our session. Now, let's look at the valid data in that time interval.

SELECT * from hr.invoice;

tmv3

We listed the entries that were valid seven minutes ago. From this example, don't think that it’s only possible to go back in time. We can go to a time period where the validity is forward in time and examine the case in that time.

EXECUTE SYS.DBMS_FLASHBACK_ARCHIVE.ENABLE_AT_VALID_TIME('ASOF', SYSTIMESTAMP + INTERVAL '3' MINUTE);

We have enabled 3 minutes after. Now, let’s query again.

SELECT * from hr.invoice;

tmv4

As can be seen, the entry that would be valid after three minutes has appeared.

2. AS OF PERIOD FOR and VERSIONS PERIOD FOR Phrases

Like the previous example, let's query 7 minutes ago with this method.

SELECT * from hr.invoice AS OF PERIOD FOR valid_time SYSTIMESTAMP - INTERVAL '7' MINUTE;

tmv5

And now, let’s query the time period between 10 minutes and 18 minutes ago.

SELECT * from hr.invoice VERSIONS PERIOD FOR valid_time between  SYSTIMESTAMP - INTERVAL '18' MINUTE and  SYSTIMESTAMP - INTERVAL '10' MINUTE;

tmv6With the methods above, we can query our data however we want. We can even pull the data with the second method and join it with other tables. In addition to that, in temporal validity infrastructure, columns that include the unique key constraint in our table are given permission to violate this constraint, while it’s guaranteed that the entries will never overlap in means of time. This means that entries containing the same unique key can be present in more than one table on the condition of all being in different validity periods.

Database

Opinions expressed by DZone contributors are their own.

Related

  • How Trustworthy Is Big Data?
  • Fixing Common Oracle Database Problems
  • How to Restore a Transaction Log Backup in SQL Server
  • Why I Built the Ultimate Text Comparison Tool (And Why You Should Try It)

Partner Resources

×

Comments
Oops! Something Went Wrong

The likes didn't load as expected. Please refresh the page and try again.

ABOUT US

  • About DZone
  • Support and feedback
  • Community research
  • Sitemap

ADVERTISE

  • Advertise with DZone

CONTRIBUTE ON DZONE

  • Article Submission Guidelines
  • Become a Contributor
  • Core Program
  • Visit the Writers' Zone

LEGAL

  • Terms of Service
  • Privacy Policy

CONTACT US

  • 3343 Perimeter Hill Drive
  • Suite 100
  • Nashville, TN 37211
  • support@dzone.com

Let's be friends:

Likes
There are no likes...yet! 👀
Be the first to like this post!
It looks like you're not logged in.
Sign in to see who liked this post!