Source

hbbackend / schema / hbstats_functions.sql

Full commit
  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
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
create or replace function create_table_new_main() returns varchar as $$

create unlogged table _new_main(
  id           bigint,
  ts           timestamp with time zone,
  ident_id     bigint,
  ident        varchar(16),
  binary_id    bigint,
  md5          char(32),
  sha512       char(128),
  source_ip    inet,
  target_port  int,
  target_ip    inet,

  agg_id           bigint,
  ident_id_local   bigint,
  binary_id_local  bigint
);
select '_new_main'::varchar;

$$ language sql;


create or replace function new_main_get(out last_id bigint, out first_id bigint, out n_rows bigint) as $$
begin
select max(id), min(id), count(*) into last_id, first_id, n_rows from _new_main;
end;
$$ language plpgsql;


create or replace function drop_table_new_main() returns void as $$
begin
drop table _new_main;
end;
$$ language plpgsql;


create or replace function merge_main_ident() returns void as $$
begin

-- create table _merge_main_ident(
--   ident           varchar(16),
--   ident_id_local  bigint,
--   n_count         bigint,
--   ts_last         timestamp with time zone,
--   ts_first        timestamp with time zone
-- );

create unlogged table _merge_main_ident as
  select a.ident, dim_ident.id as ident_id_local, a.n_count, a.ts_last, a.ts_first
    from
      (select ident, count(*) as n_count, max(ts) as ts_last, min(ts) as ts_first
       from _new_main where ident is not null
       group by ident
      ) as a
      left join dim_ident on a.ident = dim_ident.ident
;

-- update existing
update dim_ident
  set
    n_count = coalesce(dim_ident.n_count, 0) + _merge_main_ident.n_count,
    ts_last = greatest(dim_ident.ts_last, _merge_main_ident.ts_last),
    ts_first = least(dim_ident.ts_first, _merge_main_ident.ts_first)
  from _merge_main_ident
  where id = _merge_main_ident.ident_id_local and id is not null
;

-- insert new and get ids
with i as (
  insert into dim_ident (ident, n_count, ts_last, ts_first)
    select ident, n_count, ts_last, ts_first
    from _merge_main_ident where ident_id_local is null
    returning ident, id
)
update _merge_main_ident
  set
    ident_id_local = i.id
  from i
  where _merge_main_ident.ident = i.ident
;

-- copy back local ids
update _new_main
  set
    ident_id_local = _merge_main_ident.ident_id_local
  from _merge_main_ident
  where _new_main.ident = _merge_main_ident.ident
;

end;
$$ language plpgsql;


create or replace function merge_main_binary() returns void as $$
begin

-- create table _merge_main_binary(
--   md5              char(32),
--   sha512           char(128),
--   binary_id_local  bigint,
--   n_count          bigint,
--   ts_last          timestamp with time zone,
--   ts_first         timestamp with time zone
-- );

create unlogged table _merge_main_binary as
  select a.md5, a.sha512, dim_binary.id as binary_id_local, a.n_count, a.ts_last, a.ts_first
    from
      (select md5, min(sha512) as sha512, count(*) as n_count, max(ts) as ts_last, min(ts) as ts_first
       from _new_main where md5 is not null
       group by md5
      ) as a
      left join dim_binary on a.md5 = dim_binary.md5
;

-- update existing
update dim_binary
  set
    n_count = coalesce(dim_binary.n_count, 0) + _merge_main_binary.n_count,
    ts_last = greatest(dim_binary.ts_last, _merge_main_binary.ts_last),
    ts_first = least(dim_binary.ts_first, _merge_main_binary.ts_first)
  from _merge_main_binary
  where id = _merge_main_binary.binary_id_local and id is not null
;

-- insert new and get ids
with i as (
  insert into dim_binary (md5, sha512, n_count, ts_last, ts_first)
    select md5, sha512, n_count, ts_last, ts_first
    from _merge_main_binary where binary_id_local is null
    returning md5, id
)
update _merge_main_binary
  set
    binary_id_local = i.id
  from i
  where _merge_main_binary.md5 = i.md5
