Encoded Data in Columnstores
On this page
SingleStore performs some query processing operations directly on encoded data in columnstore tables.
SIMD support on your hardware is not required to benefit from operations on encoded data.
Operations on encoded data are performed automatically, by default.
What Is Encoded Data and What Does It Mean to Operate on It?
SingleStore supports several different kinds of data encodings to help compress data.operated on
directly.
For example, consider this dictionary:
ID |
value |
---|---|
0 |
red |
1 |
green |
2 |
blue |
This can be represented as a bit vector of packed string IDs when it is stored into the column segment:
-
Strings:
red
,blue
,green
,green
,red
-
String IDs: 0, 2, 1, 1, 0
-
Bit vector: 00 10 01 01 00 (2 bits per string ID)
As an example of operating directly on encoded data, SingleStore can perform a filter operation, say t.
, on a string dictionary-encoded column segment by first finding the result of the filter for every entry in the dictionary.xyz
The encoding for a blob depends on its type and data.
Most query processing in SingleStore outside of columnstore scan is done row-at-a-time.
Queries That Can Benefit from Operations on Encoded Data
Queries that can benefit from operations on encoded data are those that run over columnstore tables, and have one or more of these components:
-
Filters
-
Group-by
-
Aggregates
-
Expressions in aggregates
-
Expressions in group-by
-
Star joins on integer columns
Operations on encoded data can be done regardless of the number of distinct values of the encoded columns being processed.
Here’s an example of a query that can benefit from operations on encoded data in several ways.
SELECTDAYOFWEEK(shipdate), location,SUM(price * (1 - discount)), AVG(quantity)FROM lineitemWHEREstatus = 'S'GROUP BY 1, 2;
Here’s another example of a query that can benefit from join operations on encoded data, if the table f
is a columnstore.
SELECT d1.x, d2.y, SUM(f.m)FROM f, d1, d2WHERE f.d1_key = d1.keyAND f.d2_key = d2.keyAND d1.v > 100AND d2.v in (1, 2, 3)GROUP BY d1.x, d2.y
This query is a simple example of a star join.group by
clause and aggregate functions is required to benefit from join operations on encoded data.
Examples
The following example shows encoded group-by in action:
CREATE DATABASE db;USE db;DROP TABLE IF EXISTS r;DROP TABLE IF EXISTS is_tables;/* Extract rows for 50 different tables into a scratch table, is_tables. */CREATE TABLE is_tables ASSELECT * FROM information_schema.tablesLIMIT 50;/* Create a table with a million rows, with every table nameappearing in most or all segments. */CREATE TABLE r (INDEX USING CLUSTERED COLUMNSTORE(n)) ASSELECT s.*, (row_number () OVER (ORDER BY s.table_name) % 1000) AS nFROM (SELECT t1.*FROM is_tables t1, is_tables t2, is_tables t3, is_tables t4LIMIT 1000000) AS s;
The table r created above is a columnstore with one million rows.
SELECT COUNT(*), encoding, column_nameFROM information_schema.columnar_segmentsWHERE table_name = 'r' AND database_name = 'db'AND column_name = 'TABLE_NAME'GROUP BY column_name, encoding;
The result indicates that StringDictionary encoding is used for the column.
Now, run the following group-by/aggregate query that groups on the table_
PROFILE SELECT table_name, COUNT(*) FROM r GROUP BY table_name;
Finally, output the JSON profile for the query:
SHOW PROFILE json;
The result includes the following text:
inputs":[{"executor":"ColumnStoreScan","db":"db","table":"r",..."segments_scanned":{ "value":16, "avg":2.000000, "stddev":0.000000, "max":2, "maxPartition":0 },"segments_skipped":{ "value":0 },"segments_fully_contained":{ "value":0 },"segments_encoded_group_by":{ "value":16, "avg":2.000000, "stddev":0.000000, "max":2, "maxPartition":0 },"inputs":[]}
Notice the portion labeled segments_
.
Now, here is another query (run in profile mode) that is similar to the first, but also has a filter on column table_
PROFILE SELECT table_name, COUNT(*) FROM rWHERE table_name LIKE '%COLUMN%'GROUP BY table_name;SHOW PROFILE json;
The JSON profile for this query contains the text below:
"inputs":[{"executor":"ColumnStoreScan","db":"db","table":"r",..."segments_scanned":{ "value":16, "avg":2.000000, "stddev":0.000000, "max":2, "maxPartition":0 },"segments_skipped":{ "value":0 },"segments_fully_contained":{ "value":0 },"segments_ops_compressed_data":{ "value":16, "avg":2.000000, "stddev":0.000000, "max":2, "maxPartition":0 },"segments_encoded_group_by":{ "value":16, "avg":2.000000, "stddev":0.000000, "max":2, "maxPartition":0 },"inputs":[]}
Notice that it includes sections for both segments_
and segments_
.segments_
section indicates that 16 segments had filters applied on encoded data.
The final decision about use of operations on encoded data is made at runtime and depends on column encodings for each segment and (for group-by) the number of distinct values in the segment.encoded_
section will indicate the reasons that encoded group by was disabled as well as the number of segments disabled for each reason.
Encoded joins
This example shows encoded joins in action.
/* Create a simulated dimension table with 1000 rows with uniquevalues for n, and around 100 categories. */CREATE TABLE d ASSELECT n, MAX(CONCAT('cat', n % 100)) AS categoryFROM rGROUP BY n;/* Join dimension table d to "fact" table r on an integer columnand group by category. This is a very simple star join. */SELECT d.category, COUNT(*)FROM r, dWHERE r.n = d.nAND d.category LIKE 'cat1%'GROUP BY d.category;
The above join query takes only 0.
You can see that encoded joins are being used in the profile query execution plan for the above statement by using the graphical plan display or show profile json
output."encoded_
.segments_
with value
set to 8.
Example Performance Results
Operations on encoded data can yield some astonishingly short query execution times.
query |
time |
---|---|
|
0. |
|
0. |
|
0. |
|
0. |
|
0. |
Best case performance in other internal tests have shown a processing rate of over one billion rows per second per core for queries like the following, when column a
has eight or fewer distinct values, using a recent model high-performance Intel processor.
SELECT a, COUNT(*) FROM t GROUP BY a;
These results can be extrapolated to much larger data sets on a large SingleStore cluster, although memory bandwidth limits may limit total throughput in rows per second per core across the cluster, below the best-case numbers shown here.
Performance Considerations
Because operations on encoded data can process data so fast, their performance can become limited by the bandwidth of main memory (RAM).
So, SingleStore recommends that you configure your system so that little or no I/O is being done while processing columnstore data, under a steady query workload.
The Linux operating system will allocate available system memory to the file system buffer cache in an on-demand way, without the need to set any configuration knobs.
Relevant Hints
SingleStore can perform group-by on encoded data using a HashGroupBy operation, and can also do a group-by on columnstore data using a StreamingGroupBy operation on the sort key of the columnstore.
SELECT SUM(a) FROM t WITH (disable_ordered_scan=true) GROUP BY b;
You can use EXPLAIN to see the plan for your query to check the type of group-by operation chosen.
Data Encodings Supported
Operations on encoded data are supported only for the following:
-
String columns (including varchar, char, text, and blob) with string dictionary and string run-length encodings
-
Numeric columns (including all integer types (tinyint, bigint, etc.
) plus float, decimal, and double) with value and run-length encodings
Group-by/aggregate operations on encoded data are supported only for integers.
SingleStore recommends that you allow SingleStore to choose automatically how to encode data for columnstores.option '<encoding>'
notation.
CREATE TABLE t (a int, b varchar(50) option 'StringDictionary',key(a) USING CLUSTERED COLUMNSTORE);
Operations Supported, and Limitations
To summarize the operations supported on encoded data, as well as limitations to operations on encoded data, they include:
-
Scan
-
Faster decoding for integer encoding
-
-
Filter
-
Filters on the following:
-
Strings for string dictionary and string run-length encoding
-
Integers for run-length encoding
-
-
Or-of-ands of filter expressions; filter expressions must involve a single string column for faster processing
-
Support for Bloom filters on string columns (elimination of rows with no matches for joins on a single string column)
-
-
Aggregates
-
Aggregates supported: sum, min, max, count, any
-
Aggregate input data types supported: all numeric
-
Aggregate expressions supported: multiple table columns allowed in a single expression
-
Aggregates encodings supported: integer, integer run-length
-
-
Group-by:
-
Operations on encoded data are not done for aggregates without a group-by (a.
k. a. scalar aggregates) -
Group-by count star is very fast
-
Group-by:
-
Multiple group-by columns are allowed
-
A mix of columns and expressions is allowed
-
Group-by columns must only use these encodings: integer, integer run-length
-
There is a limit on number of distinct values per column of a few thousand rows, beyond which, the system reverts to row-at-a-time processing and the local aggregation of data for a row segment will output rows to the parent global aggregate operator
-
Similarly, there is a limit on total number of groups, of a few thousand groups, beyond which the optimized group-by processing is not used
-
Group-by on the sort key may not be as efficient as group-by on other columns because ordered group-by may be performed while hash groupby might be better
-
-
Group-by on expressions:
-
Only one input column is allowed in a single expression
-
The expression result must be integer
-
Each table column can be used only once in the set of group-by columns and expressions
-
-
-
Joins:
-
Joins must be on some type of integer column, or another column type represented internally as an integer, such as datetime
-
The join or joins selected by the query optimizer must be of type HashJoin
-
The join must be a many-to-one relationship
-
The HashJoin (or a sequence of HashJoins) must appear over a ColumnStoreScan
-
A Group By operation and aggregate must be present in the query over the result of the join
-
Encoded group by bailout reasons
The final decision on whether to use encoded group by is made at runtime.
-
Join condition is not a many-to-one relationship
-
Unsupported column encoding
-
Aggregate not guaranteed to fit in aggregate type (the result may overflow the internal integer or decimal type)
-
Reached dynamic dictionary size limit (too many unique group by values)
-
Group by column cannot be placeholder blob (column does not yet exist in columnstore)
Additional Tuning Considerations
If you have upgraded from a MemSQL release below 6.
If you find that operations on encoded data are not occurring as much as you expect them to you can rebuild the columnstore table involved.
One way to rebuild it is to use
CREATE TABLE newTable (INDEX USING CLUSTERED COLUMNSTORE(<columns>)) ASSELECT *FROM oldTable;
Then drop oldTable and rename newTable to oldTable.
Scalar count(*)
Because encoded group-by is so fast, and scalar aggregates are not done on encoded data, you may find the following unexpected behavior.
SELECT a, COUNT(*) FROM t GROUP BY a;
may be faster than this:
SELECT COUNT(*) FROM t;
Although it is usually not necessary because count(*) scalar aggregates are so fast anyway, if you want the fastest possible count(*), consider this workaround:
SELECT SUM(t2.c)FROM (SELECT a, COUNT(*) AS c FROM t GROUP BY a) AS t2;
The subquery will be done with encoded group-by, so the containing query may run faster that a scalar count(*);
Aggregation of Decimal Types
When creating decimal type columns that are aggregated in queries, for best performance, SingleStore recommends to use precision of 18 digits or less if your application can accommodate this (i.
Last modified: March 8, 2024