forecast_api/route_sql/list_changes.sql
2020-02-18 17:10:49 -05:00

40 lines
924 B
SQL

WITH
list AS materialized (
SELECT
l.doc->>'user' "user",
jsonb_path_query_first(l.doc,'$.scenario.quota_rep_descr')->>0 quota_rep_descr,
to_char((l.doc->>'stamp')::timestamptz,'YYYY-MM-DD HH:MI:SS') "stamp",
l.doc->>'tag' "tag",
l.doc->>'message' "comment",
jsonb_pretty(l.doc) def,
l.id
FROM
rlarp.osm_log l
WHERE
l.doc @? '$.scenario.quota_rep_descr ? (@ == replace_user)'
)
,agg as (
SELECT
list.user
,list.quota_rep_descr
,list.stamp
,list.tag
,list.comment
,list.def
,list.id
,to_char(round(sum(value_usd),2),'$999,999,999D00') sales
from
LIST
inner join rlarp.osm_pool on
id = logid
group BY
list.user
,list.quota_rep_descr
,list.stamp
,list.tag
,list.comment
,list.def
,list.id
)
SELECT
jsonb_agg(row_to_json(agg)::jsonb ORDER BY agg.stamp desc) x from agg