;

-- copy back local ids
update _new_main
  set
    binary_id_local = _merge_main_binary.binary_id_local
  from _merge_main_binary
  where _new_main.md5 = _merge_main_binary.md5
;

end;
$$ language plpgsql;


create or replace function merge_main_source_ip() returns void as $$
begin

-- create table merge_main_source_ip(
--   source_ip        inet,
--   source_ip_local  inet,
--   n_count          bigint,
--   ts_last          timestamp with time zone,
--   ts_first         timestamp with time zone
-- );

create unlogged table _merge_main_source_ip as
  select a.source_ip, dim_source_ip.ip as source_ip_local, a.n_count, a.ts_last, a.ts_first
    from
      (select source_ip, count(*) as n_count, max(ts) as ts_last, min(ts) as ts_first
       from _new_main where source_ip is not null
       group by source_ip
      ) as a
      left join dim_source_ip on a.source_ip = dim_source_ip.ip
;

-- update existing
update dim_source_ip
  set
    n_count = coalesce(dim_source_ip.n_count, 0) + _merge_main_source_ip.n_count,
    ts_last = greatest(dim_source_ip.ts_last, _merge_main_source_ip.ts_last),
    ts_first = least(dim_source_ip.ts_first, _merge_main_source_ip.ts_first)
  from _merge_main_source_ip
  where ip = _merge_main_source_ip.source_ip_local and ip is not null
;

-- insert new ips
insert into dim_source_ip (ip, n_count, ts_last, ts_first)
  select source_ip, n_count, ts_last, ts_first
  from _merge_main_source_ip where source_ip_local is null
;

end;
$$ language plpgsql;


create or replace function merge_main_target_port() returns void as $$
begin

-- create table _merge_main_target_port(
--   target_port        int,
--   target_port_local  int,
--   n_count            bigint,
--   ts_last            timestamp with time zone,
--   ts_first           timestamp with time zone
-- );

create unlogged table _merge_main_target_port as
  select a.target_port, dim_target_port.port as target_port_local, a.n_count, a.ts_last, a.ts_first
    from
      (select target_port, count(*) as n_count, max(ts) as ts_last, min(ts) as ts_first
       from _new_main where target_port is not null
       group by target_port
      ) as a
      left join dim_target_port on a.target_port = dim_target_port.port
;

-- update existing
update dim_target_port
  set
    n_count = coalesce(dim_target_port.n_count, 0) + _merge_main_target_port.n_count,
    ts_last = greatest(dim_target_port.ts_last, _merge_main_target_port.ts_last),
    ts_first = least(dim_target_port.ts_first, _merge_main_target_port.ts_first)
  from _merge_main_target_port
  where port = _merge_main_target_port.target_port_local and port is not null
;

-- insert new ports
insert into dim_target_port (port, n_count, ts_last, ts_first)
  select target_port, n_count, ts_last, ts_first
  from _merge_main_target_port where target_port_local is null
;

end;
$$ language plpgsql;


create or replace function merge_main_target_ip() returns void as $$
begin

-- create table _merge_main_target_ip(
--   target_ip        inet,
--   target_ip_local  inet,
--   n_count          bigint,
--   ts_last          timestamp with time zone,
--   ts_first         timestamp with time zone
-- );

create unlogged table _merge_main_target_ip as
  select a.target_ip, dim_target_ip.ip as target_ip_local, a.n_count, a.ts_last, a.ts_first
    from
      (select target_ip, count(*) as n_count, max(ts) as ts_last, min(ts) as ts_first
       from _new_main where target_ip is not null
       group by target_ip
      ) as a
      left join dim_target_ip on a.target_ip = dim_target_ip.ip
;

