MacLochlainns Weblog

Michael McLaughlin's Technical Blog

Site Admin

Archive for the ‘Oracle 11g’ Category

Filtering String Dates

with 2 comments

A question came up about how to verify dates from a string without throwing a casting error because of a non-conforming date. You can throw a number of exceptions, and I wrote a function to filter bad string formats like the DD-MON-RR or DD-MON-YYYY.

The first one is for a day between 1 and the last day of month, which is:

ORA-01847: day of month must be between 1 and last day of month

An incorrect string for a month, raises the following error:

ORA-01843: not a valid month

A date format mask longer than a DD-MON-RR or DD-MON-YYYY raises the following exception:

ORA-01830: date format picture ends before converting entire input string

The verify_date function checks for non-conforming DD-MON-RR and DD-MON-YYYY date masks, and substitutes a SYSDATE value for a bad date entry:

CREATE OR REPLACE
  FUNCTION verify_date
  ( pv_date_in  VARCHAR2) RETURN DATE IS
  /* Local return variable. */
  lv_date  DATE;
BEGIN
  /* Check for a DD-MON-RR or DD-MON-YYYY string. */
  IF REGEXP_LIKE(pv_date_in,'^[0-9]{2,2}-[ADFJMNOS][ACEOPU][BCGLNPRTVY]-([0-9]{2,2}|[0-9]{4,4})$') THEN
    /* Case statement checks for 28 or 29, 30, or 31 day month. */
    CASE
      /* Valid 31 day month date value. */
      WHEN SUBSTR(pv_date_in,4,3) IN ('JAN','MAR','MAY','JUL','AUG','OCT','DEC') AND
           TO_NUMBER(SUBSTR(pv_date_in,1,2)) BETWEEN 1 AND 31 THEN 
        lv_date := pv_date_in;
      /* Valid 30 day month date value. */
      WHEN SUBSTR(pv_date_in,4,3) IN ('APR','JUN','SEP','NOV') AND
           TO_NUMBER(SUBSTR(pv_date_in,1,2)) BETWEEN 1 AND 30 THEN 
        lv_date := pv_date_in;
      /* Valid 28 or 29 day month date value. */
      WHEN SUBSTR(pv_date_in,4,3) = 'FEB' THEN
        /* Verify 2-digit or 4-digit year. */
        IF (LENGTH(pv_date_in) = 9 AND MOD(TO_NUMBER(SUBSTR(pv_date_in,8,2)) + 2000,4) = 0 OR
            LENGTH(pv_date_in) = 11 AND MOD(TO_NUMBER(SUBSTR(pv_date_in,8,4)),4) = 0) AND
            TO_NUMBER(SUBSTR(pv_date_in,1,2)) BETWEEN 1 AND 29 THEN
          lv_date := pv_date_in;
        ELSE /* Not a leap year. */
          IF TO_NUMBER(SUBSTR(pv_date_in,1,2)) BETWEEN 1 AND 28 THEN
            lv_date := pv_date_in;
          ELSE
            lv_date := SYSDATE;
          END IF;
        END IF;
      ELSE
        /* Assign a default date. */
        lv_date := SYSDATE;
    END CASE;
  ELSE
    /* Assign a default date. */
    lv_date := SYSDATE;
  END IF;
  /* Return date. */
  RETURN lv_date;
END;
/

You can check valid dates with a DD-MON-RR format:

SELECT verify_date('28-FEB-10') AS "Non-Leap Year"
,      verify_date('29-FEB-12') AS "Leap Year"
,      verify_date('31-MAR-14') AS "31-Day Year"
,      verify_date('30-APR-14') AS "30-Day Year"
FROM   dual;

You can check valid dates with a DD-MON-YYYY format:

SELECT verify_date('28-FEB-2010') AS "Non-Leap Year"
,      verify_date('29-FEB-2012') AS "Leap Year"
,      verify_date('31-MAR-2014') AS "31-Day Year"
,      verify_date('30-APR-2014') AS "30-Day Year"
FROM   dual;

They both return:

Non-Leap    Leap YEAR 31-DAY YEAR 30-DAY YEAR
----------- --------- ----------- -----------
28-FEB-10   29-FEB-12 31-MAR-14   30-APR-14

You can check badly formatted dates with the following query:

SELECT verify_date('28-FEB-2010') AS "Non-Leap Year"
,      verify_date('29-FEB-2012') AS "Leap Year"
,      verify_date('31-MAR-2014') AS "31-Day Year"
,      verify_date('30-APR-2014') AS "30-Day Year"
FROM   dual;

