Introduction

Sometimes you face interesting challenges with unusual environment. One of my customer needed a automated and flexible backup solution. Said like that nothing very complex you will say. But if I mention that some databases were 60TB big with more than 30 filegroups and around 600 database data files each and moreover synchronized in an AlwayOn availability group, it is not the same story and you can easily imagine that working with standard backup strategy will not be viable. Therefore I was working on implementing solution using partial full, partial differential and read-only filegroups backups to minimize the time needed.
Well this post is not explaining the whole solution, but only a way to collect the last backup information of my databases, especially for the ones being in an AlwaysOn availability group and which filegroup states changed.
If you already worked with partial backups and read-only filegroups backups you know that the backup sequence is very important, but if you don’t you will quickly notice it if you need to restore, and you can easily understand why this last backup information is crucial. As the backups always have to run on the primary replica, you have to collect the information on all replicas if failover occurred and the primary changed to ensure that you execute the right backups at the right moment and not make unnecessary backups (remember the data volumes).

 

Explanation of the solution and code

Another thing to mentioned, because of security policies, it was forbidden to use linked server, but hopefully xp_CmdShell was possible. I wanted each replica to work independently, and needed a way to query the remote replicas to collect the last backup information on each SQL Server instances involved. Because backup history might be cleans, I need to store this information in local tables. I created 2 tables, one to stored last database backups information and the other to store last read-only filegroup backups information. Additionally I created 2 tables to collect temporarily the information coming from all replicas.

Creation of the last backup information tables:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
--########################################################
--###Backup generator - backup last date info temporary table
--########################################################
 
USE [<YourDatabaseName>]
GO
/*
if OBJECT_ID('[dbo].[bakgen_backuplastdt_databases_temp]') is not null
    drop table [dbo].[bakgen_backuplastdt_databases_temp]
*/
create table [dbo].[bakgen_backuplastdt_databases_temp] (
    ServerName sysname not null,
    SqlInstanceName sysname  not null,
    SqlServerName sysname  not null,
    ServiceBrokerGuid uniqueidentifier not null,
    DatabaseCreationDate datetime  not null,
    DatabaseName sysname  not null,
    BackupType char(1) not null,
    LastBackupDate datetime  not null,
    LastBackupSize numeric(20,0) not null,
    is_primary bit null,
    insertdate datetime  not null
)
GO
create unique clustered index idx_bakgen_backuplastdt_databases_temp on [dbo].[bakgen_backuplastdt_databases_temp](DatabaseCreationDate,DatabaseName,BackupType,ServerName,SqlInstanceName)
 
 
 
--########################################################
--###Backup generator - backup last date info
--########################################################
 
USE [<YourDatabaseName>]
GO
/*
if OBJECT_ID('[dbo].[bakgen_backuplastdt_databases]') is not null
    drop table [dbo].[bakgen_backuplastdt_databases]
*/
create table [dbo].[bakgen_backuplastdt_databases] (
    ServerName sysname  not null,
    SqlInstanceName sysname  not null,
    SqlServerName sysname  not null,
    ServiceBrokerGuid uniqueidentifier not null,
    DatabaseCreationDate datetime  not null,
    DatabaseName sysname  not null,
    BackupType char(1) not null,
    LastBackupDate datetime  not null,
    LastBackupSize numeric(20,0) not null,
    is_primary bit null,
    insertdate datetime  not null
)
GO
create unique clustered index idx_bakgen_backuplastdt_databases on [dbo].[bakgen_backuplastdt_databases](DatabaseCreationDate,DatabaseName,BackupType,ServerName,SqlInstanceName)

I finally decided to work with a stored procedure calling a PowerShell scripts to remotely execute the queries on the replicas.
The stored procedure lists the existing replicas and collects the last database backup information, then the read-only filegroup backup information creating 2 different queries to execute locally on the server and store the data in the temp tables first. It will create similar queries, excluding the databases not involved in availability groups and execute them on the remote replicas using xp_CmdShell running PowerShell scripts. The PowerShell scripts are dynamically created using the TSQL queries generated. They used one function of the well-known DBATools. So you will have to install it first.
You will notice that in order to log the scripts generated are nicely formatted in order to read and debug them easier. But before executing you PowerShell script through xp_CmdShell you need to apply some string formatting like the 2 lines I added to avoid the execution to fail:

