Exploring Unnest in Druid

May 30, 2023
Soumyava Das

Motivation

Many use cases require “flattening” records. The need for this is exemplified in the existence of array-type columns. Such columns occur whenever an array of objects is ingested as a single column. Real-world examples of this range from items purchased in a grocery store to a list of countries visited by a person or even a chain of activities done on a web page by a user. Flattening the data out can help in association mining, finding user patterns on a travel site or web page, thereby enabling the system to make real-time (what online item you can buy) or forward- looking recommendations (product placement inside a store).

Now considering there are thousands of places to visit and millions of things to buy online, keeping an array-type column is the generic dense representation of the data (rather than keeping a column for each, leading to sparse representation). Hence there is the requirement to flatten or UNNEST the elements from the arrays to group by and aggregate individual elements to analyze patterns. Druid supports multi-value strings through multi-value dimensions (MVDs), which automatically flattens during a group-by. But Druid also has inherent array typed columns for different data types. Therefore, there’s a need for supporting operations on array-typed columns and a function that takes in an array of objects and emits out a series of rows of individual elements, which can be aggregated later. Moreover, an MVD can inherently be converted into an array-type column using druid functions such as MV_TO_ARRAY.

Other SQL systems have similar capabilities; they expect an ARRAY type of data, and then you put that into an UNNEST operator. Then, they “explode” out one new row for every value in the array.

We implemented a similar function for Druid. For example, take the following table. We’ll call it input throughout the example.

  timedim1dim2dim3m1m2
2000-01-01T00:00: 00.000Zemptya[“a”, “b”]11
2000-01-02T00:00: 00.000Z10.1 [“a”, “b”, “c”, “d”]22
2000-01-03T00:00: 00.000Z2 [“e”, “f”]33

UNNEST on this dataset is shown below:

1. An UNNEST on a Multi-value string dimension. As UNNEST works on arrays, MV_TO_ARRAY is used to convert an MVD to an ARRAY

2. Druid supports GROUP BY, ORDER BY, etc. on the unnested column

3. Additionally Druid supports filters on the unnested column

4. Assuming a hypothetical function that creates an array of timestamps, UNNEST can also be used on that array column to create new time cols

Execution Strategy

The UNNEST operation is well-suited for distributed processing. In Druid, rows are already divided into segments so that the operation can be done at the segment level to UNNEST one column in a row. Also unlike joins, a segment does not need any additional data (such as the broadcast table, lookup table, or another table). The information for unnesting a column for a row is just the column name to be unnested and a new column name if the user wants to output the unnested value to a new column.

UNNEST, overall, is a function over an existing table. This function takes an existing table and a column name to UNNEST and explodes each row of the column into rows with individual array elements in the original row. The approach taken by Druid is to push this operation to the individual segments of the table (or data source), and each segment can UNNEST rows in a distributed way. Conceptually, UNNEST is modeled as a data source on top of the existing data source through the use of a transformation.

To apply a transformation on a data source, Druid uses the concept of a segment map function where an existing segment of the base data source can be mapped to another segment following a mapping function. The concept of a segment map function is already baked into Druid during the join data source creation. We build on the existing architecture by defining a segment map function for the UNNEST case.

Imperatively, we model UNNEST as a data source. Since UNNEST is an abstraction of a data source over an existing data source, it requires the following elements:

  1. A base data source (base)
  2. The dimension to be unnested (column)
  3. The output name of the column where the unnested values should be added (output name)

Native Query

The underlying principle here is an operation on a data source that works on a segment and creates additional rows. Joins have a similar principle where the number of rows can be more than the input table after the join operation. The current framework supports that in the following ways:

  1. Having a join data source alongside a factory and then a specialized wrapper (JoinableFactoryWrapper.java ) around it creates a function to transform one segment into another by the notion of a segment function.
  2. Having a separate implementation of segment reference through HashJoinSegment.java, which uses a custom storage adapter to access a cursor to the segment for processing.

The goal is to move out the creation of the segment map function from outside the wrapper to individual data sources. In cases where the segment map function is not an identity function (like for join and also for UNNEST), the segment functions can be created accordingly for each data source. This makes the abstraction generic and readily extendable to other data sources we might create in the future.

https://github.com/apache/druid/pull/13085 completes this refactoring part.

UNNEST data source

We now have an UnnestDataSource class that deals with UNNEST, and UnnestDataSource.java is the implementation. The UNNEST data source has two parts:

DataSource base;
VirtualColumn virtualColumn;

The base data source is the one that gets unnested. It can be a table, query, join, or even an UNNEST data source.

The virtual column has the information about which column needs to be unnested and the column reference to be unnested. It supports either a single dimension

"virtualColumn": {
  "type": "expression", 
  "name": "j0.UNNEST",
  "expression": "\"dim3\"", 
  "outputType": "STRING"
}

or a virtual column

"virtualColumn": {
  "type": "expression", 
  "name": "j0.UNNEST",
  "expression": "array(\"dim4\",\"dim5\")", 
  "outputType": "ARRAY<STRING>"
}

The name of the column that gets unnested appears in the expression field while the output column name is internally delegated as j0.UNNEST.

UNNEST Storage Adapters

We use a separate storage adapter for UNNEST, which takes care of creating cursors on the data source. Cursors are responsible for traversing over rows in a segment. The most recent implementation can be found at UnnestStorageAdapter.java. This adapter does the following:

  1. Create the pre and post-filters on the UNNEST data source. All the filters specified on the query, which can be applied to any column on the base data source, constitute the pre-UNNEST filters. The others are the post-UNNEST filters. If UNNEST is used on a single column and not on a virtual column, that particular filter is also rewritten to the pre-UNNEST filter to reduce the amount of data UNNEST has to work with. The pre-UNNEST filters are passed on to the base data source cursor to reduce the number of rows sent to UNNEST.
  2. Typically, string-based columns in Druid are dictionary encoded. The storage adapter, depending on the type of column being unnested, creates two different UNNEST cursors. One DimensionCursor takes advantage of the dictionary encoding to iterate over data while the ColumnarCursor addresses the rest.
  3. These cursors are wrapped in the end with a PostJoinCursor, which takes in the post-UNNEST filter to filter out the appropriate rows needed in the query result.