You can screen for an alphanumeric string with the following expression:

SELECT 'Valid alphanumeric string literal' AS "Statement"
FROM   dual
WHERE  REGEXP_LIKE('Some Mythical String $200','([:alnum:]|[:punct:]|[:space:])*');

You can screen for a numeric literal as a string with the following expression:

SELECT 'Valid numeric literal' AS "Statement"
FROM   dual
WHERE  REGEXP_LIKE('123.00','([:digit:]|[:punct:])');

As always, I hope this helps those who need this type of solution.

Written by maclochlainn

February 2nd, 2015 at 12:53 am

Querying an Object Type

without comments

I demonstrated a number of SQL approaches to reading object types in Appendix B of the Oracle Database 12c PL/SQL Programming book. For example, the easiest one to construct and return the results from a TO_STRING member function uses the TREAT function:

SELECT TREAT(base_t() AS base_t).to_string() AS "Text"
FROM   dual;

However, it seems that I could have provided one more. Here’s an example of how you can test the construction of an object type and how you can return its attributes with a query. It’s important to note that there’s a natural problem with this syntax when you increment a sequence inside the object type. The problem is that it double increments the counter for the sequence.

SELECT *
FROM   TABLE(SELECT CAST(COLLECT(base_t()) AS base_t_tab)
             FROM dual);

The syntax for the COLLECT function requires that you put it inside a SELECT-list. Then, the CAST function converts a single instance of the BASE_T object type to a one element BASE_T_TAB collection. Finally, the TABLE function returns a single row from the BASE_T_TAB collection.

You can find a more complete article covering column substitutability and object types and subtypes on the ToadWorld site. I think it helps clear up how you can effectively write PL/SQL types and subtypes for persistent object type columns.

Written by maclochlainn

November 25th, 2014 at 12:33 am

Finding Direct Indexes

without comments

If you’re not using Toad DBA Suite, it’s sometimes hard to find solutions. Somebody wanted to know how to find indexes that aren’t indirect. Indirect indexes are those created for a primary key because a primary key column or set of columns are both not null and uniquely constrained. Likewise, you create a unique index when you can create a unique constraint. You can’t drop a unique index for a primary key without dropping the primary key or unique constraint that indirectly created it.

The following query returns indexes with one or more columns that are created by a CREATE INDEX statement on a target table. It excludes unique indexes created by a primary key constraint, and it returns the relative position of columns in an index:

COLUMN sequence_name   FORMAT A22 HEADING "Sequence Name"
COLUMN column_position FORMAT 999 HEADING "Column|Position"
COLUMN column_name     FORMAT A22 HEADING "Column|Name"
SELECT   uin.index_name
,        uic.column_position
,        uic.column_name
FROM     user_indexes uin INNER JOIN user_ind_columns uic
ON       uin.index_name = uic.index_name
AND      uin.table_name = uic.table_name
WHERE    uin.table_name = UPPER('&&table_name')
AND NOT  uin.index_name IN (SELECT constraint_name
                            FROM   user_constraints
                            WHERE  table_name = UPPER('&&table_name'))
ORDER BY uin.index_name
,        uic.column_position;

It can be rewritten into a function, which can then drop indexes based on a table name:

CREATE OR REPLACE FUNCTION drop_indexes_on
( pv_table_name  VARCHAR2 ) RETURN NUMBER IS 
 
  /* A return value. */
  lv_return  NUMBER := 0;
 
  /* A query to return only directly created indexes. */
  CURSOR find_indexes_on
  ( cv_table_name  VARCHAR2 ) IS
    SELECT   DISTINCT ui.index_name
    FROM     user_indexes ui INNER JOIN user_ind_columns uic
    ON       ui.index_name = uic.index_name
    AND      ui.table_name = uic.table_name
    WHERE    ui.table_name = UPPER(cv_table_name)
    AND NOT  ui.index_name IN (SELECT constraint_name
                               FROM   user_constraints
                               WHERE  table_name = UPPER(cv_table_name));
 
  /* Declare function autonomous. */
  PRAGMA AUTONOMOUS_TRANSACTION;
 
BEGIN
 
  /* Drop the indexes on a table. */
  FOR i IN find_indexes_on(pv_table_name) LOOP
    EXECUTE IMMEDIATE 'DROP INDEX '||i.index_name;
    lv_return := 1;
  END LOOP;
 
  RETURN lv_return;
