Skip to main content

SQL on MongoDB using Teiid - Part 2

In the previous article SQL on MongoDB using Teiid - Part 1 I showed a simple example how one can start using SQL based queries on MongoDB using Teiid. I have showed how to install and configure the Teiid and test.

The previous example was very simple that generated a MongoDB collection for defined relational table in Teiid. One of many advantages of NoSQL based stores like MongoDB is, user's ability to de-normalize data such that data for related entities is co-located. When the data is co-located there is no requirement for defining the relationships across entities, and queries will be naturally faster to execute. However, in relational databases data is more often very normalized, the naive implementation of relational to MongoDB where one table is mapped to a collection will result in very poorly performing queries. The solution is, utilize the MongoDB's nested document feature to represent a relationships in Relational database.

In this article, I will show how to define relationships across different tables and it's representation in MongoDB document, where the performance is not compromised.

ONE-2-ONE

 CREATE FOREIGN TABLE Customer (  
   CustomerId integer PRIMARY KEY,  
   FirstName varchar(25),  
   LastName varchar(25)  
 ) OPTIONS(UPDATABLE 'TRUE');  

 CREATE FOREIGN TABLE Address (  
   CustomerId integer,  
   Street varchar(50),  
   City varchar(25),  
   State varchar(25),  
   Zipcode varchar(6),  
   FOREIGN KEY (CustomerId) REFERENCES Customer (CustomerId)  
 ) OPTIONS(UPDATABLE 'TRUE');  

When you issue INSERT statements against above tables, by default it will produce the documents like

 Customer  
 {  
  _id: 1,  
  FirstName: "John",  
  LastName: "Doe"  
 }  
 Address  
 {   
  _id: ObjectID("..."),   
   CustomerId: 1,  
   Street: "123 Lane"  
   City: "New York",  
   State: "NY"  
   Zipcode: "12345"  
 }  

You can enhance the storage in MongoDB to a single collection by using "teiid_mongo:MERGE' extension property on the table's OPTIONS clause


 CREATE FOREIGN TABLE Customer (  
   CustomerId integer PRIMARY KEY,  
   FirstName varchar(25),  
   LastName varchar(25)  
 ) OPTIONS(UPDATABLE 'TRUE');  

 CREATE FOREIGN TABLE Address (  
   CustomerId integer PRIMARY KEY,  
   Street varchar(50),  
   City varchar(25),  
   State varchar(25),  
   Zipcode varchar(6),  
   FOREIGN KEY (CustomerId) REFERENCES Customer (CustomerId)  
  ) OPTIONS(UPDATABLE 'TRUE', "teiid_mongo:MERGE" 'Customer');  

this will produce single collection in MongoDB
 Customer  
 {  
  _id: 1,  
  FirstName: "John",  
  LastName: "Doe",  
  Address:   
    {   
     Street: "123 Lane",  
     City: "New York",  
     State: "NY",  
     Zipcode: "12345"  
    }  
 }  

You can issue queries like

 SELECT * FROM Customer JOIN Address ON Customer.CustomerId = Address.CustomerId  

ONE-2-MANY

Following the similar strategy using "teiid_mongo:MERGE" property, the below shows the one to many relationship  .


 CREATE FOREIGN TABLE Customer (  
   CustomerId integer PRIMARY KEY,  
   FirstName varchar(25),  
   LastName varchar(25)  
 ) OPTIONS(UPDATABLE 'TRUE');  

 CREATE FOREIGN TABLE Order (      
   OrderID integer PRIMARY KEY,  
   CustomerId integer,  
   OrderDate date,  
   Status integer,  
   FOREIGN KEY (CustomerId) REFERENCES Customer (CustomerId)  
 ) OPTIONS(UPDATABLE 'TRUE', "teiid_mongo:MERGE" 'Customer');  

Will generate MongoDB collection like below

 {  
  _id: 1,  
  FirstName: "John",  
  LastName: "Doe",  
  Order:   
  [  
    {   
     _id: 100,   
     OrderDate: ISODate("2000-01-01T06:00:00Z")  
     Status: 2  
    },  
    {   
     _id: 101,   
     OrderDate: ISODate("2001-03-06T06:00:00Z")  
     Status: 5  
    }  
    ...  
   ]  
 }  

You can issue SQL queries like

SELECT * FROM Customer JOIN Orders ON Customer.CustomerId = Orders.CustomerId 
  WHERE OrderDate = <date>  

Note that above I showed the nesting of the documents at single level, however you can define even define deeper nesting. For example, Order table has OrderItems table

  CREATE FOREIGN TABLE Customer (   
   CustomerId integer PRIMARY KEY,   
   FirstName varchar(25),   
   LastName varchar(25)   
  ) OPTIONS(UPDATABLE 'TRUE');  
 
  CREATE FOREIGN TABLE Order (     
   OrderID integer PRIMARY KEY,   
   CustomerId integer,   
   OrderDate date,   
   Status integer,   
   FOREIGN KEY (CustomerId) REFERENCES Customer (CustomerId)   
  ) OPTIONS(UPDATABLE 'TRUE', "teiid_mongo:MERGE" 'Customer'); 
  
 CREATE FOREIGN TABLE OrderDetails (  
  OrderID integer NOT NULL,  
  UnitPrice double default '0',  
  Quantity integer default '1',  
  Discount float default '0',  
  FOREIGN KEY (OrderID) REFERENCES Orders (OrderID),  
 ) OPTIONS ("teiid_mongo:MERGE" 'Orders', UPDATABLE 'TRUE');  

