prototyp/prototyp.sql
author František Kučera <franta-hg@frantovo.cz>
Mon, 01 Sep 2014 20:03:39 +0200
changeset 8 0f6df6850ba6
parent 7 8f0e2d417702
child 9 9963cf89ffd7
permissions -rw-r--r--
prototyp: users_groups – buggy:

second run in UNION:
WARNING: SQL: XXX skupina je schizoidní 0
groups are not iterater for second time in one query (unioned)

Also this:
SELECT * FROM users; SELECT * FROM users;
returns weird results – first resultset is OK, second one is empty
     1 -- SQL-UNIX-API (prototype)
     2 -- Copyright © 2014 František Kučera (frantovo.cz)
     3 -- 
     4 -- This program is free software: you can redistribute it and/or modify
     5 -- it under the terms of the GNU General Public License as published by
     6 -- the Free Software Foundation, either version 3 of the License, or
     7 -- (at your option) any later version.
     8 -- 
     9 -- This program is distributed in the hope that it will be useful,
    10 -- but WITHOUT ANY WARRANTY; without even the implied warranty of
    11 -- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
    12 -- GNU General Public License for more details.
    13 -- 
    14 -- You should have received a copy of the GNU General Public License
    15 -- along with this program. If not, see <http://www.gnu.org/licenses/>.
    16 
    17 
    18 
    19 -- CREATE SCHEMA unix_sql_api;
    20 
    21 SET search_path TO unix_sql_api;
    22 
    23 
    24 -- fstab: --------------------------------------------------------------------
    25 
    26 DROP VIEW IF EXISTS fstab;
    27 DROP FUNCTION IF EXISTS fstab();
    28 DROP TYPE IF EXISTS unix_sql_api_fstab;
    29 
    30 CREATE TYPE unix_sql_api_fstab AS (
    31 	device VARCHAR,
    32 	device_type VARCHAR,
    33 	device_value VARCHAR,
    34 	mount_point VARCHAR,
    35 	type VARCHAR,
    36 	types VARCHAR[],
    37 	options VARCHAR[],
    38 	dump INTEGER,
    39 	pass INTEGER
    40 );
    41 
    42 CREATE OR REPLACE FUNCTION fstab()
    43 RETURNS SETOF unix_sql_api_fstab AS $$
    44 	use strict;
    45 	use warnings;
    46 	
    47 	open(FSTAB, "<", "/etc/fstab") or die $!;
    48 	
    49 	while (<FSTAB>) {
    50 		if (/^([^\s#]+)\s+([^\s]+)\s+([^\s]+)\s+([^\s]+)\s+(\d+)\s+(\d+)\s*$/) {
    51 			
    52 			my $device_spec_type;
    53 			my $device_spec_value;
    54 			{
    55 				if ($1 =~ /([^=]+)=(.*)/) {
    56 					($device_spec_type, $device_spec_value) = ($1, $2);
    57 				}
    58 			}
    59 			
    60 			return_next({
    61 				device => $1,
    62 				device_type => $device_spec_type,
    63 				device_value => $device_spec_value,
    64 				mount_point => $2,
    65 				type => $3,
    66 				types => [split(",", $3)],
    67 				options => [split(",", $4)],
    68 				dump => $5,
    69 				pass => $6
    70 			});
    71 		}
    72 	}
    73 	
    74 	return undef;
    75 $$ LANGUAGE plperlu;
    76 
    77 CREATE OR REPLACE VIEW fstab AS
    78 	SELECT * FROM fstab()
    79 ;
    80 
    81 
    82 -- user groups: --------------------------------------------------------------
    83 
    84 DROP VIEW IF EXISTS users_groups;
    85 DROP VIEW IF EXISTS users_groups_primary;
    86 DROP VIEW IF EXISTS users_groups_secondary;
    87 
    88 DROP VIEW IF EXISTS groups;
    89 DROP FUNCTION IF EXISTS groups();
    90 DROP TYPE IF EXISTS unix_sql_api_groups;
    91 
    92 CREATE TYPE unix_sql_api_groups AS (
    93 	id INTEGER,
    94 	name VARCHAR,
    95 	members VARCHAR[]
    96 );
    97 
    98 CREATE OR REPLACE FUNCTION groups()
    99 RETURNS SETOF unix_sql_api_groups STABLE AS $$
   100 	use strict;
   101 	use warnings;
   102 
   103 	use User::grent;
   104 	
   105 	my $i = 0;
   106 
   107 	while (my $group = getgrent()) {
   108 		return_next({
   109 			id => $group->gid,
   110 			name => $group->name,
   111 			members => [@{$group->members}]
   112 		});
   113 		elog(NOTICE, "skupina je schizoidní " . $i++);
   114 	}
   115 	elog(NOTICE, "XXX skupina je schizoidní " . $i++);
   116 	
   117 	elog(NOTICE, "members field does not contain users who have this group as primary one");
   118 	
   119 	return undef;
   120 $$ LANGUAGE plperlu;
   121 
   122 CREATE OR REPLACE VIEW groups AS
   123 	SELECT * FROM groups()
   124 ;
   125 COMMENT ON COLUMN groups.members IS 'does not contain users who have this group as primary one';
   126 
   127 
   128 -- users: --------------------------------------------------------------------
   129 
   130 DROP VIEW IF EXISTS users;
   131 DROP FUNCTION IF EXISTS users();
   132 DROP TYPE IF EXISTS unix_sql_api_users;
   133 
   134 CREATE TYPE unix_sql_api_users AS (
   135 	id INTEGER,
   136 	gid INTEGER,
   137 	name VARCHAR,
   138 	-- comment VARCHAR,
   139 	gecos VARCHAR[],
   140 	home VARCHAR,
   141 	shell VARCHAR
   142 	-- expire VARCHAR
   143 );
   144 
   145 CREATE OR REPLACE FUNCTION users()
   146 RETURNS SETOF unix_sql_api_users STABLE AS $$
   147 	use strict;
   148 	use warnings;
   149 	
   150 	use encoding "UTF-8";
   151 	use User::pwent;
   152 	
   153 	my $i = 0;
   154 	
   155 	while (my $user = getpwent()) {
   156 		return_next({
   157 			id => $user->uid,
   158 			gid => $user->gid,
   159 			name => $user->name,
   160 			# comment => $user->comment,
   161 			gecos => [split(",", $user->gecos)],
   162 			home => $user->dir,
   163 			shell => $user->shell,
   164 			# expire => $user->expire
   165 		});
   166 		elog(NOTICE, "uživatel je schizoidní " . $i++);
   167 	}
   168 	
   169 	elog(NOTICE, "XXX uživatel je schizoidní " . $i++);
   170 	
   171 	return undef;
   172 $$ LANGUAGE plperlu;
   173 
   174 CREATE OR REPLACE VIEW users AS
   175 	SELECT * FROM users()
   176 ;
   177 
   178 
   179 -- users_groups: -------------------------------------------------------------
   180 
   181 CREATE OR REPLACE VIEW users_groups_primary AS
   182 	SELECT
   183 		u1.id AS uid,
   184 		u1.gid AS gid,
   185 		u1.name AS user,
   186 		g1.name AS group,
   187 		true AS primary
   188 	FROM users AS u1
   189 	JOIN groups AS g1 ON (u1.gid = g1.id)
   190 ;
   191 
   192 CREATE OR REPLACE VIEW users_groups_secondary AS
   193 	SELECT
   194 		u2.id AS uid,
   195 		g2.*,
   196 		false AS primary
   197 	FROM
   198 		(SELECT
   199 			id AS gid,
   200 			unnest(members) AS user,
   201 			name AS group
   202 		FROM groups) AS g2
   203 	JOIN users AS u2 ON (u2.name = g2.user)
   204 ;
   205 
   206 CREATE OR REPLACE VIEW users_groups AS
   207 	SELECT * FROM users_groups_primary
   208 	UNION
   209 	SELECT * FROM users_groups_secondary
   210 ;
   211