MacLochlainns Weblog

Michael McLaughlin's Technical Blog

Site Admin

Archive for the ‘sql’ Category

Parametric Queries

without comments

In 2021, I wrote a MySQL example for my class on the usefulness of Common Table Expressions (CTEs). When discussing the original post, I would comment on how you could extend the last example to build a parametric reporting table.

Somebody finally asked for a concrete example. So, this explains how to build a sample MySQL parametric query by leveraging a filter cross join and tests the parameter use with a Python script.

You can build this in any database you prefer but I used a studentdb database with the sakila sample database installed. I’ve granted privileges to both databases to the student user. The following SQL is required for the example:

-- Conditionally drop the levels table.
DROP TABLE IF EXISTS levels;
 
-- Create the levels list.
CREATE TABLE levels
( level_id       int unsigned primary key auto_increment
, parameter_set  enum('Three','Five')
, description    varchar(20)
, min_roles      int
, max_roles      int );
 
-- Insert values into the list table.
INSERT INTO levels
( parameter_set
, description
, min_roles
, max_roles )
VALUES
 ('Three','Hollywood Star', 30, 99999)
,('Three','Prolific Actor', 20, 29)
,('Three','Newcommer',1,19)
,('Five','Newcommer',1,9)
,('Five','Junior Actor',10,19)
,('Five','Professional Actor',20,29)
,('Five','Major Actor',30,39)
,('Five','Hollywood Star',40,99999);

The sample lets you use the three or five value labels while filtering on any partial full_name value as the result of the query below:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
-- Query the data.
WITH actors AS
 (SELECT   a.actor_id
  ,        a.first_name
  ,        a.last_name
  ,        COUNT(*) AS num_roles
  FROM     sakila.actor a INNER JOIN sakila.film_actor fa
  ON       a.actor_id = fa.actor_id
  GROUP BY actor_id)
SELECT   CONCAT(a.last_name,', ',a.first_name) full_name
,        l.description
,        a.num_roles
FROM     actors a CROSS JOIN levels l
WHERE    a.num_roles BETWEEN l.min_roles AND l.max_roles
AND      l.parameter_set = 'Five'
AND      a.last_name LIKE CONCAT('H','%')
ORDER BY a.last_name
,        a.first_name;

They extends a concept exercise found in Chapter 9 on subqueries in Alan Beaulieu’s Learning SQL book.

This is the parametric Python program, which embeds the function locally (to make it easier for those who don’t write a lot of Python). You could set the PYTHONPATH to a relative src directory and import your function if you prefer.

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
#!/usr/bin/python
 
# Import the libraries.
import sys
import mysql.connector
from mysql.connector import errorcode
 
# ============================================================
 
# Define function to check and replace arguments.
def check_replace(argv):
 
  # Set defaults for incorrect parameter values.
  defaults = ("Three","_")
 
  # Declare empty list variables.
  inputs = []
  args = ()
 
  # Check whether or not parameters exist after file name.
  if isinstance(argv,list) and len(argv) != 0:
 
    # Check whether there are at least two parameters.
    if len(argv) >= 2:
 
      # Loop through available command-line arguments.
      for element in argv:
 
        # Check first of two parameter values and substitute
        # default value if input value is an invalid option.
        if len(inputs) == 0 and (element in ('Three','Five')) or \
           len(inputs) == 1 and (isinstance(element,str)):
          inputs.append(element)
        elif len(inputs) == 0:
          inputs.append(defaults[0])
        elif len(inputs) == 1:
          inputs.append(defaults[1])
 
      # Assign arguments to parameters.
      args = (inputs)
 
    # Check whether only one parameter value exists.
    elif len(argv) == 1 and (argv[0] in ('Three','Five')):
      args = (argv[0],"_")
 
    # Assume only one parameter is valid and substitute an 
    # empty string as the second parameter.
    else:
      args = (defaults[0],"_")
 
    # Substitute defaults when missing parameters.
  else:
    args = defaults
 
  # Return parameters as a tuple.
  return args
 
# ============================================================
 
# Assign command-line argument list to variable by removing
# the program file name.
# ============================================================
params = check_replace(sys.argv[1:])
# ============================================================
 
#  Attempt the query.
# ============================================================
#  Use a try-catch block to manage the connection.
# ============================================================
try:
  # Open connection.
  cnx = mysql.connector.connect(user='student', password='student',
                                host='127.0.0.1',
                                database='studentdb')
  # Create cursor.
  cursor = cnx.cursor()
 
  # Set the query statement.
  query = ("WITH actors AS "
           "(SELECT   a.first_name "
           " ,        a.last_name "
           " ,        COUNT(*) AS num_roles "
           " FROM     sakila.actor a INNER JOIN sakila.film_actor fa "
           " ON       a.actor_id = fa.actor_id "
           " GROUP BY a.first_name "
           " ,        a.last_name ) "
           " SELECT   CONCAT(a.last_name,', ',a.first_name) AS full_name "
           " ,        l.description "
           " ,        a.num_roles "
           " FROM     actors a CROSS JOIN levels l "
           " WHERE    a.num_roles BETWEEN l.min_roles AND l.max_roles "
           " AND      l.parameter_set = %s "
           " AND      a.last_name LIKE CONCAT(%s,'%') "
           " ORDER BY a.last_name "
           " ,        a.first_name")
 
  # Execute cursor.
  cursor.execute(query, params)
 
  # Display the rows returned by the query.
  for (full_name, description, num_roles) in cursor:
    print('{0} is a {1} with {2} films.'.format( full_name.title()
                                               , description.title()
                                               , num_roles))
 
  # Close cursor.
  cursor.close()
 
# ------------------------------------------------------------
# Handle exception and close connection.
except mysql.connector.Error as e:
  if e.errno == errorcode.ER_ACCESS_DENIED_ERROR:
    print("Something is wrong with your user name or password")
  elif e.errno == errorcode.ER_BAD_DB_ERROR:
    print("Database does not exist")
  else:
    print("Error code:", e.errno)        # error number
    print("SQLSTATE value:", e.sqlstate) # SQLSTATE value
    print("Error message:", e.msg)       # error message
 
# Close the connection when the try block completes.
else:
  cnx.close()

As always, I hope this helps those trying to understand how CTEs can solve problems that would otherwise be coded in external imperative languages like Python.

Written by maclochlainn

March 1st, 2024 at 12:30 am

Oracle 23c Free Ext Files

without comments

This is an example of how you would upload data from a flat file, or Comma Separated Value (CSV) file inside Docker Oracle Database 23c Free. It’s important to note that in the file upload you are transferring information that doesn’t have surrogate key values by leveraing joins inside a MERGE statement.

Step #1 : Create a virtual directory

You can create a virtual directory without a physical directory but it won’t work when you try to access it. Therefore, you should create the physical directory first. Assuming you’ve created the Docker Oracle Database 23c Free instance, you should put the code in subdirectories of the /opt/oracle file directory.

  • Connect as the root user with the following Docker command:

    docker exec -it --user root oracle23c bash

    Issue the following commands as the oracle user inside the Docker container to create the necessary physical directories. You may need to refer to my earlier blog post if you haven’t setup the oracle user inside the Docker instance. While this blog post will only use the /opt/oracle/upload/text and /opt/oracle/upload/log directories, a subsequent post will demonstrate the preprocessing module for the external tables.

    mkdir /opt/oracle/upload
    mkdir /opt/oracle/upload/text
    mkdir /opt/oracle/upload/log
    mkdir /opt/oracle/upload/preproc
  • Connect to the Oracle Database 23c Free inside the container as the system user to create a c##studentrole, and do the following three things:

    • Grant privileges to the c##studentrole, and grant the c##studentrole to the c##student user.

      -- Create the role.
      CREATE ROLE c##studentrole;
       
      -- Grant privileges to the role.
      GRANT CREATE CLUSTER, CREATE INDEXTYPE, CREATE PROCEDURE,
      CREATE SEQUENCE, CREATE SESSION, CREATE TABLE, CREATE TRIGGER,
      CREATE TYPE, CREATE VIEW TO c##studentrole;
       
      -- Grant privileges to the user.
      GRANT c##studentrole TO c##student;
    • As the system user, create the necessary virtual directories that map to the physical directories inside the Docker container:

      CREATE DIRECTORY upload AS '/opt/oracle/upload/text';
      CREATE DIRECTORY preproc AS '/opt/oracle/upload/preproc';
      CREATE DIRECTORY LOG AS '/opt/oracle/upload/log';
    • As the system user, grant the necessary privileges on the virtual directories to the c##studentrole role:

      GRANT read ON DIRECTORY upload TO c##studentrole;
      GRANT read, WRITE ON DIRECTORY LOG TO c##studentrole;
      GRANT read, EXECUTE ON DIRECTORY preproc TO c##studentrole;

Step #2 : Position your CSV file in the physical directory

