-
Notifications
You must be signed in to change notification settings - Fork 440
/
software.go
2800 lines (2481 loc) · 87.5 KB
/
software.go
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
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
package mysql
import (
"context"
"crypto/md5" //nolint:gosec // This hash is used as a DB optimization for software row lookup, not security
"encoding/hex"
"fmt"
"sort"
"strings"
"time"
"github.com/doug-martin/goqu/v9"
_ "github.com/doug-martin/goqu/v9/dialect/mysql"
"github.com/fleetdm/fleet/v4/server/contexts/ctxerr"
"github.com/fleetdm/fleet/v4/server/fleet"
"github.com/fleetdm/fleet/v4/server/ptr"
"github.com/go-kit/log/level"
"github.com/google/uuid"
"github.com/jmoiron/sqlx"
)
type softwareIDChecksum struct {
ID uint `db:"id"`
Checksum string `db:"checksum"`
}
// Since DB may have millions of software items, we need to batch the aggregation counts to avoid long SQL query times.
// This is a variable so it can be adjusted during unit testing.
var countHostSoftwareBatchSize = uint64(100000)
// Since a host may have a lot of software items, we need to batch the inserts.
// The maximum number of software items we can insert at one time is governed by max_allowed_packet, which already be set to a high value for MDM bootstrap packages,
// and by the maximum number of placeholders in a prepared statement, which is 65,536. These are already fairly large limits.
// This is a variable, so it can be adjusted during unit testing.
var softwareInsertBatchSize = 1000
func softwareSliceToMap(softwareItems []fleet.Software) map[string]fleet.Software {
result := make(map[string]fleet.Software, len(softwareItems))
for _, s := range softwareItems {
result[s.ToUniqueStr()] = s
}
return result
}
func (ds *Datastore) UpdateHostSoftware(ctx context.Context, hostID uint, software []fleet.Software) (*fleet.UpdateHostSoftwareDBResult, error) {
return ds.applyChangesForNewSoftwareDB(ctx, hostID, software)
}
func (ds *Datastore) UpdateHostSoftwareInstalledPaths(
ctx context.Context,
hostID uint,
reported map[string]struct{},
mutationResults *fleet.UpdateHostSoftwareDBResult,
) error {
currS := mutationResults.CurrInstalled()
hsip, err := ds.getHostSoftwareInstalledPaths(ctx, hostID)
if err != nil {
return err
}
toI, toD, err := hostSoftwareInstalledPathsDelta(hostID, reported, hsip, currS)
if err != nil {
return err
}
if len(toI) == 0 && len(toD) == 0 {
// Nothing to do ...
return nil
}
return ds.withRetryTxx(ctx, func(tx sqlx.ExtContext) error {
if err := deleteHostSoftwareInstalledPaths(ctx, tx, toD); err != nil {
return err
}
if err := insertHostSoftwareInstalledPaths(ctx, tx, toI); err != nil {
return err
}
return nil
})
}
// getHostSoftwareInstalledPaths returns all HostSoftwareInstalledPath for the given hostID.
func (ds *Datastore) getHostSoftwareInstalledPaths(
ctx context.Context,
hostID uint,
) (
[]fleet.HostSoftwareInstalledPath,
error,
) {
stmt := `
SELECT t.id, t.host_id, t.software_id, t.installed_path, t.team_identifier
FROM host_software_installed_paths t
WHERE t.host_id = ?
`
var result []fleet.HostSoftwareInstalledPath
if err := sqlx.SelectContext(ctx, ds.reader(ctx), &result, stmt, hostID); err != nil {
return nil, err
}
return result, nil
}
// hostSoftwareInstalledPathsDelta returns what should be inserted and deleted to keep the
// 'host_software_installed_paths' table in-sync with the osquery reported query results.
// 'reported' is a set of 'installed_path-software.UniqueStr' strings, built from the osquery
// results.
// 'stored' contains all 'host_software_installed_paths' rows for the given host.
// 'hostSoftware' contains the current software installed on the host.
func hostSoftwareInstalledPathsDelta(
hostID uint,
reported map[string]struct{},
stored []fleet.HostSoftwareInstalledPath,
hostSoftware []fleet.Software,
) (
toInsert []fleet.HostSoftwareInstalledPath,
toDelete []uint,
err error,
) {
if len(reported) != 0 && len(hostSoftware) == 0 {
// Error condition, something reported implies that the host has some software
err = fmt.Errorf("software installed paths for host %d were reported but host contains no software", hostID)
return
}
sIDLookup := map[uint]fleet.Software{}
for _, s := range hostSoftware {
sIDLookup[s.ID] = s
}
sUnqStrLook := map[string]fleet.Software{}
for _, s := range hostSoftware {
sUnqStrLook[s.ToUniqueStr()] = s
}
iSPathLookup := make(map[string]fleet.HostSoftwareInstalledPath)
for _, r := range stored {
s, ok := sIDLookup[r.SoftwareID]
// Software currently not found on the host, should be deleted ...
if !ok {
toDelete = append(toDelete, r.ID)
continue
}
key := fmt.Sprintf(
"%s%s%s%s%s",
r.InstalledPath, fleet.SoftwareFieldSeparator, r.TeamIdentifier, fleet.SoftwareFieldSeparator, s.ToUniqueStr(),
)
iSPathLookup[key] = r
// Anything stored but not reported should be deleted
if _, ok := reported[key]; !ok {
toDelete = append(toDelete, r.ID)
}
}
for key := range reported {
parts := strings.SplitN(key, fleet.SoftwareFieldSeparator, 3)
installedPath, teamIdentifier, unqStr := parts[0], parts[1], parts[2]
// Shouldn't be possible ... everything 'reported' should be in the the software table
// because this executes after 'ds.UpdateHostSoftware'
s, ok := sUnqStrLook[unqStr]
if !ok {
err = fmt.Errorf("reported installed path for %s does not belong to any stored software entry", unqStr)
return
}
if _, ok := iSPathLookup[key]; ok {
// Nothing to do
continue
}
toInsert = append(toInsert, fleet.HostSoftwareInstalledPath{
HostID: hostID,
SoftwareID: s.ID,
InstalledPath: installedPath,
TeamIdentifier: teamIdentifier,
})
}
return
}
func deleteHostSoftwareInstalledPaths(
ctx context.Context,
tx sqlx.ExtContext,
toDelete []uint,
) error {
if len(toDelete) == 0 {
return nil
}
stmt := `DELETE FROM host_software_installed_paths WHERE id IN (?)`
stmt, args, err := sqlx.In(stmt, toDelete)
if err != nil {
return ctxerr.Wrap(ctx, err, "building delete statement for delete host_software_installed_paths")
}
if _, err := tx.ExecContext(ctx, stmt, args...); err != nil {
return ctxerr.Wrap(ctx, err, "executing delete statement for delete host_software_installed_paths")
}
return nil
}
func insertHostSoftwareInstalledPaths(
ctx context.Context,
tx sqlx.ExtContext,
toInsert []fleet.HostSoftwareInstalledPath,
) error {
if len(toInsert) == 0 {
return nil
}
stmt := "INSERT INTO host_software_installed_paths (host_id, software_id, installed_path, team_identifier) VALUES %s"
batchSize := 500
for i := 0; i < len(toInsert); i += batchSize {
end := i + batchSize
if end > len(toInsert) {
end = len(toInsert)
}
batch := toInsert[i:end]
var args []interface{}
for _, v := range batch {
args = append(args, v.HostID, v.SoftwareID, v.InstalledPath, v.TeamIdentifier)
}
placeHolders := strings.TrimSuffix(strings.Repeat("(?, ?, ?, ?), ", len(batch)), ", ")
stmt := fmt.Sprintf(stmt, placeHolders)
_, err := tx.ExecContext(ctx, stmt, args...)
if err != nil {
return ctxerr.Wrap(ctx, err, "inserting rows into host_software_installed_paths")
}
}
return nil
}
func nothingChanged(current, incoming []fleet.Software, minLastOpenedAtDiff time.Duration) (
map[string]fleet.Software, map[string]fleet.Software, bool,
) {
// Process incoming software to ensure there are no duplicates, since the same software can be installed at multiple paths.
incomingMap := make(map[string]fleet.Software, len(current)) // setting len(current) as the length since that should be the common case
for _, s := range incoming {
uniqueStr := s.ToUniqueStr()
if duplicate, ok := incomingMap[uniqueStr]; ok {
// Check the last opened at timestamp and keep the latest.
if s.LastOpenedAt == nil ||
(duplicate.LastOpenedAt != nil && !s.LastOpenedAt.After(*duplicate.LastOpenedAt)) {
continue // keep the duplicate
}
}
incomingMap[uniqueStr] = s
}
currentMap := softwareSliceToMap(current)
if len(currentMap) != len(incomingMap) {
return currentMap, incomingMap, false
}
for _, s := range incomingMap {
cur, ok := currentMap[s.ToUniqueStr()]
if !ok {
return currentMap, incomingMap, false
}
// if the incoming software has a last opened at timestamp and it differs
// significantly from the current timestamp (or there is no current
// timestamp), then consider that something changed.
if s.LastOpenedAt != nil {
if cur.LastOpenedAt == nil {
return currentMap, incomingMap, false
}
oldLast := *cur.LastOpenedAt
newLast := *s.LastOpenedAt
if newLast.Sub(oldLast) >= minLastOpenedAtDiff {
return currentMap, incomingMap, false
}
}
}
return currentMap, incomingMap, true
}
func (ds *Datastore) ListSoftwareByHostIDShort(ctx context.Context, hostID uint) ([]fleet.Software, error) {
return listSoftwareByHostIDShort(ctx, ds.reader(ctx), hostID)
}
func listSoftwareByHostIDShort(
ctx context.Context,
db sqlx.QueryerContext,
hostID uint,
) ([]fleet.Software, error) {
q := `
SELECT
s.id,
s.name,
s.version,
s.source,
s.browser,
s.bundle_identifier,
s.release,
s.vendor,
s.arch,
s.extension_id,
hs.last_opened_at
FROM
software s
JOIN host_software hs ON hs.software_id = s.id
WHERE
hs.host_id = ?
`
var softwares []fleet.Software
err := sqlx.SelectContext(ctx, db, &softwares, q, hostID)
if err != nil {
return nil, err
}
return softwares, nil
}
// applyChangesForNewSoftwareDB returns the current host software and the applied mutations: what
// was inserted and what was deleted
func (ds *Datastore) applyChangesForNewSoftwareDB(
ctx context.Context,
hostID uint,
software []fleet.Software,
) (*fleet.UpdateHostSoftwareDBResult, error) {
r := &fleet.UpdateHostSoftwareDBResult{}
// This code executes once an hour for each host, so we should optimize for MySQL master (writer) DB performance.
// We use a slave (reader) DB to avoid accessing the master. If nothing has changed, we avoid all access to the master.
// It is possible that the software list is out of sync between the slave and the master. This is unlikely because
// it is updated once an hour under normal circumstances. If this does occur, the software list will be updated
// once again in an hour.
currentSoftware, err := listSoftwareByHostIDShort(ctx, ds.reader(ctx), hostID)
if err != nil {
return nil, ctxerr.Wrap(ctx, err, "loading current software for host")
}
r.WasCurrInstalled = currentSoftware
current, incoming, notChanged := nothingChanged(currentSoftware, software, ds.minLastOpenedAtDiff)
if notChanged {
return r, nil
}
existingSoftware, incomingByChecksum, existingTitlesForNewSoftware, err := ds.getExistingSoftware(ctx, current, incoming)
if err != nil {
return r, err
}
err = ds.withRetryTxx(
ctx, func(tx sqlx.ExtContext) error {
deleted, err := deleteUninstalledHostSoftwareDB(ctx, tx, hostID, current, incoming)
if err != nil {
return err
}
r.Deleted = deleted
inserted, err := ds.insertNewInstalledHostSoftwareDB(
ctx, tx, hostID, existingSoftware, incomingByChecksum, existingTitlesForNewSoftware,
)
if err != nil {
return err
}
r.Inserted = inserted
if err = checkForDeletedInstalledSoftware(ctx, tx, deleted, inserted, hostID); err != nil {
return err
}
if err = updateModifiedHostSoftwareDB(ctx, tx, hostID, current, incoming, ds.minLastOpenedAtDiff); err != nil {
return err
}
if err = updateSoftwareUpdatedAt(ctx, tx, hostID); err != nil {
return err
}
return nil
},
)
if err != nil {
return nil, err
}
return r, err
}
func checkForDeletedInstalledSoftware(ctx context.Context, tx sqlx.ExtContext, deleted []fleet.Software, inserted []fleet.Software,
hostID uint,
) error {
// Between deleted and inserted software, check which software titles were deleted.
// If software titles were deleted, get the software titles of the installed software.
// See if deleted titles match installed software titles.
// If so, mark the installed software as removed.
var deletedTitles map[string]struct{}
if len(deleted) > 0 {
deletedTitles = make(map[string]struct{}, len(deleted))
for _, d := range deleted {
// We don't support installing browser plugins as of 2024/08/22
if d.Browser == "" {
deletedTitles[UniqueSoftwareTitleStr(d.Name, d.Source, d.BundleIdentifier)] = struct{}{}
}
}
for _, i := range inserted {
// We don't support installing browser plugins as of 2024/08/22
if i.Browser == "" {
key := UniqueSoftwareTitleStr(i.Name, i.Source, i.BundleIdentifier)
delete(deletedTitles, key)
}
}
}
if len(deletedTitles) > 0 {
installedTitles, err := getInstalledByFleetSoftwareTitles(ctx, tx, hostID)
if err != nil {
return err
}
type deletedValue struct {
vpp bool
}
deletedTitleIDs := make(map[uint]deletedValue, 0)
for _, title := range installedTitles {
bundleIdentifier := ""
if title.BundleIdentifier != nil {
bundleIdentifier = *title.BundleIdentifier
}
key := UniqueSoftwareTitleStr(title.Name, title.Source, bundleIdentifier)
if _, ok := deletedTitles[key]; ok {
deletedTitleIDs[title.ID] = deletedValue{vpp: title.VPPAppsCount > 0}
}
}
if len(deletedTitleIDs) > 0 {
IDs := make([]uint, 0, len(deletedTitleIDs))
vppIDs := make([]uint, 0, len(deletedTitleIDs))
for id, value := range deletedTitleIDs {
if value.vpp {
vppIDs = append(vppIDs, id)
} else {
IDs = append(IDs, id)
}
}
if len(IDs) > 0 {
if err = markHostSoftwareInstallsRemoved(ctx, tx, hostID, IDs); err != nil {
return err
}
}
if len(vppIDs) > 0 {
if err = markHostVPPSoftwareInstallsRemoved(ctx, tx, hostID, vppIDs); err != nil {
return err
}
}
}
}
return nil
}
func (ds *Datastore) getExistingSoftware(
ctx context.Context, current map[string]fleet.Software, incoming map[string]fleet.Software,
) (
currentSoftware []softwareIDChecksum, incomingChecksumToSoftware map[string]fleet.Software,
incomingChecksumToTitle map[string]fleet.SoftwareTitle, err error,
) {
// Compute checksums for all incoming software, which we will use for faster retrieval, since checksum is a unique index
incomingChecksumToSoftware = make(map[string]fleet.Software, len(current))
newSoftware := make(map[string]struct{})
for uniqueName, s := range incoming {
if _, ok := current[uniqueName]; !ok {
checksum, err := computeRawChecksum(s)
if err != nil {
return nil, nil, nil, err
}
incomingChecksumToSoftware[string(checksum)] = s
newSoftware[string(checksum)] = struct{}{}
}
}
if len(incomingChecksumToSoftware) > 0 {
keys := make([]string, 0, len(incomingChecksumToSoftware))
for checksum := range incomingChecksumToSoftware {
keys = append(keys, checksum)
}
// We use the replica DB for retrieval to minimize the traffic to the master DB.
// It is OK if the software is not found in the replica DB, because we will then attempt to insert it in the master DB.
currentSoftware, err = getSoftwareIDsByChecksums(ctx, ds.reader(ctx), keys)
if err != nil {
return nil, nil, nil, err
}
for _, s := range currentSoftware {
_, ok := incomingChecksumToSoftware[s.Checksum]
if !ok {
// This should never happen. If it does, we have a bug.
return nil, nil, nil, ctxerr.New(
ctx, fmt.Sprintf("software not found for checksum %s", hex.EncodeToString([]byte(s.Checksum))),
)
}
delete(newSoftware, s.Checksum)
}
}
// Get software titles for new software, if any
incomingChecksumToTitle = make(map[string]fleet.SoftwareTitle, len(newSoftware))
if len(newSoftware) > 0 {
totalToProcess := len(newSoftware)
const numberOfArgsPerSoftwareTitle = 4 // number of ? in each WHERE clause
whereClause := strings.TrimSuffix(
strings.Repeat(`
(
(bundle_identifier = ?) OR
(name = ? AND source = ? AND browser = ? AND bundle_identifier IS NULL)
) OR`, totalToProcess), " OR",
)
stmt := fmt.Sprintf(
"SELECT id, name, source, browser, COALESCE(bundle_identifier, '') as bundle_identifier FROM software_titles WHERE %s",
whereClause,
)
args := make([]interface{}, 0, totalToProcess*numberOfArgsPerSoftwareTitle)
uniqueTitleStrToChecksum := make(map[string]string, totalToProcess)
for checksum := range newSoftware {
sw := incomingChecksumToSoftware[checksum]
args = append(args, sw.BundleIdentifier, sw.Name, sw.Source, sw.Browser)
// Map software title identifier to software checksums so that we can map checksums to actual titles later.
uniqueTitleStrToChecksum[UniqueSoftwareTitleStr(sw.Name, sw.Source, sw.Browser)] = checksum
}
var existingSoftwareTitlesForNewSoftware []fleet.SoftwareTitle
if err := sqlx.SelectContext(ctx, ds.reader(ctx), &existingSoftwareTitlesForNewSoftware, stmt, args...); err != nil {
return nil, nil, nil, ctxerr.Wrap(ctx, err, "get existing titles")
}
// Map software titles to software checksums.
for _, title := range existingSoftwareTitlesForNewSoftware {
checksum, ok := uniqueTitleStrToChecksum[UniqueSoftwareTitleStr(title.Name, title.Source, title.Browser)]
if ok {
incomingChecksumToTitle[checksum] = title
}
}
}
return currentSoftware, incomingChecksumToSoftware, incomingChecksumToTitle, nil
}
// UniqueSoftwareTitleStr creates a unique string representation of the software title
func UniqueSoftwareTitleStr(values ...string) string {
return strings.Join(values, fleet.SoftwareFieldSeparator)
}
// delete host_software that is in current map, but not in incoming map.
// returns the deleted software on the host
func deleteUninstalledHostSoftwareDB(
ctx context.Context,
tx sqlx.ExecerContext,
hostID uint,
currentMap map[string]fleet.Software,
incomingMap map[string]fleet.Software,
) ([]fleet.Software, error) {
var deletesHostSoftwareIDs []uint
var deletedSoftware []fleet.Software
for currentKey, curSw := range currentMap {
if _, ok := incomingMap[currentKey]; !ok {
deletedSoftware = append(deletedSoftware, curSw)
deletesHostSoftwareIDs = append(deletesHostSoftwareIDs, curSw.ID)
}
}
if len(deletesHostSoftwareIDs) == 0 {
return nil, nil
}
stmt := `DELETE FROM host_software WHERE host_id = ? AND software_id IN (?);`
stmt, args, err := sqlx.In(stmt, hostID, deletesHostSoftwareIDs)
if err != nil {
return nil, ctxerr.Wrap(ctx, err, "build delete host software query")
}
if _, err := tx.ExecContext(ctx, stmt, args...); err != nil {
return nil, ctxerr.Wrap(ctx, err, "delete host software")
}
return deletedSoftware, nil
}
// computeRawChecksum computes the checksum for a software entry
// The calculation must match the one in softwareChecksumComputedColumn
func computeRawChecksum(sw fleet.Software) ([]byte, error) {
h := md5.New() //nolint:gosec // This hash is used as a DB optimization for software row lookup, not security
cols := []string{sw.Name, sw.Version, sw.Source, sw.BundleIdentifier, sw.Release, sw.Arch, sw.Vendor, sw.Browser, sw.ExtensionID}
_, err := fmt.Fprint(h, strings.Join(cols, "\x00"))
if err != nil {
return nil, err
}
return h.Sum(nil), nil
}
// Insert host_software that is in softwareChecksums map, but not in existingSoftware.
// Also insert any new software titles that are needed.
// returns the inserted software on the host
func (ds *Datastore) insertNewInstalledHostSoftwareDB(
ctx context.Context,
tx sqlx.ExtContext,
hostID uint,
existingSoftware []softwareIDChecksum,
softwareChecksums map[string]fleet.Software,
existingTitlesForNewSoftware map[string]fleet.SoftwareTitle,
) ([]fleet.Software, error) {
var insertsHostSoftware []interface{}
var insertedSoftware []fleet.Software
// First, we remove incoming software that already exists in the software table.
if len(softwareChecksums) > 0 {
for _, s := range existingSoftware {
software, ok := softwareChecksums[s.Checksum]
if !ok {
return nil, ctxerr.New(ctx, fmt.Sprintf("software not found for checksum %s", hex.EncodeToString([]byte(s.Checksum))))
}
software.ID = s.ID
insertsHostSoftware = append(insertsHostSoftware, hostID, software.ID, software.LastOpenedAt)
insertedSoftware = append(insertedSoftware, software)
delete(softwareChecksums, s.Checksum)
}
}
// For software items that don't already exist in the software table, we insert them.
if len(softwareChecksums) > 0 {
keys := make([]string, 0, len(softwareChecksums))
for checksum := range softwareChecksums {
keys = append(keys, checksum)
}
for i := 0; i < len(keys); i += softwareInsertBatchSize {
start := i
end := i + softwareInsertBatchSize
if end > len(keys) {
end = len(keys)
}
totalToProcess := end - start
// Insert into software
const numberOfArgsPerSoftware = 11 // number of ? in each VALUES clause
values := strings.TrimSuffix(
strings.Repeat("(?,?,?,?,?,?,?,?,?,?,?),", totalToProcess), ",",
)
// INSERT IGNORE is used to avoid duplicate key errors, which may occur since our previous read came from the replica.
stmt := fmt.Sprintf(
`INSERT IGNORE INTO software (
name,
version,
source,
`+"`release`"+`,
vendor,
arch,
bundle_identifier,
extension_id,
browser,
title_id,
checksum
) VALUES %s`,
values,
)
args := make([]interface{}, 0, totalToProcess*numberOfArgsPerSoftware)
newTitlesNeeded := make(map[string]fleet.SoftwareTitle)
for j := start; j < end; j++ {
checksum := keys[j]
sw := softwareChecksums[checksum]
var titleID *uint
title, ok := existingTitlesForNewSoftware[checksum]
if ok {
titleID = &title.ID
} else if _, ok := newTitlesNeeded[checksum]; !ok {
st := fleet.SoftwareTitle{
Name: sw.Name,
Source: sw.Source,
Browser: sw.Browser,
}
if sw.BundleIdentifier != "" {
st.BundleIdentifier = ptr.String(sw.BundleIdentifier)
}
newTitlesNeeded[checksum] = st
}
args = append(
args, sw.Name, sw.Version, sw.Source, sw.Release, sw.Vendor, sw.Arch, sw.BundleIdentifier, sw.ExtensionID, sw.Browser,
titleID, checksum,
)
}
if _, err := tx.ExecContext(ctx, stmt, args...); err != nil {
return nil, ctxerr.Wrap(ctx, err, "insert software")
}
// Insert into software_titles
totalTitlesToProcess := len(newTitlesNeeded)
if totalTitlesToProcess > 0 {
const numberOfArgsPerSoftwareTitles = 4 // number of ? in each VALUES clause
titlesValues := strings.TrimSuffix(strings.Repeat("(?,?,?,?),", totalTitlesToProcess), ",")
// INSERT IGNORE is used to avoid duplicate key errors, which may occur since our previous read came from the replica.
titlesStmt := fmt.Sprintf("INSERT IGNORE INTO software_titles (name, source, browser, bundle_identifier) VALUES %s", titlesValues)
titlesArgs := make([]interface{}, 0, totalTitlesToProcess*numberOfArgsPerSoftwareTitles)
titleChecksums := make([]string, 0, totalTitlesToProcess)
for checksum, title := range newTitlesNeeded {
titlesArgs = append(titlesArgs, title.Name, title.Source, title.Browser, title.BundleIdentifier)
titleChecksums = append(titleChecksums, checksum)
}
if _, err := tx.ExecContext(ctx, titlesStmt, titlesArgs...); err != nil {
return nil, ctxerr.Wrap(ctx, err, "insert software_titles")
}
updateSoftwareWithoutIdentifierStmt := `
UPDATE software s
JOIN software_titles st
ON COALESCE(s.bundle_identifier, '') = '' AND s.name = st.name AND s.source = st.source AND s.browser = st.browser
SET s.title_id = st.id
WHERE (s.title_id IS NULL OR s.title_id != st.id)
AND COALESCE(s.bundle_identifier, '') = ''
AND s.checksum IN (?)
`
updateSoftwareWithoutIdentifierStmt, updateArgs, err := sqlx.In(updateSoftwareWithoutIdentifierStmt, titleChecksums)
if err != nil {
return nil, ctxerr.Wrap(ctx, err, "build update software title_id without identifier")
}
if _, err = tx.ExecContext(ctx, updateSoftwareWithoutIdentifierStmt, updateArgs...); err != nil {
return nil, ctxerr.Wrap(ctx, err, "update software title_id without identifier")
}
// update new title ids for new software table entries
updateSoftwareStmt := `
UPDATE software s
JOIN software_titles st
ON s.bundle_identifier = st.bundle_identifier AND
IF(s.source IN ('apps', 'ios_apps', 'ipados_apps'), s.source = st.source, 1)
SET s.title_id = st.id
WHERE s.title_id IS NULL
OR s.title_id != st.id
AND s.checksum IN (?)`
updateSoftwareStmt, updateArgs, err = sqlx.In(updateSoftwareStmt, titleChecksums)
if err != nil {
return nil, ctxerr.Wrap(ctx, err, "build update software title_id with identifier")
}
if _, err = tx.ExecContext(ctx, updateSoftwareStmt, updateArgs...); err != nil {
return nil, ctxerr.Wrap(ctx, err, "update software title_id with identifier")
}
}
}
// Here, we use the transaction (tx) for retrieval because we must retrieve the software IDs that we just inserted.
updatedExistingSoftware, err := getSoftwareIDsByChecksums(ctx, tx, keys)
if err != nil {
return nil, err
}
for _, s := range updatedExistingSoftware {
software, ok := softwareChecksums[s.Checksum]
if !ok {
return nil, ctxerr.New(ctx, fmt.Sprintf("software not found for checksum %s", hex.EncodeToString([]byte(s.Checksum))))
}
software.ID = s.ID
insertsHostSoftware = append(insertsHostSoftware, hostID, software.ID, software.LastOpenedAt)
insertedSoftware = append(insertedSoftware, software)
delete(softwareChecksums, s.Checksum)
}
}
if len(softwareChecksums) > 0 {
// We log and continue. We should almost never see this error. If we see it regularly, we need to investigate.
level.Error(ds.logger).Log(
"msg", "could not find or create software items. This error may be caused by master and replica DBs out of sync.", "host_id",
hostID, "number", len(softwareChecksums),
)
for checksum, software := range softwareChecksums {
uuidString := ""
checksumAsUUID, err := uuid.FromBytes([]byte(checksum))
if err == nil {
// We ignore error
uuidString = checksumAsUUID.String()
}
level.Debug(ds.logger).Log(
"msg", "software item not found or created", "name", software.Name, "version", software.Version, "source", software.Source,
"bundle_identifier", software.BundleIdentifier, "checksum", uuidString,
)
}
}
if len(insertsHostSoftware) > 0 {
values := strings.TrimSuffix(strings.Repeat("(?,?,?),", len(insertsHostSoftware)/3), ",")
sql := fmt.Sprintf(`INSERT IGNORE INTO host_software (host_id, software_id, last_opened_at) VALUES %s`, values)
if _, err := tx.ExecContext(ctx, sql, insertsHostSoftware...); err != nil {
return nil, ctxerr.Wrap(ctx, err, "insert host software")
}
}
return insertedSoftware, nil
}
func getSoftwareIDsByChecksums(ctx context.Context, tx sqlx.QueryerContext, checksums []string) ([]softwareIDChecksum, error) {
// get existing software ids for checksums
stmt, args, err := sqlx.In("SELECT id, checksum FROM software WHERE checksum IN (?)", checksums)
if err != nil {
return nil, ctxerr.Wrap(ctx, err, "build select software query")
}
var existingSoftware []softwareIDChecksum
if err = sqlx.SelectContext(ctx, tx, &existingSoftware, stmt, args...); err != nil {
return nil, ctxerr.Wrap(ctx, err, "get existing software")
}
return existingSoftware, nil
}
// update host_software when incoming software has a significantly more recent
// last opened timestamp (or didn't have on in currentMap). Note that it only
// processes software that is in both current and incoming maps, as the case
// where it is only in incoming is already handled by
// insertNewInstalledHostSoftwareDB.
func updateModifiedHostSoftwareDB(
ctx context.Context,
tx sqlx.ExtContext,
hostID uint,
currentMap map[string]fleet.Software,
incomingMap map[string]fleet.Software,
minLastOpenedAtDiff time.Duration,
) error {
var keysToUpdate []string
for key, newSw := range incomingMap {
curSw, ok := currentMap[key]
if !ok || newSw.LastOpenedAt == nil {
// software must also exist in current map, and new software must have a
// last opened at timestamp (otherwise we don't overwrite the old one)
continue
}
if curSw.LastOpenedAt == nil || newSw.LastOpenedAt.Sub(*curSw.LastOpenedAt) >= minLastOpenedAtDiff {
keysToUpdate = append(keysToUpdate, key)
}
}
sort.Strings(keysToUpdate)
for i := 0; i < len(keysToUpdate); i += softwareInsertBatchSize {
start := i
end := i + softwareInsertBatchSize
if end > len(keysToUpdate) {
end = len(keysToUpdate)
}
totalToProcess := end - start
const numberOfArgsPerSoftware = 3 // number of ? in each UPDATE
// Using UNION ALL (instead of UNION) because it is faster since it does not check for duplicates.
values := strings.TrimSuffix(
strings.Repeat(" SELECT ? as host_id, ? as software_id, ? as last_opened_at UNION ALL", totalToProcess), "UNION ALL",
)
stmt := fmt.Sprintf(
`UPDATE host_software hs JOIN (%s) a ON hs.host_id = a.host_id AND hs.software_id = a.software_id SET hs.last_opened_at = a.last_opened_at`,
values,
)
args := make([]interface{}, 0, totalToProcess*numberOfArgsPerSoftware)
for j := start; j < end; j++ {
key := keysToUpdate[j]
curSw, newSw := currentMap[key], incomingMap[key]
args = append(args, hostID, curSw.ID, newSw.LastOpenedAt)
}
if _, err := tx.ExecContext(ctx, stmt, args...); err != nil {
return ctxerr.Wrap(ctx, err, "update host software")
}
}
return nil
}
func updateSoftwareUpdatedAt(
ctx context.Context,
tx sqlx.ExtContext,
hostID uint,
) error {
const stmt = `INSERT INTO host_updates(host_id, software_updated_at) VALUES (?, CURRENT_TIMESTAMP) ON DUPLICATE KEY UPDATE software_updated_at=VALUES(software_updated_at)`
if _, err := tx.ExecContext(ctx, stmt, hostID); err != nil {
return ctxerr.Wrap(ctx, err, "update host updates")
}
return nil
}
var dialect = goqu.Dialect("mysql")
// listSoftwareDB returns software installed on hosts. Use opts for pagination, filtering, and controlling
// fields populated in the returned software.
func listSoftwareDB(
ctx context.Context,
q sqlx.QueryerContext,
opts fleet.SoftwareListOptions,
) ([]fleet.Software, error) {
sql, args, err := selectSoftwareSQL(opts)
if err != nil {
return nil, ctxerr.Wrap(ctx, err, "sql build")
}
var results []softwareCVE
if err := sqlx.SelectContext(ctx, q, &results, sql, args...); err != nil {
return nil, ctxerr.Wrap(ctx, err, "select host software")
}
var softwares []fleet.Software
ids := make(map[uint]int) // map of ids to index into softwares
for _, result := range results {
result := result // create a copy because we need to take the address to fields below
idx, ok := ids[result.ID]
if !ok {
idx = len(softwares)
softwares = append(softwares, result.Software)
ids[result.ID] = idx
}
// handle null cve from left join
if result.CVE != nil {
cveID := *result.CVE
cve := fleet.CVE{
CVE: cveID,
DetailsLink: fmt.Sprintf("https://nvd.nist.gov/vuln/detail/%s", cveID),
CreatedAt: *result.CreatedAt,
}
if opts.IncludeCVEScores && !opts.WithoutVulnerabilityDetails {
cve.CVSSScore = &result.CVSSScore
cve.EPSSProbability = &result.EPSSProbability
cve.CISAKnownExploit = &result.CISAKnownExploit
cve.CVEPublished = &result.CVEPublished
cve.Description = &result.Description
cve.ResolvedInVersion = &result.ResolvedInVersion
}
softwares[idx].Vulnerabilities = append(softwares[idx].Vulnerabilities, cve)
}
}
return softwares, nil
}
// softwareCVE is used for left joins with cve
//
//
type softwareCVE struct {
fleet.Software
// CVE is the CVE identifier pulled from the NVD json (e.g. CVE-2019-1234)
CVE *string `db:"cve"`
// CVSSScore is the CVSS score pulled from the NVD json (premium only)
CVSSScore *float64 `db:"cvss_score"`
// EPSSProbability is the EPSS probability pulled from FIRST (premium only)
EPSSProbability *float64 `db:"epss_probability"`
// CISAKnownExploit is the CISAKnownExploit pulled from CISA (premium only)
CISAKnownExploit *bool `db:"cisa_known_exploit"`
// CVEPublished is the CVE published date pulled from the NVD json (premium only)
CVEPublished *time.Time `db:"cve_published"`
// Description is the CVE description field pulled from the NVD json
Description *string `db:"description"`
// ResolvedInVersion is the version of software where the CVE is no longer applicable.
// This is pulled from the versionEndExcluding field in the NVD json
ResolvedInVersion *string `db:"resolved_in_version"`
// CreatedAt is the time the software vulnerability was created
CreatedAt *time.Time `db:"created_at"`
}
func selectSoftwareSQL(opts fleet.SoftwareListOptions) (string, []interface{}, error) {
ds := dialect.
From(goqu.I("software").As("s")).
Select(
"s.id",
"s.name",
"s.version",
"s.source",
"s.bundle_identifier",
"s.extension_id",
"s.browser",
"s.release",
"s.vendor",
"s.arch",
goqu.I("scp.cpe").As("generated_cpe"),
).
// Include this in the sub-query in case we want to sort by 'generated_cpe'
LeftJoin(
goqu.I("software_cpe").As("scp"),
goqu.On(
goqu.I("s.id").Eq(goqu.I("scp.software_id")),
),
)
if opts.HostID != nil {
ds = ds.
Join(
goqu.I("host_software").As("hs"),
goqu.On(
goqu.I("hs.software_id").Eq(goqu.I("s.id")),
goqu.I("hs.host_id").Eq(opts.HostID),
),
).