In the upcoming Icinga Web 2 release the filter functionality becomes even more powerful.
Version 2.6.0 introduces the possibility to exclude hosts and services that are member of specific groups.
You now filter for hosts that are not part of the production host group for example.
You want to filter for hosts that are member of the host groups linux and database? That will be possible as well.
I’d like to show you how the latter is done with an example. We have a database with user groups, users and their group
memberships:

CREATE TABLE user_group (
  id int(10) unsigned NOT NULL AUTO_INCREMENT,
  `name` varchar(64) NOT NULL COLLATE utf8mb4_unicode_ci,
  PRIMARY KEY (id),
  UNIQUE KEY group_name (`name`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE utf8mb4_bin;
CREATE TABLE user_group_membership (
  user_id int(10) unsigned NOT NULL,
  group_id int(10) unsigned NOT NULL,
  PRIMARY KEY (user_id,group_id),
  CONSTRAINT user_group_membership_user FOREIGN KEY (user_id) REFERENCES `user` (id),
  CONSTRAINT user_group_membership_group FOREIGN KEY (group_id) REFERENCES user_group (id)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE utf8mb4_bin;
INSERT INTO user VALUES (1,'john'),(2,'marc'),(3,'peter');
INSERT INTO user_group VALUES (1,'admins'),(3,'dev'),(2,'support');
INSERT INTO user_group_membership VALUES (1,1),(2,2),(2,3),(3,2);

User john is part of the group admins. Marc is member of the groups dev and support while Peter is part of the dev
group only. We now have the task to filter for users that are at least part of the groups dev and support. In this example
it’s easy of course because we only have three users and know the result without executing any queries.
But anyway how would you achieve this with SQL? Easy, let’s just JOIN the tables and add a WHERE IN condition:

SELECT * FROM `user` u INNER JOIN user_group_membership m ON m.user_id = u.id
INNER JOIN user_group g ON g.id = m.group_id WHERE g.name IN ('dev', 'support');
+----+-------+---------+----------+----+---------+
| id | name  | user_id | group_id | id | name    |
+----+-------+---------+----------+----+---------+
|  2 | marc  |       2 |        3 |  3 | dev     |
|  2 | marc  |       2 |        2 |  2 | support |
|  3 | peter |       3 |        2 |  2 | support |
+----+-------+---------+----------+----+---------+

The result is not surprising. Because of the WHERE IN condition we also get peter who is only part of the dev group.
So, we have to filter for users that produce two or more rows. For this aggregation, HAVING helps:

SELECT * FROM `user` u INNER JOIN user_group_membership m ON m.user_id = u.id
INNER JOIN user_group g ON g.id = m.group_id WHERE g.name IN ('dev', 'support')
HAVING(COUNT(group_id) >= 2);
+----+-------+---------+----------+----+------+
| id | name  | user_id | group_id | id | name |
+----+-------+---------+----------+----+------+
|  2 | marc  |       2 |        3 |  3 | dev  |
+----+-------+---------+----------+----+------+

Looks good! It’s best to move this to a subquery in order to be flexible if the query becomes more complex later on:

SELECT * FROM `user` u WHERE EXISTS (
  SELECT 1 FROM user_group_membership m
  INNER JOIN user_group g ON m.group_id = g.id
  WHERE m.user_id = u.id AND g.name IN ('dev', 'support')
  HAVING COUNT(*) >= 2
);
+----+-------+
| id | name  |
+----+-------+
|  2 | marc |
+----+-------+

Bonus question: how to filter for users that are member of dev and support but no other groups?

Eric Lippmann
Eric Lippmann
CTO

Eric kam während seines ersten Lehrjahres zu NETWAYS und hat seine Ausbildung bereits 2011 sehr erfolgreich abgeschlossen. Seit Beginn arbeitet er in der Softwareentwicklung und dort an den unterschiedlichen NETWAYS Open Source Lösungen, insbesondere inGraph und im Icinga Team an Icinga Web. Darüber hinaus zeichnet er für viele Kundenentwicklungen in der Finanz- und Automobilbranche verantwortlich.