process-mining
2024.10
true
UiPath logo, featuring letters U and I in white

Process Mining

Automation CloudAutomation Cloud Public SectorAutomation SuiteStandalone
Last updated Dec 18, 2024

Tags

Introduction

In Process Mining, tags are the business rules you apply to your data, that enable you to check conformance, such as inefficiencies, rework, or violations, in your process.

Note:
If you want to use the Tags dashboard to analyze tags, the fields for the Tags table must be must be present in your dataset.

Configuring Tags

If you want to use the Tags dashboard to analyze tags in your process, tags must be defined for your app template.

For certain app templates, there are out of the box tags available, which will be shown in the dashboard. In the documentation for your specific app template you will find an overview of the available tags. The App Templates page contains links to the documentation for all available app templates.

All custom process app templates have one tag implemented out of the box that checks whether a case has rework activities that are executed by different users.

If no data is available in the Tags dashboard, you need to configure your own tags using data transformations. Here you can also configure any default tags to your business needs. Below is an overview of the tags configuration files for the different app templates.

App templates based on

Tags configuration file

Event log

models\5_business_logic\Tags_base.sql
Custom process 1models\5_business_logic\Tags_base.sql

Purchase-to-Pay

models\5_business_logic\Tags.sql

Order-to-Cash

models\5_business_logic\Tags.sql
1) This applies to the Custom process app template and all other app templates based on Custom process, for example SAP-Warehouse-Management.
For Custom process you can also upload tags using the Tags_raw.csv file. See Custom process input fields.

Adding business logic in transformations

In the last transformation step, business logic is added as needed for data analysis.

Each record in the tags table represents one tag for a certain case. Example tags are:

  • SLA violation for a contract.
  • a payment done by an unauthorized person.
The mandatory fields for this table are the Case_ID, and Tag.

Not all cases will have a tag and some cases may have multiple tags.

Refer to Data transformations for more information.

SQL examples for configuring Tags

Below are some SQL examples that you can use to configure Tags using transformations.

Attention:
The below SQL examples are based on Event log app templates, and use Cases that have a Case_ID. If you want to use the SQL examples to define Tags for Purchase-to-Pay app templates or Order-to-Cash app templates, make sure to use the appropriate entity and the related internal entity_ID. When extending the implementation for Tags, follow the existing implementation.

Directly follows

This SQL code identifies cases where activity 'X' is directly followed by activity 'Y' and tags them as "Violation".

with Event_log_base as (
    select * from {{ ref('Event_log_base') }}
),

-- Event log with current activity and next activity
Event_log_extended as (
    select
        Event_log_base."Case_ID",
        Event_log_base."Activity" as "Current_activity",
        lead(Event_log_base."Activity") over (order by "Event_end") as "Next_activity"
    from Event_log_base
),

-- This SQL code checks whether activity X is directly followed by Y in a given case
Directly_follows as (
    select
        Event_log_extended ."Case_ID",
        {{ pm_utils.as_varchar('Activity X directly followed by activity Y') }} as "Tag",
        {{ pm_utils.as_varchar('Violation') }} as "Tag_type"
    from Event_log_extended 
    where Event_log_extended ."Current_activity" = 'X' and Event_log_extended ."Next_activity" = 'Y'
    group by Event_log_extended ."Case_ID"
)

select * from Directly_followswith Event_log_base as (
    select * from {{ ref('Event_log_base') }}
),

-- Event log with current activity and next activity
Event_log_extended as (
    select
        Event_log_base."Case_ID",
        Event_log_base."Activity" as "Current_activity",
        lead(Event_log_base."Activity") over (order by "Event_end") as "Next_activity"
    from Event_log_base
),

-- This SQL code checks whether activity X is directly followed by Y in a given case
Directly_follows as (
    select
        Event_log_extended ."Case_ID",
        {{ pm_utils.as_varchar('Activity X directly followed by activity Y') }} as "Tag",
        {{ pm_utils.as_varchar('Violation') }} as "Tag_type"
    from Event_log_extended 
    where Event_log_extended ."Current_activity" = 'X' and Event_log_extended ."Next_activity" = 'Y'
    group by Event_log_extended ."Case_ID"
)

select * from Directly_follows

Indirectly follows

This SQL code identifies cases where activity 'X' is directly or indirectly followed by activity 'Y' and tags them as "Violation".

with Event_log_base as (
    select * from {{ ref('Event_log_base') }}
),

Cases_with_activity_X as (
    select
        Event_log_base."Case_ID",
        min(Event_log_base."Event_end") as "Event_end"
    from Event_log_base
    where Event_log_base."Activity" = 'X'
    group by Event_log_base."Case_ID"
),

