Search Postgresql Archives

Re: Using JSONB with nested key-value structures, and skipping/wildcarding the key

[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]

 



> On 1 Jun 2020, at 20:18, Shaheed Haque <shaheedhaque@xxxxxxxxx> wrote:
> 
> Hi,
> 
> I'm using Django's ORM to access Postgres12. My "MyModel" table has a JSONB column called 'snapshot'. In Python terms, each row's 'snapshot' looks like this:
> 
> ======================
> snapshot = {
>     'pay_definition' : {
>         '1234': {..., 'name': 'foo', ...},
>         '99': {..., 'name': 'bar', ...},
> }
> ======================
> 
> I'd like to find all unique values of 'name' in all rows of MyModel. I have this working using native JSON functions from the ORM like this:
> 
> =====================
> class PayDef(Func):
>     function='to_jsonb'
>     template="%(function)s(row_to_json(jsonb_each(%(expressions)s->'pay_definition'))->'value'->'name')"
> 
> MyModel.objects.annotate(paydef=PayDef(F('snapshot'))).order_by().distinct('paydef').values_list('paydef', flat=True)
> =====================
> 
> So, skipping the ordering/distinct/ORM parts, the core looks like this:
> 
> to_jsonb(row_to_json(jsonb_each('snapshot'->'pay_definition'))->'value'->'name’)


I do something like this to get a set of sub-paths in a JSONB field (no idea how to write that in Django):

select snapshot->’pay_definition’->k.value->’name’
  from MyModel
  join lateral jsonb_object_keys(snapshot->’pay_definition’) k(value) on true

I don’t know how that compares performance-wise to using jsonb_each, but perhaps worth a try. Obviously, the way it’s written above it doesn’t return distinct values of ’name’ yet, but that’s fairly easy to remedy.

Alban Hertroys
--
If you can't see the forest for the trees,
cut the trees and you'll find there is no forest.







[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]
[Index of Archives]     [Postgresql Jobs]     [Postgresql Admin]     [Postgresql Performance]     [Linux Clusters]     [PHP Home]     [PHP on Windows]     [Kernel Newbies]     [PHP Classes]     [PHP Books]     [PHP Databases]     [Postgresql & PHP]     [Yosemite]

  Powered by Linux