set @PSCmd = replace(replace(@PSCmd, nchar(13), N”), nchar(10), N’ ‘)
set @PSCmd = replace(@PSCmd, ‘>’, N’^>’)

Do not forget to escape some characters, otherwise the execution will fails, in my case omitting to escape the ‘>’ sign raise an “Access is denied” message in the output of the xp_CmdShell execution.

After that the code is comparing what has been collected in the temp tables with the final information and update information if needed.

Here is the complete code of the stored procedure:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
use [<YourDatabaseName>]
if OBJECT_ID('dbo.bakgen_p_getbakinfo') is not null
            drop procedure dbo.bakgen_p_getbakinfo
go
 
CREATE PROCEDURE dbo.bakgen_p_getbakinfo
AS
/************************************
*   dbi-services SA, Switzerland    *
*************************************
    Group/Privileges..: DBA
    Script Name......:       bakgen_p_getbakinfo.sql
    Author...........:          Christophe Cosme
    Date.............:           2019-09-20
    Version..........:          SQL Server 2016 / 2017
    Description......:        Get the backup information locally but also on the replica involved
 
    Input parameters.:
 
            Output parameter:
                                                
    Called by........:         Stored Procdedure : [dbo].[bakgen_p_bakexe]
************************************************************************************************
    Historical
    Date        Version    Who    Whats                  Comments
    ----------  -------    ---    --------    -----------------------------------------------------
    2019-09-30  1.0        CHC    Creation
************************************************************************************************/
BEGIN
 