UNNEST Cursors

The cursor of the base table gives a pointer to iterate over each row in a segment. On each call of advance(), the cursor jumps to the next row and the method isDone() is set to true when the cursor cannot advance any more, indicating the end of a segment. We need to define an additional cursor that, when advanced, goes over the next element of the array column, and the base cursor is advanced only when the end of the array is reached. There are two implementations of cursors, one for dictionary-encoded columns and the other for regular columns. To give a simple example, consider the table

  timedim1dim3
2000-01-01T00:00:00.000Z1[“a”, “b”]
2000-01-02T00:00:00.000Z2[“c”, “d”, “x”]
2000-01-03T00:00:00.000Z3[“e”, “f”]

The base cursor is pointed to the first row at the start of the array. An UnnestCursor.advance() follows the operations described in the table below:

OperationBaseCursorUnnestCursorComment
advance()Points to start of row 1a 
advance()Points to start of row 1b 
advance()Points to start of row 2cThis advance call moved the base cursor as the end of the array on row 1 was reached
advance()Points to start of row 2d 
advance()Points to start of row 2x 
advance()Points to start of row 3eThis advance call moved the base cursor as the end of the array on row 2 was reached
advance()Points to start of row 3f 
advance()cannot advancecannot advanceThis advance call moved the base cursor as the end of the array on row 3 was reached. The baseCursor moved to a done state and so did the UNNEST cursor

Post Join Cursor

The previous case shows a regular UNNEST without any filters. The storage adapter wraps UNNEST cursor is wrapped in a post-join cursor which at the time of advance uses the value matcher of the filter to keep moving the cursor till the next match. Consider a filter like where unnested_column_over_dim IN (‘a’, ‘d’). That UNNEST operation proceeds like this:

OperationBaseCursorUnnestCursorComment
advance()Points to start of row 1a 
advance()Points to start of row 2dThe cursor was moved to the next matching value and the base cursor was also advanced as the end of the first array was reached in the process
advance()cannot advancecannot advanceThe baseCursor moved to a done state as no more rows were left to be served and so did the UNNEST cursor.

Note that the row [e,f] was never received because of the following reasons:

  • Druid figured out that the post-UNNEST filter references a single column in the input table
  • The filter was rewritten on the dimension to be unnested and passed to the base cursor
  • Only the filtered row appeared to be unnested. In an array-typed column, if there is a single match, the entire row is returned by Druid. In this case, the rows returned by the base cursor are rows 1 and 2, so the post-UNNEST filter filters out the rest.

https://github.com/apache/druid/pull/13554 has the native unit tests while the native unnest query is done by https://github.com/apache/druid/pull/13268

SQL Binding

Druid uses Apache Calcite for planning SQL queries. The logical plan generated by Calcite is governed by rules developed by Druid to cater to the underlying native queries. We need 3 things to generate the SQL binding:

  1. The query syntax
  2. The rules to support the new syntax
  3. Appropriate Druid-specific relations to convert to the native query from the logical plan

Query Syntax

We thought about the following when designing the query syntax:

  1. An easy-to-understand syntax from the users’ perspective for UNNEST that’s similar to other databases for ease of use
  2. The ability to UNNEST multiple columns in the same table
  3. The ability to pass the output of UNNEST to another operation and setup chaining

Apache Beam and BigQuery use the concept of a lateral join or cross join for defining UNNEST. We follow a similar pattern for defining the query syntax for UNNEST. Our query takes the form:

select * from table,UNNEST(expression) as table_alias(column_alias)

