Skip to content

Commit

Permalink
Merge pull request #13 from DataDog/zhengda.lu/oracle
Browse files Browse the repository at this point in the history
scan bind parameter & test cases for oracle
  • Loading branch information
lu-zhengda authored Sep 22, 2023
2 parents b222cba + 4f1b611 commit 5973eba
Show file tree
Hide file tree
Showing 6 changed files with 174 additions and 6 deletions.
9 changes: 9 additions & 0 deletions normalizer_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -298,6 +298,15 @@ multiline comment */
Commands: []string{"SELECT"},
},
},
{
input: "/* ok comment */ UPDATE /*foo comment*/ table_name SET column_name = ? WHERE column_name = ?",
expected: "UPDATE table_name SET column_name = ? WHERE column_name = ?",
statementMetadata: StatementMetadata{
Tables: []string{"table_name"},
Comments: []string{"/* ok comment */", "/*foo comment*/"},
Commands: []string{"UPDATE"},
},
},
}

normalizer := NewNormalizer(
Expand Down
58 changes: 57 additions & 1 deletion obfuscate_and_normalize_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,7 @@ func TestObfuscationAndNormalization(t *testing.T) {
input string
expected string
statementMetadata StatementMetadata
lexerOpts []lexerOption
}{
{
input: "SELECT 1",
Expand Down Expand Up @@ -88,6 +89,61 @@ multiline comment */
Commands: []string{"SELECT"},
},
},
{
input: "SELECT TRUNC(SYSDATE@!) from dual",
expected: "SELECT TRUNC ( SYSDATE @! ) from dual",
statementMetadata: StatementMetadata{
Tables: []string{"dual"},
Comments: []string{},
Commands: []string{"SELECT"},
},
lexerOpts: []lexerOption{
WithDBMS(DBMSOracle),
},
},
{
input: `
select sql_fulltext from v$sql where force_matching_signature = 1033183797897134935
GROUP BY c.name, force_matching_signature, plan_hash_value
HAVING MAX(last_active_time) > sysdate - :seconds/24/60/60
FETCH FIRST :limit ROWS ONLY`,
expected: "select sql_fulltext from v$sql where force_matching_signature = ? GROUP BY c.name, force_matching_signature, plan_hash_value HAVING MAX ( last_active_time ) > sysdate - :seconds / ? / ? / ? FETCH FIRST :limit ROWS ONLY",
statementMetadata: StatementMetadata{
Tables: []string{"v$sql"},
Comments: []string{},
Commands: []string{"SELECT"},
},
lexerOpts: []lexerOption{
WithDBMS(DBMSOracle),
},
},
{
input: "SELECT TABLESPACE_NAME, USED_SPACE, TABLESPACE_SIZE, USED_PERCENT FROM SYS.DBA_TABLESPACE_USAGE_METRICS K WHERE USED_PERCENT > 85",
expected: `SELECT TABLESPACE_NAME, USED_SPACE, TABLESPACE_SIZE, USED_PERCENT FROM SYS.DBA_TABLESPACE_USAGE_METRICS K WHERE USED_PERCENT > ?`,
statementMetadata: StatementMetadata{
Tables: []string{"SYS.DBA_TABLESPACE_USAGE_METRICS"},
Comments: []string{},
Commands: []string{"SELECT"},
},
},
{
input: "SELECT dbms_lob.substr(sql_fulltext, 4000, 1) sql_fulltext FROM sys.dd_session",
expected: "SELECT dbms_lob.substr ( sql_fulltext, ?, ? ) sql_fulltext FROM sys.dd_session",
statementMetadata: StatementMetadata{
Tables: []string{"sys.dd_session"},
Comments: []string{},
Commands: []string{"SELECT"},
},
},
{
input: "begin execute immediate 'alter session set sql_trace=true'; end;",
expected: "begin execute immediate ? ; end ;",
statementMetadata: StatementMetadata{
Tables: []string{},
Comments: []string{},
Commands: []string{"BEGIN", "EXECUTE"},
},
},
}

