tps/database/interface/source_maint/srce_build_view.sql

33 lines
1005 B
MySQL
Raw Normal View History

DROP FUNCTION IF EXISTS tps.build_srce_view_sql(text, text);
CREATE OR REPLACE FUNCTION tps.build_srce_view_sql(_srce text, _schema text) RETURNS TEXT
2018-05-24 13:22:46 -04:00
AS
2018-05-23 17:18:17 -04:00
$f$
2018-05-24 13:22:46 -04:00
DECLARE
--_schema text;
--_srce text;
2018-05-23 17:18:17 -04:00
_sql text;
BEGIN
2018-05-24 13:22:46 -04:00
--_schema:= 'default';
--_srce:= 'dcard';
2018-05-23 17:18:17 -04:00
SELECT
'DROP VIEW IF EXISTS tpsv.'||s.srce||'_'||(list.e->>'name')||'; CREATE VIEW tpsv.'||s.srce||'_'||(list.e->>'name')||' AS SELECT id, logid, allj, '||string_agg('(allj#>>'''||rec.PATH::text||''')::'||rec.type||' AS "'||rec.column_name||'"',', ')||' FROM tps.trans WHERE srce = '''||s.srce||''';'
INTO
2018-05-23 17:18:17 -04:00
_sql
FROM
tps.srce s
JOIN LATERAL jsonb_array_elements(s.defn->'schemas') list (e) ON TRUE
JOIN LATERAL jsonb_array_elements(list.e->'columns') as cols(e) ON TRUE
JOIN LATERAL jsonb_to_record (cols.e) AS rec( PATH text[], "type" text, column_name text) ON TRUE
2018-05-23 17:18:17 -04:00
WHERE
srce = _srce
AND list.e->>'name' = _schema
2018-05-23 17:18:17 -04:00
GROUP BY
s.srce
,list.e;
2018-05-23 17:18:17 -04:00
2018-05-24 13:22:46 -04:00
RETURN _sql;
2018-05-23 17:18:17 -04:00
RAISE NOTICE '%',_sql;
END
2018-05-24 13:22:46 -04:00
$f$
LANGUAGE plpgsql;