This is similar to a cross-join (or correlation between the left data source (here table on the left) and the unnested expression on the table which is referenced as a table with a single column using the alias. The expression can be the dimension name for an array-typed column, a virtual expression, or even the Druid MVD column translated into an array. Here are some example queries:

SELECT dim1,dim2,foo.d45 FROM "numFoo", UNNEST(ARRAY["dim4", "dim5"]) as foo(d45)
SELECT * FROM "numFoo", UNNEST(MV_TO_ARRAY(dim3)) as bar(d3)
SELECT dim1, dim2, ud.d2 FROM "numFoo", UNNEST(dim2) as ud(d2)

A user can also UNNEST on a constant row like so:

select ud.d from UNNEST(ARRAY[1,2,3]) as ud(d)

Planning Rules

Planning these queries, however, faces some problems since some weren’t in place in Druid. A very simple UNNEST on an array from Calcite’s perspective generates the following logical plan:

 SELECT * FROM UNNEST(ARRAY['1','2','3'])
 
 Generates the plan

25:Uncollect
  23:LogicalProject(subset=[rel#24:Subset#1.NONE.[]], EXPR$0=[ARRAY('1', '2', '3')])
    4:LogicalValues(subset=[rel#22:Subset#0.NONE.[0]], tuples=[[{ 0 }]])

While unnesting a single column and multiple columns leads to the plans

SELECT * FROM druid.numfoo, UNNEST(MV_TO_ARRAY(dim3))

Generates

80:LogicalCorrelate(correlation=[$cor0], joinType=[inner], requiredColumns=[{3}])
  6:LogicalTableScan(subset=[rel#74:Subset#0.NONE.[]], table=[[druid, numfoo]])
  78:Uncollect(subset=[rel#79:Subset#3.NONE.[]])
    76:LogicalProject(subset=[rel#77:Subset#2.NONE.[]], EXPR$0=[MV_TO_ARRAY($cor0.dim3)])
      7:LogicalValues(subset=[rel#75:Subset#1.NONE.[0]], tuples=[[{ 0 }]])

for UNNEST of UNNEST

SELECT * FROM druid.numfoo, UNNEST(MV_TO_ARRAY(dim3)), UNNEST(MV_TO_ARRAY(dim3))

Generates

138:LogicalCorrelate(correlation=[$cor1], joinType=[inner], requiredColumns=[{3}])
  132:LogicalCorrelate(subset=[rel#133:Subset#4.NONE.[]], correlation=[$cor0], joinType=[inner], requiredColumns=[{3}])
    10:LogicalTableScan(subset=[rel#126:Subset#0.NONE.[]], table=[[druid, numfoo]])
    130:Uncollect(subset=[rel#131:Subset#3.NONE.[]])
      128:LogicalProject(subset=[rel#129:Subset#2.NONE.[]], EXPR$0=[MV_TO_ARRAY($cor0.dim3)])
        11:LogicalValues(subset=[rel#127:Subset#1.NONE.[0]], tuples=[[{ 0 }]])
  136:Uncollect(subset=[rel#137:Subset#6.NONE.[]])
    134:LogicalProject(subset=[rel#135:Subset#5.NONE.[]], EXPR$0=[MV_TO_ARRAY($cor1.dim3)])
      11:LogicalValues(subset=[rel#127:Subset#1.NONE.[0]], tuples=[[{ 0 }]])

There is a common pattern seen during Uncollect (Uncollect (Apache Calcite API) ), which is basically what we needed for the UNNEST operation in Druid. The pattern is

(operand 
  (Uncollect.class, 
    operand(Project.class, 
    operand(Values.class, none()))
  )
)

This forms the first rule that we create: DruidUnnestRule.java. In this rule, we check if the data source is a constant expression or not. If we find an inline data source, we model this as a scan over an InlineDataSource. Otherwise, we transform the pattern to create a DruidUnnestRel. The picture below captures how the rule works

The second rule that we introduced is based on the pattern of

operand(
  Correlate.class, 
  operand(DruidRel.class, any()), 
  operand(DruidUnnestRel.class, any())
)

This works on the output of the DruidUnnestRule and transforms a correlate with the left child as a base data source and the right child as a DruidUnnestRel to a single DruidCorrelateUnnestRel. These two rules form the basis of the UNNEST operation done by Druid. Here’s a visual representation of the rule:

Finally, we can have filters either on top of the left data source or the right. The logical plan while using filters is shown below:

SELECT d3 FROM druid.numfoo, UNNEST(MV_TO_ARRAY(dim3)) as unnested (d3) where d3 IN ('a','b') and m1 < 10

138:LogicalProject(d3=[$17])
  136:LogicalCorrelate(subset=[rel#137:Subset#7.NONE.[]], correlation=[$cor0], joinType=[inner], requiredColumns=[{3}])
    125:LogicalFilter(subset=[rel#126:Subset#1.NONE.[]], condition=[<($14, 10)])
      8:LogicalTableScan(subset=[rel#124:Subset#0.NONE.[]], table=[[druid, numfoo]])
    132:LogicalFilter(subset=[rel#133:Subset#5.NONE.[]], condition=[OR(=($0, 'a'), =($0, 'b'))])
      130:Uncollect(subset=[rel#131:Subset#4.NONE.[]])
        128:LogicalProject(subset=[rel#129:Subset#3.NONE.[]], EXPR$0=[MV_TO_ARRAY($cor0.dim3)])
          9:LogicalValues(subset=[rel#127:Subset#2.NONE.[0]], tuples=[[{ 0 }]])

The filters on the left are brought to the top of uncollect with the following rule:

operand(
  Correlate.class, 
  operand(Filter.class, any()), 
  operand(RelNode.class, any())
)
  • Calcite puts any filter on the unnested column already on the right side. The filter is not brought on top of the correlate and is stored inside the corresponding rel node for uncollect. This is done through DruidFilterUnnestRule.java
operand(
  Filter.class, 
  operand(DruidUnnestRel.class, any())
)

Equipped with these specific rules for Unnest and an additional ProjectCorrelateTransposeRule from Calcite, we form the basis of the SQL binding for UNNEST.

if (plannerContext.featureAvailable(EngineFeature.UNNEST)) {
      retVal.add(new DruidUnnestRule(plannerContext));
      retVal.add(new DruidCorrelateUnnestRule(plannerContext));
      retVal.add(ProjectCorrelateTransposeRule.INSTANCE);
      retVal.add(CorrelateFilterLTransposeRule.instance());
      retVal.add(DruidFilterUnnestRule.instance());
    }

Currently, UNNEST is a beta feature and is behind a context parameter on the SQL side. The context can be set through QueryContext as

{
  "enableUnnest": true
}

Supporting Filters

UNNEST supports filters on any column. Filters on the query if applicable on the left data source are pushed into the input data source while filters on the unnested column are pushed onto the PostJoinCursor. For example

1. If there is an AND filter between a column on the input table and the unnested column

select * from foo, UNNEST(dim3) as u(d3) where d3 IN (a,b) and m1 < 10

Filters pushed down to the left data source: dim3 IN (a,b) AND m1 < 10
Filters pushed down to the PostJoinCursor: d3 IN (a,b)

2. If we are unnesting on a virtual column involving multiple columns, the filter cannot be pushed into the left data source and appears only on the PostJoinCursor.

select * from foo, UNNEST(ARRAY[dim1,dim2]) as u(d12) where d12 IN (a,b) and m1 < 10

Filters pushed down to the left data source: m1 < 10 (as unnest is on a virtual column it cannot be added to the pre-filter)
Filters pushed down to the PostJoinCursor: d12 IN (a,b)

3. If there is an OR filter involving unnested and regular columns, they are transformed first using the regular column to be pushed into the left data source while the entire filter now appears on the PostJoinCursor.

select * from foo, UNNEST(dim3) as u(d3) where d3 IN (a,b) or m1 < 10

Filters pushed down to the left data source: dim3 IN (a,b) or m1 < 10
Filters pushed down to the PostJoinCursor: d3 IN (a,b) or m1 < 10

4. If there is an OR filter using a virtual column on multiple input columns, the filter cannot be rewritten and pushed to the input data source and the entire filter appears on the PostJoinCursor

select * from foo, UNNEST(ARRAY[dim1,dim2]) as u(d12) where d12 IN (a,b) or m1 < 10

Filters pushed down to the left data source: None
Filters pushed down to the PostJoinCursor: d12 IN (a,b) or m1 < 10

Sum of parts

With the entire process, we can now write UNNEST queries in Druid. Here is an example spec to ingest data

{
  "type": "index_parallel",
  "spec": {
    "ioConfig": {
      "type": "index_parallel",
      "inputSource": {
        "type": "inline",
        "data": "{\"t\":\"2000-01-01\",\"m1\":\"1.0\",\"m2\":\"1.0\",\"d1\":1.0,\"f1\":1.0,\"l1\":7,\"dim1\":\"\",\"dim2\":[\"a\"],\"dim3\":[\"a\",\"b\"],\"dim4\":\"a\",\"dim5\":\"aa\"}\n{\"t\":\"2000-01-02\",\"m1\":\"2.0\",\"m2\":\"2.0\",\"d1\":1.7,\"d2\":1.7,\"f1\":0.1,\"f2\":0.1,\"l1\":325323,\"l2\":325323,\"dim1\":\"10.1\",\"dim2\":[],\"dim3\":[\"b\",\"c\"],\"dim4\":\"a\",\"dim5\":\"ab\"}\n{\"t\":\"2000-01-03\",\"m1\":\"3.0\",\"m2\":\"3.0\",\"d1\":0.0,\"d2\":0.0,\"f1\":0.0,\"f2\":0.0,\"l1\":0,\"l2\":0,\"dim1\":\"2\",\"dim2\":[\"\"],\"dim3\":[\"d\"],\"dim4\":\"a\",\"dim5\":\"ba\"}\n{\"t\":\"2001-01-01\",\"m1\":\"4.0\",\"m2\":\"4.0\",\"dim1\":\"1\",\"dim2\":[\"a\"],\"dim3\":[\"\"],\"dim4\":\"b\",\"dim5\":\"ad\"}\n{\"t\":\"2001-01-02\",\"m1\":\"5.0\",\"m2\":\"5.0\",\"dim1\":\"def\",\"dim2\":[\"abc\"],\"dim3\":[],\"dim4\":\"b\",\"dim5\":\"aa\"}\n{\"t\":\"2001-01-03\",\"m1\":\"6.0\",\"m2\":\"6.0\",\"dim1\":\"abc\",\"dim4\":\"b\",\"dim5\":\"ab\"}"
      },
      "inputFormat": {
        "type": "json"
      }
    },
    "tuningConfig": {
      "type": "index_parallel",
      "partitionsSpec": {
        "type": "dynamic"
      }
    },
    "dataSchema": {
      "dataSource": "numFoo",
      "granularitySpec": {
        "type": "uniform",
        "queryGranularity": "NONE",
        "rollup": false,
        "segmentGranularity": "YEAR"
      },
      "timestampSpec": {
        "column": "t",
        "format": "auto"
      },
      "dimensionsSpec": {
        "dimensions": [
          {
            "type": "double",
            "name": "d1"
          },
          {
            "type": "double",
            "name": "d2"
          },
          "dim1",
          "dim2",
          "dim3",
          "dim4",
          "dim5",
          {
            "type": "float",
            "name": "f1"
          },
          {
            "type": "float",
            "name": "f2"
          },
          {
            "type": "long",
            "name": "l1"
          },
          {
            "type": "long",
            "name": "l2"
          }
        ]
      },
      "metricsSpec": [
        {
          "name": "m1",
          "type": "floatSum",
          "fieldName": "m1"
        },
        {
          "name": "m2",
          "type": "doubleSum",
          "fieldName": "m2"
        }
      ]
    }
  }
}

And here are some example queries for UNNEST. We do support multiple levels of unnesting. Give it a try, and let us know how UNNEST helps solve your use case.

-- UNNEST on constant expression
select * from UNNEST(ARRAY[1,2,3]) as ud(d1) where d1 IN ('1','2')

-- UNNEST a single column from left datasource
select dim3,foo.d3 from "numFoo", UNNEST(MV_TO_ARRAY("dim3")) as foo(d3)

-- UNNEST an expression from left datasource
select * from "numFoo", UNNEST(ARRAY["dim4","dim5"]) as foo(d45)

-- UNNEST on a query datasource
select * from (select * from "numFoo" where dim2 IN ('a', 'ab') LIMIT 4), UNNEST(MV_TO_ARRAY("dim3")) as foo(d3)

-- UNNEST on a join datasource
SELECT d3 from (SELECT * from druid.numfoo JOIN (select dim2 as t from druid.numfoo where dim2 IN ('a','b','ab','abc')) ON dim2=t), UNNEST(MV_TO_ARRAY(dim3)) as unnested (d3)
        
-- UNNEST of an UNNEST
select * from "numFoo", UNNEST(MV_TO_ARRAY("dim3")) as ud(d3), UNNEST(ARRAY[dim4,dim5]) as foo(d45)

with t as (select * from "numFoo", UNNEST(MV_TO_ARRAY("dim3")) as ud(d3))
select * from t,UNNEST(ARRAY[dim4,dim5]) as foo(d45)

-- UNNEST with filters
select * from from "numFoo", UNNEST(MV_TO_ARRAY("dim3")) as foo(d3) where m1 <10 and d3 IN ('b','d')
select * from from "numFoo", UNNEST(MV_TO_ARRAY("dim3")) as foo(d3) where d3!='d'
select * from from "numFoo", UNNEST(MV_TO_ARRAY("dim3")) as foo(d3) where d3 > 'b' and d3 < 'e'

Documentation
– SQL : https://docs.imply.io/latest/druid/querying/sql/#unnest
– Native: https://docs.imply.io/latest/druid/querying/datasource/#unnest

Tutorial
https://docs.imply.io/latest/druid/tutorials/tutorial-unnest-arrays/

Acknowledgment

UNNEST was made possible by the team at Imply and I owe a huge shoutout to Eric Tschetter, Gian Merlino, Abhishek Agarwal, Rohan Garg, Paul Rogers, Clint Wylie, Brian Le and Karthik Kasibhatla for helping me bring UNNEST out to the Druid community.

Other blogs you might find interesting

No records found...
Apr 16, 2024

How to Monitor Your IoT Environment in Real Time

As IoT environments become more complex, so too does data grow in volume, variety, and velocity. Learn why, when, and how to monitor your IoT environment.

Learn More
Mar 21, 2024

How GameAnalytics Provides Flexible Data Exploration with Imply

Learn how GameAnalytics, the leading analytics provider for the gaming industry, provides insights on over 100,000 games, 1.75 billion players, and 24 billion monthly sessions.

Learn More
Mar 04, 2024

Smart Devices, Intelligent Insights: How Rivian and Thing-it use Apache Druid for IoT Analytics

Learn how engineers and architects from electric vehicle manufacturer Rivian and smart asset management platform Thing-it use Apache Druid for their IoT analytics environments.

Learn More
Feb 21, 2024

What’s new in Imply Polaris – January 2024

At Imply, we're excited to share the latest enhancements in Imply Polaris, our real-time analytics Database-as-a-Service (DBaaS) powered by Apache Druid®. Our commitment to refining your experience with Polaris...

Learn More
Feb 21, 2024

Introducing Apache Druid 29.0

Apache Druid® is an open-source distributed database designed for real-time analytics at scale. We are excited to announce the release of Apache Druid 29.0. This release contains over 350 commits & 67 contributors.

Learn More
Feb 14, 2024

Apache Druid vs. ClickHouse

If your project needs a real-time analytics database that provides subsecond performance at scale you should consider both Apache Druid and ClickHouse. Find out how to make an informed choice.

Learn More
Jan 23, 2024

Enhancing Data Security with Role-Based Access Control in Druid and Imply

Managing user access to relevant data is a crucial aspect of any data platform. In a typical Role Based Access Control (RBAC) setup, users are assigned roles that determine their access to relevant data. We...

Learn More
Jan 16, 2024

Comparing Data Formats for Analytics: Parquet, Iceberg, and Druid Segments

In this blog, I will give you a detailed overview of each choice. We will cover key features, benefits, defining characteristics, and provide a table comparing the file formats. Dive in and explore the characteristics...

Learn More
Jan 12, 2024

Scheduling batch ingestion with Apache Airflow

This guide is your map to navigating the confluence of Airflow and Druid for smooth batch ingestion. We'll get you started by showing you how to setup Airflow and the Druid Provider and use it to ingest some...

Learn More
Dec 29, 2023

A Buyer’s Guide to OLAP Tools

How do OLAP databases work—and which one is right for you? Read this blog post to learn more about which OLAP solutions are best for different use cases.

Learn More
Dec 26, 2023

What is IoT Analytics?

Because it deals with fast-moving, real-time data, IoT analytics is uniquely challenging. Learn how to overcome these challenges and how to extract (and act on) valuable insights from IoT data.

Learn More
Dec 19, 2023

OLTP and OLAP Databases: How They Differ and Where to Use Them

Learn about the differences between analytical and transactional databases—their strengths and weaknesses, what they’re used for, and which option to choose for your own use case.

Learn More
Dec 15, 2023

Query from deep storage: Introducing a new performance tier in Apache Druid

Now, Druid offers a simpler, cost-effective solution with its new feature, Query from Deep Storage. This feature enables you to query Druid’s deep storage layer directly without having to preload all of your...

Learn More
Dec 15, 2023

How KakaoBank Uses Imply for Financial Analysis

As a mobile-first digital platform, KakaoBank accumulates a substantial amount of data. Therefore, analysts need a solution that can effectively analyze and pre-process large quantities of data, visualize the...

Learn More
Dec 14, 2023

Joins, Multi-Stage Queries, and More: Relive the Excitement of Druid Summit 2023

Druid Summit kicked off its fourth year as a global gathering of minds passionate about real-time analytics and the power of Apache Druid. This year’s event revealed a common theme: the growing significance...

Learn More
Dec 13, 2023

An Introduction to Online Analytical Processing (OLAP)

Online analytical processing (OLAP) analyzes data at scale—and provides actionable insights to organizations. Learn about how OLAP works, what a data cube is, and which OLAP product to use.

Learn More
Dec 12, 2023

Real-Time Data: What it is, Why it Matters, and More

Real-time data travels directly from the source to end users, so that it can be processed and acted on instantly. Learn all about the challenges, benefits, and best practices for real-time data.

Learn More
Dec 08, 2023

Druid vs Pinot: Choosing the best database for Real-Time Analytics

Do you want fast analytics, with subsecond queries, high concurrency, and combination of streams and batch data? If so, you want real-time analytics, and you probably want to consider the two Apache Software...

Learn More
Dec 07, 2023

What’s new in Imply Polaris – October and November 2023

At Imply, our commitment to continually improving your experience with Imply Polaris—our real-time analytics Database-as-a-Service (DBaaS) powered by Apache Druid®—is evident in recent developments. Over...

Learn More
Nov 15, 2023

Introducing Apache Druid 28.0.0

Apache Druid 28.0, an open-source database for real-time analytics, introduces Async queries, UNION ALL support, SQL WINDOW functions, enhanced ingestion features, including multi-Kafka topic support, and...

Learn More
Oct 18, 2023

Migrating Data From S3 To Apache Druid

This blog covers the rationale, advantages, and step-by-step process for data transfer from AWS s3 to Apache Druid for faster real-time analytics and querying.

Learn More
Oct 12, 2023

What’s new in Imply Polaris, our real-time analytics DBaaS  – September 2023

Every week, we add new features and capabilities to Imply Polaris. Throughout September, we've focused on enhancing your experience as you explore trials, navigate data integration, oversee data management,...

Learn More
Sep 27, 2023

Introducing incremental encoding for Apache Druid dictionary encoded columns

In this blog post we deep dive on a recent engineering effort: incremental encoding of STRING columns. In preliminary testing, it has shown to be quite promising at significantly reducing the size of segment...

Learn More
Sep 21, 2023

Migrate Analytics Data from MongoDB to Apache Druid

This blog presents a concise guide on migrating data from MongoDB to Druid. It includes Python scripts to extract data from MongoDB, save it as CSV, and then ingest it into Druid. It also touches on maintaining...

Learn More
Sep 21, 2023

How Druid Facilitates Real-Time Analytics for Mass Transit

Mass transit plays a key role in reimagining life in a warmer, more densely populated world. Learn how Apache Druid helps power data and analytics for mass transit.

Learn More
Sep 19, 2023

Migrate Analytics Data from Snowflake to Apache Druid

This blog outlines the steps needed to migrate data from Snowflake to Apache Druid, a platform designed for high-performance analytical queries. The article covers the migration process, including Python scripts...

Learn More
Sep 15, 2023

Apache Kafka, Flink, and Druid: Open Source Essentials for Real-Time Data Applications

Apache Kafka, Flink, and Druid, when used together, create a real-time data architecture that eliminates all these wait states. In this blog post, we’ll explore how the combination of these tools enables...

Learn More
Sep 11, 2023

Visualizing Data in Apache Druid with the Plotly Python Library

In today's data-driven world, making sense of vast datasets can be a daunting task. Visualizing this data can transform complicated patterns into actionable insights. This blog delves into the utilization of...

Learn More
Sep 05, 2023

Bringing Real-Time Data to Solar Power with Apache Druid

In a rapidly warming world, solar power is critical for decarbonization. Learn how Apache Druid empowers a solar equipment manufacturer to provide real-time data to users, from utility plant operators to homeowners

Learn More
Sep 05, 2023

When to Build (Versus Buy) an Observability Application

Observability is the key to software reliability. Here’s how to decide whether to build or buy your own solution—and why Apache Druid is a popular database for real-time observability

Learn More
Aug 29, 2023

How Innowatts Simplifies Utility Management with Apache Druid

Data is a key driver of progress and innovation in all aspects of our society and economy. By bringing digital data to physical hardware, the Internet of Things (IoT) bridges the gap between the online and...

Learn More
Aug 14, 2023

Three Ways to Use Apache Druid for Machine Learning Workflows

An excellent addition to any machine learning environment, Apache Druid® can facilitate analytics, streamline monitoring, and add real-time data to operations and training

Learn More
Aug 11, 2023

Introducing Apache Druid 27.0.0

Apache Druid® is an open-source distributed database designed for real-time analytics at scale. Apache Druid 27.0 contains over 350 commits & 46 contributors. This release's focus is on stability and scaling...

Learn More
Aug 10, 2023

Unleashing Real-Time Analytics in APJ: Introducing Imply Polaris on AWS AP-South-1

Imply, the company founded by the original creators of Apache Druid, has exciting news for developers in India seeking to build real-time analytics applications. Introducing Imply Polaris, a powerful database-as-a-Service...

Learn More
Aug 03, 2023

Embedding Visualizations using React and Express

In this guide, we will walk you through creating a very simple web app that shows a different embedded chart for each user selected from a drop-down. While this example is simple it highlights the possibilities...

Learn More
Jul 25, 2023

Apache Druid: Making 1000+ QPS for Analytics Look Easy

This 2-part blog post explores key technical considerations to support high QPS for analytics and the strengths of Apache Druid

Learn More
Jul 25, 2023

Things to Consider When Scaling Analytics for High QPS

This 2-part blog post explores key technical considerations to support high QPS for analytics and the strengths of Apache Druid

Learn More
Jul 20, 2023

Automate Streaming Data Ingestion with Kafka and Druid

In this blog post, we explore the integration of Kafka and Druid for data stream management and analysis, emphasizing automatic topic detection and ingestion. We delve into the creation of 'Ingestion Spec',...

Learn More
Jul 12, 2023

Schema Auto-Discovery with Apache Druid

This guide explores configuring Apache Druid to receive Kafka streaming messages. To demonstrate Druid's game-changing automatic schema discovery. Using a real-world scenario where data changes are handled...

Learn More
Jul 11, 2023

What’s new in Imply Polaris – Q2 2023

Imply Polaris, our ever-evolving Database-as-a-Service, recently focused on global expansion, enhanced security, and improved data handling and visualization. This fully managed cloud service, based on Apache...

Learn More
Jun 06, 2023

Introducing hands-on developer tutorials for Apache Druid

The objective of this blog is to introduce the new set of interactive tutorials focused on the Druid API fundamentals. These tutorials are available as Jupyter Notebooks and can be downloaded as a Docker container.

Learn More
Jun 01, 2023

Introducing Schema Auto-Discovery in Apache Druid

In this blog article I’ll unpack schema auto-discovery, a new feature now available in Druid 26.0, that enables Druid to automatically discover data fields and data types and update tables to match changing...

Learn More
May 28, 2023

What’s new in Imply Polaris – Our Real-Time Analytics DBaaS

Every week we add new features and capabilities to Imply Polaris. This month, we’ve expanded security capabilities, added new query functionality, and made it easier to monitor your service with your preferred...

Learn More
May 24, 2023

Introducing Apache Druid 26.0

Apache Druid® 26.0, an open-source distributed database for real-time analytics, has seen significant improvements with 411 new commits, a 40% increase from version 25.0. The expanded contributor base of 60...

Learn More
May 22, 2023

ACID and Apache Druid

ACID and Druid, an interesting dive into some of the Druid capabilities in the light of ACID compliance

Learn More
May 21, 2023

How to Build a Sentiment Analysis Application with ChatGPT and Druid

Leveraging ChatGPT for sentiment analysis, when combined with Apache Druid, offers results from large data volumes. This integration is easily achievable, revealing valuable insights and trends for businesses...

Learn More
May 21, 2023

Snowflake and Apache Druid

In this blog, we will compare Snowflake and Druid. It is important to note that reporting data warehouses and real-time analytics databases are different domains. Choosing the right tool for your specific requirements...

Learn More
May 20, 2023

Learn how to achieve sub-second responses with Apache Druid

Learn how to achieve sub-second responses with Apache Druid. This article is an in-depth look at how Druid resolves queries and describes data modeling techniques that improve performance.

Learn More
May 19, 2023

Apache Druid – Recovering Dropped Segments

Apache Druid uses load rules to manage the ageing of segments from one historical tier to another and finally to purge old segments from the cluster. In this article, we’ll show what happens when you make...

Learn More
May 18, 2023

Real-Time Analytics: Building Blocks and Architecture

This blog identifies the key technical considerations for real-time analytics. It answers what is the right data architecture and why. It spotlights the technologies used at Confluent, Reddit, Target and 1000s...

Learn More
May 17, 2023

Transactions Come and Go, but Events are Forever

For decades, analytics has focused on Transactions. While Transactions are still important, the future of analytics is understanding Events.

Learn More
May 16, 2023

What’s new in Imply Polaris – Our Real-Time Analytics DBaaS

This blog explains some of the new features, functionality and connectivity added to Imply Polaris over the last two months. We've expanded ingestion capabilities, simplified operations and increased reliability...

Learn More
May 15, 2023

Elasticsearch and Druid

This blog will help you understand what Elasticsearch and Druid do well and will help you decide whether you need one or both to reach your goals

Learn More
May 14, 2023

Wow, that was easy – Up and running with Apache Druid

The objective of this blog is to provide a step-by-step guide on setting up Druid locally, including the use of SQL ingestion for importing data and executing analytical queries.

Learn More
May 13, 2023

Top 7 Questions about Kafka and Druid

Read on to learn more about common questions and answers about using Kafka with Druid.

Learn More
May 12, 2023

Tales at Scale Podcast Kicks off with the Apache Druid Origin Story

Tales at Scale cracks open the world of analytics projects and shares stories from developers and engineers who are building analytics applications or working within the real-time data space. One of the key...

Learn More
May 11, 2023

Real-time Analytics Database uses partitioning and pruning to achieve its legendary performance

Apache Druid uses partitioning (splitting data) and pruning (selecting subset of data) to achieve its legendary performance. Learn how to use the CLUSTERED BY clause during ingestion for performance and high...

Learn More
May 10, 2023

Easily embed analytics into your own apps with Imply’s DBaaS

This blog explains how developers can leverage Imply Polaris to embed robust visualization options directly into their own applications without them having to build a UI. This is super important because consuming...

Learn More
May 09, 2023

Building an Event Analytics Pipeline with Confluent Cloud and Imply’s real time DBaaS, Polaris

Learn how to set up a pipeline that generates a simulated clickstream event stream and sends it to Confluent Cloud, processes the raw clickstream data using managed ksqlDB in Confluent Cloud, delivers the processed...

Learn More
May 08, 2023

Real time DBaaS comes to Europe

We are excited to announce the availability of Imply Polaris in Europe, specifically in AWS eu-central-1 region based in Frankfurt. Since its launch in March 2022, Imply Polaris, the fully managed Database-as-a-Service...

Learn More
May 07, 2023

Stream big, think bigger—Analyze streaming data at scale in 2023

Imply is predicting the next "big thing" in 2023 will be analyzing streaming data in real time (and Druid is built for just that!)

Learn More
May 07, 2023

Should You Build or Buy Security Analytics for SecOps?

When should you build—or buy—a security analytics platform for your environment? Here are some common considerations—and how Apache Druid is the ideal foundation for any in-house security solution.

Learn More
May 05, 2023

Introducing Apache Druid 25.0

Apache Druid 25.0 contains over 293 updates from over 56 contributors.

Learn More
May 03, 2023

Druid and SQL syntax

This is a technical blog, which summarises the process of extending the Druid's SQL grammar for ingestion and delves into the nitty gritty of Calcite.

Learn More
May 02, 2023

Native support for semi-structured data in Apache Druid

Describes a new feature- ingest complex data as is into Druid- massive improvement in developer productivity

Learn More
May 01, 2023

Real-Time Analytics with Imply Polaris: From Setup to Visualization

Imply Polaris offers reduced operational overhead and elastic scaling for efficient real-time analytics that helps you unlock your data's potential.

Learn More
May 01, 2023

Datanami Award

Apache Druid won Datanami's 2022 Readers’ and Editors’ Choice Awards for Reader's Choice "Best Data and AI Product or Technology: Analytics Database".

Learn More
Apr 30, 2023

Alerting and Security Features in Polaris

Describes new features - alerts and some security features- and how Imply customers can leverage it

Learn More
Apr 29, 2023

Ingestion from Amazon Kinesis and S3 into Imply Polaris

Imply Polaris now supports data ingestion from Amazon Kinesis and Amazon S3

Learn More
Apr 27, 2023

Getting the Most Out of your Data

Ingesting data from one table to another is easy and fast in Imply Polaris!

Learn More
Apr 26, 2023

Combating financial fraud and money laundering at scale with Apache Druid

Learn how Apache Druid enables financial services firms and FinTech companies to get immediate insights from petabytes-plus data volumes for anti-fraud and anti-money laundering compliance.

Learn More
Apr 26, 2023

What’s new in Imply – December 2022

This is a what's new to Imply in Dec 2022. We’ve added two new features to Imply Polaris to make it easier for your end users to take advantage of real-time insights.

Learn More
Apr 25, 2023

What’s New in Imply Polaris – November 2022

This blog provides an overview for the new features, functionality, and connectivity to Imply Polaris for November 2022.

Learn More
Apr 24, 2023

Imply Pivot delivers the final mile for modern analytics applications

This blog is focused on how Imply Pivot delivers the final mile for building an anlaytics app. It showcases two customer examples - Twitch and ironsource.

Learn More
Apr 23, 2023

Why Analytics Need More than a Data Warehouse

For decades, analytics has been defined by the standard reporting and BI workflow, supported by the data warehouse. Now, 1000s of companies are realizing an expansion of analytics beyond reporting, which requires...

Learn More
Apr 21, 2023

Why Open Source Matters for Databases

Apache Druid is at the heart of Imply. We’re an open source business, and that’s why we’re committed to making Druid the best open source database for modern analytics applications

Learn More
Apr 20, 2023

Ingestion from Confluent Cloud and Kafka in Polaris

How to ingest data into Imply Polaris from Confluent Cloud and from Apache Kafka

Learn More
Apr 18, 2023

What Makes a Database Built for Streaming Data?

For an analytics app to handle real-time, streaming sources, it must be built for streaming data. Druid has 3 essential features for stream data.

Learn More
Oct 12, 2022

SQL-based Transformations and JSON Columns in Imply Polaris

You can easily do data transformations and manage JSON data with Imply Polaris, both using SQL.

Learn More
Oct 06, 2022

Approximate Distinct Counts in Imply Polaris

When it comes to modern data analytics applications, speed is of the utmost importance. In this blog we discuss two approximation algorithms which can be used to greatly enhance speed with only a slight reduction...

Learn More
Sep 20, 2022

The next chapter for Imply Polaris: celebrating 250+ accounts, continued innovation

Today we announced the next iteration of Imply Polaris, the fully managed Database-as-a-Service that helps you build modern analytics applications faster, cheaper, and with less effort. Since its launch in...

Learn More
Sep 20, 2022

Introducing Imply’s Total Value Guarantee for Apache Druid

Apache Druid 24.0 contains 450 updates and new features, major performance enhancements, bug fixes, and major documentation improvements

Learn More
Sep 16, 2022

Introducing Apache Druid 24.0

Apache Druid 24.0 contains 450 updates and new features, major performance enhancements, bug fixes, and major documentation improvements

Learn More
Aug 16, 2022

Using Imply Pivot with Druid to Deduplicate Timeseries Data

Imply Pivot offers multi step aggregations, which is valuable for timeseries data where measures are not evenly distributed in time.

Learn More
Jul 21, 2022

A Look Under the Surface at Polaris Security

We have taken a security-first approach in building the easiest real-time database for modern analytics applications.

Learn More
Jul 14, 2022

Upserts and Data Deduplication with Druid

A look at what can be done with Druid for upserts and data deduplication.

Learn More
Jul 01, 2022

What Developers Can Build with Apache Druid

We obviously talk a lot about #ApacheDruid on here. But what are folks actually building with Druid? What is a modern analytics application, exactly? Let's find out

Learn More
Jun 29, 2022

When Streaming Analytics… Isn’t

Nearly all databases are designed for batch processing, which leaves three options for stream analytics.

Learn More
Jun 29, 2022

Apache Druid vs. Snowflake

Elasticity is important, but beware the database that can only save you money when your application is not in use. The best solution will have excellent price-performance under all conditions.

Learn More
Jun 22, 2022

Druid 0.23 – Features And Capabilities For Advanced Scenarios

Many of Druid’s improvements focus on building a solid foundation, including making the system more stable, easier to use, faster to scale, and better integrated with the rest of the data ecosystem. But for...

Learn More
Jun 22, 2022

Introducing Apache Druid 0.23

Apache Druid 0.23.0 contains over 450 updates, including new features, major performance enhancements, bug fixes, and major documentation improvements.

Learn More
Jun 20, 2022

An Opinionated Guide to Component APIs

We have collected a number of guidelines for React component APIs that make components more predictable in terms of behavior and performance.

Learn More
Jun 10, 2022

Druid Architecture & Concepts

In a world full of databases, learn how Apache Druid makes real-time analytics apps a reality in this Whitepaper from Imply

Learn More
May 25, 2022

3 decisions that shaped the Polaris UI

Imply Polaris is a fully managed database-as-a-service for building realtime analytics applications. John is the tech lead for the Polaris UI, known internally as the Unified App. It began with a profound question:...

Learn More
May 19, 2022

How Imply Polaris takes a security-first approach

A primer for developers on security tools and controls available in Imply Polaris

Learn More
May 17, 2022

Imply Raises $100MM in Series D funding

There is a new category within data analytics emerging which is not centered in the world of reports and dashboards (the purview of data analysts and data scientists), but instead centered in the world of applications...

Learn More
May 11, 2022

Imply Named “Cool Database Vendor” by CRN

There can’t be one database good at everything. When it comes to real-time analytics, you need a database built for it.

Learn More
May 11, 2022

Living the Stream

We are in the early stages of a stream revolution, as developers build modern transactional and analytic applications that use real-time data continuously delivered.

Learn More
May 02, 2022

Migrating Data from ClickHouse to Imply Polaris

In this blog, we’ll review the simple steps to export data from ClickHouse in a format that is easy to ingest into Polaris.

Learn More

Let us help with your analytics apps

Request a Demo