After creating the virtual directory, copy the following contents into a file named kingdom_import.csv in the /opt/oracle/upload/texgt directory or folder. If you attempt to do this in Windows, you need to disable Windows UAC before performing this step.

Place the following in the kingdom_import.csv file. The trailing commas aren’t too meaningful in Oracle but they’re very helpful if you use the file in MySQL. A key element in creating this files requires that you avoid trailing line returns at the bottom of the file because they’re inserted as null values. There should be no lines after the last row of data.

'Narnia',77600,'Peter the Magnificent','20-MAR-1272','19-JUN-1292','The Lion, The Witch and The Wardrobe',
'Narnia',77600,'Edmund the Just','20-MAR-1272','19-JUN-1292','The Lion, The Witch and The Wardrobe',
'Narnia',77600,'Susan the Gentle','20-MAR-1272','19-JUN-1292','The Lion, The Witch and The Wardrobe',
'Narnia',77600,'Lucy the Valiant','20-MAR-1272','19-JUN-1292','The Lion, The Witch and The Wardrobe',
'Narnia',42100,'Peter the Magnificent','12-APR-1531','31-MAY-1328','Prince Caspian',
'Narnia',42100,'Edmund the Just','12-APR-1531','31-MAY-1328','Prince Caspian',
'Narnia',42100,'Susan the Gentle','12-APR-1531','31-MAY-1328','Prince Caspian',
'Narnia',42100,'Lucy the Valiant','12-APR-1531','31-MAY-1328','Prince Caspian',
'Camelot',15200,'King Arthur','10-MAR-0631','12-DEC-0686','The Once and Future King',
'Camelot',15200,'Sir Lionel','10-MAR-0631','12-DEC-0686','The Once and Future King',
'Camelot',15200,'Sir Bors','10-MAR-0631','12-DEC-0635','The Once and Future King',
'Camelot',15200,'Sir Bors','10-MAR-0640','12-DEC-0686','The Once and Future King',
'Camelot',15200,'Sir Galahad','10-MAR-0631','12-DEC-0686','The Once and Future King',
'Camelot',15200,'Sir Gawain','10-MAR-0631','12-DEC-0686','The Once and Future King',
'Camelot',15200,'Sir Tristram','10-MAR-0631','12-DEC-0686','The Once and Future King',
'Camelot',15200,'Sir Percival','10-MAR-0631','12-DEC-0686','The Once and Future King',
'Camelot',15200,'Sir Lancelot','30-SEP-0670','12-DEC-0686','The Once and Future King',

Step #3 : Reconnect as the student user

Disconnect and connect as the c##student user, or reconnect as the c##student user. The reconnect syntax that protects your password is:

CONNECT c##student@free

Step #4 : Run the script that creates tables and sequences

Copy the following into a create_kingdom_upload.sql file within a directory of your choice. I use varchar as the data type because it’s an alias for varchar2 and highlights appropriately with the GeSHi formatting. Then, run it as the student account.

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
-- Conditionally drop tables.
DROP TABLE IF EXISTS kingdom;
DROP TABLE IF EXISTS knight;
DROP TABLE IF EXISTS kingdom_knight_import;
 
-- Conditionally drop sequences.
DROP SEQUENCE IF EXISTS kingdom_s1;
DROP SEQUENCE IF EXISTS knight_s1;
 
-- Create normalized kingdom table.
CREATE TABLE kingdom
( kingdom_id    NUMBER
, kingdom_name  VARCHAR(20)
, population    NUMBER
, book          VARCHAR(40));
 
-- Create a sequence for the kingdom table.
CREATE SEQUENCE kingdom_s1;
 
-- Create normalized knight table.
CREATE TABLE knight
( knight_id             NUMBER
, knight_name           VARCHAR(22)
, kingdom_allegiance_id NUMBER
, allegiance_start_date DATE
, allegiance_end_date   DATE
, book                  VARCHAR(40));
 
-- Create a sequence for the knight table.
CREATE SEQUENCE knight_s1;
 
-- Create external import table.
CREATE TABLE kingdom_knight_import
( kingdom_name           VARCHAR(20)
, population             NUMBER
, knight_name            VARCHAR(22)
, allegiance_start_date  DATE
, allegiance_end_date    DATE
, book                   VARCHAR(40))
  ORGANIZATION EXTERNAL
  ( TYPE oracle_loader
    DEFAULT DIRECTORY upload
    ACCESS PARAMETERS
    ( RECORDS DELIMITED BY NEWLINE CHARACTERSET US7ASCII
      BADFILE     'LOG':'kingdom_import.bad'
      DISCARDFILE 'LOG':'kingdom_import.dis'
      LOGFILE     'LOG':'kingdom_import.log'
      FIELDS TERMINATED BY ','
      OPTIONALLY ENCLOSED BY "'"
      MISSING FIELD VALUES ARE NULL )
    LOCATION ('kingdom_import.csv'))
REJECT LIMIT UNLIMITED;

Step #5 : Test your access to the external table

There a number of things that could go wrong with setting up an external table, such as file permissions. Before moving on to the balance of the steps, you should test what you’ve done. Run the following query from the student account to check whether or not you can access the kingdom_import.csv file.

1
2
3
4
5
6
7
8
9
10
11
12
SET PAGESIZE 999
COL kingdom_name  FORMAT A7     HEADING "Kingdom|Name"
COL folks         FORMAT 99999  HEADING "Folks"
COL knight_name   FORMAT A21    HEADING "Knight Name"
COL dates         FORMAT A11    HEADING "Start Date"
COL source_book   FORMAT A38    HEADING "Book"
SELECT   kingdom_name
,        knight_name
,        TO_CHAR(allegiance_start_date,'DD-MON-YYYY')
||       TO_CHAR(allegiance_end_date,'DD-MON-YYYY') AS dates
,        book
FROM     kingdom_knight_import;

Step #6 : Create the upload procedure

Copy the following into a create_upload_procedure.sql file within a virtual directory of your choice. As noted above in the external table definition writes only occur in the log virtual directory. This is important because there are articles out there on the Internet that could misdirect you when you get the following error message on the upload virtual directory.

ORA-06564: Object UPLOAD does not exist or is not accessible to the user.

By the way, you’ll only see that error if you fail to:

  • Designate the procedure as AUTH_ID CURRENT, and
  • Enabled SERVEROUTPUT inside the SQL*Plus command-line interface (CLI) session or inside the glogin.sql file for the Oracle Database 23c Free Docker instance.

Then, run it as the student account.

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
-- Create a procedure to wrap the transaction.
CREATE OR REPLACE
  PROCEDURE upload_kingdom AUTHID CURRENT_USER IS 
BEGIN
  -- Set save point for an all or nothing transaction.
  SAVEPOINT starting_point;
 
  -- Insert or update the table, which makes this rerunnable when the file hasn't been updated.  
  MERGE INTO kingdom target
  USING (SELECT   DISTINCT
                  k.kingdom_id
         ,        kki.kingdom_name
         ,        kki.population
         ,        kki.book
         FROM     kingdom_knight_import kki LEFT JOIN kingdom k
         ON       kki.kingdom_name = k.kingdom_name
         AND      kki.population = k.population
         AND      kki.book = k.book) SOURCE
  ON (target.kingdom_id = SOURCE.kingdom_id)
  WHEN MATCHED THEN
  UPDATE SET kingdom_name = SOURCE.kingdom_name
  WHEN NOT MATCHED THEN
  INSERT VALUES
  ( kingdom_s1.nextval
  , SOURCE.kingdom_name
  , SOURCE.population
  , SOURCE.book);
 
  -- Insert or update the table, which makes this rerunnable when the file hasn't been updated.  
  MERGE INTO knight target
  USING (SELECT   kn.knight_id
         ,        kki.knight_name
         ,        k.kingdom_id
         ,        kki.allegiance_start_date AS start_date
         ,        kki.allegiance_end_date AS end_date
         ,        kki.book
         FROM     kingdom_knight_import kki INNER JOIN kingdom k
         ON       kki.kingdom_name = k.kingdom_name
         AND      kki.population = k.population LEFT JOIN knight kn 
         ON       k.kingdom_id = kn.kingdom_allegiance_id
         AND      kki.knight_name = kn.knight_name
         AND      kki.allegiance_start_date = kn.allegiance_start_date
         AND      kki.allegiance_end_date = kn.allegiance_end_date
         AND      kki.book = kn.book) SOURCE
  ON (target.kingdom_allegiance_id = SOURCE.kingdom_id)
  WHEN MATCHED THEN
  UPDATE SET allegiance_start_date = SOURCE.start_date
  ,          allegiance_end_date = SOURCE.end_date
  ,          book = SOURCE.book
  WHEN NOT MATCHED THEN
  INSERT VALUES
  ( knight_s1.nextval
  , SOURCE.knight_name
  , SOURCE.kingdom_id
  , SOURCE.start_date
  , SOURCE.end_date
  , SOURCE.book);
 
  -- Save the changes.
  COMMIT;
 