obfuscator := NewObfuscator(
Expand All @@ -104,7 +160,7 @@ multiline comment */

for _, test := range tests {
t.Run("", func(t *testing.T) {
got, statementMetadata, err := ObfuscateAndNormalize(test.input, obfuscator, normalizer)
got, statementMetadata, err := ObfuscateAndNormalize(test.input, obfuscator, normalizer, test.lexerOpts...)
assert.NoError(t, err)
assert.Equal(t, test.expected, got)
assert.Equal(t, &test.statementMetadata, statementMetadata)
Expand Down
32 changes: 32 additions & 0 deletions obfuscator_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -366,6 +366,38 @@ func TestObfuscator(t *testing.T) {
OUTPUT $action, inserted.*, deleted.*;`,
dbms: DBMSSQLServer,
},
{
input: "SELECT TRUNC(SYSDATE@!) from dual",
expected: "SELECT TRUNC(SYSDATE@!) from dual",
dbms: DBMSOracle,
},
{
input: `
select sql_fulltext from v$sql where force_matching_signature = 1033183797897134935
GROUP BY c.name, force_matching_signature, plan_hash_value
HAVING MAX(last_active_time) > sysdate - :seconds/24/60/60
FETCH FIRST :limit ROWS ONLY`,
expected: `select sql_fulltext from v$sql where force_matching_signature = ?
GROUP BY c.name, force_matching_signature, plan_hash_value
HAVING MAX(last_active_time) > sysdate - :seconds/?/?/?
FETCH FIRST :limit ROWS ONLY`,
dbms: DBMSOracle,
},
{
input: "SELECT TABLESPACE_NAME, USED_SPACE, TABLESPACE_SIZE, USED_PERCENT FROM SYS.DBA_TABLESPACE_USAGE_METRICS K WHERE USED_PERCENT > 85",
expected: `SELECT TABLESPACE_NAME, USED_SPACE, TABLESPACE_SIZE, USED_PERCENT FROM SYS.DBA_TABLESPACE_USAGE_METRICS K WHERE USED_PERCENT > ?`,
dbms: DBMSOracle,
},
{
input: "SELECT dbms_lob.substr(sql_fulltext, 4000, 1) sql_fulltext FROM sys.dd_session",
expected: `SELECT dbms_lob.substr(sql_fulltext, ?, ?) sql_fulltext FROM sys.dd_session`,
dbms: DBMSOracle,
},
{
input: "begin execute immediate 'alter session set sql_trace=true'; end;",
expected: "begin execute immediate ?; end;",
dbms: DBMSOracle,
},
}

for _, tt := range tests {
Expand Down
25 changes: 24 additions & 1 deletion sqllexer.go
Original file line number Diff line number Diff line change
Expand Up @@ -18,6 +18,7 @@ const (
DOLLAR_QUOTED_FUNCTION // dollar quoted function
DOLLAR_QUOTED_STRING // dollar quoted string
POSITIONAL_PARAMETER // numbered parameter
BIND_PARAMETER // bind parameter
UNKNOWN // unknown token
)

Expand Down Expand Up @@ -127,6 +128,16 @@ func (s *Lexer) Scan() Token {
return s.scanIdentifier()
}
return s.scanDollarQuotedString()
case ch == ':':
if s.config.DBMS == DBMSOracle && isLetter(s.lookAhead(1)) {
return s.scanBindParameter()
}
return s.scanOperator()
case ch == '@':
if s.config.DBMS == DBMSSQLServer && isLetter(s.lookAhead(1)) {
return s.scanBindParameter()
}
return s.scanOperator()
case isOperator(ch):
return s.scanOperator()
case isPunctuation(ch):
Expand Down Expand Up @@ -278,7 +289,7 @@ func (s *Lexer) scanIdentifier() Token {
// NOTE: this func does not distinguish between SQL keywords and identifiers
s.start = s.cursor
ch := s.next()
for isLetter(ch) || isDigit(ch) || ch == '.' || ch == '?' {
for isLetter(ch) || isDigit(ch) || ch == '.' || ch == '?' || ch == '$' {
ch = s.next()
}
// return the token as uppercase so that we can do case insensitive matching
Expand Down Expand Up @@ -405,6 +416,18 @@ func (s *Lexer) scanPositionalParameter() Token {
return Token{POSITIONAL_PARAMETER, s.src[s.start:s.cursor]}
}

func (s *Lexer) scanBindParameter() Token {
s.start = s.cursor
ch := s.nextBy(2) // consume the (colon|at sign) and the char
for {
if !isLetter(ch) {
break
}
ch = s.next()
}
return Token{BIND_PARAMETER, s.src[s.start:s.cursor]}
}

func (s *Lexer) scanUnknown() Token {
// When we see an unknown token, we advance the cursor until we see something that looks like a token boundary.
s.start = s.cursor
Expand Down
53 changes: 49 additions & 4 deletions sqllexer_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -9,9 +9,10 @@ import (

func TestLexer(t *testing.T) {
tests := []struct {
name string
input string
expected []Token
name string
input string
expected []Token
lexerOpts []lexerOption
}{
{
name: "simple select with number",
Expand Down Expand Up @@ -469,11 +470,55 @@ func TestLexer(t *testing.T) {
{OPERATOR, "?"},
},
},
{
name: "select with bind parameter",
input: "SELECT * FROM users where id = :id",
expected: []Token{
{IDENT, "SELECT"},
{WS, " "},
{WILDCARD, "*"},
{WS, " "},
{IDENT, "FROM"},
{WS, " "},
{IDENT, "users"},
{WS, " "},
{IDENT, "where"},
{WS, " "},
{IDENT, "id"},
{WS, " "},
{OPERATOR, "="},
{WS, " "},
{BIND_PARAMETER, ":id"},
},
lexerOpts: []lexerOption{WithDBMS(DBMSOracle)},
},
{
name: "select with bind parameter",
input: "SELECT * FROM users where id = @id",
expected: []Token{
{IDENT, "SELECT"},
{WS, " "},
{WILDCARD, "*"},
{WS, " "},
{IDENT, "FROM"},
{WS, " "},
{IDENT, "users"},
{WS, " "},
{IDENT, "where"},
{WS, " "},
{IDENT, "id"},
{WS, " "},
{OPERATOR, "="},
{WS, " "},
{BIND_PARAMETER, "@id"},
},
lexerOpts: []lexerOption{WithDBMS(DBMSSQLServer)},
},
}

for _, tt := range tests {
t.Run(tt.name, func(t *testing.T) {
lexer := New(tt.input)
lexer := New(tt.input, tt.lexerOpts...)
tokens := lexer.ScanAll()
assert.Equal(t, tt.expected, tokens)
})
Expand Down
3 changes: 3 additions & 0 deletions sqllexer_utils.go
Original file line number Diff line number Diff line change
Expand Up @@ -34,6 +34,9 @@ var Commands = map[string]bool{
"BEGIN": true,
"TRUNCATE": true,
"MERGE": true,
"EXECUTE": true,
"EXEC": true,
"EXPLAIN": true,
}

var tableIndicators = map[string]bool{
Expand Down

0 comments on commit 5973eba

Please sign in to comment.