SQL 脚本更新
This commit is contained in:
parent
94eca14838
commit
0c6cce1a5e
166
structure.sql
166
structure.sql
|
@ -15,14 +15,11 @@ CREATE TABLE public.short_urls (
|
|||
CONSTRAINT short_urls_un UNIQUE (short_url)
|
||||
);
|
||||
|
||||
INSERT INTO public.short_urls(short_url, dest_url, created_at, is_valid, memo)
|
||||
VALUES('AC7VgPE9', 'https://www.gitlink.org.cn/baladiwei/ohurlshortener', NOW(), true, '短链接系统 gitlink 页面');
|
||||
|
||||
INSERT INTO public.short_urls(short_url, dest_url, created_at, is_valid, memo)
|
||||
VALUES('AvTkHZP7', 'https://gitee.com/barat/ohurlshortener', NOW(), true, '短链接系统 gitee 页面');
|
||||
|
||||
INSERT INTO public.short_urls(short_url, dest_url, created_at, is_valid, memo)
|
||||
VALUES('gkT39tb5', 'https://github.com/barats/ohUrlShortener', NOW(), true, '短链接系统 github 页面');
|
||||
-- Insert new data
|
||||
INSERT INTO public.short_urls(short_url, dest_url, created_at, is_valid, memo) VALUES
|
||||
('AC7VgPE9', 'https://www.gitlink.org.cn/baladiwei/ohurlshortener', NOW(), true, '短链接系统 gitlink 页面'),
|
||||
('AvTkHZP7', 'https://gitee.com/barat/ohurlshortener', NOW(), true, '短链接系统 gitee 页面'),
|
||||
('gkT39tb5', 'https://github.com/barats/ohUrlShortener', NOW(), true, '短链接系统 github 页面');
|
||||
|
||||
|
||||
CREATE TABLE public.access_logs (
|
||||
|
@ -50,33 +47,132 @@ CREATE TABLE public.users (
|
|||
INSERT INTO public.users (account, "password") VALUES('ohUrlShortener', 'EZ2zQjC3fqbkvtggy9p2YaJiLwx1kKPTJxvqVzowtx6t');
|
||||
|
||||
|
||||
CREATE VIEW public.url_ip_count_stats AS
|
||||
SELECT
|
||||
u.short_url AS short_url,
|
||||
(SELECT count(ip) FROM public.access_logs WHERE date(ACCESS_TIME) = date(NOW()) AND short_url = u.short_url) AS today_count,
|
||||
(SELECT count(ip) FROM public.access_logs WHERE date(ACCESS_TIME) = (NOW() - INTERVAL '1 day')::date AND short_url = u.short_url) AS yesterday_count,
|
||||
(SELECT count(ip) FROM public.access_logs WHERE date(ACCESS_TIME) > (NOW() - INTERVAL '7 day')::date AND short_url = u.short_url) AS last_7_days_count,
|
||||
(SELECT count(ip) FROM public.access_logs WHERE DATE_PART('month',access_time) = DATE_PART('month',NOW()) AND short_url = u.short_url) AS monthly_count,
|
||||
(SELECT count(ip) FROM public.access_logs WHERE short_url = u.short_url) AS total_count,
|
||||
(SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE date(ACCESS_TIME) = date(NOW()) AND short_url = u.short_url) AS d_today_count,
|
||||
(SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE date(ACCESS_TIME) = (NOW() - INTERVAL '1 day')::date AND short_url = u.short_url) AS d_yesterday_count,
|
||||
(SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE date(ACCESS_TIME) > (NOW() - INTERVAL '7 day')::date AND short_url = u.short_url) AS d_last_7_days_count,
|
||||
(SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE DATE_PART('month',access_time) = DATE_PART('month',NOW()) AND short_url = u.short_url) AS d_monthly_count,
|
||||
(SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE short_url = u.short_url) AS d_total_count
|
||||
FROM public.short_urls u
|
||||
LEFT JOIN public.access_logs l ON u.short_url = l.short_url
|
||||
GROUP BY u.short_url;
|
||||
-- Create table for top25 urls
|
||||
CREATE TABLE public.stats_top25 (
|
||||
id serial4 NOT NULL,
|
||||
short_url varchar(200) NOT NULL,
|
||||
today_count int8 NOT NULL DEFAULT 0,
|
||||
d_today_count int8 NOT NULL DEFAULT 0,
|
||||
stats_time timestamp with time zone NOT NULL DEFAULT NOW(),
|
||||
CONSTRAINT stats_tv_pk PRIMARY KEY (id)
|
||||
);
|
||||
|
||||
CREATE VIEW public.sum_url_ip_count_stats AS
|
||||
SELECT
|
||||
COUNT(l.ip) AS today_count,
|
||||
COUNT(DISTINCT(l.ip)) AS d_today_count
|
||||
FROM public.access_logs l
|
||||
WHERE date(l.access_time) = date(NOW());
|
||||
-- Stored procedure for top25 urls
|
||||
CREATE FUNCTION p_stats_top25() RETURNS void AS $$
|
||||
BEGIN
|
||||
RAISE NOTICE 'Procedure p_stats_top25() called';
|
||||
|
||||
-- delete all records
|
||||
DELETE FROM public.stats_top25 WHERE 1=1;
|
||||
|
||||
-- insert fresh-new records
|
||||
INSERT INTO public.stats_top25(short_url,today_count,d_today_count,stats_time)
|
||||
SELECT l.short_url AS short_url, COUNT(l.ip) AS today_count ,COUNT(DISTINCT(l.ip)) AS d_today_count, NOW() AS stats_time
|
||||
FROM public.access_logs l WHERE date(l.access_time) = date(NOW()) GROUP BY l.short_url ORDER BY today_count DESC LIMIT 25;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE VIEW public.total_count_top25 AS
|
||||
SELECT u.*,tmp_logs.today_count, tmp_logs.d_today_count FROM public.short_urls u,(
|
||||
SELECT l.short_url,count(l.ip) AS today_count ,COUNT(DISTINCT(l.ip)) AS d_today_count
|
||||
FROM public.access_logs l WHERE date(l.access_time) = date(NOW()) GROUP BY l.short_url ORDER BY today_count DESC LIMIT 25) AS tmp_logs
|
||||
WHERE u.short_url = tmp_logs.short_url;
|
||||
-- Create table for sum view
|
||||
CREATE TABLE public.stats_sum (
|
||||
stats_key varchar(200) NOT NULL,
|
||||
stats_value int8 NOT NULL DEFAULT 0,
|
||||
CONSTRAINT stats_sum_key PRIMARY KEY (stats_key)
|
||||
);
|
||||
|
||||
-- Insert pre-defined stats
|
||||
INSERT INTO public.stats_sum (stats_key,stats_value) VALUES
|
||||
('today_count',0), ('d_today_count',0),
|
||||
('yesterday_count',0), ('d_yesterday_count',0),
|
||||
('last_7_days_count',0), ('d_last_7_days_count',0),
|
||||
('monthly_count',0), ('d_monthly_count',0);
|
||||
|
||||
-- Stored procedure for stats sum view
|
||||
CREATE FUNCTION p_stats_sum() RETURNS void AS $$
|
||||
DECLARE
|
||||
today_count int8;
|
||||
d_today_count int8;
|
||||
yesterday_count int8;
|
||||
d_yesterday_count int8;
|
||||
last_7_days_count int8;
|
||||
d_last_7_days_count int8;
|
||||
monthly_count int8;
|
||||
d_monthly_count int8;
|
||||
BEGIN
|
||||
RAISE NOTICE 'Procedure p_stats_sum() called';
|
||||
|
||||
SELECT COUNT(l.ip),COUNT(DISTINCT(l.ip)) INTO today_count,d_today_count
|
||||
FROM public.access_logs l WHERE date(l.access_time) = date(NOW());
|
||||
|
||||
SELECT COUNT(l.ip),COUNT(DISTINCT(l.ip)) INTO yesterday_count,d_yesterday_count
|
||||
FROM public.access_logs l WHERE date(l.access_time) = (NOW() - INTERVAL '1 day')::date;
|
||||
|
||||
SELECT COUNT(l.ip),COUNT(DISTINCT(l.ip)) INTO last_7_days_count,d_last_7_days_count
|
||||
FROM public.access_logs l WHERE date(l.access_time) >= (NOW() - INTERVAL '7 day')::date;
|
||||
|
||||
SELECT COUNT(l.ip),COUNT(DISTINCT(l.ip)) INTO monthly_count,d_monthly_count
|
||||
FROM public.access_logs l WHERE DATE_PART('month', l.access_time) = DATE_PART('month',NOW());
|
||||
|
||||
UPDATE public.stats_sum SET stats_value =
|
||||
CASE
|
||||
WHEN stats_key = 'today_count' THEN today_count
|
||||
WHEN stats_key = 'd_today_count' THEN d_today_count
|
||||
WHEN stats_key = 'yesterday_count' THEN yesterday_count
|
||||
WHEN stats_key = 'd_yesterday_count' THEN d_yesterday_count
|
||||
WHEN stats_key = 'last_7_days_count' THEN last_7_days_count
|
||||
WHEN stats_key = 'd_last_7_days_count' THEN d_last_7_days_count
|
||||
WHEN stats_key = 'monthly_count' THEN monthly_count
|
||||
WHEN stats_key = 'd_monthly_count' THEN d_monthly_count
|
||||
ELSE 0
|
||||
END;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Create table for ip url sum
|
||||
CREATE TABLE public.stats_ip_sum (
|
||||
short_url varchar(200) NOT NULL,
|
||||
today_count int8 NOT NULL DEFAULT 0,
|
||||
d_today_count int8 NOT NULL DEFAULT 0,
|
||||
yesterday_count int8 NOT NULL DEFAULT 0,
|
||||
d_yesterday_count int8 NOT NULL DEFAULT 0,
|
||||
last_7_days_count int8 NOT NULL DEFAULT 0,
|
||||
d_last_7_days_count int8 NOT NULL DEFAULT 0,
|
||||
monthly_count int8 NOT NULL DEFAULT 0,
|
||||
d_monthly_count int8 NOT NULL DEFAULT 0,
|
||||
total_count int8 NOT NULL DEFAULT 0,
|
||||
d_total_count int8 NOT NULL DEFAULT 0,
|
||||
CONSTRAINT stats_ip_sum_pk PRIMARY KEY (short_url)
|
||||
);
|
||||
|
||||
-- Stored procedure for ip url sum
|
||||
CREATE FUNCTION p_stats_ip_sum() RETURNS void AS $$
|
||||
BEGIN
|
||||
|
||||
RAISE NOTICE 'Procedure p_stats_ip_sum() called';
|
||||
|
||||
-- Delete all records
|
||||
DELETE FROM public.stats_ip_sum WHERE 1=1;
|
||||
|
||||
-- Calculate new stats data
|
||||
INSERT INTO public.stats_ip_sum(short_url,today_count,d_today_count,yesterday_count,d_yesterday_count,last_7_days_count,d_last_7_days_count,
|
||||
monthly_count,d_monthly_count,total_count,d_total_count)
|
||||
SELECT
|
||||
u.short_url,
|
||||
(SELECT count(ip) FROM public.access_logs WHERE date(access_time) = date(NOW()) AND short_url = u.short_url),
|
||||
(SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE date(access_time) = date(NOW()) AND short_url = u.short_url),
|
||||
|
||||
(SELECT count(ip) FROM public.access_logs WHERE date(access_time) = (NOW() - INTERVAL '1 day')::date AND short_url = u.short_url),
|
||||
(SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE date(access_time) = (NOW() - INTERVAL '1 day')::date AND short_url = u.short_url),
|
||||
|
||||
(SELECT count(ip) FROM public.access_logs WHERE date(access_time) >= (NOW() - INTERVAL '7 day')::date AND short_url = u.short_url),
|
||||
(SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE date(access_time) >= (NOW() - INTERVAL '7 day')::date AND short_url = u.short_url),
|
||||
|
||||
(SELECT count(ip) FROM public.access_logs WHERE DATE_PART('month',access_time) = DATE_PART('month',NOW()) AND short_url = u.short_url),
|
||||
(SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE DATE_PART('month',access_time) = DATE_PART('month',NOW()) AND short_url = u.short_url),
|
||||
|
||||
(SELECT count(ip) FROM public.access_logs WHERE short_url = u.short_url),
|
||||
(SELECT count(DISTINCT(ip)) FROM public.access_logs WHERE short_url = u.short_url)
|
||||
FROM public.short_urls u
|
||||
LEFT JOIN public.access_logs l ON u.short_url = l.short_url
|
||||
GROUP BY u.short_url;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
Loading…
Reference in New Issue