Skip to content

Commit

Permalink
Fix type introspection being very slow on large databases
Browse files Browse the repository at this point in the history
Stop using CTEs in the type introspection query, otherwise it runs for
ages on databases with a large number of composite attributes (i. e.
tons of tables with tons of columns).

Fixes: #186
  • Loading branch information
elprans committed Sep 7, 2017
1 parent 23394c9 commit a925617
Show file tree
Hide file tree
Showing 3 changed files with 119 additions and 70 deletions.
15 changes: 9 additions & 6 deletions asyncpg/_testbase.py
Original file line number Diff line number Diff line change
Expand Up @@ -93,9 +93,12 @@ def assertRunUnder(self, delta):
try:
yield
finally:
if time.monotonic() - st > delta:
elapsed = time.monotonic() - st
if elapsed > delta:
raise AssertionError(
'running block took longer than {}'.format(delta))
'running block took {:0.3f}s which is longer '
'than the expected maximum of {:0.3f}s'.format(
elapsed, delta))

@contextlib.contextmanager
def assertLoopErrorHandlerCalled(self, msg_re: str):
Expand Down Expand Up @@ -214,18 +217,18 @@ def wrap(func):

class ConnectedTestCase(ClusterTestCase):

def getExtraConnectOptions(self):
return {}

def setUp(self):
super().setUp()

# Extract options set up with `with_connection_options`.
test_func = getattr(self, self._testMethodName).__func__
opts = getattr(test_func, '__connect_options__', {})
if 'database' not in opts:
opts = dict(opts)
opts['database'] = 'postgres'

self.con = self.loop.run_until_complete(
self.cluster.connect(database='postgres', loop=self.loop, **opts))
self.cluster.connect(loop=self.loop, **opts))

self.server_version = self.con.get_server_version()

Expand Down
124 changes: 60 additions & 64 deletions asyncpg/introspection.py
Original file line number Diff line number Diff line change
Expand Up @@ -5,29 +5,8 @@
# the Apache 2.0 License: http://www.apache.org/licenses/LICENSE-2.0