-- Activity X is directly or indirectly followed by activity Y
Indirectly_follows as (
    select
        Event_log_base."Case_ID",
        {{ pm_utils.as_varchar('Activity X indirectly followed by activity Y') }} as "Tag",
        {{ pm_utils.as_varchar('Violation') }} as "Tag_type"
    from Event_log_base
    inner join Cases_with_activity_X
        on Event_log_base."Case_ID" = Cases_with_activity_X."Case_ID"
    where Event_log_base."Activity" = 'Y' and Event_log_base."Event_end" > Cases_with_activity_X."Event_end"
    group by Event_log_base."Case_ID"
)

select * from Indirectly_followswith Event_log_base as (
    select * from {{ ref('Event_log_base') }}
),

Cases_with_activity_X as (
    select
        Event_log_base."Case_ID",
        min(Event_log_base."Event_end") as "Event_end"
    from Event_log_base
    where Event_log_base."Activity" = 'X'
    group by Event_log_base."Case_ID"
),

-- Activity X is directly or indirectly followed by activity Y
Indirectly_follows as (
    select
        Event_log_base."Case_ID",
        {{ pm_utils.as_varchar('Activity X indirectly followed by activity Y') }} as "Tag",
        {{ pm_utils.as_varchar('Violation') }} as "Tag_type"
    from Event_log_base
    inner join Cases_with_activity_X
        on Event_log_base."Case_ID" = Cases_with_activity_X."Case_ID"
    where Event_log_base."Activity" = 'Y' and Event_log_base."Event_end" > Cases_with_activity_X."Event_end"
    group by Event_log_base."Case_ID"
)

select * from Indirectly_follows

Activity X multiple times

This SQL code identifies cases where activity 'X' occurs more than once, and tags them as "Inefficiency".

with Event_log_base as (
    select * from {{ ref('Event_log_base') }}
),

-- This SQL code checks if Activity X occurs twice or more times in the same case
Activity_X_multiple_times as (
    select
        Event_log_base."Case_ID",
        {{ pm_utils.as_varchar('Activity X multiple times') }} as "Tag",
        {{ pm_utils.as_varchar('Inefficiency') }} as "Tag_type"
    from Event_log_base
    where Event_log_base."Activity" = 'X'
    group by Event_log_base."Case_ID"
    having count(Event_log_base."Activity") > 1
)

select * from Activity_X_multiple_timeswith Event_log_base as (
    select * from {{ ref('Event_log_base') }}
),

-- This SQL code checks if Activity X occurs twice or more times in the same case
Activity_X_multiple_times as (
    select
        Event_log_base."Case_ID",
        {{ pm_utils.as_varchar('Activity X multiple times') }} as "Tag",
        {{ pm_utils.as_varchar('Inefficiency') }} as "Tag_type"
    from Event_log_base
    where Event_log_base."Activity" = 'X'
    group by Event_log_base."Case_ID"
    having count(Event_log_base."Activity") > 1
)

select * from Activity_X_multiple_times

Case has activity X

This SQL code identifies cases that have one or more activities with a name that contains 'X', and tags them as "Inefficiency".

with Event_log_base as (
    select * from {{ ref('Event_log_base') }}
),

-- Case has activity with name like X
Case_has_activity_X as (
    select
        Event_log_base."Case_ID",
        {{ pm_utils.as_varchar('Case has activity X') }} as "Tag",
        {{ pm_utils.as_varchar('Inefficiency') }} as "Tag_type"
    from Event_log_base
    where {{ pm_utils.charindex('X', 'Event_log_base."Activity"') }} > 0
    group by Event_log_base."Case_ID"
)

select * from Case_has_activity_Xwith Event_log_base as (
    select * from {{ ref('Event_log_base') }}
),

-- Case has activity with name like X
Case_has_activity_X as (
    select
        Event_log_base."Case_ID",
        {{ pm_utils.as_varchar('Case has activity X') }} as "Tag",
        {{ pm_utils.as_varchar('Inefficiency') }} as "Tag_type"
    from Event_log_base
    where {{ pm_utils.charindex('X', 'Event_log_base."Activity"') }} > 0
    group by Event_log_base."Case_ID"
)

select * from Case_has_activity_X

Case has no activity X

This SQL code identifies cases for which there are no activities that have a name containing 'X' and tags them as "Inefficiency".

with Event_log_base as (
    select * from {{ ref('Event_log_base') }}
),

Cases as (
    select * from {{ ref('Cases') }}
),