BEGIN TRY
             
            set nocount on
 
            declare
    @ErrorMessage  NVARCHAR(4000),
    @ErrorSeverity INT,
    @ErrorState    INT;
 
            declare @ModuleName sysname,
                                    @ProcName sysname,
                                    @InfoLog nvarchar(max),
                                    @Execute char(1)
                         
            set @ModuleName = 'BakGen'
            set @ProcName = OBJECT_NAME(@@PROCID)
            set @Execute = 'A'
 
            set @InfoLog = 'Retrieve backup information'
            execute dbo.bakgen_p_log      
                        @ModuleName = @ModuleName,
                        @ProcedureName = @ProcName,
                        @ExecuteMode = @Execute,
                        @LogType = 'INFO',
                        @DatabaseName = null,
                        @Information = @InfoLog,
                        @Script = null
 
 
            --###variable to store error message
            declare @errmsg varchar(4000)
            --###variable with the current datetime
            declare @cdt datetime = getdate()
 
            --###variabler to store the sql and powershell commands to execute
            declare @sqllocalDB nvarchar(4000),
                                    @sqllocalFG nvarchar(4000),
                                    @sqlremoteDB nvarchar(4000),
                                    @sqlremoteFG nvarchar(4000),
                                    @PSCmd nvarchar(4000)
 
            --###variable to store the local SQL server name
            declare @LocalSqlServerName sysname
            --###variable to store the list of replicas
            declare @TAgReplica table (AgReplicaName sysname)
            --###variable for the cursors
            declare @AgReplicaName sysname
 
            --###set the local SQL Server name
            set @LocalSqlServerName = lower(convert(sysname,serverproperty('ServerName')))
                         
 
            --############################################################################
            --### check if tables exist
            --############################################################################
            if object_id('[dbo].[bakgen_backuplastdt_databases_temp]') is null
            begin
                        set @errmsg = 'Get Backup info : table not found'
                        set @errmsg += '          table name = [dbo].[bakgen_backuplastdt_databases_temp]'
                        raiserror (@errmsg,11,1);
            end
            if object_id('[dbo].[bakgen_backuplastdt_fgreadonly_temp]') is null
            begin
                        set @errmsg = 'Get Backup info : table not found'
                        set @errmsg += '          table name = [dbo].[bakgen_backuplastdt_fgreadonly_temp]'
                        raiserror (@errmsg,11,1);                     
            end
 
            if object_id('[dbo].[bakgen_backuplastdt_databases]') is null
            begin
                        set @errmsg = 'Get Backup info : table not found'
                        set @errmsg += '          table name = [dbo].[bakgen_backuplastdt_databases]'
                        raiserror (@errmsg,11,1);
            end
            if object_id('[dbo].[bakgen_backuplastdt_fgreadonly]') is null
            begin
                        set @errmsg = 'Get Backup info : table not found'
                        set @errmsg += '          table name = [dbo].[bakgen_backuplastdt_fgreadonly]'
                        raiserror (@errmsg,11,1);                     
            end
 
 
             
            --############################################################################
            --### select the replicas involved adding first the local server
            --############################################################################
            insert into @TAgReplica (AgReplicaName ) select @LocalSqlServerName
 
            --###check if alwayson feature is activated
            if (serverproperty('IsHadrEnabled') = 1)
            begin
                        insert into @TAgReplica (AgReplicaName )
                        select lower(agr.replica_server_name) from sys.availability_replicas agr
                                    where agr.replica_server_name <> @LocalSqlServerName
            end
 
 
            --############################################################################
            --### construct the SQL command to execute on the local SQL Server
            --############################################################################
            set @sqllocalDB = ''
            set @sqllocalDB +='
 
            declare @Tbi table (
                        ServerName sysname,
                        SqlInstanceName sysname,
                        SqlServerName sysname,
                        ServiceBrokerGuid uniqueidentifier,
                        DatabaseCreationDate datetime,
                        DatabaseName sysname,
                        BackupType char(1),
                        LastBackupDate datetime,
                        is_primary bit null,
                        insertdate datetime      
            )
 
 
            insert into @Tbi (
                        [ServerName],
                        [SqlInstanceName],
                        [SqlServerName],
                        [ServiceBrokerGuid],
                        [DatabaseCreationDate],
                        [DatabaseName],
                        [BackupType],
                        [LastBackupDate],
                        [is_primary],
                        [insertdate])
            select 
                        lower(convert(sysname,serverproperty(''machinename''))) as ServerName,
                        lower(convert(sysname,serverproperty(''InstanceName''))) as SqlInstanceName,
                        lower(convert(sysname,serverproperty(''ServerName''))) as SqlServerName,
                        db.service_broker_guid as ServiceBrokerGuid,
                        db.create_date as DatabaseCreationDate,
                        bs.database_name as DatabaseName,
                        bs.type as BackupType,
                        max(bs.backup_finish_date) as LastBackupDate,
                        sys.fn_hadr_is_primary_replica(bs.database_name) as is_primary,
                        ''' + convert(varchar,@cdt,120) + '''  
            from msdb.dbo.backupset bs
                        inner join sys.databases db on db.name = bs.database_name
                        where bs.type in (''D'',''I'',''P'',''Q'')
                                    and bs.is_copy_only = 0
                                    and coalesce(sys.fn_hadr_is_primary_replica(bs.database_name),-1) in (-1,0,1)
                        group by
                                    db.service_broker_guid,
                                    db.create_date,
                                    bs.database_name,
                                    bs.type,
                                    sys.fn_hadr_is_primary_replica(bs.database_name)
 
            insert into [dbo].[bakgen_backuplastdt_databases_temp] (
                        [ServerName],
                        [SqlInstanceName],
                        [SqlServerName],
                        [ServiceBrokerGuid],
                        [DatabaseCreationDate],
                        [DatabaseName],
                        [BackupType],
                        [LastBackupDate],
                        [LastBackupSize],
                        [is_primary],
                        [insertdate])
            select 
                        t.[ServerName],
                        t.[SqlInstanceName],
                        t.[SqlServerName],
                        t.[ServiceBrokerGuid],
                        t.[DatabaseCreationDate],
                        t.[DatabaseName],
                        t.[BackupType],
                        t.[LastBackupDate],
                        bs.[backup_size],
                        t.[is_primary],
                        t.[insertdate]
            from @Tbi t
                        inner join msdb.dbo.backupset bs on
                                    bs.backup_finish_date = t.LastBackupDate 
                                    and bs.database_name collate database_default = t.DatabaseName collate database_default
                                    and bs.type collate database_default = t.BackupType collate database_default
