-
Notifications
You must be signed in to change notification settings - Fork 0
/
format_report.sql
281 lines (274 loc) · 8.55 KB
/
format_report.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
-- FUNCTION: code_src.format_report(integer)
-- DROP FUNCTION code_src.format_report(integer);
CREATE OR REPLACE FUNCTION code_src.format_report(
report_id integer)
RETURNS text
LANGUAGE 'plpgsql'
COST 100
VOLATILE SECURITY DEFINER
AS $BODY$
DECLARE
retval text;
v_rpt_data json;
html_base text;
v_title text;
v_subtitle text;
v_author text;
v_data text;
v_data_line text;
rec v_report_daily_list%ROWTYPE;
v_header text;
v_header_style text;
v_rec_num integer;
v_footer text;
v_style text;
v_row_style1 text;
v_row_style2 text;
v_title_array text[];
v_row_array text[];
v_cols integer;
v_sql text;
BEGIN
/*
Summary:
Format a report in HTML;
Testing:
SELECT format_report(1); -- '[{"stats_type":"Source #","stats_count":0}, {"stats_type":"Task #","stats_count":0}, {"stats_type":"transaction #","stats_count":0}, {"stats_type":"Control task #","stats_count":0}, {"stats_type":"AMA #","stats_count":0}, {"stats_type":"LFN #","stats_count":0}]')
SELECT format_report(1);
select json_array_length(rpt_daily())
select json_each(rpt_daily()->0)
select json_each_text(rpt_daily()->0)
select json_object_keys(rpt_daily()->0)
select * from json_populate_recordset(null::record, '[{"stats_type":"Source #","stats_count":0}, {"stats_type":"Task #","stats_count":0}, {"stats_type":"transaction #","stats_count":0}, {"stats_type":"Control task #","stats_count":0}, {"stats_type":"AMA #","stats_count":0}, {"stats_type":"LFN #","stats_count":0}]')
as
( stats_type text,
stats_count text
)
*/
html_base = '<style>
table
{
border-collapse: collapse;
width:100%;
}
th, td
{
padding: 2px;
}
th
{
[HEADER_STYLE]
}
.title
{
[TITLE_STYLE]
}
.subtitle
{
[SUBTITLE_STYLE]
}
.author
{
[AUTHOR_STYLE]
}
.footer
{
[FOOTER_STYLE]
}
.row_style1
{
[ROW_STYLE1]
}
.row_style2
{
[ROW_STYLE2]
}
.center
{
text-align:center;
}
.left
{
text-align:left;
}
.right
{
text-align:right;
}
</style>
<body>
<table>
[TITLE]
[SUBTITLE]
[AUTHOR]
</table>
<table border = 1>
<tr>
[REPORTHEADER]
</tr>
[DATA]
</table>
<table>
<tr><td> </td></tr>
<tr><td class=''footer''>[FOOTER]</td></tr>
</table>
</body>
';
retval = html_base;
SELECT * INTO rec
FROM v_report_daily_list
WHERE id = report_id
LIMIT 1;
IF rec IS NOT NULL THEN
v_sql = 'SELECT ' || rec.procedure_name || '()';
EXECUTE v_sql INTO v_rpt_data;
-- Generate title
v_title = rec.title;
IF v_title IS NOT NULL
AND LENGTH(v_title) > 0 THEN
v_title = REPLACE('<tr><td class=''title''>[TITLE]</td></tr>', '[TITLE]', v_title);
ELSE
v_title = '';
END IF;
-- title style
SELECT coalesce(value, ' ') INTO v_style
FROM configuration
WHERE category = 'report'
and type = 'settings'
and name = 'title style';
IF v_style is null or length(trim(v_style)) = 0 THEN v_style = ''; END IF;
retval = replace(retval,'[TITLE_STYLE]', v_style);
--raise notice 'After Title generation: %;', retval;
-- Generate subtitle
v_subtitle = rec.subtitle;
IF v_subtitle IS NOT NULL
AND LENGTH(v_subtitle) > 0 THEN
v_subtitle = REPLACE('<tr><td class=''subtitle''>[SUBTITLE]</td></tr>', '[SUBTITLE]', v_subtitle);
ELSE
v_subtitle = '';
END IF;
-- subtitle style
SELECT coalesce(value, ' ') INTO v_style
FROM configuration
WHERE category = 'report'
and type = 'settings'
and name = 'subtitle style';
IF v_style is null or length(trim(v_style)) = 0 THEN v_style = ''; END IF;
retval = replace(retval,'[SUBTITLE_STYLE]', v_style);
--raise notice 'After Subtitle generation: %;', retval;
-- Generate footer
IF rec.footer IS NOT NULL
AND LENGTH(rec.footer) > 0 THEN
v_footer = rec.footer;
ELSE
v_footer = '';
END IF;
-- Generate author
v_author = rec.author;
IF v_author IS NOT NULL
AND LENGTH(v_author) > 0 THEN
v_author = REPLACE('<tr><td class=''author''>[AUTHOR]</td></tr>', '[AUTHOR]', v_author);
ELSE
v_author = '';
END IF;
-- Author style
SELECT coalesce(value, ' ') INTO v_style
FROM configuration
WHERE category = 'report'
and type = 'settings'
and name = 'author style';
IF v_style is null or length(v_style) = 0 THEN v_style = ''; END IF;
retval = replace(retval,'[AUTHOR_STYLE]', v_style);
--raise notice 'After Author generation: %;', retval;
-- Generate report data
--raise notice 'Title: %; Subtitle: %; Author: %', v_title, v_subtitle, v_author;
retval = replace(retval,'[TITLE]', v_title);
retval = replace(retval,'[SUBTITLE]', v_subtitle);
retval = replace(retval,'[FOOTER]', v_footer);
retval = replace(retval,'[AUTHOR]', v_author);
-- Generate table header
SELECT string_agg(f, '</th><th>') INTO v_header
FROM
(
SELECT json_object_keys(v_rpt_data->0) f
) t;
v_header = '<th>' || v_header || '</th>';
retval = replace(retval,'[REPORTHEADER]', v_header);
SELECT coalesce(value, ' ') INTO v_header_style
FROM configuration
WHERE category = 'report'
and type = 'settings'
and name = 'header style';
IF v_header_style is null or length(trim(v_header_style)) = 0 THEN v_header_style = ''; END IF;
retval = replace(retval,'[HEADER_STYLE]', v_header_style);
-- Footer style
SELECT coalesce(value, ' ') INTO v_style
FROM configuration
WHERE category = 'report'
and type = 'settings'
and name = 'footer style';
IF v_style is null or length(trim(v_style)) = 0 THEN v_style = ''; END IF;
retval = replace(retval,'[FOOTER_STYLE]', v_style);
-- Generate table data
SELECT json_array_length(v_rpt_data) INTO v_rec_num;
v_data = '';
-- Row style 1
SELECT coalesce(value, ' ') INTO v_row_style1
FROM configuration
WHERE category = 'report'
and type = 'settings'
and name = 'alternative row style 1';
IF v_row_style1 is null or length(trim(v_row_style1)) = 0 THEN v_row_style1 = ''; END IF;
retval = replace(retval, '[ROW_STYLE1]', v_row_style1);
-- Row style 2
SELECT coalesce(value, ' ') INTO v_row_style2
FROM configuration
WHERE category = 'report'
and type = 'settings'
and name = 'alternative row style 2';
IF v_row_style2 is null or length(trim(v_row_style2)) = 0 THEN v_row_style2 = ''; END IF;
retval = replace(retval, '[ROW_STYLE2]', v_row_style2);
-- Parse table data
SELECT ARRAY(SELECT json_object_keys(rpt_daily()->0)) INTO v_title_array;
FOR row_num IN 0..v_rec_num -1 LOOP
v_data_line = '';
SELECT ARRAY
(
SELECT value
FROM json_each_text(v_rpt_data->row_num)
) INTO v_row_array;
--raise notice 'Header1:%; Col 1:%; Array length:%;', v_title_array[1], v_row_array[1], array_upper(v_title_array, 1);
FOR col_num IN 1..array_upper(v_title_array, 1) LOOP
--raise notice 'Header:%; Col:%; Array length:%;', v_title_array[col_num], v_row_array[col_num], array_upper(v_title_array, 1);
IF POSITION('[C]' IN v_title_array[col_num]) > 0 THEN
v_data_line = v_data_line || '<td class = ''center''>' || v_row_array[col_num] || '</td>';
ELSIF POSITION('[L]' IN v_title_array[col_num]) > 0 THEN
v_data_line = v_data_line || '<td class = ''left''>' || v_row_array[col_num] || '</td>';
ELSIF POSITION('[R]' IN v_title_array[col_num]) > 0 THEN
v_data_line = v_data_line || '<td class = ''right''>' || v_row_array[col_num] || '</td>';
END IF;
END LOOP;
-- Apply alternative row styles
IF row_num % 2 = 0 THEN
v_data = v_data || '<tr class=''row_style1''>' || v_data_line || '</tr>';
ELSE
v_data = v_data || '<tr class=''row_style2''>' || v_data_line || '</tr>';
END IF;
END LOOP;
retval = replace(retval,'[DATA]', v_data);
-- Remove column alignment definiction
retval = format_report_placeholder(retval);
RETURN retval;
ELSE
RETURN '';
END IF;
EXCEPTION
WHEN OTHERS THEN
RAISE NOTICE '%', SQLERRM;
RETURN 'Failed to format the report data: ' || SQLERRM;
END;
$BODY$;
ALTER FUNCTION code_src.format_report(integer)
OWNER TO network;
GRANT EXECUTE ON FUNCTION code_src.format_report(integer) TO network;
REVOKE ALL ON FUNCTION code_src.format_report(integer) FROM PUBLIC;