after inserting some data, the result MongoDB document will look like

 {  
  _id: 1,  
  FirstName: "John",  
  LastName: "Doe",  
  Order:   
  [  
    {   
     _id: 100,   
     OrderDate: ISODate("2000-01-01T06:00:00Z")  
     Status: 2,  
     OrderDetails:  
     [  
       {  
         UnitPrice: 23.12  
         Quantity: 5  
         Discount: 34.2  
       },  
       {  
         UnitPrice: 51.17  
         Quantity: 10  
         Discount: 15.0  
       }  
       ...  
     ]  
    },  
    {   
     _id: 101,   
     OrderDate: ISODate("2001-03-06T06:00:00Z")  
     Status: 5,  
     OrderDetails:  
     [  
       {  
         UnitPrice: 78.00  
         Quantity: 4  
         Discount: 20  
       },  
       {  
         UnitPrice: 43.12  
         Quantity: 100  
         Discount: 30  
       }  
       ...  
     ]      
    }  
    ...  
   ]  
 }  

So, as you can see you can create pretty complex nested documents in MongoDB using Teiid, to save query performance, at the same time you can use your expertise in SQL to design the queries using the JOINS to  read the data that you are interested in or run BI tool on top it to generate reports etc.

For more information please read https://docs.jboss.org/author/display/TEIID/MongoDB+Translator 

If you are working with existing MongoDB database, Teiid can import the existing collections and their document structure and automatically create the relational tables in Teiid. For that please refer to article https://developer.jboss.org/wiki/ConnectToAMongoDBSource

I have showed in these articles how to create and use MongoDB database and access the MongoDB using SQL. This is great tool, if you looking to replace your relational database like Oracle, SQLServer etc with MongoDB. Most of the concepts in your relational world map one to one using Teiid.

Thank you, If you have any questions please let us know.

Ramesh..

Comments

Popular posts from this blog

Teiid 8.11 Beta1 and 8.10.1 Released

Teiid 8.11 Beta1 is now available from the  downloads  and maven.  Feature highlights since Alpha2 include: TEIID-3434 More caching control over ttls in the result set cache down to the schema/table level. TEIID-3412 MS Access support via the UCanAccess driver. The UCanAccess support is necessary for those running on Java 1.8 as the JDBC ODBC bridge has been removed from the JRE. The waiting continues on EAP 6.4 Alpha1 - it still should be available shortly and should be the platform target for Teiid 8.11 Beta2. Of course, let us know if you find any issues with these early releases.  There's still plenty of time to get fixes into the final release. Teiid 8.10.1 is also available.  It addresses 5 important issues discovered since 8.10 was released: [ TEIID-3409 ] - PostgreSQLExecutionFactory TranslatorProperty annotation in wrong place [ TEIID-3437 ] - Inconsistencies with row count handling [ TEIID-3438 ] - Null value returned from BlobImpl

Tech Tip: Teiid SQL Language MAKEDEP Hint Explained

In this article I will explain what a MAKEDEP hint is, how and when, why it should be used in Teiid. What: MAKEDEP is query hint.  When a query hint is defined in the SQL query it influences the Teiid query planner to optimize the query in a way that is driven by the user. MAKEDEP means "make this as a dependent join". What is a Dependent Join? For example if we have query like: SELECT * FROM X INNER JOIN Y ON X.PK = Y.FK Where the data for X, and Y are coming from two different sources like Oracle and WebService in Teiid, so in relational algebra you can represent above query as Here the result tuples from node X and node Y are being simultaneously fetched by Teiid query engine, then it joins the both the results inside Teiid engine based on the specified X.PK = Y.PK condition and returns the filtered resulted to the user. simple.. Now, what if, if X table has 5 rows and Y table has 100K rows? In order to do the JOIN naively Teiid need sto read all the 5

Teiid Spring Boot 1.7.0 Released

Teiid Spring Boot version 1.7.0 to support Teiid 16.0 has been released. This release is mainly to support the Teiid's latest version.  In this release, the support for OpenAPI code generation based on VDB has been removed as there is no community interest and moreover it was at OpenAPI 2.0, and the industry has moved to 3.0 and beyond. There are no plans to further pursue this feature. VDB maven plugin was also removed, which was intended to be a replacement for the VDB importing feature was to be used when working on OpenShift, however, since it requires the Maven repository and does not completely represent the feature as defined on the WildFly based deployments this is also removed. You can still use the VDB import feature with Teiid Spring Boot, simply define the VDB with your "IMPORT DATABASE" statements and provide the additional files along with the main VDB file. During the start of the application, Teiid Spring Boot will load all the necessary DDL files for the