'
 
 
 
 
            set @sqllocalFG = ''
            set @sqllocalFG +='
 
            insert into [dbo].[bakgen_backuplastdt_fgreadonly_temp]
           ([ServerName],
           [SqlInstanceName],
           [SqlServerName],
                           [ServiceBrokerGuid],
                           [DatabaseCreationDate],
           [DatabaseName],
           [BackupType],
           [filegroup_name],
           [file_logicalname],
           [filegroup_guid],
           [file_guid],
           [LastBackupDate],
                           [LastBackupReadOnlyLsn],
           [is_primary],
                           [insertdate])
            select 
                        lower(convert(sysname,serverproperty(''machinename''))) as ServerName,
                        lower(convert(sysname,serverproperty(''InstanceName''))) as SqlInstanceName,
                        lower(convert(sysname,serverproperty(''ServerName''))) as SqlServerName,
                        db.service_broker_guid as ServiceBrokerGuid,
                        db.create_date as DatabaseCreationDate,
                        bs.database_name as DatabaseName,
                        bs.type as BackupType,
                        bf.filegroup_name,
                        bf.logical_name as file_logicalname,
                        bf.filegroup_guid,
                        bf.file_guid,
                        max(bs.backup_finish_date) as LastBackupDate,
                        max(bf.read_only_lsn) as LastBackupReadOnlyLsn,
                        sys.fn_hadr_is_primary_replica(bs.database_name) as is_primary,
                        ''' + convert(varchar,@cdt,120) + '''  
            from msdb.dbo.backupset bs
                                    inner join msdb.dbo.backupfile bf on  bf.backup_set_id = bs.backup_set_id
                                    inner join sys.databases db on db.name = bs.database_name
                        where
                                    bs.backup_finish_date >= db.create_date
                                    and bs.type in (''F'')
                                    and bs.is_copy_only = 0
                                    and coalesce(sys.fn_hadr_is_primary_replica(bs.database_name),-1) in (-1,0,1)
                                    and bf.is_present = 1
                                    and bf.is_readonly = 1
                                    and bf.file_type = ''D''
                        group by
                                    db.service_broker_guid,
                                    db.create_date,
                                    bs.database_name,
                                    bs.type,
                                    bf.filegroup_name,
                                    bf.logical_name,
                                    bf.filegroup_guid,
                                    bf.file_guid,
                                    sys.fn_hadr_is_primary_replica(bs.database_name)
'
 
 
             
            --############################################################################
            --### construct the SQL command to execute on the remote SQL Server
            --############################################################################
            set @sqlremoteDB = ''
            set @sqlremoteDB +='
 
            declare @Tbi table (
                        ServerName sysname,
                        SqlInstanceName sysname,
                        SqlServerName sysname,
                        ServiceBrokerGuid uniqueidentifier,
                        DatabaseCreationDate datetime,
                        DatabaseName sysname,
                        BackupType char(1),
                        LastBackupDate datetime,
                        is_primary bit null,
                        insertdate datetime      
            )
 
            insert into @Tbi (
                        [ServerName],
                        [SqlInstanceName],
                        [SqlServerName],
                        [ServiceBrokerGuid],
                        [DatabaseCreationDate],
                        [DatabaseName],
                        [BackupType],
                        [LastBackupDate],
                        [is_primary],
                        [insertdate])
            select 
                        lower(convert(sysname,serverproperty(''machinename''))) as ServerName,
                        lower(convert(sysname,serverproperty(''InstanceName''))) as SqlInstanceName,
                        lower(convert(sysname,serverproperty(''ServerName''))) as SqlServerName,
                        db.service_broker_guid as ServiceBrokerGuid,
                        db.create_date as DatabaseCreationDate,
                        bs.database_name as DatabaseName,
                        bs.type as BackupType,
                        max(bs.backup_finish_date) as LastBackupDate,
                        sys.fn_hadr_is_primary_replica(bs.database_name) as is_primary,
                        ''' + convert(varchar,@cdt,120) + '''    
            from msdb.dbo.backupset bs
                        inner join sys.databases db on db.name = bs.database_name
                        where bs.type in (''D'',''I'',''P'',''Q'')
                                    and bs.is_copy_only = 0
                                    and coalesce(sys.fn_hadr_is_primary_replica(bs.database_name),-1) in (0,1)
                        group by
                                    db.service_broker_guid,
                                    db.create_date,
                                    bs.database_name,
                                    bs.type,
                                    sys.fn_hadr_is_primary_replica(bs.database_name)
 
            select 
                        t.[ServerName],
                        t.[SqlInstanceName],
                        t.[SqlServerName],
                        t.[ServiceBrokerGuid],
                        t.[DatabaseCreationDate],
                        t.[DatabaseName],
                        t.[BackupType],
                        t.[LastBackupDate],
                        bs.[backup_size],
                        t.[is_primary],
                        t.[insertdate]
            from @Tbi t
                        inner join msdb.dbo.backupset bs on
                                    bs.backup_finish_date = t.LastBackupDate
                                    and bs.database_name collate database_default = t.DatabaseName collate database_default
                                    and bs.type collate database_default = t.BackupType collate database_default
 
