Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

perf: Add foreign key indexes to tables #887

Open
wants to merge 2 commits into
base: main
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
35 changes: 33 additions & 2 deletions db-service/lib/SQLService.js
Original file line number Diff line number Diff line change
Expand Up @@ -294,8 +294,39 @@ class SQLService extends DatabaseService {
DEBUG?.(query, data)
const ps = await this.prepare(query)
const exec = this.hasResults(query) ? d => ps.all(d) : d => ps.run(d)
if (Array.isArray(data) && Array.isArray(data[0])) return await Promise.all(data.map(exec))
else return exec(data)
let ret
if (Array.isArray(data) && Array.isArray(data[0])) ret = await Promise.all(data.map(exec))
else ret = await exec(data)

// Leverage modeling structure to create table indexes
if (this.model && /^\s*CREATE TABLE/i.test(query)) {
// Extracts the name from the incoming SQL statment
const name = query.match(/^CREATE TABLE ("[^"]+"|[^\s(]+)/im)[1]
// Replaces all '_' with '.' from left to right
const split = name.split('_')
const options = split.map((_, i) => split.slice(0, i + 1).join('.') + '.' + split.slice(i + 1).join('_'))
// Finds the first match inside the model
const target = options.find(n => this.model.definitions[n])

// if target definition is found create foreign key indexes
if (target) {
// Create indexes for foreign key columns
const cqn2sql = new this.constructor.CQN2SQL(this)
const indexes = {}
const entity = this.model.definitions[target]
for (const e in entity.elements) {
const element = entity.elements[e]
const assoc = element._foreignKey4
if (!assoc || element.virtual) continue
(indexes[assoc] ??= []).push(cqn2sql.quote(element.name))
}
for (const assocName in indexes) {
await this.exec(`CREATE INDEX ${cqn2sql.quote(name + '_' + assocName)} on ${cqn2sql.quote(name)} (${indexes[assocName]})`)
}
}
}

return ret
} else return next()
}

Expand Down
20 changes: 10 additions & 10 deletions test/scenarios/bookshop/read.test.js
Original file line number Diff line number Diff line change
Expand Up @@ -55,10 +55,10 @@ describe('Bookshop - Read', () => {
expect(res.data.value.length).to.be.eq(4) // As there are two books which have the same author
expect(
res.data.value.every(
item =>
'author' in item &&
'ID' in item.author && // foreign key is renamed to element name in target
!('author_ID' in item.author),
item =>
'author' in item &&
'ID' in item.author && // foreign key is renamed to element name in target
!('author_ID' in item.author),
),
).to.be.true
})
Expand Down Expand Up @@ -355,18 +355,18 @@ describe('Bookshop - Read', () => {
})

it('allows filtering with between operator', async () => {
const query = SELECT.from('sap.capire.bookshop.Books', ['ID', 'stock']).where ({ stock: { between: 0, and: 100 } })
const query = SELECT.from('sap.capire.bookshop.Books', ['ID', 'stock']).where({ stock: { between: 0, and: 100 } })

return expect((await query).every(row => row.stock >=0 && row.stock <=100)).to.be.true
return expect((await query).every(row => row.stock >= 0 && row.stock <= 100)).to.be.true
})

it('allows various mechanisms for expressing "not in"', async () => {
const results = await cds.db.run([
SELECT.from('sap.capire.bookshop.Books', ['ID']).where({ ID: { 'not in': [201, 251] } }),
SELECT.from('sap.capire.bookshop.Books', ['ID']).where({ ID: { not: { in: [201, 251] } } }),
SELECT.from('sap.capire.bookshop.Books', ['ID']).where('ID not in', [201, 251])
SELECT.from('sap.capire.bookshop.Books', ['ID']).where({ ID: { 'not in': [201, 251] } }).orderBy('ID'),
SELECT.from('sap.capire.bookshop.Books', ['ID']).where({ ID: { not: { in: [201, 251] } } }).orderBy('ID'),
SELECT.from('sap.capire.bookshop.Books', ['ID']).where('ID not in', [201, 251]).orderBy('ID')
])

for (const row of results) expect(row).to.deep.eq([{ID: 207},{ID: 252},{ID: 271}])
for (const result of results) expect(result).to.deep.eq([{ ID: 207 }, { ID: 252 }, { ID: 271 }])
})
})