END drop_indexes_on;
/

You can call the drop_on_indexes_on function like this:

SELECT   drop_indexes_on(UPPER('address_lab'))
FROM     dual;

Hope this helps those who need to work with dropping indexes.

Written by maclochlainn

November 23rd, 2014 at 8:42 pm

Check Constraints

without comments

Oracle Database 12c introduces a SEARCH_CONDITION_VC column to the CDB_, DBA_, ALL_, and USER_CONSTRAINTS views. The SEARCH_CONDITION_VC column is a VARCHAR2 data type equivalent to the search condition in the LONG data type SEARCH_CONDITION column. Unfortunately, Oracle Database 11g and earlier versions requires you to convert the LONG data type to a VARCHAR2 for the equivalent behavior. This post provides you with a function to help you do that in Oracle Database 11g.

While Oracle Database 12c let’s you check the search condition of a CHECK constraint, with this query:

SELECT   uc.constraint_name AS constraint_name
,	 uc.search_condition_vc AS search_condition
FROM     user_constraints uc
WHERE    uc.table_name = UPPER('table_name')
AND	 REGEXP_LIKE(uc.search_condition_vc,'search_key','i');

You need the following GET_SEARCH_CONDITION function to convert the SEARCH_CONDITION column from a LONG data type to a VARCHAR2 data type. It uses the DBMS_SQL package to convert the LONG data type.

CREATE OR REPLACE FUNCTION get_search_condition
( pv_table_name   VARCHAR2
, pv_column_name  VARCHAR2 )
RETURN VARCHAR2 AS
 
  /* Declare local variables. */
  lv_cursor           INTEGER := DBMS_SQL.open_cursor;
  lv_feedback         INTEGER;         -- Acknowledgement of dynamic execution
  lv_length           INTEGER;         -- Length of the input string
  lv_value_length     INTEGER;         -- Length of the output string
  lv_constraint_name  VARCHAR2(30);    -- Constraint name
  lv_return           VARCHAR2(32767); -- Function output
  lv_stmt             VARCHAR2(2000);  -- Dynamic SQL statement
  lv_long             LONG;            -- Dynamic LONG data type.
  lv_string           VARCHAR2(32760); -- Maximum length of LONG data type
 
  FUNCTION return_length 
  ( pv_table_name   VARCHAR2
  , pv_column_name  VARCHAR2 ) RETURN VARCHAR2 IS
 
    /* Declare a target variable,  because of the limit of SELECT-INTO. */
    lv_long_view  LONG;
 
    /* Declare a dynamic cursor. */
    CURSOR c
    ( cv_table_name   VARCHAR2
    , cv_column_name  VARCHAR2 ) IS
      SELECT   uc.search_condition
      FROM     user_constraints uc INNER JOIN user_cons_columns ucc
      ON       uc.table_name = ucc.table_name
      AND      uc.constraint_name = ucc.constraint_name
      WHERE    uc.table_name = UPPER(cv_table_name)
      AND      ucc.column_name = UPPER(cv_column_name)
      AND      uc.constraint_type = 'C';
 
  BEGIN
    /* Open, fetch, and close cursor to capture view text. */
    OPEN c (pv_table_name, pv_column_name);
    FETCH c INTO lv_long_view;
    CLOSE c;
 
    /* Return the output CLOB length value. */
    RETURN LENGTH(lv_long_view);
  END return_length;
 
BEGIN
 
  /* Get the length of the CLOB column value. */
  lv_length := return_length(pv_table_name, pv_column_name);
 
  /* Create dynamic statement. */
  lv_stmt := 'SELECT uc.search_condition'||CHR(10)
          || 'FROM   user_constraints uc INNER JOIN user_cons_columns ucc'||CHR(10)
          || 'ON     uc.table_name = ucc.table_name'||CHR(10)
          || 'AND    uc.constraint_name = ucc.constraint_name'||CHR(10)
          || 'WHERE  uc.table_name = UPPER('''||pv_table_name||''')'||CHR(10)
          || 'AND    ucc.column_name = UPPER('''||pv_column_name||''')'||CHR(10)
          || 'AND    uc.constraint_type = ''C''';
 
  /* Parse and define VARCHAR2 and LONG columns. */
  DBMS_SQL.parse(lv_cursor, lv_stmt, DBMS_SQL.native);
  DBMS_SQL.define_column_long(lv_cursor,1);
 
  /* Only attempt to process the return value when fetched. */
  IF DBMS_SQL.execute_and_fetch(lv_cursor) = 1 THEN
    DBMS_SQL.column_value_long(
        lv_cursor
      , 1
      , lv_length
      , 0
      , lv_string
      , lv_value_length);
  END IF;
 
  /* Check for an open cursor. */
  IF DBMS_SQL.is_open(lv_cursor) THEN
    DBMS_SQL.close_cursor(lv_cursor);
  END IF;
 
  /* Convert the long length string to a maximum size length. */
  lv_return := lv_string;
 
  RETURN lv_return;
