Skip to main content

Different SYSDATE behaviors in SQL and PL/SQL



The SYSDATE function is available in both SQL and PL/SQL. They both return the current date-time (down to nearest second) for the database, So it would be reasonable to assume that they "act" the same in both SQL statements and PL/SQL blocks.

That would, however, be a bad assumption to make, because in reality:

In SQL, SYSDATE is called just once for the entire statement.

In PL/SQL, SYSDATE is called every time it is invoked.

Wow. Mind blown. 

Let's take a look.

In the script below, I create a table and insert four rows. Then I create a package that keeps track of distinct dates added to a collection and show those dates. Finally, a function that uses the package.

CREATE TABLE tab (id INT)
/

BEGIN
   INSERT INTO tab VALUES (1);
   INSERT INTO tab VALUES (2);
   INSERT INTO tab VALUES (3);
   INSERT INTO tab VALUES (4);
   COMMIT;
END;
/

CREATE OR REPLACE PACKAGE tracker
   AUTHID DEFINER
IS
   TYPE when_t IS TABLE OF INTEGER INDEX BY VARCHAR2 (100);

   dates   when_t;

   PROCEDURE add_date (date_in IN DATE);

   FUNCTION store_and_return_date (date_in            IN DATE,
                                   call_in_plsql_in   IN VARCHAR2)
      RETURN DATE;

   PROCEDURE show_count;
END;
/

CREATE OR REPLACE PACKAGE BODY tracker
IS
   PROCEDURE add_date (date_in IN DATE)
   IS
   BEGIN
      dates (TO_CHAR (date_in, 'YYYY-MM-DD HH:MI:SS')) := 0;
   END;

   PROCEDURE show_count
   IS
      l_index   VARCHAR2 (100) := dates.FIRST;
   BEGIN
      DBMS_OUTPUT.put_line ('Date Count = ' || dates.COUNT);

      WHILE l_index IS NOT NULL
      LOOP
         DBMS_OUTPUT.put_line (l_index);
         l_index := dates.NEXT (l_index);
      END LOOP;

      dates.delete;
   END;

   FUNCTION store_and_return_date (date_in            IN DATE,
                                   call_in_plsql_in   IN VARCHAR2)
      RETURN DATE
   IS
      d   DATE;
   BEGIN
      /* This is the value for SYSDATE passed in from The SELECT */
      add_date (date_in); 

      IF call_in_plsql_in = 'YES'
      THEN
         /* Now we call SYSDATE inside PL/SQL. Will it be the same
            value as passed in for date_in, or different? The
            count in the collection will tell us */
         add_date (SYSDATE);
      END IF;

      DBMS_SESSION.sleep (1);

      RETURN date_in;
   END;
END;
/
When I call the store_and_return_date, I can specify whether or not I want SYSDATE to be called again from within the PL/SQL function - which will be invoked below inside a SELECT statement.

Notice that I use the date (converted explicitly to a string) as the index in the associative array. That makes it easy to keep track of unique timestamps added.

In the first query below, I do not call SYSDATE inside PL/SQL, only in the call to the function, which happens inside the SQL engine.

In the second query, I call SYDATE in PL/SQL in addition to the invocation in the SELECT statement.
SELECT tracker.store_and_return_date (
          SYSDATE, call_in_plsql_in => 'NO') 
  FROM tab
/

BEGIN
   tracker.show_count;
END;
/

SELECT tracker.store_and_return_date (
          SYSDATE, call_in_plsql_in => 'YES') 
  FROM tab
/

BEGIN
   tracker.show_count;
END;
/
And here's the output:
Date Count = 1
2020-09-29 01:28:58

Date Count = 4
2020-09-29 01:29:02
2020-09-29 01:29:03
2020-09-29 01:29:04
2020-09-29 01:29:05

And there you see the difference between SQL and PL/SQL engines when it comes to executing SYSDATE. There are four rows in the TAB table. But the value for SYSDATE when executed in SQL doesn't change for the duration of the query, so there is just one element in the array.

When I ask for SYSDATE to also be called in PL/SQL, it is executed and the current date-time returned - even when that function is called from within a SQL statement.

