cancel
Showing results for 
Search instead for 
Did you mean: 

How do I stop multiple databases from all checkpointing at the same time?

Breck_Carter
Participant
3,284

Scenario: A single version 12 server is running 100 separate databases, all started at the same time (or as fast as 100 START DATABASE statements can run), and all lightly loaded (let's say "completely idle").

Idle databases take checkpoints every 20 minutes or so, and when the 20 minutes are up all heck breaks loose, performance-wise, as all 100 databases take their checkpoints one after the other.

If something ELSE is running, say on database 101, or even some other non-database process, you can just forget latency, throughput, or whatever other measure of performance you're interested in... if the computer isn't a super-high-performer, it will be crushed for maybe a minute or two or more.

So... all I want is some method to get those 100 databases on separate checkpoint schedules, something cheaper than "upgrade the hardware".

Any ideas?

Accepted Solutions (0)

Answers (2)

Answers (2)

MarkCulp
Participant

Volker alluded to a solution in his comment to the question.... but here is the idea in more detail:

Create a database start event in each of the databases that delays a variable amount of time and then executes an explicit checkpoint. The idea is to spread the checkpoints out evenly across the ~20 minute regular checkpointing interval.

CREATE EVENT randomize_first_checkpoint
   TYPE DatabaseStart
HANDLER
   BEGIN
      declare @num  int;    -- total number of databases running on server
      declare @ord  int;    -- ordinal of this database within list of databases
      declare @sec  int;
      declare @min  int;

      -- wait some time to let all databases to start (from command line!)
      WAITFOR DELAY '0:0:10';

      -- figure out how many databases are running on the server?
      SELECT number as num, db_name(number) as name, number(*) as ord
        into #temp
        from sa_db_list()
       order by num;
      SET @num = ( select count(*) from #temp );

      -- ... and what position is this database on the server?
      SET @ord = ( select ord from #temp where name = db_name() );

      -- assume checkpoints occur at 20 minute regular intervals (i.e. 20*60 seconds)
      -- figure out how long to wait before we force a checkpoint on this database
      set @sec  = ( 20*60 )*( @ord - 1 ) / @num;
      set @min  = @sec / 60;
      set @sec  = @sec - 60*@min;

      execute immediate 'WAITFOR DELAY ''0:' || @min || ':' || @sec || '''';
      checkpoint;
   END;

You may want to change the initial delay in the above procedure and/or change the '20' minutes in the above computation (if you change the checkpoint interval from the default).

VolkerBarth
Contributor
0 Kudos

Yes, that's the detailed solution I had been too lazy to work out:)

VolkerBarth
Contributor
0 Kudos

In case all those databases have one common DBA account (or you know all of their DBA accounts), you could also use one particular database as "checkpoint controller" and use remote database access to FORWARD CHECKPOINT statements to each database in a round-robin fashion.

That would prevent the need to alter each and every database...it would just need a remote server object - and possibly you could use one (or a few) remote servers and adapt them via ALTER SERVER USING ... on the fly:)