Skip to content

Commit 2b2d314

Browse files
feat(views): added views and subviews for some KPI
- number of eservices without tokens - number of clients without tokens - number of eservices without tokens in last N days - number of clients without tokens in last N days - ratio, for each consumer tenant, between subscribed eservices and used eservices - average delta time between administrative usage request and first JWT issued, for each eservice. - ratio between declared maximum total daily call for each eservice and sum of daily call promised for each agreement
1 parent 59ed021 commit 2b2d314

18 files changed

+601
-0
lines changed
Lines changed: 41 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,41 @@
1+
CREATE SCHEMA IF NOT EXISTS sub_views;
2+
3+
GRANT USAGE ON SCHEMA sub_views TO GROUP readonly_group;
4+
5+
DROP MATERIALIZED VIEW sub_views.mv_00_client_without_token__raw_data CASCADE;
6+
7+
-- We need to know which client have generated token and which haven't.
8+
-- But we can't use lateral (left or right) join; due to a limitation
9+
-- of redshift materilized views incremental refresh.
10+
-- As a workaround we generate a record for each active client and
11+
-- one for each JWT of that clients; each record has usage_weight field that
12+
-- can assume 0 or 1 value. Making sum of the usage_weight field as a result
13+
-- we can assume that clients with total usage_weight equals 0 are clients
14+
-- never used to detach some JWT.
15+
CREATE MATERIALIZED VIEW sub_views.mv_00_client_without_token__raw_data AUTO REFRESH YES AS
16+
select
17+
t.name as consumer_name,
18+
c.id as client_id,
19+
0 as usage_weight
20+
from
21+
domains.client c
22+
join domains.tenant t on c.consumer_id = t.id
23+
where
24+
not coalesce( c.deleted, false )
25+
and
26+
not coalesce( t.deleted, false )
27+
union all
28+
select
29+
t.name as consumer_name,
30+
c.id as client_id,
31+
1 as usage_weight
32+
from
33+
domains.client c
34+
join domains.tenant t on c.consumer_id = t.id
35+
join jwt.generated_token_audit jwt
36+
on jwt.client_id = c.id
37+
where
38+
not coalesce( c.deleted, false )
39+
and
40+
not coalesce( t.deleted, false )
41+
;
Lines changed: 18 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,18 @@
1+
CREATE SCHEMA IF NOT EXISTS sub_views;
2+
3+
GRANT USAGE ON SCHEMA sub_views TO GROUP readonly_group;
4+
5+
DROP MATERIALIZED VIEW sub_views.mv_01_client_without_token__usage_count CASCADE;
6+
7+
-- number_of_usage is the number of detached JWT.
8+
CREATE MATERIALIZED VIEW sub_views.mv_01_client_without_token__usage_count AS
9+
select
10+
consumer_name,
11+
client_id,
12+
sum( usage_weight) as number_of_usage
13+
from
14+
sub_views.mv_00_client_without_token__raw_data
15+
group by
16+
consumer_name,
17+
client_id
18+
;
Lines changed: 31 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,31 @@
1+
CREATE SCHEMA IF NOT EXISTS views;
2+
3+
GRANT USAGE ON SCHEMA views TO GROUP readonly_group;
4+
GRANT USAGE ON SCHEMA views TO interop_analytics_quicksight_user;
5+
6+
DROP MATERIALIZED VIEW views.mv_02_client_without_token__final CASCADE;
7+
8+
CREATE MATERIALIZED VIEW views.mv_02_client_without_token__final AS
9+
select
10+
consumer_name,
11+
count( client_id ) as client__count,
12+
sum( case when number_of_usage = 0 then 1 else 0 end ) as client_not_used__count,
13+
round(
14+
100
15+
*
16+
sum( case when number_of_usage = 0 then 1 else 0 end )
17+
/
18+
cast( count( client_id) as decimal )
19+
,
20+
2
21+
)
22+
as client_not_used__percent
23+
from
24+
sub_views.mv_01_client_without_token__usage_count
25+
group by
26+
consumer_name
27+
;
28+
29+
comment on view views_test.mv_02_client_without_token__final
30+
is 'This view show, for each consumer tenant: how many active client are registered; \n how many of them have requested at least one token; the ratio in percentage format. '
31+
Lines changed: 42 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,42 @@
1+
CREATE SCHEMA IF NOT EXISTS sub_views;
2+
3+
GRANT USAGE ON SCHEMA sub_views TO GROUP readonly_group;
4+
5+
DROP MATERIALIZED VIEW sub_views.mv_00_client_not_used_after_ts__raw_data CASCADE;
6+
7+
-- We need to know which client have generated token and which haven't.
8+
-- But we can't use lateral (left or right) join; due to a limitation
9+
-- of redshift materilized views incremental refresh.
10+
-- As a workaround we generate a record for each active client and
11+
-- one for each JWT of that clients; each record has issued_at field that
12+
-- can assume -1 value for records not associated to any JWT. As a result clients
13+
-- that have never detached any JWT have max(issued_at) == -1
14+
CREATE MATERIALIZED VIEW sub_views.mv_00_client_not_used_after_ts__raw_data AUTO REFRESH YES AS
15+
select
16+
t.name as consumer_name,
17+
c.id as client_id,
18+
c."name" as client_name,
19+
-1 as issued_at
20+
from
21+
domains.client c
22+
join domains.tenant t on t.id = c.consumer_id
23+
where
24+
not coalesce( c.deleted, false )
25+
and
26+
not coalesce( t.deleted, false )
27+
union all
28+
select
29+
t.name as consumer_name,
30+
c.id as client_id,
31+
c."name" as client_name,
32+
jwt.issued_at as issued_at
33+
from
34+
domains.client c
35+
join domains.tenant t on t.id = c.consumer_id
36+
join jwt.generated_token_audit jwt
37+
on jwt.client_id = c.id
38+
where
39+
not coalesce( c.deleted, false )
40+
and
41+
not coalesce( t.deleted, false )
42+
;
Lines changed: 24 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,24 @@
1+
CREATE SCHEMA IF NOT EXISTS views;
2+
3+
GRANT USAGE ON SCHEMA views TO GROUP readonly_group;
4+
GRANT USAGE ON SCHEMA views TO interop_analytics_quicksight_user;
5+
6+
DROP MATERIALIZED VIEW IF EXISTS views.mv_01_client_not_used_after_ts__last_issued_at CASCADE;
7+
8+
CREATE MATERIALIZED VIEW views.mv_01_client_not_used_after_ts__last_issued_at AS
9+
select
10+
consumer_name,
11+
client_id,
12+
min(client_name) as client_name,
13+
max(issued_at) as last_issued_at,
14+
timestamp 'epoch' + ( max(issued_at) / 1000 ) * interval '1 second' as last_issued_at_ts
15+
from
16+
sub_views.mv_00_client_not_used_after_ts__raw_data
17+
group by
18+
consumer_name,
19+
client_id
20+
;
21+
22+
COMMENT ON VIEW views.mv_01_client_not_used_after_ts__last_issued_at
23+
is 'This view show, for each client, the epoch timestamp of last issued token. \n The last_issued_at field assume value -1 for clients that have never detachd a JWT.'
24+
;
Lines changed: 38 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,38 @@
1+
CREATE SCHEMA IF NOT EXISTS sub_views;
2+
3+
GRANT USAGE ON SCHEMA sub_views TO GROUP readonly_group;
4+
5+
DROP MATERIALIZED VIEW sub_views.mv_00_not_used_subscribed_eservice__raw_data CASCADE;
6+
7+
-- We need to know which eservice was authorized and which wasn't.
8+
-- But we can't use lateral (left or right) join; due to a limitation
9+
-- of redshift materilized views incremental refresh.
10+
-- As a workaround we generate a record for each active eservice and
11+
-- one for each JWT was authorizing that eservice; each record has required_jwt field that
12+
-- can assume 0 or 1 value, 0 if the record is not related to any JWT. The result is
13+
-- that eservices with sum(required_jwt) == 0 are never used.
14+
CREATE MATERIALIZED VIEW sub_views.mv_00_not_used_subscribed_eservice__raw_data AUTO REFRESH YES AS
15+
select
16+
t.name as consumer_name,
17+
p.eservice_id,
18+
0 as required_jwt
19+
from
20+
domains.purpose p
21+
join domains.purpose_version pv on pv.purpose_id = p.id
22+
join domains.tenant t on t.id = p.consumer_id
23+
where
24+
pv.state in ('Active')
25+
union all
26+
select
27+
t.name as consumer_name,
28+
p.eservice_id,
29+
1 as required_jwt
30+
from
31+
domains.purpose p
32+
join domains.purpose_version pv on pv.purpose_id = p.id
33+
join domains.tenant t on t.id = p.consumer_id
34+
join jwt.generated_token_audit jwt
35+
on jwt.purpose_version_id = pv.id
36+
where
37+
pv.state in ('Active')
38+
;
Lines changed: 18 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,18 @@
1+
CREATE SCHEMA IF NOT EXISTS sub_views;
2+
3+
GRANT USAGE ON SCHEMA sub_views TO GROUP readonly_group;
4+
5+
DROP MATERIALIZED VIEW sub_views.mv_01_not_used_subscribed_eservice__usage_count CASCADE;
6+
7+
-- For each eservice show the number of JWT that provide authorization for that eservice calls.
8+
CREATE MATERIALIZED VIEW sub_views.mv_01_not_used_subscribed_eservice__usage_count AS
9+
select
10+
consumer_name,
11+
eservice_id,
12+
sum(required_jwt) as how_many_required_jwt
13+
from
14+
sub_views.mv_00_not_used_subscribed_eservice__raw_data
15+
group by
16+
consumer_name,
17+
eservice_id
18+
;
Lines changed: 33 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,33 @@
1+
CREATE SCHEMA IF NOT EXISTS views;
2+
3+
GRANT USAGE ON SCHEMA views TO GROUP readonly_group;
4+
GRANT USAGE ON SCHEMA views TO interop_analytics_quicksight_user;
5+
6+
DROP MATERIALIZED VIEW IF EXISTS views.mv_02_not_used_subscribed_eservice__final CASCADE;
7+
8+
CREATE MATERIALIZED VIEW views.mv_02_not_used_subscribed_eservice__final AS
9+
select
10+
consumer_name,
11+
sum( case when how_many_required_jwt > 0 then 1 else 0 end ) as used_eservices,
12+
count( * ) as subscribed_eservices,
13+
round(
14+
100
15+
*
16+
(
17+
sum( case when how_many_required_jwt > 0 then 1 else 0 end )
18+
/
19+
cast( count( * ) as decimal )
20+
)
21+
,
22+
2 -- keep two decimal digit
23+
)
24+
as used_eservices_percent
25+
from
26+
sub_views.mv_01_not_used_subscribed_eservice__usage_count
27+
group by
28+
consumer_name
29+
;
30+
31+
COMMENT ON VIEW views.mv_02_not_used_subscribed_eservice__final
32+
is 'For each consumer show the number of subscribed eservices; \n the number of distinct eservices with, at least, one detached token;\n the ration as percentage.\n N.B.: tenant self invocations are included'
33+
;
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,33 @@
1+
CREATE SCHEMA IF NOT EXISTS sub_views;
2+
3+
GRANT USAGE ON SCHEMA sub_views TO GROUP readonly_group;
4+
5+
DROP MATERIALIZED VIEW sub_views.mv_00_avg_first_token_delta_by_eservice__first_issued_token CASCADE;
6+
7+
CREATE MATERIALIZED VIEW sub_views.mv_00_avg_first_token_delta_by_eservice__first_issued_token AUTO REFRESH YES AS
8+
select
9+
t.name as producer_name,
10+
a.eservice_id,
11+
a.id as agreement_id,
12+
min( a_s.when ) as agreement_activation_ts,
13+
min( jwt.issued_at_tz ) as first_jwt_issued_at_tz
14+
from
15+
domains.agreement a
16+
join domains.agreement_stamp a_s on a_s.agreement_id = a.id
17+
join domains.tenant t on t.id = a.producer_id
18+
join jwt.generated_token_audit jwt on jwt.agreement_id = a.id
19+
where
20+
a.state in ('Active', 'Suspended', 'Archived', 'MissingCertifiedAttributes' ) -- Keep every agreement that was "Active" fore some time.
21+
and
22+
a_s.kind = 'activation' -- Select the agreement activation timestamp
23+
and
24+
not coalesce( a.deleted, false)
25+
and
26+
not coalesce( a_s.deleted, false)
27+
and
28+
not coalesce( t.deleted, false)
29+
group by
30+
t.name,
31+
a.eservice_id,
32+
a.id
33+
;
Lines changed: 30 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,30 @@
1+
CREATE SCHEMA IF NOT EXISTS views;
2+
3+
GRANT USAGE ON SCHEMA views TO GROUP readonly_group;
4+
GRANT USAGE ON SCHEMA views TO interop_analytics_quicksight_user;
5+
6+
DROP MATERIALIZED VIEW IF EXISTS views.mv_01_avg_first_token_delta_by_eservice__final CASCADE;
7+
8+
CREATE MATERIALIZED VIEW views.mv_01_avg_first_token_delta_by_eservice__final AS
9+
select
10+
producer_name,
11+
eservice_id,
12+
avg(
13+
datediff(
14+
seconds,
15+
agreement_activation_ts at time zone 'GMT',
16+
first_jwt_issued_at_tz at time zone 'GMT'
17+
)
18+
) as avg_first_token_delta_time__seconds,
19+
count(*) as num_of_agreement
20+
from
21+
sub_views.mv_00_avg_first_token_delta_by_eservice__first_issued_token
22+
group by
23+
producer_name,
24+
eservice_id
25+
;
26+
27+
28+
COMMENT ON VIEW views.mv_01_avg_first_token_delta_by_eservice__final
29+
is 'This view show, for each eservice, the average delta time between agreement accepted time and fist detached JWT issued_at time.\n Self tenant invocation are included.'
30+
;

0 commit comments

Comments
 (0)