END get_search_condition;
/

Then, you can use the following query to view the full search criteria of a CHECK constraint that matches part of a search string:

COLUMN constraint_name   FORMAT A16
COLUMN search_condition  FORMAT A30
SELECT   uc.constraint_name AS constraint_name
,        get_search_condition('table_name','column_name') AS search_condition
FROM     user_constraints uc
WHERE    REGEXP_LIKE(get_search_condition('table_name','column_name'),'check_constraint_search_string','i')
AND      uc.constraint_type = 'C';

Hope this helps those looking at discovering the full search criteria of a CHECK constraint.

Written by maclochlainn

October 21st, 2014 at 12:51 am

Wrapping SQL*Plus

without comments

One annoying thing from installing Oracle Database 11g on Fedora, was that the up arrows for command history didn’t work. I decided to fix that today after seeing Lutz Hartmann’s article on rlwrap. Unfortunately, the epel (Extra Packages for Enterprise Linux) package he recommended doesn’t run on Fedora 20. You can read my tale of woe, or skip to the .bashrc function that fixed it when I installed only rlwrap.

Attempting it on yum, gave me these errors:

# yum install http://www.mirrorservice.org/sites/dl.fedoraproject.org/pub/epel/6/i386/epel-release-6-8.noarch.rpm
Loaded plugins: langpacks, refresh-packagekit
epel-release-6-8.noarch.rpm                                 |  14 kB  00:00     
Examining /var/tmp/yum-root-5CLTPa/epel-release-6-8.noarch.rpm: epel-release-6-8.noarch
Marking /var/tmp/yum-root-5CLTPa/epel-release-6-8.noarch.rpm to be installed
Resolving Dependencies
--> Running transaction check
---> Package epel-release.noarch 0:6-8 will be installed
--> Processing Conflict: epel-release-6-8.noarch conflicts fedora-release
No package matched to upgrade: epel-release
--> Finished Dependency Resolution
Error: epel-release conflicts with fedora-release-20-3.noarch
 You could try using --skip-broken to work around the problem
 You could try running: rpm -Va --nofiles –nodigest

Poking around for an epel fix wasn’t successful, so I chose to install only the rlwrap package. Here’s that command and log file:

[root@localhost ~]# yum install rlwrap 
Loaded plugins: langpacks, protectbase, refresh-packagekit
0 packages excluded due to repository protections
Resolving Dependencies
--> Running transaction check
---> Package rlwrap.x86_64 0:0.41-1.fc20 will be installed
--> Finished Dependency Resolution
 
Dependencies Resolved
 
================================================================================
 Package         Arch            Version                 Repository        Size
================================================================================
Installing:
 rlwrap          x86_64          0.41-1.fc20             updates           95 k
 
Transaction Summary
================================================================================
Install  1 Package
 
Total download size: 95 k
Installed size: 204 k
Is this ok [y/d/N]: y
Downloading packages:
rlwrap-0.41-1.fc20.x86_64.rpm                               |  95 kB  00:00     
Running transaction check
Running transaction test
Transaction test succeeded
Running transaction (shutdown inhibited)
  Installing : rlwrap-0.41-1.fc20.x86_64                                    1/1 
  Verifying  : rlwrap-0.41-1.fc20.x86_64                                    1/1 
 
Installed:
  rlwrap.x86_64 0:0.41-1.fc20                                                   
Complete!

The next step was getting it to work. A sqlplus function wrapper inside the .bashrc file seemed the easiest. Here’s the code to the .bashrc file:

# .bashrc
 
# Source global definitions
if [ -f /etc/bashrc ]; then
	. /etc/bashrc
fi
 
# Uncomment the following line if you don't like systemctl's auto-paging feature:
# export SYSTEMD_PAGER=
 
# User specific aliases and functions
. /u01/app/oracle/product/11.2.0/xe/bin/oracle_env.sh
 
