Friday, July 9, 2021

Uploading data to a table in an Oracle Cloud database using Sql*Loader

In a previous post I went through the steps necessary for connecting to an Oracle Cloud database using SQL*Plus. Shortly after this, I had need to upload data to a table in my Oracle Cloud database. So, as most of the necessary software was already configured, I decided to use SQL*Loader.

The first thing I needed to do was to download the Instant Client Tools package from the Oracle web site ( Instant Client for Microsoft Windows (x64) 64-bit | Oracle United Kingdom ). In fact, as my currently installed Instant Client was a few upgrades out of date, I decided to build a new Instant Client folder, so I downloaded the Basic Light Package and the SQL*Plus Package as well as the Tools Package.

When the files had finished downloading, I extracted the Basic Light Package first, followed by the SQL*Package and, finally, the Tools Package. In this case I extracted all the files to the folder "instantclient_19_11" in my "C:\Oracle" folder.

To finish off, I amended the PATH and TNS_ADMIN path variables to point to the new Instant Client folder and copied the tnsnames.ora from the old Instant Client folder to the new one. After a successful test connection to the cloud database using SQL*Plus, I was ready to do the upload with SQL*Loader.

SQL*Loader isn't something I've made much use of over the years. However, I can see how it can come in handy now and again, so it's worth being able to use, even at a basic level.

I had created a simple table in my cloud database to hold product sales data.

create table sales (
sa_id number(12), 
sa_cust_id number(12), 
sa_prod_id number(12), 
sa_date date, 
sa_amount number (15,2)
);

Following this, I created a PL/SQL script, using DBMS_RANDOM to generate 5000 random records of product sales data.

declare
    l_seed varchar2(100);
    l_low number := 1;
    l_high number;
    l_year number := 2019;
    lcTab   varchar2(1) := chr(9);
begin
    dbms_output.enable(null);
    if is_leap_year(l_year) then
        l_high := 366;
    else
        l_high := 365;
    end if;
    l_seed := to_char(systimestamp, 'YYYYDDMMHH24MISSFFFF');
    --dbms_output.put_line('Run 1: seed=' || l_seed);
    dbms_random.seed(val=>l_seed);
    --dbms_output.put_line('sa_cust_id' || lcTab || 'sa_prod_id' || lcTab || 'sa_date' || lcTab || 'sa_amount');
    for i in 1..5000 loop
        dbms_output.put(i || lcTab);
        dbms_output.put(trunc(dbms_random.value(low=>10000000, high=>19999999)) || lcTab);
        dbms_output.put(trunc(dbms_random.value(low=>500000, high=>599999)) || lcTab);
        dbms_output.put(to_char(date_from_day_number(trunc(dbms_random.value(low=>1, high=>l_high)),l_year), 'DD-MON-YYYY') || lcTab);
        dbms_output.put_line(round(dbms_random.value(low=>1, high=>10000), 2));
    end loop;
        
end;


The above code uses two user-defined functions. IS_LEAP_YEAR, as the name suggests, checks whether the supplied year is a leap year.

create or replace function is_leap_year (l_year in number) return boolean is

    l_result boolean := false;
begin
    case 
        when mod(l_year, 400) = 0 then l_result := true;
        when mod(l_year, 100) = 0 then l_result := false;
        when mod(l_year, 4) = 0 then l_result := true;
        else l_result := false;
    end case;
    return l_result;
end;

The other function, DATE_FROM_DAY_NUMBER, accepts as parameters a number and a valid year and returns the corresponding date. For example, passing 190 and 2021 to the function will return 09/07/2021, since this date is the 190th day of 2021.

create or replace function date_from_day_number (l_day_number in  number, l_year in number) return date is
    l_total_days    number;
    l_current_date  date;
begin
    if is_leap_year(l_year) then
        l_total_days := 366;
    else
        l_total_days := 365;
    end if;
    
    if l_day_number > l_total_days then
        return null;
    end if;
    
    l_current_date := to_date('01/01/' || l_year, 'DD/MM/YYYY');
    for i in 1..l_total_days loop
        if i = l_day_number then
            exit;
        end if;
        l_current_date := l_current_date + 1;
    end loop;

    return l_current_date;
end;

Running the anonymous PL/SQL block, shown above, generated 5000 tab-delimited records with random values for imaginary product sales for the whole of 2019.

I created a subfolder off my C:\Oracle folder and called it "loader". I saved the product sales records in this folder in a file named "product_sales_2019.dat". The "dat" file is one of three files required by SQL*Loader for uploading a basic text file of data.

The next file I created was the control file, which requires the file name extension ".ctl".  I named my control file "product_sales_2019.ctl". Here are the contents of my control file:

load data into table sales
insert
fields terminated by "\t"
(
sa_id,
sa_cust_id,
sa_prod_id,
sa_date,
sa_amount
)

Had I decided to use a comma as the separator, the wording would have read:

fields terminated by ","

If the file had optional double quotes around the delimiting comma, the working would have read:

fields terminated by ","
optionally enclosed by '"' -- a single quote followed by a double quote and then another single quote

The final file that I created was the parameter file, which I named "product_sales_2019.par". The contents of this were as follows (I have removed my actual login details):

userid=<username>@<database SID>/<password>
control=product_sales_2019.ctl
log=product_sales_2019.log
bad=product_sales_2019.bad
data=product_sales_2019.dat
direct=true

The userid uses the same login details that you would use to connect to the same database using SQL*Plus. For example, to connect to a database called "my_db" with a user name of "fred" and a password of "pa$$w0rd", you would create the following userid value:

userid=fred@my_db/pa$$w0rd

The "direct=true" line instructs the SQL*Loader to use the direct path load method. You can read about the different load methods at SQL*Loader Concepts (oracle.com)

I opened a console window and ran SQL*Loader from the folder containing the configuration files.

sqlldr parfile=product_sales_2019.par

The upload process was successful. The output is shown below.