Skip to content

Commit adeee94

Browse files
committed
Add support for DuckDB MAP functions
- Add map_extract, map_keys, map_values, cardinality, element_at, map_concat, map_contains, map_contains_entry, map_contains_value, map_entries, map_extract_value, and map_from_entries functions - Create migration file pg_duckdb--1.0.0--1.1.0.sql with function definitions - Update metadata cache to recognize all MAP functions as DuckDB-only - Add comprehensive tests covering all functions with edge cases - Update documentation with detailed usage examples and function descriptions - Bump version to 1.1.0 in pg_duckdb.control - Add regression tests to schedule Closes #774
1 parent 0f8447e commit adeee94

File tree

9 files changed

+495
-2
lines changed

9 files changed

+495
-2
lines changed

docs/functions.md

Lines changed: 135 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -20,6 +20,25 @@ Note: `ALTER EXTENSION pg_duckdb WITH SCHEMA schema` is not currently supported.
2020

2121
All of the DuckDB [json functions and aggregates](https://duckdb.org/docs/data/json/json_functions.html). Postgres JSON/JSONB functions are not supported.
2222

23+
## MAP Functions
24+
25+
All of the DuckDB [map functions](https://duckdb.org/docs/sql/data_types/map.html#map-functions).
26+
27+
| Name | Description |
28+
| :--- | :---------- |
29+
| [`cardinality`](#cardinality) | Return the size of the map |
30+
| [`element_at`](#element_at) | Return the value for a given key as a list |
31+
| [`map_concat`](#map_concat) | Merge multiple maps |
32+
| [`map_contains`](#map_contains) | Check if a map contains a given key |
33+
| [`map_contains_entry`](#map_contains_entry) | Check if a map contains a given key-value pair |
34+
| [`map_contains_value`](#map_contains_value) | Check if a map contains a given value |
35+
| [`map_entries`](#map_entries) | Return a list of struct(k, v) for each key-value pair |
36+
| [`map_extract`](#map_extract) | Extract a value from a map using a key |
37+
| [`map_extract_value`](#map_extract_value) | Return the value for a given key or NULL |
38+
| [`map_from_entries`](#map_from_entries) | Create a map from an array of struct(k, v) |
39+
| [`map_keys`](#map_keys) | Get all keys from a map as a list |
40+
| [`map_values`](#map_values) | Get all values from a map as a list |
41+
2342
## Aggregates
2443

2544
|Name|Description|
@@ -327,3 +346,119 @@ CALL duckdb.force_motherduck_sync(drop_with_cascade := true);
327346
```
328347

329348
NOTE: Dropping with cascade will drop all objects that depend on the MotherDuck tables. This includes all views, functions, and tables that depend on the MotherDuck tables. This can be a destructive operation, so use with caution.
349+
350+
#### <a name="map_extract"></a>`map_extract(map_col duckdb.map, key TEXT) -> duckdb.unresolved_type`
351+
352+
Extracts a value from a map using the specified key. If the key doesn't exist, returns NULL.
353+
354+
```sql
355+
SELECT map_extract(MAP(['a', 'b'], [1, 2]), 'a'); -- Returns 1
356+
SELECT map_extract(MAP(['a', 'b'], [1, 2]), 'c'); -- Returns NULL
357+
```
358+
359+
##### Required Arguments
360+
361+
| Name | Type | Description |
362+
| :--- | :--- | :---------- |
363+
| map_col | duckdb.map | The map to extract from |
364+
| key | text | The key to look up in the map |
365+
366+
#### <a name="map_keys"></a>`map_keys(map_col duckdb.map) -> duckdb.unresolved_type`
367+
368+
Returns all keys from a map as a list.
369+
370+
```sql
371+
SELECT map_keys(MAP(['a', 'b', 'c'], [1, 2, 3])); -- Returns ['a', 'b', 'c']
372+
```
373+
374+
##### Required Arguments
375+
376+
| Name | Type | Description |
377+
| :--- | :--- | :---------- |
378+
| map_col | duckdb.map | The map to extract keys from |
379+
380+
#### <a name="map_values"></a>`map_values(map_col duckdb.map) -> duckdb.unresolved_type`
381+
382+
Returns all values from a map as a list.
383+
384+
```sql
385+
SELECT map_values(MAP(['a', 'b', 'c'], [1, 2, 3])); -- Returns [1, 2, 3]
386+
```
387+
388+
##### Required Arguments
389+
390+
| Name | Type | Description |
391+
| :--- | :--- | :---------- |
392+
| map_col | duckdb.map | The map to extract values from |
393+
394+
#### <a name="cardinality"></a>`cardinality(map_col duckdb.map) -> integer`
395+
396+
Returns the size of the map.
397+
398+
```sql
399+
SELECT cardinality(MAP(['a', 'b', 'c'], [1, 2, 3])); -- Returns 3
400+
```
401+
402+
#### <a name="element_at"></a>`element_at(map_col duckdb.map, key TEXT) -> duckdb.unresolved_type`
403+
404+
Returns the value for a given key as a list. Alias for `map_extract`.
405+
406+
```sql
407+
SELECT element_at(MAP(['a', 'b'], [1, 2]), 'a'); -- Returns [1]
408+
```
409+
410+
#### <a name="map_concat"></a>`map_concat(map_col duckdb.map, map_col2 duckdb.map) -> duckdb.unresolved_type`
411+
412+
Merges multiple maps. On key collision, the value is taken from the last map.
413+
414+
```sql
415+
SELECT map_concat(MAP(['a', 'b'], [1, 2]), MAP(['b', 'c'], [3, 4])); -- Returns {'a': 1, 'b': 3, 'c': 4}
416+
```
417+
418+
#### <a name="map_contains"></a>`map_contains(map_col duckdb.map, key TEXT) -> boolean`
419+
420+
Checks if a map contains a given key.
421+
422+
```sql
423+
SELECT map_contains(MAP(['a', 'b'], [1, 2]), 'a'); -- Returns true
424+
```
425+
426+
#### <a name="map_contains_entry"></a>`map_contains_entry(map_col duckdb.map, key TEXT, value TEXT) -> boolean`
427+
428+
Checks if a map contains a given key-value pair.
429+
430+
```sql
431+
SELECT map_contains_entry(MAP(['a', 'b'], [1, 2]), 'a', '1'); -- Returns true
432+
```
433+
434+
#### <a name="map_contains_value"></a>`map_contains_value(map_col duckdb.map, value TEXT) -> boolean`
435+
436+
Checks if a map contains a given value.
437+
438+
```sql
439+
SELECT map_contains_value(MAP(['a', 'b'], [1, 2]), '1'); -- Returns true
440+
```
441+
442+
#### <a name="map_entries"></a>`map_entries(map_col duckdb.map) -> duckdb.unresolved_type`
443+
444+
Returns a list of struct(k, v) for each key-value pair in the map.
445+
446+
```sql
447+
SELECT map_entries(MAP(['a', 'b'], [1, 2])); -- Returns [{'key': 'a', 'value': 1}, {'key': 'b', 'value': 2}]
448+
```
449+
450+
#### <a name="map_extract_value"></a>`map_extract_value(map_col duckdb.map, key TEXT) -> duckdb.unresolved_type`
451+
452+
Returns the value for a given key or NULL if the key is not contained in the map.
453+
454+
```sql
455+
SELECT map_extract_value(MAP(['a', 'b'], [1, 2]), 'a'); -- Returns 1
456+
```
457+
458+
#### <a name="map_from_entries"></a>`map_from_entries(entries duckdb.unresolved_type) -> duckdb.unresolved_type`
459+
460+
Creates a map from an array of struct(k, v).
461+
462+
```sql
463+
SELECT map_from_entries([{'k': 'a', 'v': 1}, {'k': 'b', 'v': 2}]); -- Returns {'a': 1, 'b': 2}
464+
```

pg_duckdb.control

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,5 @@
11
comment = 'DuckDB Embedded in Postgres'
2-
default_version = '1.0.0'
2+
default_version = '1.1.0'
33
module_pathname = '$libdir/pg_duckdb'
44
relocatable = false
55
schema = public

sql/pg_duckdb--1.0.0--1.1.0.sql

Lines changed: 82 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,82 @@
1+
-- Add MAP functions support
2+
-- Extract value from map using key
3+
CREATE FUNCTION @[email protected]_extract(map_col duckdb.map, key text)
4+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
5+
CREATE FUNCTION @[email protected]_extract(map_col duckdb.unresolved_type, key text)
6+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
7+
8+
-- Get all keys from map
9+
CREATE FUNCTION @[email protected]_keys(map_col duckdb.map)
10+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
11+
CREATE FUNCTION @[email protected]_keys(map_col duckdb.unresolved_type)
12+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
13+
14+
-- Get all values from map
15+
CREATE FUNCTION @[email protected]_values(map_col duckdb.map)
16+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
17+
CREATE FUNCTION @[email protected]_values(map_col duckdb.unresolved_type)
18+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
19+
20+
-- Get map size
21+
CREATE FUNCTION @[email protected](map_col duckdb.map)
22+
RETURNS integer AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
23+
CREATE FUNCTION @[email protected](map_col duckdb.unresolved_type)
24+
RETURNS integer AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
25+
26+
-- Get element at key (alias for map_extract)
27+
CREATE FUNCTION @[email protected]_at(map_col duckdb.map, key text)
28+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
29+
CREATE FUNCTION @[email protected]_at(map_col duckdb.unresolved_type, key text)
30+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
31+
CREATE FUNCTION @[email protected]_at(map_col duckdb.map, key integer)
32+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
33+
CREATE FUNCTION @[email protected]_at(map_col duckdb.unresolved_type, key integer)
34+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
35+
36+
-- Merge multiple maps
37+
CREATE FUNCTION @[email protected]_concat(map_col duckdb.map, map_col2 duckdb.map)
38+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
39+
CREATE FUNCTION @[email protected]_concat(map_col duckdb.unresolved_type, map_col2 duckdb.unresolved_type)
40+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
41+
42+
-- Check if map contains key
43+
CREATE FUNCTION @[email protected]_contains(map_col duckdb.map, key text)
44+
RETURNS boolean AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
45+
CREATE FUNCTION @[email protected]_contains(map_col duckdb.unresolved_type, key text)
46+
RETURNS boolean AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
47+
CREATE FUNCTION @[email protected]_contains(map_col duckdb.map, key integer)
48+
RETURNS boolean AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
49+
CREATE FUNCTION @[email protected]_contains(map_col duckdb.unresolved_type, key integer)
50+
RETURNS boolean AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
51+
52+
-- Check if map contains key-value pair
53+
CREATE FUNCTION @[email protected]_contains_entry(map_col duckdb.map, key text, value text)
54+
RETURNS boolean AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
55+
CREATE FUNCTION @[email protected]_contains_entry(map_col duckdb.unresolved_type, key text, value text)
56+
RETURNS boolean AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
57+
58+
-- Check if map contains value
59+
CREATE FUNCTION @[email protected]_contains_value(map_col duckdb.map, value text)
60+
RETURNS boolean AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
61+
CREATE FUNCTION @[email protected]_contains_value(map_col duckdb.unresolved_type, value text)
62+
RETURNS boolean AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
63+
64+
-- Get all key-value pairs as structs
65+
CREATE FUNCTION @[email protected]_entries(map_col duckdb.map)
66+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
67+
CREATE FUNCTION @[email protected]_entries(map_col duckdb.unresolved_type)
68+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
69+
70+
-- Extract single value from map (not as list)
71+
CREATE FUNCTION @[email protected]_extract_value(map_col duckdb.map, key text)
72+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
73+
CREATE FUNCTION @[email protected]_extract_value(map_col duckdb.unresolved_type, key text)
74+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
75+
CREATE FUNCTION @[email protected]_extract_value(map_col duckdb.map, key integer)
76+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
77+
CREATE FUNCTION @[email protected]_extract_value(map_col duckdb.unresolved_type, key integer)
78+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;
79+
80+
-- Create map from array of struct(k, v)
81+
CREATE FUNCTION @[email protected]_from_entries(entries duckdb.unresolved_type)
82+
RETURNS duckdb.unresolved_type AS 'MODULE_PATHNAME', 'duckdb_only_function' LANGUAGE C;

src/pgduckdb_metadata_cache.cpp

Lines changed: 13 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -177,7 +177,19 @@ BuildDuckdbOnlyFunctions() {
177177
"make_timestamptz",
178178
"time_bucket",
179179
"union_extract",
180-
"union_tag"};
180+
"union_tag",
181+
"cardinality",
182+
"element_at",
183+
"map_concat",
184+
"map_contains",
185+
"map_contains_entry",
186+
"map_contains_value",
187+
"map_entries",
188+
"map_extract",
189+
"map_extract_value",
190+
"map_from_entries",
191+
"map_keys",
192+
"map_values"};
181193

182194
for (uint32_t i = 0; i < lengthof(function_names); i++) {
183195
CatCList *catlist = SearchSysCacheList1(PROCNAMEARGSNSP, CStringGetDatum(function_names[i]));
Lines changed: 66 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,66 @@
1+
-- Test MAP functions
2+
-- These tests verify that the MAP functions are properly exposed and working
3+
-- Test map_extract function
4+
SELECT map_extract(r['map_col'], 'a') as extracted_value FROM duckdb.query($$ SELECT MAP(['a', 'b', 'c'], [1, 2, 3]) as map_col $$) r;
5+
extracted_value
6+
-----------------
7+
{1}
8+
(1 row)
9+
10+
SELECT map_extract(r['map_col'], 'd') as missing_key FROM duckdb.query($$ SELECT MAP(['a', 'b', 'c'], [1, 2, 3]) as map_col $$) r;
11+
missing_key
12+
-------------
13+
{}
14+
(1 row)
15+
16+
SELECT map_extract(r['map_col'], 'key1') as string_value FROM duckdb.query($$ SELECT MAP(['key1', 'key2'], ['value1', 'value2']) as map_col $$) r;
17+
string_value
18+
--------------
19+
{value1}
20+
(1 row)
21+
22+
-- Test map_keys function
23+
SELECT map_keys(r['map_col']) as keys FROM duckdb.query($$ SELECT MAP(['a', 'b', 'c'], [1, 2, 3]) as map_col $$) r;
24+
keys
25+
---------
26+
{a,b,c}
27+
(1 row)
28+
29+
SELECT map_keys(r['map_col']) as empty_keys FROM duckdb.query($$ SELECT MAP([], []) as map_col $$) r;
30+
empty_keys
31+
------------
32+
{}
33+
(1 row)
34+
35+
-- Test map_values function
36+
SELECT map_values(r['map_col']) as values FROM duckdb.query($$ SELECT MAP(['a', 'b', 'c'], [1, 2, 3]) as map_col $$) r;
37+
values
38+
---------
39+
{1,2,3}
40+
(1 row)
41+
42+
SELECT map_values(r['map_col']) as empty_values FROM duckdb.query($$ SELECT MAP([], []) as map_col $$) r;
43+
empty_values
44+
--------------
45+
{}
46+
(1 row)
47+
48+
-- Test with unresolved_type for flexibility
49+
SELECT map_extract(r['map_col']::duckdb.unresolved_type, 'x') as flexible_extract FROM duckdb.query($$ SELECT MAP(['x', 'y'], [10, 20]) as map_col $$) r;
50+
flexible_extract
51+
------------------
52+
{10}
53+
(1 row)
54+
55+
SELECT map_keys(r['map_col']::duckdb.unresolved_type) as flexible_keys FROM duckdb.query($$ SELECT MAP(['p', 'q'], [100, 200]) as map_col $$) r;
56+
flexible_keys
57+
---------------
58+
{p,q}
59+
(1 row)
60+
61+
SELECT map_values(r['map_col']::duckdb.unresolved_type) as flexible_values FROM duckdb.query($$ SELECT MAP(['m', 'n'], [1000, 2000]) as map_col $$) r;
62+
flexible_values
63+
-----------------
64+
{1000,2000}
65+
(1 row)
66+

0 commit comments

Comments
 (0)