# Wrap sqlplus with rlwrap to edit prior lines.
sqlplus()
{
  if [ "$RLWRAP" = "0" ]; then
    sqlplus "$@"
  else
    rlwrap sqlplus "$@"
  fi
}
 
# Set vi as a command line editor.
set -o vi

As always, I hope this helps some folks.

Written by maclochlainn

August 20th, 2014 at 6:58 pm

Hiding a Java Source

with one comment

The ability to deploy Java inside the Oracle database led somebody to conclude that the source isn’t visible in the data catalog. Then, that person found that they were wrong because the Java source is visible when you use a DDL command to CREATE, REPLACE, and COMPILE the Java source. This post discloses how to find the Java source and how to prevent it from being stored in the data catalog.

You can verify that the Java class and source files exist with the following query:

1
2
3
4
5
6
7
8
COLUMN object_name FORMAT A20 HEADING "Object Name"
COLUMN object_type FORMAT A12 HEADING "Object Type"
COLUMN status      FORMAT A14 HEADING "Object Status"
SELECT   object_name
,        object_type
,        status
FROM     user_objects
WHERE    object_name = 'ReadFile';

It displays:

Object Name          Object Type  Object Status
-------------------- ------------ --------------
ReadFile             JAVA SOURCE  VALID
ReadFile             JAVA CLASS   VALID
 
2 rows selected.

Then, you can use the following query to discovery a Java library created by a SQL command:

1
2
3
4
5
6
COLUMN line FORMAT 9999 HEADING "Line|#"
COLUMN text FORMAT A66  HEADING "Text"
SELECT   line
,        text
FROM     user_source
WHERE    name = 'ReadFile';

It displays the following:

 Line # Text
------- ------------------------------------------------------------------
    1   // Java library imports.
    2   import java.io.File;
    3   import java.io.BufferedReader;
    4   import java.io.FileNotFoundException;
    5   import java.io.IOException;
    6   import java.io.FileReader;
    7   import java.security.AccessControlException;
    8
    9   // Class definition.
   10   public class ReadFile {
   11     // Define class variables.
   12     private static File file;
   13     private static FileReader inTextFile;
   14     private static BufferedReader inTextReader;
   15     private static StringBuffer output = new StringBuffer();
   16     private static String outLine, outText;
   17
   18     // Define readText() method.
   19     public static String readText(String fromFile)
   20       throws AccessControlException, IOException {
   21       // Read file.
   22       try {
   23         // Initialize File.
   24         file = new File(fromFile);
   25
   26         // Check for valid file.
   27         if (file.exists()) {
   28
   29           // Assign file to a stream.
   30           inTextFile = new FileReader(file);
   31           inTextReader = new BufferedReader(inTextFile);
   32
   33           // Read character-by-character.
   34           while ((outLine = inTextReader.readLine()) != null) {
   35             output.append(outLine + "\n"); }
   36
   37           // Assing the StringBuffer to a String.
   38           outText = Integer.toString(output.toString().length());
   39
   40           // Close File.
   41           inTextFile.close(); }
   42         else {
   43           outText = new String("Empty"); }}
   44       catch (IOException e) {
   45         outText = new String("");
   46         return outText; }
   47     return outText; }}
 
47 rows selected.

You can eliminate the source by compiling the Java library outside the database. Then, you use the loadjava utility to load the only the class file into the data catalog. The syntax would be the following command for an importer user in a video Pluggable Database (PDB):

loadjava -r -f -o -user importer/importer@video ReadFile.class

You should know that this syntax is disallowed by the loadjava utility, notwithstanding it’s found in the Oracle Database 12c documentation:

loadjava -r -f -o -user importer@video/importer ReadFile.class

You can verify that only the Java class file exists with the following query:

1
2
3
4
5
6
7
8
COLUMN object_name FORMAT A20 HEADING "Object Name"
COLUMN object_type FORMAT A12 HEADING "Object Type"
COLUMN status      FORMAT A14 HEADING "Object Status"
SELECT   object_name
,        object_type
,        status
FROM     user_objects
WHERE    object_name = 'ReadFile';

It displays:

Object Name          Object Type  Object Status
-------------------- ------------ --------------
ReadFile             JAVA CLASS   VALID
 
1 row selected.

Hope this helps those who want to hide the Java source files.

Written by maclochlainn

July 22nd, 2014 at 10:23 pm

External Table Access

without comments