INTRO_LOOKUP_TYPES = '''\
WITH RECURSIVE typeinfo_tree(
oid, ns, name, kind, basetype, has_bin_io, elemtype, elemdelim,
range_subtype, elem_has_bin_io, attrtypoids, attrnames, depth)
AS (
WITH composite_attrs
AS (
SELECT
c.reltype AS comptype_oid,
array_agg(ia.atttypid ORDER BY ia.attnum) AS typoids,
array_agg(ia.attname::text ORDER BY ia.attnum) AS names
FROM
pg_attribute ia
INNER JOIN pg_class c
ON (ia.attrelid = c.oid)
WHERE
ia.attnum > 0 AND NOT ia.attisdropped
GROUP BY
c.reltype
),
typeinfo
AS (
_TYPEINFO = '''\
(
SELECT
t.oid AS oid,
ns.nspname AS ns,
Expand Down Expand Up @@ -76,16 +55,28 @@
elem_t.typsend::oid != 0
END) AS elem_has_bin_io,
(CASE WHEN t.typtype = 'c' THEN
(SELECT ca.typoids
FROM composite_attrs AS ca
WHERE ca.comptype_oid = t.oid)
(SELECT
array_agg(ia.atttypid ORDER BY ia.attnum)
FROM
pg_attribute ia
INNER JOIN pg_class c
ON (ia.attrelid = c.oid)
WHERE
ia.attnum > 0 AND NOT ia.attisdropped
AND c.reltype = t.oid)
ELSE NULL
END) AS attrtypoids,
(CASE WHEN t.typtype = 'c' THEN
(SELECT ca.names
FROM composite_attrs AS ca
WHERE ca.comptype_oid = t.oid)
(SELECT
array_agg(ia.attname::text ORDER BY ia.attnum)
FROM
pg_attribute ia
INNER JOIN pg_class c
ON (ia.attrelid = c.oid)
WHERE
ia.attnum > 0 AND NOT ia.attisdropped
AND c.reltype = t.oid)
ELSE NULL
END) AS attrnames
Expand All @@ -102,13 +93,20 @@
t.oid = range_t.rngtypid
)
)
'''


INTRO_LOOKUP_TYPES = '''\
WITH RECURSIVE typeinfo_tree(
oid, ns, name, kind, basetype, has_bin_io, elemtype, elemdelim,
range_subtype, elem_has_bin_io, attrtypoids, attrnames, depth)
AS (
SELECT
ti.oid, ti.ns, ti.name, ti.kind, ti.basetype, ti.has_bin_io,
ti.elemtype, ti.elemdelim, ti.range_subtype, ti.elem_has_bin_io,
ti.attrtypoids, ti.attrnames, 0
FROM
typeinfo AS ti
{typeinfo} AS ti
WHERE
ti.oid = any($1::oid[])
Expand All @@ -119,7 +117,7 @@
ti.elemtype, ti.elemdelim, ti.range_subtype, ti.elem_has_bin_io,
ti.attrtypoids, ti.attrnames, tt.depth + 1
FROM
typeinfo ti,
{typeinfo} ti,
typeinfo_tree tt
WHERE
(tt.elemtype IS NOT NULL AND ti.oid = tt.elemtype)
Expand All @@ -133,33 +131,12 @@
typeinfo_tree
ORDER BY
depth DESC
'''
'''.format(typeinfo=_TYPEINFO)


# Prior to 9.2 PostgreSQL did not have range types.
INTRO_LOOKUP_TYPES_91 = '''\
WITH RECURSIVE typeinfo_tree(
oid, ns, name, kind, basetype, has_bin_io, elemtype, elemdelim,
range_subtype, elem_has_bin_io, attrtypoids, attrnames, depth)
AS (
WITH composite_attrs
AS (
SELECT
c.reltype AS comptype_oid,
array_agg(ia.atttypid ORDER BY ia.attnum) AS typoids,
array_agg(ia.attname::text ORDER BY ia.attnum) AS names
FROM
pg_attribute ia
INNER JOIN pg_class c
ON (ia.attrelid = c.oid)
WHERE
ia.attnum > 0 AND NOT ia.attisdropped
GROUP BY
c.reltype
),
typeinfo
AS (
_TYPEINFO_91 = '''\
(
SELECT
t.oid AS oid,
ns.nspname AS ns,
Expand Down Expand Up @@ -199,16 +176,28 @@
elem_t.typsend::oid != 0
AS elem_has_bin_io,
(CASE WHEN t.typtype = 'c' THEN
(SELECT ca.typoids
FROM composite_attrs AS ca
WHERE ca.comptype_oid = t.oid)
(SELECT
array_agg(ia.atttypid ORDER BY ia.attnum)
FROM
pg_attribute ia
INNER JOIN pg_class c
ON (ia.attrelid = c.oid)
WHERE
ia.attnum > 0 AND NOT ia.attisdropped
AND c.reltype = t.oid)
ELSE NULL
END) AS attrtypoids,
(CASE WHEN t.typtype = 'c' THEN
(SELECT ca.names
FROM composite_attrs AS ca
WHERE ca.comptype_oid = t.oid)
(SELECT
array_agg(ia.attname::text ORDER BY ia.attnum)
FROM
pg_attribute ia
INNER JOIN pg_class c
ON (ia.attrelid = c.oid)
WHERE
ia.attnum > 0 AND NOT ia.attisdropped
AND c.reltype = t.oid)
ELSE NULL
END) AS attrnames
Expand All @@ -222,13 +211,20 @@
t.typelem = elem_t.oid
)
)
'''

INTRO_LOOKUP_TYPES_91 = '''\
WITH RECURSIVE typeinfo_tree(
oid, ns, name, kind, basetype, has_bin_io, elemtype, elemdelim,
range_subtype, elem_has_bin_io, attrtypoids, attrnames, depth)
AS (
SELECT
ti.oid, ti.ns, ti.name, ti.kind, ti.basetype, ti.has_bin_io,
ti.elemtype, ti.elemdelim, ti.range_subtype, ti.elem_has_bin_io,
ti.attrtypoids, ti.attrnames, 0
FROM
typeinfo AS ti
{typeinfo} AS ti
WHERE
ti.oid = any($1::oid[])
Expand All @@ -239,7 +235,7 @@
ti.elemtype, ti.elemdelim, ti.range_subtype, ti.elem_has_bin_io,
ti.attrtypoids, ti.attrnames, tt.depth + 1
FROM
typeinfo ti,
{typeinfo} ti,
typeinfo_tree tt
WHERE
(tt.elemtype IS NOT NULL AND ti.oid = tt.elemtype)
Expand All @@ -253,7 +249,7 @@
typeinfo_tree
ORDER BY
depth DESC
'''
'''.format(typeinfo=_TYPEINFO_91)


TYPE_BY_NAME = '''\
Expand Down
50 changes: 50 additions & 0 deletions tests/test_introspection.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,50 @@
# Copyright (C) 2016-present the asyncpg authors and contributors
# <see AUTHORS file>
#
# This module is part of asyncpg and is released under
# the Apache 2.0 License: http://www.apache.org/licenses/LICENSE-2.0


from asyncpg import _testbase as tb


MAX_RUNTIME = 0.1


class TestTimeout(tb.ConnectedTestCase):
@classmethod
def setUpClass(cls):
super().setUpClass()
cls.adminconn = cls.loop.run_until_complete(
cls.cluster.connect(database='postgres', loop=cls.loop))
cls.loop.run_until_complete(
cls.adminconn.execute('CREATE DATABASE asyncpg_intro_test'))

@classmethod
def tearDownClass(cls):
cls.loop.run_until_complete(
cls.adminconn.execute('DROP DATABASE asyncpg_intro_test'))

cls.loop.run_until_complete(cls.adminconn.close())
cls.adminconn = None

super().tearDownClass()

@tb.with_connection_options(database='asyncpg_intro_test')
async def test_introspection_on_large_db(self):
await self.con.execute(
'CREATE DOMAIN intro_test AS int'
)

await self.con.execute(
'CREATE TABLE base ({})'.format(
','.join('c{:02} varchar'.format(n) for n in range(50))
)
)
for n in range(1000):
await self.con.execute(
'CREATE TABLE child_{:04} () inherits (base)'.format(n)
)

with self.assertRunUnder(MAX_RUNTIME):
await self.con.fetchval('SELECT $1::intro_test', 1)

0 comments on commit a925617

Please sign in to comment.