Skip to main content
Skip to main content

sumMap

sumMappedArrays

Introduced in: v1.1

Totals one or more value arrays according to the keys specified in the key array. Returns a tuple of arrays: keys in sorted order, followed by values summed for the corresponding keys without overflow.

Note
  • Passing a tuple of keys and value arrays is identical to passing an array of keys and an array of values.
  • The number of elements in key and all value arrays must be the same for each row that is totaled.

Syntax

sumMappedArrays(key, value1 [, value2, ...])
sumMappedArrays(Tuple(key, value1 [, value2, ...]))

Arguments

  • key — Array of keys. Array
  • value1, value2, ... — Arrays of values to sum for each key. Array

Returned value

Returns a tuple of arrays: the first array contains keys in sorted order, followed by arrays containing values summed for the corresponding keys. Tuple

Examples

Basic usage with Nested type

CREATE TABLE sum_map(
    date Date,
    timeslot DateTime,
    statusMap Nested(
        status UInt16,
        requests UInt64
    ),
    statusMapTuple Tuple(Array(Int32), Array(Int32))
) ENGINE = Memory;

INSERT INTO sum_map VALUES
    ('2000-01-01', '2000-01-01 00:00:00', [1, 2, 3], [10, 10, 10], ([1, 2, 3], [10, 10, 10])),
    ('2000-01-01', '2000-01-01 00:00:00', [3, 4, 5], [10, 10, 10], ([3, 4, 5], [10, 10, 10])),
    ('2000-01-01', '2000-01-01 00:01:00', [4, 5, 6], [10, 10, 10], ([4, 5, 6], [10, 10, 10])),
    ('2000-01-01', '2000-01-01 00:01:00', [6, 7, 8], [10, 10, 10], ([6, 7, 8], [10, 10, 10]));

SELECT
    timeslot,
    sumMappedArrays(statusMap.status, statusMap.requests),
    sumMappedArrays(statusMapTuple)
FROM sum_map
GROUP BY timeslot;
┌────────────timeslot─┬─sumMappedArrays(statusMap.status, statusMap.requests)─┬─sumMappedArrays(statusMapTuple)─────────┐
│ 2000-01-01 00:00:00 │ ([1,2,3,4,5],[10,10,20,10,10])                        │ ([1,2,3,4,5],[10,10,20,10,10])          │
│ 2000-01-01 00:01:00 │ ([4,5,6,7,8],[10,10,20,10,10])                        │ ([4,5,6,7,8],[10,10,20,10,10])          │
└─────────────────────┴───────────────────────────────────────────────────────┴─────────────────────────────────────────┘

Multiple value arrays example

CREATE TABLE multi_metrics(
    date Date,
    browser_metrics Nested(
        browser String,
        impressions UInt32,
        clicks UInt32
    )
)
ENGINE = Memory;

INSERT INTO multi_metrics VALUES
    ('2000-01-01', ['Firefox', 'Chrome'], [100, 200], [10, 25]),
    ('2000-01-01', ['Chrome', 'Safari'], [150, 50], [20, 5]),
    ('2000-01-01', ['Firefox', 'Edge'], [80, 40], [8, 4]);

SELECT
    sumMappedArrays(browser_metrics.browser, browser_metrics.impressions, browser_metrics.clicks) AS result
FROM multi_metrics;
┌─result────────────────────────────────────────────────────────────────────────┐
│ (['Chrome', 'Edge', 'Firefox', 'Safari'], [350, 40, 180, 50], [45, 4, 18, 5]) │
└───────────────────────────────────────────────────────────────────────────────┘
-- In this example:
-- The result tuple contains three arrays
-- First array: keys (browser names) in sorted order
-- Second array: total impressions for each browser
-- Third array: total clicks for each browser

See Also