-- update existing
update dim_target_ip
  set
    n_count = coalesce(dim_target_ip.n_count, 0) + _merge_main_target_ip.n_count,
    ts_last = greatest(dim_target_ip.ts_last, _merge_main_target_ip.ts_last),
    ts_first = least(dim_target_ip.ts_first, _merge_main_target_ip.ts_first)
  from _merge_main_target_ip
  where ip = _merge_main_target_ip.target_ip_local and ip is not null
;

-- insert new ips
insert into dim_target_ip (ip, n_count, ts_last, ts_first)
  select target_ip, n_count, ts_last, ts_first
  from _merge_main_target_ip where target_ip_local is null
;

end;
$$ language plpgsql;


create or replace function merge_agg_main() returns void as $$
begin

perform merge_main_ident();
perform merge_main_binary();
perform merge_main_source_ip();
perform merge_main_target_port();
perform merge_main_target_ip();

create unlogged table _merge_agg_main as
  select
    a.ident_id, a.binary_id, a.source_ip, a.target_port, a.target_ip,
    a.n_count, a.ts_last, a.ts_first,
    agg_main.agg_id
  from
    (select
        ident_id_local as ident_id, binary_id_local as binary_id,
        source_ip, target_port, target_ip,
        count(*) as n_count, max(ts) as ts_last, min(ts) as ts_first
      from _new_main
      where
        not (ident_id_local is null
             or binary_id_local is null
             or source_ip is null
             or target_port is null
             or target_ip is null
            )
      group by
        ident_id_local, binary_id_local,
        source_ip, target_port, target_ip
    ) as a
    left join agg_main on
      a.ident_id = agg_main.ident_id and
      a.binary_id = agg_main.binary_id and
      a.source_ip = agg_main.source_ip and
      a.target_port = agg_main.target_port and
      a.target_ip = agg_main.target_ip
;

-- update existing
update agg_main
  set
    n_count = coalesce(agg_main.n_count, 0) + _merge_agg_main.n_count,
    ts_last = greatest(agg_main.ts_last, _merge_agg_main.ts_last),
    ts_first = least(agg_main.ts_first, _merge_agg_main.ts_first)
  from _merge_agg_main
  where agg_main.agg_id = _merge_agg_main.agg_id and _merge_agg_main.agg_id is not null
;

-- insert new and get ids
with i as (
  insert into agg_main (ident_id, binary_id, source_ip, target_port, target_ip, n_count, ts_last, ts_first)
    select ident_id, binary_id, source_ip, target_port, target_ip, n_count, ts_last, ts_first
    from _merge_agg_main where agg_id is null
    returning ident_id, binary_id, source_ip, target_port, target_ip, n_count, ts_last, ts_first, agg_id
)
update _merge_agg_main
  set
    agg_id = i.agg_id
  from i
  where
    _merge_agg_main.ident_id = i.ident_id and
    _merge_agg_main.binary_id = i.binary_id and
    _merge_agg_main.source_ip = i.source_ip and
    _merge_agg_main.target_port = i.target_port and
    _merge_agg_main.target_ip = i.target_ip
;

-- copy back ids
update _new_main
  set
    agg_id = _merge_agg_main.agg_id
  from _merge_agg_main
  where
    _new_main.ident_id_local = _merge_agg_main.ident_id and
    _new_main.binary_id_local = _merge_agg_main.binary_id and
    _new_main.source_ip = _merge_agg_main.source_ip and
    _new_main.target_port = _merge_agg_main.target_port and
    _new_main.target_ip = _merge_agg_main.target_ip
;

drop table _merge_agg_main;
drop table _merge_main_ident;
drop table _merge_main_binary;
drop table _merge_main_source_ip;
drop table _merge_main_target_port;
drop table _merge_main_target_ip;

end;
$$ language plpgsql;


create or replace function merge_ts_main_min() returns void as $$
begin