-- Case has no activity with name like X
-- Obtained by subtracting the set of cases that have activity X from the set of all cases
Case_has_no_activity_X as (
    select
        Cases."Case_ID",
        {{ pm_utils.as_varchar('Case has no activity X') }} as "Tag",
        {{ pm_utils.as_varchar('Inefficiency') }} as "Tag_type"
    from Cases
    where Cases."Case_ID" not in (
        -- Case has activity with name like X
        select
            Event_log_base."Case_ID"
        from Event_log_base
        where {{ pm_utils.charindex('X', 'Event_log_base."Activity"') }} > 0
        group by Event_log_base."Case_ID"
    )
)

select * from Case_has_no_activity_Xwith Event_log_base as (
    select * from {{ ref('Event_log_base') }}
),

Cases as (
    select * from {{ ref('Cases') }}
),

-- Case has no activity with name like X
-- Obtained by subtracting the set of cases that have activity X from the set of all cases
Case_has_no_activity_X as (
    select
        Cases."Case_ID",
        {{ pm_utils.as_varchar('Case has no activity X') }} as "Tag",
        {{ pm_utils.as_varchar('Inefficiency') }} as "Tag_type"
    from Cases
    where Cases."Case_ID" not in (
        -- Case has activity with name like X
        select
            Event_log_base."Case_ID"
        from Event_log_base
        where {{ pm_utils.charindex('X', 'Event_log_base."Activity"') }} > 0
        group by Event_log_base."Case_ID"
    )
)

select * from Case_has_no_activity_X

Starts with

This SQL code identifies cases that start with activity 'X' and tags them as "Violation".

with Event_log_base as (
    select * from {{ ref('Event_log_base') }}
),

-- Add row_number to initial event log
Event_log_base_numbered as (
    select
        Event_log_base."Case_ID",
        Event_log_base."Activity",
        Event_log_base."Event_end",
        row_number() over (partition by Event_log_base."Case_ID" order by Event_log_base."Event_end") as "Row_number"
    from Event_log_base
),

-- Case starts with activity X
Starts_with as (
    select
        Event_log_base_numbered."Case_ID",
        {{ pm_utils.as_varchar('Case starts with activity X') }} as "Tag",
        {{ pm_utils.as_varchar('Violation') }} as "Tag_type"
    from Event_log_base_numbered
    where
        Event_log_base_numbered."Row_number" = 1
        and Event_log_base_numbered."Activity" = 'X'
)

select * from Starts_withwith Event_log_base as (
    select * from {{ ref('Event_log_base') }}
),

-- Add row_number to initial event log
Event_log_base_numbered as (
    select
        Event_log_base."Case_ID",
        Event_log_base."Activity",
        Event_log_base."Event_end",
        row_number() over (partition by Event_log_base."Case_ID" order by Event_log_base."Event_end") as "Row_number"
    from Event_log_base
),

-- Case starts with activity X
Starts_with as (
    select
        Event_log_base_numbered."Case_ID",
        {{ pm_utils.as_varchar('Case starts with activity X') }} as "Tag",
        {{ pm_utils.as_varchar('Violation') }} as "Tag_type"
    from Event_log_base_numbered
    where
        Event_log_base_numbered."Row_number" = 1
        and Event_log_base_numbered."Activity" = 'X'
)

select * from Starts_with

Throughput time longer than 10 days

This SQL code identifies cases for which the throughput time is longer than 10 days and tags them as "Inefficiency".

with Event_log_base as (
    select * from {{ ref('Event_log_base') }}
),

-- Throuput time of each case
Throughput_time_per_case as (
    select
        Event_log_base."Case_ID",
        {{ pm_utils.datediff('day', 'coalesce(min(Event_log_base."Event_start"), min(Event_log_base."Event_end"))', 'max(Event_log_base."Event_end")') }} as "Throughput_time"
    from Event_log_base
    group by Event_log_base."Case_ID"
),

-- Case throughput time is longer than 10 days
Throughput_time_longer_than_10_days as (
    select
        Throughput_time_per_case."Case_ID",
        {{ pm_utils.as_varchar('Throughput time is longer than 10 days') }} as "Tag",
        {{ pm_utils.as_varchar('Inneficiency') }} as "Tag_type"
    from Throughput_time_per_case
    where Throughput_time_per_case."Throughput_time" > 10
)

select * from Throughput_time_longer_than_10_dayswith Event_log_base as (
    select * from {{ ref('Event_log_base') }}
),

