Here I am giving an example of PL/SQL stored function to validate the Credit Card number and identify its type, whether it is a Visa, MasterCard or American Express Credit Card. I am checking the Credit Card number using the LUHN Algorithm which is used to validate a variety of identification numbers. If Credit Card number is valid, then the function checks for its type.
PL/SQL Function Example to Validate Credit Card Number and Its Type in Oracle
The following function takes an argument as Credit Card number and then validates the number using Luhn algorithm and returns its type. Currently, this PL/SQL function supports three kinds of the Credit Cards which are Visa, MasterCard, and American Express. You can modify to add more Credit Card types. Function CHECK_LUHN_ALGO to check the number using Luhn algorithm is written inside the function VALIDATE_CC, so if you want to add the more card types support then no need to change the CHECK_LUHN_ALGO function, change only the main part of the VALIDATE_CC function.
CREATE OR REPLACE FUNCTION validate_CC (cc_number IN VARCHAR2) RETURN VARCHAR2 IS v_ret_string VARCHAR2 (100); FUNCTION check_luhn_algo (p_ccnumber VARCHAR2) RETURN NUMBER IS i NUMBER; n_ntoi SMALLINT; n_retval SMALLINT; n_calc NUMBER := 0; n_ntoc NUMBER; BEGIN n_ntoc := LENGTH (p_ccnumber); FOR i IN 1 .. n_ntoc LOOP n_ntoi := TO_NUMBER (SUBSTR (p_ccnumber, n_ntoc + 1 - i, 1)); n_calc := n_calc + MOD (i, 2) * n_ntoi + MOD (i + 1, 2) * SIGN (-SIGN (n_ntoi - 4) + 1) * (2 * n_ntoi) + MOD (i + 1, 2) * SIGN (SIGN (n_ntoi - 5) + 1) * (2 * n_ntoi - 9); END LOOP; n_retval := SIGN (MOD (n_calc, 10)); RETURN n_retval; EXCEPTION WHEN OTHERS THEN RETURN 1; END check_luhn_algo; BEGIN /* Credit card number is invalid if below funciton returns non zero value */ IF check_luhn_algo (cc_number) != 0 THEN v_ret_string := 'Not a valid Credit Card Number.'; RETURN v_ret_string; ELSE v_ret_string := 'A Valid '; END IF; /* Credit card number is valid now check for its type */ IF SUBSTR (cc_number, 1, 1) = '4' /* check if it is a Visa card */ THEN IF LENGTH (cc_number) = 13 OR LENGTH (cc_number) = 16 THEN v_ret_string := v_ret_string || 'Visa Credit Card Number.'; END IF; ELSIF SUBSTR (cc_number, 1, 2) BETWEEN 51 AND 55 /* check if master card*/ THEN IF LENGTH (cc_number) = 16 THEN v_ret_string := v_ret_string || 'MasterCard Credit Card Number.'; END IF; ELSIF SUBSTR (cc_number, 1, 2) = 34 OR SUBSTR (cc_number, 1, 2) = 37 /* check if amex card */ THEN IF LENGTH (cc_number) = 15 THEN v_ret_string := v_ret_string || 'American Express Credit Card Number.'; END IF; ELSE v_ret_string := v_ret_string || 'But unable to identify its type.'; END IF; RETURN v_ret_string; EXCEPTION WHEN OTHERS THEN RETURN 'Error...'; END validate_CC;
Test
Change the 4047xxxxxxxxxxxx string below with your Visa, MasterCard or Amex Credit Card number to test.
SET SERVEROUTPUT ON; DECLARE RetVal VARCHAR2 (100); CC_NUMBER VARCHAR2 (100); BEGIN CC_NUMBER := '4047xxxxxxxxxxxx'; RetVal := VALIDATE_CC (CC_NUMBER); DBMS_OUTPUT.put_line (retval); END; /
Output
A Valid Visa Credit Card Number. PL/SQL procedure successfully completed.
Note: Test thoroughly before implementing in your application.
See also:
- Validate Email Address using PL/SQL in Oracle