Skip to content

Commit 44e1cba

Browse files
committed
Add various queries to the performance tests.
1 parent 4a2f448 commit 44e1cba

File tree

1 file changed

+185
-6
lines changed

1 file changed

+185
-6
lines changed

dart/test/perf_test.dart

Lines changed: 185 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -18,9 +18,11 @@ void testFilesystemOperations(
1818
{bool unique = true,
1919
int count = 200000,
2020
int alreadyApplied = 10000,
21-
int buckets = 10}) {
21+
int buckets = 10,
22+
bool rawQueries = false}) {
2223
late TrackingFileSystem vfs;
2324
late CommonDatabase db;
25+
final skip = rawQueries == false ? 'For manual query testing only' : null;
2426

2527
setUpAll(() {
2628
loadExtension();
@@ -40,6 +42,8 @@ void testFilesystemOperations(
4042
});
4143

4244
setUp(() {
45+
// Optional: set a custom cache size - it affects the number of filesystem operations.
46+
// db.execute('PRAGMA cache_size=-50000');
4347
db.execute('SELECT powersync_replace_schema(?)', [json.encode(schema)]);
4448
// Generate dummy data
4549
// We can replace this with actual similated download operations later
@@ -78,7 +82,8 @@ FROM generate_bucket_rows;
7882
7983
COMMIT;
8084
''');
81-
print('init stats: ${vfs.stats()}');
85+
// Enable this to see stats for initial data generation
86+
// print('init stats: ${vfs.stats()}');
8287

8388
vfs.clearStats();
8489
});
@@ -109,26 +114,200 @@ COMMIT;
109114
expect(timer.elapsed,
110115
lessThan(Duration(milliseconds: 100 + (count / 50).round())));
111116
});
117+
118+
// The tests below are for comparing different queries, not run as part of the
119+
// standard test suite.
120+
121+
test('sync_local new query', () {
122+
// This query only uses a single TEMP B-TREE for the GROUP BY operation,
123+
// leading to fairly efficient execution.
124+
125+
// QUERY PLAN
126+
// |--CO-ROUTINE updated_rows
127+
// | `--COMPOUND QUERY
128+
// | |--LEFT-MOST SUBQUERY
129+
// | | |--SCAN buckets
130+
// | | `--SEARCH b USING INDEX ps_oplog_opid (bucket=? AND op_id>?)
131+
// | `--UNION ALL
132+
// | `--SCAN ps_updated_rows
133+
// |--SCAN b
134+
// |--USE TEMP B-TREE FOR GROUP BY
135+
// `--CORRELATED SCALAR SUBQUERY 3
136+
// `--SEARCH r USING INDEX ps_oplog_row (row_type=? AND row_id=?)
137+
138+
var timer = Stopwatch()..start();
139+
final q = '''
140+
WITH updated_rows AS (
141+
SELECT b.row_type, b.row_id FROM ps_buckets AS buckets
142+
CROSS JOIN ps_oplog AS b ON b.bucket = buckets.id
143+
AND (b.op_id > buckets.last_applied_op)
144+
UNION ALL SELECT row_type, row_id FROM ps_updated_rows
145+
)
146+
147+
SELECT
148+
b.row_type,
149+
b.row_id,
150+
(
151+
SELECT iif(max(r.op_id), r.data, null)
152+
FROM ps_oplog r
153+
WHERE r.row_type = b.row_type
154+
AND r.row_id = b.row_id
155+
156+
) as data
157+
FROM updated_rows b
158+
GROUP BY b.row_type, b.row_id;
159+
''';
160+
db.select(q);
161+
print('${timer.elapsed.inMilliseconds}ms ${vfs.stats()}');
162+
}, skip: skip);
163+
164+
test('old query', () {
165+
// This query used a TEMP B-TREE for the first part of finding unique updated rows,
166+
// then another TEMP B-TREE for the second GROUP BY. This redundant B-TREE causes
167+
// a lot of temporary storage overhead.
168+
169+
// QUERY PLAN
170+
// |--CO-ROUTINE updated_rows
171+
// | `--COMPOUND QUERY
172+
// | |--LEFT-MOST SUBQUERY
173+
// | | |--SCAN buckets
174+
// | | `--SEARCH b USING INDEX ps_oplog_opid (bucket=? AND op_id>?)
175+
// | `--UNION USING TEMP B-TREE
176+
// | `--SCAN ps_updated_rows
177+
// |--SCAN b
178+
// |--SEARCH r USING INDEX ps_oplog_row (row_type=? AND row_id=?) LEFT-JOIN
179+
// `--USE TEMP B-TREE FOR GROUP BY
180+
181+
var timer = Stopwatch()..start();
182+
final q = '''
183+
WITH updated_rows AS (
184+
SELECT DISTINCT b.row_type, b.row_id FROM ps_buckets AS buckets
185+
CROSS JOIN ps_oplog AS b ON b.bucket = buckets.id
186+
AND (b.op_id > buckets.last_applied_op)
187+
UNION SELECT row_type, row_id FROM ps_updated_rows
188+
)
189+
SELECT b.row_type as type,
190+
b.row_id as id,
191+
r.data as data,
192+
count(r.bucket) as buckets,
193+
max(r.op_id) as op_id
194+
FROM updated_rows b
195+
LEFT OUTER JOIN ps_oplog AS r
196+
ON r.row_type = b.row_type
197+
AND r.row_id = b.row_id
198+
GROUP BY b.row_type, b.row_id;
199+
''';
200+
db.select(q);
201+
print('${timer.elapsed.inMilliseconds}ms ${vfs.stats()}');
202+
}, skip: skip);
203+
204+
test('group_by query', () {
205+
// This is similar to the new query, but uses a GROUP BY .. LIMIT 1 clause instead of the max(op_id) hack.
206+
// It is similar in the number of filesystem operations, but slightly slower in real time.
207+
208+
// QUERY PLAN
209+
// |--CO-ROUTINE updated_rows
210+
// | `--COMPOUND QUERY
211+
// | |--LEFT-MOST SUBQUERY
212+
// | | |--SCAN buckets
213+
// | | `--SEARCH b USING INDEX ps_oplog_opid (bucket=? AND op_id>?)
214+
// | `--UNION ALL
215+
// | `--SCAN ps_updated_rows
216+
// |--SCAN b
217+
// |--USE TEMP B-TREE FOR GROUP BY
218+
// `--CORRELATED SCALAR SUBQUERY 3
219+
// |--SEARCH r USING INDEX ps_oplog_row (row_type=? AND row_id=?)
220+
// `--USE TEMP B-TREE FOR ORDER BY
221+
222+
var timer = Stopwatch()..start();
223+
final q = '''
224+
WITH updated_rows AS (
225+
SELECT b.row_type, b.row_id FROM ps_buckets AS buckets
226+
CROSS JOIN ps_oplog AS b ON b.bucket = buckets.id
227+
AND (b.op_id > buckets.last_applied_op)
228+
UNION ALL SELECT row_type, row_id FROM ps_updated_rows
229+
)
230+
231+
SELECT
232+
b.row_type,
233+
b.row_id,
234+
(
235+
SELECT r.data FROM ps_oplog r
236+
WHERE r.row_type = b.row_type
237+
AND r.row_id = b.row_id
238+
ORDER BY r.op_id DESC
239+
LIMIT 1
240+
241+
) as data
242+
FROM updated_rows b
243+
GROUP BY b.row_type, b.row_id;
244+
''';
245+
db.select(q);
246+
print('${timer.elapsed.inMilliseconds}ms ${vfs.stats()}');
247+
}, skip: skip);
248+
249+
test('full scan query', () {
250+
// This is a nice alternative for initial sync or resyncing large amounts of data.
251+
// This is very efficient for reading all data, but not for incremental updates.
252+
253+
// QUERY PLAN
254+
// |--SCAN r USING INDEX ps_oplog_row
255+
// |--CORRELATED SCALAR SUBQUERY 1
256+
// | `--SEARCH ps_buckets USING INTEGER PRIMARY KEY (rowid=?)
257+
// `--CORRELATED SCALAR SUBQUERY 1
258+
// `--SEARCH ps_buckets USING INTEGER PRIMARY KEY (rowid=?)
259+
260+
var timer = Stopwatch()..start();
261+
final q = '''
262+
SELECT r.row_type as type,
263+
r.row_id as id,
264+
r.data as data,
265+
max(r.op_id) as op_id,
266+
sum((select 1 from ps_buckets where ps_buckets.id = r.bucket and r.op_id > ps_buckets.last_applied_op)) as buckets
267+
268+
FROM ps_oplog r
269+
GROUP BY r.row_type, r.row_id
270+
HAVING buckets > 0;
271+
''';
272+
db.select(q);
273+
print('${timer.elapsed.inMilliseconds}ms ${vfs.stats()}');
274+
}, skip: skip);
112275
}
113276

114277
main() {
115278
group('test filesystem operations with unique ids', () {
116279
testFilesystemOperations(
117-
unique: true, count: 500000, alreadyApplied: 10000, buckets: 10);
280+
unique: true,
281+
count: 500000,
282+
alreadyApplied: 10000,
283+
buckets: 10,
284+
rawQueries: false);
118285
});
119286
group('test filesytem operations with duplicate ids', () {
120287
// If this takes more than a couple of milliseconds to complete, there is a performance bug
121288
testFilesystemOperations(
122-
unique: false, count: 5000, alreadyApplied: 1000, buckets: 10);
289+
unique: false,
290+
count: 500000,
291+
alreadyApplied: 1000,
292+
buckets: 10,
293+
rawQueries: false);
123294
});
124295

125296
group('test filesystem operations with a small number of changes', () {
126297
testFilesystemOperations(
127-
unique: true, count: 100000, alreadyApplied: 95000, buckets: 10);
298+
unique: true,
299+
count: 100000,
300+
alreadyApplied: 95000,
301+
buckets: 10,
302+
rawQueries: false);
128303
});
129304

130305
group('test filesystem operations with a large number of buckets', () {
131306
testFilesystemOperations(
132-
unique: true, count: 100000, alreadyApplied: 10000, buckets: 1000);
307+
unique: true,
308+
count: 100000,
309+
alreadyApplied: 10000,
310+
buckets: 1000,
311+
rawQueries: false);
133312
});
134313
}

0 commit comments

Comments
 (0)