Commit 358a897f authored by Bruce Momjian's avatar Bruce Momjian

Move dbsize functions into the backend. New functions:

	pg_tablespace_size
	pg_database_size
	pg_relation_size
	pg_complete_relation_size
	pg_size_pretty

Remove /contrib/dbsize.

Dave Page
parent b05801c8
# $PostgreSQL: pgsql/contrib/Makefile,v 1.57 2005/07/01 19:23:04 tgl Exp $
# $PostgreSQL: pgsql/contrib/Makefile,v 1.58 2005/07/29 14:46:55 momjian Exp $
subdir = contrib
top_builddir = ..
......@@ -11,7 +11,6 @@ WANTED_DIRS = \
dbase \
dblink \
dbmirror \
dbsize \
earthdistance \
fulltextindex \
fuzzystrmatch \
......
MODULES = dbsize
DATA_built = dbsize.sql
DOCS = README.dbsize
ifdef USE_PGXS
PGXS = $(shell pg_config --pgxs)
include $(PGXS)
else
subdir = contrib/dbsize
top_builddir = ../..
include $(top_builddir)/src/Makefile.global
include $(top_srcdir)/contrib/contrib-global.mk
endif
This module contains several functions that report the on-disk size of a
given database object in bytes:
int8 database_size(name)
int8 relation_size(text)
int8 indexes_size(text)
int8 total_relation_size(text)
int8 pg_database_size(oid)
int8 pg_relation_size(oid)
int8 pg_tablespace_size(oid)
text pg_size_pretty(int8)
setof record relation_size_components(text)
The first four functions take the name of the object (possibly
schema-qualified for the latter three) and returns the size of the
on-disk files in bytes.
SELECT database_size('template1');
SELECT relation_size('pg_class');
SELECT indexes_size('pg_class');
SELECT total_relation_size('pg_class');
These functions take object OIDs:
SELECT pg_database_size(1); -- template1 database
SELECT pg_relation_size(1259); -- pg_class table size
SELECT pg_tablespace_size(1663); -- pg_default tablespace
The indexes_size() function returns the total size of the indices for a
relation, including any toasted indices.
The total_relation_size() function returns the total size of the relation,
all its indices, and any toasted data.
Please note that relation_size and pg_relation_size report only the size of
the selected relation itself; any related indexes or toast tables are not
counted. To obtain the total size of a table including all indices and
toasted data, use total_relation_size().
The last function, relation_size_components(), returns a set of rows
showing the sizes of the component relations constituting the input
relation.
Examples
========
I've loaded the following table with a little less than 3 MB of data for
illustration:
create table fat ( id serial, data varchar );
create index fat_uidx on fat (id);
create index fat_idx on fat (data);
You can retrieve a rowset containing constituent sizes as follows:
# SELECT relation_size_components('fat');
relation_size_components
----------------------------------------------------
(2088960,65536,2891776,fat,r,59383,59383)
(32768,704512,737280,pg_toast_59383,t,59386,59386)
(0,32768,32768,pg_toast_59383_index,i,59388,59388)
(0,2039808,2039808,fat_idx,i,59389,59389)
(0,49152,49152,fat_uidx,i,59911,59911)
(5 rows)
To see a more readable output of the rowset:
SELECT *
FROM relation_size_components('fat') AS (idxsize BIGINT,
datasize BIGINT,
totalsize BIGINT,
relname NAME,
kind "char",
relid OID,
node OID)
ORDER BY totalsize;
idxsize | datasize | totalsize | relname | kind | relid | node
---------+----------+-----------+----------------------+------+-------+-------
0 | 32768 | 32768 | pg_toast_59383_index | i | 59388 | 59388
0 | 49152 | 49152 | fat_uidx | i | 59911 | 59911
32768 | 704512 | 737280 | pg_toast_59383 | t | 59386 | 59386
0 | 2039808 | 2039808 | fat_idx | i | 59389 | 59389
2088960 | 65536 | 2891776 | fat | r | 59383 | 59383
(5 rows)
To see the sum total size of a relation:
# select total_relation_size('fat');
total_relation_size
-------------------------
2891776
(1 row)
To see just the size of the uncompressed relation data:
# select relation_size('fat');
relation_size
---------------
65536
(1 row)
To see the size of all related indices:
# select indexes_size('fat');
indexes_size
--------------
2088960
(1 row)
To install, just run make; make install. Then load the functions
into any database using dbsize.sql.
CREATE FUNCTION database_size (name) RETURNS bigint
AS 'MODULE_PATHNAME', 'database_size'
LANGUAGE C STRICT;
CREATE FUNCTION relation_size (text) RETURNS bigint
AS 'MODULE_PATHNAME', 'relation_size'
LANGUAGE C STRICT;
CREATE FUNCTION pg_tablespace_size(oid) RETURNS bigint
AS 'MODULE_PATHNAME', 'pg_tablespace_size'
LANGUAGE C STRICT;
CREATE FUNCTION pg_database_size(oid) RETURNS bigint
AS 'MODULE_PATHNAME', 'pg_database_size'
LANGUAGE C STRICT;
CREATE FUNCTION pg_relation_size(oid) RETURNS bigint
AS 'MODULE_PATHNAME', 'pg_relation_size'
LANGUAGE C STRICT;
CREATE FUNCTION pg_size_pretty(bigint) RETURNS text
AS 'MODULE_PATHNAME', 'pg_size_pretty'
LANGUAGE C STRICT;
CREATE FUNCTION total_relation_size (text) RETURNS bigint AS '
SELECT pg_relation_size(r.oid)
+ COALESCE(pg_relation_size(t.oid), 0)::bigint
+ COALESCE(pg_relation_size(ti.oid), 0)::bigint
+ COALESCE(SUM(pg_relation_size(i.indexrelid)), 0)::bigint
+ COALESCE(SUM(pg_relation_size(it.oid)), 0)::bigint
+ COALESCE(SUM(pg_relation_size(iti.oid)), 0)::bigint AS bytes
FROM pg_class r
LEFT JOIN pg_class t ON (r.reltoastrelid = t.oid)
LEFT JOIN pg_class ti ON (t.reltoastidxid = ti.oid)
LEFT JOIN pg_index i ON (r.oid = i.indrelid)
LEFT JOIN pg_class ir ON (ir.oid = i.indexrelid)
LEFT JOIN pg_class it ON (ir.reltoastrelid = it.oid)
LEFT JOIN pg_class iti ON (it.reltoastidxid = iti.oid)
WHERE r.relname = \$1
GROUP BY r.oid, t.oid, ti.oid
' LANGUAGE SQL;
CREATE FUNCTION indexes_size (text) RETURNS bigint
AS '
SELECT COALESCE(SUM(pg_relation_size(ir.oid)), 0)::bigint
+ COALESCE(SUM(pg_relation_size(it.oid)), 0)::bigint
+ COALESCE(SUM(pg_relation_size(iti.oid)), 0)::bigint AS bytes
FROM pg_class r
LEFT JOIN pg_index i ON (r.oid = i.indrelid)
LEFT JOIN pg_class ir ON (ir.oid = i.indexrelid)
LEFT JOIN pg_class it ON (ir.reltoastrelid = it.oid)
LEFT JOIN pg_class iti ON (it.reltoastidxid = iti.oid)
WHERE r.relname = \$1
' LANGUAGE SQL;
CREATE FUNCTION relation_size_components (text) RETURNS SETOF RECORD
AS '
-- relation size
SELECT indexes_size(r.relname) AS indexes_size,
relation_size(r.relname) AS data_size,
total_relation_size(r.relname) AS total_size,
r.relname, r.relkind, r.oid AS relid, r.relfilenode
FROM pg_class r
WHERE r.relname = \$1
UNION ALL
-- relation toast size
SELECT indexes_size(toast.relname) AS indexes_size,
relation_size(''pg_toast.''||toast.relname) AS data_size,
total_relation_size(toast.relname) AS total_size,
toast.relname, toast.relkind, toast.oid AS relid, toast.relfilenode
FROM pg_class r, pg_class toast
WHERE r.reltoastrelid = toast.oid
AND r.relname = \$1
UNION ALL
-- relation toast index size
SELECT indexes_size(toastidxr.relname) AS indexes_size,
relation_size(''pg_toast.''||toastidxr.relname) AS data_size,
total_relation_size(toastidxr.relname) AS total_size,
toastidxr.relname, toastidxr.relkind,
toastidxr.oid AS relid, toastidxr.relfilenode
FROM pg_class r, pg_index toastidx, pg_class toastidxr
WHERE r.relname = \$1
AND r.reltoastrelid = toastidx.indrelid
AND toastidx.indexrelid = toastidxr.oid
UNION ALL
-- relation indices size
SELECT indexes_size(idxr.relname) AS indexes_size,
relation_size(idxr.relname) AS data_size,
total_relation_size(idxr.relname) AS total_size,
idxr.relname, idxr.relkind, idxr.oid AS relid, idxr.relfilenode
FROM pg_class r, pg_class idxr, pg_index idx
WHERE r.relname = \$1
AND r.oid = idx.indrelid
AND idx.indexrelid = idxr.oid
UNION ALL
-- relation indices toast size
SELECT indexes_size(idxtoastr.relname) AS indexes_size,
relation_size(''pg_toast.''||idxtoastr.relname) AS data_size,
total_relation_size(idxtoastr.relname) AS total_size,
idxtoastr.relname, idxtoastr.relkind, idxtoastr.oid AS relid,
idxtoastr.relfilenode
FROM pg_class r, pg_class idxr, pg_index idx, pg_class idxtoastr
WHERE r.relname = \$1
AND r.oid = idx.indrelid
AND idx.indexrelid = idxr.oid
AND idxr.reltoastrelid = idxtoastr.oid
UNION ALL
-- relation indices toast index size
SELECT indexes_size(idxtoastidxr.relname) AS indexes_size,
relation_size(''pg_toast.''||idxtoastidxr.relname) AS data_size,
total_relation_size(idxtoastidxr.relname) AS total_size,
idxtoastidxr.relname, idxtoastidxr.relkind,
idxtoastidxr.oid AS relid, idxtoastidxr.relfilenode
FROM pg_class r, pg_class idxr, pg_index idx, pg_class idxtoast,
pg_class idxtoastidxr
WHERE r.relname = \$1
AND r.oid = idx.indrelid
AND idx.indexrelid = idxr.oid
AND idxr.reltoastrelid = idxtoast.oid
AND idxtoast.reltoastrelid = idxtoastidxr.oid
' LANGUAGE SQL;
<!--
$PostgreSQL: pgsql/doc/src/sgml/diskusage.sgml,v 1.14 2005/01/10 00:04:38 tgl Exp $
$PostgreSQL: pgsql/doc/src/sgml/diskusage.sgml,v 1.15 2005/07/29 14:46:56 momjian Exp $
-->
<chapter id="diskusage">
......@@ -31,11 +31,16 @@ $PostgreSQL: pgsql/doc/src/sgml/diskusage.sgml,v 1.14 2005/01/10 00:04:38 tgl Ex
</para>
<para>
You can monitor disk space from three places: from
<application>psql</> using <command>VACUUM</> information, from
<application>psql</> using the tools in <filename>contrib/dbsize</>, and from
the command line using the tools in <filename>contrib/oid2name</>. Using
<application>psql</> on a recently vacuumed or analyzed database,
You can monitor disk space from three ways: using
SQL functions listed in <xref linkend="functions-admin-dbsize">,
using <command>VACUUM</> information, and from the command line
using the tools in <filename>contrib/oid2name</>. The SQL functions
are the easiest to use and report information about tables, tables with
indexes and long value storage (TOAST), databases, and tablespaces.
</para>
<para>
Using <application>psql</> on a recently vacuumed or analyzed database,
you can issue queries to see the disk usage of any table:
<programlisting>
SELECT relfilenode, relpages FROM pg_class WHERE relname = 'customer';
......@@ -101,12 +106,6 @@ SELECT relname, relpages FROM pg_class ORDER BY relpages DESC;
</programlisting>
</para>
<para>
<filename>contrib/dbsize</> loads functions into your database that allow
you to find the size of a table or database from inside
<application>psql</> without the need for <command>VACUUM</> or <command>ANALYZE</>.
</para>
<para>
You can also use <filename>contrib/oid2name</> to show disk usage. See
<filename>README.oid2name</> in that directory for examples. It includes a script that
......
<!--
$PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.272 2005/07/26 16:38:25 tgl Exp $
$PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.273 2005/07/29 14:46:56 momjian Exp $
PostgreSQL documentation
-->
......@@ -9161,6 +9161,115 @@ SELECT set_config('log_statement_stats', 'off', false);
For details about proper usage of these functions, see
<xref linkend="backup-online">.
</para>
<para>
The functions shown in <xref
linkend="functions-admin-dbsize"> calculate the actual disk space
usage of database objects.
</para>
<table id="functions-admin-dbsize">
<title>Database Object Size Functions</title>
<tgroup cols="3">
<thead>
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry>
<literal><function>pg_tablespace_size</function>(<parameter>oid</parameter>)</literal>
</entry>
<entry><type>int8</type></entry>
<entry>Calculates the total disk space used by the tablespace with the specified OID</entry>
</row>
<row>
<entry>
<literal><function>pg_tablespace_size</function>(<parameter>name</parameter>)</literal>
</entry>
<entry><type>int8</type></entry>
<entry>Calculates the total disk space used by the tablespace with the specified name</entry>
</row>
<row>
<entry>
<literal><function>pg_database_size</function>(<parameter>oid</parameter>)</literal>
</entry>
<entry><type>int8</type></entry>
<entry>Calculates the total disk space used by the database with the specified OID</entry>
</row>
<row>
<entry>
<literal><function>pg_database_size</function>(<parameter>name</parameter>)</literal>
</entry>
<entry><type>int8</type></entry>
<entry>Calculates the total disk space used by the database with the specified name</entry>
</row>
<row>
<entry>
<literal><function>pg_relation_size</function>(<parameter>oid</parameter>)</literal>
</entry>
<entry><type>int8</type></entry>
<entry>Calculates the disk space used by the table or index with the specified OID</entry>
</row>
<row>
<entry>
<literal><function>pg_relation_size</function>(<parameter>text</parameter>)</literal>
</entry>
<entry><type>int8</type></entry>
<entry>Calculates the disk space used by the index or table with the specified name.
The name may be prefixed with a schema name if required</entry>
</row>
<row>
<entry>
<literal><function>pg_complete_relation_size</function>(<parameter>oid</parameter>)</literal>
</entry>
<entry><type>int8</type></entry>
<entry>Calculates the total disk space used by the table with the specified OID,
including indexes and toasted data</entry>
</row>
<row>
<entry>
<literal><function>pg_complete_relation_size</function>(<parameter>text</parameter>)</literal>
</entry>
<entry><type>int8</type></entry>
<entry>Calculates the total disk space used by the table with the specified name,
including indexes and toasted data. The name may be prefixed with a schema name if
required</entry>
</row>
<row>
<entry>
<literal><function>pg_size_pretty</function>(<parameter>int8</parameter>)</literal>
</entry>
<entry><type>text</type></entry>
<entry>Formats the size value (in bytes) into a human readable format with size units </entry>
</row>
</tbody>
</tgroup>
</table>
<para>
<function>pg_tablespace_size</> and <function>pg_database_size</> accept an
oid or name of a tablespace or database, and return the disk space usage of the specified object.
</para>
<indexterm zone="functions-admin">
<primary>pg_relation_size</primary>
</indexterm>
<para>
<function>pg_relation_size</> accepts the oid or name of a table, index or
toast table, and returns the size in bytes.
</para>
<para>
<function>pg_complete_relation_size</> accepts the oid or name of a table or
toast table, and returns the size in bytes of the data and all associated
indexes and toast tables.
</para>
<para>
<function>pg_size_pretty</> can be used to format the size of the
database objects in a human readable way, using kB, MB, GB or TB as appropriate.
</para>
</sect1>
</chapter>
......
#
# Makefile for utils/adt
#
# $PostgreSQL: pgsql/src/backend/utils/adt/Makefile,v 1.57 2004/04/01 21:28:45 tgl Exp $
# $PostgreSQL: pgsql/src/backend/utils/adt/Makefile,v 1.58 2005/07/29 14:46:57 momjian Exp $
#
subdir = src/backend/utils/adt
......@@ -24,7 +24,7 @@ OBJS = acl.o arrayfuncs.o array_userfuncs.o arrayutils.o bool.o \
tid.o timestamp.o varbit.o varchar.o varlena.o version.o xid.o \
network.o mac.o inet_net_ntop.o inet_net_pton.o \
ri_triggers.o pg_lzcompress.o pg_locale.o formatting.o \
ascii.o quote.o pgstatfuncs.o encode.o
ascii.o quote.o pgstatfuncs.o encode.o dbsize.o
like.o: like.c like_match.c
......
......@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2005, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/catalog/pg_proc.h,v 1.378 2005/07/26 00:04:19 tgl Exp $
* $PostgreSQL: pgsql/src/include/catalog/pg_proc.h,v 1.379 2005/07/29 14:47:01 momjian Exp $
*
* NOTES
* The script catalog/genbki.sh reads this file and generates .bki
......@@ -1573,6 +1573,11 @@ DESCR("matches regex., case-insensitive");
DATA(insert OID = 1241 ( nameicregexne PGNSP PGUID 12 f f t f i 2 16 "19 25" _null_ _null_ _null_ nameicregexne - _null_ ));
DESCR("does not match regex., case-insensitive");
DATA(insert OID = 2322 ( pg_tablespace_size PGNSP PGUID 12 f f t f v 1 20 "26" _null_ _null_ _null_ pg_tablespace_size_oid - _null_ ));
DESCR("Calculate total disk space usage for the specified tablespace");
DATA(insert OID = 2323 ( pg_tablespace_size PGNSP PGUID 12 f f t f v 1 20 "19" _null_ _null_ _null_ pg_tablespace_size_name - _null_ ));
DESCR("Calculate total disk space usage for the specified tablespace");
DATA(insert OID = 1251 ( int4abs PGNSP PGUID 12 f f t f i 1 23 "23" _null_ _null_ _null_ int4abs - _null_ ));
DESCR("absolute value");
DATA(insert OID = 1253 ( int2abs PGNSP PGUID 12 f f t f i 1 21 "21" _null_ _null_ _null_ int2abs - _null_ ));
......@@ -1581,6 +1586,9 @@ DESCR("absolute value");
DATA(insert OID = 1263 ( interval PGNSP PGUID 12 f f t f s 1 1186 "25" _null_ _null_ _null_ text_interval - _null_ ));
DESCR("convert text to interval");
DATA(insert OID = 2324 ( pg_database_size PGNSP PGUID 12 f f t f v 1 20 "26" _null_ _null_ _null_ pg_database_size_oid - _null_ ));
DESCR("Calculate total disk space usage for the specified database");
DATA(insert OID = 1271 ( overlaps PGNSP PGUID 12 f f f f i 4 16 "1266 1266 1266 1266" _null_ _null_ _null_ overlaps_timetz - _null_ ));
DESCR("SQL92 interval comparison");
DATA(insert OID = 1272 ( datetime_pl PGNSP PGUID 12 f f t f i 2 1114 "1082 1083" _null_ _null_ _null_ datetime_timestamp - _null_ ));
......@@ -1624,6 +1632,9 @@ DESCR("latest tid of a tuple");
DATA(insert OID = 1294 ( currtid2 PGNSP PGUID 12 f f t f v 2 27 "25 27" _null_ _null_ _null_ currtid_byrelname - _null_ ));
DESCR("latest tid of a tuple");
DATA(insert OID = 2168 ( pg_database_size PGNSP PGUID 12 f f t f v 1 20 "19" _null_ _null_ _null_ pg_database_size_name - _null_ ));
DESCR("Calculate total disk space usage for the specified database");
DATA(insert OID = 1296 ( timedate_pl PGNSP PGUID 14 f f t f i 2 1114 "1083 1082" _null_ _null_ _null_ "select ($2 + $1)" - _null_ ));
DESCR("convert time and date to timestamp");
DATA(insert OID = 1297 ( datetimetz_pl PGNSP PGUID 12 f f t f i 2 1184 "1082 1266" _null_ _null_ _null_ datetimetz_timestamptz - _null_ ));
......@@ -3038,7 +3049,6 @@ DESCR("Prepare for taking an online backup");
DATA(insert OID = 2173 ( pg_stop_backup PGNSP PGUID 12 f f t f v 0 25 "" _null_ _null_ _null_ pg_stop_backup - _null_ ));
DESCR("Finish taking an online backup");
/* Aggregates (moved here from pg_aggregate for 7.3) */
DATA(insert OID = 2100 ( avg PGNSP PGUID 12 t f f f i 1 1700 "20" _null_ _null_ _null_ aggregate_dummy - _null_ ));
......@@ -3227,6 +3237,17 @@ DESCR("current user privilege on schema by schema name");
DATA(insert OID = 2273 ( has_schema_privilege PGNSP PGUID 12 f f t f s 2 16 "26 25" _null_ _null_ _null_ has_schema_privilege_id - _null_ ));
DESCR("current user privilege on schema by schema oid");
DATA(insert OID = 2325 ( pg_relation_size PGNSP PGUID 12 f f t f v 1 20 "26" _null_ _null_ _null_ pg_relation_size_oid - _null_ ));
DESCR("Calculate disk space usage for the specified table or index");
DATA(insert OID = 2289 ( pg_relation_size PGNSP PGUID 12 f f t f v 1 20 "25" _null_ _null_ _null_ pg_relation_size_name - _null_ ));
DESCR("Calculate disk space usage for the specified table or index");
DATA(insert OID = 2286 ( pg_complete_relation_size PGNSP PGUID 12 f f t f v 1 20 "26" _null_ _null_ _null_ pg_complete_relation_size_oid - _null_ ));
DESCR("Calculate total disk space usage for the specified table and associated indexes and toast tables");
DATA(insert OID = 2287 ( pg_complete_relation_size PGNSP PGUID 12 f f t f v 1 20 "25" _null_ _null_ _null_ pg_complete_relation_size_name - _null_ ));
DESCR("Calculate total disk space usage for the specified table and associated indexes and toast tables");
DATA(insert OID = 2288 ( pg_size_pretty PGNSP PGUID 12 f f t f v 1 25 "20" _null_ _null_ _null_ pg_size_pretty - _null_ ));
DESCR("Convert a long int to a human readable text using size units");
DATA(insert OID = 2390 ( has_tablespace_privilege PGNSP PGUID 12 f f t f s 3 16 "19 25 25" _null_ _null_ _null_ has_tablespace_privilege_name_name - _null_ ));
DESCR("user privilege on tablespace by username, tablespace name");
DATA(insert OID = 2391 ( has_tablespace_privilege PGNSP PGUID 12 f f t f s 3 16 "19 26 25" _null_ _null_ _null_ has_tablespace_privilege_name_id - _null_ ));
......
......@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2005, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/utils/builtins.h,v 1.261 2005/07/26 00:04:19 tgl Exp $
* $PostgreSQL: pgsql/src/include/utils/builtins.h,v 1.262 2005/07/29 14:47:04 momjian Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -363,6 +363,17 @@ extern Datum float84le(PG_FUNCTION_ARGS);
extern Datum float84gt(PG_FUNCTION_ARGS);
extern Datum float84ge(PG_FUNCTION_ARGS);
/* dbsize.c */
extern Datum pg_tablespace_size_oid(PG_FUNCTION_ARGS);
extern Datum pg_tablespace_size_name(PG_FUNCTION_ARGS);
extern Datum pg_database_size_oid(PG_FUNCTION_ARGS);
extern Datum pg_database_size_name(PG_FUNCTION_ARGS);
extern Datum pg_relation_size_oid(PG_FUNCTION_ARGS);
extern Datum pg_relation_size_name(PG_FUNCTION_ARGS);
extern Datum pg_complete_relation_size_oid(PG_FUNCTION_ARGS);
extern Datum pg_complete_relation_size_name(PG_FUNCTION_ARGS);
extern Datum pg_size_pretty(PG_FUNCTION_ARGS);
/* misc.c */
extern Datum nullvalue(PG_FUNCTION_ARGS);
extern Datum nonnullvalue(PG_FUNCTION_ARGS);
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment