mirror of
https://github.com/MLBZ521/MacAdmin.git
synced 2026-02-03 14:03:26 +00:00
Minor cleanup
This commit is contained in:
@@ -1,321 +0,0 @@
|
||||
-- #############################
|
||||
-- # Clean up icons in the JSS #
|
||||
-- #############################
|
||||
|
||||
-- These are notes on performing maintenance on the icons table within the Jamf Pro database.
|
||||
-- Several of the below actions have been incorporated within my jamf_db_maint.sh script.
|
||||
|
||||
-- Resources:
|
||||
-- jaycohen @ https://www.jamf.com/jamf-nation/feature-requests/1474/manage-self-service-policy-icons
|
||||
-- Sample queries originally provided by Jamf Support and have been modified as needed
|
||||
|
||||
-- ####################################################################################################
|
||||
-- Queries for different icons table "issues"
|
||||
|
||||
-- Get total count of icons
|
||||
SELECT COUNT(*) FROM icons;
|
||||
|
||||
-- Count the number of icons where the contents contain "%<!DOCTYPE%"
|
||||
-- My environment had a lot of these for some reason; they resulted in "broken" images in the GUI
|
||||
SELECT COUNT(*) FROM icons WHERE contents LIKE "%<!DOCTYPE%";
|
||||
|
||||
-- Get all icons that are assigned to deleted Mobile Device VPP Apps
|
||||
SELECT DISTINCT COUNT(*) FROM icons
|
||||
INNER JOIN mobile_device_apps ON mobile_device_apps.icon_attachment_id = icons.icon_id
|
||||
WHERE mobile_device_apps.deleted IS true;
|
||||
|
||||
-- Count the number of unused icon_id"s
|
||||
SELECT COUNT(*) FROM icons WHERE icons.icon_id NOT IN (
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM ibooks
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mobile_device_apps
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mobile_device_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mac_apps
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM os_x_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM self_service_plugins
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM vpp_mobile_device_app_license_app
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM vpp_assets
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM os_x_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM patch_policies
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM policies
|
||||
UNION ALL
|
||||
SELECT profile_id AS id
|
||||
FROM mobile_device_management_commands
|
||||
WHERE command="Wallpaper"
|
||||
UNION ALL
|
||||
SELECT deprecated_branding_icon_id AS id
|
||||
FROM self_service
|
||||
UNION ALL
|
||||
SELECT deprecated_branding_image_id AS id
|
||||
FROM self_service
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM ss_ios_branding_settings
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM ss_macos_branding_settings
|
||||
);
|
||||
|
||||
-- Count the number of unused icon_id's that are from VPP Apps
|
||||
SELECT COUNT(*) FROM icons WHERE icons.icon_id NOT IN (
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM ibooks
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mobile_device_apps
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mobile_device_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mac_apps
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM os_x_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM self_service_plugins
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM vpp_mobile_device_app_license_app
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM vpp_assets
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM os_x_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM patch_policies
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM policies
|
||||
UNION ALL
|
||||
SELECT profile_id AS id
|
||||
FROM mobile_device_management_commands
|
||||
WHERE command="Wallpaper"
|
||||
UNION ALL
|
||||
SELECT deprecated_branding_icon_id AS id
|
||||
FROM self_service
|
||||
UNION ALL
|
||||
SELECT deprecated_branding_image_id AS id
|
||||
FROM self_service
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM ss_ios_branding_settings
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM ss_macos_branding_settings
|
||||
)
|
||||
AND ( icons.filename REGEXP "^([0-9]+x[0-9]+bb|[0-9]+)[.](png|jpg)$");
|
||||
|
||||
-- Above regex matches or could be substituded with:
|
||||
-- AND ( filename IN ( 100x100bb.jpg, 100x100bb.png, 1024x1024bb.png, 512x512bb.png ) OR filename REGEXP "^[0-9]+.(png|jpg)$");
|
||||
|
||||
-- ####################################################################################################
|
||||
-- Creating back ups of the icon tables and similar actions
|
||||
|
||||
-- Create a backup of the icon table
|
||||
CREATE TABLE icons_backup LIKE icons;
|
||||
INSERT icons_backup SELECT * FROM icons;
|
||||
|
||||
-- Drop the backup table
|
||||
DROP TABLE icons_backup;
|
||||
|
||||
-- Create table of icons that are in use, but not including -1 and 0 IDs
|
||||
CREATE TABLE icons_ids_inuse (
|
||||
icon_Id int(11)
|
||||
);
|
||||
|
||||
INSERT INTO icons_ids_inuse SELECT id FROM icons WHERE icons.icon_id IN
|
||||
(
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM ibooks
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mobile_device_apps
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mobile_device_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mac_apps
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM os_x_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM self_service_plugins
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM vpp_mobile_device_app_license_app
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM vpp_assets
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM os_x_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM patch_policies
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM policies
|
||||
UNION ALL
|
||||
SELECT profile_id AS id
|
||||
FROM mobile_device_management_commands
|
||||
WHERE command="Wallpaper"
|
||||
UNION ALL
|
||||
SELECT deprecated_branding_icon_id AS id
|
||||
FROM self_service
|
||||
UNION ALL
|
||||
SELECT deprecated_branding_image_id AS id
|
||||
FROM self_service
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM ss_ios_branding_settings
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM ss_macos_branding_settings
|
||||
)
|
||||
AND id != -1 AND id != 0;
|
||||
|
||||
-- Create a table with all icon_id and content for all icons in use
|
||||
CREATE TABLE icons_inuse (
|
||||
icon_Id int(11),
|
||||
contents longblob
|
||||
);
|
||||
|
||||
INSERT INTO icons_inuse
|
||||
SELECT DISTINCT icons.icon_id, contents FROM icons
|
||||
INNER JOIN icons_ids_inuse ON icons_ids_inuse.icon_id = icons.icon_id;
|
||||
|
||||
-- Create a table with all icon_id and content that are not being used
|
||||
CREATE TABLE icons_notinuse (
|
||||
icon_Id int(11),
|
||||
contents longblob
|
||||
);
|
||||
|
||||
-- Insert into icons_notinuse
|
||||
SELECT DISTINCT icons.icon_id, icons.contents FROM icons
|
||||
WHERE icons.icon_id NOT IN (
|
||||
SELECT icon_id FROM icons_inuse
|
||||
);
|
||||
|
||||
-- ####################################################################################################
|
||||
-- Deleting icons, via specific ids, patterns, contents, etc
|
||||
|
||||
-- Delete icons by icon_id
|
||||
DELETE FROM icons WHERE icon_id IN (
|
||||
2, 16, 17, 18, 21, 80, 81, 87, 88
|
||||
);
|
||||
|
||||
-- Get or delete icons between ID numbers
|
||||
[ SELECT * | DELETE ] FROM icons WHERE (
|
||||
icon_id BETWEEN 110 AND 293
|
||||
OR icon_id BETWEEN 2281 AND 2284
|
||||
OR icon_id BETWEEN 2314 AND 2501
|
||||
OR icon_id BETWEEN 2505 AND 2579
|
||||
OR icon_id BETWEEN 3385 AND 4186
|
||||
OR icon_id BETWEEN 6776 AND 13500 );
|
||||
|
||||
-- Delete the icons where the contents contain "%<!DOCTYPE%"
|
||||
DELETE FROM icons WHERE contents LIKE "%<!DOCTYPE%";
|
||||
|
||||
-- Get or delete all icons that are assigned to deleted Mobile Device VPP Apps
|
||||
DELETE icons FROM icons
|
||||
INNER JOIN mobile_device_apps ON mobile_device_apps.icon_attachment_id = icons.icon_id
|
||||
WHERE mobile_device_apps.deleted IS true;
|
||||
|
||||
-- Delete icons that are not in use, but not specific IDs
|
||||
DELETE icons_backup FROM icons_backup
|
||||
WHERE icons_backup.icon_id NOT IN (
|
||||
SELECT icon_id FROM icon_ids_inuse
|
||||
)
|
||||
AND
|
||||
icons_backup.icon_id NOT IN (
|
||||
6, 14, 41, 89, 108, 484, 2286, 2580, 19513, 19514, 49370, 56529, 57582
|
||||
);
|
||||
|
||||
-- Delete VPP App Icons not in use
|
||||
DELETE icons_backup FROM icons_backup WHERE icons_backup.icon_id NOT IN (
|
||||
SELECT icon_id FROM icon_ids_inuse
|
||||
)
|
||||
AND
|
||||
icons_backup.filename IN (
|
||||
"100x100bb.jpg", "100x100bb.png", "1024x1024bb.png", "512x512bb.png"
|
||||
);
|
||||
|
||||
-- Delete unused icons' that are from VPP Apps
|
||||
DELETE FROM icons WHERE icons.icon_id NOT IN (
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM ibooks
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mobile_device_apps
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mobile_device_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mac_apps
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM os_x_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM self_service_plugins
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM vpp_mobile_device_app_license_app
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM vpp_assets
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM os_x_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM patch_policies
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM policies
|
||||
UNION ALL
|
||||
SELECT profile_id AS id
|
||||
FROM mobile_device_management_commands
|
||||
WHERE command="Wallpaper"
|
||||
UNION ALL
|
||||
SELECT deprecated_branding_icon_id AS id
|
||||
FROM self_service
|
||||
UNION ALL
|
||||
SELECT deprecated_branding_image_id AS id
|
||||
FROM self_service
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM ss_ios_branding_settings
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM ss_macos_branding_settings
|
||||
)
|
||||
AND ( icons.filename REGEXP "^([0-9]+x[0-9]+bb|[0-9]+)[.](png|jpg)$");
|
||||
|
||||
@@ -0,0 +1,322 @@
|
||||
-- #############################
|
||||
-- # Clean up icons in the JSS #
|
||||
-- #############################
|
||||
|
||||
-- These are notes on performing maintenance on the icons table within the Jamf Pro database.
|
||||
-- Several of the below actions have been incorporated within my jamf_db_maint.sh script.
|
||||
|
||||
-- Resources:
|
||||
-- jaycohen @ https://www.jamf.com/jamf-nation/feature-requests/1474/manage-self-service-policy-icons
|
||||
-- Sample queries originally provided by Jamf Support and have been modified as needed
|
||||
|
||||
-- ####################################################################################################
|
||||
-- Queries for different icons table "issues"
|
||||
|
||||
-- Get total count of icons
|
||||
SELECT COUNT(*) FROM icons;
|
||||
|
||||
-- Count the number of icons where the contents contain "%<!DOCTYPE%"
|
||||
-- My environment had a lot of these for some reason; they resulted in "broken" images in the GUI
|
||||
SELECT COUNT(*) FROM icons WHERE contents LIKE "%<!DOCTYPE%";
|
||||
|
||||
-- Get all icons that are assigned to deleted Mobile Device VPP Apps
|
||||
SELECT DISTINCT COUNT(*) FROM icons
|
||||
INNER JOIN mobile_device_apps ON mobile_device_apps.icon_attachment_id = icons.icon_id
|
||||
WHERE mobile_device_apps.deleted IS true;
|
||||
|
||||
-- Count the number of unused icon_id"s
|
||||
SELECT COUNT(*) FROM icons WHERE icons.icon_id NOT IN (
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM ibooks
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mobile_device_apps
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mobile_device_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mac_apps
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM os_x_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM self_service_plugins
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM vpp_mobile_device_app_license_app
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM vpp_assets
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM os_x_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM patch_policies
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM policies
|
||||
UNION ALL
|
||||
SELECT profile_id AS id
|
||||
FROM mobile_device_management_commands
|
||||
WHERE command="Wallpaper"
|
||||
UNION ALL
|
||||
SELECT deprecated_branding_icon_id AS id
|
||||
FROM self_service
|
||||
UNION ALL
|
||||
SELECT deprecated_branding_image_id AS id
|
||||
FROM self_service
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM ss_ios_branding_settings
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM ss_macos_branding_settings
|
||||
);
|
||||
|
||||
-- Count the number of unused icon_id's that are from VPP Apps
|
||||
SELECT COUNT(*) FROM icons WHERE icons.icon_id NOT IN (
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM ibooks
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mobile_device_apps
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mobile_device_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mac_apps
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM os_x_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM self_service_plugins
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM vpp_mobile_device_app_license_app
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM vpp_assets
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM os_x_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM patch_policies
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM policies
|
||||
UNION ALL
|
||||
SELECT profile_id AS id
|
||||
FROM mobile_device_management_commands
|
||||
WHERE command="Wallpaper"
|
||||
UNION ALL
|
||||
SELECT deprecated_branding_icon_id AS id
|
||||
FROM self_service
|
||||
UNION ALL
|
||||
SELECT deprecated_branding_image_id AS id
|
||||
FROM self_service
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM ss_ios_branding_settings
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM ss_macos_branding_settings
|
||||
)
|
||||
AND ( icons.filename REGEXP "^([0-9]+x[0-9]+bb|[0-9]+)[.](png|jpg)$");
|
||||
|
||||
-- Above regex matches or could be substituded with:
|
||||
-- AND ( filename IN ( 100x100bb.jpg, 100x100bb.png, 1024x1024bb.png, 512x512bb.png ) OR filename REGEXP "^[0-9]+.(png|jpg)$");
|
||||
|
||||
-- ####################################################################################################
|
||||
-- Creating back ups of the icon tables and similar actions
|
||||
|
||||
-- Create a backup of the icon table
|
||||
CREATE TABLE icons_backup LIKE icons;
|
||||
INSERT icons_backup SELECT * FROM icons;
|
||||
|
||||
-- Drop the backup table
|
||||
DROP TABLE icons_backup;
|
||||
|
||||
-- Create table of icons that are in use, but not including -1 and 0 IDs
|
||||
CREATE TABLE icons_ids_inuse (
|
||||
icon_Id int(11)
|
||||
);
|
||||
|
||||
INSERT INTO icons_ids_inuse SELECT id FROM icons WHERE icons.icon_id IN
|
||||
(
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM ibooks
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mobile_device_apps
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mobile_device_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mac_apps
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM os_x_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM self_service_plugins
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM vpp_mobile_device_app_license_app
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM vpp_assets
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM os_x_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM patch_policies
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM policies
|
||||
UNION ALL
|
||||
SELECT profile_id AS id
|
||||
FROM mobile_device_management_commands
|
||||
WHERE command="Wallpaper"
|
||||
UNION ALL
|
||||
SELECT deprecated_branding_icon_id AS id
|
||||
FROM self_service
|
||||
UNION ALL
|
||||
SELECT deprecated_branding_image_id AS id
|
||||
FROM self_service
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM ss_ios_branding_settings
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM ss_macos_branding_settings
|
||||
)
|
||||
AND id != -1 AND id != 0;
|
||||
|
||||
-- Create a table with all icon_id and content for all icons in use
|
||||
CREATE TABLE icons_inuse (
|
||||
icon_Id int(11),
|
||||
contents longblob
|
||||
);
|
||||
|
||||
INSERT INTO icons_inuse
|
||||
SELECT DISTINCT icons.icon_id, contents FROM icons
|
||||
INNER JOIN icons_ids_inuse ON icons_ids_inuse.icon_id = icons.icon_id;
|
||||
|
||||
-- Create a table with all icon_id and content that are not being used
|
||||
CREATE TABLE icons_notinuse (
|
||||
icon_Id int(11),
|
||||
contents longblob
|
||||
);
|
||||
|
||||
-- Insert into icons_notinuse
|
||||
SELECT DISTINCT icons.icon_id, icons.contents FROM icons
|
||||
WHERE icons.icon_id NOT IN (
|
||||
SELECT icon_id FROM icons_inuse
|
||||
);
|
||||
|
||||
-- ####################################################################################################
|
||||
-- Deleting icons, via specific ids, patterns, contents, etc
|
||||
|
||||
-- Delete icons by icon_id
|
||||
DELETE FROM icons WHERE icon_id IN (
|
||||
2, 16, 17, 18, 21, 80, 81, 87, 88
|
||||
);
|
||||
|
||||
-- Get or delete icons between ID numbers
|
||||
[ SELECT * | DELETE ] FROM icons WHERE (
|
||||
icon_id BETWEEN 110 AND 293
|
||||
OR icon_id BETWEEN 2281 AND 2284
|
||||
OR icon_id BETWEEN 2314 AND 2501
|
||||
OR icon_id BETWEEN 2505 AND 2579
|
||||
OR icon_id BETWEEN 3385 AND 4186
|
||||
OR icon_id BETWEEN 6776 AND 13500 );
|
||||
|
||||
-- Delete the icons where the contents contain "%<!DOCTYPE%"
|
||||
DELETE FROM icons WHERE contents LIKE "%<!DOCTYPE%";
|
||||
|
||||
-- Get or delete all icons that are assigned to deleted Mobile Device VPP Apps
|
||||
DELETE icons FROM icons
|
||||
INNER JOIN mobile_device_apps ON mobile_device_apps.icon_attachment_id = icons.icon_id
|
||||
WHERE mobile_device_apps.deleted IS true;
|
||||
|
||||
-- Delete icons that are not in use, but not specific IDs
|
||||
DELETE icons_backup
|
||||
FROM icons_backup
|
||||
WHERE icons_backup.icon_id NOT IN (
|
||||
SELECT icon_id FROM icon_ids_inuse
|
||||
)
|
||||
AND icons_backup.icon_id NOT IN (
|
||||
6, 14, 41, 89, 108, 484, 2286, 2580, 19513, 19514, 49370, 56529, 57582
|
||||
);
|
||||
|
||||
-- Delete VPP App Icons not in use
|
||||
DELETE icons_backup
|
||||
FROM icons_backup
|
||||
WHERE icons_backup.icon_id NOT IN (
|
||||
SELECT icon_id FROM icon_ids_inuse
|
||||
)
|
||||
AND icons_backup.filename IN (
|
||||
"100x100bb.jpg", "100x100bb.png", "1024x1024bb.png", "512x512bb.png"
|
||||
);
|
||||
|
||||
-- Delete unused icons' that are from VPP Apps
|
||||
DELETE FROM icons WHERE icons.icon_id NOT IN (
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM ibooks
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mobile_device_apps
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mobile_device_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM mac_apps
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM os_x_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT icon_attachment_id AS id
|
||||
FROM self_service_plugins
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM vpp_mobile_device_app_license_app
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM vpp_assets
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM os_x_configuration_profiles
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM patch_policies
|
||||
UNION ALL
|
||||
SELECT self_service_icon_id AS id
|
||||
FROM policies
|
||||
UNION ALL
|
||||
SELECT profile_id AS id
|
||||
FROM mobile_device_management_commands
|
||||
WHERE command="Wallpaper"
|
||||
UNION ALL
|
||||
SELECT deprecated_branding_icon_id AS id
|
||||
FROM self_service
|
||||
UNION ALL
|
||||
SELECT deprecated_branding_image_id AS id
|
||||
FROM self_service
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM ss_ios_branding_settings
|
||||
UNION ALL
|
||||
SELECT icon_id AS id
|
||||
FROM ss_macos_branding_settings
|
||||
)
|
||||
AND ( icons.filename REGEXP "^([0-9]+x[0-9]+bb|[0-9]+)[.](png|jpg)$");
|
||||
|
||||
@@ -2,9 +2,9 @@
|
||||
-- # Clean up Location History #
|
||||
-- #############################
|
||||
|
||||
-- NOTE: These really aren't required any more since Jamf added these tables to the automtaic
|
||||
-- NOTE: These really aren't required any more since Jamf added these tables to the automtaic
|
||||
-- Flush Policy -- which I disagree with.
|
||||
-- (But you can disable that and then these my still be useful to you.)
|
||||
-- (But you can disable that and then these may still be useful to you.)
|
||||
|
||||
-- These are notes on performing maintenance on the locations and location_history tables within the Jamf Pro database.
|
||||
-- The actions in option one were incorporated within my jamf_db_maint.sh script.
|
||||
@@ -28,27 +28,27 @@ INSERT locations_backup SELECT * FROM locations;
|
||||
|
||||
-- Create a table with the empty location records
|
||||
CREATE TABLE empty_location_records (
|
||||
SELECT locations.location_id FROM locations WHERE (
|
||||
locations.username = ""
|
||||
AND locations.realname = ""
|
||||
AND locations.room = ""
|
||||
AND locations.phone = ""
|
||||
AND locations.email = ""
|
||||
AND locations.position = ""
|
||||
AND locations.location_id NOT IN (
|
||||
SELECT location_id FROM locations
|
||||
INNER JOIN computers_denormalized ON computers_denormalized.last_location_id = locations.location_id
|
||||
)
|
||||
)
|
||||
SELECT locations.location_id FROM locations WHERE (
|
||||
locations.username = ""
|
||||
AND locations.realname = ""
|
||||
AND locations.room = ""
|
||||
AND locations.phone = ""
|
||||
AND locations.email = ""
|
||||
AND locations.position = ""
|
||||
AND locations.location_id NOT IN (
|
||||
SELECT location_id FROM locations
|
||||
INNER JOIN computers_denormalized ON computers_denormalized.last_location_id = locations.location_id
|
||||
)
|
||||
)
|
||||
);
|
||||
|
||||
-- Delete empty location records
|
||||
DELETE locations_backup FROM locations_backup WHERE location_id IN (
|
||||
SELECT location_id FROM empty_location_records
|
||||
);
|
||||
DELETE location_history_backup FROM location_history_backup WHERE location_id IN (
|
||||
SELECT location_id FROM empty_location_records
|
||||
);
|
||||
DELETE locations_backup FROM locations_backup WHERE location_id IN (
|
||||
SELECT location_id FROM empty_location_records
|
||||
);
|
||||
DELETE location_history_backup FROM location_history_backup WHERE location_id IN (
|
||||
SELECT location_id FROM empty_location_records
|
||||
);
|
||||
|
||||
-- Start Tomcat on master JPS that is admin facing and verify everything looks good with the modifications performed.
|
||||
|
||||
@@ -70,16 +70,16 @@ DROP TABLE empty_location_records;
|
||||
CREATE TABLE location_history_new LIKE location_history;
|
||||
|
||||
INSERT INTO location_history_new (
|
||||
SELECT * FROM location_history
|
||||
WHERE computer_id = 0
|
||||
);
|
||||
SELECT * FROM location_history
|
||||
WHERE computer_id = 0
|
||||
);
|
||||
|
||||
INSERT INTO location_history_new (
|
||||
SELECT * FROM location_history
|
||||
WHERE location_id IN (
|
||||
SELECT last_location_id FROM computers_denormalized
|
||||
)
|
||||
);
|
||||
SELECT * FROM location_history
|
||||
WHERE location_id IN (
|
||||
SELECT last_location_id FROM computers_denormalized
|
||||
)
|
||||
);
|
||||
|
||||
RENAME TABLE location_history TO location_history_old;
|
||||
|
||||
@@ -92,18 +92,18 @@ DROP TABLE location_history_old;
|
||||
CREATE TABLE locations_new LIKE locations;
|
||||
|
||||
INSERT INTO locations_new (
|
||||
SELECT * FROM locations
|
||||
WHERE location_id IN (
|
||||
SELECT last_location_id FROM computers_denormalized
|
||||
)
|
||||
);
|
||||
SELECT * FROM locations
|
||||
WHERE location_id IN (
|
||||
SELECT last_location_id FROM computers_denormalized
|
||||
)
|
||||
);
|
||||
|
||||
INSERT INTO locations_new (
|
||||
SELECT * FROM locations
|
||||
WHERE location_id IN (
|
||||
SELECT last_location_id FROM mobile_devices_denormalized
|
||||
)
|
||||
);
|
||||
SELECT * FROM locations
|
||||
WHERE location_id IN (
|
||||
SELECT last_location_id FROM mobile_devices_denormalized
|
||||
)
|
||||
);
|
||||
|
||||
RENAME TABLE locations TO locations_old;
|
||||
|
||||
@@ -1,5 +1,4 @@
|
||||
-- Queries on APNS/MDM Commands
|
||||
-- Most of these should be working, but some may still be a work in progress.
|
||||
-- These are formatted for readability, just fyi.
|
||||
|
||||
-- ##################################################
|
||||
@@ -7,25 +6,30 @@
|
||||
-- # Install application commands loop
|
||||
SELECT device_id, device_object_id, profile_id, command, COUNT(*)
|
||||
FROM mobile_device_management_commands
|
||||
WHERE
|
||||
command="InstallApplication" AND
|
||||
date_completed_epoch>unix_timestamp(date_sub(NOW(), interval 24 hour))*1000
|
||||
GROUP BY device_id,device_object_id,profile_id,command
|
||||
WHERE
|
||||
command="InstallApplication" AND
|
||||
date_completed_epoch > unix_timestamp(date_sub(NOW(), interval 24 hour))*1000
|
||||
GROUP BY device_id, device_object_id, profile_id, command
|
||||
ORDER BY 5 DESC LIMIT 50;
|
||||
|
||||
|
||||
-- # Pending Commands
|
||||
SELECT COUNT(*), command
|
||||
FROM mobile_device_management_commands
|
||||
WHERE apns_result_status=""
|
||||
GROUP BY command
|
||||
GROUP BY command
|
||||
HAVING COUNT(*) > 99
|
||||
ORDER BY COUNT(*) DESC;
|
||||
ORDER BY COUNT(*)
|
||||
DESC;
|
||||
|
||||
|
||||
-- # Completed Commands; verify that counts are dropping
|
||||
SELECT device_id, command, device_object_id, COUNT(*)
|
||||
FROM mobile_device_management_commands
|
||||
WHERE date_completed_epoch>unix_timestamp(date_sub(NOW(), interval 24 hour))*1000
|
||||
GROUP BY device_id,command, device_object_id ORDER BY COUNT(*) DESC LIMIT 100;
|
||||
WHERE date_completed_epoch > unix_timestamp(date_sub(NOW(), interval 24 hour))*1000
|
||||
GROUP BY device_id,command, device_object_id
|
||||
ORDER BY COUNT(*)
|
||||
DESC LIMIT 100;
|
||||
|
||||
|
||||
-- ##################################################
|
||||
@@ -44,39 +48,39 @@ CREATE TABLE mobile_device_management_commands LIKE mobile_device_management_com
|
||||
INSERT INTO mobile_device_management_commands
|
||||
SELECT * FROM mobile_device_management_commands_original
|
||||
WHERE command NOT IN (
|
||||
"RemoveProfile", "ProfileList", "InstalledApplicationList", "CertificateList",
|
||||
"DeviceInformation", "SecurityInfo", "UpdateInventory", "ContentCachingInformation",
|
||||
"RemoveApplication", "UserList"
|
||||
"RemoveProfile", "ProfileList", "InstalledApplicationList", "CertificateList",
|
||||
"DeviceInformation", "SecurityInfo", "UpdateInventory", "ContentCachingInformation",
|
||||
"RemoveApplication", "UserList"
|
||||
);
|
||||
|
||||
-- Jamf Pro Product Issue: (Couldn't find the PI at the moment)
|
||||
-- When a machine is re-enrolled, it gets a new push token and all of the remote commands
|
||||
-- When a machine is re-enrolled, it gets a new push token and all of the remote commands
|
||||
-- associated with the old push token are supposed to be cleared out.
|
||||
-- However, the this doesn't happen which is what the PI is for and the below command will clear out.
|
||||
-- ***PLEASE NOTE*** Workarounds that remove objects from the mobile_device_management_commands
|
||||
-- table will leave orphan records in the mdm_command_source and mdm_command_group tables.
|
||||
-- ***PLEASE NOTE*** Workarounds that remove objects from the mobile_device_management_commands
|
||||
-- table will leave orphan records in the mdm_command_source and mdm_command_group tables.
|
||||
-- If you are running this workaround, the workaround for PI-009639 must be run promptly after.
|
||||
|
||||
-- Get orphaned remote commands
|
||||
SELECT COUNT(*)
|
||||
FROM mobile_device_management_commands
|
||||
WHERE
|
||||
apns_result_status="" AND
|
||||
device_object_id=12 AND
|
||||
device_id NOT IN (
|
||||
SELECT computer_user_pushtoken_id
|
||||
FROM computer_user_pushtokens
|
||||
);
|
||||
WHERE
|
||||
apns_result_status="" AND
|
||||
device_object_id=12 AND
|
||||
device_id NOT IN (
|
||||
SELECT computer_user_pushtoken_id
|
||||
FROM computer_user_pushtokens
|
||||
);
|
||||
|
||||
-- Clean up additional records
|
||||
DELETE FROM mobile_device_management_commands
|
||||
DELETE FROM mobile_device_management_commands
|
||||
WHERE
|
||||
apns_result_status="" AND
|
||||
device_object_id=12 AND
|
||||
device_id NOT IN (
|
||||
SELECT computer_user_pushtoken_id
|
||||
FROM computer_user_pushtokens
|
||||
);
|
||||
apns_result_status="" AND
|
||||
device_object_id=12 AND
|
||||
device_id NOT IN (
|
||||
SELECT computer_user_pushtoken_id
|
||||
FROM computer_user_pushtokens
|
||||
);
|
||||
|
||||
|
||||
-- ##################################################
|
||||
@@ -96,19 +100,19 @@ CREATE TABLE mdm_command_source LIKE mdm_command_source_original;
|
||||
CREATE TABLE mdm_command_group LIKE mdm_command_group_original;
|
||||
|
||||
-- Inserting desired records into new table
|
||||
INSERT INTO mdm_command_source (
|
||||
SELECT * FROM mdm_command_source_original
|
||||
WHERE mdm_command_id IN (
|
||||
SELECT mobile_device_management_command_id FROM mobile_device_management_commands
|
||||
)
|
||||
INSERT INTO mdm_command_source (
|
||||
SELECT * FROM mdm_command_source_original
|
||||
WHERE mdm_command_id IN (
|
||||
SELECT mobile_device_management_command_id FROM mobile_device_management_commands
|
||||
)
|
||||
);
|
||||
|
||||
-- Inserting desired records into new table
|
||||
INSERT INTO mdm_command_group (
|
||||
SELECT * FROM mdm_command_group_original
|
||||
WHERE id IN (
|
||||
SELECT id FROM mdm_command_source
|
||||
)
|
||||
INSERT INTO mdm_command_group (
|
||||
SELECT * FROM mdm_command_group_original
|
||||
WHERE id IN (
|
||||
SELECT id FROM mdm_command_source
|
||||
)
|
||||
);
|
||||
|
||||
|
||||
@@ -119,7 +123,7 @@ INSERT INTO mdm_command_group (
|
||||
SELECT COUNT(*) FROM computer_user_pushtokens;
|
||||
|
||||
-- Get number of records to delete
|
||||
SELECT COUNT(*) FROM computer_user_pushtokens
|
||||
SELECT COUNT(*) FROM computer_user_pushtokens
|
||||
WHERE user_short_name LIKE "uid_%";
|
||||
|
||||
-- Rename the original table
|
||||
@@ -129,6 +133,6 @@ RENAME TABLE computer_user_pushtokens TO computer_user_pushtokens_original;
|
||||
CREATE TABLE computer_user_pushtokens LIKE computer_user_pushtokens_original;
|
||||
|
||||
-- Insert the records from the original table
|
||||
INSERT INTO computer_user_pushtokens
|
||||
SELECT * FROM computer_user_pushtokens_original
|
||||
INSERT INTO computer_user_pushtokens
|
||||
SELECT * FROM computer_user_pushtokens_original
|
||||
WHERE user_short_name NOT LIKE "uid_%";
|
||||
@@ -0,0 +1,169 @@
|
||||
-- Queries on Miscellaneous Configurations
|
||||
-- Most of these should be working, but some may still be a work in progress.
|
||||
-- These are formatted for readability, just fyi.
|
||||
|
||||
-- ##################################################
|
||||
-- Computer Inventory Submissions
|
||||
|
||||
-- Count the number inventory submissions per day per computer
|
||||
SELECT
|
||||
DATE(date_sub(from_unixtime(reports.date_entered_epoch/1000), INTERVAL 1 DAY)) AS "Date",
|
||||
computer_id AS "Computer ID",
|
||||
COUNT(*) AS "Inventory Reports"
|
||||
FROM reports
|
||||
WHERE
|
||||
reports.date_entered_epoch > unix_timestamp(date_sub(now(), INTERVAL 1 DAY))*1000
|
||||
AND computer_id != 0
|
||||
GROUP BY DATE(date_sub(from_unixtime(reports.date_entered_epoch/1000), INTERVAL 1 DAY)), computer_id
|
||||
ORDER BY COUNT(*) DESC
|
||||
|
||||
|
||||
-- Count the number of inventory submissions per day
|
||||
DATE(date_sub(from_unixtime(reports.date_entered_epoch/1000), INTERVAL 1 DAY)) AS "Date",
|
||||
COUNT(*) AS "Inventory Reports"
|
||||
FROM reports
|
||||
WHERE computer_id != 0
|
||||
GROUP BY DATE(date_sub(from_unixtime(reports.date_entered_epoch/1000), INTERVAL 1 DAY))
|
||||
ORDER BY DATE(date_sub(from_unixtime(reports.date_entered_epoch/1000), INTERVAL 1 DAY)) DESC
|
||||
|
||||
|
||||
-- Count the number of inventory submissions per day in the last 7 days
|
||||
SELECT
|
||||
DATE(date_sub(from_unixtime(reports.date_entered_epoch/1000), INTERVAL 1 DAY)) AS "Date",
|
||||
COUNT(*) AS "Inventory Reports"
|
||||
FROM reports
|
||||
WHERE
|
||||
reports.date_entered_epoch > unix_timestamp(date_sub(now(), INTERVAL 7 DAY))*1000
|
||||
AND computer_id != 0
|
||||
GROUP BY DATE(date_sub(from_unixtime(reports.date_entered_epoch/1000), INTERVAL 1 DAY))
|
||||
ORDER BY DATE(date_sub(from_unixtime(reports.date_entered_epoch/1000), INTERVAL 1 DAY)) DESC
|
||||
|
||||
|
||||
-- ##################################################
|
||||
-- Queries for App Store Apps
|
||||
|
||||
-- Mac Apps with No Scope
|
||||
SELECT DISTINCT
|
||||
IF(sites.site_name IS NULL, "none", sites.site_name) AS "Site",
|
||||
mac_apps.mac_app_id AS "ID",
|
||||
mac_apps.app_name AS "Name"
|
||||
FROM mac_apps
|
||||
LEFT JOIN site_objects
|
||||
ON mac_apps.mac_app_id = site_objects.object_id
|
||||
AND site_objects.object_type = "350"
|
||||
LEFT JOIN sites
|
||||
ON sites.site_id = site_objects.site_id
|
||||
WHERE mac_apps.mac_app_id NOT IN (
|
||||
SELECT mac_app_id FROM mac_app_deployment
|
||||
)
|
||||
AND mac_apps.deleted = 0;
|
||||
|
||||
|
||||
-- Mac Apps not using VPP Devices Based Licenses
|
||||
SELECT DISTINCT
|
||||
IF(sites.site_name IS NULL, "none", sites.site_name) AS "Site",
|
||||
mac_apps.mac_app_id AS "ID",
|
||||
mac_apps.app_name AS "Name"
|
||||
FROM mac_apps
|
||||
LEFT JOIN site_objects
|
||||
ON mac_apps.mac_app_id = site_objects.object_id
|
||||
AND site_objects.object_type = "350"
|
||||
LEFT JOIN sites
|
||||
ON sites.site_id = site_objects.site_id
|
||||
WHERE mac_apps.assign_vpp_device_based_licenses = 0
|
||||
AND mac_apps.deleted = 0;
|
||||
|
||||
|
||||
-- Mobile Device Apps with No Scope
|
||||
SELECT DISTINCT
|
||||
IF(sites.site_name IS NULL, "none", sites.site_name) AS "Site",
|
||||
mobile_device_apps.mobile_device_app_id AS "ID",
|
||||
mobile_device_apps.app_name AS "Name"
|
||||
FROM mobile_device_apps
|
||||
LEFT JOIN site_objects
|
||||
ON mobile_device_apps.mobile_device_app_id = site_objects.object_id
|
||||
AND site_objects.object_type = "23"
|
||||
LEFT JOIN sites
|
||||
ON sites.site_id = site_objects.site_id
|
||||
WHERE mobile_device_apps.mobile_device_app_id NOT IN (
|
||||
SELECT mobile_device_app_id FROM mobile_device_app_deployment
|
||||
)
|
||||
AND mobile_device_apps.deleted = 0;
|
||||
|
||||
|
||||
-- Mobile Device Apps not using VPP Devices Based Licenses
|
||||
SELECT DISTINCT
|
||||
IF(sites.site_name IS NULL, "none", sites.site_name) AS "Site",
|
||||
mobile_device_apps.mobile_device_app_id AS "ID",
|
||||
mobile_device_apps.app_name AS "Name"
|
||||
FROM mobile_device_apps
|
||||
LEFT JOIN site_objects
|
||||
ON mobile_device_apps.mobile_device_app_id = site_objects.object_id
|
||||
AND site_objects.object_type = "23"
|
||||
LEFT JOIN sites
|
||||
ON sites.site_id = site_objects.site_id
|
||||
WHERE mobile_device_apps.assign_vpp_device_based_licenses = 0
|
||||
AND mobile_device_apps.deleted = 0;
|
||||
|
||||
|
||||
-- ##################################################
|
||||
-- Queries to check configuration profiles health would likely be useful
|
||||
|
||||
|
||||
|
||||
-- ##################################################
|
||||
-- Clean up orphaned records in the log_actions table
|
||||
|
||||
-- Get total count
|
||||
SELECT COUNT(*) FROM log_actions;
|
||||
|
||||
-- Get number of orphaned records
|
||||
SELECT COUNT(*) FROM log_actions
|
||||
WHERE log_id NOT IN ( SELECT log_id FROM logs );
|
||||
|
||||
-- Rename the original table
|
||||
RENAME TABLE log_actions TO log_actions_original;
|
||||
|
||||
-- Create new table like the old table
|
||||
CREATE TABLE log_actions LIKE log_actions_original;
|
||||
|
||||
-- Select the non-orphaned records from the original table
|
||||
INSERT INTO log_actions
|
||||
SELECT * FROM log_actions_original
|
||||
WHERE log_id IN ( SELECT log_id FROM logs );
|
||||
|
||||
-- Verify no orphaned records
|
||||
SELECT COUNT(*) FROM log_actions
|
||||
WHERE log_id NOT IN ( SELECT log_id FROM logs );
|
||||
|
||||
|
||||
-- ##################################################
|
||||
-- Clean up orphaned records in the mobile_device_extension_attribute_values table
|
||||
|
||||
-- Get total count
|
||||
SELECT COUNT(*) FROM mobile_device_extension_attribute_values;
|
||||
|
||||
-- Get number of orphaned records
|
||||
SELECT COUNT(*) FROM mobile_device_extension_attribute_values
|
||||
WHERE report_id NOT IN (
|
||||
SELECT report_id FROM reports WHERE mobile_device_id > 0 );
|
||||
|
||||
-- Rename the original table
|
||||
RENAME TABLE mobile_device_extension_attribute_values TO mobile_device_extension_attribute_values_original;
|
||||
|
||||
-- Create new table like the old table
|
||||
CREATE TABLE mobile_device_extension_attribute_values LIKE mobile_device_extension_attribute_values_original;
|
||||
|
||||
-- Select the non-orphaned records from the original table
|
||||
INSERT INTO mobile_device_extension_attribute_values
|
||||
SELECT * FROM mobile_device_extension_attribute_values_original
|
||||
WHERE report_id IN (
|
||||
SELECT report_id FROM reports WHERE mobile_device_id > 0 );
|
||||
|
||||
-- Verify no orphaned records
|
||||
SELECT COUNT(*) FROM mobile_device_extension_attribute_values
|
||||
WHERE report_id NOT IN (
|
||||
SELECT report_id FROM reports WHERE mobile_device_id > 0 );
|
||||
|
||||
-- Get new total count
|
||||
SELECT COUNT(*) FROM mobile_device_extension_attribute_values;
|
||||
@@ -1,59 +1,60 @@
|
||||
-- Queries on Policy Configurations
|
||||
-- Most of these should be working, but some may still be a work in progress.
|
||||
-- These are formatted for readability, just fyi.
|
||||
|
||||
-- ##################################################
|
||||
-- Basic Queries
|
||||
|
||||
-- Get Policies that Execute @ Ongoing
|
||||
SELECT policy_id
|
||||
FROM policies
|
||||
WHERE
|
||||
SELECT policy_id
|
||||
FROM policies
|
||||
WHERE
|
||||
execution_frequency LIKE "Ongoing";
|
||||
|
||||
|
||||
-- Policies with no Scope
|
||||
SELECT DISTINCT policies.policy_id, policies.name
|
||||
FROM policies
|
||||
WHERE policies.policy_id NOT IN (
|
||||
SELECT policy_id FROM policy_deployment
|
||||
);
|
||||
FROM policies
|
||||
WHERE policies.policy_id NOT IN (
|
||||
SELECT policy_id FROM policy_deployment
|
||||
);
|
||||
|
||||
|
||||
-- Policies that are Disabled
|
||||
SELECT DISTINCT policies.policy_id, policies.name
|
||||
FROM policies
|
||||
FROM policies
|
||||
WHERE policies.enabled != "1";
|
||||
|
||||
|
||||
-- Policies with no Category and not created by Jamf Remote
|
||||
SELECT DISTINCT policies.policy_id, policies.name, policies.use_for_self_service
|
||||
FROM policies
|
||||
FROM policies
|
||||
WHERE
|
||||
policies.category_id = "-1"
|
||||
policies.category_id = "-1"
|
||||
AND policies.created_by = "jss";
|
||||
|
||||
|
||||
-- Policies Scoped to All Users
|
||||
SELECT DISTINCT policies.policy_id, policies.name
|
||||
FROM policies
|
||||
JOIN policy_deployment
|
||||
JOIN policy_deployment
|
||||
ON policy_deployment.policy_id = policies.policy_id
|
||||
JOIN site_objects
|
||||
JOIN site_objects
|
||||
ON site_objects.object_id = policies.policy_id
|
||||
JOIN sites
|
||||
JOIN sites
|
||||
ON sites.site_id = site_objects.site_id
|
||||
WHERE
|
||||
WHERE
|
||||
policy_deployment.target_type = "106";
|
||||
|
||||
|
||||
-- For every Policy ID, get its Site Name
|
||||
SELECT policies.policy_id, IF(sites.site_name IS NULL, "none", sites.site_name) AS Site
|
||||
SELECT
|
||||
policies.policy_id,
|
||||
IF(sites.site_name IS NULL, "none", sites.site_name) AS "Site"
|
||||
FROM policies
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
AND site_objects.object_type = "3"
|
||||
LEFT JOIN sites
|
||||
LEFT JOIN sites
|
||||
ON sites.site_id = site_objects.site_id;
|
||||
|
||||
|
||||
@@ -61,28 +62,39 @@ LEFT JOIN sites
|
||||
-- Self Service Policies
|
||||
|
||||
-- Get Policies are report if they are set for Self Service and if have a Description and Icon and include it's Site
|
||||
SELECT policies.policy_id AS "Policy ID", policies.name AS "Policy Name", IF(sites.site_name IS NULL, "none", sites.site_name) AS Site, IF(policies.use_for_self_service = "1", "Yes", "No") AS "Self Service", IF(policies.self_service_description = "", "No", "Yes") AS "Has Description", IF(policies.self_service_icon_id = "-1", "No", "Yes") AS "Has Icon",
|
||||
SELECT
|
||||
policies.policy_id AS "Policy ID",
|
||||
policies.name AS "Policy Name",
|
||||
IF(sites.site_name IS NULL, "none", sites.site_name) AS "Site",
|
||||
IF(policies.use_for_self_service = "1", "Yes", "No") AS "Self Service",
|
||||
IF(policies.self_service_description = "", "No", "Yes") AS "Has Description",
|
||||
IF(policies.self_service_icon_id = "-1", "No", "Yes") AS "Has Icon"
|
||||
FROM policies
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
AND site_objects.object_type = "3"
|
||||
LEFT JOIN sites
|
||||
LEFT JOIN sites
|
||||
ON sites.site_id = site_objects.site_id;
|
||||
|
||||
|
||||
-- Get Self Service Policies that install a Package (Also get each Package ID and Name)
|
||||
SELECT policies.policy_id AS "Policy ID", policies.name AS "Policy Name", IF(sites.site_name IS NULL, "none", sites.site_name) AS Site, policy_packages.package_id AS "Package ID" , packages.package_name AS "Package Name"
|
||||
SELECT
|
||||
policies.policy_id AS "Policy ID",
|
||||
policies.name AS "Policy Name",
|
||||
IF(sites.site_name IS NULL, "none", sites.site_name) AS "Site",
|
||||
policy_packages.package_id AS "Package ID",
|
||||
packages.package_name AS "Package Name"
|
||||
FROM policies
|
||||
JOIN policy_packages
|
||||
JOIN policy_packages
|
||||
ON policy_packages.policy_id = policies.policy_id
|
||||
JOIN packages
|
||||
JOIN packages
|
||||
ON policy_packages.package_id = packages.package_id
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
AND site_objects.object_type = "3"
|
||||
LEFT JOIN sites
|
||||
LEFT JOIN sites
|
||||
ON sites.site_id = site_objects.site_id
|
||||
WHERE
|
||||
WHERE
|
||||
policies.use_for_self_service = 1;
|
||||
|
||||
|
||||
@@ -90,53 +102,66 @@ WHERE
|
||||
-- Policies ran over time period
|
||||
|
||||
-- Get Policies that ran within the last 24 hours, get and order by count
|
||||
SELECT policies.policy_id AS "Policy ID", policies.name AS "Policy Name", IF(sites.site_name IS NULL, "none", sites.site_name) AS Site, COUNT(*)
|
||||
SELECT
|
||||
policies.policy_id AS "Policy ID",
|
||||
policies.name AS "Policy Name",
|
||||
IF(sites.site_name IS NULL, "none", sites.site_name) AS "Site",
|
||||
COUNT(*)
|
||||
FROM policies
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
AND site_objects.object_type = "3"
|
||||
LEFT JOIN sites
|
||||
LEFT JOIN sites
|
||||
ON sites.site_id = site_objects.site_id
|
||||
JOIN policy_history
|
||||
JOIN policy_history
|
||||
ON policy_history.policy_id = policies.policy_id
|
||||
WHERE
|
||||
policy_history.completed_epoch>unix_timestamp(date_sub(NOW(), interval 1 day))*1000
|
||||
GROUP BY policy_history.policy_id, sites.site_name
|
||||
policy_history.completed_epoch>unix_timestamp(date_sub(NOW(), interval 1 day))*1000
|
||||
GROUP BY policy_history.policy_id, sites.site_name
|
||||
ORDER BY COUNT(*) DESC;
|
||||
|
||||
|
||||
-- Get Policies that submitted Inventory within the last 24 hours, get and order by count
|
||||
SELECT policies.policy_id AS "Policy ID", policies.name AS "Policy Name", IF(sites.site_name IS NULL, "none", sites.site_name) AS Site, COUNT(*)
|
||||
SELECT
|
||||
policies.policy_id AS "Policy ID",
|
||||
policies.name AS "Policy Name",
|
||||
IF(sites.site_name IS NULL, "none", sites.site_name) AS "Site",
|
||||
COUNT(*)
|
||||
FROM policies
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
AND site_objects.object_type = "3"
|
||||
LEFT JOIN sites
|
||||
LEFT JOIN sites
|
||||
ON sites.site_id = site_objects.site_id
|
||||
JOIN policy_history
|
||||
JOIN policy_history
|
||||
ON policy_history.policy_id = policies.policy_id
|
||||
WHERE
|
||||
policy_history.completed_epoch>unix_timestamp(date_sub(NOW(), interval 1 day))*1000
|
||||
WHERE
|
||||
policy_history.completed_epoch>unix_timestamp(date_sub(NOW(), interval 1 day))*1000
|
||||
AND policies.update_inventory = 1
|
||||
GROUP BY policy_history.policy_id, sites.site_name
|
||||
GROUP BY policy_history.policy_id, sites.site_name
|
||||
ORDER BY COUNT(*) DESC;
|
||||
|
||||
|
||||
-- Get Policies that have ran witin the last 24 hours, if they perform inventory, have errors, and their Site, and group/count the occurences
|
||||
SELECT policies.policy_id AS "Policy ID", policies.name AS "Policy Name", IF(sites.site_name IS NULL, "none", sites.site_name) AS Site, IF(policies.update_inventory = "1", "Yes", "No") AS "Update Inventory?", logs.error AS "Errors", COUNT(*)
|
||||
SELECT
|
||||
policies.policy_id AS "Policy ID",
|
||||
policies.name AS "Policy Name",
|
||||
IF(sites.site_name IS NULL, "none", sites.site_name) AS "Site",
|
||||
IF(policies.update_inventory = "1", "Yes", "No") AS "Update Inventory?",
|
||||
logs.error AS "Errors", COUNT(*)
|
||||
FROM policies
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
AND site_objects.object_type = "3"
|
||||
LEFT JOIN sites
|
||||
LEFT JOIN sites
|
||||
ON sites.site_id = site_objects.site_id
|
||||
JOIN policy_history
|
||||
JOIN policy_history
|
||||
ON policy_history.policy_id = policies.policy_id
|
||||
JOIN logs
|
||||
JOIN logs
|
||||
ON logs.log_id = policy_history.log_id
|
||||
WHERE
|
||||
WHERE
|
||||
policy_history.completed_epoch > unix_timestamp(date_sub(NOW(), INTERVAL 1 DAY))*1000
|
||||
GROUP BY policies.policy_id, sites.site_name, logs.error
|
||||
GROUP BY policies.policy_id, sites.site_name, logs.error
|
||||
ORDER BY COUNT(*) DESC;
|
||||
|
||||
|
||||
@@ -144,18 +169,30 @@ ORDER BY COUNT(*) DESC;
|
||||
-- Mash up of other queries
|
||||
|
||||
-- Get various Policies details of interest, including if they perform inventory, have errors, and their Site, and group/count the occurences
|
||||
SELECT COUNT(*), policies.policy_id AS "Policy ID", policies.name AS "Policy Name", IF(sites.site_name IS NULL, "none", sites.site_name) AS Site, IF(policies.enabled = "1", "Yes", "No") AS "Enabled", IF(policies.update_inventory = "1", "Yes", "No") AS "Update Inventory?", logs.error AS "Errors", IF(policies.use_for_self_service = "1", "Yes", "No") AS "Self Service", IF(policies.self_service_description = "", "No", "Yes") AS "Has Description", IF(policies.self_service_icon_id = "-1", "No", "Yes") AS "Has Icon", IF(policies.category_id = "-1" AND policies.created_by = "jss", "No", "Yes") AS "Has Category", IF( policies.policy_id NOT IN ( SELECT policy_id FROM policy_deployment ), "False", "True") AS "Has Scope"
|
||||
SELECT
|
||||
COUNT(*),
|
||||
policies.policy_id AS "Policy ID",
|
||||
policies.name AS "Policy Name",
|
||||
IF(sites.site_name IS NULL, "none", sites.site_name) AS "Site",
|
||||
IF(policies.enabled = "1", "Yes", "No") AS "Enabled",
|
||||
IF(policies.update_inventory = "1", "Yes", "No") AS "Update Inventory?",
|
||||
logs.error AS "Errors",
|
||||
IF(policies.use_for_self_service = "1", "Yes", "No") AS "Self Service",
|
||||
IF(policies.self_service_description = "", "No", "Yes") AS "Has Description",
|
||||
IF(policies.self_service_icon_id = "-1", "No", "Yes") AS "Has Icon",
|
||||
IF(policies.category_id = "-1" AND policies.created_by = "jss", "No", "Yes") AS "Has Category",
|
||||
IF(policies.policy_id NOT IN ( SELECT policy_id FROM policy_deployment ), "False", "True") AS "Has Scope"
|
||||
FROM policies
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
AND site_objects.object_type = "3"
|
||||
LEFT JOIN sites
|
||||
LEFT JOIN sites
|
||||
ON sites.site_id = site_objects.site_id
|
||||
JOIN policy_history
|
||||
JOIN policy_history
|
||||
ON policy_history.policy_id = policies.policy_id
|
||||
JOIN logs
|
||||
JOIN logs
|
||||
ON logs.log_id = policy_history.log_id
|
||||
GROUP BY policies.policy_id, sites.site_name, logs.error
|
||||
GROUP BY policies.policy_id, sites.site_name, logs.error
|
||||
ORDER BY COUNT(*) DESC
|
||||
|
||||
|
||||
@@ -163,20 +200,25 @@ ORDER BY COUNT(*) DESC
|
||||
-- Policies that are configured for Ongoing with any "reoccuring" trigger and installs a Package
|
||||
|
||||
-- Get Policies that are configured for Ongoing with any "reoccuring" trigger and installs a Package (Also get each Package ID and Name)
|
||||
SELECT DISTINCT policies.policy_id AS "Policy ID", policies.name AS "Policy Name", IF(sites.site_name IS NULL, "none", sites.site_name) AS Site, packages.package_id AS "Package ID" , packages.package_name AS "Package Name"
|
||||
SELECT DISTINCT
|
||||
policies.policy_id AS "Policy ID",
|
||||
policies.name AS "Policy Name",
|
||||
IF(sites.site_name IS NULL, "none", sites.site_name) AS "Site",
|
||||
packages.package_id AS "Package ID" ,
|
||||
packages.package_name AS "Package Name"
|
||||
FROM policies
|
||||
JOIN policy_packages
|
||||
JOIN policy_packages
|
||||
ON policy_packages.policy_id = policies.policy_id
|
||||
JOIN packages
|
||||
JOIN packages
|
||||
ON policy_packages.package_id = packages.package_id
|
||||
JOIN policy_deployment
|
||||
JOIN policy_deployment
|
||||
ON policy_deployment.policy_id = policies.policy_id
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
AND site_objects.object_type = "3"
|
||||
LEFT JOIN sites
|
||||
LEFT JOIN sites
|
||||
ON sites.site_id = site_objects.site_id
|
||||
WHERE
|
||||
WHERE
|
||||
policies.execution_frequency = "Ongoing"
|
||||
AND (
|
||||
policies.trigger_event_startup = "1"
|
||||
@@ -190,24 +232,31 @@ WHERE
|
||||
-- Get Policies that are configured for Ongoing with any "reoccuring" trigger and installs a Package which has a Scope that is not a Smart Group (Also get each Package ID and Name)
|
||||
-- Need to add if scoped to Computer IDs directly
|
||||
-- This query needs verification
|
||||
SELECT DISTINCT policies.policy_id AS "Policy ID", policies.name AS "Policy Name", IF(sites.site_name IS NULL, "none", sites.site_name) AS Site, packages.package_id AS "Package ID" , packages.package_name AS "Package Name", computer_groups.computer_group_id AS "Group ID", computer_groups.computer_group_name AS "Group Name"
|
||||
SELECT DISTINCT
|
||||
policies.policy_id AS "Policy ID",
|
||||
policies.name AS "Policy Name",
|
||||
IF(sites.site_name IS NULL, "none", sites.site_name) AS "Site",
|
||||
packages.package_id AS "Package ID" ,
|
||||
packages.package_name AS "Package Name",
|
||||
computer_groups.computer_group_id AS "Group ID",
|
||||
computer_groups.computer_group_name AS "Group Name"
|
||||
FROM policies
|
||||
JOIN policy_packages
|
||||
JOIN policy_packages
|
||||
ON policy_packages.policy_id = policies.policy_id
|
||||
JOIN packages
|
||||
JOIN packages
|
||||
ON policy_packages.package_id = packages.package_id
|
||||
JOIN policy_deployment
|
||||
JOIN policy_deployment
|
||||
ON policy_deployment.policy_id = policies.policy_id
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
AND site_objects.object_type = "3"
|
||||
LEFT JOIN sites
|
||||
LEFT JOIN sites
|
||||
ON sites.site_id = site_objects.site_id
|
||||
LEFT JOIN computer_groups
|
||||
LEFT JOIN computer_groups
|
||||
ON computer_groups.computer_group_id = policy_deployment.target_id
|
||||
LEFT JOIN smart_computer_group_criteria
|
||||
LEFT JOIN smart_computer_group_criteria
|
||||
ON smart_computer_group_criteria.computer_group_id = computer_groups.computer_group_id
|
||||
WHERE
|
||||
WHERE
|
||||
policies.execution_frequency = "Ongoing"
|
||||
AND (
|
||||
policies.trigger_event_startup = "1"
|
||||
@@ -219,10 +268,10 @@ WHERE
|
||||
AND (
|
||||
policy_deployment.target_type = "101"
|
||||
OR policy_deployment.target_type = "7"
|
||||
AND policy_deployment.target_id IN (
|
||||
SELECT computer_group_id
|
||||
FROM computer_groups
|
||||
WHERE computer_groups.is_smart_group != 1
|
||||
AND policy_deployment.target_id IN (
|
||||
SELECT computer_group_id
|
||||
FROM computer_groups
|
||||
WHERE computer_groups.is_smart_group != 1
|
||||
)
|
||||
);
|
||||
|
||||
@@ -231,8 +280,13 @@ WHERE
|
||||
-- Enrollment Policies that install Packages
|
||||
|
||||
-- Enrollment Policies installing Packages that are Scoped to All Computers
|
||||
SELECT DISTINCT policy_packages.policy_id, policies.name, policy_packages.package_id, packages.package_name, sites.site_name
|
||||
FROM policies
|
||||
SELECT DISTINCT
|
||||
policies.policy_id AS "Policy ID",
|
||||
policies.name AS "Policy Name",
|
||||
IF(sites.site_name IS NULL, "none", sites.site_name) AS "Site",
|
||||
packages.package_id AS "Package ID" ,
|
||||
packages.package_name AS "Package Name",
|
||||
FROM policies
|
||||
JOIN policy_packages ON policy_packages.policy_id = policies.policy_id
|
||||
JOIN packages ON policy_packages.package_id = packages.package_id
|
||||
JOIN policy_deployment ON policy_deployment.policy_id = policies.policy_id
|
||||
@@ -250,64 +304,74 @@ AND (
|
||||
|
||||
|
||||
-- Get Policies that are configured for Enrollment and installs a Package which has a Scope Smart Group that is Not ADE Enrolled Machines
|
||||
SELECT DISTINCT policies.policy_id AS "Policy ID", policies.name AS "Policy Name", IF(sites.site_name IS NULL, "none", sites.site_name) AS Site, computer_groups.computer_group_id AS "Group ID", computer_groups.computer_group_name AS "Group Name"
|
||||
SELECT DISTINCT
|
||||
policies.policy_id AS "Policy ID",
|
||||
policies.name AS "Policy Name",
|
||||
IF(sites.site_name IS NULL, "none", sites.site_name) AS "Site",
|
||||
computer_groups.computer_group_id AS "Group ID",
|
||||
computer_groups.computer_group_name AS "Group Name"
|
||||
FROM policies
|
||||
JOIN policy_deployment
|
||||
JOIN policy_deployment
|
||||
ON policy_deployment.policy_id = policies.policy_id
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
AND site_objects.object_type = "3"
|
||||
LEFT JOIN sites
|
||||
LEFT JOIN sites
|
||||
ON sites.site_id = site_objects.site_id
|
||||
JOIN computer_groups
|
||||
JOIN computer_groups
|
||||
ON computer_groups.computer_group_id = policy_deployment.target_id
|
||||
JOIN smart_computer_group_criteria
|
||||
JOIN smart_computer_group_criteria
|
||||
ON smart_computer_group_criteria.computer_group_id = computer_groups.computer_group_id
|
||||
WHERE
|
||||
WHERE
|
||||
policies.trigger_event_enrollment_complete = "1"
|
||||
AND (
|
||||
policy_deployment.target_type = "7"
|
||||
AND policy_deployment.target_id IN (
|
||||
SELECT computer_group_id
|
||||
FROM computer_groups
|
||||
WHERE computer_groups.is_smart_group = 1
|
||||
AND policy_deployment.target_id IN (
|
||||
SELECT computer_group_id
|
||||
FROM computer_groups
|
||||
WHERE computer_groups.is_smart_group = 1
|
||||
)
|
||||
AND policy_deployment.target_id IN
|
||||
(
|
||||
SELECT computer_group_id
|
||||
FROM smart_computer_group_criteria
|
||||
SELECT computer_group_id
|
||||
FROM smart_computer_group_criteria
|
||||
WHERE search_field != "Enrollment Method: PreStage enrollment"
|
||||
)
|
||||
);
|
||||
|
||||
|
||||
-- Get Policies that are configured for Enrollment and installs a Package which has a Scope Smart Group that is ADE Enrolled Machines
|
||||
SELECT DISTINCT policies.policy_id AS "Policy ID", policies.name AS "Policy Name", IF(sites.site_name IS NULL, "none", sites.site_name) AS Site, computer_groups.computer_group_id AS "Group ID", computer_groups.computer_group_name AS "Group Name"
|
||||
SELECT DISTINCT
|
||||
policies.policy_id AS "Policy ID",
|
||||
policies.name AS "Policy Name",
|
||||
IF(sites.site_name IS NULL, "none", sites.site_name) AS "Site",
|
||||
computer_groups.computer_group_id AS "Group ID",
|
||||
computer_groups.computer_group_name AS "Group Name"
|
||||
FROM policies
|
||||
JOIN policy_deployment
|
||||
JOIN policy_deployment
|
||||
ON policy_deployment.policy_id = policies.policy_id
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
LEFT JOIN site_objects
|
||||
ON policies.policy_id = site_objects.object_id
|
||||
AND site_objects.object_type = "3"
|
||||
LEFT JOIN sites
|
||||
LEFT JOIN sites
|
||||
ON sites.site_id = site_objects.site_id
|
||||
JOIN computer_groups
|
||||
JOIN computer_groups
|
||||
ON computer_groups.computer_group_id = policy_deployment.target_id
|
||||
JOIN smart_computer_group_criteria
|
||||
JOIN smart_computer_group_criteria
|
||||
ON smart_computer_group_criteria.computer_group_id = computer_groups.computer_group_id
|
||||
WHERE
|
||||
WHERE
|
||||
policies.trigger_event_enrollment_complete = "1"
|
||||
AND (
|
||||
policy_deployment.target_type = "7"
|
||||
AND policy_deployment.target_id IN (
|
||||
SELECT computer_group_id
|
||||
FROM computer_groups
|
||||
WHERE computer_groups.is_smart_group = 1
|
||||
AND policy_deployment.target_id IN (
|
||||
SELECT computer_group_id
|
||||
FROM computer_groups
|
||||
WHERE computer_groups.is_smart_group = 1
|
||||
)
|
||||
AND policy_deployment.target_id IN
|
||||
(
|
||||
SELECT computer_group_id
|
||||
FROM smart_computer_group_criteria
|
||||
SELECT computer_group_id
|
||||
FROM smart_computer_group_criteria
|
||||
WHERE search_field = "Enrollment Method: PreStage enrollment"
|
||||
)
|
||||
);
|
||||
@@ -1,107 +0,0 @@
|
||||
-- Queries on Miscellaneous Configurations
|
||||
-- Most of these should be working, but some may still be a work in progress.
|
||||
-- These are formatted for readability, just fyi.
|
||||
|
||||
-- ##################################################
|
||||
-- Computer Inventory Submissions
|
||||
|
||||
-- Count the number inventory submissions per day per computer
|
||||
SELECT DATE(date_sub(from_unixtime(reports.date_entered_epoch/1000), INTERVAL 1 DAY)) AS "Date", computer_id AS "Computer ID", COUNT(*) AS "Inventory Reports"
|
||||
FROM reports
|
||||
WHERE
|
||||
reports.date_entered_epoch > unix_timestamp(date_sub(now(), INTERVAL 1 DAY))*1000
|
||||
AND computer_id != 0
|
||||
GROUP BY DATE(date_sub(from_unixtime(reports.date_entered_epoch/1000), INTERVAL 1 DAY)), computer_id
|
||||
ORDER BY COUNT(*) DESC
|
||||
|
||||
|
||||
-- Count the number of inventory submissions per day
|
||||
SELECT DATE(date_sub(from_unixtime(reports.date_entered_epoch/1000), INTERVAL 1 DAY)) AS "Date", COUNT(*) AS "Inventory Reports"
|
||||
FROM reports
|
||||
WHERE computer_id != 0
|
||||
GROUP BY DATE(date_sub(from_unixtime(reports.date_entered_epoch/1000), INTERVAL 1 DAY))
|
||||
ORDER BY DATE(date_sub(from_unixtime(reports.date_entered_epoch/1000), INTERVAL 1 DAY)) DESC
|
||||
|
||||
|
||||
-- Count the number of inventory submissions per day in the last 7 days
|
||||
SELECT DATE(date_sub(from_unixtime(reports.date_entered_epoch/1000), INTERVAL 1 DAY)) AS "Date", COUNT(*) AS "Inventory Reports"
|
||||
FROM reports
|
||||
WHERE
|
||||
reports.date_entered_epoch > unix_timestamp(date_sub(now(), INTERVAL 7 DAY))*1000
|
||||
AND computer_id != 0
|
||||
GROUP BY DATE(date_sub(from_unixtime(reports.date_entered_epoch/1000), INTERVAL 1 DAY))
|
||||
ORDER BY DATE(date_sub(from_unixtime(reports.date_entered_epoch/1000), INTERVAL 1 DAY)) DESC
|
||||
|
||||
|
||||
-- ##################################################
|
||||
-- Printers
|
||||
|
||||
-- Unused Printers
|
||||
SELECT DISTINCT printers.printer_id, printers.display_name
|
||||
FROM printers
|
||||
WHERE printers.printer_id NOT IN (
|
||||
SELECT printer_id FROM policy_printers
|
||||
);
|
||||
|
||||
|
||||
-- ##################################################
|
||||
-- Queries to check configuration profiles would likely be useful
|
||||
|
||||
|
||||
|
||||
-- ##################################################
|
||||
-- Clean up orphaned records in the log_actions table
|
||||
|
||||
-- Get total count
|
||||
SELECT COUNT(*) FROM log_actions;
|
||||
|
||||
-- Get number of orphaned records
|
||||
SELECT COUNT(*) FROM log_actions
|
||||
WHERE log_id NOT IN ( SELECT log_id FROM logs );
|
||||
|
||||
-- Rename the original table
|
||||
RENAME TABLE log_actions TO log_actions_original;
|
||||
|
||||
-- Create new table like the old table
|
||||
CREATE TABLE log_actions LIKE log_actions_original;
|
||||
|
||||
-- Select the non-orphaned records from the original table
|
||||
INSERT INTO log_actions
|
||||
SELECT * FROM log_actions_original
|
||||
WHERE log_id IN ( SELECT log_id FROM logs );
|
||||
|
||||
-- Verify no orphaned records
|
||||
SELECT COUNT(*) FROM log_actions
|
||||
WHERE log_id NOT IN ( SELECT log_id FROM logs );
|
||||
|
||||
|
||||
-- ##################################################
|
||||
-- Clean up orphaned records in the mobile_device_extension_attribute_values table
|
||||
|
||||
-- Get total count
|
||||
SELECT COUNT(*) FROM mobile_device_extension_attribute_values;
|
||||
|
||||
-- Get number of orphaned records
|
||||
SELECT COUNT(*) FROM mobile_device_extension_attribute_values
|
||||
WHERE report_id NOT IN (
|
||||
SELECT report_id FROM reports WHERE mobile_device_id > 0 );
|
||||
|
||||
-- Rename the original table
|
||||
RENAME TABLE mobile_device_extension_attribute_values TO mobile_device_extension_attribute_values_original;
|
||||
|
||||
-- Create new table like the old table
|
||||
CREATE TABLE mobile_device_extension_attribute_values LIKE mobile_device_extension_attribute_values_original;
|
||||
|
||||
-- Select the non-orphaned records from the original table
|
||||
INSERT INTO mobile_device_extension_attribute_values
|
||||
SELECT * FROM mobile_device_extension_attribute_values_original
|
||||
WHERE report_id IN (
|
||||
SELECT report_id FROM reports WHERE mobile_device_id > 0 );
|
||||
|
||||
-- Verify no orphaned records
|
||||
SELECT COUNT(*) FROM mobile_device_extension_attribute_values
|
||||
WHERE report_id NOT IN (
|
||||
SELECT report_id FROM reports WHERE mobile_device_id > 0 );
|
||||
|
||||
-- Get new total count
|
||||
SELECT COUNT(*) FROM mobile_device_extension_attribute_values;
|
||||
Reference in New Issue
Block a user