How do I find Dedicated SQL pool inactive time

Sasikanth Prabha 41 Reputation points
2022-04-27T05:18:48.58+00:00

I would like to know how to find Dedicated SQL pool inactive time.
To reduce the cost, I would like to trigger a pause after certain time of inactive period on the DB pool, or there are no queries to execute.

I refer to the following Q, but that explains explicitly invoking APIs.
https://learn.microsoft.com/en-us/answers/questions/692639/pause-synapse-pool-after-a-period-of-inactivity.html

Azure Synapse Analytics
Azure Synapse Analytics
An Azure analytics service that brings together data integration, enterprise data warehousing, and big data analytics. Previously known as Azure SQL Data Warehouse.
5,035 questions
0 comments No comments
{count} votes

Accepted answer
  1. AnnuKumari-MSFT 33,636 Reputation points Microsoft Employee
    2022-04-27T12:34:08.647+00:00

    Hi @Sasikanth Prabha ,
    Welcome to Microsoft Q&A platform and thanks for posting your query here.
    As I understand your requirement, it seems you want to know if there is any workaround to find out the period of inactivity in dedicated sql pool so as to make sure that there is no active queries running and we are good to pause the sql pool.

    This can be achieved by running monitoring queries in the SQL pool using script activity or stored procedure activity.

    196993-image.png

    Use the following query in Script activity :

    select count(*) as queriesRunning from sys.dm_pdw_exec_requests WHERE status='Running' and session_id <> session_id();

    SELECT min(DATEDIFF (mi, end_compile_time, getutcdate())) as minutesPassed FROM sys.dm_pdw_exec_requests WHERE session_id <> session_id()

    197003-image.png

    Use the below expression in If condition block:
    @and(equals(activity('Script1').output.resultSets[0].rows[0].queriesRunning,0),greaterOrEquals(activity('Script1').output.resultSets[1].rows[0].minutesPassed,2))

    Case 1: When query is running :

    equals(activity('Script1').output.resultSets[0].rows[0].queriesRunning,0 will result in false

    196889-case1.gif

    Case 2: When there is no active query but minutes passed is < 2:
    196890-case2.gif

    Case 3: When there is no active query and minutes passed is >=2:
    197021-case3.gif

    Hope this will help. Please let us know if any further queries.

    ------------------------------

    • Please don't forget to click on 130616-image.png or upvote 130671-image.png button whenever the information provided helps you.
      Original posters help the community find answers faster by identifying the correct answer. Here is how
    • Want a reminder to come back and check responses? Here is how to subscribe to a notification
    • If you are interested in joining the VM program and help shape the future of Q&A: Here is how you can be part of Q&A Volunteer Moderators
    1 person found this answer helpful.

1 additional answer

Sort by: Most helpful
  1. Pratik Somaiya 4,206 Reputation points
    2022-04-27T12:04:30.79+00:00

    Hello @Sasikanth Prabha

    To pause or resume the Synapse pool you will have to invoke the APIs as mentioned in the documentation

    You will have to create the pipelines to pause the Synapse pool

    1 person found this answer helpful.

Your answer

Answers can be marked as Accepted Answers by the question author, which helps users to know the answer solved the author's problem.