create unlogged table _merge_ts_main_min as
  select
    a.ts_min, a.agg_id, a.n_count,
    ts_main_min.ts_min as ts_min_local, ts_main_min.agg_id as agg_id_local
  from
    (select
        date_trunc('minute', ts) as ts_min, agg_id, count(*) as n_count
      from _new_main
      where
        not (ts is null or agg_id is null)
      group by ts_min, agg_id
    ) as a
    left join ts_main_min on
      a.ts_min = ts_main_min.ts_min and
      a.agg_id = ts_main_min.agg_id
;

-- update existing
update ts_main_min
  set
    n_count = coalesce(ts_main_min.n_count, 0) + _merge_ts_main_min.n_count
  from _merge_ts_main_min
  where
    ts_main_min.ts_min = _merge_ts_main_min.ts_min_local and ts_main_min.agg_id = _merge_ts_main_min.agg_id_local and
    not (_merge_ts_main_min.ts_min_local is null or _merge_ts_main_min.agg_id_local is null)
;

-- insert new
insert into ts_main_min (ts_min, agg_id, n_count)
  select ts_min, agg_id, n_count
  from _merge_ts_main_min
  where
    ts_min_local is null and agg_id_local is null
;

drop table _merge_ts_main_min;

end;
$$ language plpgsql;




create or replace function x_log_main_get(out x_log_main.last_id%type) as $$

select last_id from x_log_main where id = (select max(id) from x_log_main);

$$ language sql;


create or replace function x_log_main_insert(x_log_main.last_id%type, x_log_main.first_id%type, x_log_main.n_rows%type, out x_log_main.id%type) as $$

insert into x_log_main
    (last_id, first_id, n_rows, ts_compl, ts_start)
  values
    ($1, $2, $3, statement_timestamp(), transaction_timestamp())
  returning id;

$$ language sql;



-- virustotal
create or replace function create_table_new_virustotal() returns varchar as $$

create unlogged table _new_virustotal(
    md5            char(32),
    response_code  int,
    result_count   bigint,
    scan_id    	   varchar,
    scan_date      timestamp with time zone,
    permalink      varchar,
    ts             timestamp with time zone,
    label          varchar,
    engine         varchar,
    e_version      varchar,
    e_update       varchar
);
select '_new_virustotal'::varchar;

$$ language sql;

create or replace function merge_virustotal() returns void as $$
begin

-- update existing
alter table _new_virustotal add column local_binary_id bigint;
alter table _new_virustotal add column local_ts timestamp with time zone;
update _new_virustotal
  set
    local_binary_id = att_virustotal_report.binary_id,
    local_ts = att_virustotal_report.ts
  from
    att_virustotal_report join dim_binary on att_virustotal_report.binary_id = dim_binary.id
  where
    _new_virustotal.md5 = dim_binary.md5
;
delete from att_virustotal_result
  where
    att_virustotal_result.binary_id in
      (select distinct local_binary_id from _new_virustotal where local_binary_id is not null and ts > local_ts)
;
delete from att_virustotal_report
  where
    att_virustotal_report.binary_id in
      (select distinct local_binary_id from _new_virustotal where local_binary_id is not null and ts > local_ts)
;
insert into att_virustotal_report
  select distinct local_binary_id as binary_id, response_code, result_count, scan_id, scan_date, permalink, ts
    from _new_virustotal
    where local_binary_id is not null and ts > local_ts
;
insert into att_virustotal_result
  select distinct local_binary_id as binary_id, label, engine, e_version, e_update
    from _new_virustotal
    where local_binary_id is not null and ts > local_ts
;
delete from _new_virustotal
  where local_binary_id is not null
;

-- insert new
update _new_virustotal
  set
    local_binary_id = t.id
  from
    (select id, md5 from dim_binary where md5 in (select distinct md5 from _new_virustotal where md5 is not null)) as t
  where
    _new_virustotal.md5 = t.md5
;
insert into att_virustotal_report
  select distinct local_binary_id as binary_id, response_code, result_count, scan_id, scan_date, permalink, ts
    from _new_virustotal
    where local_binary_id is not null
