Client Management Suite

 View Only

A Stored Procedure to Monitor Agent Upgrade Status Over-Time 

Mar 06, 2014 12:11 PM

[END OF "SUPPORT" NOTICE]

Hello everyone, after close to 5 years maintaining various tools around Symantec Connect this legacy is turning to be more of a burden than anything else.

It's still is a great set of tool and they all have their use, but as such I'm not going to maintain them anymore.

The source code for this tool may still change over time, and can be found on Github: https://github.com/somewhatsomewhere?tab=repositories

[/END OF "SUPPORT" NOTICE]

  • Introduction
  • Design
  • SQL code
  • Usage
  • Conclusion

Introduction

Monitoring agent upgrade progress over time is an important task in large environments, and is beneficial in any environment to understand the managed computer pool behaviour and effects of seasonality and human behaviour on tasks execution, agent upgrades or patch compliance.

In this article we will create a stored procedure that will allow us to automatically find out which is agent versions are the highest and record the count of computers with the agent and the count of computers to update.

Design

The data will be collected in a custom table name 'TREND_AgentVersions. If the table does not exist it will be automatically created when running the procedure.

The data collection should not happen many times a day, so to avoid this we verify if the last recorded data set was taken within the last 23 hour. If so we will return the last dataset to the caller. If yes we collect fresh data and return the fresh data to the caller.

The data gathered itself is based on the Basic Inventory dataclass 'AeX AC Client Agent' .

We currently track the following agent versions:

  • Symantec Altiris Agent (core)
  • Altiris Inventory Solution agent
  • Altiris Software Update Agent (Patch Management agent)
  • Altiris Software Management Solution Agent

Other agents could be added, such as the Symantec Workspace Virtualization, but this could be done easily by amending the select code in the procedure.

The table will contain the following columns:

  • _exec_id
  • _exec_time
  • Agent Name
  • Agent Highest Version
  • Agents Installed
  • Agents to upgrade
  • % up-to-date

The last field is the result of a computation that could be done at run time (when we select data from the table) but I have decided to store the data so that the information is readily usable for SMP reports and other consumption by users.

SQL Code

Here is the full procedure code:

GO

SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO

CREATE procedure [dbo].[spTrendAgentVersions]
  @force as int = 0
as
/* 
      STORED AGENT COUNTS
*/
-- PART I: Make sure underlying infrastructure exists and is ready to use
if (not exists(select 1 from sys.objects where type = 'U' and name = 'TREND_AgentVersions'))
begin
  CREATE TABLE [dbo].[TREND_AgentVersions](
    [_Exec_id] [int] NOT NULL,
    [_Exec_time] [datetime] NOT NULL,
    [Agent Name] varchar(255) NOT NULL,
    [Agent Highest Version] varchar(255) not null,
    [Agents Installed] varchar(255) NOT NULL,
    [Agents to upgrade] varchar(255) NOT NULL,
    [% up-to-date] money
  ) ON [PRIMARY]

  CREATE UNIQUE CLUSTERED INDEX [IX_TREND_AgentVersions] ON [dbo].[TREND_AgentVersions] 
  (
    [_exec_id] ASC,
    [Agent Name]
  )WITH (PAD_INDEX  = OFF, STATISTICS_NORECOMPUTE  = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = 
OFF, ONLINE = OFF, ALLOW_ROW_LOCKS  = ON, ALLOW_PAGE_LOCKS  = ON) ON [PRIMARY]

end

