Simplify sessions/users charts
This commit is contained in:
parent
ebdcb8d4d0
commit
4aaea28187
@ -561,7 +561,7 @@ wwv_flow_api.create_jet_chart_series(
|
||||
p_id=>wwv_flow_api.id(11885852966358762)
|
||||
,p_chart_id=>wwv_flow_api.id(11884191829358759)
|
||||
,p_seq=>10
|
||||
,p_name=>'Sessions'
|
||||
,p_name=>'Users'
|
||||
,p_location=>'REGION_SOURCE'
|
||||
,p_items_value_column_name=>'COUNT_USERS'
|
||||
,p_items_label_column_name=>'CHART_LABEL'
|
||||
@ -573,9 +573,24 @@ wwv_flow_api.create_jet_chart_series(
|
||||
,p_items_label_rendered=>false
|
||||
);
|
||||
wwv_flow_api.create_jet_chart_series(
|
||||
p_id=>wwv_flow_api.id(11886438944358762)
|
||||
p_id=>wwv_flow_api.id(13239464881910331)
|
||||
,p_chart_id=>wwv_flow_api.id(11884191829358759)
|
||||
,p_seq=>20
|
||||
,p_name=>'Pages'
|
||||
,p_location=>'REGION_SOURCE'
|
||||
,p_items_value_column_name=>'COUNT_PAGES'
|
||||
,p_items_label_column_name=>'CHART_LABEL'
|
||||
,p_line_style=>'solid'
|
||||
,p_line_type=>'auto'
|
||||
,p_marker_rendered=>'auto'
|
||||
,p_marker_shape=>'circle'
|
||||
,p_assigned_to_y2=>'off'
|
||||
,p_items_label_rendered=>false
|
||||
);
|
||||
wwv_flow_api.create_jet_chart_series(
|
||||
p_id=>wwv_flow_api.id(11886438944358762)
|
||||
,p_chart_id=>wwv_flow_api.id(11884191829358759)
|
||||
,p_seq=>30
|
||||
,p_name=>'Requests'
|
||||
,p_location=>'REGION_SOURCE'
|
||||
,p_items_value_column_name=>'COUNT_REQUESTS'
|
||||
|
||||
@ -3620,6 +3620,21 @@ wwv_flow_api.create_jet_chart_series(
|
||||
,p_assigned_to_y2=>'off'
|
||||
,p_items_label_rendered=>false
|
||||
);
|
||||
wwv_flow_api.create_jet_chart_series(
|
||||
p_id=>wwv_flow_api.id(13239592666910332)
|
||||
,p_chart_id=>wwv_flow_api.id(10893251519121641)
|
||||
,p_seq=>20
|
||||
,p_name=>'Sessions'
|
||||
,p_location=>'REGION_SOURCE'
|
||||
,p_items_value_column_name=>'COUNT_SESSIONS'
|
||||
,p_items_label_column_name=>'CHART_LABEL'
|
||||
,p_line_style=>'solid'
|
||||
,p_line_type=>'auto'
|
||||
,p_marker_rendered=>'auto'
|
||||
,p_marker_shape=>'circle'
|
||||
,p_assigned_to_y2=>'off'
|
||||
,p_items_label_rendered=>false
|
||||
);
|
||||
wwv_flow_api.create_jet_chart_axis(
|
||||
p_id=>wwv_flow_api.id(10893487984121643)
|
||||
,p_chart_id=>wwv_flow_api.id(10893251519121641)
|
||||
|
||||
@ -1,37 +1,5 @@
|
||||
CREATE OR REPLACE VIEW sessions_chart AS
|
||||
WITH t AS (
|
||||
SELECT
|
||||
NVL(d.user_id, LOWER(l.apex_user)) AS user_id,
|
||||
l.application_id AS app_id,
|
||||
l.application_name AS app_name, -- NULL for APEX Builder
|
||||
l.page_id,
|
||||
l.page_name,
|
||||
SUBSTR(l.page_view_type, 1, 1) AS request_type,
|
||||
l.page_view_type,
|
||||
l.request_value,
|
||||
l.view_timestamp AS requested_at
|
||||
FROM apex_workspace_activity_log l
|
||||
JOIN apex_workspaces w
|
||||
ON w.workspace_id = l.workspace_id
|
||||
JOIN apex_applications a
|
||||
ON a.workspace = w.workspace
|
||||
AND a.application_id = l.application_id
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
UPPER(d.user_name) AS user_name,
|
||||
LOWER(d.email) AS user_id
|
||||
FROM apex_workspace_developers d
|
||||
WHERE d.is_application_developer = 'Yes'
|
||||
AND d.account_locked = 'No'
|
||||
) d
|
||||
ON d.user_name = l.apex_user
|
||||
WHERE a.application_id = NVL(app.get_app_id(), a.application_id)
|
||||
AND l.page_view_type IN ('Rendering', 'Processing', 'Ajax')
|
||||
AND l.apex_user NOT IN ('nobody')
|
||||
AND l.view_timestamp >= TRUNC(app.get_date_item('G_TODAY'))
|
||||
AND l.view_timestamp < TRUNC(app.get_date_item('G_TODAY')) + 1
|
||||
),
|
||||
z AS (
|
||||
WITH z AS (
|
||||
SELECT
|
||||
LEVEL AS bucket_id,
|
||||
TRUNC(SYSDATE) + NUMTODSINTERVAL((LEVEL - 1) * 10, 'MINUTE') AS start_at,
|
||||
@ -41,17 +9,16 @@ z AS (
|
||||
)
|
||||
SELECT
|
||||
z.bucket_id,
|
||||
TO_CHAR(z.start_at, 'HH24:MI') AS chart_label,
|
||||
--
|
||||
NULLIF(COUNT(DISTINCT t.user_id), 0) AS count_users,
|
||||
NULLIF(COUNT(DISTINCT t.page_id), 0) AS count_pages,
|
||||
--
|
||||
NULLIF(SUM(CASE WHEN t.app_id = app.get_app_id() THEN 1 ELSE 0 END), 0) AS count_requests,
|
||||
NULLIF(SUM(CASE WHEN t.app_id IS NOT NULL AND t.app_name IS NULL THEN 1 ELSE 0 END), 0) AS count_others,
|
||||
--
|
||||
NULL AS count_events
|
||||
TO_CHAR(z.start_at, 'HH24:MI') AS chart_label,
|
||||
NULLIF(COUNT(DISTINCT l.session_id), 0) AS count_sessions,
|
||||
NULLIF(COUNT(DISTINCT l.user_id), 0) AS count_users,
|
||||
NULLIF(COUNT(DISTINCT l.page_id), 0) AS count_pages,
|
||||
NULLIF(SUM(CASE WHEN l.flag = 'P' THEN 1 ELSE 0 END), 0) AS count_requests -- app.flag_request
|
||||
FROM z
|
||||
LEFT JOIN t
|
||||
ON app.get_time_bucket(t.requested_at, 10) = z.bucket_id
|
||||
LEFT JOIN logs l
|
||||
ON l.created_at >= TRUNC(app.get_date_item('G_TODAY'))
|
||||
AND l.created_at < TRUNC(app.get_date_item('G_TODAY')) + 1
|
||||
AND l.app_id = app.get_app_id()
|
||||
AND z.bucket_id = app.get_time_bucket(l.created_at, 10)
|
||||
GROUP BY z.bucket_id, TO_CHAR(z.start_at, 'HH24:MI');
|
||||
|
||||
|
||||
@ -1,53 +0,0 @@
|
||||
CREATE OR REPLACE VIEW users_chart AS
|
||||
WITH t AS (
|
||||
SELECT
|
||||
NVL(d.user_id, LOWER(l.apex_user)) AS user_id,
|
||||
l.application_id AS app_id,
|
||||
l.application_name AS app_name, -- NULL for APEX Builder
|
||||
l.page_id,
|
||||
l.page_name,
|
||||
SUBSTR(l.page_view_type, 1, 1) AS request_type,
|
||||
l.page_view_type,
|
||||
l.request_value,
|
||||
l.view_timestamp AS requested_at
|
||||
FROM apex_workspace_activity_log l
|
||||
JOIN apex_workspaces w
|
||||
ON w.workspace_id = l.workspace_id
|
||||
JOIN apex_applications a
|
||||
ON a.workspace = w.workspace
|
||||
AND a.application_id = l.application_id
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
UPPER(d.user_name) AS user_name,
|
||||
LOWER(d.email) AS user_id
|
||||
FROM apex_workspace_developers d
|
||||
WHERE d.is_application_developer = 'Yes'
|
||||
AND d.account_locked = 'No'
|
||||
) d
|
||||
ON d.user_name = l.apex_user
|
||||
WHERE (a.application_id = app.get_app_id() OR a.application_id >= 4000)
|
||||
AND l.page_view_type IN ('Rendering', 'Processing', 'Ajax')
|
||||
AND l.apex_user NOT IN ('nobody')
|
||||
AND l.view_timestamp >= TRUNC(app.get_date_item('G_TODAY'))
|
||||
AND l.view_timestamp < TRUNC(app.get_date_item('G_TODAY')) + 1
|
||||
),
|
||||
z AS (
|
||||
SELECT
|
||||
LEVEL AS bucket_id,
|
||||
TRUNC(SYSDATE) + NUMTODSINTERVAL((LEVEL - 1) * 10, 'MINUTE') AS start_at,
|
||||
TRUNC(SYSDATE) + NUMTODSINTERVAL( LEVEL * 10, 'MINUTE') AS end_at
|
||||
FROM DUAL
|
||||
CONNECT BY LEVEL <= (1440 / 10)
|
||||
)
|
||||
SELECT
|
||||
z.bucket_id,
|
||||
TO_CHAR(z.start_at, 'HH24:MI') AS chart_label,
|
||||
NULLIF(COUNT(DISTINCT t.user_id), 0) AS count_users,
|
||||
--
|
||||
NULLIF(SUM(CASE WHEN t.app_id = app.get_app_id() THEN 1 ELSE 0 END), 0) AS count_requests,
|
||||
NULLIF(SUM(CASE WHEN t.app_id IS NOT NULL AND t.app_name IS NULL THEN 1 ELSE 0 END), 0) AS count_others
|
||||
FROM z
|
||||
LEFT JOIN t
|
||||
ON app.get_time_bucket(t.requested_at, 10) = z.bucket_id
|
||||
GROUP BY z.bucket_id, TO_CHAR(z.start_at, 'HH24:MI');
|
||||
|
||||
Loading…
x
Reference in New Issue
Block a user