;
insert into att_virustotal_result
  select distinct local_binary_id as binary_id, label, engine, e_version, e_update
    from _new_virustotal
    where local_binary_id is not null
;

end;
$$ language plpgsql;


-- asn_shadowserver
create or replace function create_table_new_asn_shadowserver() returns varchar as $$

create unlogged table _new_asn_shadowserver(
    ip          inet,
    asn         bigint,
    as_name     varchar,
    cc          char(2),
    dom         varchar,
    isp         varchar,
    bgp_prefix  inet,
    ts          timestamp with time zone
);
select '_new_asn_shadowserver'::varchar;

$$ language sql;

create or replace function merge_asn_shadowserver() returns void as $$
begin

-- update existing
alter table _new_asn_shadowserver add column local_ip inet;
alter table _new_asn_shadowserver add column local_ts timestamp with time zone;
update _new_asn_shadowserver
  set
    local_ip = t.ip,
    local_ts = t.ts
  from
    (select ip, ts from att_asn_shadowserver where ip in (select distinct ip from _new_asn_shadowserver where ip is not null)) as t
  where
    _new_asn_shadowserver.ip = t.ip
;
delete from att_asn_shadowserver
  where ip in (select distinct local_ip from _new_asn_shadowserver where local_ip is not null and ts > local_ts)
;
insert into att_asn_shadowserver
  select distinct local_ip as ip, asn, as_name, cc, dom, isp, bgp_prefix, ts 
    from _new_asn_shadowserver
    where local_ip is not null and ts > local_ts
;
delete from _new_asn_shadowserver
  where local_ip is not null
;

-- insert new
insert into att_asn_shadowserver
  select distinct ip, asn, as_name, cc, dom, isp, bgp_prefix, ts 
  from _new_asn_shadowserver
  where ip is not null
;

end;
$$ language plpgsql;


-- geoip_shadowserver
create or replace function create_table_new_geoip_shadowserver() returns varchar as $$

create unlogged table _new_geoip_shadowserver(
    ip         inet,
    cc         char(2),
    city       varchar,
    latitude   float,
    longitude  float,
    ts         timestamp with time zone
);
select '_new_geoip_shadowserver'::varchar;

$$ language sql;


create or replace function merge_geoip_shadowserver() returns void as $$
begin

-- update existing
alter table _new_geoip_shadowserver add column local_ip inet;
alter table _new_geoip_shadowserver add column local_ts timestamp with time zone;
update _new_geoip_shadowserver
  set
    local_ip = t.ip,
    local_ts = t.ts
  from
    (select ip, ts from att_geoip_shadowserver where ip in (select distinct ip from _new_geoip_shadowserver where ip is not null)) as t
  where
    _new_geoip_shadowserver.ip = t.ip
;
delete from att_geoip_shadowserver
  where ip in (select distinct local_ip from _new_geoip_shadowserver where local_ip is not null and ts > local_ts)
;
insert into att_geoip_shadowserver
  select distinct local_ip as ip, cc, city, latitude, longitude, ts
    from _new_geoip_shadowserver
    where local_ip is not null and ts > local_ts
;
delete from _new_geoip_shadowserver
  where local_ip is not null
;

-- insert new
insert into att_geoip_shadowserver
  select distinct ip, cc, city, latitude, longitude, ts
  from _new_geoip_shadowserver
  where ip is not null
;

end;
$$ language plpgsql;


create or replace function drop_table_new_virustotal() returns void as $$
begin
drop table _new_virustotal;
end;
$$ language plpgsql;

create or replace function drop_table_new_asn_shadowserver() returns void as $$
begin
drop table _new_asn_shadowserver;
end;
$$ language plpgsql;

create or replace function drop_table_new_geoip_shadowserver() returns void as $$
begin
drop table _new_geoip_shadowserver;
end;
$$ language plpgsql;