diff --git a/samples/SessionCallback.py b/samples/SessionCallback.py new file mode 100644 index 0000000..1ebb4e6 --- /dev/null +++ b/samples/SessionCallback.py @@ -0,0 +1,139 @@ +#------------------------------------------------------------------------------ +# Copyright (c) 2019, Oracle and/or its affiliates. All rights reserved. +#------------------------------------------------------------------------------ + +#------------------------------------------------------------------------------ +# SessionCallback.py +# +# Demonstrate how to use a session callback written in Python. The callback is +# invoked whenever a newly created session is acquired from the pool, or when +# the requested tag does not match the tag that is associated with the +# session. It is generally used to set session state, so that the application +# can count on known session state, which allows the application to reduce the +# number of round trips made to the database. +# +# This script requires cx_Oracle 7.1 and higher. +#------------------------------------------------------------------------------ + +from __future__ import print_function + +import cx_Oracle +import SampleEnv + +# define a dictionary of NLS_DATE_FORMAT formats supported by this sample +SUPPORTED_FORMATS = { + "SIMPLE" : "'YYYY-MM-DD HH24:MI'", + "FULL" : "'YYYY-MM-DD HH24:MI:SS'" +} + +# define a dictionary of TIME_ZONE values supported by this sample +SUPPORTED_TIME_ZONES = { + "UTC" : "'UTC'", + "MST" : "'-07:00'" +} + +# define a dictionary of keys that are supported by this sample +SUPPORTED_KEYS = { + "NLS_DATE_FORMAT" : SUPPORTED_FORMATS, + "TIME_ZONE" : SUPPORTED_TIME_ZONES +} + +# define session callback +def init_session(conn, requestedTag): + + # display the requested and actual tags + print("init_session(): requested tag=%r, actual tag=%r" % \ + (requestedTag, conn.tag)) + + # tags are expected to be in the form "key1=value1;key2=value2" + # in this example, they are used to set NLS parameters and the tag is + # parsed to validate it + if requestedTag is not None: + stateParts = [] + for directive in requestedTag.split(";"): + parts = directive.split("=") + if len(parts) != 2: + raise ValueError("Tag must contain key=value pairs") + key, value = parts + valueDict = SUPPORTED_KEYS.get(key) + if valueDict is None: + raise ValueError("Tag only supports keys: %s" % \ + (", ".join(SUPPORTED_KEYS))) + actualValue = valueDict.get(value) + if actualValue is None: + raise ValueError("Key %s only supports values: %s" % \ + (key, ", ".join(valueDict))) + stateParts.append("%s = %s" % (key, actualValue)) + sql = "alter session set %s" % " ".join(stateParts) + cursor = conn.cursor() + cursor.execute(sql) + + # assign the requested tag to the connection so that when the connection + # is closed, it will automatically be retagged; note that if the requested + # tag is None (no tag was requested) this has no effect + conn.tag = requestedTag + + +# create pool with session callback defined +pool = cx_Oracle.SessionPool(SampleEnv.MAIN_USER, SampleEnv.MAIN_PASSWORD, + SampleEnv.CONNECT_STRING, min=2, max=5, increment=1, threaded=True, + sessionCallback=init_session) + +# acquire session without specifying a tag; since the session returned is +# newly created, the callback will be invoked but since there is no tag +# specified, no session state will be changed +print("(1) acquire session without tag") +conn = pool.acquire() +cursor = conn.cursor() +cursor.execute("select to_char(current_date) from dual") +result, = cursor.fetchone() +print("main(): result is", repr(result)) +conn.close() + +# acquire session, specifying a tag; since the session returned has no tag, +# the callback will be invoked; session state will be changed and the tag will +# be saved when the connection is closed +print("(2) acquire session with tag") +conn = pool.acquire(tag="NLS_DATE_FORMAT=SIMPLE") +cursor = conn.cursor() +cursor.execute("select to_char(current_date) from dual") +result, = cursor.fetchone() +print("main(): result is", repr(result)) +conn.close() + +# acquire session, specifying the same tag; since a session exists in the pool +# with this tag, it will be returned and the callback will not be invoked but +# the connection will still have the session state defined previously +print("(3) acquire session with same tag") +conn = pool.acquire(tag="NLS_DATE_FORMAT=SIMPLE") +cursor = conn.cursor() +cursor.execute("select to_char(current_date) from dual") +result, = cursor.fetchone() +print("main(): result is", repr(result)) +conn.close() + +# acquire session, specifying a different tag; since no session exists in the +# pool with this tag, a new session will be returned and the callback will be +# invoked; session state will be changed and the tag will be saved when the +# connection is closed +print("(4) acquire session with different tag") +conn = pool.acquire(tag="NLS_DATE_FORMAT=FULL;TIME_ZONE=UTC") +cursor = conn.cursor() +cursor.execute("select to_char(current_date) from dual") +result, = cursor.fetchone() +print("main(): result is", repr(result)) +conn.close() + +# acquire session, specifying a different tag but also specifying that a +# session with any tag can be acquired from the pool; a session with one of the +# previously set tags will be returned and the callback will be invoked; +# session state will be changed and the tag will be saved when the connection +# is closed +print("(4) acquire session with different tag but match any also specified") +conn = pool.acquire(tag="NLS_DATE_FORMAT=FULL;TIME_ZONE=MST", matchanytag=True) +cursor = conn.cursor() +cursor.execute("select to_char(current_date) from dual") +result, = cursor.fetchone() +print("main(): result is", repr(result)) +conn.close() + diff --git a/samples/SessionCallbackPLSQL.py b/samples/SessionCallbackPLSQL.py new file mode 100644 index 0000000..5c6b172 --- /dev/null +++ b/samples/SessionCallbackPLSQL.py @@ -0,0 +1,104 @@ +#------------------------------------------------------------------------------ +# Copyright (c) 2019, Oracle and/or its affiliates. All rights reserved. +#------------------------------------------------------------------------------ + +#------------------------------------------------------------------------------ +# SessionCallbackPLSQL.py +# +# Demonstrate how to use a session callback written in PL/SQL. The callback is +# invoked whenever the tag requested by the application does not match the tag +# associated with the session in the pool. It should be used to set session +# state, so that the application can count on known session state, which allows +# the application to reduce the number of round trips to the database. +# +# The primary advantage to this approach over the equivalent approach shown in +# SessionCallback.py is when DRCP is used, as the callback is invoked on the +# server and no round trip is required to set state. +# +# This script requires cx_Oracle 7.1 and higher. +#------------------------------------------------------------------------------ + +from __future__ import print_function + +import cx_Oracle +import SampleEnv + +# create pool with session callback defined +pool = cx_Oracle.SessionPool(SampleEnv.MAIN_USER, SampleEnv.MAIN_PASSWORD, + SampleEnv.CONNECT_STRING, min=2, max=5, increment=1, threaded=True, + sessionCallback="pkg_SessionCallback.TheCallback") + +# truncate table logging calls to PL/SQL session callback +conn = pool.acquire() +cursor = conn.cursor() +cursor.execute("truncate table PLSQLSessionCallbacks") +conn.close() + +# acquire session without specifying a tag; the callback will not be invoked as +# a result and no session state will be changed +print("(1) acquire session without tag") +conn = pool.acquire() +cursor = conn.cursor() +cursor.execute("select to_char(current_date) from dual") +result, = cursor.fetchone() +print("main(): result is", repr(result)) +conn.close() + +# acquire session, specifying a tag; since the session returned has no tag, +# the callback will be invoked; session state will be changed and the tag will +# be saved when the connection is closed +print("(2) acquire session with tag") +conn = pool.acquire(tag="NLS_DATE_FORMAT=SIMPLE") +cursor = conn.cursor() +cursor.execute("select to_char(current_date) from dual") +result, = cursor.fetchone() +print("main(): result is", repr(result)) +conn.close() + +# acquire session, specifying the same tag; since a session exists in the pool +# with this tag, it will be returned and the callback will not be invoked but +# the connection will still have the session state defined previously +print("(3) acquire session with same tag") +conn = pool.acquire(tag="NLS_DATE_FORMAT=SIMPLE") +cursor = conn.cursor() +cursor.execute("select to_char(current_date) from dual") +result, = cursor.fetchone() +print("main(): result is", repr(result)) +conn.close() + +# acquire session, specifying a different tag; since no session exists in the +# pool with this tag, a new session will be returned and the callback will be +# invoked; session state will be changed and the tag will be saved when the +# connection is closed +print("(4) acquire session with different tag") +conn = pool.acquire(tag="NLS_DATE_FORMAT=FULL;TIME_ZONE=UTC") +cursor = conn.cursor() +cursor.execute("select to_char(current_date) from dual") +result, = cursor.fetchone() +print("main(): result is", repr(result)) +conn.close() + +# acquire session, specifying a different tag but also specifying that a +# session with any tag can be acquired from the pool; a session with one of the +# previously set tags will be returned and the callback will be invoked; +# session state will be changed and the tag will be saved when the connection +# is closed +print("(4) acquire session with different tag but match any also specified") +conn = pool.acquire(tag="NLS_DATE_FORMAT=FULL;TIME_ZONE=MST", matchanytag=True) +cursor = conn.cursor() +cursor.execute("select to_char(current_date) from dual") +result, = cursor.fetchone() +print("main(): result is", repr(result)) +conn.close() + +# acquire session and display results from PL/SQL session logs +conn = pool.acquire() +cursor = conn.cursor() +cursor.execute(""" + select RequestedTag, ActualTag + from PLSQLSessionCallbacks + order by FixupTimestamp""") +print("(5) PL/SQL session callbacks") +for requestedTag, actualTag in cursor: + print("Requested:", requestedTag, "Actual:", actualTag) + diff --git a/samples/sql/SetupSamples.sql b/samples/sql/SetupSamples.sql index 89480ff..af23259 100644 --- a/samples/sql/SetupSamples.sql +++ b/samples/sql/SetupSamples.sql @@ -167,6 +167,12 @@ create table &main_user..Ptab ( mydata varchar(20) ); +create table &main_user..PlsqlSessionCallbacks ( + RequestedTag varchar2(250), + ActualTag varchar2(250), + FixupTimestamp timestamp +); + -- create queue table and queues for demonstrating advanced queuing begin dbms_aqadm.create_queue_table('&main_user..BOOK_QUEUE', @@ -351,3 +357,117 @@ create or replace package body &main_user..pkg_Demo as end; / +-- +-- Create package for demoing PL/SQL session callback +-- + +create or replace package &main_user..pkg_SessionCallback as + + procedure TheCallback ( + a_RequestedTag varchar2, + a_ActualTag varchar2 + ); + +end; +/ + +create or replace package body &main_user..pkg_SessionCallback as + + type udt_Properties is table of varchar2(64) index by varchar2(64); + + procedure LogCall ( + a_RequestedTag varchar2, + a_ActualTag varchar2 + ) is + pragma autonomous_transaction; + begin + insert into PlsqlSessionCallbacks + values (a_RequestedTag, a_ActualTag, systimestamp); + commit; + end; + + procedure ParseProperty ( + a_Property varchar2, + a_Name out nocopy varchar2, + a_Value out nocopy varchar2 + ) is + t_Pos number; + begin + t_Pos := instr(a_Property, '='); + if t_Pos = 0 then + raise_application_error(-20000, 'Tag must contain key=value pairs'); + end if; + a_Name := substr(a_Property, 1, t_Pos - 1); + a_Value := substr(a_Property, t_Pos + 1); + end; + + procedure SetProperty ( + a_Name varchar2, + a_Value varchar2 + ) is + t_ValidValues udt_Properties; + begin + if a_Name = 'TIME_ZONE' then + t_ValidValues('UTC') := 'UTC'; + t_ValidValues('MST') := '-07:00'; + elsif a_Name = 'NLS_DATE_FORMAT' then + t_ValidValues('SIMPLE') := 'YYYY-MM-DD HH24:MI'; + t_ValidValues('FULL') := 'YYYY-MM-DD HH24:MI:SS'; + else + raise_application_error(-20000, 'Unsupported session setting'); + end if; + if not t_ValidValues.exists(a_Value) then + raise_application_error(-20000, 'Unsupported session setting'); + end if; + execute immediate + 'ALTER SESSION SET ' || a_Name || '=''' || + t_ValidValues(a_Value) || ''''; + end; + + procedure ParseTag ( + a_Tag varchar2, + a_Properties out nocopy udt_Properties + ) is + t_PropertyName varchar2(64); + t_PropertyValue varchar2(64); + t_StartPos number; + t_EndPos number; + begin + t_StartPos := 1; + while t_StartPos < length(a_Tag) loop + t_EndPos := instr(a_Tag, ';', t_StartPos); + if t_EndPos = 0 then + t_EndPos := length(a_Tag) + 1; + end if; + ParseProperty(substr(a_Tag, t_StartPos, t_EndPos - t_StartPos), + t_PropertyName, t_PropertyValue); + a_Properties(t_PropertyName) := t_PropertyValue; + t_StartPos := t_EndPos + 1; + end loop; + end; + + procedure TheCallback ( + a_RequestedTag varchar2, + a_ActualTag varchar2 + ) is + t_RequestedProps udt_Properties; + t_ActualProps udt_Properties; + t_PropertyName varchar2(64); + begin + LogCall(a_RequestedTag, a_ActualTag); + ParseTag(a_RequestedTag, t_RequestedProps); + ParseTag(a_ActualTag, t_ActualProps); + t_PropertyName := t_RequestedProps.first; + while t_PropertyName is not null loop + if not t_ActualProps.exists(t_PropertyName) or + t_ActualProps(t_PropertyName) != + t_RequestedProps(t_PropertyName) then + SetProperty(t_PropertyName, t_RequestedProps(t_PropertyName)); + end if; + t_PropertyName := t_RequestedProps.next(t_PropertyName); + end loop; + end; + +end; +/ +