xref: /netbsd-src/share/examples/puffs/pgfs/check.sql (revision 49413e37758aefe75effb0f891d65c98cc944d13)
1*49413e37Syamt-- $NetBSD: check.sql,v 1.1 2011/10/12 01:05:00 yamt Exp $
2*49413e37Syamt
3*49413e37Syamt-- Copyright (c)2010,2011 YAMAMOTO Takashi,
4*49413e37Syamt-- All rights reserved.
5*49413e37Syamt--
6*49413e37Syamt-- Redistribution and use in source and binary forms, with or without
7*49413e37Syamt-- modification, are permitted provided that the following conditions
8*49413e37Syamt-- are met:
9*49413e37Syamt-- 1. Redistributions of source code must retain the above copyright
10*49413e37Syamt--    notice, this list of conditions and the following disclaimer.
11*49413e37Syamt-- 2. Redistributions in binary form must reproduce the above copyright
12*49413e37Syamt--    notice, this list of conditions and the following disclaimer in the
13*49413e37Syamt--    documentation and/or other materials provided with the distribution.
14*49413e37Syamt--
15*49413e37Syamt-- THIS SOFTWARE IS PROVIDED BY THE AUTHOR AND CONTRIBUTORS ``AS IS'' AND
16*49413e37Syamt-- ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE
17*49413e37Syamt-- IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE
18*49413e37Syamt-- ARE DISCLAIMED.  IN NO EVENT SHALL THE AUTHOR OR CONTRIBUTORS BE LIABLE
19*49413e37Syamt-- FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL
20*49413e37Syamt-- DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS
21*49413e37Syamt-- OR SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION)
22*49413e37Syamt-- HOWEVER CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT
23*49413e37Syamt-- LIABILITY, OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY
24*49413e37Syamt-- OUT OF THE USE OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF
25*49413e37Syamt-- SUCH DAMAGE.
26*49413e37Syamt
27*49413e37Syamt-- filesystem consistency checks.  ie. something like "fsck -n"
28*49413e37Syamt
29*49413e37SyamtBEGIN;
30*49413e37SyamtSET TRANSACTION ISOLATION LEVEL REPEATABLE READ;
31*49413e37SyamtSET TRANSACTION READ ONLY;
32*49413e37SyamtSET search_path TO pgfs;
33*49413e37SyamtSELECT count(*) AS "unreferenced files (dirent)"
34*49413e37Syamt	FROM file f LEFT JOIN dirent d
35*49413e37Syamt	ON f.fileid = d.child_fileid
36*49413e37Syamt	WHERE f.fileid <> 1 AND d.child_fileid IS NULL;
37*49413e37SyamtSELECT count(*) AS "unreferenced files (nlink)"
38*49413e37Syamt	FROM file f
39*49413e37Syamt	WHERE f.nlink = 0;
40*49413e37SyamtSELECT count(*) AS "regular files without datafork"
41*49413e37Syamt	FROM file f LEFT JOIN datafork df
42*49413e37Syamt	ON f.fileid = df.fileid
43*49413e37Syamt	WHERE df.fileid IS NULL AND f.type IN ('regular', 'link');
44*49413e37SyamtSELECT count(*) AS "broken datafork reference"
45*49413e37Syamt	FROM file f INNER JOIN datafork df
46*49413e37Syamt	ON f.fileid = df.fileid
47*49413e37Syamt	WHERE f.type NOT IN ('regular', 'link');
48*49413e37SyamtSELECT count(*) AS "unreferenced dataforks"
49*49413e37Syamt	FROM file f RIGHT JOIN datafork df
50*49413e37Syamt	ON f.fileid = df.fileid
51*49413e37Syamt	WHERE f.fileid IS NULL;
52*49413e37SyamtSELECT count(*) AS "dataforks without large object"
53*49413e37Syamt	FROM datafork df LEFT JOIN pg_largeobject_metadata lm
54*49413e37Syamt	ON df.loid = lm.oid
55*49413e37Syamt	WHERE lm.oid IS NULL;
56*49413e37SyamtSELECT count(*) AS "unreferenced large objects"
57*49413e37Syamt	FROM datafork df RIGHT JOIN pg_largeobject_metadata lm
58*49413e37Syamt	ON df.loid = lm.oid
59*49413e37Syamt	WHERE df.loid IS NULL;
60*49413e37SyamtSELECT count(*) AS "dirent broken parent_fileid references"
61*49413e37Syamt	FROM dirent d LEFT JOIN file f
62*49413e37Syamt	ON d.parent_fileid = f.fileid
63*49413e37Syamt	WHERE f.fileid IS NULL OR f.type <> 'directory';
64*49413e37SyamtSELECT count(*) AS "dirent broken child_fileid references"
65*49413e37Syamt	FROM dirent d LEFT JOIN file f
66*49413e37Syamt	ON d.child_fileid = f.fileid
67*49413e37Syamt	WHERE f.fileid IS NULL;
68*49413e37SyamtSELECT count(*) AS "dirent loops" FROM file f WHERE EXISTS (
69*49413e37Syamt	WITH RECURSIVE r AS
70*49413e37Syamt	(
71*49413e37Syamt			SELECT d.* FROM dirent d
72*49413e37Syamt				WHERE d.child_fileid = f.fileid
73*49413e37Syamt		UNION ALL
74*49413e37Syamt			SELECT d.* FROM dirent d INNER JOIN r
75*49413e37Syamt				ON d.child_fileid = r.parent_fileid
76*49413e37Syamt	)
77*49413e37Syamt	SELECT * FROM r WHERE r.parent_fileid = f.fileid);
78*49413e37SyamtSELECT count(*) AS "broken nlink"
79*49413e37Syamt	FROM
80*49413e37Syamt	(
81*49413e37Syamt	SELECT coalesce(fp.fileid, fc.fileid) AS fileid,
82*49413e37Syamt		coalesce(fp.nlink, 0) + coalesce(fc.nlink, 0) +
83*49413e37Syamt		CASE
84*49413e37Syamt			WHEN coalesce(fp.fileid, fc.fileid) = 1 THEN 1
85*49413e37Syamt			ELSE 0
86*49413e37Syamt		END
87*49413e37Syamt		AS nlink
88*49413e37Syamt		FROM
89*49413e37Syamt		(
90*49413e37Syamt		SELECT child_fileid AS fileid, count(*) AS nlink
91*49413e37Syamt			FROM dirent
92*49413e37Syamt			GROUP BY child_fileid
93*49413e37Syamt		) fp
94*49413e37Syamt		FULL JOIN
95*49413e37Syamt		(
96*49413e37Syamt		SELECT count(*) AS nlink, d.parent_fileid AS fileid
97*49413e37Syamt			FROM dirent d
98*49413e37Syamt			JOIN file f
99*49413e37Syamt			ON d.child_fileid = f.fileid
100*49413e37Syamt			WHERE f.type = 'directory'
101*49413e37Syamt			GROUP BY parent_fileid
102*49413e37Syamt		) fc
103*49413e37Syamt		ON fp.fileid = fc.fileid
104*49413e37Syamt	) d
105*49413e37Syamt	FULL JOIN file f
106*49413e37Syamt	ON d.fileid = f.fileid
107*49413e37Syamt	WHERE (d.nlink IS NULL AND (f.fileid <> 1 AND f.nlink <> 0))
108*49413e37Syamt	    OR f.nlink IS NULL
109*49413e37Syamt	    OR d.nlink <> f.nlink;
110*49413e37SyamtCOMMIT;
111