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 Platform Sizing Guidelines and Limitations

Users/customers always ask us about the sizing of their Data Virtaulization infrastructure based on Teiid or the JDV product from Redhat. Typically this is very involved question and not a very easy one answer in plain terms. This is due to fact that it involves taking into consideration questions like:
What kind of sources that user is working with? Relational, file, CRM, NoSQL etc.How many sources they are trying to integrate? 10, 20, 100?What are the volumes of data they are working with? 10K, 100K, 1M+?What are the query latency times from the sources? How you are using Teiid to implement the data integration/virtualization solution. What kind of queries that user is executing? Even small federated results may take a lot of server side processing - especially if the plan needs tweaking.Is materializing being used?Is query written in optimal way?and so on..Each and every one of the question affects the performance profoundly, and if you got mixture of those then it become that much…

Teiid Runtimes Explained

If you have been following Teiid lately we have been going through a whole lot of renovations. Yes, renovations or reorganization or refactoring or whatever you want to call it. Basically, we are making Teiid more modular with fewer dependencies that can be used by however your use case dictates rather than use it as one monolith application deployed into WildFly JEE Application Server. There is nothing wrong in using Teiid as server model, but with the proliferation of container-based workloads and cloud-based architectures, the previous server-based model does not work or simply won't scale. So, we needed to think of alternatives, thus Teiid team introduced a couple different versions modular Teiid what we are calling as "Teiid Runtimes".

Note that in these modular Teiid runtimes, not all the features you were used to using in Teiid Server model may not be there but you will have extensions to add in those that are most appropriate for your domain. If you are looking …