-- PART II: Get data into the trending table if no data was captured in the last 23 hours
if ((select MAX(_exec_time) from TREND_AgentVersions) <  dateadd(hour, -23, getdate()) or (select COUNT(*) from TREND_AgentVersions) = 0) or (@force = 1)
begin

  declare @id as int
    set @id = (select MAX(_exec_id) from TREND_AgentVersions)

  insert into TREND_AgentVersions
  select (ISNULL(@id + 1, 1)), GETDATE() as '_Exec_time', _cur.[Agent Name], _cur.Latest as 'Agent highest version', _cur.[Agent #] as 'Agents installed', isnull(_old.[Agent #], 0) as 'Agents to upgrade',
       CAST(CAST(_cur.[Agent #] - isnull(_old.[Agent #], 0) as float) / CAST(_cur.[agent #] as float) * 100 as money) as '% up-to-date'
    from 
      (
        select [Agent name], COUNT(*) as 'Agent #', max(a.[Product Version]) as 'Latest'
          from Inv_AeX_AC_Client_Agent a
         where [Agent Name] in ('Altiris Agent'
                    , 'Altiris Inventory Agent'
                    , 'Altiris Software Update Agent'
                    , 'Software Management Solution Agent'
                    )
         group by [agent name]
      ) _cur
    left join (
      select a1.[Agent name], COUNT(*) as 'Agent #'
        from Inv_AeX_AC_Client_Agent a1
        join (
            select [Agent name], max(a.[Product Version]) as 'Latest'
              from Inv_AeX_AC_Client_Agent a
             where [Agent Name] in (  'Altiris Agent'
                        , 'Altiris Inventory Agent'
                        , 'Altiris Software Update Agent'
                        , 'Software Management Solution Agent'
                        , 'Symantec Workspace Virtualization Agent'
                        )
             group by [agent name]
          ) a2
        on a1.[Agent Name] = a2.[Agent Name]
       where a1.[Product Version] < a2.Latest
       group by a1.[Agent Name]
      ) _old
    on _cur.[Agent Name] = _old.[Agent Name]
   order by [Agent Name]
   
end
select *
  from TREND_AgentVersions
 where _exec_id = (select MAX(_exec_id) from TREND_AgentVersions)
 order by [Agent Name]
 
GO

Usage

Copy the SQL procedure code above or save the attached file to run it against your Symantec_CMDB database.

Once the procedure is created on the server you can call it from a SQL task on the SMP, with the following command:

exec spTrendAgentVersions

Save the task and schedule it to run daily. during the night (anytime between 2100 and 0500. Personally I like to schedule it before 23:59 as this ensure the _exec_date field matches the day when the results where collected. If you run the task past midnight the data will be shown for day <d> but the execution time (and date label in any UI) would show <d +1> which can be confusing.

Conclusion

With a daily schedule you can now track the agent upgrade status of your computers over time. But in order to show the data in a visualize appealing manner you will need a custom User Interface. But this will be the subject of another article or download!

Statistics
0 Favorited
1 Views
1 Files
0 Shares
0 Downloads
Attachment(s)
txt file
spTrendAgentVersions.txt   3 KB   1 version
Uploaded - Feb 25, 2020

Tags and Keywords

Comments

Mar 06, 2014 02:41 PM

Thanks for this Don Cardinal. I actually had some similar issues when I was bringing in some other sub-agent that are part of the core agent in (I didn't start with the where clause that sepcify which agents to track down).

So your work around is nice and I suspect that depending on how well the version numbers are maintained over time (and provided we don't go from version 8460 to 1000 for example) we may be okay.

But we also may have to tweak the procedure to use a user table where we would define which are the highest agent versions we are interested in.

In this manner we'd avoid problem with the higher versions detection problem.

Mar 06, 2014 01:03 PM

Very nice. Only issue I see is that it does not account for Mac's. In my instance, we are currently on 7.1.15435.8435 whereas our current Mac version of the Altiris agent is 7.1.8287. Since the Mac version is higher, it returns 0.0232% of my environment is up-to-date for the Altiris Agent. Mac's always get in the way.

Here is my modification to remove those pesky Mac versions:

go

set ansi_nulls on
go

set quoted_identifier on
go

create procedure [dbo].[spTrendAgentVersions] @force as int = 0
as
/* 
      STORED AGENT COUNTS
*/
-- PART I: Make sure underlying infrastructure exists and is ready to use
if (
		not exists (
			select 1
			from sys.objects
			where type = 'U'
				and name = 'TREND_AgentVersions'
			)
		)
begin
	create table [dbo].[TREND_AgentVersions] (
		[_Exec_id] [int] not null,
		[_Exec_time] [datetime] not null,
		[Agent Name] varchar(255) not null,
		[Agent Highest Version] varchar(255) not null,
		[Agents Installed] varchar(255) not null,
		[Agents to upgrade] varchar(255) not null,
		[% up-to-date] money
		) on [PRIMARY]

	create unique clustered index [IX_TREND_AgentVersions] on [dbo].[TREND_AgentVersions] (
		[_exec_id] asc,
		[Agent Name]
		)
		with (
				PAD_INDEX = off,
				STATISTICS_NORECOMPUTE = off,
				SORT_IN_TEMPDB = off,
				IGNORE_DUP_KEY = off,
				DROP_EXISTING = off,
				ONLINE = off,
				ALLOW_ROW_LOCKS = on,
				ALLOW_PAGE_LOCKS = on
				) on [PRIMARY]
end

-- PART II: Get data into the trending table if no data was captured in the last 23 hours
if (
		(
			select MAX(_exec_time)
			from TREND_AgentVersions
			) < dateadd(hour, - 23, getdate())
		or (
			select COUNT(*)
			from TREND_AgentVersions
			) = 0
		)
	or (@force = 1)
begin
	declare @id as int

	set @id = (
			select MAX(_exec_id)
			from TREND_AgentVersions
			)

	insert into TREND_AgentVersions
	select (ISNULL(@id + 1, 1)),
		GETDATE() as '_Exec_time',
		_cur.[Agent Name],
		_cur.Latest as 'Agent highest version',
		_cur.[Agent #] as 'Agents installed',
		isnull(_old.[Agent #], 0) as 'Agents to upgrade',
		CAST(CAST(_cur.[Agent #] - isnull(_old.[Agent #], 0) as float) / CAST(_cur.[agent #] as float) * 100 as money) as '% up-to-date'
	from (
		select [Agent name],
			COUNT(*) as 'Agent #',
			max(a.[Product Version]) as 'Latest'
		from Inv_AeX_AC_Client_Agent a
		where [Agent Name] in (
				'Altiris Agent',
				'Altiris Inventory Agent',
				'Altiris Software Update Agent',
				'Software Management Solution Agent',
				'Symantec Workspace Virtualization Agent'
				)
			and ProgId != 'Altiris.PluginManager'
		group by [agent name]
		) _cur
	left join (
		select a1.[Agent name],
			COUNT(*) as 'Agent #'
		from Inv_AeX_AC_Client_Agent a1
		join (
			select [Agent name],
				max(a.[Product Version]) as 'Latest'
			from Inv_AeX_AC_Client_Agent a
			where [Agent Name] in (
					'Altiris Agent',
					'Altiris Inventory Agent',
					'Altiris Software Update Agent',
					'Software Management Solution Agent',
					'Symantec Workspace Virtualization Agent'
					)
				and ProgId != 'Altiris.PluginManager'
			group by [agent name]
			) a2
			on a1.[Agent Name] = a2.[Agent Name]
		where a1.[Product Version] < a2.Latest
		group by a1.[Agent Name]
		) _old
		on _cur.[Agent Name] = _old.[Agent Name]
	order by [Agent Name]
end

select *
from TREND_AgentVersions
where _exec_id = (
		select MAX(_exec_id)
		from TREND_AgentVersions
		)
order by [Agent Name]
go

 

Related Entries and Links

No Related Resource entered.