EXCEPTION
  WHEN OTHERS THEN
    dbms_output.put_line(SQLERRM);
    ROLLBACK TO starting_point;
    RETURN;
END;
/

Step #7 : Run the upload procedure

You can run the file by calling the script above. The procedure ensures that records are inserted or updated into their respective tables.

EXECUTE upload_kingdom;

Step #8 : Test the results of the upload procedure

You can test whether or not it worked by running the following queries.

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
-- Format Oracle output.
COLUMN kingdom_id    FORMAT 999      HEADING "Kingdom|ID #"
COLUMN kingdom_name  FORMAT A14      HEADING "Kingdom|Name"
COLUMN population    FORMAT 999,999  HEADING "Population"
COLUMN book          FORMAT A40      HEADING "Source Book"
 
-- Check the kingdom table.
SELECT * FROM kingdom;
 
-- Format Oracle output.
SET PAGESIZE 999
COLUMN knight_id              FORMAT 999  HEADING "Knight|ID #"
COLUMN knight_name            FORMAT A23  HEADING "Knight|Name"
COLUMN kingdom_allegiance_id  FORMAT 999  HEADING "Kingdom|ID #"
COLUMN allegiance_start_date  FORMAT A11 HEADING "Allegiance|Start Date"
COLUMN allegiance_end_date    FORMAT A11 HEADING "Allegiance|End Date"
 
-- Check the knight table.
SELECT   knight_id
,        knight_name
,        kingdom_allegiance_id
,        TO_CHAR(allegiance_start_date,'DD-MON-YYYY') AS allegiance_start_date
,        TO_CHAR(allegiance_end_date,'DD-MON-YYYY') AS allegiance_end_date
FROM     knight;

It should display the following information:

Kingdom Kingdom
   ID # Name	       Population Source Book
------- -------------- ---------- ----------------------------------------
      1 Narnia		   42,100 Prince Caspian
      2 Narnia		   77,600 The Lion, The Witch and The Wardrobe
      3 Camelot 	   15,200 The Once and Future King
 
 
Knight Knight		       Kingdom Allegiance  Allegiance
  ID # Name			  ID # Start Date  End Date
------ ----------------------- ------- ----------- -----------
     1 Peter the Magnificent	     2 20-MAR-1272 19-JUN-1292
     2 Edmund the Just		     2 20-MAR-1272 19-JUN-1292
     3 Susan the Gentle 	     2 20-MAR-1272 19-JUN-1292
     4 Lucy the Valiant 	     2 20-MAR-1272 19-JUN-1292
     5 Peter the Magnificent	     1 12-APR-1531 31-MAY-1328
     6 Edmund the Just		     1 12-APR-1531 31-MAY-1328
     7 Susan the Gentle 	     1 12-APR-1531 31-MAY-1328
     8 Lucy the Valiant 	     1 12-APR-1531 31-MAY-1328
     9 King Arthur		     3 10-MAR-0631 12-DEC-0686
    10 Sir Lionel		     3 10-MAR-0631 12-DEC-0686
    11 Sir Bors 		     3 10-MAR-0631 12-DEC-0635
    12 Sir Bors 		     3 10-MAR-0640 12-DEC-0686
    13 Sir Galahad		     3 10-MAR-0631 12-DEC-0686
    14 Sir Gawain		     3 10-MAR-0631 12-DEC-0686
    15 Sir Tristram		     3 10-MAR-0631 12-DEC-0686
    16 Sir Percival		     3 10-MAR-0631 12-DEC-0686
    17 Sir Lancelot		     3 30-SEP-0670 12-DEC-0686

You can rerun the procedure to check that it doesn’t alter any information, then you could add a new knight to test the insertion portion.

Written by maclochlainn

January 6th, 2024 at 11:53 pm

Oracle 23c Free SQL*Plus

without comments

It’s always frustrated me when using the sqlplus command-line interface (CLI) that you can’t just “up arrow” to through the history. At least, that’s the default case unless you wrap the sqlplus executable.

I like to do my development work as close to the database as possible. The delay from SQL Developer to the database or VSCode to the database is just too long. Therefore, I like the native sqlplus to be as efficient as possible. This post shows you how to install the rlwarp utility to wrap sqlplus and create a sandboxed student user for a local development account inside the Oracle 23c Free container. You should note that the Docker or Podman Container is using Oracle Unbreakable Linux 8 as it’s native OS.

You can connect to your Docker version of Oracle Database 23c Free with the following command:

docker exec -it -u root oracle23c bash

You can’t just use dnf to install rlwrap and get it to magically install all the dependencies. That would be too easy, eh?

Attempting to do so will lock your base OS and eventually force you to kill with prejudice the hung dnf process (at least it forced me to do so). You need to determine the rlwrap dependencies and then install them first. In that process, I noticed that the which utility program wasn’t installed in the container.

Naturally, I installed the which utility first with this command:

dnf install -y which

The rlwrap dependencies are: glibc, ncurses, perl, readline, python, and git. Only the perl, python, and git are missing from the list of formal dependencies but there’s another dependency the epel-release package.

If you want to verify whether a package is installed, you can use the rpm command like this:

rpm -qa | grep package_name

I installed the perl programming environment (a big install) with this command:

dnf install -y perl

I installed the python3 with this command:

dnf install -y python3

I installed the git module with this command:

dnf install -y git

I installed the epel-release container with this command:

dnf install -y epel-release

After installing all of these, you’re now ready to install the core rlwrap utility program. Like the other installations, you use:

dnf install -y rlwrap

At this point, you need to create a sandboxed user account for the Docker instance because as a developer using the root user for simple tasks is a bad idea. While you could do this with a Docker command, the Oracle 23c Free edition raised a lock on the /etc/group file when I tried it. Naturally, that’s not a problem because you can connect as the root user with this syntax:

docker exec -it -u root oracle23c bash

As the root user, create a student account as a developer account in the Oracle 23c Free container:

useradd -u 501 -g dba -G users -d /home/student -s /bin/bash/ -c "Student" -n student

You’ll be unable to leverage the tnsnames.ora file unless you alter the prior command to replace dba with oinstall or add the following command:

usermod -a -G oinstall student

Exit the Oracle 23c Free container as the root user and reconnect as the student user with this syntax:

docker exec -it --user student oracle23c bash

While you’re connected as the root user, you should create an upload directory as a subdirectory of the $ORACLE_BASE directory. The $ORACLE_BASE directory in the Oracle Database 23c Free Docker image is the /opt/oracle directory.

You should use the following syntax to create the upload directory and change its permission to that of the Oracle Database 23c Free installation (for a future blog post on developing external table deployment on the Docker image):

mkdir /opt/oracle
chown -R oracle:install /opt/oracle/upload

You also can add the following student function to the Ubuntu student user’s .bashrc file. It means all you need to type to connect to the Oracle Database 23c Free Docker instance is “student“. I like shortcuts like this one, which let you leverage one-line Python commands.