Comments

  1. Why do we have count as 4? Ideally, there is just 2 time insertion into the collection, correct?

    ReplyDelete
  2. The function is called four times. So SYSDATE is executed once in SQL and then four more times inside the PL/SQL function. With the one second delay inside the function, we are (fairly) certain that SYSDATE will return four different date-times, so there are four unique strings used as index values in the collection.

    Does that clear things up?

    ReplyDelete
    Replies
    1. I am caught in the trap here, it is still unclear to me. Sorry, I started to feel silly. When I executed in Toad it returned Count=4. But still when I read it, I don't get it how it returned 4. Can you elaborate it or can you make an other post on this please.

      In the function: store_and_return_date

      --#1. First call to insert into the Collection: dates with parameter's SYSDATE
      add_date (date_in);


      IF call_in_plsql_in = 'YES'
      THEN
      --#2.Second call to insert into the Collection: dates, with SYSDATE current
      add_date (SYSDATE);
      END IF;

      Since the table: tab has got 4 rows, what impact does it make while calling functions with parameter (call_in_plsql_in=YES/NO).

      Delete
    2. I use the parameter call_in_plsql_in to determine if SYSDATE should also be called inside the PL/SQL function. If NO, it is only called in the SQL statement, and we see that it is only actually executed once, since the value passed into the function and used as an index never changes (so the count in the collection is just 1).

      When I pass YES for this parameter, SYSDATE is also called inside the PL/SQL function. The collection then ends up with > 1 element in it, because SYSDATE is actually executed each time (with a second's delay in between).

      This demonstrates the point of the post:

      In a SQL statement, SYSDATE is executed just once and its value is used for the duration of the execution of that statement, no matter how many times SYSDATE is actually "encountered" in the processing of that statement.

      In a PL/SQL block, SYSDATE is execute every single time the PL/SQL runtime engine runs across it.

      Please don't hesitate to follow up if you need more clarification! This is tricky stuff.....

      Delete
    3. Thankyou Steven, this helps a lot. I was just lost in the call. Modifying function would explain when it would take 5 Rows into the Collection: dates. Much appreciate your posts. I'm a big fan.

      FUNCTION store_and_return_date (date_in IN DATE,
      call_in_plsql_in IN VARCHAR2)
      RETURN DATE
      IS
      d DATE;
      BEGIN
      add_date (date_in); --First call to insert into the Collection: dates with parameter's SYSDATE

      --DBMS_SESSION.sleep (1);
      DBMS_LOCK.SLEEP (1);

      IF call_in_plsql_in = 'YES'
      THEN
      add_date (SYSDATE); --Second call to insert into the Collection: dates, with SYSDATE current
      END IF;

      --DBMS_SESSION.sleep (1);
      DBMS_LOCK.SLEEP (1);

      RETURN date_in;
      END;

      Delete
    4. Great idea. I have added comments to the code.

      Delete

Post a Comment

Popular posts from this blog

Quick Guide to User-Defined Types in Oracle PL/SQL

A Twitter follower recently asked for more information on user-defined types in the PL/SQL language, and I figured the best way to answer is to offer up this blog post. PL/SQL is a strongly-typed language . Before you can work with a variable or constant, it must be declared with a type (yes, PL/SQL also supports lots of implicit conversions from one type to another, but still, everything must be declared with a type). PL/SQL offers a wide array of pre-defined data types , both in the language natively (such as VARCHAR2, PLS_INTEGER, BOOLEAN, etc.) and in a variety of supplied packages (e.g., the NUMBER_TABLE collection type in the DBMS_SQL package). Data types in PL/SQL can be scalars, such as strings and numbers, or composite (consisting of one or more scalars), such as record types, collection types and object types. You can't really declare your own "user-defined" scalars, though you can define subtypes  from those scalars, which can be very helpful from the p

The differences between deterministic and result cache features

 EVERY once in a while, a developer gets in touch with a question like this: I am confused about the exact difference between deterministic and result_cache. Do they have different application use cases? I have used deterministic feature in many functions which retrieve data from some lookup tables. Is it essential to replace these 'deterministic' key words with 'result_cache'?  So I thought I'd write a post about the differences between these two features. But first, let's make sure we all understand what it means for a function to be  deterministic. From Wikipedia : In computer science, a deterministic algorithm is an algorithm which, given a particular input, will always produce the same output, with the underlying machine always passing through the same sequence of states.  Another way of putting this is that a deterministic subprogram (procedure or function) has no side-effects. If you pass a certain set of arguments for the parameters, you will always get

My two favorite APEX 5 features: Regional Display Selector and Cards

We (the over-sized development team for the PL/SQL Challenge - myself and my son, Eli) have been busy creating a new website on top of the PLCH platform (tables and packages): The Oracle Dev Gym! In a few short months (and just a part time involvement by yours truly), we have leveraged Oracle Application Express 5 to create what I think is an elegant, easy-to-use site that our users will absolutely love.  We plan to initially make the Dev Gym available only for current users of PL/SQL Challenge, so we can get feedback from our loyal user base. We will make the necessary adjustments and then offer it for general availability later this year. Anyway, more on that as the date approaches (the date being June 27, the APEX Open Mic Night at Kscope16 , where I will present it to a packed room of APEX experts). What I want to talk about today are two features of APEX that are making me so happy these days: Regional Display Selector and Cards. Regional Display Sel