I left to chance where students would attempt to place their external files in a Linux or Unix implementation. As frequently occurs, they choose a location in their student user’s home directory. Any attempt to read an external table based on a file in this type of directory fails because it’s not accessible by the Oracle user because the directory within the student user’s account isn’t reachable. You can’t simply chown a directory and the files in a directory.

The failure returns the following result:

SELECT COUNT(*) FROM transaction_upload
*
ERROR AT line 1:
ORA-29913: error IN executing ODCIEXTTABLEOPEN callout
ORA-29400: data cartridge error
error opening FILE /home/student/upload/transaction_upload.LOG

The reason isn’t readily visible to all, but a virtual directory must reference a physical directory owned by the oracle user and dba group. That also means the oracle user must own all directories from the logical mount point to the physical directory name.

Assuming you’re working in an Oracle Database 11g XE instance, you can create a valid upload directory by navigating to this directory:

/u01/app/oracle

Then, issue this command as the root user to create a new upload directory:

mkdir upload

Now you have the following directory:

/u01/app/oracle/upload

Assuming you’ve created the upload directory as the root user, the root user should issue the following two commands from the /u01/app/oracle directory:

chown -R oracle:dba upload
chmod -R 755 upload

Having made that change you should now be able to query the external file source, like a *.csv (comma-separated values) file. Hope this helps those trying to use external tables, which I subsequently wrote about for Toad World – External Tables.

Written by maclochlainn

June 19th, 2014 at 1:39 am

Sequence disallows order by

without comments

A call to a PRICE_S1 sequence in a query with an ORDER BY clause is disallowed, which typically occurs in an INSERT statement. Any attempt raises the following exception:

SELECT   price_s1.NEXTVAL AS price_id
                  *
ERROR AT line 1:
ORA-02287: SEQUENCE NUMBER NOT allowed here

You need to remove the ORDER BY clause to eliminate the error.

Written by maclochlainn

June 15th, 2014 at 6:20 pm

SQL Insert from Query

with 5 comments

Sometimes my students find new errors that I’ve never seen. One student did that this week by including an ORDER BY clause in a subquery that feeds an INSERT statement. It raises an ORA-00907 exception, like:

ORA-00907: missing right parenthesis

You can’t include a subquery with an ORDER BY clause because it generates an error. The reason is simple. A subquery can’t perform a sort operation inside a subquery. Here’s a quick demonstration:

DROP TABLE destination;
CREATE TABLE destination
( destination_id    NUMBER
, destination_name  VARCHAR2(20));
 
INSERT INTO destination
(
  SELECT   1,'Sample1' FROM dual
  UNION ALL
  SELECT   2,'Sample2' FROM dual
  ORDER BY 1 DESC
);

If you remove the ORDER BY clause, the statement works without a problem. For example, here’s the working version:

INSERT INTO destination
(
  SELECT   1,'Sample1' FROM dual
  UNION ALL
  SELECT   2,'Sample2' FROM dual
);

Alternatively, you can include an ORDER BY clause when you remove the parentheses from around the subquery. This is an example:

INSERT INTO destination
  SELECT   1,'Sample1' FROM dual
  UNION ALL
  SELECT   2,'Sample2' FROM dual
  ORDER BY 1 DESC;

I hope this helps anybody who runs into the problem.

Written by maclochlainn

June 14th, 2014 at 10:40 pm

Free Oracle NoSQL Book

with 9 comments

It’s seldom that Oracle makes an effort to give an Oracle Press book away for free, but they’ve done it. You can download the Getting Started with Oracle NoSQL Database book from Oracle Press for free.

Getting Started with Oracle NoSQL Database

OracleNoSQL

  1. Overview of Oracle NoSQL Database and Big Data
  2. Introducing Oracle NoSQL Database
  3. Oracle NoSQL Database Architecture
  4. Oracle NoSQL Database Installation and Configuration
  5. Getting Started with Oracle NoSQL Database Development
  6. Reading and Writing Data
  7. Advanced Programming Concepts: Avro Schemas and Bindings
  8. Capacity Planning and Sizing
  9. Advanced Topics

Just so you know, knowledge of Java and Hadoop are helpful. It’s a short 71 pages but a nice heads up and here’s what you do starter book.

If you’re opening in iBooks on an iPad, make sure you let the whole book download first as a PDF file. You may only get a partial PDF file when you don’t let it download completely to your browser. It isn’t the speediest download, notwithstanding its small size.

Written by maclochlainn

May 31st, 2014 at 9:34 am