student () 
{
    # Discover the fully qualified program name. 
    path=`which docker 2>/dev/null`
    file=''
 
    # Parse the program name from the path.
    if [ -n ${path} ]; then
        file=${path##/*/}
    fi
 
    # Wrap when there is a file and it is rewrap.
    if [ -n ${file} ] && [[ ${file} = "docker" ]]; then
        python -c "import subprocess; subprocess.run(['docker exec -it --user student oracle23c bash'], shell=True)" 
    else
        echo "Docker is unavailable: Install the docker package."
    fi
}

Open a Ubuntu Terminal shell and type a student function name to connect to the Docker Oracle Database 23c Free instance where you can now test things like external tables with the SQL*Plus command line without installing it on the Ubuntu local operating system.

student@student-virtual-machine:~$ student
[student@d28375f0c43f ~]$ sqlplus c##student/student@free
 
SQL*Plus: Release 23.0.0.0.0 - Production on Wed Jan 3 02:14:22 2024
Version 23.3.0.23.09
 
Copyright (c) 1982, 2023, Oracle.  All rights reserved.
 
Last Successful login time: Wed Jan 03 2024 01:56:44 +00:00
 
Connected to:
Oracle Database 23c Free Release 23.0.0.0.0 - Develop, Learn, and Run for Free
Version 23.3.0.23.09
 
SQL>

Then, I added this sqlplus function to the /home/student/.bashrc file, which is owned by the student user. However, I also added the instruction to change to the student user’s home directory because the Oracle 23c Free container will connect you to the /home/oracle directory by default. I also added the default long list (ll) alias to the .bashrc file.

sqlplus () 
{
    # Discover the fully qualified program name. 
    path=`which rlwrap 2>/dev/null`
    file=''
 
    # Parse the program name from the path.
    if [ -n ${path} ]; then
        file=${path##/*/}
    fi;
 
    # Wrap when there is a file and it is rewrap.
    if [ -n ${file} ] && [[ ${file} = "rlwrap" ]]; then
        rlwrap sqlplus "${@}"
    else
        echo "Command-line history unavailable: Install the rlwrap package."
        $ORACLE_HOME/bin/sqlplus "${@}"
    fi
}
 
# Change to the user's home directory.
cd ${HOME}
 
# Create a long list alias:
alias ll='ls -l --color=auto'

After you’ve configured your student user, you can configure the oracle user account to work like a regular server. Exit the Docker Oracle Database 23c Free as the student user, then connect as the root user with this command:

docker exec -it -u root oracle23c bash

As the root user you can become the oracle user with the following command:

su - oracle

Now, add the following .bashrc shell in the /home/oracle directory:

# The oracle user's .bashrc
 
# Source global definitions
if [ -f /etc/bashrc ]; then
	. /etc/bashrc
fi
 
# User specific environment
if ! [[ "$PATH" =~ "$HOME/.local/bin:$HOME/bin:" ]]
then
    PATH="$HOME/.local/bin:$HOME/bin:$PATH"
fi
export PATH
 
# Uncomment the following line if you don't like systemctl's auto-paging feature:
# export SYSTEMD_PAGER=
 
# User specific aliases and functions
export ORACLE_SID=FREE
export ORACLE_BASE=/opt/oracle
export ORACLE_HOME=/opt/oracle/product/23c/dbhomeFree
export PATH=$PATH:/$ORACLE_HOME/bin
 
# Change to the user's home directory.
cd ${HOME}
 
# Create a long list alias:
alias ll='ls -l --color=auto'
 
sqlplus () 
{
    # Discover the fully qualified program name. 
    path=`which rlwrap 2>/dev/null`
    file=''
 
    # Parse the program name from the path.
    if [ -n ${path} ]; then
        file=${path##/*/}
    fi;
 
    # Wrap when there is a file and it is rewrap.
    if [ -n ${file} ] && [[ ${file} = "rlwrap" ]]; then
        rlwrap sqlplus "${@}"
    else
        echo "Command-line history unavailable: Install the rlwrap package."
        $ORACLE_HOME/bin/sqlplus "${@}"
    fi
}

You need to manually source the .bashrc for the oracle user because it’s not an externally available user. Use this syntax to connect as the internal user:

sqlplus / as sysdba

It’ll display:

SQL*Plus: RELEASE 23.0.0.0.0 - Production ON Wed Jan 3 07:08:11 2024
Version 23.3.0.23.09
 
Copyright (c) 1982, 2023, Oracle.  ALL rights reserved.
 
 
Connected TO:
Oracle DATABASE 23c Free RELEASE 23.0.0.0.0 - Develop, Learn, AND Run FOR Free
Version 23.3.0.23.09
 
SQL>

After all this, I can now click the “up arrow” to edit any of the sqlplus command history. If you like to work inside sqlplus natively, this should help you.

Written by maclochlainn

December 20th, 2023 at 11:11 pm

SQL 1 v.s. SQL 3

without comments

In Alan Beaulieu’s wonderful book Learning SQL: Generate, Manipulate, and Retrieve Data, he uses a SQL 1 to demonstrates a CROSS JOIN in MySQL counting from 1 to 100. My students always find it difficult to read because the subqueries take so much space it makes it difficult to see the process, for example he gives this SQL 1 solution:

SELECT ones.x + tens.x + 1 AS counter
FROM
 (SELECT 0 AS x UNION ALL
  SELECT 1 AS x UNION ALL
  SELECT 2 AS x UNION ALL
  SELECT 3 AS x UNION ALL
  SELECT 4 AS x UNION ALL
  SELECT 5 AS x UNION ALL
  SELECT 6 AS x UNION ALL
  SELECT 7 AS x UNION ALL
  SELECT 8 AS x UNION ALL
  SELECT 9 AS x ) ones CROSS JOIN
 (SELECT 0 AS x UNION ALL
  SELECT 10 AS x UNION ALL
  SELECT 20 AS x UNION ALL
  SELECT 30 AS x UNION ALL
  SELECT 40 AS x UNION ALL
  SELECT 50 AS x UNION ALL
  SELECT 60 AS x UNION ALL
  SELECT 70 AS x UNION ALL
  SELECT 80 AS x UNION ALL
  SELECT 90 AS x ) tens
ORDER BY counter;

While anybody with a command of SQL should be able to see how it works, for those new to SQL it’s difficult. It’s more effective to use a Common Table Expression with the WITH clause because the derived tables become variables in the scope of the WITH clause and the final query works more like a CROSS JOIN between two tables:

WITH ones AS
 (SELECT 0 AS x UNION ALL
  SELECT 1 AS x UNION ALL
  SELECT 2 AS x UNION ALL
  SELECT 3 AS x UNION ALL
  SELECT 4 AS x UNION ALL
  SELECT 5 AS x UNION ALL
  SELECT 6 AS x UNION ALL
  SELECT 7 AS x UNION ALL
  SELECT 8 AS x UNION ALL
  SELECT 9 AS x )
, tens AS
 (SELECT 0 AS x UNION ALL
  SELECT 10 AS x UNION ALL
  SELECT 20 AS x UNION ALL
  SELECT 30 AS x UNION ALL
  SELECT 40 AS x UNION ALL
  SELECT 50 AS x UNION ALL
  SELECT 60 AS x UNION ALL
  SELECT 70 AS x UNION ALL
  SELECT 80 AS x UNION ALL
  SELECT 90 AS x )
SELECT ones.x + tens.x + 1 AS counter
FROM ones CROSS JOIN tens
ORDER BY counter;

As always, I hope this helps somebody trying to sort out the syntax and workflow.

Written by maclochlainn

November 7th, 2023 at 10:10 pm

Posted in MySQL,MySQL 8,sql

Tagged with

AWS EC2 TNS Listener

without comments

Having configured an AlmaLinux 8.6 with Oracle Database 11g XE, MySQL 8.0.30, and PostgreSQL 15, we migrated it to AWS EC2 and provisioned it. We used the older and de-supported Oracle Database 11g XE because it didn’t require any kernel modifications and had a much smaller footprint.

I had to address why attempting to connect with the sqlplus utility raised the following error after provisioning a copy with a new static IP address:

ERROR:
ORA-12514: TNS:listener does NOT currently know OF service requested IN CONNECT descriptor

A connection from SQL Developer raises a more addressable error, like:

ORA-17069

I immediately tried to check the connection with the tnsping utility and found that tnsping worked fine. However, when I tried to connect with the sqlplus utility it raised an ORA-12514 connection error.

There were no diagnostic steps beyond checking the tnsping utility. So, I had to experiment with what might block communication.

I changed the host name from ip-172-58-65-82.us-west-2.compute.internal to a localhost string in both the listener.ora and tnsnames.ora. The listener.ora file:

# listener.ora Network Configuration FILE:
 
SID_LIST_LISTENER =
  (SID_LIST =
    (SID_DESC =
      (SID_NAME = PLSExtProc)
      (ORACLE_HOME = /u01/app/oracle/product/11.2.0/xe)
      (PROGRAM = extproc)
    )
  )
 
LISTENER =
  (DESCRIPTION_LIST =
    (DESCRIPTION =
      (ADDRESS = (PROTOCOL = IPC)(KEY = EXTPROC_FOR_XE))
      (ADDRESS = (PROTOCOL = TCP)(HOST = localhost)(PORT = 1521))
    )
  )
 
DEFAULT_SERVICE_LISTENER = (XE)

The tnsnames.ora file:

# tnsnames.ora Network Configuration FILE:
 
XE =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = localhost)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = XE)
    )
  )
 
EXTPROC_CONNECTION_DATA =
  (DESCRIPTION =
    (ADDRESS_LIST =
      (ADDRESS = (PROTOCOL = IPC)(KEY = EXTPROC_FOR_XE))
    )
    (CONNECT_DATA =
      (SID = PLSExtProc)
      (PRESENTATION = RO)
    )
  )

I suspected that it might be related to the localhost value. So, I checked the /etc/hostname and /etc/hosts files.

Then, I modified /etc/hostname file by removing the AWS EC2 damain address. I did it on a memory that Oracle’s TNS raises errors for dots or periods in some addresses.

The /etc/hostname file:

ip-172-58-65-82

The /etc/hosts file:

127.0.0.1   localhost localhost.localdomain localhost4 localhost4.localdomain4 ip-172-58-65-82
::1         localhost localhost.localdomain localhost6 localhost6.localdomain6 ip-172-58-65-82

Now, we can connect to the Oracle Database 11g XE instance with the sqlplus utility. I believe this type of solution will work for other AWS EC2 provisioned Oracle databases.

Written by maclochlainn

