Size on Disk
Hello.
I am working on a Knoppix distribution of my program.
I do have it working, but the size of the database on
disk is becoming a factor. (I copy it to ramdisk
before starting postmaster).
How can I change (minimize) the size of the db on
disk? Are there any parameters I can set? Maybe limit
the size of logs/journals?
Greg (dostatnig@yahoo.com)
__________________________________
Do you Yahoo!?
Free Pop-Up Blocker - Get it now
http://companion.yahoo.com/
you do not mention which version of postgresql or which files are problematic,
but just guessing:
- log/checkpoint files: http://www.varlena.com/GeneralBits/Tidbits/perf.html
- index files: see "reindex" command
- table files: see FSM settings and vacuum more, or vacuum full
(contrib/pg_autovacuum is helpful here)
SELECT CASE WHEN ((SELECT class3.relname FROM pg_class class3, pg_index WHERE ((class1.oid = pg_index.indexrelid) AND (class3.oid = pg_index.indrelid))) IS NOT NULL) THEN (SELECT class3.relname FROM pg_class class3, pg_index WHERE ((class1.oid = pg_index.indexrelid) AND (class3.oid = pg_index.indrelid))) WHEN (class1.relname IS NOT NULL) THEN class1.relname ELSE NULL::name END AS "table", CASE WHEN (class1.relkind = 'r'::"char") THEN NULL::name ELSE class1.relname END AS "index", (class1.relpages * 8) AS "size (KBytes)" FROM pg_class class1 WHERE ((class1.relkind = 'r'::"char") OR (class1.relkind = 'i'::"char")) ORDER BY CASE WHEN ((SELECT class3.relname FROM pg_class class3, pg_index WHERE ((class1.oid = pg_index.indexrelid) AND (class3.oid = pg_index.indrelid))) IS NOT NULL) THEN (SELECT class3.relname FROM pg_class class3, pg_index WHERE ((class1.oid = pg_index.indexrelid) AND (class3.oid = pg_index.indrelid))) WHEN (class1.relname IS NOT NULL) THEN class1.relname ELSE NULL::name END, CASE WHEN (class1.relkind = 'r'::"char") THEN NULL::name ELSE class1.relname END, (class1.relpages * 8);
might help telling you how big things are. i have problems sometimes where
the sizes for indexes are not correct. you can also run "vacuum verbose full"
and see if it is maybe dead tuples sticking around.
Show quoted text
On Tue, 25 Nov 2003, Grzegorz Dostatni wrote:
I am working on a Knoppix distribution of my program.
I do have it working, but the size of the database on
disk is becoming a factor. (I copy it to ramdisk
before starting postmaster).How can I change (minimize) the size of the db on
disk? Are there any parameters I can set? Maybe limit
the size of logs/journals?
Thank you for your very quick response Chester.
I guess I should clarify something. Knoppix is a
version of linux that runs entirely in memory. I need
as smallest footprint as possible.
Currently the datase is roughly 80 Megs. About half of
the size is stored in pg_xlog directory. I managed to
figure out that those files are transaction log files?
How can I delete them safely? (after creatation the
database will pretty much be read-only - any changes
will be in memory only). Are there any other tricks I
can use to get the size down? Please keep in mind that
I work with a fairly new database - I'm always
recreating it from a dump so only the initial inserts
are in there, no changes or deletions.
Vacuuming helps a bit, but nowhere near as much as I
would hope.
Greg
Greg
__________________________________
Do you Yahoo!?
Free Pop-Up Blocker - Get it now
http://companion.yahoo.com/
Grzegorz Dostatni <dostatnig@yahoo.com> writes:
Currently the datase is roughly 80 Megs. About half of
the size is stored in pg_xlog directory. I managed to
figure out that those files are transaction log files?
How can I delete them safely?
You can NOT. Don't even think about going there.
What you can do, if you intend only low-update-volume usage,
is reduce checkpoint_segments to reduce the number of WAL files
the system wants to keep around.
regards, tom lane
Hello
SELECT CASE WHEN ((SELECT class3.relname FROM pg_class class3, pg_index WHERE ((class1.oid = pg_index.indexrelid) AND (class3.oid = pg_index.indrelid))) IS NOT NULL) THEN (SELECT class3.relname FROM pg_class class3, pg_index WHERE ((class1.oid = pg_index.indexrelid) AND (class3.oid = pg_index.indrelid))) WHEN (class1.relname IS NOT NULL) THEN class1.relname ELSE NULL::name END AS "table", CASE WHEN (class1.relkind = 'r'::"char") THEN NULL::name ELSE class1.relname END AS "index", (class1.relpages * 8) AS "size (KBytes)" FROM pg_class class1 WHERE ((class1.relkind = 'r'::"char") OR (class1.relkind = 'i'::"char")) ORDER BY CASE WHEN ((SELECT class3.relname FROM pg_class class3, pg_index WHERE ((class1.oid = pg_index.indexrelid) AND (class3.oid = pg_index.indrelid))) IS NOT NULL) THEN (SELECT class3.relname FROM pg_class class3, pg_index WHERE ((class1.oid = pg_index.indexrelid) AND (class3.oid = pg_index.indrelid))) WHEN (class1.relname IS NOT NULL) THEN class1.relname ELSE NULL::name END, CASE WHEN (class1.relkind = 'r'::"char") THEN NULL::name ELSE class1.relname END, (class1.relpages * 8);
I was verry interested in your querry but I did not understood it.
Therefore I rewrote it. Now it is a little simpler to read and does (in
my opinion) the same?
--
-- Amount of space per object used after vacuum
--
VACUUM;
SELECT c1.relname AS "tablename", c2.relname AS "indexname",
c2.relpages * 8 AS "size_kb", c2.relfilenode AS "filename"
FROM pg_class c1, pg_class c2, pg_index i
WHERE c1.oid = i.indrelid
AND i.indexrelid = c2.oid
UNION
SELECT relname, NULL, relpages * 8, relfilenode
FROM pg_class
WHERE relkind = 'r'
ORDER BY tablename, indexname DESC, size_kb;
Caution: This Sktipt does NOT exactly the same... but the results should
be the same
Regrards
Oli
-------------------------------------------------------
Oli Sennhauser
Database-Engineer (Oracle & PostgreSQL)
Rebenweg 6
CH - 8610 Uster / Switzerland
Phone (+41) 1 940 24 82 or Mobile (+41) 79 450 49 14
e-Mail oli.sennhauser@bluewin.ch
Website http://mypage.bluewin.ch/shinguz/PostgreSQL/
Secure (signed/encrypted) e-Mail with a Free Personal SwissSign ID: http://www.swisssign.ch
Import the SwissSign Root Certificate: http://swisssign.net/cgi-bin/trust/import
Hello,
Try SQlite. It is small DB with SQL 92 standard - almost
implemented. If you need something fast and small it is
just for you.
BTW: it is embadded system, so concurency... is not in the
focus ;)
--
Regards
Michal Zaborowski (TeXXaS)
http://sqlite4delphi.sourceforge.net/
On Wed, 2003-11-26 at 05:53, Tom Lane wrote:
Grzegorz Dostatni <dostatnig@yahoo.com> writes:
Currently the datase is roughly 80 Megs. About half of
the size is stored in pg_xlog directory. I managed to
figure out that those files are transaction log files?
How can I delete them safely?You can NOT. Don't even think about going there.
What you can do, if you intend only low-update-volume usage,
is reduce checkpoint_segments to reduce the number of WAL files
the system wants to keep around.
The use of the word "log" in the directory name does tend to invite this
error, and some have acted on it without asking first. I think initdb
should put a README.IMPORTANT file in $PGDATA to say,
pg_xlog and pg_clog are crucial to the preservation of your
data. They do not contain standard log files. Do not even think
about deleting them to save space; you would destroy your
database.
The cost is only one disk block per cluster, and it might deflect some
of the weaponry pointed at hapless feet...
Patch for initdb.c attached
I notice that pg_clog and pg_xlog are not mentioned in the index to the
documentation, which makes it more difficult for people to find out what
they are. I therefore also attach a doc patch to add index entries for
those two files.
--
Oliver Elphick Oliver.Elphick@lfix.co.uk
Isle of Wight, UK http://www.lfix.co.uk/oliver
GPG: 1024D/3E1D0C1C: CA12 09E0 E8D5 8870 5839 932A 614D 4C34 3E1D 0C1C
========================================
"Who shall ascend into the hill of the LORD? or who
shall stand in his holy place? He that hath clean
hands, and a pure heart..." Psalms 24:3,4
Attachments:
initdb.patchtext/x-patch; charset=ISO-8859-15Download
Index: src/bin/initdb/initdb.c
===================================================================
RCS file: /projects/cvsroot/pgsql-server/src/bin/initdb/initdb.c,v
retrieving revision 1.15
diff -c -r1.15 initdb.c
*** src/bin/initdb/initdb.c 29 Nov 2003 19:52:04 -0000 1.15
--- src/bin/initdb/initdb.c 30 Nov 2003 21:52:47 -0000
***************
*** 179,184 ****
--- 179,185 ----
static int set_paths(void);
static char **replace_token(char **, char *, char *);
static void set_short_version(char *, char *);
+ static void set_warning_file(void);
static void set_null_conf(void);
static void test_buffers(void);
static void test_connections(void);
***************
*** 1064,1069 ****
--- 1065,1088 ----
}
/*
+ * write out the warning file in the data dir; this is to try to ensure
+ * that users don't delete pg_xlog in the belief that it is "just" a log
+ * file
+ */
+ static void
+ set_warning_file(void)
+ {
+ FILE *warning_file;
+ char *path;
+
+ path = xmalloc(strlen(pg_data) + 20);
+ sprintf(path, "%s/README.IMPORTANT", pg_data);
+ warning_file = fopen(path, PG_BINARY_W);
+ fprintf(warning_file, "pg_xlog and pg_clog are crucial to the preservation of your\ndata. They do not contain standard log files. Do not even think\nabout deleting them to save space; you would destroy your\ndatabase.\n");
+ fclose(warning_file);
+ }
+
+ /*
* set up an empty config file so we can check buffers and connections
*/
static void
***************
*** 2427,2432 ****
--- 2446,2454 ----
/* Top level PG_VERSION is checked by bootstrapper, so make it first */
set_short_version(short_version, NULL);
+
+ /* Write the warning file - a warning not to delete pg_xlog! */
+ set_warning_file();
/*
* Determine platform-specific config settings
pg_xlog.doc.patchtext/x-patch; charset=ISO-8859-15Download
Index: doc/src/sgml/backup.sgml
===================================================================
RCS file: /projects/cvsroot/pgsql-server/doc/src/sgml/backup.sgml,v
retrieving revision 2.32
diff -c -r2.32 backup.sgml
*** doc/src/sgml/backup.sgml 29 Nov 2003 19:51:36 -0000 2.32
--- doc/src/sgml/backup.sgml 30 Nov 2003 22:22:35 -0000
***************
*** 342,347 ****
--- 342,350 ----
<listitem>
<para>
+ <indexterm scope="All">
+ <primary>pg_clog</primary>
+ </indexterm>
If you have dug into the details of the file system layout of the data you
may be tempted to try to back up or restore only certain
individual tables or databases from their respective files or
Index: doc/src/sgml/wal.sgml
===================================================================
RCS file: /projects/cvsroot/pgsql-server/doc/src/sgml/wal.sgml,v
retrieving revision 1.26
diff -c -r1.26 wal.sgml
*** doc/src/sgml/wal.sgml 29 Nov 2003 19:51:38 -0000 1.26
--- doc/src/sgml/wal.sgml 30 Nov 2003 22:22:35 -0000
***************
*** 83,88 ****
--- 83,92 ----
<title>Future Benefits</title>
<para>
+ <indexterm scope="All">
+ <primary>pg_clog</primary>
+ </indexterm>
+
The UNDO operation is not implemented. This means that changes
made by aborted transactions will still occupy disk space and that
a permanent <filename>pg_clog</filename> file to hold
***************
*** 283,288 ****
--- 287,295 ----
</para>
<para>
+ <indexterm scope="All">
+ <primary>pg_xlog</primary>
+ </indexterm>
<acronym>WAL</acronym> logs are stored in the directory
<filename>pg_xlog</filename> under the data directory, as a set of
segment files, each 16 MB in size. Each segment is divided into 8
Index: doc/src/sgml/ref/pg_resetxlog.sgml
===================================================================
RCS file: /projects/cvsroot/pgsql-server/doc/src/sgml/ref/pg_resetxlog.sgml,v
retrieving revision 1.8
diff -c -r1.8 pg_resetxlog.sgml
*** doc/src/sgml/ref/pg_resetxlog.sgml 29 Nov 2003 19:51:39 -0000 1.8
--- doc/src/sgml/ref/pg_resetxlog.sgml 30 Nov 2003 22:22:35 -0000
***************
*** 73,78 ****
--- 73,84 ----
</para>
<para>
+ <indexterm scope="All">
+ <primary>pg_clog</primary>
+ </indexterm>
+ <indexterm scope="All">
+ <primary>pg_xlog</primary>
+ </indexterm>
The <literal>-o</>, <literal>-x</>, and <literal>-l</> switches allow
the next OID, next transaction ID, and WAL starting address values to
be set manually. These are only needed when
Oliver Elphick <olly@lfix.co.uk> writes:
The use of the word "log" in the directory name does tend to invite
this error, and some have acted on it without asking first. I think
initdb should put a README.IMPORTANT file in $PGDATA to say [...]
If someone deletes something from $PGDATA without understanding what
it is, they deserve what they get.
I do agree that we could stand to document the purpose of pg_clog
and pg_xlog more clearly. However, this information belongs in the
standard documentation, not scattered throughout $PGDATA.
-Neil
On Sun, 2003-11-30 at 23:18, Neil Conway wrote:
Oliver Elphick <olly@lfix.co.uk> writes:
The use of the word "log" in the directory name does tend to invite
this error, and some have acted on it without asking first. I think
initdb should put a README.IMPORTANT file in $PGDATA to say [...]If someone deletes something from $PGDATA without understanding what
it is, they deserve what they get.
People have a distressing tendency to want to shoot themselves in the
foot; and the somewhat unfortunate naming of those files contributes to
the problem. While it is satisfying to see stupidity properly rewarded,
it is more neighbourly at least to attempt to protect a fool from his
folly. It is also kinder to those who may be depending on him for the
protection of their data.
I do agree that we could stand to document the purpose of pg_clog
and pg_xlog more clearly. However, this information belongs in the
standard documentation, not scattered throughout $PGDATA.
Then it needs to be stated very prominently. But the place to put a
sign saying "Dangerous cliff edge" is beside the path that leads along
it.
--
Oliver Elphick Oliver.Elphick@lfix.co.uk
Isle of Wight, UK http://www.lfix.co.uk/oliver
GPG: 1024D/3E1D0C1C: CA12 09E0 E8D5 8870 5839 932A 614D 4C34 3E1D 0C1C
========================================
"Who is like unto thee, O LORD, among the gods? who is
like thee, glorious in holiness, fearful in praises,
doing wonders?" Exodus 15:11
Oliver Elphick <olly@lfix.co.uk> writes:
On Sun, 2003-11-30 at 23:18, Neil Conway wrote:
I do agree that we could stand to document the purpose of pg_clog
and pg_xlog more clearly. However, this information belongs in the
standard documentation, not scattered throughout $PGDATA.
Then it needs to be stated very prominently. But the place to put a
sign saying "Dangerous cliff edge" is beside the path that leads along
it.
How about changing the names of those directories?
regards, tom lane
Tom Lane wrote:
Oliver Elphick <olly@lfix.co.uk> writes:
On Sun, 2003-11-30 at 23:18, Neil Conway wrote:
I do agree that we could stand to document the purpose of pg_clog
and pg_xlog more clearly. However, this information belongs in the
standard documentation, not scattered throughout $PGDATA.Then it needs to be stated very prominently. But the place to put a
sign saying "Dangerous cliff edge" is beside the path that leads along
it.How about changing the names of those directories?
I thought about that, but what would we call them? We could change xlog
to wal, I guess. That might actually be clearer. xlog could become
xstatus or xactstatus or just xact.
--
Bruce Momjian | http://candle.pha.pa.us
pgman@candle.pha.pa.us | (610) 359-1001
+ If your life is a hard drive, | 13 Roberts Road
+ Christ can be your backup. | Newtown Square, Pennsylvania 19073
Bruce Momjian wrote:
Tom Lane wrote:
Oliver Elphick <olly@lfix.co.uk> writes:
On Sun, 2003-11-30 at 23:18, Neil Conway wrote:
I do agree that we could stand to document the purpose of pg_clog
and pg_xlog more clearly. However, this information belongs in the
standard documentation, not scattered throughout $PGDATA.Then it needs to be stated very prominently. But the place to put a
sign saying "Dangerous cliff edge" is beside the path that leads along
it.How about changing the names of those directories?
I thought about that, but what would we call them? We could change xlog
to wal, I guess. That might actually be clearer. xlog could become
xstatus or xactstatus or just xact.
active_xdata
active_cdata
Mike Mascari
mascarm@mascari.com
Oliver Elphick <olly@lfix.co.uk> writes:
Then it needs to be stated very prominently. But the place to put a
sign saying "Dangerous cliff edge" is beside the path that leads along
it.
The only way to make this prominent would be a file with the *name* "THIS
DIRECTORY CONTAINS CRITICAL DATA". Not a "README" with that message inside.
--
greg
Greg Stark wrote:
Oliver Elphick <olly@lfix.co.uk> writes:
Then it needs to be stated very prominently. But the place to put a
sign saying "Dangerous cliff edge" is beside the path that leads along
it.The only way to make this prominent would be a file with the *name* "THIS
DIRECTORY CONTAINS CRITICAL DATA". Not a "README" with that message inside.
Renaming the directories is the only suggestion I've seen that makes
sense. The others remind me of the warning that is now placed on coffee
cup lids at fast food places: "Caution, Contents May Be Hot".
cheers
andrew
On Mon, 2003-12-01 at 16:39, Andrew Dunstan wrote:
Renaming the directories is the only suggestion I've seen that makes
sense. The others remind me of the warning that is now placed on coffee
cup lids at fast food places: "Caution, Contents May Be Hot".
I agree that renaming the directories is the best solution.
--
Oliver Elphick Oliver.Elphick@lfix.co.uk
Isle of Wight, UK http://www.lfix.co.uk/oliver
GPG: 1024D/3E1D0C1C: CA12 09E0 E8D5 8870 5839 932A 614D 4C34 3E1D 0C1C
========================================
"Who is like unto thee, O LORD, among the gods? who is
like thee, glorious in holiness, fearful in praises,
doing wonders?" Exodus 15:11
Greg Stark writes:
Oliver Elphick <olly@lfix.co.uk> writes:
Then it needs to be stated very prominently. But the place to put a
sign saying "Dangerous cliff edge" is beside the path that leads along
it.Greg Stark <gsstark@mit.edu>, pThe only way to make this prominent would be a file with the *name* "THIS
DIRECTORY CONTAINS CRITICAL DATA". Not a "README" with that message inside.
That's exacly what I did, after some "root" came along and moved my pgdata
away while postmaster was running. The data was not that important in that
case, but nevertheless I put a file with a name like
NEVER_MOVE_THIS_DIRECTORY_WHILE_POSTMASTER_PROCESS_IS_RUNNING.txt
in pgdata and wrote a few lines in that file, how to shutdown postmaster
properly.
But renaming pgdata to something like that would be even better and could be
done alrealy (if I'm right).
Regards,
Tilo