'
 
            set @sqlremoteFG = ''
            set @sqlremoteFG +='
 
            select 
                        lower(convert(sysname,serverproperty(''machinename''))) as ServerName,
                        lower(convert(sysname,serverproperty(''InstanceName''))) as SqlInstanceName,
                        lower(convert(sysname,serverproperty(''ServerName''))) as SqlServerName,
                        db.service_broker_guid as ServiceBrokerGuid,
                        db.create_date as DatabaseCreationDate,
                        bs.database_name as DatabaseName,
                        bs.type as BackupType,
                        bf.filegroup_name,
                        bf.logical_name as file_logicalname,
                        bf.filegroup_guid,
                        bf.file_guid,
                        max(bs.backup_finish_date) as LastBackupDate,
                        max(bf.read_only_lsn) as LastReadOnlyLsn,
                        sys.fn_hadr_is_primary_replica(bs.database_name) as is_primary,
                        ''' + convert(varchar,@cdt,120) + '''  
            from msdb.dbo.backupset bs
                                    inner join msdb.dbo.backupfile bf on  bf.backup_set_id = bs.backup_set_id
                                    inner join sys.databases db on db.name = bs.database_name
                        where
                                    bs.backup_finish_date >= db.create_date
                                    and bs.type in (''F'')
                                    and bs.is_copy_only = 0
                                    and coalesce(sys.fn_hadr_is_primary_replica(bs.database_name),-1) in (0,1)
                                    and bf.is_present = 1
                                    and bf.is_readonly = 1
                                    and bf.file_type = ''D''
                        group by
                                    db.service_broker_guid,
                                    db.create_date,
                                    bs.database_name,
                                    bs.type,
                                    bf.filegroup_name,
                                    bf.logical_name,
                                    bf.filegroup_guid,
                                    bf.file_guid,
                                    sys.fn_hadr_is_primary_replica(bs.database_name)