March 22nd, 2023 at 10:09 pm

DML Event Management

without comments

Data Manipulation Language (DML)

DML statements add data to, change data in, and remove data from tables. This section examines four DML statements—the INSERT, UPDATE, DELETE, and MERGE statements—and builds on concepts of data transactions. The INSERT statement adds new data, the UPDATE statement changes data, the DELETE statement removes data from the database, and the MERGE statement either adds new data or changes existing data.

Any INSERT, UPDATE, MERGE, or DELETE SQL statement that adds, updates, or deletes rows in a table locks rows in a table and hides the information until the change is committed or undone (that is, rolled back). This is the nature of ACID-compliant SQL statements. Locks prevent other sessions from making a change while a current session is working with the data. Locks also restrict other sessions from seeing any changes until they’re made permanent. The database keeps two copies of rows that are undergoing change. One copy of the rows with pending changes is visible to the current session, while the other displays committed changes only.

ACID Compliant Transactions

ACID compliance relies on a two-phase commit (2PC) protocol and ensures that the current session is the only one that can see new inserts, updated column values, and the absence of deleted rows. Other sessions run by the same or different users can’t see the changes until you commit them.

ACID Compliant INSERT Statements

The INSERT statement adds rows to existing tables and uses a 2PC protocol to implement ACID- compliant guarantees. The SQL INSERT statement is a DML statement that adds one or more rows to a table. Oracle supports a VALUES clause when adding a single-row, and support a subquery when adding one to many rows.

The figure below shows a flow chart depicting an INSERT statement. The process of adding one or more rows to a table occurs during the first phase of an INSERT statement. Adding the rows exhibits both atomic and consistent properties. Atomic means all or nothing: it adds one or more rows and succeeds, or it doesn’t add any rows and fails. Consistent means that the addition of rows is guaranteed whether the database engine adds them sequentially or concurrently in threads.

Concurrent behaviors happen when the database parallelizes DML statements. This is similar to the concept of threads as lightweight processes that work under the direction of a single process. The parallel actions of a single SQL statement delegate and manage work sent to separate threads. Oracle supports all ACID properties and implements threaded execution as parallel operations. All tables support parallelization.

After adding the rows to a table, the isolation property prevents any other session from seeing the new rows—that means another session started by the same user or by another user with access to the same table. The atomic, consistent, and isolation properties occur in the first phase of any INSERT statement. The durable property is exclusively part of the second phase of an INSERT statement, and rows become durable when the COMMIT statement ratifies the insertion of the new data.

ACID Compliant UPDATE Statements

An UPDATE statement changes column values in one-to-many rows. With a WHERE clause, you update only rows of interest, but if you forget the WHERE clause, an UPDATE statement would run against all rows in a table. Although you can update any column in a row, it’s generally bad practice to update a primary or foreign key column because you can break referential integrity. You should only update non-key data in tables—that is, the data that doesn’t make a row unique within a table.

Changes to column values are atomic when they work. For scalability reasons, the database implementation of updates to many rows is often concurrent, in threads through parallelization. This process can span multiple process threads and uses a transaction paradigm that coordinates changes across the threads. The entire UPDATE statement fails when any one thread fails.

Similar to the INSERT statement, UPDATE statement changes to column values are also hidden until they are made permanent with the application of the isolation property. The changes are hidden from other sessions, including sessions begun by the same database user.

It’s possible that another session might attempt to lock or change data in a modified but uncommitted row. When this happens, the second DML statement encounters a lock and goes into a wait state until the row becomes available for changes. If you neglected to set a timeout value for the wait state, such as this clause, the FOR UPDATE clause waits until the target rows are unlocked:

WAIT n

As the figure below shows, actual updates are first-phase commit elements. While an UPDATE statement changes data, it changes only the current session values until it is made permanent by a COMMIT statement. Like the INSERT statement, the atomic, consistent, and isolation properties of an UPDATE statement occur during the first phase of a 2PC process. Changes to column values are atomic when they work. Any column changes are hidden from other sessions until the UPDATE statement is made permanent by a COMMIT or ROLLBACK statement, which is an example of the isolation property.

Any changes to column values can be modified by an ON UPDATE trigger before a COMMIT statement. ON UPDATE triggers run inside the first phase of the 2PC process. A COMMIT or ROLLBACK statement ends the transaction scope of the UPDATE statement.

The Oracle database engine can dispatch changes to many threads when an UPDATE statement works against many rows. UPDATE statements are consistent when these changes work in a single thread-of-control or across multiple threads with the same results.

As with the INSERT statement, the atomic, consistent, and isolation properties occur during the first phase of any UPDATE statement, and the COMMIT statement is the sole activity of the second phase. Column value changes become durable only with the execution of a COMMIT statement.

ACID Compliant DELETE Statements

A DELETE statement removes rows from a table. Like an UPDATE statement, the absence of a WHERE clause in a DELETE statement deletes all rows in a table. Deleted rows remain visible outside of the transaction scope where it has been removed. However, any attempts to UPDATE those deleted rows are held in a pending status until they are committed or rolled back.

You delete rows when they’re no longer useful. Deleting rows can be problematic when rows in another table have a dependency on the deleted rows. Consider, for example, a customer table that contains a list of cell phone contacts and an address table that contains the addresses for some but not all of the contacts. If you delete a row from the customer table that still has related rows in the address table, those address table rows are now orphaned and useless.

As a rule, you delete data from the most dependent table to the least dependent table, which is the opposite of the insertion process. Basically, you delete the child record before you delete the parent record. The parent record holds the primary key value, and the child record holds the foreign key value. You drop the foreign key value, which is a copy of the primary key, before you drop the primary key record. For example, you would insert a row in the customer table before you insert a row in the address table, and you delete rows from the address table before you delete rows in the customer table.

The figure below shows the logic behind a DELETE statement. Like the INSERT and UPDATE statements, acid, consistency, and isolation properties of the ACID-compliant transaction are managed during the first phase of a 2PC. The durability property is managed by the COMMIT or ROLLBACK statement.

There’s no discussion or diagrams for the MERGE statement because it does either an INSERT or UPDATE statement based on it’s internal logic. That means a MERGE statement is ACID compliant like an INSERT or UPDATE statement.

Written by maclochlainn

January 1st, 2023 at 8:05 pm

Wrapping sqlplus

with one comment

After sorting out the failures of Oracle Database 11g (11.2.0) on AlmaLinux, I grabbed the Enterprise Linux 9 rlwrap library. The rlwrap is a ‘readline wrapper’ that uses the GNU readline library to
allow the editing of keyboard input for any other command. Input history is remembered across invocations, separately for each command; history completion and search work as in bash and completion word
lists can be specified on the command line.

Installed it with the dnf utility:

dnf install -y rlwrap

It gave me this log file:

Last metadata expiration check: 0:53:30 ago on Fri 02 Dec 2022 01:07:54 AM EST.
Dependencies resolved.
================================================================================================================================
 Package                      Architecture                 Version                             Repository                  Size
================================================================================================================================
Installing:
 rlwrap                       x86_64                       0.45.2-3.el9                        epel                       132 k
 
Transaction Summary
================================================================================================================================
Install  1 Package
 
Total download size: 132 k
Installed size: 323 k
Downloading Packages:
rlwrap-0.45.2-3.el9.x86_64.rpm                                                                  162 kB/s | 132 kB     00:00    
--------------------------------------------------------------------------------------------------------------------------------
Total                                                                                           117 kB/s | 132 kB     00:01     
Running transaction check
Transaction check succeeded.
Running transaction test
Transaction test succeeded.
Running transaction
Regex version mismatch, expected: 10.40 2022-04-14 actual: 10.37 2021-05-26
Regex version mismatch, expected: 10.40 2022-04-14 actual: 10.37 2021-05-26
  Preparing        :                                                                                                        1/1 
  Installing       : rlwrap-0.45.2-3.el9.x86_64                                                                             1/1 
  Running scriptlet: rlwrap-0.45.2-3.el9.x86_64                                                                             1/1 
  Verifying        : rlwrap-0.45.2-3.el9.x86_64                                                                             1/1 
 
Installed:
  rlwrap-0.45.2-3.el9.x86_64                                                                                                    
 
Complete!

Then, I added this sqlplus function to the student account’s .bashrc file:

