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

Add Postgres.js #55

Open
wants to merge 4 commits into
base: master
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
2 changes: 1 addition & 1 deletion Makefile
Original file line number Diff line number Diff line change
Expand Up @@ -298,7 +298,7 @@ run-py:
$(RUNNER) --html docs/py.html --json docs/py.json django sqlalchemy edgedb_py_sync

run-sql:
$(RUNNER) --html docs/sql.html --json docs/sql.json edgedb_py_sync postgres_psycopg postgres_asyncpg postgres_pg postgres_pgx
$(RUNNER) --html docs/sql.html --json docs/sql.json edgedb_py_sync postgres_psycopg postgres_asyncpg postgresjs postgres_pg postgres_pgx

run-graphql:
$(RUNNER) --html docs/py.html --json docs/py.json postgres_hasura_go postgres_postgraphile_go edgedb_go_graphql
Expand Down
239 changes: 239 additions & 0 deletions _postgresjs/index.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,239 @@
/* eslint max-len: 0 */

const postgres = require('postgres')

module.exports = function(options) {
const concurrency = options.max
const INSERT_PREFIX = 'insert_test__'
const sql = postgres({
fetch_types: false,
user: 'postgres_bench',
host: 'localhost',
database: 'postgres_bench',
password: 'edgedbbenchmark',
port: 15432,
...(options || {})
})

const queries = {
get_user,
get_person,
get_movie,
update_movie,
insert_user,
insert_movie,
insert_movie_plus
}

const api = {
benchQuery: (name, id) => queries[name](id),
connect: () => sql`select 1`,
getConnection: () => api,
getIDs,
setup,
cleanup
}

return api

async function get_user(id) {
const [user] = await sql`
select
u.id,
u.name,
u.image,
json_agg(q) as latest_reviews
from users u, lateral (
select
r.id as review_id,
r.body as review_body,
r.rating as review_rating,
json_build_object(
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Other implementations aren't using in-database JSON encoding, so this wouldn't be a fair comparison of binding performance. See also #48 (comment)

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Is postgres.js capable of decoding arrays and tuples? If so, I'd use the asyncpg queries for fairness.

Copy link
Author

@porsager porsager Jun 9, 2022

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@elprans it does arrays but not record tuples. I did do a query assembling things in the client just like the go example, but it didn't do any performance difference (i actually think it was a bit faster). In my opinion I think using json in the query is more fair, since PostgreSQL can do so much more - so if you want to honestly compare eg EdgeDB queries to PostgreSQL - choose the best from both worlds. I can change it to match the go query or asyncpg, but I think it would make more sense to maybe change them to use this query instead? I might be biased since I want to stay as close to the "native" queries as possible, which I guess is also part of your reasons for making EdgeDB?

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The issue is that JSON strips rich type information, e.g. instead of a proper Date object for a timestamp column, you get a string, etc, which is significantly less useful for application code. This isn't entirely obvious here, because the current benchmark code just serializes things back to JSON, but it's an important aspect nonetheless.

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

We can add a variation of each query that returns JSON directly, if supported. In fact, EdgeDB explicitly supports database-side JSON encoding of results of arbitrary queries.

'id', m.id,
'image', m.image,
'title', m.title,
'avg_rating', m.avg_rating::float
) as movie
from reviews as r
inner join movies as m on (r.movie_id = m.id)
where r.author_id = u.id
order by r.creation_time desc
limit 10
) as q
where u.id = ${ id }
group by u.id
`

return user
}

async function get_movie(id) {
const [x] = await sql`
select
m.id,
m.image,
m.title,
m.year,
m.description,
m.avg_rating::float,
(
select
json_agg(q)
from (
select p.id, p.full_name, p.image
from directors
join persons p on (directors.person_id = p.id)
where directors.movie_id = m.id
order by directors.list_order nulls last, p.last_name
) q
) directors,
(
select
json_agg(q)
from (
select p.id, p.full_name, p.image
from actors
join persons p on actors.person_id = p.id
where actors.movie_id = m.id
order by actors.list_order nulls last, p.last_name
) q
) actors,
(
select
json_agg(q)
from (
select r.id, r.body, r.rating,
json_build_object(
'id', a.id,
'name', a.name,
'image', a.image
) author
from reviews r
join users a on r.author_id = a.id
where r.movie_id = m.id
order by r.creation_time desc
) q
) reviews
from movies m
where id = ${ id }
`

return x
}

async function insert_movie(val) {
const num = Math.floor(Math.random() * 1000000)
const [user] = await sql`
with m as (
insert into movies (title, image, description, year)
values (
${ val.prefix + num },
${ val.prefix + 'image' + num + '.jpeg' },
${ val.prefix + 'description' + num },
${ num }
)
returning id, title, image, description, year
), d as (
select
id,
p.full_name,
image
from persons p
where id = ${ val.people[0] }
), c as (
select
id,
p.full_name,
image
from persons p
where id in (${ val.people[1] }, ${ val.people[1] }, ${ val.people[1] })
), dl as (
insert into directors (person_id, movie_id)
(select d.id, m.id from m, d)
), cl as (
insert into actors (person_id, movie_id)
(select c.id, m.id from m, c)
)
select
m.id,
m.image,
m.title,
m.year,
m.description,
(
select
json_agg(q)
from (
select id, full_name, image
from d
) q
) directors,
(
select
json_agg(q)
from (
select id, full_name, image
from c
) q
) actors
from m
`

return user
}

async function update_movie() {
throw new Error('not implemented')
}

async function insert_user() {
throw new Error('not implemented')
}

async function get_person() {
throw new Error('not implemented')
}

async function insert_movie_plus() {
throw new Error('not implemented')
}

async function getIDs() {
const ids = await Promise.all([
sql`select id from users order by random()`,
sql`select id from persons order by random()`,
sql`select id from movies order by random()`
])

const people = ids[1].map(x => x.id)

return {
get_user: ids[0].map(x => x.id),
get_person: people,
get_movie: ids[2].map(x => x.id),
update_movie: ids[2].map(x => x.id),
insert_user: Array(concurrency).fill(INSERT_PREFIX),
insert_movie: Array(concurrency).fill({ prefix: INSERT_PREFIX, people: people.slice(0, 4) }),
insert_movie_plus: Array(concurrency).fill(INSERT_PREFIX)
}
}

async function setup(query) {
return query === 'update_movie'
? sql`update movies set title = split_part(movies.title, '---', 1) where movies.title like '%---%'`
: query === 'insert_user'
? sql`delete from users where users.name like ${ INSERT_PREFIX + '%' }`
: query === 'insert_movie' || query === 'insert_movie_plus' && Promise.all([
sql`delete from directors as d using movies as m where d.movie_id = m.id and m.image like ${ INSERT_PREFIX + '%' }`,
sql`delete from actors as a using movies as m where a.movie_id = m.id and m.image like ${ INSERT_PREFIX + '%' }`,
sql`delete from movies where image like ${ INSERT_PREFIX + '%' }`,
sql`delete from persons where image like ${ INSERT_PREFIX + '%' }`
])
}

async function cleanup(query) {
if (['update_movie', 'insert_user', 'insert_movie', 'insert_movie_plus'].indexOf(query) >= 0)
return setup(query)
}

}
3 changes: 3 additions & 0 deletions _shared.py
Original file line number Diff line number Diff line change
Expand Up @@ -115,6 +115,9 @@ class impl(typing.NamedTuple):
'postgres_pg':
impl('js', 'PostgreSQL (Node.js, pg)', None),