'
 
            --############################################################################
            --### delete all records in the backup info tables
            --############################################################################
            delete from [dbo].[bakgen_backuplastdt_databases_temp]
            delete from [dbo].[bakgen_backuplastdt_fgreadonly_temp]
 
            --############################################################################
            --### loop for all replicas involved
            --############################################################################
            declare cur_replica cursor
            static local forward_only
            for
                        select AgReplicaName
                        from @TAgReplica
                  
            open cur_replica
            fetch next from cur_replica into
                        @AgReplicaName                   
 
 
            while @@fetch_status = 0
            begin
                                     
                        if @LocalSqlServerName = @AgReplicaName
                        begin
 
                                    set @InfoLog = 'Get database backup information on local SQL Server instance ' + QUOTENAME(@AgReplicaName)
                                    execute dbo.bakgen_p_log      
                                               @ModuleName = @ModuleName,
                                               @ProcedureName = @ProcName,
                                                @ExecuteMode = @Execute,
                                               @LogType = 'INFO',
                                               @DatabaseName = null,
                                               @Information = @InfoLog,
                                               @Script = @sqllocalDB
                                    execute sp_executesql @sqllocalDB
 
                                    set @InfoLog = 'Get read-only filegroup backup information on local SQL Server instance ' + QUOTENAME(@AgReplicaName)
                                    execute dbo.bakgen_p_log      
                                               @ModuleName = @ModuleName,
                                               @ProcedureName = @ProcName,
                                               @ExecuteMode = @Execute,
                                               @LogType = 'INFO',
                                               @DatabaseName = null,
                                               @Information = @InfoLog,
                                               @Script = @sqllocalFG
                                    execute sp_executesql @sqllocalFG
 
                        end
                        else
                        begin
                                    --############################################################################
                                    --### construct the PowerShell command to execute on the remote SQL Server
                                    --############################################################################
                                    set @PSCmd  = ''
                                    set @PSCmd += 'PowerShell.exe '
                                    set @PSCmd += '-Command "'
                                    set @PSCmd += '$qrydb = "' + @sqlremoteDB + '"; '
                                    set @PSCmd += '$qryfg = "' + @sqlremoteFG + '"; '
                                    set @PSCmd += '$rdb = Invoke-DbaQuery -SqlInstance ' + @AgReplicaName + ' -Query $qrydb; '
                                    set @PSCmd += '$rfg = Invoke-DbaQuery -SqlInstance ' + @AgReplicaName + ' -Query $qryfg; '
                                    set @PSCmd += 'if ($rdb -ne $null) { '
                                    set @PSCmd += 'Write-DbaDbTableData -SqlInstance ' + @LocalSqlServerName + ' -Database ' + db_name() + ' -Schema dbo -Table bakgen_backuplastdt_databases_temp -InputObject $rdb;'
                                    set @PSCmd += '} '
                                    set @PSCmd += 'if ($rfg -ne $null) { '
                                    set @PSCmd += 'Write-DbaDbTableData -SqlInstance ' + @LocalSqlServerName + ' -Database ' + db_name() + ' -Schema dbo -Table bakgen_backuplastdt_fgreadonly_temp -InputObject $rfg;'
                                    set @PSCmd += '} '
                                    set @PSCmd += '"'
 
                                    set @InfoLog = 'Get backup information on replica SQL Server instance ' + QUOTENAME(@AgReplicaName) + ' executing master..xp_cmdshell PowerShell script'
                                    execute dbo.bakgen_p_log      
                                               @ModuleName = @ModuleName,
                                               @ProcedureName = @ProcName,
                                               @ExecuteMode = @Execute,
                                               @LogType = 'INFO',
                                               @DatabaseName = null,
                                               @Information = @InfoLog,
                                               @Script = @PSCmd
 
                                    --###remove CRLF for xp_cmdshell and PowerShell
                                    set @PSCmd = replace(replace(@PSCmd, nchar(13), N''), nchar(10), N' ')
                                    set @PSCmd = replace(@PSCmd, '>', N'^>')
                                    --###Execute the powershell command on the replica and store the result in the temporary tables
                                    exec master..xp_cmdshell @PSCmd
                        end
                         
                        fetch next from cur_replica into
                                    @AgReplicaName                   
 
 
            end
            close cur_replica
            deallocate cur_replica
 
 
            --############################################################################
            --### Update and insert backup information in final tables
            --############################################################################
 
            --###Update first the database creation date with the local ones
            Update t
                        set t.DatabaseCreationDate = db.create_date
            from [dbo].[bakgen_backuplastdt_databases_temp] t
                        inner join sys.databases db
                                    on db.name collate database_default = t.DatabaseName collate database_default
                                               and db.service_broker_guid = t.ServiceBrokerGuid
 
            Update t
                        set t.DatabaseCreationDate = db.create_date
            from [dbo].[bakgen_backuplastdt_fgreadonly_temp] t
                        inner join sys.databases db
                                    on db.name collate database_default = t.DatabaseName collate database_default
                                               and db.service_broker_guid = t.ServiceBrokerGuid
 
 
 
 
            BEGIN TRY
 
                        begin transaction
 
                        delete f
                                    from [dbo].[bakgen_backuplastdt_databases_temp] t
                                               inner join [dbo].[bakgen_backuplastdt_databases] f
                                                           on f.DatabaseCreationDate = t.DatabaseCreationDate
                                                                       and f.DatabaseName = t.DatabaseName
                                                                       and f.BackupType = t.BackupType
                                                                       and f.ServerName = t.ServerName
                                                                       and t.SqlInstanceName = f.SqlInstanceName
                                               where f.LastBackupDate < t.LastBackupDate
 
                        Insert into [dbo].[bakgen_backuplastdt_databases] (
                                    ServerName,
                                    SqlInstanceName,
                                    SqlServerName,
                                    DatabaseCreationDate,
                                    DatabaseName,
                                    BackupType,
                                    LastBackupDate,
                                    LastBackupSize,
                                    is_primary,
                                    insertdate
                        )
                        select
                                    t.ServerName,
                                    t.SqlInstanceName,
                                    t.SqlServerName,
                                    t.DatabaseCreationDate,
                                    t.DatabaseName,
                                    t.BackupType,
                                    t.LastBackupDate,
                                    t.LastBackupSize,
                                    t.is_primary,
                                    t.insertdate
                                    from [dbo].[bakgen_backuplastdt_databases_temp] t
                                               where not exists (select 1 from [dbo].[bakgen_backuplastdt_databases] f
                                                                                                                      where f.DatabaseName = t.DatabaseName
                                                                                                                                  and f.BackupType = t.BackupType
                                                                                                                                  and f.ServerName = t.ServerName
                                                                                                                                  and t.SqlInstanceName = f.SqlInstanceName)
                                     
                         
                        commit
 
                        begin transaction
 
                        delete f
                                    from [dbo].[bakgen_backuplastdt_fgreadonly_temp] t
                                               inner join [dbo].[bakgen_backuplastdt_fgreadonly] f
                                                           on f.DatabaseName = t.DatabaseName
                                                                       and f.BackupType = t.BackupType
                                                                       and f.filegroup_name = t.filegroup_name
                                                                       and f.ServerName = t.ServerName
                                                                       and f.SqlInstanceName = t.SqlInstanceName
                                               where f.LastBackupDate < t.LastBackupDate
 
 
                        Insert into [dbo].[bakgen_backuplastdt_fgreadonly] (
                                    ServerName,    
                                    SqlInstanceName,
                                    SqlServerName,          
                                    DatabaseCreationDate,
                                    DatabaseName,           
                                    BackupType,
                                    filegroup_name,
                                    file_logicalname,         
                                    filegroup_guid,
                                    file_guid,         
                                    LastBackupDate,         
                                    LastBackupReadOnlyLsn,
                                    is_primary,
                                    insertdate                    
                        )
                        select
                                    t.ServerName,  
                                    t.SqlInstanceName,
                                    t.SqlServerName,
                                    t.DatabaseCreationDate,
                                    t.DatabaseName,         
                                    t.BackupType,
                                    t.filegroup_name,
                                    t.file_logicalname,       
                                    t.filegroup_guid,          
                                    t.file_guid,       
                                    t.LastBackupDate,       
                                    t.LastBackupReadOnlyLsn,
                                    t.is_primary,
                                    t.insertdate                  
                        from [dbo].[bakgen_backuplastdt_fgreadonly_temp] t                                       
                                    where not exists (
                                               select 1 from  [dbo].[bakgen_backuplastdt_fgreadonly] f
                                               where f.DatabaseName = t.DatabaseName
                                                                       and f.BackupType = t.BackupType
                                                                       and f.filegroup_name = t.filegroup_name
                                                                       and f.ServerName = t.ServerName
                                                                       and t.SqlInstanceName = f.SqlInstanceName)
 
                         
                        commit
            END TRY
            BEGIN CATCH
                SELECT
                                    @ErrorMessage = ERROR_MESSAGE(),
                                    @ErrorSeverity = ERROR_SEVERITY(),
                                    @ErrorState = ERROR_STATE();
 
                        IF @@TRANCOUNT > 0
                                    ROLLBACK
                         
                        raiserror(@ErrorMessage, @ErrorSeverity, @ErrorState);
 
            END CATCH
 
 
 
