Created
September 10, 2015 09:28
-
-
Save stevelacey/1006d713443f77fcb809 to your computer and use it in GitHub Desktop.
Collect recursive JSON key paths In Postgres
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
WITH RECURSIVE doc_key_and_value_recursive(key, value) AS ( | |
SELECT | |
t.key, | |
t.value | |
FROM ideas, json_each(ideas.custom) AS t | |
WHERE ideas.bucket_id = 889 | |
UNION ALL | |
SELECT | |
CONCAT(doc_key_and_value_recursive.key, '.', t.key), | |
t.value | |
FROM doc_key_and_value_recursive, | |
json_each(CASE | |
WHEN json_typeof(doc_key_and_value_recursive.value) <> 'object' THEN '{}' :: JSON | |
ELSE doc_key_and_value_recursive.value | |
END) AS t | |
) | |
SELECT DISTINCT key | |
FROM doc_key_and_value_recursive | |
WHERE json_typeof(doc_key_and_value_recursive.value) NOT IN ('array', 'object') | |
ORDER BY key |
Hi,
I come from the StackOverflow post you commented with your solution!
Combined with array solution, this code becomes really powerful!
Thank you very much for sharing it,
Théophile.
BTW : as said in the post, change ligne 12 to the following code in order to avoid table issues.
-----------------
CASE
WHEN (json_typeof(t.value)='array')
THEN json_array_elements(t.value)
ELSE t.value
END
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment
=>