start work on Events_(Hour|Day|Month|etc) tables for the event count data
This commit is contained in:
parent
b2fbd976cb
commit
1db4d7df83
|
@ -216,6 +216,47 @@ CREATE TABLE `Events` (
|
||||||
KEY `Events_EndTime_DiskSpace` (`EndTime`,`DiskSpace`)
|
KEY `Events_EndTime_DiskSpace` (`EndTime`,`DiskSpace`)
|
||||||
) ENGINE=@ZM_MYSQL_ENGINE@;
|
) ENGINE=@ZM_MYSQL_ENGINE@;
|
||||||
|
|
||||||
|
DROP TABLE IF EXISTS `Events_Hour`;
|
||||||
|
CREATE TABLE `Events_Hour` (
|
||||||
|
`EventId` int(10) unsigned NOT NULL,
|
||||||
|
`MonitorId` int(10) unsigned NOT NULL,
|
||||||
|
`StartTime` datetime default NULL,
|
||||||
|
`DiskSpace` bigint unsigned default NULL,
|
||||||
|
PRIMARY KEY (`EventId`),
|
||||||
|
KEY `Events_Hour_MonitorId_StartTime_idx` (`MonitorId`,`StartTime`)
|
||||||
|
) ENGINE=@ZM_MYSQL_ENGINE@;
|
||||||
|
|
||||||
|
DROP TABLE IF EXISTS `Events_Day`;
|
||||||
|
CREATE TABLE `Events_Day` (
|
||||||
|
`EventId` int(10) unsigned NOT NULL,
|
||||||
|
`MonitorId` int(10) unsigned NOT NULL,
|
||||||
|
`StartTime` datetime default NULL,
|
||||||
|
`DiskSpace` bigint unsigned default NULL,
|
||||||
|
PRIMARY KEY (`EventId`),
|
||||||
|
KEY `Events_Day_MonitorId_StartTime_idx` (`MonitorId`,`StartTime`)
|
||||||
|
) ENGINE=@ZM_MYSQL_ENGINE@;
|
||||||
|
|
||||||
|
|
||||||
|
DROP TABLE IF EXISTS `Events_Week`;
|
||||||
|
CREATE TABLE `Events_Week` (
|
||||||
|
`EventId` int(10) unsigned NOT NULL,
|
||||||
|
`MonitorId` int(10) unsigned NOT NULL,
|
||||||
|
`StartTime` datetime default NULL,
|
||||||
|
`DiskSpace` bigint unsigned default NULL,
|
||||||
|
PRIMARY KEY (`EventId`),
|
||||||
|
KEY `Events_Week_MonitorId_StartTime_idx` (`MonitorId`,`StartTime`)
|
||||||
|
) ENGINE=@ZM_MYSQL_ENGINE@;
|
||||||
|
|
||||||
|
DROP TABLE IF EXISTS `Events_Month`;
|
||||||
|
CREATE TABLE `Events_Month` (
|
||||||
|
`EventId` int(10) unsigned NOT NULL,
|
||||||
|
`MonitorId` int(10) unsigned NOT NULL,
|
||||||
|
`StartTime` datetime default NULL,
|
||||||
|
`DiskSpace` bigint unsigned default NULL,
|
||||||
|
PRIMARY KEY (`EventId`),
|
||||||
|
KEY `Events_Month_MonitorId_StartTime_idx` (`MonitorId`,`StartTime`)
|
||||||
|
) ENGINE=@ZM_MYSQL_ENGINE@;
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Table structure for table `Filters`
|
-- Table structure for table `Filters`
|
||||||
--
|
--
|
||||||
|
|
|
@ -0,0 +1,160 @@
|
||||||
|
|
||||||
|
SET @s = (SELECT IF(
|
||||||
|
(SELECT COUNT(*)
|
||||||
|
FROM INFORMATION_SCHEMA.TABLES
|
||||||
|
WHERE table_name = 'Events_Hour'
|
||||||
|
AND table_schema = DATABASE()
|
||||||
|
) > 0,
|
||||||
|
"SELECT 'Events_Hour table exists'",
|
||||||
|
"
|
||||||
|
CREATE TABLE `Events_Hour` (
|
||||||
|
`EventId` int(10) unsigned NOT NULL,
|
||||||
|
`MonitorId` int(10) unsigned NOT NULL,
|
||||||
|
`StartTime` datetime default NULL,
|
||||||
|
`DiskSpace` bigint unsigned default NULL,
|
||||||
|
PRIMARY KEY (`EventId`),
|
||||||
|
KEY `Events_Hour_MonitorId_StartTime_idx` (`MonitorId`,`StartTime`)
|
||||||
|
);
|
||||||
|
"
|
||||||
|
));
|
||||||
|
|
||||||
|
PREPARE stmt FROM @s;
|
||||||
|
EXECUTE stmt;
|
||||||
|
|
||||||
|
SET @s = (SELECT IF(
|
||||||
|
(SELECT COUNT(*)
|
||||||
|
FROM INFORMATION_SCHEMA.TABLES
|
||||||
|
WHERE table_name = 'Events_Day'
|
||||||
|
AND table_schema = DATABASE()
|
||||||
|
) > 0,
|
||||||
|
"SELECT 'Events_Day table exists'",
|
||||||
|
"
|
||||||
|
CREATE TABLE `Events_Day` (
|
||||||
|
`EventId` int(10) unsigned NOT NULL,
|
||||||
|
`MonitorId` int(10) unsigned NOT NULL,
|
||||||
|
`StartTime` datetime default NULL,
|
||||||
|
`DiskSpace` bigint unsigned default NULL,
|
||||||
|
PRIMARY KEY (`EventId`),
|
||||||
|
KEY `Events_Day_MonitorId_StartTime_idx` (`MonitorId`,`StartTime`)
|
||||||
|
);
|
||||||
|
"));
|
||||||
|
|
||||||
|
PREPARE stmt FROM @s;
|
||||||
|
EXECUTE stmt;
|
||||||
|
|
||||||
|
SET @s = (SELECT IF(
|
||||||
|
(SELECT COUNT(*)
|
||||||
|
FROM INFORMATION_SCHEMA.TABLES
|
||||||
|
WHERE table_name = 'Events_Week'
|
||||||
|
AND table_schema = DATABASE()
|
||||||
|
) > 0,
|
||||||
|
"SELECT 'Events_Week table exists'",
|
||||||
|
"
|
||||||
|
CREATE TABLE `Events_Week` (
|
||||||
|
`EventId` int(10) unsigned NOT NULL,
|
||||||
|
`MonitorId` int(10) unsigned NOT NULL,
|
||||||
|
`StartTime` datetime default NULL,
|
||||||
|
`DiskSpace` bigint unsigned default NULL,
|
||||||
|
PRIMARY KEY (`EventId`),
|
||||||
|
KEY `Events_Week_MonitorId_StartTime_idx` (`MonitorId`,`StartTime`)
|
||||||
|
);
|
||||||
|
"));
|
||||||
|
|
||||||
|
PREPARE stmt FROM @s;
|
||||||
|
EXECUTE stmt;
|
||||||
|
|
||||||
|
|
||||||
|
SET @s = (SELECT IF(
|
||||||
|
(SELECT COUNT(*)
|
||||||
|
FROM INFORMATION_SCHEMA.TABLES
|
||||||
|
WHERE table_name = 'Events_Month'
|
||||||
|
AND table_schema = DATABASE()
|
||||||
|
) > 0,
|
||||||
|
"SELECT 'Events_Month table exists'",
|
||||||
|
"
|
||||||
|
CREATE TABLE `Events_Month` (
|
||||||
|
`EventId` int(10) unsigned NOT NULL,
|
||||||
|
`MonitorId` int(10) unsigned NOT NULL,
|
||||||
|
`StartTime` datetime default NULL,
|
||||||
|
`DiskSpace` bigint unsigned default NULL,
|
||||||
|
PRIMARY KEY (`EventId`),
|
||||||
|
KEY `Events_Month_MonitorId_StartTime_idx` (`MonitorId`,`StartTime`)
|
||||||
|
);
|
||||||
|
"));
|
||||||
|
|
||||||
|
PREPARE stmt FROM @s;
|
||||||
|
EXECUTE stmt;
|
||||||
|
|
||||||
|
drop trigger if exists event_update_trigger;
|
||||||
|
|
||||||
|
delimiter //
|
||||||
|
|
||||||
|
create trigger event_update_trigger after update on Events
|
||||||
|
for each row
|
||||||
|
begin
|
||||||
|
declare diff BIGINT default 0;
|
||||||
|
|
||||||
|
set diff = NEW.DiskSpace - OLD.DiskSpace;
|
||||||
|
IF ( NEW.StorageId = OLD.StorageID ) THEN
|
||||||
|
|
||||||
|
IF ( diff ) THEN
|
||||||
|
call update_storage_stats(OLD.StorageId, diff);
|
||||||
|
END IF;
|
||||||
|
ELSE
|
||||||
|
IF ( NEW.DiskSpace ) THEN
|
||||||
|
call update_storage_stats(NEW.StorageId, NEW.DiskSpace);
|
||||||
|
END IF;
|
||||||
|
IF ( OLD.DiskSpace ) THEN
|
||||||
|
call update_storage_stats(OLD.StorageId, -OLD.DiskSpace);
|
||||||
|
END IF;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
end;
|
||||||
|
|
||||||
|
//
|
||||||
|
|
||||||
|
delimiter ;
|
||||||
|
|
||||||
|
drop trigger if exists event_insert_trigger;
|
||||||
|
|
||||||
|
delimiter //
|
||||||
|
create trigger event_insert_trigger after insert on Events
|
||||||
|
for each row
|
||||||
|
begin
|
||||||
|
|
||||||
|
INSERT INTO Events_Hour (EventId,MonitorId,StartTime,DiskSpace) VALUES (NEW.Id,NEW.MonitorId,NEW.StartTime,0);
|
||||||
|
INSERT INTO Events_Day (EventId,MonitorId,StartTime,DiskSpace) VALUES (NEW.Id,NEW.MonitorId,NEW.StartTime,0);
|
||||||
|
INSERT INTO Events_Week (EventId,MonitorId,StartTime,DiskSpace) VALUES (NEW.Id,NEW.MonitorId,NEW.StartTime,0);
|
||||||
|
INSERT INTO Events_Month (EventId,MonitorId,StartTime,DiskSpace) VALUES (NEW.Id,NEW.MonitorId,NEW.StartTime,0);
|
||||||
|
|
||||||
|
end;
|
||||||
|
//
|
||||||
|
|
||||||
|
delimiter ;
|
||||||
|
|
||||||
|
|
||||||
|
drop trigger if exists event_delete_trigger;
|
||||||
|
|
||||||
|
delimiter //
|
||||||
|
|
||||||
|
create trigger event_delete_trigger
|
||||||
|
|
||||||
|
before delete
|
||||||
|
|
||||||
|
on Events
|
||||||
|
|
||||||
|
for each row
|
||||||
|
|
||||||
|
begin
|
||||||
|
|
||||||
|
call update_storage_stats(OLD.StorageId, -OLD.DiskSpace);
|
||||||
|
DELETE FROM Events_Hour WHERE EventId=OLD.Id;
|
||||||
|
DELETE FROM Events_Day WHERE EventId=OLD.Id;
|
||||||
|
DELETE FROM Events_Week WHERE EventId=OLD.Id;
|
||||||
|
DELETE FROM Events_Month WHERE EventId=OLD.Id;
|
||||||
|
end;
|
||||||
|
|
||||||
|
//
|
||||||
|
|
||||||
|
delimiter ;
|
||||||
|
|
|
@ -110,10 +110,60 @@ UPDATE Monitors INNER JOIN (
|
||||||
Monitors.MonthEventDiskSpace = E.MonthEventDiskSpace
|
Monitors.MonthEventDiskSpace = E.MonthEventDiskSpace
|
||||||
`;
|
`;
|
||||||
|
|
||||||
|
|
||||||
|
my $eventcounts_hour_sql = q`
|
||||||
|
UPDATE Monitors INNER JOIN (
|
||||||
|
SELECT MonitorId, COUNT(*) AS HourEvents, SUM(DiskSpace) AS HourEventDiskSpace
|
||||||
|
FROM Events_Hour GROUP BY MonitorId
|
||||||
|
) AS E ON E.MonitorId=Monitors.Id SET
|
||||||
|
Monitors.HourEvents = E.HourEvents,
|
||||||
|
Monitors.HourEventDiskSpace = E.HourEventDiskSpace
|
||||||
|
`;
|
||||||
|
|
||||||
|
|
||||||
|
my $eventcounts_day_sql = q`
|
||||||
|
UPDATE Monitors INNER JOIN (
|
||||||
|
SELECT MonitorId, COUNT(*) AS DayEvents, SUM(DiskSpace) AS DayEventDiskSpace
|
||||||
|
FROM Events_Day GROUP BY MonitorId
|
||||||
|
) AS E ON E.MonitorId=Monitors.Id SET
|
||||||
|
Monitors.DayEvents = E.DayEvents,
|
||||||
|
Monitors.DayEventDiskSpace = E.DayEventDiskSpace
|
||||||
|
`;
|
||||||
|
|
||||||
|
my $eventcounts_week_sql = q`
|
||||||
|
UPDATE Monitors INNER JOIN (
|
||||||
|
SELECT MonitorId, COUNT(*) AS WeekEvents, SUM(DiskSpace) AS WeekEventDiskSpace
|
||||||
|
FROM Events_Week GROUP BY MonitorId
|
||||||
|
) AS E ON E.MonitorId=Monitors.Id SET
|
||||||
|
Monitors.WeekEvents = E.WeekEvents,
|
||||||
|
Monitors.WeekEventDiskSpace = E.WeekEventDiskSpace
|
||||||
|
`;
|
||||||
|
|
||||||
|
my $eventcounts_month_sql = q`
|
||||||
|
UPDATE Monitors INNER JOIN (
|
||||||
|
SELECT MonitorId, COUNT(*) AS MonthEvents, SUM(DiskSpace) AS MonthEventDiskSpace
|
||||||
|
FROM Events_Month GROUP BY MonitorId
|
||||||
|
) AS E ON E.MonitorId=Monitors.Id SET
|
||||||
|
Monitors.MonthEvents = E.MonthEvents,
|
||||||
|
Monitors.MonthEventDiskSpace = E.MonthEventDiskSpace
|
||||||
|
`;
|
||||||
|
|
||||||
|
|
||||||
my $eventcounts_sth = $dbh->prepare_cached( $eventcounts_sql );
|
my $eventcounts_sth = $dbh->prepare_cached( $eventcounts_sql );
|
||||||
|
my $eventcounts_hour_sth = $dbh->prepare_cached( $eventcounts_hour_sql );
|
||||||
|
my $eventcounts_day_sth = $dbh->prepare_cached( $eventcounts_day_sql );
|
||||||
|
my $eventcounts_week_sth = $dbh->prepare_cached( $eventcounts_week_sql );
|
||||||
|
my $eventcounts_month_sth = $dbh->prepare_cached( $eventcounts_month_sql );
|
||||||
|
|
||||||
while( 1 ) {
|
while( 1 ) {
|
||||||
$eventcounts_sth->execute( ) or Error( "Can't execute: ".$eventcounts_sth->errstr() );
|
$dbh->do('DELETE FROM Events_Hour WHERE StartTime < DATE_SUB(NOW(), INTERVAL 1 hour)');
|
||||||
|
$dbh->do('DELETE FROM Events_Day WHERE StartTime < DATE_SUB(NOW(), INTERVAL 1 day)');
|
||||||
|
$dbh->do('DELETE FROM Events_Week WHERE StartTime < DATE_SUB(NOW(), INTERVAL 1 week)');
|
||||||
|
$dbh->do('DELETE FROM Events_Month WHERE StartTime < DATE_SUB(NOW(), INTERVAL 1 month)');
|
||||||
|
$eventcounts_hour_sth->execute( ) or Error( "Can't execute: ".$eventcounts_sth->errstr() );
|
||||||
|
$eventcounts_day_sth->execute( ) or Error( "Can't execute: ".$eventcounts_sth->errstr() );
|
||||||
|
$eventcounts_week_sth->execute( ) or Error( "Can't execute: ".$eventcounts_sth->errstr() );
|
||||||
|
$eventcounts_month_sth->execute( ) or Error( "Can't execute: ".$eventcounts_sth->errstr() );
|
||||||
|
|
||||||
my $res = $sth->execute( $Config{ZM_SERVER_ID} ? $Config{ZM_SERVER_ID} : () )
|
my $res = $sth->execute( $Config{ZM_SERVER_ID} ? $Config{ZM_SERVER_ID} : () )
|
||||||
or Fatal( "Can't execute: ".$sth->errstr() );
|
or Fatal( "Can't execute: ".$sth->errstr() );
|
||||||
|
|
Loading…
Reference in New Issue