RETURN;
 
END TRY
BEGIN CATCH
    SELECT
        @ErrorMessage = ERROR_MESSAGE(),
        @ErrorSeverity = ERROR_SEVERITY(),
        @ErrorState = ERROR_STATE();
 
            set @InfoLog = '@ErrorState = ' + convert(nvarchar, @ErrorState) + '/@ErrorSeverity = ' + convert(nvarchar, @ErrorSeverity) + '/@ErrorMessage = ' + @ErrorMessage
            execute dbo.bakgen_p_log      
                        @ModuleName = @ModuleName,
                        @ProcedureName = @ProcName,
                        @ExecuteMode = @Execute,
                        @LogType = 'ERROR',
                        @DatabaseName = null,
                        @Information = @InfoLog,
                        @Script = null
 
    raiserror(@ErrorMessage, @ErrorSeverity, @ErrorState);
END CATCH;
 
RETURN
END

Other Objects needed

As mentioned above I used the DBATools Write-DbaDbTableData function, so need to install it before being able to run the above stored procedure.

I share also the 2 other objects used in the above stored procedure, but of course you can adapt the code to your needs

Creation of the log table:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
--########################################################
--###Backup generator - logs
--########################################################
 
USE [<YourDatabaseName>]
GO
/*
if OBJECT_ID('[dbo].[bakgen_logs]') is not null
    drop table [dbo].[bakgen_logs]
*/
create table [dbo].[bakgen_logs] (
    id bigint identity(1,1) not null,
    LogDate datetime,
    SqlServerName sysname,
    ModuleName sysname,
    ProcedureName sysname,
    ExecuteMode char(1),
    LogType nvarchar(50),
    DatabaseName sysname null,
    Information nvarchar(max) null,
    Scripts nvarchar(max) null,
CONSTRAINT [PK_bakgen_logs] PRIMARY KEY CLUSTERED
(
    [id] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
)
GO

Creation of the stored procedure to write the logs:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
use [<YourDatabaseName>]
if OBJECT_ID('dbo.bakgen_p_log') is not null
    drop procedure dbo.bakgen_p_log
go
 
CREATE PROCEDURE dbo.bakgen_p_log
(
    @ModuleName sysname,
    @ProcedureName sysname,
    @ExecuteMode char(1),
    @LogType nvarchar(50),
    @DatabaseName sysname = null,
    @Information nvarchar(max) =  null,
    @Script nvarchar(max)  = null
)
 
AS
/************************************
*   dbi-services SA, Switzerland    *
*************************************
    Group/Privileges..: DBA
    Script Name......:  bakgen_p_log.sql
    Author...........:  Christophe Cosme
    Date.............:  2019-09-20
    Version..........:  SQL Server 2016 / 2017
    Description......:  write information to the log table to keep trace of the step executed
 
    Input parameters.:
 
    Output parameter:
                 
************************************************************************************************
    Historical
    Date        Version    Who    Whats     Comments
    ----------  -------    ---    --------  -----------------------------------------------------
    2019-10-14  1.0        CHC    Creation
************************************************************************************************/
BEGIN
 
BEGIN TRY
     
    --###variable to store error message
    declare @errmsg varchar(4000)
 
    if OBJECT_ID('[dbo].[bakgen_logs]') is null
    begin
        set @errmsg = 'bakgen_p_log : table not found - be sure the table exists'
        set @errmsg += '    table name = [dbo].[bakgen_logs]'
        raiserror (@errmsg,11,1);
    end    
 
    insert into [dbo].[bakgen_logs] (
        LogDate,
        SqlServerName,
        ModuleName,
        ProcedureName,
        ExecuteMode,
        LogType,
        DatabaseName,
        Information,
        Scripts
        )
    values(
        getdate(),
        convert(sysname,SERVERPROPERTY('servername')),
        @ModuleName,
        @ProcedureName,
        @ExecuteMode,
        @LogType,
        @DatabaseName,
        @Information,
        @Script
        )
 
 
RETURN;
 
END TRY
BEGIN CATCH
    declare
    @ErrorMessage  NVARCHAR(4000),
    @ErrorSeverity INT,
    @ErrorState    INT;
    SELECT
        @ErrorMessage = ERROR_MESSAGE(),
        @ErrorSeverity = ERROR_SEVERITY(),
        @ErrorState = ERROR_STATE();
  
    -- return the error inside the CATCH block
    raiserror(@ErrorMessage, @ErrorSeverity, @ErrorState);
END CATCH;
 
RETURN
END

Conclusion

Triggering PowerShell from a stored procedure did the trick for my special case and is very practical. But to find the right syntax to make the script running through xp_CmdShell was not so trivial. I admit to spend sometimes to figure out what was causing the issue.
But I definitely enjoyed the solution for retrieving information outside the local SQL Server instance.