Skip to content

Commit

Permalink
Add query samples to basic monitoring (#392)
Browse files Browse the repository at this point in the history
- remove unused comment
- add query samples
- add connection details
- add 3 query samples
- use new docker image
- remove unused comment
- use new docker image
- add reference table and result image to each row
- add result image to images directory
- fix small bug
  • Loading branch information
o-mura authored Mar 15, 2024
1 parent 99d5d78 commit 3fbbad0
Show file tree
Hide file tree
Showing 29 changed files with 311 additions and 33 deletions.
2 changes: 2 additions & 0 deletions scenarios/monitoring/basic_monitoring/common/settings.yaml
Original file line number Diff line number Diff line change
Expand Up @@ -4,6 +4,8 @@ td:
jobs: jobs
connections: connections
connections_history: connections_history
connections_details: connections_details
connections_details_history: connections_details_history
schedules: schedules
schedules_history: schedules_history
sources: sources
Expand Down
33 changes: 28 additions & 5 deletions scenarios/monitoring/basic_monitoring/incremental_ingest.dig
Original file line number Diff line number Diff line change
Expand Up @@ -17,7 +17,30 @@ schedule:
dest_table: ${td.tables.connections}
api_endpoint: ${td.api_endpoint}
docker:
image: "digdag/digdag-python:3.9"
image: "digdag/digdag-python:3.10.1"
_env:
TD_API_KEY: ${secret:td.apikey}

+increment_ingest_connection_details:
+append_connection_details_history:
td>:
query: select * from ${td.tables.connections_details}
database: ${td.database}
insert_into: ${td.tables.connections_details_history}

+get_all_connection:
td>:
query: SELECT ARRAY_JOIN(ARRAY_AGG(name), ',') AS names FROM connections
store_last_results: true

+ingest_connection_details:
py>: scripts.ingest_connection_details.run
dest_db: ${td.database}
dest_table: ${td.tables.connections_details}
names: ${td.last_results.names}
api_endpoint: ${td.api_endpoint}
docker:
image: "digdag/digdag-python:3.10.1"
_env:
TD_API_KEY: ${secret:td.apikey}

Expand All @@ -33,7 +56,7 @@ schedule:
dest_table: ${td.tables.schedules}
api_endpoint: ${td.api_endpoint}
docker:
image: "digdag/digdag-python:3.9"
image: "digdag/digdag-python:3.10.1"
_env:
TD_API_KEY: ${secret:td.apikey}

Expand All @@ -49,7 +72,7 @@ schedule:
dest_table: ${td.tables.sources}
api_endpoint: ${td.api_endpoint}
docker:
image: "digdag/digdag-python:3.9"
image: "digdag/digdag-python:3.10.1"
_env:
TD_API_KEY: ${secret:td.apikey}

Expand All @@ -69,7 +92,7 @@ schedule:
ids: ${td.last_results.ids}
api_endpoint: ${td.api_endpoint}
docker:
image: "digdag/digdag-python:3.9"
image: "digdag/digdag-python:3.10.1"
_env:
TD_API_KEY: ${secret:td.apikey}
+check_max_job_id:
Expand All @@ -88,6 +111,6 @@ schedule:
api_endpoint: ${td.api_endpoint}
if_exists: 'append'
docker:
image: "digdag/digdag-python:3.9"
image: "digdag/digdag-python:3.10.1"
_env:
TD_API_KEY: ${secret:td.apikey}
Original file line number Diff line number Diff line change
Expand Up @@ -23,7 +23,7 @@ schedule:
user_assign_policies_table: ${td.tables.user_assign_policies}
api_endpoint: ${td.api_endpoint}
docker:
image: "digdag/digdag-python:3.9"
image: "digdag/digdag-python:3.10.1"
_env:
TD_API_KEY: ${secret:td.apikey}

Expand All @@ -39,7 +39,7 @@ schedule:
dest_table: ${td.tables.databases}
api_endpoint: ${td.api_endpoint}
docker:
image: "digdag/digdag-python:3.9"
image: "digdag/digdag-python:3.10.1"
_env:
TD_API_KEY: ${secret:td.apikey}

Expand Down Expand Up @@ -77,6 +77,6 @@ schedule:
policy_assign_users_table: ${td.tables.policies_assign_users}
api_endpoint: ${td.api_endpoint}
docker:
image: "digdag/digdag-python:3.9"
image: "digdag/digdag-python:3.10.1"
_env:
TD_API_KEY: ${secret:td.apikey}
25 changes: 21 additions & 4 deletions scenarios/monitoring/basic_monitoring/initial_ingest.dig
Original file line number Diff line number Diff line change
Expand Up @@ -12,17 +12,34 @@ _export:
dest_table: ${td.tables.connections}
api_endpoint: ${td.api_endpoint}
docker:
image: "digdag/digdag-python:3.9"
image: "digdag/digdag-python:3.10.1"
_env:
TD_API_KEY: ${secret:td.apikey}

+ingest_connection_details:
+get_all_connection:
td>:
query: SELECT ARRAY_JOIN(ARRAY_AGG(name), ',') AS names FROM connections
store_last_results: true

+ingest_connection_details:
py>: scripts.ingest_connection_details.run
dest_db: ${td.database}
dest_table: ${td.tables.connections_details}
names: ${td.last_results.names}
api_endpoint: ${td.api_endpoint}
docker:
image: "digdag/digdag-python:3.10.1"
_env:
TD_API_KEY: ${secret:td.apikey}

+ingest_schedule:
py>: scripts.ingest_schedule.run
dest_db: ${td.database}
dest_table: ${td.tables.schedules}
api_endpoint: ${td.api_endpoint}
docker:
image: "digdag/digdag-python:3.9"
image: "digdag/digdag-python:3.10.1"
_env:
TD_API_KEY: ${secret:td.apikey}

Expand All @@ -32,7 +49,7 @@ _export:
dest_table: ${td.tables.sources}
api_endpoint: ${td.api_endpoint}
docker:
image: "digdag/digdag-python:3.9"
image: "digdag/digdag-python:3.10.1"
_env:
TD_API_KEY: ${secret:td.apikey}

Expand All @@ -46,6 +63,6 @@ _export:
api_endpoint: ${td.api_endpoint}
if_exists: 'overwrite'
docker:
image: "digdag/digdag-python:3.9"
image: "digdag/digdag-python:3.10.1"
_env:
TD_API_KEY: ${secret:td.apikey}
Original file line number Diff line number Diff line change
Expand Up @@ -13,7 +13,7 @@ _export:
user_assign_policies_table: ${td.tables.user_assign_policies}
api_endpoint: ${td.api_endpoint}
docker:
image: "digdag/digdag-python:3.9"
image: "digdag/digdag-python:3.10.1"
_env:
TD_API_KEY: ${secret:td.apikey}

Expand All @@ -23,7 +23,7 @@ _export:
dest_table: ${td.tables.databases}
api_endpoint: ${td.api_endpoint}
docker:
image: "digdag/digdag-python:3.9"
image: "digdag/digdag-python:3.10.1"
_env:
TD_API_KEY: ${secret:td.apikey}

Expand All @@ -36,7 +36,7 @@ _export:
policy_assign_users_table: ${td.tables.policies_assign_users}
api_endpoint: ${td.api_endpoint}
docker:
image: "digdag/digdag-python:3.9"
image: "digdag/digdag-python:3.10.1"
_env:
TD_API_KEY: ${secret:td.apikey}

14 changes: 14 additions & 0 deletions scenarios/monitoring/basic_monitoring/query_samples/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
This document is a list of query samples for each tables of basic_monitoring database.

| # | file | reference table | description | result |
|----|----|----|----|----|
| 1 | [database_list.sql](database_list.sql) | basic_monitoring.databases | extract a list of Databases | ![](images/1.png)|
| 2 | [connection_list.sql](connection_list.sql)| basic_monitoring.connections <br> basic_monitoring.connections_details| extract a list of Authentications | ![](images/2.png) |
| 3 | [query_list.sql](query_list.sql) | basic_monitoring.schedules | extract a list of Saved Queries | ![](images/3.png) |
| 4 | [user_list.sql](user_list.sql) | basic_monitoring.users | extract a list of Users | ![](images/4.png) |
| 5 | [db_permission_list_per_policy.sql](db_permission_list_per_policy.sql) | basic_monitoring.policies <br> basic_monitoring.policies_detail <br> basic_monitoring.databases| extract a list of db permission per policy | ![](images/5.png) |
| 6 | [workflow_permission_list_per_policy.sql](workflow_permission_list_per_policy.sql) | basic_monitoring.policies <br> basic_monitoring.policies_detail | extract a list of workflow permission per policy | ![](images/6.png) |
| 7 | [auth_permission_list_per_policy.sql](auth_permission_list_per_policy.sql) | basic_monitoring.policies <br> basic_monitoring.policies_detail <br> basic_monitoring.connections_details | extract a list of auth permission per policy | ![](images/7.png) |
| 8 | [parent_segment_permission_list_per_policy.sql](parent_segment_permission_list_per_policy.sql) | basic_monitoring.policies <br>basic_monitoring.policies_detail <br> cdp_monitoring.parent_segments| extract a list of parent segment permission per policy | ![](images/8.png) |
| 9 | [num_of_jobs_per_type_and_hours.sql](num_of_jobs_per_type_and_hours.sql) | basic_monitoring.jobs | extract num of jobs per type and hours | ![](images/9.png) |

Original file line number Diff line number Diff line change
@@ -0,0 +1,45 @@
with temp1 as (
select
p.id, p.name, p.description,
json_extract(json_parse(d.permissions), '$.Authentications') as permissions
from policies p
join policies_detail d on p.id = d.id
), temp2 as (
select
id, name, description, CAST(permissions as ARRAY(JSON)) as permissions
from temp1
where permissions is not null
), temp3 as (
select id, name, description, permissions2
from temp2
cross join unnest(permissions) as t(permissions2)
), temp4 as (
select
id, name, description,
CASE
when JSON_FORMAT(permissions2) like '%"ids"%' then JSON_EXTRACT_SCALAR(permissions2, '$.ids')
else NULL
END as auth_ids,
JSON_EXTRACT_SCALAR(permissions2, '$.operation') as operation
from temp3
), temp5 as (
select
id, name, description,
split(auth_ids, ',') as auth_ids,
operation
from temp4
where auth_ids is not null
), temp6 as (
select id, name, description, auth_ids2, operation
from temp5
cross join unnest(auth_ids) as t(auth_ids2)
), temp7 as (
select t.id, t.name, t.description, t.operation, t.auth_ids2 as auth_id, d.name as auth_name
from temp6 t
join connections_details d on t.auth_ids2 = cast(d.id as VARCHAR)
), temp8 as (
select id, name, description, operation, auth_id, auth_name from temp7
union all
select id, name, description, operation, NULL as auth_id, NULL as auth_name from temp4 where auth_ids is null
)
select * from temp8 order by 1, 4, 5
Original file line number Diff line number Diff line change
@@ -0,0 +1,9 @@
select
d.id,
c.name,
CASE
when c.url like '{%}' then JSON_EXTRACT_SCALAR(JSON_PARSE(c.url), '$.type')
else REGEXP_EXTRACT(c.url, '(.*):\/\/.*', 1)
END as connection_type
from connections c
join connections_details d on c.name = d.name
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
select
id, name, created_at, 'https://console.treasuredata.com/app/databases/' || id as console_url
from databases
Original file line number Diff line number Diff line change
@@ -0,0 +1,27 @@
with temp1 as (
select
p.id, p.name, p.description,
json_extract(json_parse(d.permissions), '$.Databases') as permissions
from policies p
join policies_detail d on p.id = d.id
), temp2 as (
select
id, name, description, CAST(permissions as ARRAY(JSON)) as permissions
from temp1
where permissions is not null
), temp3 as (
select id, name, description, permissions2
from temp2
cross join unnest(permissions) as t(permissions2)
), temp4 as (
select
id, name, description,
JSON_EXTRACT_SCALAR(permissions2, '$.operation') as operation,
JSON_EXTRACT_SCALAR(permissions2, '$.ids') as target
from temp3
)
select
t4.id as policy_id, t4.name as policy_name, t4.description as policy_description, t4.operation database_operation, cast(d.id as BIGINT) as database_id, d.name as database_name
from temp4 t4
join databases d on t4.target = d.id
order by 1, 5, 4
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
select
TD_TIME_FORMAT(time, 'yyyy-MM-dd HH') as utc_date_hour,
type,
count(*) as num
from jobs
where TD_INTERVAL(time, '-1d/now')
group by 1, 2
order by 1, 2
Original file line number Diff line number Diff line change
@@ -0,0 +1,52 @@
with temp1 as (
select
p.id, p.name, p.description,
JSON_EXTRACT(JSON_PARSE(d.permissions), '$.MasterSegmentConfig') as permissions
from policies p
join policies_detail d on p.id = d.id
), temp2 as (
select
id, name, description, CAST(permissions as ARRAY(JSON)) as permissions
from temp1
where permissions is not null
), temp3 as (
select id, name, description, permissions2
from temp2
cross join unnest(permissions) as t(permissions2)
), temp4 as (
select
id, name, description,
JSON_EXTRACT_SCALAR(permissions2, '$.id') as parent_segments_id,
JSON_EXTRACT_SCALAR(permissions2, '$.operation') as parent_segment_operation
from temp3
), temp5 as (
select
t.id as policy_id, t.name as policy_name, t.description,
t.parent_segment_operation,
CAST(p.id as BIGINT) as parent_segment_id,
JSON_EXTRACT_SCALAR(p.attributes, '$.name') as parent_segment_name
from temp4 t
join cdp_monitoring.parent_segments p on t.parent_segments_id = p.id
), temp6 as (
select
p.id, p.name, p.description,
JSON_EXTRACT_SCALAR(JSON_PARSE(d.permissions), '$.Segmentation[0].operation') as parent_segment_operation
from policies p
join policies_detail d on p.id = d.id
), temp7 as (
select
id as policy_id, name as policy_name, description,
parent_segment_operation
from temp6
where parent_segment_operation is not null
), temp8 as (
select
policy_id, policy_name, description, parent_segment_operation, parent_segment_id, parent_segment_name
from temp5
union all
select
policy_id, policy_name, description, parent_segment_operation, NULL as parent_segment_id, NULL as parent_segment_name
from temp7
)
select * from temp8
order by 1, 5, 4
10 changes: 10 additions & 0 deletions scenarios/monitoring/basic_monitoring/query_samples/query_list.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
select
name,
type,
query,
user_name,
CASE
when result like '{%}' then JSON_EXTRACT_SCALAR(JSON_PARSE(result), '$.type')
else REGEXP_EXTRACT(result, '(.*):\/\/.*', 1)
END as export_type
from schedules
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
select id, name, email, created_at from users
Loading

0 comments on commit 3fbbad0

Please sign in to comment.