-- Throuput time of each case
Throughput_time_per_case as (
    select
        Event_log_base."Case_ID",
        {{ pm_utils.datediff('day', 'coalesce(min(Event_log_base."Event_start"), min(Event_log_base."Event_end"))', 'max(Event_log_base."Event_end")') }} as "Throughput_time"
    from Event_log_base
    group by Event_log_base."Case_ID"
),

-- Case throughput time is longer than 10 days
Throughput_time_longer_than_10_days as (
    select
        Throughput_time_per_case."Case_ID",
        {{ pm_utils.as_varchar('Throughput time is longer than 10 days') }} as "Tag",
        {{ pm_utils.as_varchar('Inneficiency') }} as "Tag_type"
    from Throughput_time_per_case
    where Throughput_time_per_case."Throughput_time" > 10
)

select * from Throughput_time_longer_than_10_days

Duration more than 30 minutes

This SQL code identifies cases where the time duration between activity 'X' and 'Y' is more than 30 minutes and tags them as "Inefficiency".

with Event_log_base as (
    select * from {{ ref('Event_log_base') }}
),

-- First activity X of each case
First_activity_X_of_each_case as (
    select
        Event_log_base."Case_ID",
        min(Event_log_base."Event_end") as "Event_end"
    from Event_log_base
    where Event_log_base."Activity" = 'X'
    group by Event_log_base."Case_ID"
),

-- Last activity Y of each case
Last_activity_Y_of_each_case as (
    select
        Event_log_base."Case_ID",
        max(Event_log_base."Event_end") as "Event_end"
    from Event_log_base
    where Event_log_base."Activity" = 'Y'
    group by Event_log_base."Case_ID"
),

-- Time between first X and last Y > 30 minutes
Duration_more_than_30_minutes as (
    select
        First_activity_X_of_each_case."Case_ID",
        {{ pm_utils.as_varchar('Duration more than 30 minutes') }} as "Tag",
        {{ pm_utils.as_varchar('Inefficiency') }} as "Tag_type"
    from First_activity_X_of_each_case
    inner join Last_activity_Y_of_each_case
        on First_activity_X_of_each_case."Case_ID" = Last_activity_Y_of_each_case."Case_ID"
    where {{ pm_utils.datediff('minute', 'First_activity_X_of_each_case."Event_end"', 'Last_activity_Y_of_each_case."Event_end"') }} > 30
)

select * from Duration_more_than_30_minuteswith Event_log_base as (
    select * from {{ ref('Event_log_base') }}
),

-- First activity X of each case
First_activity_X_of_each_case as (
    select
        Event_log_base."Case_ID",
        min(Event_log_base."Event_end") as "Event_end"
    from Event_log_base
    where Event_log_base."Activity" = 'X'
    group by Event_log_base."Case_ID"
),

-- Last activity Y of each case
Last_activity_Y_of_each_case as (
    select
        Event_log_base."Case_ID",
        max(Event_log_base."Event_end") as "Event_end"
    from Event_log_base
    where Event_log_base."Activity" = 'Y'
    group by Event_log_base."Case_ID"
),

-- Time between first X and last Y > 30 minutes
Duration_more_than_30_minutes as (
    select
        First_activity_X_of_each_case."Case_ID",
        {{ pm_utils.as_varchar('Duration more than 30 minutes') }} as "Tag",
        {{ pm_utils.as_varchar('Inefficiency') }} as "Tag_type"
    from First_activity_X_of_each_case
    inner join Last_activity_Y_of_each_case
        on First_activity_X_of_each_case."Case_ID" = Last_activity_Y_of_each_case."Case_ID"
    where {{ pm_utils.datediff('minute', 'First_activity_X_of_each_case."Event_end"', 'Last_activity_Y_of_each_case."Event_end"') }} > 30
)

select * from Duration_more_than_30_minutes

Analyzing Tags

Tags dashboard

The Tags dashboard enables you to analyze the tags that occur in the process.

Follow these steps to display the Tags dashboard.

  1. Select Tags in the menu on the left of the dashboard.

The Tags dashboard is displayed.

Metrics

Below is a description of the metrics that can be used to analyze the cases regarding tags.

Metric

Description

Number of cases

The number of cases that have the tag assigned.

Number of tags

The number of tags assigned.

  • Introduction
  • Configuring Tags
  • Adding business logic in transformations
  • SQL examples for configuring Tags
  • Analyzing Tags
  • Tags dashboard

Was this page helpful?

Get The Help You Need
Learning RPA - Automation Courses
UiPath Community Forum
Uipath Logo White
Trust and Security
© 2005-2024 UiPath. All rights reserved.