Created
October 28, 2020 09:36
-
-
Save antonagestam/46bc93ffc0bf55da3cfc59c9270cec58 to your computer and use it in GitHub Desktop.
Postgres SE SSN constraint
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
CREATE OR REPLACE FUNCTION se_ssn_valid (VARCHAR(12)) | |
RETURNS boolean | |
AS $$ | |
SELECT | |
char_length($1) = 12 | |
AND date_part('year', age(now(), to_timestamp(substring($1, 1, 8), 'YYYYMMDD'))) > 0 | |
AND ( | |
(select sum(t) from unnest(regexp_split_to_array((substring($1, 3, 1)::int * 2)::text, '')::int[]) as t) | |
+ (select sum(t) from unnest(regexp_split_to_array((substring($1, 4, 1)::int * 1)::text, '')::int[]) as t) | |
+ (select sum(t) from unnest(regexp_split_to_array((substring($1, 5, 1)::int * 2)::text, '')::int[]) as t) | |
+ (select sum(t) from unnest(regexp_split_to_array((substring($1, 6, 1)::int * 1)::text, '')::int[]) as t) | |
+ (select sum(t) from unnest(regexp_split_to_array((substring($1, 7, 1)::int * 2)::text, '')::int[]) as t) | |
+ (select sum(t) from unnest(regexp_split_to_array((substring($1, 8, 1)::int * 1)::text, '')::int[]) as t) | |
+ (select sum(t) from unnest(regexp_split_to_array((substring($1, 9, 1)::int * 2)::text, '')::int[]) as t) | |
+ (select sum(t) from unnest(regexp_split_to_array((substring($1, 10, 1)::int * 1)::text, '')::int[]) as t) | |
+ (select sum(t) from unnest(regexp_split_to_array((substring($1, 11, 1)::int * 2)::text, '')::int[]) as t) | |
+ substring($1, 12, 1)::int | |
) % 10 = 0; | |
$$ | |
LANGUAGE SQL | |
IMMUTABLE; | |
create table person ( | |
id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, | |
ssn VARCHAR(12) null, | |
CONSTRAINT valid_date CHECK (se_ssn_valid(ssn)) | |
); |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment