forked from Velocidex/SQLiteHunter
-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Loading branch information
Showing
20 changed files
with
854 additions
and
0 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,28 @@ | ||
package api | ||
|
||
type ConfigDefinitions struct { | ||
Globs map[string][]string `yaml:"Globs"` | ||
} | ||
|
||
type Definition struct { | ||
Name string `yaml:"Name"` | ||
Author string `yaml:"Author"` | ||
Email string `yaml:"Email"` | ||
Category string `yaml:"Category"` | ||
SQLiteIdentifyQuery string `yaml:"SQLiteIdentifyQuery"` | ||
SQLiteIdentifyValue interface{} `yaml:"SQLiteIdentifyValue"` | ||
Globs []string `yaml:"Globs"` | ||
FilenameRegex string `yaml:"FilenameRegex"` | ||
Sources []Source `yaml:"Sources"` | ||
} | ||
|
||
type Source struct { | ||
Name string `yaml:"name"` | ||
// Specialized VQL to post process the rows. Default is a | ||
// passthrough `SELECT * FROM Rows` | ||
VQL string `yaml:"VQL"` | ||
SQL string `yaml:"SQL"` | ||
SQLiteIdentifyQuery string `json:"id_query"` | ||
SQLiteIdentifyValue interface{} `json:"id_value"` | ||
Filename string `json:"filename"` | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,18 @@ | ||
package api | ||
|
||
import "github.com/Velocidex/ordereddict" | ||
|
||
// This is the main data structure that will be used by the | ||
// application. | ||
type Spec struct { | ||
Globs []GlobSpec `json:"globs"` | ||
|
||
// map[string]Source | ||
Sources *ordereddict.Dict `json:"sources"` | ||
} | ||
|
||
type GlobSpec struct { | ||
Glob string `json:"glob"` | ||
Tag string `json:"tag"` | ||
Filename string `json:"name"` | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,134 @@ | ||
package compile | ||
|
||
import ( | ||
"bytes" | ||
"compress/gzip" | ||
"encoding/base64" | ||
"encoding/json" | ||
"fmt" | ||
"strings" | ||
|
||
"github.com/Velocidex/SQLiteHunter/api" | ||
"github.com/Velocidex/SQLiteHunter/utils" | ||
) | ||
|
||
// Produce the YAML of the artifact definition. | ||
func (self *Artifact) Yaml() string { | ||
return fmt.Sprintf(` | ||
name: %v | ||
description: %v | ||
export: | | ||
LET SPEC <= %q | ||
LET Specs <= parse_json(data=gunzip(string=base64decode(string=SPEC))) | ||
LET _ <= log(message="%%v", args=str(str=gunzip(string=base64decode(string=SPEC)))) | ||
LET CheckHeader(OSPath) = read_file(filename=OSPath, length=12) = "SQLite forma" | ||
LET Bool(Value) = if(condition=Value, then="Yes", else="No") | ||
-- In fast mode we check the filename, then the header then run the sqlite precondition | ||
LET matchFilename(SourceName, OSPath) = OSPath =~ get(item=Specs.sources, field=SourceName).filename | ||
AND CheckHeader(OSPath=OSPath) | ||
AND Identify(SourceName= SourceName, OSPath= OSPath) | ||
AND log(message=format(format="%%v matched by filename %%v", | ||
args=[OSPath, get(item=Specs.sources, field=SourceName).filename])) | ||
LET Identify(SourceName, OSPath) = SELECT if( | ||
condition=CheckHeader(OSPath=OSPath), | ||
then={ | ||
SELECT * | ||
FROM sqlite(file=OSPath, query=get(item=Specs.sources, field=SourceName).id_query) | ||
}) AS Hits | ||
FROM scope() | ||
WHERE if(condition=Hits[0].Check = get(item=Specs.sources, field=SourceName).id_value, | ||
then= log(message="%%v was identified as %%v", | ||
args=[OSPath, get(item=Specs.sources, field=SourceName).Name]), | ||
else=log(message="%%v was not identified as %%v (got %%v, wanted %%v)", | ||
args=[OSPath, get(item=Specs.sources, field=SourceName).Name, str(str=Hits), | ||
get(item=Specs.sources, field=SourceName).id_value]) AND FALSE) | ||
LET ApplyFile(SourceName) = SELECT * FROM foreach(row={ | ||
SELECT OSPath FROM AllFiles | ||
WHERE if(condition=MatchFilename, then=matchFilename(SourceName=SourceName, OSPath=OSPath), | ||
else=Identify(SourceName= SourceName, OSPath= OSPath)) | ||
}, query={ | ||
SELECT * FROM sqlite( | ||
file=OSPath, query=get(item=Specs.sources, field=SourceName).SQL) | ||
}) | ||
LET category_regex <= join(sep="|", array=Category) | ||
LET AllGlobs <= filter(list=Specs.globs, condition="x=> x.tag =~ category_regex") | ||
LET _ <= log(message="Globs for category %%v is %%v", args=[category_regex, CustomGlob || AllGlobs.glob]) | ||
LET AllFiles <= SELECT OSPath FROM glob(globs=CustomGlob || AllGlobs.glob) | ||
WHERE NOT IsDir | ||
parameters: | ||
- name: MatchFilename | ||
description: | | ||
If set we use the filename to detect the type of sqlite file. | ||
When unset we use heristics (slower) | ||
type: bool | ||
default: Y | ||
- name: CustomGlob | ||
description: Specify this glob to select other files | ||
- name: Category | ||
type: multichoice | ||
default: %q | ||
choices: | ||
%v | ||
- name: SQLITE_ALWAYS_MAKE_TEMPFILE | ||
type: bool | ||
default: Y | ||
sources: | ||
- name: AllFiles | ||
query: | | ||
SELECT * FROM AllFiles | ||
%v | ||
`, self.Name, self.Description, | ||
self.encodeSpec(), utils.MustMarshalString(self.Category.Keys()), | ||
self.getParameters(), | ||
self.getSources()) | ||
} | ||
|
||
func (self *Artifact) encodeSpec() string { | ||
serialized, _ := json.Marshal(self.Spec) | ||
|
||
// Compress the string | ||
var b bytes.Buffer | ||
gz := gzip.NewWriter(&b) | ||
gz.Write(serialized) | ||
gz.Close() | ||
return base64.StdEncoding.EncodeToString(b.Bytes()) | ||
} | ||
|
||
func (self *Artifact) getParameters() string { | ||
res := []string{} | ||
for _, k := range self.Category.Keys() { | ||
res = append(res, fmt.Sprintf(` - %v`, k)) | ||
} | ||
return strings.Join(res, "\n") | ||
} | ||
|
||
func (self *Artifact) getSources() string { | ||
res := []string{} | ||
for _, k := range self.Spec.Sources.Keys() { | ||
v_any, _ := self.Spec.Sources.Get(k) | ||
v, ok := v_any.(api.Source) | ||
if !ok { | ||
continue | ||
} | ||
res = append(res, fmt.Sprintf(` | ||
- name: %v | ||
query: | | ||
LET Rows = SELECT * FROM ApplyFile(SourceName=%q) | ||
%v | ||
`, k, k, indent(v.VQL, 4))) | ||
} | ||
return strings.Join(res, "\n") | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,73 @@ | ||
package compile | ||
|
||
import ( | ||
"fmt" | ||
|
||
"github.com/Velocidex/SQLiteHunter/api" | ||
"github.com/Velocidex/SQLiteHunter/definitions" | ||
"github.com/Velocidex/ordereddict" | ||
) | ||
|
||
type Artifact struct { | ||
Spec api.Spec | ||
Name, Description string | ||
Category *ordereddict.Dict | ||
Sources []api.Definition | ||
} | ||
|
||
func newArtifact() *Artifact { | ||
return &Artifact{ | ||
Name: "Generic.Forensic.SQLiteHunter", | ||
Description: "Hunt for SQLite files", | ||
Category: ordereddict.NewDict(), | ||
Spec: api.Spec{ | ||
Sources: ordereddict.NewDict(), | ||
}, | ||
} | ||
} | ||
|
||
// Build the spec and artifact | ||
func Compile(defs []api.Definition, | ||
config_obj *api.ConfigDefinitions) (*Artifact, error) { | ||
|
||
res := newArtifact() | ||
for _, d := range defs { | ||
category := d.Category | ||
if category == "" { | ||
category = "Misc" | ||
} | ||
res.Category.Set(category, true) | ||
globs := definitions.ExpandGlobs(d, config_obj) | ||
for _, g := range globs { | ||
res.Spec.Globs = append(res.Spec.Globs, api.GlobSpec{ | ||
Glob: g, | ||
Tag: category, | ||
Filename: d.FilenameRegex, | ||
}) | ||
} | ||
|
||
// Each definition can contain multiple queries. Each such | ||
// query ends up in a separate source. | ||
for idx, s := range d.Sources { | ||
// Calculate a unique name for the source | ||
name := s.Name | ||
if name == "" { | ||
name = fmt.Sprintf("%v", idx) | ||
} | ||
|
||
s.Name = d.Name + "_" + name | ||
if s.SQLiteIdentifyQuery == "" { | ||
s.SQLiteIdentifyQuery = d.SQLiteIdentifyQuery | ||
} | ||
|
||
if s.SQLiteIdentifyValue == nil { | ||
s.SQLiteIdentifyValue = d.SQLiteIdentifyValue | ||
} | ||
|
||
s.Filename = d.FilenameRegex | ||
res.Spec.Sources.Update(s.Name, s) | ||
} | ||
} | ||
|
||
return res, nil | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,14 @@ | ||
package compile | ||
|
||
import ( | ||
"strings" | ||
) | ||
|
||
func indent(in string, indent int) string { | ||
lines := strings.Split(in, "\n") | ||
result := []string{} | ||
for _, l := range lines { | ||
result = append(result, strings.Repeat(" ", indent)+l) | ||
} | ||
return strings.Join(result, "\n") | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,7 @@ | ||
Globs: | ||
LinuxChromeProfiles: | ||
- /home/*/.config/{google-chrome,chrome-remote-desktop/chrome-profile,chromium}/** | ||
WindowsChromeProfiles: | ||
- C:\Users\*\AppData\Local\Google\Chrome\User Data\*\** | ||
MacOSChromeProfiles: | ||
- /Users/*/Library/Application Support/{BraveSoftware/Brave,Google/Chrome,Microsoft Edge}/** |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,54 @@ | ||
Name: Chromium Browser Autofill | ||
Author: Andrew Rathbun | ||
Email: [email protected] | ||
SQLiteIdentifyQuery: SELECT count(*) AS `Check` FROM sqlite_master WHERE type='table' AND (name='autofill' OR name='credit_cards' OR name='offer_data' OR name='server_addresses' OR name='keywords'); | ||
SQLiteIdentifyValue: 5 | ||
FilenameRegex: "Web Data" | ||
Globs: | ||
- "{{LinuxChromeProfiles}}/**/Web Data" | ||
- "{{WindowsChromeProfiles}}/**/Web Data" | ||
- "{{MacOSChromeProfiles}}/**/Web Data" | ||
|
||
Sources: | ||
- name: Profiles | ||
VQL: "SELECT * FROM Rows" | ||
SQL: | | ||
SELECT | ||
autofill_profiles.guid AS GUID, | ||
datetime( "date_modified", 'unixepoch' ) AS DateModified, | ||
datetime( "use_date", 'unixepoch' ) AS UseDate, | ||
autofill_profile_names.first_name AS FirstName, | ||
autofill_profile_names.middle_name AS MiddleName, | ||
autofill_profile_names.last_name AS LastName, | ||
autofill_profile_emails.email as EmailAddress, | ||
autofill_profile_phones.number AS PhoneNumber, | ||
autofill_profiles.company_name AS CompanyName, | ||
autofill_profiles.street_address AS StreetAddress, | ||
autofill_profiles.city AS City, | ||
autofill_profiles.state AS State, | ||
autofill_profiles.zipcode AS ZipCode, | ||
autofill_profiles.use_count AS UseCount | ||
FROM | ||
autofill_profiles | ||
INNER JOIN autofill_profile_emails ON autofill_profile_emails.guid = autofill_profiles.guid | ||
INNER JOIN autofill_profile_phones ON autofill_profiles.guid = autofill_profile_phones.guid | ||
INNER JOIN autofill_profile_names ON autofill_profile_phones.guid = autofill_profile_names.guid | ||
ORDER BY | ||
autofill_profiles.guid ASC | ||
- name: Masked Credit Cards | ||
VQL: "SELECT * FROM Rows" | ||
SQL: | | ||
SELECT | ||
masked_credit_cards.id AS ID, | ||
masked_credit_cards.status AS Status, | ||
masked_credit_cards.name_on_card AS NameOnCard, | ||
masked_credit_cards.network AS CardNetwork, | ||
masked_credit_cards.last_four AS LastFour, | ||
masked_credit_cards.exp_month AS ExpMonth, | ||
masked_credit_cards.exp_year AS ExpYear, | ||
masked_credit_cards.bank_name AS BankName, | ||
masked_credit_cards.nickname AS CardNickname, | ||
masked_credit_cards.card_issuer AS CardIssuer, | ||
masked_credit_cards.instrument_id AS InstrumentID | ||
FROM masked_credit_cards | ||
ORDER BY masked_credit_cards.id ASC |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,42 @@ | ||
Name: Chromium Browser | ||
Author: Andrew Rathbun | ||
Email: [email protected] | ||
SQLiteIdentifyQuery: | | ||
SELECT count(*) AS `Check` | ||
FROM sqlite_master WHERE type='table' AND (name='cookies' OR name='meta'); | ||
SQLiteIdentifyValue: 2 | ||
FilenameRegex: "Cookies" | ||
Globs: | ||
- "{{LinuxChromeProfiles}}/**/Cookies" | ||
- "{{WindowsChromeProfiles}}/**/Cookies" | ||
- "{{MacOSChromeProfiles}}/**/Cookies" | ||
|
||
Sources: | ||
- name: Cookies | ||
VQL: | | ||
SELECT timestamp(winfiletime=creation_utc * 10) AS CreationUTC, | ||
timestamp(winfiletime=expires_utc * 10) AS ExpiresUTC, | ||
timestamp(winfiletime=last_access_utc * 10) AS LastAccessUTC, | ||
HostKey, Name, Path, | ||
Bool(Value=is_secure) AS IsSecure, | ||
Bool(Value=is_httponly) AS IsHttpOnly, | ||
Bool(Value=has_expires) AS HasExpiration, | ||
Bool(Value=is_persistent) AS IsPersistent, | ||
Priority, SourcePort | ||
FROM Rows | ||
SQL: | | ||
SELECT | ||
cookies.creation_utc, | ||
cookies.expires_utc, | ||
cookies.last_access_utc, | ||
cookies.host_key AS HostKey, | ||
cookies.name AS Name, | ||
cookies.path AS Path, | ||
cookies.is_secure, | ||
cookies.is_httponly, | ||
cookies.has_expires, | ||
cookies.is_persistent, | ||
cookies.priority AS Priority, | ||
cookies.source_port AS SourcePort | ||
FROM cookies | ||
ORDER BY cookies.creation_utc ASC |
Oops, something went wrong.