'postgresjs':
impl('js', 'PostgreSQL (Node.js, postgres)', None),

'prisma_untuned':
impl('js', 'Prisma (Untuned)', None),

Expand Down
35 changes: 19 additions & 16 deletions jsbench.js
Original file line number Diff line number Diff line change
Expand Up @@ -11,25 +11,27 @@
const argparse = require('argparse');
const _ = require('lodash');
const process = require('process');
const typeormapp = require('./_typeorm/build/index');
const sequelizeapp = require('./_sequelize/index');
const pgapp = require('./_postgres/index');
const edgedbapp = require('./_edgedb_js/index');
const prismaapp = require('./_prisma/index');

async function getApp(args) {
var app;
var ncon = args.concurrency;

if (args.orm == 'typeorm') {
app = new typeormapp.App({
if (args.orm == 'postgresjs') {
app = require('./_postgresjs/index')({
host: args.host,
port: args.port,
max: ncon
})
await app.connect();
} else if (args.orm == 'typeorm') {
app = new (require('./_typeorm/build/index').App)({
host: args.host,
port: args.port,
extra: {max: ncon},
});
await app.connect();
} else if (args.orm == 'sequelize') {
app = new sequelizeapp.App({
app = new (require('./_sequelize/index').App)({
host: args.host,
port: args.port,
pool: {
Expand All @@ -38,49 +40,49 @@ async function getApp(args) {
},
});
} else if (args.orm == 'prisma_untuned') {
app = new prismaapp.App();
app = new (require('./_prisma/index').App)();
} else if (args.orm == 'prisma') {
app = new prismaapp.TunedApp();
app = new (require('./_prisma/index').TunedApp)();
} else if (args.orm == 'postgres_pg') {
app = new pgapp.App({
app = new (require('./_postgres/index').App)({
host: args.host,
port: args.port,
max: ncon,
});
} else if (args.orm == 'edgedb_js_json') {
app = new edgedbapp.App({
app = new (require('./_edgedb_js/index').App)({
style: 'json',
host: args.host,
port: args.port,
pool: ncon,
});
await app.initPool();
} else if (args.orm == 'edgedb_js') {
app = new edgedbapp.App({
app = new (require('./_edgedb_js/index').App)({
style: 'repack',
host: args.host,
port: args.port,
pool: ncon,
});
await app.initPool();
} else if (args.orm == 'edgedb_js_qb') {
app = new edgedbapp.App({
app = new (require('./_edgedb_js/index').App)({
style: 'querybuilder',
host: args.host,
port: args.port,
pool: ncon,
});
await app.initPool();
} else if (args.orm == 'edgedb_js_qb_uncached') {
app = new edgedbapp.App({
app = new (require('./_edgedb_js/index').App)({
style: 'querybuilder_uncached',
host: args.host,
port: args.port,
pool: ncon,
});
await app.initPool();
} else {
throw new Error('Unexpected ORM: ' + orm);
throw new Error('Unexpected ORM: ' + args.orm);
}

return app;
Expand Down Expand Up @@ -315,6 +317,7 @@ async function main() {
'typeorm',
'sequelize',
'postgres_pg',
'postgresjs',
'prisma',
'prisma_untuned',
'edgedb_js',
Expand Down
17 changes: 16 additions & 1 deletion package-lock.json

Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.

Loading