sqlplus () 
{
    # Discover the fully qualified program name. 
    path=`which rlwrap 2>/dev/null`
    file=''
 
    # Parse the program name from the path.
    if [ -n ${path} ]; then
        file=${path##/*/}
    fi;
 
    # Wrap when there is a file and it is rewrap.
    if [ -n ${file} ] && [[ ${file} = "rlwrap" ]]; then
        rlwrap sqlplus "${@}"
    else
        echo "Command-line history unavailable: Install the rlwrap package."
        $ORACLE_HOME/bin/sqlplus "${@}"
    fi
}

Then, I connected to the old, but tiny, footprint of Oracle Database 11g XE for testing, which worked:

Yes, I couldn’t resist. After all Version 11 was the last non-pluggable release and it’s been 11 years since its release. A double lucky 11.

Naturally, you can always use vi (or vim) to edit the command history provided you include the following command in your .bashrc file:

set -o vi

Next, I’ll build a new VM instance with the current version of Oracle Database XE for student testing.

As always, I hope this helps those working with Oracle’s database products.

Written by maclochlainn

December 19th, 2022 at 11:28 am

AlmaLinux MySQL+Perl

without comments

A quick primer on Perl programs connecting to the MySQL database. It’s another set of coding examples for the AlmaLinux instance that I’m building for students. This one demonstrates basic Perl programs, connecting to MySQL, returning data sets by reference and position, dynamic queries, and input parameters to dynamic queries.

  1. Naturally, a hello.pl is a great place to start:

    #!/usr/bin/perl
     
    # Hello World program.
    print "Hello World!\n";

    After setting the permissions to -rwxr-xr-x. with this command:

    chmod 755 hello.pl

    You call it like this from the Command-Line Interface (CLI):

    ./hello.pl

    It prints:

    Hello World!
  2. Next, a connect.pl program lets us test the Perl::DBI connection to the MySQL database.

    #!/usr/bin/perl
     
    # Import libraries.
    use strict;
    use warnings;
    use v5.10;     # for say() function
    use DBI;
     
    # Print with say() function message.
    say "Perl MySQL Connect Attempt.";
     
    # MySQL data source name should have a valid database as the
    # third argument; this uses the sakila demo database.
    my $dsn = "DBI:mysql:sakila";
     
    # Local variables to build the connection string.
    my $username = "student";
    my $password = "student";
     
    # Set arguments for MySQL database error management.
    my %attr = ( PrintError=>0,  # turn off error reporting via warn()
                 RaiseError=>1);   # turn on error reporting via die()           
     
    # Create connction with a data source name, user name and password.
    my $dbh  = DBI->connect($dsn,$username,$password, \%attr);
     
    # Print with say() function valid connection message.
    say "Connected to the MySQL database.";

    After setting the permissions to -rwxr-xr-x. you call it with this CLI command:

    ./connect.pl

    It prints:

    Perl MySQL Connect Attempt.
    Connected to the MySQL database.
  3. After connecting to the database lets query a couple columns by reference notation in a static.pl program. This one just returns the result of the MySQL version() and database() functions.

    #!/usr/bin/perl
     
    # Import libraries.
    use strict;
    use warnings;
    use v5.10;     # for say() function
    use DBI;
     
    # Print with say() function message.
    say "Perl MySQL Connect Attempt.";
     
    # MySQL data source name must have a valid database as the
    # third argument; this uses the sakila demo database.
    my $dsn = "DBI:mysql:sakila";
     
    # Local variables to build the connection string.
    my $username = "student";
    my $password = "student";
     
    # Set arguments for MySQL database error management.
    my %attr = ( PrintError=>0,  # turn off error reporting via warn()
                 RaiseError=>1); # turn on error reporting via die()           
     
    # Create connction with a data source name, user name and password.
    my $dbh  = DBI->connect($dsn,$username,$password, \%attr);
     
    # Creaet a static SQL statement or query.
    my $sth = $dbh->prepare("SELECT version() AS version \
    	                 ,      database() AS db_name");
     
    # Execute the static statement.
    $sth->execute() or die "Execution failed: $dbh->errstr()";
     
    # Read data and print by reference.
    print "----------------------------------------\n";
    while (my $ref = $sth->fetchrow_hashref()) {
      print "MySQL Version:  $ref->{'version'}\nMySQL Database: $ref->{'db_name'}\n";
    }
    print "----------------------------------------\n";
     
    # Close the statement.
    $sth->finish;
     
    # Disconnect from database connection.
    $dbh->disconnect();
     
    # Print with say() function valid connection message.
    say "Connected to the MySQL database.";

    After setting the permissions to -rwxr-xr-x. you call it with this CLI command:

    ./static.pl

    It prints:

    Perl MySQL Connect Attempt.
    ----------------------------------------
    MySQL Version:  8.0.30
    MySQL Database: sakila
    ----------------------------------------
    Connected to the MySQL database.
  4. After connecting to the database and securing variables by reference notation, lets return the value as an array of rows in a columns.pl program. This one just returns data from the film table of the sakila database. It is a static query because all the values are contained inside the SQL statement.

    #!/usr/bin/perl
     
    # Import libraries.
    use strict;
    use warnings;
    use v5.10;     # for say() function
    use DBI;
     
    # Print with say() function message.
    say "Perl MySQL Connect Attempt.";
     
    # MySQL data source name must have a valid database as the
    # third argument; this uses the sakila demo database.
    my $dsn = "DBI:mysql:sakila";
     
    # Local variables to build the connection string.
    my $username = "student";
    my $password = "student";
     
    # Set arguments for MySQL database error management.
    my %attr = ( PrintError=>0,  # turn off error reporting via warn()
                 RaiseError=>1); # turn on error reporting via die()           
     
    # Create connction with a data source name, user name and password.
    my $dbh  = DBI->connect($dsn,$username,$password, \%attr);
     
    # Creaet a static SQL statement or query.
    my $sth = $dbh->prepare("SELECT title         \
    	                 ,      release_year  \
    			 ,      rating        \
    			 FROM   film          \
    			 WHERE  title LIKE 'roc%'");
     
    # Execute the static statement.
    $sth->execute() or die "Execution failed: $dbh->errstr()";
     
    # Read data and print by comma-delimited row position.
    print "----------------------------------------\n";
    while (my @row = $sth->fetchrow_array()) {
      print join(", ", @row), "\n";
    }
    print "----------------------------------------\n";
     
    # Close the statement.
    $sth->finish;
     
    # Disconnect from database connection.
    $dbh->disconnect();
     
    # Print with say() function valid connection message.
    say "Connected to the MySQL database.";

    After setting the permissions to -rwxr-xr-x. you call it with this CLI command:

    ./columns.pl

    It prints:

    Perl MySQL Connect Attempt.
    ----------------------------------------
    ROCK INSTINCT, 2006, G
    ROCKETEER MOTHER, 2006, PG-13
    ROCKY WAR, 2006, PG-13
    ----------------------------------------
    Connected to the MySQL database.
  5. After connecting to the database and securing variables by reference notation, lets return the value as an array of rows in a dynamic.pl program. This one just returns data from the film table of the sakila database. It is a dynamic query because a string passed to the execute method and that value is bound to a ? placeholder in the SQL statement.

    #!/usr/bin/perl
     
    # Import libraries.
    use strict;
    use warnings;
    use v5.10;     # for say() function
    use DBI;
     
    # Print with say() function message.
    say "Perl MySQL Connect Attempt.";
     
    # MySQL data source name must have a valid database as the
    # third argument; this uses the sakila demo database.
    my $dsn = "DBI:mysql:sakila";
     
    # Local variables to build the connection string.
    my $username = "student";
    my $password = "student";
     
    # Set arguments for MySQL database error management.
    my %attr = ( PrintError=>0,  # turn off error reporting via warn()
                 RaiseError=>1); # turn on error reporting via die()           
     
    # Create connction with a data source name, user name and password.
    my $dbh  = DBI->connect($dsn,$username,$password, \%attr);
     
    # Creaet a static SQL statement or query.
    my $sth = $dbh->prepare("SELECT title         \
    	                 ,      release_year  \
    			 ,      rating        \
    			 FROM   film          \
    			 WHERE  title LIKE CONCAT(?,'%')");
     
    # Execute the dynamic statement by providing an input parameter.
    $sth->execute('roc') or die "Execution failed: $dbh->errstr()";
     
    # Read data and print by comma-delimited row position.
    print "----------------------------------------\n";
    while (my @row = $sth->fetchrow_array()) {
      print join(", ", @row), "\n";
    }
    print "----------------------------------------\n";
     
    # Close the statement.
    $sth->finish;
     
    # Disconnect from database connection.
    $dbh->disconnect();
     
    # Print with say() function valid connection message.
    say "Connected to the MySQL database.";

    After setting the permissions to -rwxr-xr-x. you call it with this CLI command:

    ./dynamic.pl

    It prints:

    Perl MySQL Connect Attempt.
    ----------------------------------------
    ROCK INSTINCT, 2006, G
    ROCKETEER MOTHER, 2006, PG-13
    ROCKY WAR, 2006, PG-13
    ----------------------------------------
    Connected to the MySQL database.
  6. After connecting to the database and securing variables by reference notation, lets return the value as an array of rows in a input.pl program. This one just returns data from the film table of the sakila database. It is a dynamic query because an input parameter is passed to a local variable and the local variable is bound to a ? placeholder in the SQL statement.

    #!/usr/bin/perl
     
    # Import libraries.
    use strict;
    use warnings;
    use v5.10;     # for say() function
    use DBI;
     
    # Get the index value of the maximum argument in the
    # argument.
    my $argc = $#ARGV;
     
    # Accept first argument value as parameter.
    my $param = $ARGV[$argc];
     
    # Verify variable value assigned.
    if (not defined $param) {
      die "Need parameter value.\n";
    }
     
    # Print with say() function message.
    say "Perl MySQL Connect Attempt.";
     
    # MySQL data source name must have a valid database as the
    # third argument; this uses the sakila demo database.
    my $dsn = "DBI:mysql:sakila";
     
    # Local variables to build the connection string.
    my $username = "student";
    my $password = "student";
     
    # Set arguments for MySQL database error management.
    my %attr = ( PrintError=>0,  # turn off error reporting via warn()
                 RaiseError=>1); # turn on error reporting via die()           
     
    # Create connction with a data source name, user name and password.
    my $dbh  = DBI->connect($dsn,$username,$password, \%attr);
     
    # Creaet a static SQL statement or query.
    my $sth = $dbh->prepare("SELECT title         \
    	                 ,      release_year  \
    			 ,      rating        \
    			 FROM   film          \
    			 WHERE  title LIKE CONCAT(?,'%')");
     
    # Execute the static statement.
    $sth->execute($param) or die "Execution failed: $dbh->errstr()";
     
    # Read data and print by comma-delimited row position.
    print "----------------------------------------\n";
    while (my @row = $sth->fetchrow_array()) {
      print join(", ", @row), "\n";
    }
    print "----------------------------------------\n";
     
    # Close the statement.
    $sth->finish;
     
    # Disconnect from database connection.
    $dbh->disconnect();
     
    # Print with say() function valid connection message.
    say "Connected to the MySQL database.";

    After setting the permissions to -rwxr-xr-x. you call it with this CLI command:

    ./input.pl ta

    It prints:

    Perl MySQL Connect Attempt.
    ----------------------------------------
    TADPOLE PARK, 2006, PG
    TALENTED HOMICIDE, 2006, PG
    TARZAN VIDEOTAPE, 2006, PG-13
    TAXI KICK, 2006, PG-13
    ----------------------------------------
    Connected to the MySQL database.

I think these examples cover most of the basic elements of writing Perl against the MySQL database. If I missed something you think would be useful, please advise. As always, I hope this helps those working with the MySQL and Perl products.

Written by maclochlainn

November 17th, 2022 at 12:01 am

Debugging PL/SQL Functions

without comments

Teaching student how to debug a PL/SQL function takes about an hour now. I came up with the following example of simple deterministic function that adds three numbers and trying to understand how PL/SQL implicitly casts data types. The lecture follows a standard Harvard Case Study, which requires the students to suggest next steps. The starting code is:

1
2
3
4
5
6
7
8
9
10
CREATE OR REPLACE
  FUNCTION adding
  ( a  DOUBLE PRECISION
  , b  INTEGER
  , c  DOUBLE PRECISION )
  RETURN INTEGER DETERMINISTIC IS
  BEGIN
    RETURN a + b + c;
END;
/

Then, we use one test case for two scenarios:

SELECT adding(1.25, 2, 1.24) AS "Test Case 1"
,      adding(1.25, 2, 1.26) AS "Test Case 2"
FROM   dual;

It returns:

Test Case 1 Test Case 2
----------- -----------
          4           5

Then, I ask why does that work? Somehow many students can’t envision how it works. Occasionally, a student will say it must implicitly cast the INTEGER to a DOUBLE PRECISION data type and add the numbers as DOUBLE PRECISION values before down-casting it to an INTEGER data type.

Whether I have to explain it or a student volunteers it, the next question is: “How would you build a test case to see if the implicit casting?” Then, I ask them to take 5-minutes and try to see how the runtime behaves inside the function.

At this point in the course, they only know how to use dbms_output.put_line to print content from anonymous blocks. So, I provide them with a modified adding function:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
CREATE OR REPLACE
  FUNCTION adding
  ( a  DOUBLE PRECISION
  , b  INTEGER
  , c  DOUBLE PRECISION )
  RETURN INTEGER DETERMINISTIC IS
 
    /* Define a double precision temporary result variable. */ 
    temp_result  NUMBER;
 
    /* Define an integer return variable. */
    temp_return  INTEGER;
 
  BEGIN
    /*
     *  Perform the calculation and assign the value to the temporary
     *  result variable.
     */
    temp_result := a + b + c;
 
    /*
     *  Assign the temporary result variable to the return variable.
     */
   temp_return := temp_result;
 
   /* Return the integer return variable as the function result. */
   RETURN temp_return;
 END;
/

The time limit ensures they spend their time typing the code from the on screen display and limits testing to the dbms_output.put_line attempt. Any more time and one or two of them would start using Google to find an answer.

I introduce the concept of a Black Box as their time expires, and typically use an illustration like the following to explain that by design you can’t see inside runtime operations of functions. Then, I teach them how to do exactly that.

You can test the runtime behaviors and view the variable values of functions by doing these steps:

  1. Create a debug table, like
    CREATE TABLE debug
    ( msg  VARCHAR2(200));
  2. Make the function into an autonomous transaction by:
    • Adding the PRAGMA (or precompiler) instruction in the declaration block.
    • Adding a COMMIT at the end of the execution block.
  3. Use an INSERT statement to write descriptive text with the variable values into the debug table.

Here’s the refactored test code:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
CREATE OR REPLACE
  FUNCTION adding
  ( a  DOUBLE PRECISION
  , b  INTEGER
  , c  DOUBLE PRECISION )
  RETURN INTEGER DETERMINISTIC IS
 
    /* Define a double precision temporary result variable. */ 
    temp_result  NUMBER;
 
    /* Define an integer return variable. */
    temp_return  INTEGER;
 
    /* Precompiler Instrunction. */
    PRAGMA AUTONOMOUS_TRANSACTION;
 
  BEGIN
    /*
     *  Perform the calculation and assign the value to the temporary
     *  result variable.
     */
    temp_result := a + b + c;
 
    /* Insert the temporary result variable into the debug table. */
    INSERT INTO debug (msg) VALUES ('Temporary Result Value: ['||temp_result||']');
 
    /*
     *  Assign the temporary result variable to the return variable.
     */
   temp_return := temp_result;
 
    /* Insert the temporary result variable into the debug table. */
    INSERT INTO debug (msg) VALUES ('Temporary Return Value: ['||temp_return||']');
 
   /* Commit to ensure the write succeeds in a separate process scope. */
   COMMIT;
 
   /* Return the integer return variable as the function result. */
   RETURN temp_return;
 END;
/

While an experienced PL/SQL developer might ask while not introduce conditional computation, the answer is that’s for another day. Most students need to uptake pieces before assembling pieces and this example is already complex for a newbie.

The same test case works (shown to avoid scrolling up):

SELECT adding(1.25, 2, 1.24) AS "Test Case 1"
,      adding(1.25, 2, 1.26) AS "Test Case 2"
FROM   dual;

It returns:

Test Case 1 Test Case 2
----------- -----------
          4           5

Now, they can see the internal step-by-step values with this query:

COL msg FORMAT A30 HEADING "Internal Variable Auditing"
SELECT msg FROM debug;

It returns:

Internal Variable Auditing
------------------------------
Temporary Result Value: [4.49]
Temporary Return Value: [4]
Temporary Result Value: [4.51]
Temporary Return Value: [5]
 
4 rows selected.

What we learn is that:

  • Oracle PL/SQL up-casts the b variable from an integer to a double precision data type before adding the three input variables.
  • Oracle PL/SQL down-casts the sum of the three input variables from a double precision data type to an integer by applying traditionally rounding.

I hope this helps those trying to understand implicit casting and discovering how to unhide an opaque function’s operations for debugging purposes.

Written by maclochlainn

October 5th, 2022 at 12:10 am

PL/SQL Overloading

without comments

So, I wrote an updated example of my grandma and tweetie_bird for my students. It demonstrates overloading with the smallest parameter lists possible across a transaction of two tables. It also shows how one version of the procedure can call another version of the procedure.

The tables are created with the following:

/* Conditionally drop grandma table and grandma_s sequence. */
BEGIN
  FOR i IN (SELECT object_name
            ,      object_type
            FROM   user_objects
            WHERE  object_name IN ('GRANDMA','GRANDMA_SEQ')) LOOP
    IF i.object_type = 'TABLE' THEN
      /* Use the cascade constraints to drop the dependent constraint. */
      EXECUTE IMMEDIATE 'DROP TABLE '||i.object_name||' CASCADE CONSTRAINTS';
    ELSE
      EXECUTE IMMEDIATE 'DROP SEQUENCE '||i.object_name;
    END IF;
  END LOOP;
END;
/
 
/* Create the table. */
CREATE TABLE GRANDMA
( grandma_id     NUMBER       CONSTRAINT grandma_nn1 NOT NULL
, grandma_house  VARCHAR2(30) CONSTRAINT grandma_nn2 NOT NULL
, created_by     NUMBER       CONSTRAINT grandma_nn3 NOT NULL
, CONSTRAINT grandma_pk       PRIMARY KEY (grandma_id)
);
 
/* Create the sequence. */
CREATE SEQUENCE grandma_seq;
 
/* Conditionally drop a table and sequence. */
BEGIN
  FOR i IN (SELECT object_name
            ,      object_type
            FROM   user_objects
            WHERE  object_name IN ('TWEETIE_BIRD','TWEETIE_BIRD_SEQ')) LOOP
    IF i.object_type = 'TABLE' THEN
      EXECUTE IMMEDIATE 'DROP TABLE '||i.object_name||' CASCADE CONSTRAINTS';
    ELSE
      EXECUTE IMMEDIATE 'DROP SEQUENCE '||i.object_name;
    END IF;
  END LOOP;
END;
/
 
/* Create the table with primary and foreign key out-of-line constraints. */
CREATE TABLE TWEETIE_BIRD
( tweetie_bird_id     NUMBER        CONSTRAINT tweetie_bird_nn1 NOT NULL
, tweetie_bird_house  VARCHAR2(30)  CONSTRAINT tweetie_bird_nn2 NOT NULL
, grandma_id          NUMBER        CONSTRAINT tweetie_bird_nn3 NOT NULL
, created_by          NUMBER        CONSTRAINT tweetie_bird_nn4 NOT NULL
, CONSTRAINT tweetie_bird_pk        PRIMARY KEY (tweetie_bird_id)
, CONSTRAINT tweetie_bird_fk        FOREIGN KEY (grandma_id)
  REFERENCES GRANDMA (GRANDMA_ID)
);
 
/* Create sequence. */
CREATE SEQUENCE tweetie_bird_seq;

The sylvester package specification holds the two overloaded procedures, like:

CREATE OR REPLACE
  PACKAGE sylvester IS
 
  /* Three variable length strings. */
  PROCEDURE warner_brother
  ( pv_grandma_house       VARCHAR2
  , pv_tweetie_bird_house  VARCHAR2
  , pv_system_user_name    VARCHAR2  );
 
  /* Two variable length strings and a number. */  
  PROCEDURE warner_brother
  ( pv_grandma_house       VARCHAR2
  , pv_tweetie_bird_house  VARCHAR2
  , pv_system_user_id      NUMBER   );
 
END sylvester;
/

The sylvester package implements two warner_brother procedures. One takes the system user’s ID and the other takes the system user’s name. The procedure that accepts the system user name queries the system_user table with the system_user_name to get the system_user_id column and then calls the other version of itself. This demonstrates how you only write logic once when overloading and let one version call the other with the added information.

Here’s the sylvester package body code:

CREATE OR REPLACE
  PACKAGE BODY sylvester IS
 
  /* Procedure warner_brother with user name. */
  PROCEDURE warner_brother
  ( pv_grandma_house       VARCHAR2
  , pv_tweetie_bird_house  VARCHAR2
  , pv_system_user_id      NUMBER  ) IS
 
    /* Declare a local variable for an existing grandma_id. */
    lv_grandma_id   NUMBER;
 
    FUNCTION get_grandma_id
    ( pv_grandma_house  VARCHAR2 ) RETURN NUMBER IS
 
      /* Initialized local return variable. */
      lv_retval  NUMBER := 0;  -- Default value is 0.
 
      /* A cursor that lookups up a grandma's ID by their name. */
      CURSOR find_grandma_id
      ( cv_grandma_house  VARCHAR2 ) IS
        SELECT grandma_id
        FROM   grandma
        WHERE  grandma_house = cv_grandma_house;
 
    BEGIN   
      /* Assign a grandma_id as the return value when a row exists. */
      FOR i IN find_grandma_id(pv_grandma_house) LOOP
        lv_retval := i.grandma_id;
      END LOOP;
 
      /* Return 0 when no row found and the grandma_id when a row is found. */
      RETURN lv_retval;
    END get_grandma_id;
 
  BEGIN
    /* Set the savepoint. */
    SAVEPOINT starting;
 
    /*
     *  Identify whether a member account exists and assign it's value
     *  to a local variable.
     */
    lv_grandma_id := get_grandma_id(pv_grandma_house);
 
    /*
     *  Conditionally insert a new member account into the member table
     *  only when a member account does not exist.
     */
    IF lv_grandma_id = 0 THEN
 
      /* Insert grandma. */
      INSERT INTO grandma
      ( grandma_id
      , grandma_house
      , created_by )
      VALUES
      ( grandma_seq.NEXTVAL
      , pv_grandma_house
      , pv_system_user_id  );
 
      /* Assign grandma_seq.currval to local variable. */
      lv_grandma_id := grandma_seq.CURRVAL;
 
    END IF;
 
    /* Insert tweetie bird. */
    INSERT INTO tweetie_bird
    ( tweetie_bird_id
    , tweetie_bird_house 
    , grandma_id
    , created_by )
    VALUES
    ( tweetie_bird_seq.NEXTVAL
    , pv_tweetie_bird_house
    , lv_grandma_id
    , pv_system_user_id );
 
    /* If the program gets here, both insert statements work. Commit it. */
    COMMIT;
 
  EXCEPTION
    /* When anything is broken do this. */
    WHEN OTHERS THEN
      /* Until any partial results. */
      ROLLBACK TO starting;
  END;
 
  PROCEDURE warner_brother
  ( pv_grandma_house       VARCHAR2
  , pv_tweetie_bird_house  VARCHAR2
  , pv_system_user_name    VARCHAR2  ) IS
 
    /* Define a local variable. */
	lv_system_user_id  NUMBER := 0;
 
    FUNCTION get_system_user_id
    ( pv_system_user_name  VARCHAR2 ) RETURN NUMBER IS
 
      /* Initialized local return variable. */
      lv_retval  NUMBER := 0;  -- Default value is 0.
 
      /* A cursor that lookups up a grandma's ID by their name. */
      CURSOR find_system_user_id
      ( cv_system_user_id  VARCHAR2 ) IS
        SELECT system_user_id
        FROM   system_user
        WHERE  system_user_name = pv_system_user_name;
 
    BEGIN   
      /* Assign a grandma_id as the return value when a row exists. */
      FOR i IN find_system_user_id(pv_system_user_name) LOOP
        lv_retval := i.system_user_id;
      END LOOP;
 
      /* Return 0 when no row found and the grandma_id when a row is found. */
      RETURN lv_retval;
    END get_system_user_id;
 
  BEGIN
 
    /* Convert a system_user_name to system_user_id. */
	lv_system_user_id := get_system_user_id(pv_system_user_name);
 
	/* Call the warner_brother procedure. */
	warner_brother
    ( pv_grandma_house      => pv_grandma_house
    , pv_tweetie_bird_house => pv_tweetie_bird_house
    , pv_system_user_id     => lv_system_user_id  );
 
  EXCEPTION
    /* When anything is broken do this. */
    WHEN OTHERS THEN
      /* Until any partial results. */
      ROLLBACK TO starting;
  END;  
 
END sylvester;
/

The following anonymous block test case works with the code:

BEGIN
  sylvester.warner_brother( pv_grandma_house      => 'Blue House'
                          , pv_tweetie_bird_house => 'Cage'
				          , pv_system_user_name   => 'DBA 3' );
  sylvester.warner_brother( pv_grandma_house      => 'Blue House'
                          , pv_tweetie_bird_house => 'Tree House'
				          , pv_system_user_id     =>  4 );
END;
/

You can now query the results with this SQL*PLus formatting and query:

/* Query results from warner_brother procedure. */
COL grandma_id          FORMAT 9999999  HEADING "Grandma|ID #"
COL grandma_house       FORMAT A14      HEADING "Grandma House"
COL created_by          FORMAT 9999999  HEADING "Created|By"
COL tweetie_bird_id     FORMAT 9999999  HEADING "Tweetie|Bird ID"
COL tweetie_bird_house  FORMAT A18      HEADING "Tweetie Bird House"
SELECT *
FROM   grandma g INNER JOIN tweetie_bird tb
ON     g.grandma_id = tb.grandma_id;

You should see the following data:

 Grandma                 Created  Tweetie                     Grandma  Created
    ID # Grandma House        By  Bird ID Tweetie Bird House     ID #       By
-------- -------------- -------- -------- ------------------ -------- --------
       1 Blue House            3        1 Cage                      1        3
       1 Blue House            3        2 Tree House                1        4

As always, I hope complete code samples help solve real problems.

Written by maclochlainn

September 29th, 2022 at 9:24 pm